Cody Pendant has asked for the wisdom of the Perl Monks concerning the following question:

Say I have a MySQL db that I want to search for the phrase

it's not a problem

Then I have to use something like this:

SELECT * FROM foo WHERE bar LIKE 'it's not a problem'

But of course that doesn't work.

So I try and use $dbh->quote(), which changes it to this:

SELECT * FROM foo WHERE bar LIKE 'it\'s not a problem'

But that doesn't work either.

The way to successfully search with apostrophes in a LIKE statment is

SELECT * FROM foo WHERE bar LIKE 'it''s not a problem'

So is there another quote() method I could be using to get that result? Or shall I just hope that

$str =~ s/'/''/g

Will do the trick, and I don't end up with an odd number?



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

Replies are listed 'Best First'.
Re: Quoting Strings For SQL LIKE queries
by jZed (Prior) on Dec 22, 2004 at 00:47 UTC
    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});
      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).

        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        

Re: Quoting Strings For SQL LIKE queries
by aquarium (Curate) on Dec 22, 2004 at 04:41 UTC
    btw..doing your manual search/replace
    $str =~ s/'/''/g;
    ...will never produce an odd number of single quotes, no matter what the string. think about it :)
    the hardest line to type correctly is: stty erase ^H