Generay speaking, a procedure is a routine that can accept arguments but does not return any values. A function is a routine that can accept arguments and returns one or more values. Axional Ax library support calling either database procedures or functions.
Return | Method |
---|---|
JSResultSet
|
executeFunction(String sql, Object ...args) |
JSResultSet
|
executeFunction(String sql, Function<Integer,String> columnNameMap, Object ...args) |
Map<String, Object> | executeFunctionWithParameters(String sql, Consumer<FunctionCallConfigurator> columnNameMap) |
JSResultSet
|
executeProcedure(String sql, Object ...args) |
JSResultSet
|
executeProcedure(String sql, Function<Integer,String> columnNameMap, Object ...args) |
1 Calling functions
1.1 Functions
Most databases support SPL functions. SPL functions are UDRs (user defined routines) that in most of database engines return a single value. To write and register an SPL function, use a CREATE FUNCTION statement.
1.1.1 Single value
The simpliest data that can be returned in a SPL function is a basic type value.
-- Return number of rows from specified table CREATE FUNCTION IF NOT EXISTS test_function1(p_tabname VARCHAR(30)) RETURNING INTEGER; DEFINE m_tabrows INTEGER; SELECT nrows INTO m_tabrows FROM systables WHERE tabname = p_tabname; RETURN m_tabrows; END FUNCTION
-- Return number of rows from specified table CREATE OR REPLACE FUNCTION test_function1(p_tabname VARCHAR2) RETURN INTEGER AS m_tabrows integer; BEGIN m_tabrows := 0; BEGIN SELECT table_name, num_rows INTO m_tabname, m_tabrows FROM all_tables WHERE table_name = p_tabname AND owner = (SELECT sys_context('userenv','current_schema') FROM dual); EXCEPTION WHEN NO_DATA_FOUND THEN NULL; END; RETURN m_tabrows; END; /
-- Return number of rows from specified table CREATE OR REPLACE FUNCTION test_function1(tablename text) RETURNS INTEGER AS $$ DECLARE tabrows INTEGER; BEGIN tablename := 'public.' || tablename; EXECUTE format('SELECT count(1) FROM %s', tablename) INTO tabrows; return tabrows; END $$ LANGUAGE 'plpgsql';
Let's see how to execute it (enter a table name that exists in the database):
<script> Ax.db.execute('DROP FUNCTION IF EXISTS test_function1'); Ax.db.execute(`-- Return number of rows from specified table CREATE FUNCTION IF NOT EXISTS test_function1(p_tabname VARCHAR(30)) RETURNING INTEGER; DEFINE m_tabrows INTEGER; SELECT nrows INTO m_tabrows FROM systables WHERE tabname = p_tabname; RETURN m_tabrows; END FUNCTION`); var nrows = Ax.db.executeFunction("test_function1", "systables"); console.log(nrows); nrows.close(); nrows = Ax.db.executeFunction("test_function1", "systables"); console.log(nrows.toOne()["(expression)"]); nrows = Ax.db.executeFunction("test_function1", "systables"); console.log(nrows.toValue()); Ax.db.execute('DROP FUNCTION test_function1'); </script>
+------------+
|(expression)|
|int |
+------------+
| 683|
+------------+
683
683
1.1.2 Single row values
A SPL function can return more than one value from a single row of a table. The following example shows an SPL function that returns two column values from a single row of a table.
-- Return tabid and number of rows from specified table DROP FUNCTION IF EXISTS test_function1; CREATE FUNCTION IF NOT EXISTS test_function1(p_tabname VARCHAR(30)) RETURNING ROW(a int, b int); DEFINE m_tabid INTEGER; DEFINE m_tabrows INTEGER; SELECT tabid, nrows INTO m_tabid, m_tabrows FROM systables WHERE tabname = p_tabname; RETURN ROW(m_tabid, m_tabrows); END FUNCTION;
CREATE OR REPLACE TYPE test_type_record AS OBJECT ( tabname VARCHAR2(30), tabrows INTEGER ); / -- Return table name and number of rows from specified table CREATE OR REPLACE FUNCTION test_function_return_record(p_tabname VARCHAR2) RETURN test_type_record AS m_tabname varchar2(30); m_tabrows integer; var_record test_type_record; BEGIN m_tabname := p_tabname; m_tabrows := 0; var_record := test_type_record(m_tabname,m_tabrows); BEGIN SELECT table_name, num_rows INTO m_tabname, m_tabrows FROM all_tables WHERE table_name = p_tabname AND owner = (SELECT sys_context('userenv','current_schema') FROM dual); EXCEPTION WHEN NO_DATA_FOUND THEN NULL; END; var_record.tabname := m_tabname; var_record.tabrows := m_tabrows; RETURN (var_record); END; /
CREATE TYPE test_function1_return_type AS ( tabname TEXT, tabrows INTEGER ); -- Return table name and number of rows from specified table CREATE OR REPLACE FUNCTION test_function1(tablename text) RETURNS test_function1_return_type AS $$ DECLARE result_record test_function1_return_type; BEGIN tablename := 'public.' || tablename; result_record.tabname := tablename; EXECUTE format('SELECT count(1) FROM %s', tablename) INTO result_record.tabrows; return result_record; END $$ LANGUAGE 'plpgsql';
Let's see how to execute it (enter a table name that exists in the database):
<script> Ax.db.execute('DROP FUNCTION IF EXISTS test_function1'); Ax.db.execute(`-- Return tabid and number of rows from specified table CREATE FUNCTION IF NOT EXISTS test_function1(p_tabname VARCHAR(30)) RETURNING ROW(a int, b int); DEFINE m_tabid INTEGER; DEFINE m_tabrows INTEGER; SELECT tabid, nrows INTO m_tabid, m_tabrows FROM systables WHERE tabname = p_tabname; RETURN ROW(m_tabid, m_tabrows); END FUNCTION;`); var rs = Ax.db.executeFunction("test_function1", "systables"); var row = rs.toOne() console.log(row); console.log(row["(expression)"][0]); console.log(row["(expression)"][1]); Ax.db.execute('DROP FUNCTION test_function1'); </script>
{(expression)=[1, 103]}
1
103
In previous example, default column name "(expression)" is asigned to parameter returned. You can change the name of returned values from an executeFunction call, by passing a mapping function as second parameter :
<script> Ax.db.execute('DROP FUNCTION IF EXISTS test_function1'); Ax.db.execute(`-- Return tabid and number of rows from specified table CREATE FUNCTION IF NOT EXISTS test_function1(p_tabname VARCHAR(30)) RETURNING ROW(a int, b int); DEFINE m_tabid INTEGER; DEFINE m_tabrows INTEGER; SELECT tabid, nrows INTO m_tabid, m_tabrows FROM systables WHERE tabname = p_tabname; RETURN ROW(m_tabid, m_tabrows); END FUNCTION;`); var rs = Ax.db.executeFunction("test_function1", columnIndex => { // TODO switch (columnIndex) { case 1: return "rowtype"; default: return "undefined"; } }, "systables").toOne(); console.log(rs["rowtype"][0]); console.log(rs["rowtype"][1]); Ax.db.execute('DROP FUNCTION test_function1'); </script>
1
103
1.1.3 Multiple rows
The following example is an SPL function that returns more than one row.
-- Return system tables with more than specific number of rows CREATE FUNCTION IF NOT EXISTS test_function2() RETURNING ROW(color VARCHAR(30), val INTEGER); RETURN ROW('Red', 10) WITH RESUME; RETURN ROW('Green', 20) WITH RESUME; RETURN ROW('Blue', 30) WITH RESUME; END FUNCTION
CREATE OR REPLACE FUNCTION test_function_cursor2(p_numrows INTEGER) RETURN SYS_REFCURSOR AS var_cursor SYS_REFCURSOR; BEGIN BEGIN OPEN var_cursor FOR SELECT table_name, num_rows FROM all_tables WHERE num_rows >p_numrows AND owner = (SELECT sys_context('userenv','current_schema') FROM dual); EXCEPTION WHEN NO_DATA_FOUND THEN NULL; END; RETURN (var_cursor); END; /
Let's see how to execute it:
<script> Ax.db.execute('DROP FUNCTION IF EXISTS test_function2'); Ax.db.execute(`-- Return system tables with more than specific number of rows CREATE FUNCTION IF NOT EXISTS test_function2() RETURNING ROW(color VARCHAR(30), val INTEGER); RETURN ROW('Red', 10) WITH RESUME; RETURN ROW('Green', 20) WITH RESUME; RETURN ROW('Blue', 30) WITH RESUME; END FUNCTION`); var rs = Ax.db.executeFunction("test_function2"); for (var row of rs) { console.log(row); } Ax.db.execute('DROP FUNCTION test_function2'); </script>
+------------+
|(expression)|
+------------+
|[Red, 10] |
|[Green, 20] |
|[Blue, 30] |
+------------+
1.1.4 Passing multiple arguments
In the previous examples we have been using a function receiving only one value as input parameter.
You can pass multiple arguments (varargs
) to a function that will be passed in same order to the correspoding
function arguments.
The following example is a simple echo function that returns values passed as arguments.
CREATE FUNCTION IF NOT EXISTS test_function3 (p_int INTEGER, p_float FLOAT, p_dec DECIMAL(14, 6), p_date DATE, p_char CHAR(20)) RETURNING ROW(r_int INTEGER, r_float FLOAT, r_dec DECIMAL(14, 6), r_date DATE, r_char CHAR(20)); RETURN ROW(p_int, p_float, p_dec, p_date, p_char); END FUNCTION
<script> Ax.db.execute(`DROP FUNCTION IF EXISTS test_function3`); Ax.db.execute(` CREATE FUNCTION IF NOT EXISTS test_function3 (p_int INTEGER, p_float FLOAT, p_dec DECIMAL(14, 6), p_date DATE, p_char CHAR(20)) RETURNING ROW(r_int INTEGER, r_float FLOAT, r_dec DECIMAL(14, 6), r_date DATE, r_char CHAR(20)); RETURN ROW(p_int, p_float, p_dec, p_date, p_char); END FUNCTION `); var rs = Ax.db.executeFunction("test_function3", 1, 1.234, 1.23456, new Date(), "Hello"); console.log(rs); rs.close(); Ax.db.execute('DROP FUNCTION test_function3'); </script>
+------------------------------------------------------------+
|(expression) |
+------------------------------------------------------------+
|[1, 1.234, 1.234560, 2019-03-25, Hello ] |
+------------------------------------------------------------+
1.2 Fetching a single value of type row
From previous examples we can see all data returned is a ResultSet
as we
any function may return one or multiple rows. You need to iterate the
ResultSet
to fetch firs row and so on. This can be tedious when we
are processing only one row
When application knows a function will return only one value, it can
transform the ResultSet
into a JSON object to simplify data processing.
<script> Ax.db.execute(`DROP FUNCTION IF EXISTS test_function3`); Ax.db.execute(` CREATE FUNCTION IF NOT EXISTS test_function3 (p_int INTEGER, p_float FLOAT, p_dec DECIMAL(14, 6), p_date DATE, p_char CHAR(20)) RETURNING ROW(r_int INTEGER, r_float FLOAT, r_dec DECIMAL(14, 6), r_date DATE, r_char CHAR(20)); RETURN ROW(p_int, p_float, p_dec, p_date, p_char); END FUNCTION `); var rs = Ax.db.executeFunction("test_function3", columnIndex => { switch (columnIndex) { case 1: return "rowtype"; default: return "undefined"; } }, // arguments 1, 1.234, 1.23456, new Date(), "Hello" ); var row = rs.toOne(); console.log(row); console.log(row.rowtype); console.log(row.rowtype[0] + ", " + row.rowtype[1] + ", " + row.rowtype[2]); Ax.db.execute('DROP FUNCTION test_function3'); </script>
{rowtype=[1, 1.234, 1.234560, 2019-03-25, Hello ]}
[[1, 1.234, 1.234560, 2019-03-25, Hello ]]
1, 1.234, 1.234560
-
If
ResultSet
returns no rows, a JSON object with columns set to null values is returned. -
If
ResultSet
retutrns more than one row an SQLException will be thrown as only one row is expected. - Calling toOne() function with (argument required="message") will make function throws SQLException(message) if no row is found.
2 Calling Procedures
SPL procedures are UDRs written in Stored Procedure Language (SPL) that do not return a value. To write and register an SPL routine, use the CREATE PROCEDURE statement.
In general a procedure is a routine that can accept arguments but does not return any values. Even so, many database agents allow procedures return values (for example Informix).
2.1 No return
You can call a procedure not returning any values by executing Ax.db.executeProcedure. First argument is the name of the procedure you want to execute followed by parameter values you want to pass to procedure in same order it were declared in the procedure signature.
If the procedure doesn't return any parameter, execution of Ax.db.executeProcedure returns a null value.
-- Creates a temporary table with the number of rows from specified table CREATE PROCEDURE IF NOT EXISTS test_procedure1(p_tabname VARCHAR(30)) DROP TABLE IF EXISTS t_tmp_1; SELECT tabname, nrows FROM systables WHERE tabname = p_tabname INTO TEMP t_tmp_1 WITH NO LOG; END PROCEDURE;
-- Creates a temporary table with the number of rows from specified table CREATE OR REPLACE PROCEDURE test_procedure1(p_tabname VARCHAR2) AS table_or_view_not_exist exception; pragma exception_init(table_or_view_not_exist, -942); attempted_ddl_on_in_use_GTT exception; pragma exception_init(attempted_ddl_on_in_use_GTT, -14452); m_sql VARCHAR2(32767); m_new INTEGER; begin DBMS_OUTPUT.PUT_LINE('Starts test_procedure1'); BEGIN EXECUTE IMMEDIATE 'drop table t_tmp_1'; EXCEPTION WHEN table_or_view_not_exist THEN DBMS_OUTPUT.PUT_LINE('Table t_tmp_1 does not exists'); WHEN attempted_ddl_on_in_use_GTT THEN DBMS_OUTPUT.PUT_LINE('Table t_tmp_1 is in use (truncate)'); EXECUTE IMMEDIATE 'TRUNCATE table t_tmp_1'; EXECUTE IMMEDIATE 'drop table t_tmp_1'; END; DBMS_OUTPUT.PUT_LINE('Create table t_tmp_1'); m_sql := 'CREATE GLOBAL TEMPORARY TABLE t_tmp_1 ON COMMIT PRESERVE ROWS AS SELECT table_name, num_rows FROM all_tables WHERE owner = (SELECT sys_context(''userenv'',''current_schema'') FROM dual) AND table_name = '''||p_tabname||''' '; EXECUTE IMMEDIATE m_sql; END; /
Let's see how to execute it (enter a table name that exists in the database):
<script> Ax.db.execute(`DROP PROCEDURE IF EXISTS test_procedure1`); Ax.db.execute(` CREATE PROCEDURE IF NOT EXISTS test_procedure1(p_tabname VARCHAR(30)) DROP TABLE IF EXISTS t_tmp_1; SELECT tabname, nrows FROM systables WHERE tabname = p_tabname INTO TEMP t_tmp_1 WITH NO LOG; END PROCEDURE; `); console.log("Execute returns: " + Ax.db.executeProcedure("test_procedure1", "systables")); console.log("========================================"); console.log(Ax.db.executeQuery("select * from t_tmp_1")); Ax.db.execute('DROP PROCEDURE test_procedure1'); </script>
Execute returns: null
========================================
+----------------------------------------+----------------+
|tabname |nrows |
+----------------------------------------+----------------+
|systables | 103.0|
+----------------------------------------+----------------+
2.2 Single return parameter
When calling a procedure, doesn't matter if it returns a single or multiple parameters, it always returns a resultset with parameters returned as columns.
Usually a procedure returns a single row, so you can use toOne() method to avoid resultset iteration.
CREATE PROCEDURE IF NOT EXISTS test_procedure2(value INTEGER) RETURNING INTEGER; IF value IS NULL THEN RETURN 1; ELSE RETURN 0; END IF END PROCEDURE;
Let's see how to execute it:
<script> Ax.db.execute(`DROP PROCEDURE IF EXISTS test_procedure2`); Ax.db.execute(` CREATE PROCEDURE IF NOT EXISTS test_procedure2(value INTEGER) RETURNING INTEGER; IF value IS NULL THEN RETURN 1; ELSE RETURN 0; END IF END PROCEDURE; `); var rs = Ax.db.executeProcedure("test_procedure2", 150); var data = rs.toOne() console.log("Result is: " + data["(expression)"]); Ax.db.execute('DROP PROCEDURE test_procedure2'); </script>
Result is: 0
2.3 Multiple return parameters
As explained in previous section, when using procedures, returning multiple parameters is similar than returning a single one. Result from procedure execution is a ResultSet
with a single or multiple columns.
Lets see a simple procedure that returns multiple values (two) for a given input value and how to call it according specific engine.
DROP PROCEDURE IF EXISTS test_procedure3; CREATE PROCEDURE IF NOT EXISTS test_procedure3(value INTEGER) RETURNING INTEGER AS a, INTEGER AS b RETURN value * 2, value / 2; END PROCEDURE;
<script> Ax.db.execute(`DROP PROCEDURE IF EXISTS test_procedure3`); Ax.db.execute(` DROP PROCEDURE IF EXISTS test_procedure3; CREATE PROCEDURE IF NOT EXISTS test_procedure3(value INTEGER) RETURNING INTEGER AS a, INTEGER AS b RETURN value * 2, value / 2; END PROCEDURE; `); var rs = Ax.db.executeProcedure("test_procedure3", 6); for (var row of rs) console.log(row); Ax.db.execute('DROP PROCEDURE test_procedure3'); </script>
{a=12, b=3}
2.3.1 Column name mapping
From previous examples we may see that procedure has a named returned data, and this names are returned as part of resultset.
But, if you don't name return parameters explicitly, database returns the same name for all columns: expression
.
The problem is we will not be able to use a javascript object to fetch the data.
Let's try to fetch data getting every row as a JavaScript object (Map).
<script> Ax.db.execute(`CREATE PROCEDURE IF NOT EXISTS test_procedure4(value INTEGER) RETURNING INTEGER, INTEGER RETURN value * 2, value / 2; END PROCEDURE;`); var rs = Ax.db.executeProcedure("test_procedure4", 6); for (var row of rs) console.log(row); Ax.db.execute('DROP PROCEDURE test_procedure4'); </script>
{(expression)=3}
We can see, first parameter is lost and we only get last value.
A solution is to use a column name mapper using JDBC columnIndex to return the desired column name corresponding to return variable ordinal.
<script> Ax.db.execute('DROP PROCEDURE IF EXISTS test_procedure4'); Ax.db.execute(`CREATE PROCEDURE IF NOT EXISTS test_procedure4(value INTEGER) RETURNING INTEGER, INTEGER RETURN value * 2, value / 2; END PROCEDURE;`); var rs = Ax.db.executeProcedure("test_procedure4", columnIndex => { switch (columnIndex) { case 1: return "p_mul"; case 2: return "p_div"; default: return "undefined"; } }, // arguments 6 ); console.log(rs); rs.close(); Ax.db.execute('DROP PROCEDURE test_procedure4'); </script>
+----------+----------+
|p_mul |p_div |
+----------+----------+
| 12| 3|
+----------+----------+
2.4 Multiple rows with multiple return params
Invoking calls to procedures returning multiple rows is similar to invoking a call returning a single row. A resultset is returned and you need to iterate it to get all rows returned.
<script> Ax.db.execute("DROP PROCEDURE IF EXISTS test_procedure5"); Ax.db.execute(`CREATE PROCEDURE IF NOT EXISTS test_procedure5(value INTEGER) RETURNING INTEGER AS multiplied, INTEGER AS divided RETURN value * 2, value / 2 WITH RESUME; RETURN value * 4, value / 4 WITH RESUME; RETURN value * 6, value / 6 WITH RESUME; RETURN value * 8, value / 8 WITH RESUME; RETURN value * 10, value / 10 WITH RESUME; END PROCEDURE;`); var rs = Ax.db.executeProcedure("test_procedure5", 40); for (var row of rs) console.log(row); Ax.db.execute('DROP PROCEDURE test_procedure5'); </script>
{multiplied=80, divided=20}
{multiplied=160, divided=10}
{multiplied=240, divided=6}
{multiplied=320, divided=5}
{multiplied=400, divided=4}