a firstworks project
SQL Relay
About Documentation Download Licensing Support News

Programming with SQL Relay using the Java API


Compiling an SQL Relay Client Program

When writing an SQL Relay client program using the Java API, you need to include /usr/local/firstworks/java in your CLASSPATH.

CLASSPATH=$CLASSPATH:/usr/local/firstworks/java
export CLASSPATH
javac MyProgram.java

To run your program, you need to include /usr/local/firstworks/java in your LD_LIBRARY_PATH. If your system supports ld.so, you can alternatively add /usr/local/firstworks/java to your /etc/ld.so.conf or /etc/ld.so.conf.d (if your system supports ld.so.conf.d) and run ldconfig.

LD_LIBRARY_PATH=$LD_LIBRARY_PATH:/usr/local/firstworks/java
export LD_LIBRARY_PATH
java MyProgram

Establishing a Session

To use SQL Relay, you have to identify the connection that you intend to use.

import SQLRConnection;

public class MyClass {
	public static main() {

       		SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);

       		... execute some queries ...

       		con.delete();
	}
}

After calling the constructor, 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.

Sessions can also be encrypted and authenticated using Kerberos/Active Directory or TLS/SSL. The enableKerberos() method is provided to enable Kerberos/Active Directory encryption and authentication and the enableTls() method is provided to enable TLS/SSL encryption and authentication. The disableEncryption() method is provided to disable any previously enabled encryption.

See the SQLRConnection class reference for information about these methods and the SQL Relay Configuration Guide for more information about Kerberos/Active Directory and TLS/SSL configurations. In particular, note that user and password are not typically used when using Kerberos/AD.

Executing Queries

Allocate a cursor, then call sendQuery() or sendFileQuery() to run a query. The same cursor may be used over and over.

import SQLRConnection;
import SQLRCursor;

public class MyClass {
	public static main() {

        	SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
        	SQLRCursor          cur=new SQLRCursor(con);

        	cur.sendQuery("select * from my_table");

        	... do some stuff that takes a short time ...

        	cur.sendFileQuery("/usr/local/myprogram/sql","myquery.sql");
        	con.endSession();

        	... do some stuff that takes a long time ...

        	cur.sendQuery("select * from my_other_table");
        	con.endSession();

        	... process the result set ...

		cur.delete();
		con.delete();
	}
}

Note the call to endSession() after the call to sendFileQuery(). Since the program does some stuff that takes a long time between that query and the next, ending the session there allows another client an opportunity to use that database connection while your client is busy. The next call to sendQuery() establishes another session. Since the program does some stuff that takes a short time between the first two queries, it's OK to leave the session open between them.

Commits and Rollbacks

If you need to execute a commit or rollback, you should use the commit() and rollback() methods of the SQLRConnection class 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 with the autoCommitOn() and autoCommitOff() methods of the SQLRConnection class. 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, autoCommitOn() and autoCommitOff() have 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 call to sendQuery() or sendFileQuery() returns a 0, the query failed. You can find out why by calling errorMessage().

import SQLRConnection;
import SQLRCursor;

public class MyClass {
	public static main() {

        	SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
        	SQLRCursor          cur=new SQLRCursor(con);

        	if (!cur.sendQuery("select * from my_nonexistant_table")) {
                	System.out.println(cur.errorMessage());
        	}

		cur.delete();
		con.delete();
	}
}

Substitution and Bind Variables

Programs rarely execute fixed queries. More often than not, some part of the query is dynamically generated. The SQL Relay API provides methods for making substitutions and binds in those queries.

For a detailed discussion of substitutions and binds, see this document.

Rather than just calling sendQuery() you call prepareQuery(), substitution(), inputBind() and executeQuery(). If you using queries stored in a file, you can call prepareFileQuery() instead of prepareQuery().

When passing a floating point number in as a bind or substitution variable, you have to supply precision and scale for the number. See this page for a discussion of precision and scale.

