The CREATE FUNCTION and CREATE PROCEDURE statements define a callable function or procedure, usually called a routine.
The CREATE FUNCTION and CREATE PROCEDURE statements define a callable function or procedure, usually called a routine.
Routines are useful for creating reusable blocks of code that can be executed independently many times. They can be implemented as a series of ESQL statements, a Java method, or a database stored procedure. This flexibility means that some of the clauses in the syntax diagram are not applicable (or allowed) for all types of routine.
Each routine has a name, which must be unique within the schema to which it belongs. This means that routine names cannot be overloaded; if the broker detects that a routine has been overloaded, it raises an exception.
Specify the routine's name using the RoutineName clause and the routine's parameters using the ParameterList clause. If the LANGUAGE clause specifies ESQL, the routine must be implemented using a single ESQL statement. This statement is most useful if it is a compound statement (BEGIN ... END) as it can then contain as many ESQL statements as necessary to fulfil its function.
Alternatively, instead of providing an ESQL body for the routine, you can specify a LANGUAGE clause other than ESQL. This allows you to use the EXTERNAL NAME clause to provide a reference to the actual body of the routine, wherever it is located externally to the broker. For more details about using the EXTERNAL NAME clause, see Invoking stored procedures and Calling a Java routine.
Routines of any LANGUAGE type can have IN, OUT, and INOUT parameters. This allows the caller to pass several values into the routine, and to receive several updated values back. This is in addition to any RETURNS clause the routine may have. The RETURNS clause allows the routine to pass back a value to the caller.
Routines implemented in different languages have their own restrictions on which data-types can be passed in or returned, and these are documented below. The data-type of the returned value must match the data-type of the value defined to be returned from the routine. Also, if a routine is defined to have a return value, the caller of the routine cannot ignore it. For more details see the CALL statement.
For any language or routine type, the method of invocation of the routine must match the manner of declaration of the routine. If the routine has a RETURNS clause, use either the FUNCTION invocation syntax or a CALL statement with an INTO clause. Conversely, if a routine has no RETURNS clause you must use a CALL statement without an INTO clause.
If the routine type is FUNCTION, the direction indicator (IN, OUT, INOUT) is optional for each parameter. However, it is good programming practice to specify a direction indicator for all new routines of any type for documentation purposes.
ESQL variables that are declared to be CONSTANT (or references to variables declared to be CONSTANT) are not allowed to have the direction OUT or INOUT.
ESQL routines are written in ESQL, and have a LANGUAGE clause of ESQL. The body of an ESQL routine is usually a compound statement of the form BEGIN … END, containing multiple statements for processing the parameters passed to the routine.
CREATE PROCEDURE swapParms ( IN parm1 CHARACTER, OUT parm2 CHARACTER, INOUT parm3 CHARACTER ) BEGIN SET parm2 = parm3; SET parm3 = parm1; END;
This example procedure shows the recursive use of an ESQL routine. It parses a tree, visiting all places at and below the specified starting point, and reports what it has found:
SET OutputRoot.MQMD = InputRoot.MQMD; DECLARE answer CHARACTER; SET answer = ''; CALL navigate(InputRoot.XML, answer); SET OutputRoot.XML.Data.FieldNames = answer; CREATE PROCEDURE navigate (IN root REFERENCE, INOUT answer CHARACTER) BEGIN SET answer = answer || 'Reached Field... Type:' || CAST(FIELDTYPE(root) AS CHAR)|| ': Name:' || FIELDNAME(root) || ': Value :' || root || ': '; DECLARE cursor REFERENCE TO root; MOVE cursor FIRSTCHILD; IF LASTMOVE(cursor) THEN SET answer = answer || 'Field has children... drilling down '; ELSE SET answer = answer || 'Listing siblings... '; END IF; WHILE LASTMOVE(cursor) DO CALL navigate(cursor, answer); MOVE cursor NEXTSIBLING; END WHILE; SET answer = answer || 'Finished siblings... Popping up '; END;
When given the following input message:
<Person> <Name>John Smith</Name> <Salary period='monthly' taxable='yes'>-1200</Salary> </Person>
the procedure produces the following output, which has been manually formatted:
Reached Field... Type:16777232: Name:XML: Value :: Field has children... drilling down Reached Field... Type:16777216: Name:Person: Value :: Field has children... drilling down Reached Field... Type:16777216: Name:Name: Value :John Smith: Field has children... drilling down Reached Field... Type:33554432: Name:: Value :John Smith: Listing siblings... Finished siblings... Popping up Finished siblings... Popping up Reached Field... Type:16777216: Name:Salary: Value :-1200: Field has children... drilling down Reached Field... Type:50331648: Name:period: Value :monthly: Listing siblings... Finished siblings... Popping up Reached Field... Type:50331648: Name:taxable: Value :yes: Listing siblings... Finished siblings... Popping up Reached Field... Type:33554432: Name:: Value :-1200: Listing siblings... Finished siblings... Popping up Finished siblings... Popping up Finished siblings... Popping up Finished siblings... Popping up
>>--"-- className---.---methodName--"--------------><where className identifies the class that contains the method and methodName identifies the method to be invoked. If the class is part of a package, the class identifier part must include the complete package prefix; for example, "com.ibm.broker.test.MyClass.myMethod".
To find the Java class, the broker searches as described in Deploying Java classes.
public static <return-type> <method-name> (< 0 - N parameters>)
where <return-type> must be in the list of Java IN data types in the table in ESQL to Java data type mapping (excluding the REFERENCE type, which is not permitted as a return value), or the Java void data type. The parameter data types must also be in the ESQL to Java data type mapping table. In addition, the Java method is not allowed to have an exception throws clause in its signature.
You can use the Java User defined Node (UDN) API in your Java method, provided that you observe the restrictions documented in Restrictions on Java routines. For more information about using the UDN API, see Compiling a Java user-defined node.
This routine contains three parameters of varying directions, and returns an integer, which maps to a Java return type of java.lang.Long.
CREATE FUNCTION myProc1( IN P1 INTEGER, OUT P2 INTEGER, INOUT P3 INTEGER ) RETURNS INTEGER LANGUAGE JAVA EXTERNAL NAME "com.ibm.broker.test.MyClass.myMethod1";
You can use the following ESQL to invoke myProc1:
CALL myProc1( intVar1, intVar2, intVar3) INTO intReturnVar3; -- or SET intReturnVar3 = myProc1( intVar1, intVar2, intVar3);
This routine contains three parameters of varying directions and has a Java return type of void.
CREATE PROCEDURE myProc2( IN P1 INTEGER, OUT P2 INTEGER, INOUT P3 INTEGER ) LANGUAGE JAVA EXTERNAL NAME "com.ibm.broker.test.MyClass.myMethod2";
You must use the following ESQL to invoke myProc2:
CALL myProc2(intVar1, intVar2, intVar3);
The following Java class provides a method for each of the preceding Java examples:
package com.ibm.broker.test; class MyClass { public static Long myMethod1( Long P1, Long[] P2 Long[] P3) { ... } public static void myMethod2( Long P2, Long[] P2 Long[] P3) { ... } /* When either of these methods is called: P1 may or may not be NULL (depending on the value of intVar1). P2[0] is always NULL (whatever the value of intVar2). P3[0] may or may not be NULL (depending on the value of intVar3). This is the same as with LANGUAGE ESQL routines. When these methods return: intVar1 is unchanged intVar2 may still be NULL or may have been changed intVar3 may contain the same value or may have been changed. This is the same as with LANGUAGE ESQL routines. When myMethod1 returns: intReturnVar3 is either NULL (if the method returns NULL) or it contains the value returned by the method. */ }
ESQL data types 1 | Java IN data types | Java INOUT and OUT data types |
INTEGER, INT | java.lang.Long | java.lang.Long [] |
FLOAT | java.lang.Double | java.lang.Double[] |
DECIMAL | java.math.BigDecimal | java.math.BigDecimal[] |
CHARACTER, CHAR | java.lang.String | java.lang.String[] |
BLOB | byte[] | byte[][] |
BIT | java.util.BitSet | java.util.BitSet[] |
DATE | com.ibm.broker.plugin.MbDate | com.ibm.broker.plugin.MbDate[] |
TIME 2 | com.ibm.broker.plugin.MbTime | com.ibm.broker.plugin.MbTime[] |
GMTTIME 2 | com.ibm.broker.plugin.MbTime | com.ibm.broker.plugin.MbTime[] |
TIMESTAMP 2 | com.ibm.broker.plugin.MbTimestamp | com.ibm.broker.plugin.MbTimestamp[] |
GMTTIMESTAMP 2 | com.ibm.broker.plugin.MbTimestamp | com.ibm.broker.plugin.MbTimestamp[] |
INTERVAL | Not supported | Not supported |
BOOLEAN | java.lang.Boolean | java.lang.Boolean[] |
REFERENCE (to a message tree) 3 4 5 6 | com.ibm.broker.plugin.MbElement | com.ibm.broker.plugin.MbElement[] (Supported for INOUT. Not supported for OUT) |
ROW | Not supported | Not supported |
LIST | Not supported | Not supported |
For example, if an ESQL reference to OutputRoot.XML.Test is passed into a Java method as an INOUT MbElement, but a different MbElement is passed back to ESQL when the call returns, the different element must also point to somewhere in the OutputRoot tree.
A REFERENCE to a scalar variable can be used in the CALL of a Java method, provided that the data type of the variable the reference refers to matches the corresponding data type in the Java program signature.
You are allowed to spawn threads inside your method. However, spawned threads must not use the Java plug-in APIs and you must return control back to the broker.
Note that all restrictions that apply to the usage of the UDN API also apply to Java methods called from ESQL.
Adding your JAR file to the BAR file is the most efficient and flexible method of deploying to the broker.
You can add a JAR file to the BAR file manually, by hand, or automatically, using the tooling. The tooling is the simplest way to add a JAR file to a BAR file.
If the tooling finds the correct Java class inside a referenced Java project open in the workspace, it automatically compiles the Java class into a JAR file and adds it to the BAR file. This is the same procedure that you follow to deploy a Java Compute node inside a JAR, as described in User-defined node classloading.
When deploying a JAR file from the tooling, a redeploy of the BAR file containing the JAR file causes the referenced Java classes to be reloaded by the flow that has been redeployed; as does stopping and restarting a message flow that references a Java class. Ensure that you stop and restart (or redeploy) all flows that reference the JAR file that you want to update. This avoids the problem of some flows running with the old version of the JAR file and other flows running with the new version.
Note that the tooling will only deploy a JAR file; it will not deploy a standalone Java class file.
This procedure must be done manually; you cannot use the tooling.
In this method, redeploying the message flow does not reload the referenced Java classes; neither does stopping and restarting the message flow. The only way to reload the classes in this case is to stop and restart the broker itself.
To enable the broker to find a Java class, ensure that it is in one of the above locations. If the broker cannot find the specified class, it throws an exception.
Although you have the choices shown above when deploying the JAR file, allowing the tooling to deploy the BAR file provides the greatest flexibility when redeploying the JAR file.
Database Routines are routines implemented as database stored procedures. Database routines have a LANGUAGE clause of DATABASE, and must have a routine type of PROCEDURE.
When writing stored procedures in languages like C, you must use NULL indicators to ensure that your procedure can process the data correctly.
Although the database definitions of a stored procedure will vary between the databases, the ESQL used to invoke them does not. The names given to parameters in the ESQL do not have to match the names they are given on the database side. However, the external name of the routine, including any package or container specifications, must match its defined name in the database.
The DYNAMIC RESULT SET clause is allowed only for database routines. It is required only if a stored procedure returns one or more result sets. The integer parameter to this clause must be 0 (zero) or more and specifies the number of result sets to be returned.
The optional RETURNS clause is required if a stored procedure returns a single scalar value.
The EXTERNAL NAME clause specifies the name by which the database knows the routine. This can be either a qualified or an unqualified name, where the qualifier is the name of the database schema in which the procedure is defined. If you do not provide a schema name, the database connection user name is used as the schema in which to locate the procedure. If the required procedure does not exist in this schema, you must provide an explicit schema name, either on the routine definition or on the CALL to the routine at runtime. For more information about dynamically choosing the schema which contains the routine, see the CALL statement. When a qualified name is used, the name must be in quotation marks.
EXTERNAL NAME "mySchema.myProc";
EXTERNAL NAME "mySchema.myPackage.myProc";
This allows the schema, but not the package name, to be chosen dynamically in the CALL statement.
EXTERNAL NAME "mySchema.Proc_";
The following is a simple ESQL definition of a stored procedure that returns a single scalar value and an OUT parameter:
CREATE PROCEDURE myProc1(IN P1 INT, OUT P2 INT) LANGUAGE DATABASE RETURNS INTEGER EXTERNAL NAME "myschema.myproc";
Use this ESQL to invoke the myProc1 routine:
/*using CALL statement invocation syntax*/ CALL myProc1(intVar1, intVar2) INTO intReturnVar3; /*or using function invocation syntax*/ SET intReturnVar3 = myProc1(intVar1, intVar2);
The following ESQL code demonstrates how to define and call DB2 stored procedures:
ESQL Definition: DECLARE inputParm CHARACTER; DECLARE outputParm CHARACTER; DECLARE inputOutputParm CHARACTER; SET inputParm = 'Hello'; SET inputOutputParm = 'World'; CALL swapParms( inputParm, outputParm, inputOutputParm ); CREATE PROCEDURE swapParms ( IN parm1 CHARACTER, OUT parm2 CHARACTER, INOUT parm3 CHARACTER ) EXTERNAL NAME dbSwapParms;
To register this stored procedure with DB2, copy the following script to a file (for example, test1.sql)
-- DB2 Example Stored Procedure DROP PROCEDURE dbSwapParms @ CREATE PROCEDURE dbSwapParms ( IN in_param CHAR(32), OUT out_param CHAR(32), INOUT inout_param CHAR(32)) LANGUAGE SQL BEGIN SET out_param = inout_param; SET inout_param = in_param; END @and execute:
db2 -td@ -vf test1.sqlfrom the DB2 command prompt.
The following ESQL code demonstrates how to define and call Oracle stored procedures:
ESQL Definition: DECLARE inputParm CHARACTER; DECLARE outputParm CHARACTER; DECLARE inputOutputParm CHARACTER; SET inputParm = 'Hello'; SET inputOutputParm = 'World'; CALL swapParms( inputParm, outputParm, inputOutputParm ); CREATE PROCEDURE swapParms ( IN parm1 CHARACTER, OUT parm2 CHARACTER, INOUT parm3 CHARACTER ) EXTERNAL NAME dbSwapParms;
To register this stored procedure with Oracle, copy the following script to a file (for example, test1.sql)
CREATE OR REPLACE PROCEDURE dbSwapParms ( in_param IN VARCHAR2, out_param OUT VARCHAR2, inout_param IN OUT VARCHAR2 ) AS BEGIN out_param := inout_param; inout_param := in_param; END; /and execute:
sqlplus <userid>/<password> @test1.sql
The following ESQL code demonstrates how to define and call SQL Server stored procedures:
ESQL Definition: DECLARE inputParm CHARACTER; DECLARE outputParm CHARACTER; DECLARE inputOutputParm CHARACTER; SET inputParm = 'Hello'; SET inputOutputParm = 'World'; CALL swapParms( inputParm, outputParm, inputOutputParm ); CREATE PROCEDURE swapParms ( IN parm1 CHARACTER, INOUT parm2 CHARACTER, INOUT parm3 CHARACTER ) EXTERNAL NAME dbSwapParms;
To register this stored procedure with SQLServer, copy the following script to a file (for example, test1.sql)
-- SQLServer Example Stored Procedure DROP PROCEDURE dbSwapParms go CREATE PROCEDURE dbSwapParms @in_param CHAR(32), @out_param CHAR(32) OUT, @inout_param CHAR(32) OUT AS SET NOCOUNT ON SET @out_param = @inout_param SET @inout_param = @in_param goand execute:
isql -U<userid> -P<password> -S<server> -d<datasource> -itest1.sql
If you declare these as OUT parameters in your ESQL you encounter a type mismatch error at run time. To avoid that mismatch you must declare SQL Server OUTPUT parameters as INOUT in your ESQL.
The following ESQL code demonstrates how to define and call SYBASE stored procedures:
ESQL Definition: DECLARE inputParm CHARACTER; DECLARE outputParm CHARACTER; DECLARE inputOutputParm CHARACTER; SET inputParm = 'Hello'; SET inputOutputParm = 'World'; CALL swapParms( inputParm, outputParm, inputOutputParm ); CREATE PROCEDURE swapParms ( IN parm1 CHARACTER, INOUT parm2 CHARACTER, INOUT parm3 CHARACTER ) EXTERNAL NAME dbSwapParms;
To register this stored procedure with SYBASE, copy the following script to a file (for example, test1.sql)
-- SYBASE Example Stored Procedure DROP PROCEDURE dbSwapParms go CREATE PROCEDURE dbSwapParms @in_param CHAR(32), @out_param CHAR(32) OUT, @inout_param CHAR(32) OUT AS SET @out_param = @inout_param SET @inout_param = @in_param goand execute:
isql -U<userid> -P<password> -S<server> -d<datasource> -itest1.sql
If you declare these as OUT parameters in your ESQL you encounter a type mismatch error at run time. To avoid that mismatch you must declare SYBASE OUTPUT parameters as INOUT in your ESQL.
This example shows how to call a stored procedure that returns two result sets, as well as an out parameter:
CREATE PROCEDURE myProc1 (IN P1 INT, OUT P2 INT) LANGUAGE DATABASE DYNAMIC RESULT SETS 2 EXTERNAL NAME "myschema.myproc";
Use the following ESQL to invoke myProc1:
/* using a field reference */ CALL myProc1(intVar1, intVar2, Environment.RetVal[], OutputRoot.XML.A[]) /* using a reference variable*/ CALL myProc1(intVar1, intVar2, myReferenceVariable.RetVal[], myRef2.B[])
Notices |
Trademarks |
Downloads |
Library |
Support |
Feedback
![]() ![]() |
ak04970_ |