Programming with SQL Relay using the Perl DBI API
- Establishing a Session
- Executing Queries
- Commits and Rollbacks
- Temporary Tables
- Catching Errors
- Bind Variables
- Re-Binding and Re-Executing
- Accessing Fields in the Result Set
- Dealing With Large Result Sets
- Statements
- Getting Column Information
- Stored Procedures
- Getting the Last Insert ID
- Driver-Specific Attributes
Establishing a Session
To use SQL Relay, you have to identify the connection that you intend to use.
#!/usr/bin/env perl use DBI; my $dbh=DBI->connect("DBI:SQLRelay:host=sqlrserver;port=9000;socket=/tmp/example.socket;tries=0;retrytime=1;debug=0","exampleuser","examplepassword"); ... execute some queries ... $dbh->disconnect;
The following connect string variables control attributes of the connection:
- host - The SQL Relay server to connect to.
- port - The port that the SQL Relay server is listening on. Either port or socket must be specified. If both are specified, socket will be preferred to port.
- socket - The socket that the SQL Relay server is listening on. Either port or socket must be specified. If both are specified, socket will be preferred to port.
- tries - If a connection fails, it will be retried this many times.
- retrytime - If a connection fails, it will be retried on this interval (in seconds).
- db - The database to switch to when logging into SQL Relay. May be left empty or omitted to accept the default database that SQL Relay is already connected to.
- debug - If this is set to 1 or to a file name then debug is enabled. If set to a file name then debug will be written to the file. If set to 1 then debug will be written to standard output. Defaults to 0.
- lazyconnect - By default, the SQL Relay client does "lazy connects". I.e. the connection to the SQL Relay server isn't established until the first query or other operation is run. This optimizes availability of the connection pool but is inconstent with most other database API's. Setting this parameter to 0 causes the connection to the SQL Relay server to be established immediately and the constructor to fail, returning undef, if the connection cannot be established. Defaults to 1.
In addition, the following connect string variables can be used to establish Kerberos or Active Directory encryption and authentication with the server:
See the SQL Relay Configuration Guide for more information about Kerberos and Active Directory configurations. In particular, user and password are not typically used when using Kerberos/AD.
- krb - Set to yes to enable Kerberos/AD encryption/authentication or no to disable it.
- krbservice - Specifies the Kerberos service name of the SQL Relay server. If omitted or left empty then the service name "sqlrelay" will be used. "sqlrelay" is the default service name of the SQL Relay server. Note that on Windows platforms the service name must be fully qualified, including the host and realm name. For example: "sqlrelay/sqlrserver.firstworks.com@AD.FIRSTWORKS.COM".
- krbmech - Specifies the Kerberos mechanism to use. On Linux/Unix platforms, this should be a string representation of the mechnaism's OID, such as: { 1 2 840 113554 1 2 2 }. On Windows platforms, this should be a string like: Kerberos. If omitted or left empty then the default mechanism will be used. Only set this if you know that you have a good reason to.
- krbflags - Specifies what Kerberos flags to use. Multiple flags may be specified, separated by commas. If left empty or NULL then a defalt set of flags will be used. Only set this if you know that you have a good reason to. Valid flags include: GSS_C_MUTUAL_FLAG, GSS_C_REPLAY_FLAG, GSS_C_SEQUENCE_FLAG, GSS_C_CONF_FLAG, and GSS_C_INTEG_FLAG. For a full list of flags, consult the GSSAPI documentation, though note that only the previously listed flags are supported on Windows.
The following connect string variables can be used to establish TLS/SSL encryption and authentication with the server:
See the SQL Relay Configuration Guide for more information about TLS/SSL configurations.
- tls - Set to yes to enable TLS/SSL encryption/authentication or no to disable it.
- tlsversion - Specifies the TLS/SSL protocol version that the client will attempt to use. Valid values include SSL2, SSL3, TLS1, TLS1.1, TLS1.2 or any more recent version of TLS, as supported by and enabled in the underlying TLS/SSL library. If omittted or left empty then the highest supported version will be negotiated.
- tlscert - Specifies the file name of the certificate chain file to send to the SQL Relay server. This is only necessary if the SQL Relay server is configured to authenticate and authorize clients by certificate.
- tlspassword - If tlscert contains a password-protected private key, then tlspassword may be supplied to access it. If the private key is not password-protected, then this argument is ignored, and may be omitted or left empty.
- tlsciphers - Specifies a list of ciphers to allow. Ciphers may be separated by spaces, commas, or colons. If omitted or left empty then a default set is used. For a list of valid ciphers on Linux/Unix platforms, see: man ciphers. For a list of valid ciphers on Windows platforms, see this page. On Windows platforms, the ciphers (alg_id's) should omit CALG_ and may be given with underscores or dashes. For example: 3DES_112. Only set this if you know that you have a good reason to.
- tlsvalidate - Indicates whether to validate the SQL Relay server's certificate, and may be set to one of the following: no - Don't validate the server's certificate. ca - Validate that the server's certificate was signed by a trusted certificate authority. ca+host - Perform "ca" validation and also validate that one of the subject altenate names (or the common name if no SANs are present) in the certificate matches the host parameter. (Falls back to "ca" validation when a unix socket is used.) ca+domain - Perform "ca" validation and also validate that the domain name of one of the subject alternate names (or the common name if no SANs are present) in the certificate matches the domain name of the host parameter. (Falls back to "ca" validation when a unix socket is used.)
- tlsca - Specifies the location of a certificate authority file to use, in addition to the system's root certificates, when validating the SQL Relay server's certificate. This is useful if the SQL Relay server's certificate is self-signed. On Windows, "ca" must be a file name. On non-Windows systems, "ca" can be either a file or directory name. If it is a directory name, then all certificate authority files found in that directory will be used. If it a file name, then only that file will be used.
Note that the supported tlscert and tlsca file formats may vary between platforms. A variety of file formats are generally supported on Linux/Unix platfoms (.pem, .pfx, etc.) but only the .pfx format is currently supported on Windows.
Database handle attributes may be specified in the SQLRelay component of the connect string to control connection and statement behavior. For example:
my $dbh=DBI->connect("DBI:SQLRelay(AutoCommit=>0,PrintError=>0):host=sqlrserver;port=9000;socket=/tmp/example.socket;tries=0;retrytime=1;debug=0","exampleuser","examplepassword");
In addition to the standard database handle attributes (such as AutoCommit, PrintError, etc.), these additional connect string variables control some default statement attributes:
- DBD::SQLRelay::ResultSetBufferSize - Sets the number of rows to buffer at a time. See Dealing With Large Result Sets below. If set to 0 (the default) then the entire result set is buffered.
- DBD::SQLRelay::ColumnNameCase - Indicates the case to convert column names to. May be set to "mixed", "upper", or "lower". Defaults to "mixed".
- DBD::SQLRelay::DontGetColumnInfo - If this is set to 1 then column info is not fetched with the result set. If set to 0 then column info is fetched. Defaults to 0.
- DBD::SQLRelay::GetNullsaAsEmptyStrings - If this is set to 1 then NULL values are returned as empty strings. If set to 0 then NULL values are returned as nulls. Defaults to 0.
Setting one of the statement attribute connect string variables has the same effect as if the corresponding statement handle attribute were set immediately after creating each statement. See Driver-Specific Attributes below.
The other two parameters following the connect string are.
- user - The username to use when logging into SQL Relay.
- password - The password to use when logging into SQL Relay.
After calling the constructor, a session is established when the first query or other operation is run, unless lazyconnect=0 is used, in which case a session is established immediately.
For the duration of the session, the client occupies one of the database connections, so care should be taken to minimize the length of a session.
Executing Queries
Call prepare() and execute() to run a query.
#!/usr/bin/env perl use DBI; my $dbh=DBI->connect("DBI:SQLRelay:host=sqlrserver;port=9000;socket=/tmp/example.socket;tries=0;retrytime=1;debug=0","exampleuser","examplepassword"); my $sth=$dbh->prepare("select * from user_tables"); $sth->execute(); ... process the result set ... $dbh->disconnect;
Commits and Rollbacks
If you need to execute a commit or rollback, you should use the commit() and rollback() methods rather than sending a "commit" or "rollback" query. There are two reasons for this. First, it's much more efficient to call the methods. Second, if you're writing code that can run on transactional or non-transactional databases, some non-transactional databases will throw errors if they receive a "commit" or "rollback" query, but by calling the commit() and rollback() methods you instruct the database connection daemon to call the commit and rollback API methods for that database rather than issuing them as queries. If the API's have no commit or rollback methods, the calls do nothing and the database throws no error.
You can also turn Autocommit on or off by setting the AutoCommit attribute of the database handle.
The following command turns Autocommit on.
$dbh->{AutoCommit} = 1;
The following command turns Autocommit off.
$dbh->{AutoCommit} = 0;
When Autocommit is on, the database performs a commit after each successful DML or DDL query. When Autocommit is off, the database commits when the client instructs it to, or (by default) when a client disconnects. For databases that don't support Autocommit, setting the AutoCommit attribute has no effect.
Temporary Tables
Some databases support temporary tables. That is, tables which are automatically dropped or truncated when an application closes its connection to the database or when a transaction is committed or rolled back.
For databases which drop or truncate tables when a transaction is committed or rolled back, temporary tables work naturally.
However, for databases which drop or truncate tables when an application closes its connection to the database, there is an issue. Since SQL Relay maintains persistent database connections, when an application disconnects from SQL Relay, the connection between SQL Relay and the database remains, so the database does not know to drop or truncate the table. To remedy this situation, SQL Relay parses each query to see if it created a temporary table, keeps a list of temporary tables and drops (or truncates them) when the application disconnects from SQL Relay. Since each database has slightly different syntax for creating a temporary table, SQL Relay parses each query according to the rules for that database.
In effect, temporary tables should work when an application connects to SQL Relay in the same manner that they would work if the application connected directly to the database.
Catching Errors
If your calls to connect(), prepare() or execute() fail, you can catch the error in DBI->errstr.
#!/usr/bin/env perl use DBI; my $dbh=DBI->connect("DBI:SQLRelay:host=sqlrserver;port=9000;socket=/tmp/example.socket;tries=0;retrytime=1;debug=0","exampleuser","examplepassword") or die DBI->errstr; my $sth=$dbh->prepare("select * from user_tables") or die DBI->errstr; $sth->execute() or die DBI->errstr; ... process the result set ... $dbh->disconnect;
Bind Variables
Programs rarely execute fixed queries. More often than not, some part of the query is dynamically generated. The Perl DBI API provides means for using bind variables in those queries.
For a detailed discussion of binds, see this document.
Here is an example using the bind_param() function. The first parameter of the bind_param() function corresponds to the name or position of the bind variable.
#!/usr/bin/env perl use DBI; my $dbh=DBI->connect("DBI:SQLRelay:host=sqlrserver;port=9000;socket=/tmp/example.socket;tries=0;retrytime=1;debug=0","exampleuser","examplepassword"); my $sth=$dbh->prepare("select * from my_table where col1=:1 and col2=:2 and col3=:3"); $sth->bind_param(1,"hello"); $sth->bind_param(2,1); $sth->bind_param(3,5.5); $sth->execute(); ... process the result set ... $dbh->disconnect;
The precision and scale parameters can be used to specify a precision and scale for floating point numbers.
#!/usr/bin/env perl use DBI; my $dbh=DBI->connect("DBI:SQLRelay:host=sqlrserver;port=9000;socket=/tmp/example.socket","exampleuser","examplepassword"); my $sth=$dbh->prepare("insert into mytable values (:floatval)"); $sth->bind_param(":floatval,5.5,{precision=>10,scale=>3}); $sth->execute(); ... process the result set ... $dbh->disconnect;
- You can also bind CLOB's and BLOB's using the DBD
- SQLRelay::SQL_CLOB and DBD::SQLRelay::SQL_BLOB extensions. When binding a BLOB, you need to pass a hash containing type and length values.
#!/usr/bin/env perl use DBI; my $dbh=DBI->connect("DBI:SQLRelay:host=sqlrserver;port=9000;socket=/tmp/example.socket","exampleuser","examplepassword"); my $sth=$dbh->prepare("insert into mytable values (:clobval,:blobval)"); $sth->bind_param(":clobval","example clob",DBD::SQLRelay::SQL_CLOB); $sth->bind_param(":blobval","example blob",{type=>DBD::SQLRelay::SQL_BLOB,length=>9}); $sth->execute(); ... process the result set ... $dbh->disconnect;
bind_param() is used for input binds. bind_param_inout() is used for output binds. Here is an example using the bind_param_inout() function to retrieve a value from a query. The first parameter of a bind_param_inout() call is the name or position of the bind variable, the second parameter is the local variable to return the result in and the third variable is the size of the buffer to reserve for the value.
#!/usr/bin/env perl use DBI; my $dbh=DBI->connect("DBI:SQLRelay:host=sqlrserver;port=9000;socket=/tmp/example.socket","exampleuser","examplepassword"); my $sth=$dbh->prepare("begin; :1='hello'; :2=1; :3=5.5; end;"); my $hello; my $integer; my $float; $sth->bind_param_inout(1,\$hello,10); $sth->bind_param_inout(2,\$integer,10); $sth->bind_param_inout(3,\$float,10); $sth->execute(); print("$hello $integer $float\n"); $dbh->disconnect;
Here is an example using the execute() function directly. The additional parameters correspond to bind variable positions. Note that the first parameter must be "undef".
#!/usr/bin/env perl use DBI; my $dbh=DBI->connect("DBI:SQLRelay:host=sqlrserver;port=9000;socket=/tmp/example.socket;tries=0;retrytime=1;debug=0","exampleuser","examplepassword"); my $sth=$dbh->prepare("select * from my_table where col1=:0 and col2=:1 and col3=:2"); $sth->execute(undef,"hello",1,5.5); ... process the result set ... $dbh->disconnect;
Re-Binding and Re-Execution
A feature of the prepare/bind/execute paradigm is the ability to prepare, bind and execute a query once, then re-bind and re-execute the query over and over without re-preparing it. If your back-end database natively supports this paradigm, you can reap a substantial performance improvement.
#!/usr/bin/env perl use DBI; my $dbh=DBI->connect("DBI:SQLRelay:host=sqlrserver;port=9000;socket=/tmp/example.socket;tries=0;retrytime=1;debug=0","exampleuser","examplepassword"); my $sth=$dbh->prepare("select * from my_table where col1=:0 and col2=:1 and col3=:2"); $sth->execute(undef,"hello",1,1.1); ... process result set ... $sth->execute(undef,"hi",2,2.2); ... process result set ... $sth->execute(undef,"goodbye",3,3.3); ... process result set ... $dbh->disconnect;
Accessing Fields in the Result Set
The fetchrow_array(), bind_columns() and fetch() functions are useful for processing result sets. fetchrow_array() returns an array of values. bind_columns() associates variables with columns which are set when fetch() is called.
Here's an example using fetchrow_array().
#!/usr/bin/env perl use DBI; my $dbh=DBI->connect("DBI:SQLRelay:host=sqlrserver;port=9000;socket=/tmp/example.socket;tries=0;retrytime=1;debug=0","exampleuser","examplepassword"); my $sth=$dbh->prepare("select * from user_tables"); $sth->execute(); while (@data=$sth->fetchrow_array()) { foreach $col (@data) { print "\"$col\","; } print "\n"; } $dbh->disconnect;
Here's an example using bind_columns() and fetch(). Note that the first bind_columns() parameter must be "undef".
#!/usr/bin/env perl use DBI; my $dbh=DBI->connect("DBI:SQLRelay:host=sqlrserver;port=9000;socket=/tmp/example.socket;tries=0;retrytime=1;debug=0","exampleuser","examplepassword"); my $sth=$dbh->prepare("select * from my_table"); $sth->execute(); $sth->bind_columns(undef,\$col1,\$col2,\$col3,\$col4); while ($sth->fetch()) { print "$col, $col2, $col3, $col4\n"; } $dbh->disconnect;
Dealing With Large Result Sets
SQL Relay normally buffers the entire result set. This can speed things up at the cost of memory. With large enough result sets, it makes sense to buffer the result set in chunks instead of all at once.
Perl DBI provides a RowCacheSize database handle attribute to control the numer of rows to buffer at a time. This attribute may be specified in the connect string or as a database handle attribute prior to the execution of a query. If left undefined or set to -1 then the entire result set will be buffered. If set to 0 then the driver will decide how many rows to buffer. If set to a specific number other than 0 or -1 then that many rows will be buffered.
- The statement handle attribute DBD
- SQLRelay::ResultSetBufferSize may also be used to set the number of rows to buffer at a time. This attribute is a little more flexible because as a statement handle attribute it can be altered after prepare but before execute, or in between executes. It can also be specified in the connect string.
When buffering the result set in chunks, calls to fetch() cause the chunk containing the requested field to be fetched. Rows in that chunk are accessible but rows before it are not.
For example, if you set the result set buffer size to 5 and execute a query that returns 20 rows, rows 0-4 are available at once, then rows 5-9, then 10-14, then 15-19. When rows 5-9 are available, fetching row 0 will return false and fetching row 11 will cause rows 10-14 to be fetched and return the requested row.
The following code sets the result set buffer size using RowCacheSize in the connect string.
my $dbh=DBI->connect("DBI:SQLRelay(RowCacheSize=>5):host=sqlrserver;port=9000;socket=/tmp/example.socket;tries=0;retrytime=1;debug=0","exampleuser","examplepassword");
The following code sets the result set buffer size using RowCacheSize to 5.
$dbh->{RowCacheSize}=5;
The following code retrieves the result set buffer size using RowCacheSize.
$rsbs=$dbh->{RowCacheSize};
The following code sets the result set buffer size using ResultSetBufferSize
in the connect string.
my $dbh=DBI->connect("DBI:SQLRelay(DBD::SQLRelay::ResultSetBufferSize=>5):host=sqlrserver;port=9000;socket=/tmp/example.socket;tries=0;retrytime=1;debug=0","exampleuser","examplepassword");
The following code sets the result set buffer size using ResultSetBufferSize to 5.
$sth->{DBD::SQLRelay::ResultSetBufferSize}=5;
The following code retrieves the result set buffer size using ResultSetBufferSize.
$rsbs=$sth->{DBD::SQLRelay::ResultSetBufferSize};
Statements
It's possible to execute new queries while processing the result set of another query. You can select rows from a table in one query, then iterate through its result set, inserting rows into another table, using only 1 database connection for both operations.
For example:
#!/usr/bin/env perl use DBI; my $dbh=DBI->connect("DBI:SQLRelay:host=sqlrserver;port=9000;socket=/tmp/example.socket;tries=0;retrytime=1;debug=0","exampleuser","examplepassword"); my $sth=$dbh->prepare("select * from my_table where col1=:0 and col2=:1 and col3=:2"); $sth->execute(undef,"hello",1,1.1); ... process result set ... $sth->execute(undef,"hi",2,2.2); ... process result set ... $sth->execute(undef,"goodbye",3,3.3); ... process result set ... $dbh->disconnect;
Getting Column Information
After executing a query, the column count is stored in the NUMBER_OF_FIELDS statement property and column names are stored in the NAME statement property. They are accessible as follows:
#!/usr/bin/env perl use DBI; my $dbh=DBI->connect("DBI:SQLRelay:host=sqlrserver;port=9000;socket=/tmp/example.socket;tries=0;retrytime=1;debug=0","exampleuser","examplepassword"); my $sth=$dbh->prepare("select * from my_table"); $sth->execute(); for ($i=1; $i<=$sth->{NUM_OF_FIELDS}; $i++) { print "Column $i: $sth->{NAME}->[$i-1]\n"; } $dbh->disconnect;
Stored Procedures
Many databases support stored procedures. Stored procedures are sets of queries and procedural code that are executed inside of the database itself. For example, a stored procedure may select rows from one table, iterate through the result set and, based on the values in each row, insert, update or delete rows in other tables. A client program could do this as well, but a stored procedure is generally more efficient because queries and result sets don't have to be sent back and forth between the client and database. Also, stored procedures are generally stored in the database in a compiled state, while queries may have to be re-parsed and re-compiled each time they are sent.
While many databases support stored procedures. The syntax for creating and executing stored procedures varies greatly between databases.
Stored procedures typically take input paramters from client programs through input bind variables and return values back to client programs either through bind variables or result sets. Stored procedures can be broken down into several categories, based on the values that they return. Some stored procedures don't return any values, some return a single value, some return multiple values and some return entire result sets.
No Values
Some stored procedures don't return any values. Below are examples, illustrating how to create, execute and drop this kind of stored procedure for each database that SQL Relay supports.
Oracle
To create the stored procedure, run a query like the following.
create procedure exampleproc(in1 in number, in2 in number, in3 in varchar2) is begin insert into mytable values (in1,in2,in3); end;
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth->$dbh->prepare("begin exampleproc(:in1,:in2,:in3); end;"); $sth->bind_param("in1",1); $sth->bind_param("in2",1.1,2,1); $sth->bind_param("in3","hello"); $sth->execute();
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
Sybase and Microsoft SQL Server
To create the stored procedure, run a query like the following.
create procedure exampleproc @in1 int, @in2 float, @in3 varchar(20) as insert into mytable values (@in1,@in2,@in3)
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth->$dbh->prepare("exec exampleproc"); $sth->bind_param("in1",1); $sth->bind_param("in2",1.1,2,1); $sth->bind_param("in3","hello"); $sth->execute();
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
Firebird
To create the stored procedure, run a query like the following.
create procedure exampleproc(in1 integer, in2 float, in3 varchar(20)) as begin insert into mytable values (in1,in2,in3); suspend; end;
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dbh->prepare("execute procedure exampleproc ?, ?, ?"); $sth->bind_param("1",1); $sth->bind_param("2",1.1,2,1); $sth->bind_param("3","hello"); $sth->execute();
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
DB2
To create the stored procedure, run a query like the following.
create procedure exampleproc(in in1 int, in in2 double, in in3 varchar(20)) language sql begin insert into mytable values (in1,in2,in3); end;
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dbh->prepare("call exampleproc(?,?,?)"); $sth->bind_param("1",1); $sth->bind_param("2",1.1,2,1); $sth->bind_param("3","hello"); $sth->execute();
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
Postgresql
To create the stored procedure, run a query like the following.
create function examplefunc(int,float,varchar(20)) returns void as ' begin insert into mytable values ($1,$2,$3); return; end;' language plpgsql
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dbh->prepare("select examplefunc($1,$2,$3)"); $sth->bind_param("1",1); $sth->bind_param("2",1.1,2,1); $sth->bind_param("3","hello"); $sth->execute();
To drop the stored procedure, run a query like the following.
drop function examplefunc(int,float,varchar(20))
MySQL/MariaDB
To create the stored procedure, run a query like the following.
create procedure exampleproc(in in1 int, in in2 float, in in3 varchar(20)) begin insert into mytable values (in1,in2,in3); end;
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dbh->prepare("select examplefunc(?,?,?)"); $sth->bind_param("1",1); $sth->bind_param("2",1.1,4,2); $sth->bind_param("3","hello"); $sth->execute();
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
Single Values
Some stored procedures return single values. Below are examples, illustrating how to create, execute and drop this kind of stored procedure for each database that SQL Relay supports.
Oracle
In Oracle, stored procedures can return values through output parameters or as return values of the procedure itself.
Here is an example where the procedure itself returns a value. Note that Oracle calls these functions.
To create the stored procedure, run a query like the following.
create function exampleproc(in1 in number, in2 in number, in3 in varchar2) returns number is begin return in1; end;
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dbh->prepare("select exampleproc(:in1,:in2,:in3) from dual"); $sth->bind_param("in1",1); $sth->bind_param("in2",1.1,2,1); $sth->bind_param("in3","hello"); $sth->execute(); my $result; $sth->bind_columns(undef,\$result); $sth->fetch();
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
Here is an example where the value is returned through an output parameter.
To create the stored procedure, run a query like the following.
create procedure exampleproc(in1 in number, in2 in number, in3 in varchar2, out1 out number) as begin out1:=in1; end;
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dbh->prepare("begin exampleproc(:in1,:in2,:in3,:out1); end;"); $sth->bind_param("in1",1); $sth->bind_param("in2",1.1,2,1); $sth->bind_param("in3","hello"); my $result; $sth->bind_param_inout("out1",\$result,20); $sth->execute();
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
Sybase and Microsoft SQL Server
In Sybase and Microsoft SQL Server, stored procedures return values through output parameters rather than as return values of the procedure itself.
To create the stored procedure, run a query like the following.
create procedure exampleproc @in1 int, @in2 float, @in3 varchar(20), @out1 int output as select @out1=convert(varchar(20),@in1)
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dth->prepare("exec exampleproc"); $sth->bind_param("in1",1); $sth->bind_param("in2",1.1,2,1); $sth->bind_param("in3","hello"); my $result; $sth->bind_param_inout("out1",\$result,20); $sth->execute();
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
Firebird
To create the stored procedure, run a query like the following.
create procedure exampleproc(in1 integer, in2 float, in3 varchar(20)) returns (out1 integer) as begin out1=in1; suspend; end;
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dth->prepare("select * from exampleproc(?,?,?)"); $sth->bind_param("1",1); $sth->bind_param("2",1.1,2,1); $sth->bind_param("3","hello"); $sth->execute(); my $result; $sth->bind_columns(undef,\$result); $sth->fetch();
Alternatively, you can run a query like the following and receive the result using an output bind variable. Note that in Firebird, input and output bind variable indices are distict from one another. The index of the output bind variable is 1 rather than 4, even though there were 3 input bind variables.
my $sth=$dbh->prepare("execute procedure exampleproc ?, ?, ?"); $sth->bind_param("1",1); $sth->bind_param("2",1.1,2,1); $sth->bind_param("3","hello"); my $result; $sth->bind_param_inout("1",\$result,20); $sth->execute();
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
DB2
In DB2, stored procedures return values through output parameters rather than as return values of the procedure itself.
To create the stored procedure, run a query like the following.
create procedure exampleproc(in in1 int, in in2 double, in in3 varchar(20), out out1 int) language sql begin set out1 = in1; end
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dbh->prepare("call exampleproc(?,?,?,?)"); $sth->bind_param("1",1); $sth->bind_param("2",1.1,2,1); $sth->bind_param("3","hello"); my $result; $sth->bind_param_inout("4",\$result,25); $sth->execute();
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
Postgresql
To create the stored procedure, run a query like the following.
create function examplefunc(int,float,char(20)) returns int as ' declare in1 int; in2 float; in3 char(20); begin in1:=$1; return; end; ' language plpgsql
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dbh->prepare("select * from examplefunc($1,$2,$3)"); $sth->bind_param("1",1); $sth->bind_param("2",1.1,4,2); $sth->bind_param("3","hello"); $sth->execute(); my $result; $sth->bind_columns(undef,\$result); $sth->fetch();
To drop the stored procedure, run a query like the following.
drop function examplefunc(int,float,char(20))
MySQL/MariaDB
A single value can be returned from a MySQL/MariaDB function.
To create the function, run a query like the following.
create function examplefunc(in in1 int, in in2 float, in in3 varchar(20)) returns int return in1;
To execute the function from an SQL Relay program, use code like the following.
my $sth=$dbh->prepare("select examplefunc(?,?,?)"); $sth->bind_param("1",1); $sth->bind_param("2",1.1,4,2); $sth->bind_param("3","hello"); $sth->execute(); my $out1; $sth->bind_columns(undef,\$out1); $sth->fetch();
To drop the function, run a query like the following.
drop procedure exampleproc
A single value can be returned in the result set of a MySQL/MariaDB procedure.
To create the procedure, run a query like the following.
create procedure exampleproc() begin select 1; end;
To execeute the procedure from an SQL Relay program, use code like the following.
my $sth=$dbh->prepare("select exampleproc()"); $sth->execute(); $sth->bind_columns(undef,\$out1); $sth->fetch();
To drop the procedure, run a query like the following.
drop procedure exampleproc
A single value can be returned using the output variable of a MySQL/MariaDB procedure.
To create the procedure, run a query like the following.
create procedure exampleproc(out out1 int) begin select 1 into out1; end;
To execeute the procedure from an SQL Relay program, use code like the following.
my $sth=$dbh->prepare("select \@out1=0"); $sth->execute(); my $sth=$dbh->prepare("call exampleproc(\@out1)"); $sth->execute(); my $sth=$dbh->prepare("select \@out1"); $sth->execute(); $sth->bind_columns(undef,\$out1); $sth->fetch();
To drop the procedure, run a query like the following.
drop procedure exampleproc
Multiple Values
Some stored procedures return multiple values. Below are examples, illustrating how to create, execute and drop this kind of stored procedure for each database that SQL Relay supports.
Oracle
In Oracle, stored procedures can return values through output parameters or as return values of the procedure itself. If a procedure needs to return multiple values, it can return one of them as the return value of the procedure itself, but the rest must be returned through output parameters.
To create the stored procedure, run a query like the following.
create procedure exampleproc(in1 in number, in2 in number, in3 in varchar2, out1 out number, out2 out number, out3 out varchar2) is begin out1:=in1; out2:=in2; out3:=in3; end;
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dbh->prepare("begin exampleproc(:in1,:in2,:in3,:out1,:out2,:out3); end;"); $sth->bind_param("in1",1); $sth->bind_param("in2",1.1,2,1); $sth->bind_param("in3","hello"); my $out1; my $out2; my $out3; $sth->bind_input_param("out1",\$out1,20); $sth->bind_input_param("out2",\$out2,20); $sth->bind_input_param("out3",\$out3,20);
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
Sybase and Microsoft SQL Server
To create the stored procedure, run a query like the following.
create procedure exampleproc @in1 int, @in2 float, @in3 varchar(20), @out1 int output, @out2 int output, @out3 int output as select @out1=convert(varchar(20),@in1), @out2=convert(varchar(20),@in2), @out2=convert(varchar(20),@in2)
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dth->prepare("exec exampleproc"); $sth->bind_param("in1",1); $sth->bind_param("in2",1.1,2,1); $sth->bind_param("in3","hello"); my $out1; my $out2; my $out3; $sth->bind_param_inout("out1",\$out1,20); $sth->bind_param_inout("out2",\$out2,20); $sth->bind_param_inout("out3",\$out3,20); $sth->execute();
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
Firebird
To create the stored procedure, run a query like the following.
create procedure exampleproc(in1 integer, in2 float, in3 varchar(20)) returns (out1 integer, out2 float, out3 varchar(20)) as begin out1=in1; out2=in2; out3=in3; suspend; end;
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dth->prepare("select * from exampleproc(?,?,?)"); $sth->bind_param("1",1); $sth->bind_param("2",1.1,2,1); $sth->bind_param("3","hello"); $sth->execute(); my $out1; my $out2; my $out3; $sth->bind_columns(undef,\$out1,\$out1,\$out3); $sth->fetch();
Alternatively, you can run a query like the following and receive the result using a output bind variables. Note that in Firebird, input and output bind variable indices are distict from one another. The index of the first output bind variable is 1 rather than 4, even though there were 3 input bind variables.
my $sth=$dbh->prepare("execute procedure exampleproc ?, ?, ?"); $sth->bind_param("1",1); $sth->bind_param("2",1.1,2,1); $sth->bind_param("3","hello"); my $out1; my $out2; my $out3; $sth->bind_param_inout("1",\$out1,20); $sth->bind_param_inout("2",\$out2,20); $sth->bind_param_inout("3",\$out3,20); $sth->execute();
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
DB2
To create the stored procedure, run a query like the following.
create procedure exampleproc(in in1 int, in in2 double, in in3 varchar(20), out out1 int, out out2 double, out out3 varchar(20)) language sql begin set out1 = in1; set out2 = in2; set out3 = in3; end
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dbh->prepare("call exampleproc(?,?,?,?,?,?)"); $sth->bind_param("1",1); $sth->bind_param("2",1.1,2,1); $sth->bind_param("3","hello"); my $out1; my $out2; my $out3; $sth->bind_param_inout("4",\$out1,25); $sth->bind_param_inout("5",\$out2,25); $sth->bind_param_inout("6",\$out3,25); $sth->execute();
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
Postgresql
To create the stored procedure, run a query like the following.
create function examplefunc(int,float,char(20)) returns record as ' declare output record; begin select $1,$2,$3 into output; return output; end; ' language plpgsql
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dbh->prepare("select * from examplefunc($1,$2,$3) as (col1 int, col2 float, col3 char(20))"); $sth->bind_param("1",1); $sth->bind_param("2",1.1,4,2); $sth->bind_param("3","hello"); $sth->execute(); my $out1; my $out2; my $out3; $sth->bind_columns(undef,\$out1,\$out2,\$out3); $sth->fetch();
To drop the stored procedure, run a query like the following.
drop function examplefunc(int,float,char(20))
MySQL/MariaDB
Here's how you can get multiple values from the result set of a MySQL/MariaDB procedure.
To create the stored procedure, run a query like the following.
create procedure exampleproc(in in1 int, in in2 float, in in3 varchar(20)) begin select in1, in2, in3; end;
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dbh->prepare("call exampleproc(?,?,?)"); $sth->bind_param("1",1); $sth->bind_param("2",1.1,4,2); $sth->bind_param("3","hello"); $sth->execute(); my $out1; my $out2; my $out3; $sth->bind_columns(undef,\$out1,\$out2,\$out3); $sth->fetch();
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
Here's how you can get multiple values from the output variables of a MySQL/MariaDB procedure.
To create the stored procedure, run a query like the following.
create procedure exampleproc(out out1 int, out out2 float, out out3 varchar(20)) begin select 1,1.1,'hello' into out1, out2, out3; end;
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dbh->prepare("set \@out1=0, \@out2=0.0, \@out3='')"); $sth->execute(); $sth=$dbh->prepare("call exampleproc(\@out1,\@out2,\@out3)"); $sth->execute(); $sth=$dbh->prepare("select \@out1,\@out2,\@out3"); $sth->execute(); my $out1; my $out2; my $out3; $sth->bind_columns(undef,\$out1,\$out2,\$out3); $sth->fetch();
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
Result Sets
Some stored procedures return entire result sets. Below are examples, illustrating how to create, execute and drop this kind of stored procedure for each database that SQL Relay supports.
Oracle
Stored procedures in Oracle can return open cursors as return values or output parameters. A client-side cursor can be bound to this open cursor and rows can be fetched from it. However the SQL Relay driver for Perl DBI does not currently support output bind cursors.
Sybase and Microsoft SQL Server
To create the stored procedure, run a query like the following.
create procedure exampleproc as select * from exampletable
To exceute the stored procedure from an SQL Relay program, ue code like the following.
my $sth=$dbh->prepareQuery("exec exampleproc"); $sth->execute(); my $out1; my $out2; my $out3; $sth->bind_columns(undef,\$out1,\$out2,\$out3); while ($sth->fetch()) { print "$out1, $out2, $out3\n"; }
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
Firebird
Stored procedures in Firebird can return a result set if a select query in the procedure selects values into the output parameters and then issues a suspend command, however SQL Relay doesn't currently support stored procedures that return result sets.
DB2
Stored procedures in DB2 can return a result set if the procedure is declared to return one, however SQL Relay doesn't currently support stored procedures that return result sets.
Postgresql
To create the stored procedure, run a query like the following.
create function examplefunc() returns setof record as ' declare output record; begin for output in select * from mytable loop return next output; end loop; return; end; ' language plpgsql
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dbh->prepare("select * from examplefunc() as (exampleint int, examplefloat float, examplechar char(40))"); $sth->execute(); my $col1; my $col2; my $col3; $sth->bind_columns(undef,\$col1,\$col2,\$col3); while ($sth->fetch()) { print "$col1, $col2, $col3\n"; }
To drop the stored procedure, run a query like the following.
drop function examplefunc
MySQL/MariaDB
The result sets of all select statements called within MySQL/MariaDB stored procedures (that aren't selected into variables) are returned from the procedure call. Though MySQL/MariaDB stored procedures can return multiple result sets, currently SQL Relay can only fetch the first result set.
To create the stored procedure which returns a result set, run a query like the following.
create procedure exampleproc() begin select * from mytable; end;
To execute the stored procedure from an SQL Relay program, use code like the following.
my $sth=$dbh->prepareQuery("call exampleproc(?,?,?)"); $sth->bind_param("1",1); $sth->bind_param("2",1.1,4,2); $sth->bind_param("3","hello"); $sth->execute(); my $out1; my $out2; my $out3; $sth->bind_columns(undef,\$out1,\$out2,\$out3); while ($sth->fetch()) { print "$out1, $out2, $out3\n"; }
To drop the stored procedure, run a query like the following.
drop procedure exampleproc
Getting the Last Insert ID
Databases with autoincrement or identity columns often provide functions which return the "last insert id"; the value of the autoincrement column that was generated during the insert into the database.
DBI provides the $dbh->last_insert_id() method to get this value.
When using the SQLite database, you can also get the last insert id by running the query:
select last insert rowid
Driver-Specific Attributes
Perl DBI allows drivers to define their own attributes for database handles and statements. These attributes can be set to control various parameters unique to the driver. SQL Relay implements several of these.
Database handle attributes defined by the SQL Relay driver:
- DBD::SQLRelay::Debug - set-only (1, 0 or file name), when set to 1, debug is enabled to standard output, when set to 0, debug is disabled, when set to a file name, debug is sent to that file.
Statement handle attributes defined by the SQL Relay driver:
- DBD::SQLRelay::ResultSetBufferSize - get/set, returns or sets the result set buffer size as described above.
- DBD::SQLRelay::ColumnNameCase - set-only, returns the case that column names will be converted to - "mixed", "upper", or "lower".
- DBD::SQLRelay::DontGetColumnInfo - set-only (1 or 0), sets whether or not to fetch column info with the result set, default (0) is to return column info
- PDO::SQLRelay::GetNullsAsEmptyStrings - set-only (1 or 0), sets whether to return NULL values as empty strings or nulls, default (0) is to return NULL values as nulls
Default values for the statement handle attributes can be set as database handle attributes in the connect string. Setting the corresponding connect string variable has the same effect as if the statement handle attribute were set immediately after creating the statement. See Establishing a Session above.