import SQLRConnection;
import SQLRCursor;

public class myclass {
        public static main() {

                SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
                SQLRCursor          cur=new SQLRCursor(con);

                cur.prepareQuery("select * from mytable $(whereclause)")
                cur.substitution("whereclause","where stringcol=:stringval and integercol>:integerval and floatcol>floatval");
                cur.inputBind("stringval","true");
                cur.inputBind("integerval",10);
                cur.inputBind("floatval",1.1,2,1);
                cur.executeQuery();

                ... process the result set ...
        }
}

If you are curious how many bind variables have been declared in a query, you can call countBindVariables() after preparing the query.

If you're using a database with an embedded procedural language, you may want to retrieve data from function calls. To facilitate this, SQL Relay provides methods for defining and retrieving output bind variables.

import SQLRConnection;
import SQLRCursor;

public class myclass {
        public static main() {

                SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
                SQLRCursor          cur=new SQLRCursor(con);

                cur.prepareQuery("begin  :result1:=addTwoIntegers(:integer1,:integer2);  :result2=addTwoFloats(:float1,:float2);  :result3=convertToString(:integer3); end;");
                cur.inputBind("integer1",10);
                cur.inputBind("integer2",20);
                cur.inputBind("float1",1.1,2,1);
                cur.inputBind("float2",2.2,2,1);
                cur.inputBind("integer3",30);
                cur.defineOutputBindInteger("result1");
                cur.defineOutputBindDouble("result2");
                cur.defineOutputBindString("result3",100);
                cur.executeQuery();
                long       result1=cur.getOutputBindInteger("result1");
                double     result2=cur.getOutputBindDouble("result2");
                String     result3=cur.getOutputBindString("result3");
                con.endSession();

                ... do something with the result ...

        }
}

The getOutputBindString() method returns a NULL value as an empty string. If you would it to come back as a NULL instead, you can call the getNullsAsNulls() method. To revert to the default behavior, you can call getNullsAsEmptyStrings().

You can insert data into BLOB and CLOB columns using the inputBindBlob(), inputBindClob() methods.

import SQLRConnection;
import SQLRCursor;

public class myclass {
        public static main() {

                SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
                SQLRCursor          cur=new SQLRCursor(con);

                cur.executeQuery("create table images (image blob, description clob)");

                String     imagedata;
                long       imagelength;

                ... read an image from a file into imagedata and the length of the
                        file into imagelength ...

                String     description;
                long       desclength;

                ... read a description from a file into description and the length of
                        the file into desclength ...

                cur.prepareQuery("insert into images values (:image,:desc)");
                cur.inputBindBlob("image",imagedata,imagelength);
                cur.inputBindClob("desc",description,desclength);
                cur.executeQuery();
        }
}

Likewise, you can retreive BLOB or CLOB data using defineOutputBindBlob()/getOutputBindBlob() and defineOutputBindClob()/getOutputBindClob().

import SQLRConnection;
import SQLRCursor;

public class myclass {
        public static main() {

                SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
                SQLRCursor          cur=new SQLRCursor(con);

                cur.prepareQuery("begin  select image into :image from images;  select description into :desc from images;  end;");
                cur.defineOutputBindBlob("image");
                cur.defineOutputBindClob("desc");
                cur.executeQuery();

                String  image=cur.getOutputBindBlob("image");
                long    imagelength=cur.getOutputBindLength("image");

                String  desc=cur.getOutputBindClob("desc");
                String  desclength=cur.getOutputBindLength("desc");

                con.endSession();

                ... do something with image and desc ...

        }
}

Sometimes it's convenient to bind a bunch of variables that may or may not actually be in the query. For example, if you are building a web based application, it may be easy to just bind all the form variables/values from the previous page, even though some of them don't appear in the query. Databases usually generate errors in this case. Calling validateBinds() just prior to calling executeQuery() causes the API to check the query for each bind variable before actually binding it, preventing those kinds of errors. You can also call validBind() to see if a specific variable is valid. However there is a performance cost associated with calling validateBinds() and validBind().

