Re: How to Speed up MySQL w/ Perl
by Abigail-II (Bishop) on May 26, 2004 at 09:12 UTC
|
Well, what you really want is something like this (assuming you have transactions turned on (which you really, really want), and RaiseError as well):
eval {
my $sth = $dbh -> prepare (<<' --');
update new_table
set newData = ?
where newID = ?
--
while (my ($id, $data) = each %Data) {
$sth -> execute ($data, $id)
}
};
if ($@) {
$dbh -> rollback;
die $@;
}
else {
$dbh -> commit;
}
Note that the data inserted doesn't get quotes tacked on - that's why you are using placeholders, quoting is being taken care of.
Abigail | [reply] [d/l] |
|
|
assuming you have transactions turned on (which you really, really want), and RaiseError as well)
I'm going to take issue with the transactions part of this statement. Transactions can be necessary in many cases. However, one of the benefits of MySQL over, say, Oracle is that you can choose whether or not you want transactions or not. In a majority of cases, you don't actually need transactions because your transactions are all one statement long.
The benefit of ACID-compliant transactions is the ability to rollback multi-statement changes. If your one-statement transaction fails, nothing has actually occurred to change the state of the tables involved.
By using a table type that doesn't have transactions (such as the default MyISAM), you can do many activities (like bulk inserts) 5-10x faster. If you don't need transactions, that's a huge benefit.
------
We are the carpenters and bricklayers of the Information Age.
Then there are Damian modules.... *sigh* ... that's not about being less-lazy -- that's about being on some really good drugs -- you know, there is no spoon. - flyingmoose
I shouldn't have to say this, but any code, unless otherwise stated, is untested
| [reply] |
|
|
If your one-statement transaction fails, nothing has actually occurred to change the state of the tables involved.
It would only be a one-statement transaction if %Data contains less than two elements. It's unlikely that that is the common case.
Transactions are a bit like "use strict" (except they prevent you from real harm). While there are cases you don't need "use strict", it's a good idea to get into the habit of using them, and only in special cases you don't use them.
By using a table type that doesn't have transactions
... you have committed yourself to never be able to use transaction on modifications of that table. Why bother with a database in such a case? Might as well use a bunch of DBM files.
If you don't need transactions
Famous last words, and belongs in the series "we don't need backups", "we don't need redundancy", "we don't need to look around when crossing the street". And indeed, most of the time, you don't need them. You just never know when you do.
Abigail
| [reply] |
|
|
|
|
|
|
if ($@) {
$dbh -> rollback;
die $@;
}
else {
$dbh -> commit;
}
# Can we leave out the 'else' and just say:
if ($@) {
$dbh -> rollback;
die $@;
}
$dbh -> commit;
Is there any difference? | [reply] [d/l] |
|
|
Sure, you can leave off the else, but that makes your code less flexible. Suppose you want to replace the die with a warn, then you shouldn't forget introduce the else. Again, if there's just a commit, not much of a problem, if there are a whole bunch of statements, you have to figure out which ones belong logically in the else, and which ones should be run regardless whether the eval block failed. If you start off the else to begin with - or rather, if you use that as a habit, you won't have such problems. Having the else block is more of an engineering issue than a semantic one.
Abigail
| [reply] |
|
|
Re: Re: Re: Re: How to Speed up MySQL w/ Perl
by Jasper (Chaplain) on May 26, 2004 at 12:05 UTC
|
Also, check the docs to learn the better way of quoting data that's getting inserted into the database. There's a DBI method that does it for you
Well, Abigail already told you what to do here, but I thought some of you might find this funny. I just started a new job, and the first task I imposed upon myself was removing all the instances of the wonderful subroutine sql_quote (AKA quote_for_db, db_quote). Actual code follows:
sub sql_quote {
my ($entry) = @_;
$entry =~ s/'/''/g;
return "'" . $entry . "'";
}
All indented with tabs, too, and I'm not even going to mention the formatting of the SQL queries.
A useful (IMO) thing for placeholders, not in the DBI docs (at least I don't think it is), is when using foo LIKE ?. Then you have to put your % or ? in the parameter passed in the execute:
$st->execute("%$bar");
or whatever. | [reply] [d/l] [select] |
Re: Re: Re: Re: How to Speed up MySQL w/ Perl
by rsiedl (Friar) on May 26, 2004 at 08:52 UTC
|
Thanks dave.
I follow it now.
Mysql look out, here i come :)
Cheers,
Reagen | [reply] |
Re: Re: Re: Re: How to Speed up MySQL w/ Perl
by rsiedl (Friar) on May 26, 2004 at 09:58 UTC
|
Hey Dave,
I think I understand placeholders now. Is it also possible to do this:
my $insert = $dbh->prepare("insert into table values (?,?,?)");
while (something) {
$insert->execute($var1,$var2,$var3);
} # end-while
Cheers,
Reagen | [reply] [d/l] |
|
|
Is it also possible to do this
Instead of just saying "yes" or "no", I give you a counter question: what happened when you tried?
Abigail
| [reply] |
|
|
Touche :)
Thankyou. I sometimes need a slap on the wrist to stop myself becoming lazy :~)
Cheers,
Reagen
| [reply] |
|
|
Better to get in the habit of specifying your column values:
my $insert = $dbh->prepare("insert into table
(column1, column2, column3) values (?,?,?)");
OT, but the only time I don't do this is outside of Perl where the language lets me declare record variables like a table:define some_record like some_table.*
insert into some_table some_record.*
And even this breaks when columns get out of order between the time you compile the program and run it, so column order becomes one more thing to maintain, and it's better to not have to maintain one more thing. :) | [reply] [d/l] [select] |