Beefy Boxes and Bandwidth Generously Provided by pair Networks
Don't ask to ask, just ask
 
PerlMonks  

DBI conditional insert (and things of those nature)

by data (Monk)
on Jan 25, 2002 at 23:32 UTC ( #141605=perlquestion: print w/replies, xml ) Need Help??
data has asked for the wisdom of the Perl Monks concerning the following question:

Hi all, i 've been looking for better way to do this so here it is...

BACKGROUND
I have this program here that inserts a new employee to my Oracle table. As you can see below i am filling my variables with parameters passed from a different program and using a "filtering" sub that i found on line to take out the (')s.
And all of this is forking fine but...
PROBLEM
Here's whats wrong:
There are two concerns that i have, but you may find more that need attention.:
QUESTION_ONE
Before i insert any record i need to make sure that an employee with that particular "employee_number" does not exist. And if it does exist, print a message on the browser that it exists. If not go ahead and insert and print confirmation.

what would be the best way? should i use SQL like selec count(*) or use the DBI $sth->rows. A good conditional insert example would definately help.

QUESTION_TWO
Look at the sub called "filter", this is something that i saw a guy use on-line. But, DBI has a thing called $sql = $dbh->quote($string); that can take care of unwanted charachters in your program (e.g, ", ' ) but i saw this used for the SQL rather than to take care of variables. By the way, if i end up using the filter subroutine, it need to take care of "(double-quotes) also. Is there a way i can use DBI-quote() to handel problem characters or should i just modify the filter subroutine to check for (") also.

Here is what i have so far

use DBI; $DSN = "dbi:Oracle:host=localhost;sid=essinv;port=1521"; $user = "username"; $pw = "password"; $dbh = DBI->connect($DSN,$user,$pw, { RaiseError => 1, AutoCommit => +1}) || die "Cannot connect: $DBI::errstr\n" unless $dbh; # get params & set variables my $employee_number = &filter(param('employee_number')) +; my $last_name = &filter(param('last_name')); my $first_name = &filter(param('first_name')); print header (); eval{ $SQL = "INSERT INTO EMPLOYEE ( EMPLOYEE_NUMBER, FIRST_NAME, LAST_NAME, INFORMATION_DATE +) VALUES ('$employee_number', '$last_name', '$first_name', + SYSDATE)"; $sth = $dbh->prepare($SQL); }; # End of eval # Check for errors. if($@){ $dbh->disconnect; print "Content-type: text/html\n\n"; print "An ERROR occurred! $@\n<P>"; exit; } else { $sth->execute; } # End of if..else ## Filter - Gets rid of characters that screw up the program. sub filter{ $_[0]=~s/\'/\\\'/g; return $_[0]; } # End of filter subroutine # Disconnect from the database $sth->finish; $dbh->disconnect;

Thanks ...

Replies are listed 'Best First'.
Re: DBI conditional insert (and things of those nature)
by Masem (Monsignor) on Jan 25, 2002 at 23:47 UTC
    1) Most databases support unique id keys for tables. If you set up the employee database that the ID must be unique, and then try to insert a conflicting record, you'll get an error from DBI. Otherwise, it's probably just as easy to use either method; since rows() is a DBI level and not database level, it'll be portable anyway.

    2) Instead of worrying about quotes, you should use placeholders in the DBI statement, such as:

    $SQL = "INSERT INTO EMPLOYEE ( EMPLOYEE_NUMBER, FIRST_NAME, LAST_NAME, INFORMATION_DATE +) VALUES (?, ?, ?, SYSDATE)" +; $sth = $dbh->prepare($SQL); $sth->execute( $employee_number, $first_name, $last_name );
    When you use placeholders, all variables are quoted appropriately to escape \' and \" constructs as well as other characters that might cuase the DB trouble. This is better than having to roll out your own.

    Finally, not asked, but you're checking for errors in a very odd way. DBI statements don't die, so using eval won't catch errors. Instead, you should check the error status via the $DBI::errstr variable, and do this after every "prepare" and "execute" statement, such as

    $SQL = "INSERT INTO EMPLOYEE ( EMPLOYEE_NUMBER, FIRST_NAME, LAST_NAME, INFORMATION_DATE +) VALUES (?, ?, ?, SYSDATE)" +; $sth = $dbh->prepare($SQL) or die $DBI::errstr; $sth->execute( $employee_number, $first_name, $last_name ) or die $D +BI::errstr;
    Or, in your case, since you want to let the user know of a problem to the broswer, that execute can be written as:
    if ( !$sth->execute( $employee_number, $first_name, $last_name ) ) { print "Could not insert into database: ", $DBI::errstr, "\n"; return; }
    (or some control similar to that.)

    -----------------------------------------------------
    Dr. Michael K. Neylon - mneylon-pm@masemware.com || "You've left the lens cap of your mind on again, Pinky" - The Brain
    "I can see my house from here!"
    It's not what you know, but knowing how to find it if you don't know that's important

      ++ on the placeholder issue (it's the only way to fly), but since the original code had RaiseError => 1 in the connect(), every DBI call that fails will issue a die. Extremely handy.

      Chris
      M-x auto-bs-mode

        True, though I'm not a big fan a RaiseError in production code (as it sorta hides what you are trying to do). But the original code had a bare execute() outside of an eval block, and this is the key step that would be need an error check if the unique ID route was taken.

        -----------------------------------------------------
        Dr. Michael K. Neylon - mneylon-pm@masemware.com || "You've left the lens cap of your mind on again, Pinky" - The Brain
        "I can see my house from here!"
        It's not what you know, but knowing how to find it if you don't know that's important

Re: DBI conditional insert (and things of those nature)
by tradez (Pilgrim) on Jan 26, 2002 at 00:00 UTC
    Possible answer for question 1: Simply do some
    my $sth = $dbh->prepare("select employee_number from employees where +employee_number = '$employee_number' for update"); $sth->execute; my $userID = ($sth->fetchrow)[0]; if ($userID) { print "This employee is already in there \n"; }
    Question 2: DBI-quote() is probably the best way Cool?
    Tradez
    "Never underestimate the power of stupidity" - Bullet Tooth Tony, Snatch (2001)

      That won't work because you're using single quotes in your prepare(), meaning you're looking for the literal string "$employee_number".Errors like this, which won't raise errors because you're executing valid SQL, can be exceedingly difficult to debug, and are avoided totally with placeholders.

      As others have said, placeholders are the way to go, everywhere you can possibly use them. They automatically escape anything sketchy, also.

      -Any sufficiently advanced technology is
      indistinguishable from doubletalk.

        Consider: my $str = "abcde '$myvar' fghi";
        $myvar will interpolate because the single quotes are just characters in the double-quoted string.

        All of which is beside the point since placeholders are a more robust approach.

        Those aren't Perl single-quotes; since their wrapped inside double-quotes, they're literal single-quotes. Therefore $employee_number will interpolate.

        However, if the employee number were actually stored in the database as a numeric type, there could be a problem with sending it as a SQL string.

        Nevertheless, as you (and everyone else) has said, placeholders are a better solution.

        Impossible Robot
Re: DBI conditional insert (and things of those nature)
by screamingeagle (Curate) on Jan 26, 2002 at 00:01 UTC
    as for your first question, There is a third method, besides using count(*) and sth->rows, and that is, write a PL/SQL function (return type varchar2) in Oracle,by passing it the primary key of the row to check for.if the row is not present, insert the row, or else return back the appropriate message like "row already exists". The advantage of this is that the code will be precompiled and on the database tier, will run faster, and can be called from more than one perl script, thus improving code reuse)...

    as for your second problem, i've found that dbh->quote does work nicely to remove all the unwanted characters from the SQL i want to execute (thanks to blakem who pointed this out to me); instead of calling the filter sub for each variable, just form the SQL first and then write :
    $dbh->quote($sql)
Re: DBI conditional insert (and things of those nature)
by CMonster (Scribe) on Jan 26, 2002 at 01:14 UTC

    Answer one:
    I'd use COUNT, mostly because it's a fast query that would give a consistent Perl-friendly 1 or 0 in a single row. Code could look something like this:

    my $check_q = "SELECT COUNT(EMPLOYEE_NUMBER) FROM EMPLOYEE WHERE EMPLO +YEE_NUMBER = ?"; my ($employee_already_present) = $dbh->selectrow_array($check_q, undef +, $employee_number); if ($employee_already_present) { # raise an HTML error } else { # continue with the insert statement }

    Answer two:
    The filter you're using may cause more problems than it solves. Since your eval is blocked instead of quoted, that extra slash will make its way into your data. You may have wanted to turn ' into '' instead (the SQL escape for '), in which case you're better off using $dbh->quote() or bind values (as in answer one above).

Log In?
Username:
Password:

What's my password?
Create A New User
Node Status?
node history
Node Type: perlquestion [id://141605]
Approved by root
help
Chatterbox?
and the web crawler heard nothing...

How do I use this? | Other CB clients
Other Users?
Others browsing the Monastery: (2)
As of 2018-09-22 01:02 GMT
Sections?
Information?
Find Nodes?
Leftovers?
    Voting Booth?
    Eventually, "covfefe" will come to mean:













    Results (190 votes). Check out past polls.

    Notices?
    • (Sep 10, 2018 at 22:53 UTC) Welcome new users!