Re-Binding and Re-Execution

Another 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.

import SQLRConnection;
import SQLRCursor;

public class MyClass {
       public static main() {

               SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
               SQLRCursor          cur=new SQLRCursor(con);

               cur.prepareQuery("select * from mytable where mycolumn>:value");
               cur.inputBind("value",1);
               cur.executeQuery();

               ... process the result set ...

               cur.clearBinds();
               cur.inputBind("value",5);
               cur.executeQuery();

               ... process the result set ...

               cur.clearBinds();
               cur.inputBind("value",10);
               cur.executeQuery();

               ... process the result set ...

	       cur.delete();
	       con.delete();
       }
}

Accessing Fields in the Result Set

The rowCount(), colCount() and getField() methods are useful for processing result sets.

import SQLRConnection;
import SQLRCursor;

public class MyClass {
	public static main() {

        	SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
        	SQLRCursor          cur=new SQLRCursor(con);

        	cur.sendQuery("select * from my_table");
        	con.endSession();

        	for (int row=0; row<cur.rowCount(); row++) {
                	for (int col=0; col<cur.colCount(); col++) {
                        	System.out.println(cur.getField(row,col) + ",");
                	}
                	System.out.println();
        	}

		cur.delete();
		con.delete();
	}
}

The getField() method returns a string. If you would like to get a field as a long or double, you can use getFieldAsLong() and getFieldAsDouble(). If you would like to get a field as an array of bytes, you can use getFieldAsByteArray().

You can also use getRow() which returns a null-terminated array of the fields in the row.

import SQLRConnection;
import SQLRCursor;

public class MyClass {
	public static main() {

        	SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
        	SQLRCursor          cur=new SQLRCursor(con);

        	cur.sendQuery("select * from my_table");
        	con.endSession();

        	for (int row=0; row<cur.rowCount(); row++) {
                	String[]    rowarray=cur.getRow(row);
                	for (int col=0; col<cur.colCount(); col++) {
                        	System.out.println(rowarray[col] + ",");
                	}
                	System.out.println();
        	}

		cur.delete();
		con.delete();
	}
}

The getField() and getRow() methods return NULL fields as empty strings. If you would like them to come back as null's instead, you can call the getNullsAsNulls() method. To revert to the default behavior, you can call getNullsAsEmptyStrings().

