in reply to Quoting Strings For SQL LIKE queries

First of all, you don't have any % or _ wildcards, so do you really need a LIKE comparison? Second, what do you mean $dbh->quote() doesn't work, of course it does, perhaps you are using it wrong, show us the code. And third, the safest and best way to deal with embedded quotes (and pretty much everything else) is to use placeholders:
my $sth=$dbh->prepare(q{ SELECT * FROM foo WHERE bar LIKE ? }); $sth->execute(q{it's not a problem});

Replies are listed 'Best First'.
Re^2: Quoting Strings For SQL LIKE queries
by Cody Pendant (Prior) on Dec 22, 2004 at 01:01 UTC
    Sorry, you're quite right, that was just an example and I should have posted
    SELECT * FROM foo WHERE bar LIKE '%it's not a problem%'
    or similar.

    OK for an example of it not working? If I do this:

    $str = $dbh->quote("it's not a problem"); $sth = $dbh->prepare( "SELECT * FROM practice WHERE name LIKE '%$str%'" ) || die "Error: " . $dbh->errstr; $sth->execute() || die "Error: " . $dbh->errstr;

    I get an error:

    Error: You have an error in your SQL syntax. Check the manual that cor +responds to your MySQL server version for the right syntax to use nea +r 'it\'s not a problem'%'' at line 1 at /foo/bar.cgi line 29.

    What I'm saying is, the quote() function puts backslashes before my apostrophes. But that's not what I need if it's LIKE (something containing an apostrophe). What am I missing?



    ($_='kkvvttuubbooppuuiiffssqqffssmmiibbddllffss')
    =~y~b-v~a-z~s; print
      If you use $dbh->quote() on a string, that puts quote marks around it, so when you put more quotes around it in your SQL you are ruining it. Here are two ways to do it:
      $str = $dbh->quote("%it's not a problem%"); $sth = $dbh->prepare( "SELECT * FROM practice WHERE name LIKE $str" ) || die "Error: " . $dbh->errstr; $sth->execute() || die "Error: " . $sth->errstr; OR BETTER $str = "%it's not a problem%"; $sth = $dbh->prepare( "SELECT * FROM practice WHERE name LIKE ?" ) || die "Error: " . $dbh->errstr; $sth->execute($str) || die "Error: " . $sth->errstr;
      Note that I also changed $dbh->errstr to $sth->errstr for your execute, the error is in whatever handle you are using ($dbh for prepare, $sth for execute).
        Ah, I see. Of course it puts quotes around it.

        But there's still something I don't get.

        If I use your code, and print $str after you've quoted it:

        $str = $dbh->quote("%it's not a problem%"); print "<p>quoted: $str</p>";

        I can see that it's been changed into '%it\'s not a problem%'

        And it works.

        But if I use that string literally, as in:

        $sth = $dbh->prepare( "SELECT name FROM practice WHERE name LIKE '%it\'s not a problem%' " ) || die "Error: " . $dbh->errstr;

        I get the error again.

        And if instead I use this:

        $sth = $dbh->prepare( "SELECT name FROM practice WHERE name LIKE '%it''s not a problem%' " ) || die "Error: " . $dbh->errstr;
        Then it works. Can you see the disconnect, and why I "deduced", wrongly it seems, that there are two different kinds of quoting?


        ($_='kkvvttuubbooppuuiiffssqqffssmmiibbddllffss')
        =~y~b-v~a-z~s; print

      Ohh, what's really going to bake your noodle later on is, how do you portably quote the '%' or '_' in $str (you want to search for bars that mention "the 7% solution").

      - tye