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

Monks,

A MySQL related PERL question from a relative newbie.

I'm trying to get the id # for a press release with a given header ($header). Each header is unique. When I run the code below, however, and check the contents of $header_id, I find it contains the following : DBI::st=HASH(0x81b862c). Not what I need.

$header_id = $dbh->prepare("SELECT id FROM press_releases WHERE header + = '$header'"); $header_id -> execute();
I checked to see if the id # was in $header_id[0] or $header_id[1], but both were empty (as far as I could tell).

Any advice on how I can get the id# out of the database as a single integer?

thanks

Replies are listed 'Best First'.
(ichimunki) Re: Retrieval of ID# as Integer from MySQL
by ichimunki (Priest) on Aug 07, 2001 at 22:33 UTC
    $header_id contains a hash reference (in this case it is a blessed reference, indicating that you have created a DBI object), not your data. This is good, DBI is doing exactly what we want it to when we call execute(). It is creating a set handler to provide us with a few different ways of accessing the results of our query-- probably the most useful access method here is line-by-line as a list.

    Your code should probably look more like:
    $sth = $dbh->prepare( $SQL ); $sth->execute(); @header_ID = $sth->fetchrow_array();

    Now $header_ID[0] will work more how you expected. For more information 'perldoc DBI' or this: Reading from a database.
(jeffa) Re: Retrieval of ID# as Integer from MySQL
by jeffa (Bishop) on Aug 07, 2001 at 22:43 UTC
    ichimunki has the answer - i just wanted to point out a couple of style issues:

    1. don't be afraid to use whitespace:

    $header_id = $dbh->prepare(" SELECT id FROM press_release WHERE header = ? ");
    Makes the SQL much much more readable - but what about the question mark? That's #2:

    2. Use bind variables instead of interpolated statements. If this statement is to be executed again and again, using bind variables will increase performance. So, how do you tell DBI what the value of the question mark is? Inside the execute function:

    $header_id->execute($header);
    Check out Programming the Perl DBI for more DBI goodness.

    jeffa

(Ovid - security and bind variables) Re: Retrieval of ID# as Integer from MySQL
by Ovid (Cardinal) on Aug 07, 2001 at 22:58 UTC

    In addition to the comments that jeffa made regarding the performance benefits of using placeholders in DBI statements (the question mark), I'd like to mention something else about them.

    Using bind variables can also plug up significant security holes. Imagine what happens if someone using the program manages to set $header to the following:

    foo';DROP TABLE press_release;SELECT * FROM press_release WHERE header +='foo

    For databases that allow multiple SQL statements separated by semi-colons, this is how the SQL gets interpreted:

    SELECT id FROM press_release WHERE header = 'foo'; DROP TABLE press_release; SELECT * FROM press_release WHERE header='foo'

    The last statement is a throwaway, but because the cracker has taken the time to balance the quotes, the database will happily attempt to execute all of the SQL statements. These may or may not succeed (depending upon permissions, foreign key constraints, etc.), but a cracker should never get this close to touching the database. Placeholders, in addition to benefitting performance, also plug this potentially huge security hole.

    You can also protect yourself with the following changes:

    $header = $dbh->quote( $header ); # note the *lack* of single quotes around $header $header_id = $dbh->prepare("SELECT id FROM press_releases WHERE header + = $header");

    This works, but there are two problems with it:

    1. You lose the performance benefits of using placeholders and bind variables.
    2. It's easy to forget to quote the variable.

    Stick with placeholders and your scripts will be much more secure.

    Cheers,
    Ovid

    Vote for paco!

    Join the Perlmonks Setiathome Group or just click on the the link and check out our stats.

Re: Retrieval of ID# as Integer from MySQL
by elbie (Curate) on Aug 07, 2001 at 22:55 UTC
    Once you execute the SQL statement using $header_id->execute you then have to fetch the results back. When you're only expecting one result, the fetchrow_array method works just fine:

    ( my $header_id_num ) = $header_id->fetchrow_array;

    For records with more fields, I'm partial to fetchrow_hashref:

    my $record = $header_id->fetchrow_hashref; my $header_id_num = $record->{ 'id' };

    As an aside, if you're not doing so already, I strongly recommend that you check the error status of your prepare and execute statements. It's saved my rear many a time.

    $header_id = $dbh->prepare( $sql_command ) || die $dbh->errstr; $header_id->execute || die $dbh->errstr;

    (Or use whatever you want in place of die...)

    Note that the fetchrow returning 0 might just mean that you're at the end of a record, so you shouldn't check for errors there. I believe there is an error flag that is raised if your fetch fails for other reasons. Check the DBI docs for more info.

    elbieelbieelbie