Programming with SQL Relay using the ADO.NET API
- Language Compatibility
- 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
- Cursors
- Getting Column Information
- Stored Procedures
- Extensions
- Getting the Last Insert ID
Language Compatibility
The SQL Relay ADO.NET Adapter is supported on Windows platforms using Visual Studio and on Unix/Linux using Mono.
The example code below is given in C# but the SQL Relay ADO.NET Adapter can be used from any language capable of using the .NET API.
Compiling an SQL Relay Client Program
When writing an SQL Relay client program using the ADO.NET API, you need to use the SQLRClient namespace.
using SQLRClient;
You'll also need to include the SQLRelay.dll assembly. This is usually found in C:\Program Files\Firstworks\bin on Windows or /usr/local/firstworks/lib on Unix/Linux.
As the ADO.NET Adapter ultimately relies on the C API, on Unix/Linux, there is also a SQLRelay.dll.config file, found in the same directory, that maps internal references to libsqlrclient.dll to the Unix/Linux equivalent shared object library. This file isn't necessary on Windows and isn't installed.
To compile a progarm using the Visual Studio IDE, you just have to configure your project to include the SQLRelay.dll assembly and compile your program.
To compile from the command line using either Visual Studio or Mono, it's easiest to copy SQLRelay.dll into the current directory and build against it locally.
When using Mono, you should also copy SQLRelay.dll.config into the current directory.
For example, to create the executable sqlrexample.exe from the source code sqlrexample.cs...
From the Visual Studio command line:
copy "C:\Program Files\Firstworks\bin\SQLRClient.dll" . csc /out:sqlrexample.exe sqlrexample.cs /reference:SQLRClient.dll
Using the Mono compiler from the Unix/Linux command line:
cp /usr/local/firstworks/lib/SQLRClient.dll . cp /usr/local/firstworks/lib/SQLRClient.dll.config . mcs -pkg:dotnet /out:sqlrexample.exe sqlrexample.cs /reference:SQLRClient.dll
(Note that an explicit reference to the dotnet package is required with Mono).
To run the program under Windows, you can just run it directly:
sqlrexample.exe
Use the mono runtime to run the program on Unix/Linux:
mono sqlrexample.exe
If you get an error about libsqlrclient.dll not being found, then you probably forgot to copy SQLRClient.dll.config into the current directory.
Establishing a Session
To use SQL Relay, you have to first open a connection.
using System; using SQLRClient; using System.Data; using System.IO; namespace SQLRExamples { class SQLRExample { public static void Main() { SQLRelayConnection sqlrcon = new SQLRelayConnection("Data Source=sqlrserver:9000;User ID=user;Password=password;Retry Time=0;Tries=1;Debug=false"); sqlrcon.Open(); } } }
The following connect string variables control attributes of the connection:
- Data Source - The SQL Relay server to connect to. This may be specified as host:port, host:port:socket or just socket. If host, port and socket are all three specified, then a connection will first be attempted to the local socket and then to the host/port.
- User ID - The username to use when logging into SQL Relay.
- Password - The password to use when logging into SQL Relay.
- Retry Time - If a connection fails, it will be retried on this interval (in seconds).
- Tries - If a connection fails, it will be retried this many times.
- Initial Catalog - The database/schema to switch to after logging in. Optional.
- Debug - If this is set to true then debug is enabled.
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 ID 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 provided in the Data Source 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 provided in the Data Source 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.
After opening the connection, a session is established when the first query is run.
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
There are three ways to execute queries.
If a query doesn't return a result set, such as DML (insert, update, delete, etc.) or DDL (create, drop, etc.) then you can use ExecuteNonQuery. If the query returns a single value you can use ExecuteScalar. If the query returns a result set then you must use ExecuteReader.
In any case, you must create an instance of SQLRelayCommand and set its CommandText.
using System; using SQLRClient; using System.Data; using System.IO; namespace SQLRExamples { class SQLRExample { public static void Main() { SQLRelayConnection sqlrcon = new SQLRelayConnection("Data Source=sqlrserver:9000;User ID=user;Password=password;Retry Time=0;Tries=1;Debug=false"); sqlrcon.Open(); // DML queries... SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "insert into exampletable values (1,'hello')"; try { sqlrcom.ExecuteNonQuery(); } catch (Exception ex) { ... handle exceptions ... } // Single values sqlrcom.CommandText = "select 1 from dual"; try { Int64 value = sqlrcom.ExecuteScalar(); ... do something with the value ... } catch (Exception ex) { ... handle exceptions ... } // Multiple rows sqlrcom.CommandText = "select * from exampletable"; try { System.Data.IDataReader datareader = sqlrcom.ExecuteReader(); ... do something with the result set ... } catch (Exception ex) { ... handle exceptions ... } } } }
Commits and Rollbacks
If you need to execute a commit or rollback, you should create an instance of the SQLRelayTransaction class and use its commit() and rollback() methods rather than sending "commit" or "rollback" queries. 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.
using System; using SQLRClient; using System.Data; using System.IO; namespace SQLRExamples { class SQLRExample { public static void Main() { SQLRelayConnection sqlrcon = new SQLRelayConnection("Data Source=sqlrserver:9000;User ID=user;Password=password;Retry Time=0;Tries=1;Debug=false"); sqlrcon.Open(); SQLRelayTransaction sqlrtran = sqlrcon.BeginTransaction(); ... run some queries that we want to keep the results of ... sqlrtran.Commit(); ... run some queries that we don't want to keep the results of ... sqlrtran.Rollback(); } } }
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 ExecuteNonQuery, ExecuteScalar or ExecuteReader fail, you can catch the error an exception.
using System; using SQLRClient; using System.Data; using System.IO; namespace SQLRExamples { class SQLRExample { public static void Main() { SQLRelayConnection sqlrcon = new SQLRelayConnection("Data Source=sqlrserver:9000;User ID=user;Password=password;Retry Time=0;Tries=1;Debug=false"); sqlrcon.Open(); SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "insert into exampletable values (1,'hello')"; try { sqlrcom.ExecuteNonQuery(); } catch (Exception ex) { Console.WriteLine(ex.Message); } } } }
Bind Variables
Programs rarely execute fixed queries. More often than not, some part of the query is dynamically generated. The ADO.NET API provides means for using bind variables (also known as parameters) in those queries.
For a detailed discussion of binds, see this document.
To use bind variables (parameters) with the ADO.NET API, you must add variable/value pairs to the parameter collection associated with each instance of SQLRelayCommand. For numeric, string or date variables, this is straightforward, you can just use the Parameters.Add() method.
using System; using SQLRClient; using System.Data; using System.IO; namespace SQLRExamples { class SQLRExample { public static void Main() { SQLRelayConnection sqlrcon = new SQLRelayConnection("Data Source=sqlrserver:9000;User ID=user;Password=password;Retry Time=0;Tries=1;Debug=false"); sqlrcon.Open(); SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "insert into exampletable values (:var1,:var2,:var3)"; sqlrcom.Parameters.Add("var1", 1); sqlrcom.Parameters.Add("var2", "hello"); sqlrcom.Parameters.Add("var2", new DateTime(2001, 1, 1, 0, 0, 0)); try { sqlrcom.ExecuteNonQuery(); } catch (Exception ex) { Console.WriteLine(ex.Message); } } } }
You can also bind CLOB's and BLOB's. It is a little more complex but not terribly.
using System; using SQLRClient; using System.Data; using System.IO; namespace SQLRExamples { class SQLRExample { public static void Main() { SQLRelayConnection sqlrcon = new SQLRelayConnection("Data Source=sqlrserver:9000;User ID=user;Password=password;Retry Time=0;Tries=1;Debug=false"); sqlrcon.Open(); SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "insert into exampletable values (:clobvar,:blobvar)"; SQLRelayParameter clobvar = new SQLRelayParameter(); clobvar.ParameterName = "clobvar"; clobvar.Value = "exampleclob"; clobvar.SQLRelayType = SQLRelayType.Clob; sqlrcom.Parameters.Add(clobvar); SQLRelayParameter blobvar = new SQLRelayParameter(); blobvar.ParameterName = "blobvar"; blobvar.Value = System.Text.Encoding.Default.GetBytes("exampleblob"); blobvar.SQLRelayType = SQLRelayType.Blob; sqlrcom.Parameters.Add(blobvar); try { sqlrcom.ExecuteNonQuery(); } catch (Exception ex) { Console.WriteLine(ex.Message); } } } }
Note that in the above code, the Parameter.SQLRelayType must be set rather than Parameter.DbType, which would generally be set. DbType is constrained to a set of values defined in the ADO.NET spec, which does not include Clob or Blob types.
Output bind variables can be used too. The Direction and DbType attributes of the parameter must be specified though and for strings, the Size of the buffer to allocate for the return value must be specified as well.
using System; using SQLRClient; using System.Data; using System.IO; namespace SQLRExamples { class SQLRExample { public static void Main() { SQLRelayConnection sqlrcon = new SQLRelayConnection("Data Source=sqlrserver:9000;User ID=user;Password=password;Retry Time=0;Tries=1;Debug=false"); sqlrcon.Open(); SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "begin :numvar:=1; :stringvar:='hello'; :floatvar:=2.5; :datevar:='03-FEB-2001'; end;"; SQLRelayParameter numvar = new SQLRelayParameter(); numvar.ParameterName = "numvar"; numvar.Direction = ParameterDirection.Output; numvar.DbType = DbType.Int64; sqlrcom.Parameters.Add(numvar); SQLRelayParameter stringvar = new SQLRelayParameter(); stringvar.ParameterName = "stringvar"; stringvar.Direction = ParameterDirection.Output; stringvar.DbType = DbType.String; stringvar.Size = 20; sqlrcom.Parameters.Add(stringvar); SQLRelayParameter floatvar = new SQLRelayParameter(); floatvar.ParameterName = "floatvar"; floatvar.Direction = ParameterDirection.Output; floatvar.DbType = DbType.Double; sqlrcom.Parameters.Add(floatvar); SQLRelayParameter datevar = new SQLRelayParameter(); datevar.ParameterName = "datevar"; datevar.Direction = ParameterDirection.Output; datevar.DbType = DbType.DateTime; sqlrcom.Parameters.Add(datevar); try { sqlrcom.ExecuteNonQuery(); } catch (Exception ex) { Console.WriteLine(ex.Message); } ... do something with numvar.Value ... ... do something with stringvar.Value ... ... do something with floatvar.Value ... ... do something with datevar.Value ... } } }
FIXME: ... clob, blob and cursor output bind ...
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.
using System; using SQLRClient; using System.Data; using System.IO; namespace SQLRExamples { class SQLRExample { public static void Main() { SQLRelayConnection sqlrcon = new SQLRelayConnection("Data Source=sqlrserver:9000;User ID=user;Password=password;Retry Time=0;Tries=1;Debug=false"); sqlrcon.Open(); // Prepare the query... SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "insert into exampletable values (:var1,:var2,:var3)"; sqlrcom.Prepare(); // Execute once... sqlrcom.Parameters.Add("var1", 1); sqlrcom.Parameters.Add("var2", "hello"); sqlrcom.Parameters.Add("var2", new DateTime(2001, 1, 1, 0, 0, 0)); try { sqlrcom.ExecuteNonQuery(); } catch (Exception ex) { Console.WriteLine(ex.Message); } sqlrcom.Parameters.Clear(); // Execute again with new values... sqlrcom.Parameters.Add("var1", 2); sqlrcom.Parameters.Add("var2", "bye"); sqlrcom.Parameters.Add("var2", new DateTime(2002, 2, 2, 0, 0, 0)); try { sqlrcom.ExecuteNonQuery(); } catch (Exception ex) { Console.WriteLine(ex.Message); } ... re-bind and re-execute again and again ... } } }
Accessing Fields in the Result Set
Once returned from an ExecuteReader call, the SQLRelayDataReader provides methods for accessing the fields of the result set.
To fetch a row, call the Read() method. This method will return false if no more rows are available.
After the row has been fetched, individual fields of that row may be accessed through a wide variety of methods. The raw data for each field can be accessed by index using GetValue(), as a numeric array returned by the GetValues() or by using the SQLRelayDataReader directly as either a numeric or associative array. The GetOrdinal() method can also be used to get the numeric index of a column name as well.
Further, the raw data for each field can be coaxed into a native type using the GetBoolean(), GetByte(), GetBytes(), GetChar(), GetChars(), GetGuid(), GetInt16(), GetInt32(), GetInt64(), GetFloat(), GetDouble(), GetString(), GetDecimal() and GetDateTime() methods.
using System; using SQLRClient; using System.Data; using System.IO; namespace SQLRExamples { class SQLRExample { public static void Main() { SQLRelayConnection sqlrcon = new SQLRelayConnection("Data Source=sqlrserver:9000;User ID=user;Password=password;Retry Time=0;Tries=1;Debug=false"); sqlrcon.Open(); SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "select col1,col2 from exampletable"; try { System.Data.IDataReader datareader = sqlrcom.ExecuteReader(); // read row... datareader.Read(); // get the raw data of the first field in a variety of ways Object o1 = datareader.GetValue(0); o1 = datareader[0]; o1 = datareader.GetValue(datareader.GetOrdinal("col1")); o1 = datareader["col1"]; Object[] os1 = datareader.GetValues(); o1 = os1[0]; // get the first field as a string String s1 = datareader.GetString(0); // get the raw data of the second field in a variety of ways Object o2 = datareader.GetValue(1); o2 = datareader[1]; o2 = datareader.GetValue(datareader.GetOrdinal("col2")); o2 = datareader["col2"]; Object[] os2 = datareader.GetValues(); o2 = os2[1]; // get the second field as a string String s2 = datareader.GetString(1); // read another row... datareader.Read(); ... do something with this row ... ... fetch more rows ... } catch (Exception ex) { Console.WriteLine(ex.Message); } } } }
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.
Use the parameter SQLRelayCommand.ResultSetBufferSize to set the number of rows to buffer at a time. Calls to SQLRelayDataReader.Read() cause the chunk containing the requested field to be fetched.
Cursors
Cursors make it possible to execute 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.
In the ADO.NET API, cursors are abstracted by the SQLRelayCommand class. Each SQLRelayCommand can be thought of as a separate cursor and in many cases, each SQLRelayCommand consumes a separate server-side cursor.
For example:
using System; using SQLRClient; using System.Data; using System.IO; namespace SQLRExamples { class SQLRExample { public static void Main() { SQLRelayConnection sqlrcon = new SQLRelayConnection("Data Source=sqlrserver:9000;User ID=user;Password=password;Retry Time=0;Tries=1;Debug=false"); sqlrcon.Open(); SQLRelayCommand sqlrcom1 = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom1.CommandText = "select * from my_first_table"; SQLRelayCommand sqlrcom2 = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom2.CommandText = "insert into my_second_table values (:col1, :col2, :col3)"; try { System.Data.IDataReader datareader = sqlrcom1.ExecuteReader(); while (datareader.Read()) { sqlrcom2.Parameters.Clear(); sqlrcom2.Parameters.Add("col1",datareader.GetString(0)); sqlrcom2.Parameters.Add("col2",datareader.GetString(1)); sqlrcom2.Parameters.Add("col3",datareader.GetString(2)); try { sqlrcom2.ExecuteNonQuery(); } catch (Exception ex) { Console.WriteLine(ex.Message); } } } catch (Exception ex) { Console.WriteLine(ex.Message); } } } }
Getting Column Information
After executing a query, the column count is stored in the FieldCount property of the SQLRelayDataReader class. Column names are accessible via the GetName() method. Column types are available from the GetDataTypeName(). The native .NET data type for the field is avialable from the GetFieldType() method. They may be used as follows:
using System; using SQLRClient; using System.Data; using System.IO; namespace SQLRExamples { class SQLRExample { public static void Main() { SQLRelayConnection sqlrcon = new SQLRelayConnection("Data Source=sqlrserver:9000;User ID=user;Password=password;Retry Time=0;Tries=1;Debug=false"); sqlrcon.Open(); SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "select * from my_first_table"; try { System.Data.IDataReader datareader = sqlrcom.ExecuteReader(); for (UInt32 index = 0; index < sqlrcom.FieldCount; index++) { String name = datareader.GetName(index); String datatype = datareader.GetDataTypename(index); String nativedatatype = datareader.GetFieldType(index).ToString(); ... do someting with the column data ... } } catch (Exception ex) { Console.WriteLine(ex.Message); } } } }
Extended column information is available from the GetSchemaTable method. Usage is best illustrated by example.
using System; using SQLRClient; using System.Data; using System.IO; namespace SQLRExamples { class SQLRExample { public static void Main() { SQLRelayConnection sqlrcon = new SQLRelayConnection("Data Source=sqlrserver:9000;User ID=user;Password=password;Retry Time=0;Tries=1;Debug=false"); sqlrcon.Open(); SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "select * from my_first_table"; try { System.Data.IDataReader datareader = sqlrcom.ExecuteReader(); DataTable schematable = datareader.GetSchemaTable(); for (UInt32 index = 0; index < sqlrcom.FieldCount; index++) { String columnname = Convert.ToString(schematable.Rows[index]["ColumnName"]); Int64 columnordinal = Convert.ToInt64(schematable.Rows[index]["ColumnOrdinal"]); Int64 columnsize = Convert.ToInt64(schematable.Rows[index]["ColumnSize"]); Int64 numericprecision = Convert.ToInt64(schematable.Rows[index]["NumericPrecision"]); Int64 numericscale = Convert.ToInt64(schematable.Rows[index]["NumericScale"]); Boolean isunique = Convert.ToBoolean(schematable.Rows[index]["IsUnique"]); Boolean iskey = Convert.ToBoolean(schematable.Rows[index]["IsKey"]); String baseservername = Convert.ToString(schematable.Rows[index]["BaseServerName"]); String basecatalogname = Convert.ToString(schematable.Rows[index]["BaseCatalogName"]); String basecolumnname = Convert.ToString(schematable.Rows[index]["BaseColumnName"]); String baseschemaname = Convert.ToString(schematable.Rows[index]["BaseSchemaName"]); String basetablename = Convert.ToString(schematable.Rows[index]["BaseTableName"]); String datatype = Convert.ToString(schematable.Rows[index]["DataType"]); Boolean allowdbnull = Convert.ToBoolean(schematable.Rows[index]["AllowDBNull"]); String providertype = Convert.ToString(schematable.Rows[index]["ProviderType"]); Boolean isaliased = Convert.ToBoolean(schematable.Rows[index]["IsAliased"]); Boolean isexpression = Convert.ToBoolean(schematable.Rows[index]["IsExpression"]); Boolean isidentity = Convert.ToBoolean(schematable.Rows[index]["IsIdentity"]); Boolean isautoincrement = Convert.ToBoolean(schematable.Rows[index]["IsAutoIncrement"]); Boolean isrowversion = Convert.ToBoolean(schematable.Rows[index]["IsRowVersion"]); Boolean ishidden = Convert.ToBoolean(schematable.Rows[index]["IsHidden"]); Boolean islong = Convert.ToBoolean(schematable.Rows[index]["IsLong"]); Boolean isreadonly = Convert.ToBoolean(schematable.Rows[index]["IsReadOnly"]); String providerspecificdatatype = Convert.ToString(schematable.Rows[index]["ProviderSpecificDataType"]); String datatypename = Convert.ToString(schematable.Rows[index]["DataTypeName"]); String xmlschemacollectiondatabase = Convert.ToString(schematable.Rows[index]["XmlSchemaCollectionDatabase"]); String xmlschemacollectionowningschema = Convert.ToString(schematable.Rows[index]["XmlSchemaCollectionOwningSchema"]); String xmlschemacollectionname = Convert.ToString(schematable.Rows[index]["XmlSchemaCollectionName"]); ... do something with all these bits of information ... } } catch (Exception ex) { Console.WriteLine(ex.Message); } } } }
SQL Relay support most of the fields that might be returned in the schema table but not all. Most databases don't support all of these fields either. In the future, support may improve.
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "begin exampleproc(:in1,:in2,:in3); end;"; sqlrcom.Parameters.Add("in1",1); sqlrcom.Parameters.Add("in2",1.1); sqlrcom.Parameters.Add("in3","hello"); sqlrcom.ExecuteNonQuery();
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "exec exampleproc"; sqlrcom.Parameters.Add("in1",1); sqlrcom.Parameters.Add("in2",1.1); sqlrcom.Parameters.Add("in3","hello"); sqlrcom.ExecuteNonQuery();
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "execute procedure exampleproc ?, ?, ?"; sqlrcom.Parameters.Add("1",1); sqlrcom.Parameters.Add("2",1.1); sqlrcom.Parameters.Add("3","hello"); sqlrcom.ExecuteNonQuery();
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "call exampleproc(?,?,?)"; sqlrcom.Parameters.Add("1",1); sqlrcom.Parameters.Add("2",1.1); sqlrcom.Parameters.Add("3","hello"); sqlrcom.ExecuteNonQuery();
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "call examplefunc($1,$2,$3)"; sqlrcom.Parameters.Add("1",1); sqlrcom.Parameters.Add("2",1.1); sqlrcom.Parameters.Add("3","hello"); sqlrcom.ExecuteNonQuery();
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "call exampleproc(?,?,?)"; sqlrcom.Parameters.Add("1",1); sqlrcom.Parameters.Add("2",1.1); sqlrcom.Parameters.Add("3","hello"); sqlrcom.ExecuteNonQuery();
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "select exampleproc(:in1,:in2,:in3) from dual"; sqlrcom.Parameters.Add("in1",1); sqlrcom.Parameters.Add("in2",1.1); sqlrcom.Parameters.Add("in3","hello"); Int64 result=sqlrcom.ExecuteScalar();
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "begin exampleproc(:in1,:in2,:in3,:out1); end"; sqlrcom.Parameters.Add("in1",1); sqlrcom.Parameters.Add("in2",1.1); sqlrcom.Parameters.Add("in3","hello"); SQLRelayParameter out1 = new SQLRelayParameter(); out1.ParameterName = "out1"; out1.Direction = ParameterDirection.Output; out1.DbType = DbType.Int64; sqlrcom.Parameters.Add(out1); sqlrcom.ExecuteNonQuery(); Int64 result = Convert.ToInt64(out1.Value);
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "exec exampleproc"; sqlrcom.Parameters.Add("in1",1); sqlrcom.Parameters.Add("in2",1.1); sqlrcom.Parameters.Add("in3","hello"); SQLRelayParameter out1 = new SQLRelayParameter(); out1.ParameterName = "out1"; out1.Direction = ParameterDirection.Output; out1.DbType = DbType.Int64; sqlrcom.Parameters.Add(out1); sqlrcom.ExecuteNonQuery(); Int64 result = Convert.ToInt64(out1.Value);
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "select * from exampleproc(?,?,?)"; sqlrcom.Parameters.Add("1",1); sqlrcom.Parameters.Add("2",1.1); sqlrcom.Parameters.Add("3","hello"); Int64 result = sqlrcom.ExecuteScalar();
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "execute procedure exampleproc ?, ?, ?"; sqlrcom.Parameters.Add("1",1); sqlrcom.Parameters.Add("2",1.1); sqlrcom.Parameters.Add("3","hello"); SQLRelayParameter out1 = new SQLRelayParameter(); out1.ParameterName = "1"; out1.Direction = ParameterDirection.Output; out1.DbType = DbType.Int64; sqlrcom.Parameters.Add(out1); sqlrcom.ExecuteNonQuery(); Int64 result = Convert.ToInt64(out1.Value);
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "call exampleproc(?,?,?,?)"; sqlrcom.Parameters.Add("1",1); sqlrcom.Parameters.Add("2",1.1); sqlrcom.Parameters.Add("3","hello"); SQLRelayParameter out4 = new SQLRelayParameter(); out4.ParameterName = "4"; out4.Direction = ParameterDirection.Output; out4.DbType = DbType.Int64; sqlrcom.Parameters.Add(out4); sqlrcom.ExecuteNonQuery(); Int64 result = Convert.ToInt64(out4.Value);
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "select * from examplefunc($1,$2,$3)"; sqlrcom.Parameters.Add("1",1); sqlrcom.Parameters.Add("2",1.1); sqlrcom.Parameters.Add("3","hello"); Int64 result = sqlrcom.ExecuteScalar();
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "select * from examplefunc(?,?,?)"; sqlrcom.Parameters.Add("1",1); sqlrcom.Parameters.Add("2",1.1); sqlrcom.Parameters.Add("3","hello"); Int64 result = sqlrcom.ExecuteScalar();
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 execute the procedure from an SQL Relay program, use code like the following.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "select exampleproc()"; Int64 result = sqlrcom.ExecuteScalar();
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 execute the procedure from an SQL Relay program, use code like the following.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "set @out1=0"; Int64 result = sqlrcom.ExecuteNonQuery(); sqlrcom.CommandText = "call exampleproc(@out1)"; Int64 result = sqlrcom.ExecuteNonQuery(); sqlrcom.CommandText = "select @out1"; Int64 result = sqlrcom.ExecuteScalar();
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "begin exampleproc(:in1,:in2,:in3,:out1,:out2,:out3); end;"; sqlrcom.Parameters.Add("in1",1); sqlrcom.Parameters.Add("in2",1.1); sqlrcom.Parameters.Add("in3","hello"); SQLRelayParameter out1 = new SQLRelayParameter(); out1.ParameterName = "out1"; out1.Direction = ParameterDirection.Output; out1.DbType = DbType.Int64; sqlrcom.Parameters.Add(out1); SQLRelayParameter out2 = new SQLRelayParameter(); out2.ParameterName = "out2"; out2.Direction = ParameterDirection.Output; out2.DbType = DbType.Double; sqlrcom.Parameters.Add(out2); SQLRelayParameter out2 = new SQLRelayParameter(); out3.ParameterName = "out3"; out3.Direction = ParameterDirection.Output; out3.DbType = DbType.String; out3.Size = 20; sqlrcom.Parameters.Add(out3); sqlrcom.ExecuteNonQuery(); Int64 result1 = Convert.ToInt64(out1.Value); Double result2 = Convert.ToDouble(out2.Value); String result3 = Convert.ToString(out3.Value);
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "exec exampleproc"; sqlrcom.Parameters.Add("in1",1); sqlrcom.Parameters.Add("in2",1.1); sqlrcom.Parameters.Add("in3","hello"); SQLRelayParameter out1 = new SQLRelayParameter(); out1.ParameterName = "out1"; out1.Direction = ParameterDirection.Output; out1.DbType = DbType.Int64; sqlrcom.Parameters.Add(out1); SQLRelayParameter out2 = new SQLRelayParameter(); out2.ParameterName = "out2"; out2.Direction = ParameterDirection.Output; out2.DbType = DbType.Double; sqlrcom.Parameters.Add(out2); SQLRelayParameter out2 = new SQLRelayParameter(); out3.ParameterName = "out3"; out3.Direction = ParameterDirection.Output; out3.DbType = DbType.String; out3.Size = 20; sqlrcom.Parameters.Add(out3); sqlrcom.ExecuteNonQuery(); Int64 result1 = Convert.ToInt64(out1.Value); Double result2 = Convert.ToDouble(out2.Value); String result3 = Convert.ToString(out3.Value);
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "select * from exampleproc(?,?,?)"; sqlrcom.Parameters.Add("1",1); sqlrcom.Parameters.Add("2",1.1); sqlrcom.Parameters.Add("3","hello"); sqlrcom.ExecuteReader(); System.Data.IDataReader datareader = sqlrcom.ExecuteReader(); datareader.Read(); Int64 out1 = datareader.GetInt64(0); Double out2 = datareader.GetDouble(1); String out3 = datareader.GetString(2);
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "exec procedure exampleproc ?, ?, ?"; sqlrcom.Parameters.Add("1",1); sqlrcom.Parameters.Add("2",1.1); sqlrcom.Parameters.Add("3","hello"); SQLRelayParameter out1 = new SQLRelayParameter(); out1.ParameterName = "1"; out1.Direction = ParameterDirection.Output; out1.DbType = DbType.Int64; sqlrcom.Parameters.Add(out1); SQLRelayParameter out2 = new SQLRelayParameter(); out2.ParameterName = "2"; out2.Direction = ParameterDirection.Output; out2.DbType = DbType.Double; sqlrcom.Parameters.Add(out2); SQLRelayParameter out2 = new SQLRelayParameter(); out3.ParameterName = "3"; out3.Direction = ParameterDirection.Output; out3.DbType = DbType.String; out3.Size = 20; sqlrcom.Parameters.Add(out3); sqlrcom.ExecuteNonQuery(); Int64 result1 = Convert.ToInt64(out1.Value); Double result2 = Convert.ToDouble(out2.Value); String result3 = Convert.ToString(out3.Value);
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "call exampleproc(?,?,?,?,?,?)"; sqlrcom.Parameters.Add("1",1); sqlrcom.Parameters.Add("2",1.1); sqlrcom.Parameters.Add("3","hello"); SQLRelayParameter out1 = new SQLRelayParameter(); out1.ParameterName = "4"; out1.Direction = ParameterDirection.Output; out1.DbType = DbType.Int64; sqlrcom.Parameters.Add(out1); SQLRelayParameter out2 = new SQLRelayParameter(); out2.ParameterName = "5"; out2.Direction = ParameterDirection.Output; out2.DbType = DbType.Double; sqlrcom.Parameters.Add(out2); SQLRelayParameter out2 = new SQLRelayParameter(); out3.ParameterName = "6"; out3.Direction = ParameterDirection.Output; out3.DbType = DbType.String; out3.Size = 20; sqlrcom.Parameters.Add(out3); sqlrcom.ExecuteNonQuery(); Int64 result1 = Convert.ToInt64(out1.Value); Double result2 = Convert.ToDouble(out2.Value); String result3 = Convert.ToString(out3.Value);
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "select * from examplefunc(?,?,?) as (col1 int, col2 float, col3 char(20))"; sqlrcom.Parameters.Add("in1",1); sqlrcom.Parameters.Add("in2",1.1); sqlrcom.Parameters.Add("in3","hello"); sqlrcom.ExecuteReader(); System.Data.IDataReader datareader = sqlrcom.ExecuteReader(); datareader.Read(); Int64 out1 = datareader.GetInt64(0); Double out2 = datareader.GetDouble(1); String out3 = datareader.GetString(2);
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "call exampleproc(?,?,?)"; sqlrcom.Parameters.Add("1",1); sqlrcom.Parameters.Add("2",1.1); sqlrcom.Parameters.Add("3","hello"); sqlrcom.ExecuteReader(); System.Data.IDataReader datareader = sqlrcom.ExecuteReader(); datareader.Read(); Int64 out1 = datareader.GetInt64(0); Double out2 = datareader.GetDouble(1); String out3 = datareader.GetString(2);
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.
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "set @out1=0, @out2=0.0, @out3=''"; Int64 result = sqlrcom.ExecuteNonQuery(); sqlrcom.CommandText = "call exampleproc(@out1,@out2,@out3)"; Int64 result = sqlrcom.ExecuteNonQuery(); sqlrcom.CommandText = "select @out1,@out2,@out3"; System.Data.IDataReader datareader = sqlrcom.ExecuteReader(); datareader.Read(); Int64 out1 = datareader.GetInt64(0); Double out2 = datareader.GetDouble(1); String out3 = datareader.GetString(2);
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
To create the stored procedure, run a query like the following.
create or replace package types as type cursorType is ref cursor; end; create function exampleproc return types.cursortype is l_cursor types.cursorType; begin open l_cursor for select * from mytable; return l_cursor; end;
In Oracle, for a result set to be fetched from a stored procedure, the result set must be bound to an output parameter of type cursor. That cursor may then be opened and fetched from. In fact, a stored procedure may return multiple result sets and each may be bound to a cursor.
ADO.NET abstracts this with the "multiple result sets" paradigm. Output cursors must be defined when the query is executed. Once the main query has been executed, NextResult may be called to step through the result sets bound to each cursor.
For example:
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "begin :curs=exampleproc; end;"; SQLRelayParameter curs = new SQLRelayParameter(); curs.ParameterName = "curs"; curs.Direction = ParameterDirection.Output; curs.SQLRelayType = SQLRelayType.Cursor; sqlrcom.Parameters.Add(curs); System.Data.IDataReader datareader = sqlrcom.ExecuteReader(); // the main result set will be empty, skip to the result set of the cursor datareader.NextResult(); datareader.Read(); Int64 out1 = datareader.GetInt64(0); Double out2 = datareader.GetDouble(1); String out3 = datareader.GetString(2);
Note that in the above code, the Parameter.SQLRelayType must be set rather than Parameter.DbType, which would generally be set. DbType is constrained to a set of values defined in the ADO.NET spec, which does not include Cursor types.
This approach has some drawbacks though. Mainly, if a stored procedure returns multiple results sets then they must be accessed sequentially. The SQL Relay ADO.NET adapter provides another way of accessing the result sets of a stored procedure. After execution, the Value of each cursor parameter may be cast to a SQLRelayDataReader and data may be fetched from it. This approach allows data to be fetched from any result set, in any order.
For example:
SQLRelayCommand sqlrcom = (SQLRelayComand)sqlrcon.CreateCommand(); sqlrcom.CommandText = "begin :curs=exampleproc; end;"; SQLRelayParameter curs = new SQLRelayParameter(); curs.ParameterName = "curs"; curs.Direction = ParameterDirection.Output; curs.SQLRelayType = SQLRelayType.Cursor; sqlrcom.Parameters.Add(curs); sqlrcom.ExecuteNonQuery(); SQLRelayDataReader datareader = (SQLRelayDataReader)curs.Value; datareader.Read(); Int64 out1 = datareader.GetInt64(0); Double out2 = datareader.GetDouble(1); String out3 = datareader.GetString(2);
To drop the stored procedure, run a query like the following.
drop function exampleproc drop package types
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.
sqlrcom.CommandText = "exec exampleproc"; System.Data.IDataReader datareader = sqlrcom.ExecuteReader(); datareader.Read(); Int64 out1 = datareader.GetInt64(0); Double out2 = datareader.GetDouble(1); String out3 = datareader.GetString(2); datareader.Read(); out1 = datareader.GetInt64(0); out2 = datareader.GetDouble(1); out3 = datareader.GetString(2);
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.
sqlrcom.CommandText = "select * from examplefunc() as (exampleint int, examplefloat float, examplechar char(40))"; System.Data.IDataReader datareader = sqlrcom.ExecuteReader(); datareader.Read(); Int64 out1 = datareader.GetInt64(0); Double out2 = datareader.GetDouble(1); String out3 = datareader.GetString(2); datareader.Read(); out1 = datareader.GetInt64(0); out2 = datareader.GetDouble(1); out3 = datareader.GetString(2);
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.
sqlrcom.CommandText = "call exampleproc()"; System.Data.IDataReader datareader = sqlrcom.ExecuteReader(); datareader.Read(); Int64 out1 = datareader.GetInt64(0); Double out2 = datareader.GetDouble(1); String out3 = datareader.GetString(2); datareader.Read(); out1 = datareader.GetInt64(0); out2 = datareader.GetDouble(1); out3 = datareader.GetString(2);
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.
Unfortunately ADO.NET doesn't expose a generic method for getting the last insert id, but when using the SQLite database, you can get the last insert id by running the query:
select last insert rowid