Beefy Boxes and Bandwidth Generously Provided by pair Networks
Perl-Sensitive Sunglasses
 
PerlMonks  

Quote mark in string messing up mySQL INSERT

by heezy (Monk)
on Dec 12, 2002 at 04:55 UTC ( #219250=perlquestion: print w/replies, xml ) Need Help??

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

Hi

Here's the thing... I have a lovely simple procedure...

sub insertAttribute{ my ($serverID, $featureID, $value) = @_; my $sqlINS = qq{ INSERT INTO attribute VALUES ("$serverID", "$feat +ureID", "$value") }; $dbh->do ($sqlINS); }

It works fine providing that $value does not contain any quotes " " " " So...

Dynamic System Domains

...works fine but...

Rack-optimized 30" deep design

...doesn't becuase of the quote messing things up

How can I overcome this problem, I'm sure it must be quite a common thing just I've never encountered before.

Thanks in advance,

M

Replies are listed 'Best First'.
Re: Quote mark in string messing up mySQL INSERT
by diotalevi (Canon) on Dec 12, 2002 at 05:06 UTC

    Placeholders. Definately placeholders. You won't have to worry about quoting then because it happens automatically (or even for some cases it saves a step or two internally)

    sub insertAttribute { my ($serverID, $featureID, $value) = @_; my $sqlINS = q{ INSERT INTO attribute VALUES (?, ?, ?) }; $dbh->do ( $sqlINS, undef, $serverID, $featureID, $value ); }

    Update: BTW I said exactly this yesterday Re^2: Strange experiences w/ perl 5.6.0 on linux 2.2.16-22

    __SIG__ use B; printf "You are here %08x\n", unpack "L!", unpack "P4", pack "L!", B::svref_2object(sub{})->OUTSIDE;
      I second this - placeholders is definitely the way to go. Get used to using them - not only will you not have to worry about proper quoting any more, but in some situations you'll get big performance gains. There's really no reason not to use placeholders, and many reasons *to* use them.

      You may already by doing this, but since I can't see any in your submitted code, I'll just add that you should be error checking your DBI statements. I typically use "RaiseError" with "eval" - proper error checking is described very nicely in the DBI perldocs.
      perldoc DBI
      at a command prompt.

      HTH.
      There's a problem with MySQL and placeholders which I discovered in Re^2: DBD::mysql Unusual Behavior. The only sure-fire way to work around it is to ensure that your string values are string values. In short, this means that the internal type of the variable is set correctly.

      If the first variable sent into the placeholder is an integer, subsequent calls using the same statement handle might fail on string data. Here, this is just a do() call, so you're probably okay. If you use prepare() and more than one execute() you can encounter problems.
      sub insertAttribute { my ($serverID, $featureID, $value) = @_; my $sqlINS = "INSERT INTO attribute VALUES (?,?,?)"; $dbh->do($sqlINS, {}, "$serverID", "$featureID", "$value"); }
      Of course, this might depend on the version of DBD::mysql that you use.
        Also, last I checked, you CANNOT use placeholders with the version of DBD::Sybase that works with FreeTDS and MS-SQL. :(
        --
        Spring: Forces, Coiled Again!
Re: Quote mark in string messing up mySQL INSERT
by htoug (Deacon) on Dec 12, 2002 at 11:19 UTC
    Either placeholders or use the quote function in DBI.

    I would recode your example thus (completely untested and with no warranty):

    sub insertAttribute{ my ($serverID, $featureID, $value) = @_; $_ = $dbh->quote($_) for qw($serverID, $featureID, $value); my $sqlINS = qq{ INSERT INTO attribute VALUES ($serverID, $feature +ID, $value) }; $dbh->do ($sqlINS); }
    Remember: $dbh->quote(expression) is your friend.

      Using $dbh->quote or placeholders will also prevent you from suffering SQL injection attacks... which could clear out your database if you're unlucky! tom
        Is it safe to use apostrophes instead of quotes? In the past I have always done:
        $dbh->do("insert into mytable values('$myStringWhichPossiblyContainsQu +otes', '$another string', ...);
        Rohit
Re: Quote mark in string messing up mySQL INSERT
by khudgins (Sexton) on Dec 13, 2002 at 18:28 UTC

    Check your DBI docs for more specifics, but you don't have to put your data directly into the string like you're doing.

    You can just as easily say:

    my $sqlString = "INSERT INTO attribute VALUES (?, ?, ?)"; $dbh->prepare($sqlString); $dbh->execute($serverId, $featureID, $value);

    The best thing is, if you've got a lot of them and wanna do multiple inserts, you can put the $dbh->execute() statement into a loop by itself. With most databases that will make a pretty significant performance increase for you.

    A far better explanation of this technique can be found here.
Re: Quote mark in string messing up mySQL INSERT
by Anonymous Monk on Dec 13, 2002 at 04:36 UTC
    escape the " with a backlash
    ie use \"
    all the best

Log In?
Username:
Password:

What's my password?
Create A New User
Domain Nodelet?
Node Status?
node history
Node Type: perlquestion [id://219250]
Approved by fireartist
Front-paged by htoug
help
Chatterbox?
and the web crawler heard nothing...

How do I use this? | Other CB clients
Other Users?
Others scrutinizing the Monastery: (3)
As of 2021-10-16 20:41 GMT
Sections?
Information?
Find Nodes?
Leftovers?
    Voting Booth?
    My first memorable Perl project was:







    Results (70 votes). Check out past polls.

    Notices?