If you want to access the result set, but don't care about the column information (column names, types or sizes) and don't mind getting fields by their numeric index instead of by name, you can call the dontGetColumnInfo() method prior to executing your query. This can result in a performance improvement, especially when many queries with small result sets are executed in rapid succession. You can call getColumnInfo() again later to turn off this feature.

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 setResultSetBufferSize() to set the number of rows to buffer at a time. Calls to getRow() and getField() 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 setResultSetBufferSize(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, getField(0,0) will return NULL and getField(11,0) will cause rows 10-14 to be fetched and return the requested value.

When buffering the result set in chunks, don't end the session until after you're done with the result set.

If you call setResultSetBufferSize() and forget what you set it to, you can always call getResultSetBufferSize().

When buffering a result set in chunks, the rowCount() method returns the number of rows returned so far. The firstRowIndex() method returns the index of the first row of the currently buffered chunk.

import SQLRConnection;
import SQLRCursor;

public class MyClass {
	public static main() {

        	SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
        	SQLRCursor          cur=new SQLRCursor(con);

        	cur.setResultSetBufferSize(5);

        	cur.sendQuery("select * from my_table");

        	int     done=0;
        	int     row=0;
        	String  field;
        	while (!done) {
                	for (int col=0; col<cur.colCount(); col++) {
                        	if (field=cur.getField(row,col)) {
                                	System.out.println(field + ",");
                        	} else {
                                	done=1;
                        	}
                	}
                	System.out.println();
                	row++;
        	}

        	cur.sendQuery("select * from my_other_table");

        	... process this query's result set in chunks also ...

        	cur.setResultSetBufferSize(0);

        	cur.sendQuery("select * from my_third_table");

        	... process this query's result set all at once ...

        	con.endSession();

		cur.delete();
		con.delete();
	}
}

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.

For example:

import SQLRConnection;
import SQLRCursor;

public class MyClass {
	public static main() {

        	SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
        	SQLRCursor          cursor1=new SQLRCursor(con);
        	SQLRCursor          cursor2=new SQLRCursor(con);

        	cursor1.setResultSetBufferSize(10);
        	cursor1.sendQuery("select * from my_huge_table");

        	int     index=0;
        	while (!cursor1.endOfResultSet()) {
                	cursor2.prepareQuery("insert into my_other_table values (:1,:2,:3)");
                	cursor2.inputBind("1",cursor1.getField(index,1));
                	cursor2.inputBind("2",cursor1.getField(index,2));
                	cursor2.inputBind("3",cursor1.getField(index,3));
                	cursor2.executeQuery();
        	}

		cursor2.delete();
		cursor1.delete();
		con.delete();
	}
}

If you are using stored procedures with Oracle, a stored procedure can execute a query and return a cursor. A cursor bind variable can then retrieve that cursor. Your program can retrieve the result set from the cursor. All of this can be accomplished using defineOutputBindCursor(), getOutputBindCursor() and fetchFromOutputBindCursor().

import SQLRConnection;
import SQLRCursor;

public class MyClass {

        public static main() {

                SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
                SQLRCursor          cur=new SQLRCursor(con);

                cur.prepareQuery("begin  :curs:=sp_mytable; end;");
                cur.defineOutputBindCursor("curs");
                cur.executeQuery();

                SQLRCursor      bindcur=cur.getOutputBindCursor("curs");
                bindcur.fetchFromBindCursor();

                // print fields from table
                for (int i=0; i<bindcur.rowCount(); i++) {
                        for (int j=0; j<bindcur.colCount(); j++) {
                                System.out.print(bindcur.getField(i,j)+", ");
                        }
                        System.out.println();
                }

                bindcur.delete();

                cur.delete();
                con.delete();
        }
}

The number of cursors simultaneously available per-connection is set at compile time and defaults to 5.

Getting Column Information

For each column, the API supports getting the name, type and length of each field. All databases support these attributes. The API also supports getting the precision, scale (see this page for a discussion of precision and scale), length of the longest field, and whether the column is nullable, the primary key, unique, part of a key, unsigned, zero-filled, binary, or an auto-incrementing field. However, not all databases support these attributes. If a database doesn't support an attribute, it is always returned as false.

import SQLRConnection;
import SQLRCursor;

public class MyClass {
	public static main() {

        	SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
        	SQLRCursor          cur=new SQLRCursor(con);

        	cur.sendQuery("select * from my_table");
        	con.endSession();

        	for (int i=0; i<cur.colCount(); i++) {
                	System.out.println("Name:          " + cur.getColumnName(i));
                	System.out.println("Type:          " + cur.getColumnType(i));
                	System.out.print("Length:        ");
                	System.out.println(cur.getColumnLength(i));
                	System.out.print("Precision:     ");
                	System.out.println(cur.getColumnPrecision(i));
                	System.out.print("Scale:         ");
                	System.out.println(cur.getColumnScale(i));
                	System.out.print("Longest Field: ");
                	System.out.println(cur.getLongest(i));
                	System.out.print("Nullable:       ");
                	System.out.println(cur.getColumnIsNullable(i));
                	System.out.print("Primary Key:    ");
                	System.out.println(cur.getColumnIsPrimaryKey(i));
                	System.out.print("Unique:         ");
                	System.out.println(cur.getColumnIsUnique(i));
                	System.out.print("Part Of Key:    ");
                	System.out.println(cur.getColumnIsPartOfKey(i));
                	System.out.print("Unsigned:       ");
                	System.out.println(cur.getColumnIsUnsigned(i));
                	System.out.print("Zero Filled:    ");
                	System.out.println(cur.getColumnIsZeroFilled(i));
                	System.out.print("Binary:         ");
                	System.out.println(cur.getColumnIsBinary(i));
                	System.out.print("Auto Increment: ");
                	System.out.println(cur.getColumnIsAutoIncrement(i));
                	System.out.println();
        	}

		cur.delete();
		con.delete();
	}
}

Some databases force column names to upper case, others force column names to lower case, and others still support mixed-case column names. Sometimes, when migrating between databases, you can run into trouble. You can use upperCaseColumnNames() and lowerCaseColumnNames() to cause column names to be converted to upper or lower case, or you can use mixedCaseColumnNames() to cause column names to be returned in the same case as they are defined in the database.

import SQLRConnection;
import SQLRCursor;

public class MyClass {

        public static main() {

                SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
                SQLRCursor          cur=new SQLRCursor(con);

                // column names will be forced to upper case
                cur.upperCaseColumnNames();
                cur.sendQuery("select * from my_table");
                con.endSession();

                for (int i=0; i<cur.colCount(); i++) {
                        System.out.println("Name: "+cur.getColumnName(i));
                }

                // column names will be forced to lower case
                cur.lowerCaseColumnNames();
                cur.sendQuery("select * from my_table");
                con.endSession();

                for (int i=0; i<cur.colCount(); i++) {
                        System.out.println("Name: "+cur.getColumnName(i));
                }

                // column names will be the same as they are in the database
                cur.mixedCaseColumnNames();
                cur.sendQuery("select * from my_table");
                con.endSession();

                for (int i=0; i<cur.colCount(); i++) {
                        System.out.println("Name: "+cur.getColumnName(i));
                }

                cur.delete();
                con.delete();
        }
}

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.

cur.prepareQuery("begin exampleproc(:in1,:in2,:in3); end;");
cur.inputBind("in1",1);
cur.inputBind("in2",1.1,2,1);
cur.inputBind("in3","hello");
cur.executeQuery();

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.

cur.prepareQuery("exec exampleproc");
cur.inputBind("in1",1);
cur.inputBind("in2",1.1,2,1);
cur.inputBind("in3","hello");
cur.executeQuery();

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.

cur.prepareQuery("execute procedure exampleproc ?, ?, ?");
cur.inputBind("1",1);
cur.inputBind("2",1.1,2,1);
cur.inputBind("3","hello");
cur.executeQuery();

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.

cur.prepareQuery("call exampleproc(?,?,?)");
cur.inputBind("1",1);
cur.inputBind("2",1.1,2,1);
cur.inputBind("3","hello");
cur.executeQuery();

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.

cur.prepareQuery("select examplefunc($1,$2,$3)");
cur.inputBind("1",1);
cur.inputBind("2",1.1,2,1);
cur.inputBind("3","hello");
cur.executeQuery();

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.

cur.prepareQuery("call exampleproc(?,?,?)");
cur.inputBind("1",1);
cur.inputBind("2",1.1,2,1);
cur.inputBind("3","hello");
cur.executeQuery();

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.

cur.prepareQuery("select exampleproc(?,?,?) from dual");
cur.inputBind("1",1);
cur.inputBind("2",1.1,2,1);
cur.inputBind("3","hello");
cur.executeQuery();
String  result=cur.getField(0,0);

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.

cur.prepareQuery("begin exampleproc(:in1,:in2,:in3,:out1); end;");
cur.inputBind("in1",1);
cur.inputBind("in2",1.1,2,1);
cur.inputBind("in3","hello");
cur.defineOutputBindInteger("out1");
cur.executeQuery();
long    result=cur.getOutputBindInteger("out1");

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.

cur.prepareQuery("exec exampleproc");
cur.inputBind("in1",1);
cur.inputBind("in2",1.1,2,1);
cur.inputBind("in3","hello");
cur.defineOutputBindInteger("out1");
cur.executeQuery();
long    result=cur.getOutputBindInteger("out1");

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.

cur.prepareQuery("select * from exampleproc(?,?,?)");
cur.inputBind("1",1);
cur.inputBind("2",1.1,2,1);
cur.inputBind("3","hello");
cur.executeQuery();
String  result=cur.getField(0,0);

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.

cur.prepareQuery("execute procedure exampleproc ?, ?, ?");
cur.inputBind("1",1);
cur.inputBind("2",1.1,2,1);
cur.inputBind("3","hello");
cur.defineOutputBindInteger("1");
cur.executeQuery();
long    result=cur.getOutputBindInteger("1");

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.

cur.prepareQuery("call exampleproc(?,?,?,?)");
cur.inputBind("1",1);
cur.inputBind("2",1.1,2,1);
cur.inputBind("3","hello");
cur.defineOutputBindInteger("4");
cur.executeQuery();
long  result=cur.getOutputBindInteger("4");

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.

cur.prepareQuery("select * from examplefunc($1,$2,$3)");
cur.inputBind("1",1);
cur.inputBind("2",1.1,4,2);
cur.inputBind("3","hello");
cur.executeQuery();
String  result=cur.getField(0,0);

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.

cur.prepareQuery("select examplefunc(?,?,?)");
cur.inputBind("1",1);
cur.inputBind("2",1.1,4,2);
cur.inputBind("3","hello");
cur.executeQuery();
String   result=cur.getField(0,0);

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.

cur.sendQuery("select exampleproc()");
String  result=cur.getFieldByIndex(0,0);

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.

cur.sendQuery("set @out1=0");
cur.sendQuery("call exampleproc(@out1)");
cur.sendQuery("select @out1");
String  result=cur.getFieldByIndex(0,0);

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.

cur.prepareQuery("begin exampleproc(:in1,:in2,:in3,:out1,:out2,:out3); end;");
cur.inputBind("in1",1);
cur.inputBind("in2",1.1,2,1);
cur.inputBind("in3","hello");
cur.defineOutputBindInteger("out1");
cur.defineOutputBindDouble("out2");
cur.defineOutputBindString("out3",20);
cur.executeQuery();
long    out1=cur.getOutputBindInteger("out1");
double  out2=cur.getOutputBindDouble("out2");
String  out3=cur.getOutputBindString("out3");

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.

cur.prepareQuery("exec exampleproc");
cur.inputBind("in1",1);
cur.inputBind("in2",1.1,2,1);
cur.inputBind("in3","hello");
cur.defineOutputBindInteger("out1");
cur.defineOutputBindDouble("out2");
cur.defineOutputBindString("out3",20);
cur.executeQuery();
long    out1=cur.getOutputBindInteger("out1");
double  out2=cur.getOutputBindDouble("out2");
String  out3=cur.getOutputBindString("out3");

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.

cur.prepareQuery("select * from exampleproc(?,?,?)");
cur.inputBind("1",1);
cur.inputBind("2",1.1,2,1);
cur.inputBind("3","hello");
cur.executeQuery();
String  out1=cur.getField(0,0);
String  out2=cur.getField(0,1);
String  out3=cur.getField(0,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.

cur.prepareQuery("execute procedure exampleproc ?, ?, ?");
cur.inputBind("1",1);
cur.inputBind("2",1.1,2,1);
cur.inputBind("3","hello");
cur.defineOutputBindInteger("1");
cur.defineOutputBindDouble("2");
cur.defineOutputBindString("3",20);
cur.executeQuery();
long    out1=cur.getOutputBindInteger("1");
double  out2=cur.getOutputBindDouble("2");
String  out3=cur.getOutputBindString("3");

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.

cur.prepareQuery("call exampleproc(?,?,?,?,?,?)");
cur.inputBind("1",1);
cur.inputBind("2",1.1,2,1);
cur.inputBind("3","hello");
cur.defineOutputBindInteger("4");
cur.defineOutputBindDouble("5");
cur.defineOutputBindString("6",25);
cur.executeQuery();
long    out1=cur.getOutputBindInteger("4");
double  out2=cur.getOutputBindDouble("5");
String  out3=cur.getOutputBindString("6");

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.

cur.prepareQuery("select * from examplefunc($1,$2,$3) as (col1 int, col2 float, col3 char(20))");
cur.inputBind("1",1);
cur.inputBind("2",1.1,4,2);
cur.inputBind("3","hello");
cur.executeQuery();
String  out1=cur.getField(0,0);
String  out2=cur.getField(0,1);
String  out3=cur.getField(0,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.

cur.prepareQuery("call exampleproc(?,?,?)");
cur.inputBind("1",1);
cur.inputBind("2",1.1,4,2);
cur.inputBind("3","hello");
cur.executeQuery();
String  out1=cur.getField(0,0);
String  out2=cur.getField(0,1);
String  out3=cur.getField(0,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.

cur.sendQuery("set @out1=0, @out2=0.0, @out3=''");
cur.sendQuery("call exampleproc(@out1,@out3,@out3)");
cur.sendQuery("select @out1,@out2,@out3");
String  out1=cur.getFieldByIndex(0,0);
String  out2=cur.getFieldByIndex(0,1);
String  out3=cur.getFieldByIndex(0,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;

To execute the stored procedure from an SQL Relay program, use code like the following.

cur.prepareQuery("begin  :curs:=exampleproc; end;");
cur.defineOutputBindCursor("curs");
cur.executeQuery();
sqlrcursor      *bindcur=cur.getOutputBindCursor("curs");
bindcur.fetchFromBindCursor();
String  field00=bindcur.getField(0,0);
String  field01=bindcur.getField(0,1);
String  field02=bindcur.getField(0,2);
String  field10=bindcur.getField(1,0);
String  field11=bindcur.getField(1,1);
String  field12=bindcur.getField(1,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.

cur.sendQuery("exec exampleproc");
String  field00=cur.getFieldByIndex(0,0);
String  field01=cur.getFieldByIndex(0,1);
String  field02=cur.getFieldByIndex(0,2);
String  field10=cur.getFieldByIndex(1,0);
String  field11=cur.getFieldByIndex(1,1);
String  field12=cur.getFieldByIndex(1,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.

cur.sendQuery("select * from examplefunc() as (exampleint int, examplefloat float, examplechar char(40))");
String  field00=cur.getField(0,0);
String  field01=cur.getField(0,1);
String  field02=cur.getField(0,2);
String  field10=cur.getField(1,0);
String  field11=cur.getField(1,1);
String  field12=cur.getField(1,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.

cur.sendQuery("call exampleproc()");
String  field00=cur.getField(0,0);
String  field01=cur.getField(0,1);
String  field02=cur.getField(0,2);
String  field10=cur.getField(1,0);
String  field11=cur.getField(1,1);
String  field12=cur.getField(1,2);

To drop the stored procedure, run a query like the following.

drop procedure exampleproc

Caching The Result Set

Say you're writing a web-based report where a query with a huge result set is executed and 20 rows are displayed per page. Rather than rerunning the query for every page every time and dumping all but the 20 rows you want to display, you can run the query once, cache the result set to a local file and just open the file for each page of the report.

First page:

import SQLRConnection;
import SQLRCursor;

public class MyClass {
	public static main() {

        	SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
        	SQLRCursor          cur=new SQLRCursor(con);

		... generate a unique filename ...

        	cur.cacheToFile(filename);
        	cur.setCacheTtl(600);
        	cur.sendQuery("select * from my_table");
        	con.endSession();
        	cur.cacheOff();

        	... pass the filename to the next page ...

		cur.delete();
		con.delete();
	}
}

Second page:

import SQLRConnection;
import SQLRCursor;

public class MyClass {
	public static main() {

        	... get the filename from the previous page ...

        	... get the page to display from the previous page ...

        	SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
        	SQLRCursor          cur=new SQLRCursor(con);

        	cur.openCachedResultSet(filename);
        	con.endSession();

        	for (int row=pagetodisplay*20; row<(pagetodisplay+1)*20; row++) {
                	for (int col=0; col<cur.colCount(); col++) {
                        	System.out.println(cur.getField(row,col) + ",");
                	}
                	System.out.println();
        	}

		cur.delete();
		con.delete();
	}
}

For result-set caching to be effective, the sqlr-cachemanager process must be enabled and running on the client system. The sqlr-cachemanager scans the cache periodically and deletes cached result sets whos ttl's have expired. If it is not running, stale result sets persist beyond their intended ttl's.

To enable the sqlr-cachemanager at boot on systemd platforms:

systemctl enable sqlrcachemanager.service

To start the sqlr-cachemanager on systemd platforms:

systemctl start sqlrcachemanager.service

To enable the sqlr-cachemanager at boot on most non-systemd platforms, you must create a symlink into the /etc/rc2.d or /etc/rc3.d directory. Eg:

cd /etc/rc2.d
ln -s ../init.d/sqlrcachemanager S15sqlrcachemanager

or

cd /etc/rc3.d
ln -s ../init.d/sqlrcachemanager S15sqlrcachemanager

To start the sqlr-cachemanager on most non-systemd platforms:

/etc/init.d/sqlrcachemanager start

To enable the sqlr-cachemanager at boot on FreeBSD platforms, edit /etc/rc.conf and add a line like:

sqlrcachemanager_enable=YES

To enable the sqlr-cachemanager at boot on NetBSD platforms, edit /etc/rc.conf and add a line like:

sqlrcachemanager=YES

To enable the sqlr-cachemanager at boot on OpenBSD platforms, edit /etc/rc.conf and add a line like:

sqlrcachemanager_flags=YES

To start the sqlr-cachemanager on BSD platforms:

/etc/init.d/sqlrcachemanager start

Suspending and Resuming Sessions

Sometimes web-based applications need a single database transaction to span multiple pages. Since SQL Relay sessions can be suspended and resumed, this is possible.

First page:

import SQLRConnection;
import SQLRCursor;

public class MyClass {
	public static main() {

        	SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
        	SQLRCursor          cur=new SQLRCursor(con);

        	cur.sendQuery("insert into my_table values (1,2,3)");
        	cur.suspendResultSet();
        	con.suspendSession();
        	int     rs=cur.getResultSetId();
        	int     port=cur.getConnectionPort();
        	String  socket=cur.getConnectionSocket();

        	... pass the rs, port and socket to the next page ...

		cur.delete();
		con.delete();
	}
}

Second page:

import SQLRConnection;
import SQLRCursor;

public class MyClass {
	public static main() {

        	... get rs, port and socket from previous page ...

        	SQLRConnection      con=new SQLRConnection("sqlrserver",(short)9000,"/tmp/example.socket","user","password",0,1);
        	SQLRCursor          cur=new SQLRCursor(con);

        	con.resumeSession(port,socket);
        	cur.resumeResultSet(rs);
        	cur.sendQuery("commit");
        	con.endSession();

		cur.delete();
		con.delete();
	}
}

You can also distribute the processing of a result set across a series of pages using suspended sessions. If you're buffering a result set in chunks instead of all at once and suspend a session, when you resume the session you can continue to retrieve rows from the result set.

Similarly, if you're buffering a result set in chunks, caching that result set and suspend your session. When you resume the session, you can continue caching the result set. You must use resumeCachedResultSet() instead of resumeResultSet() however.

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.

SQL Relay provides the SQLRConnection.getLastInsertId() 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
Copyright 2017 - David Muse - Contact