Query a database from JavaScript is easy using Axional library. When performing a query,
database returns an SQL ResultSet
.
A SQL result set is a set of rows from a database, as well as metadata about the query such as the column names, and the types and sizes of each column. Depending on the database system, the number of rows in the result set may or may not be known. Usually, this number is not known up front because the result set is built on-the-fly.
A result set is effectively a table. The ORDER BY clause can be used in a query to impose a certain sort condition on the rows. Without that clause, there is no guarantee whatsoever on the order in which the rows are returned.
Specific wrappers around database ResultSet
and in memory ResultSet
are provided
as built-in Javascript objects. You can read more about how to handle ResultSet
objects in the Ax.rs
package.
The database object provides basic methods to perform query execution.
Return | Method | Description |
---|---|---|
JSResultSet
|
executeQuery(String sql, Object... args) | Executes a query. |
JSResultSet
|
executeGlobalCachedQuery(String sql, Object... args) | Executes a query and stores results in memory to be reused for same queries in other JS executions. This cache is global for the server and neve expires. |
JSResultSet
|
executeLocalCachedQuery(String sql, Object... args) | Executes a query and stores results in memory to be reused for same queries in the JS process. This cache expires at the end of the JS process execution. |
JSResultSet
|
executeCachedQuery(String sql, Object... args) | This is a synonym for executeLocalCachedQuery. |
JSResultSet
|
executePreparedQuery(String sql, Object... args) | Executes a query, replacing :{varname} with placeholders. |
Object | executeGet(String sql, Object... args) | Executes a single row and single column query. Better use executeGetXXX for the appropiate number type to avoid script engine side effects. |
int | executeGetInt(String sql, Object... args) | Executes a single row and single column query |
long | executeGetLong(String sql, Object... args) | Executes a single row and single column query |
double | executeGetDouble(String sql, Object... args) | Executes a single row and single column query |
JSResultSet
|
executeScriptOrQuery(String sql, Object... args) | Executes a script or query |
JSSQLCA
|
execute(String sql, Object... args) | Execute an SQL statement that may return a ResultSet or not depending statement type |
1 Writing a statement
You can write a statement as literal string is a sequence of bytes or characters, enclosed within either two single quotes (' ') or two double quotes (" ").
1.1 Passing arguments
All methods admit variable number of arguments to match SQL statement place holders.
var rs = Ax.db.executeQuery( "SELECT tabname, created FROM systables WHERE tabid = ?", 1 ); console.log(rs);
+----------------------------------------+----------+
|tabname |created |
+----------------------------------------+----------+
|systables |2018-05-17|
+----------------------------------------+----------+
1.2 Using template literals
Template literals are string literals allowing embedded expressions. You can use multi-line strings and string interpolation features with them. They were called "template strings" in prior editions of the ES2015 specification.
Template literals are enclosed by the back-tick (` `) (grave accent
) character instead of double or single quotes.
Template literals can contain placeholders.
These are indicated by the dollar sign and curly braces (${expression}
).
The expressions in the placeholders and the text between them get passed to a function.
var tabid = 1; var rs = Ax.db.executeQuery( `SELECT tabname, created FROM systables WHERE tabid = ${tabid}` ); console.log(rs);
+----------------------------------------+----------+
|tabname |created |
+----------------------------------------+----------+
|systables |2018-05-17|
+----------------------------------------+----------+
1.3 Multiline strings
Any newline characters inserted in the source are part of the template literal. This has a great advantage for readability when writing large multi line SQL statements.
var tabid = 1; var rs = Ax.db.executeQuery(` SELECT tabname, created FROM systables WHERE tabid = ${tabid} `); console.log(rs);
2 Quering a database
You have several methods to query a database witch are more simple than their Java synonyms.
2.1 executeQuery
The executeQuery statements executes the SQL query in this PreparedStatement object and returns the ResultSet
object generated by the query.
return Ax.db.executeQuery( "SELECT tabid, tabname, nrows, created FROM systables WHERE tabname='systables'" );
data
+----------+----------------------------------------+----------------+----------+
|tabid |tabname |nrows |created |
|serial |varchar |float |date |
+----------+----------------------------------------+----------------+----------+
| 1|systables | 89.000|2018-04-08|
+----------+----------------------------------------+----------------+----------+
2.1.1 Iterating results
The ResulSet object is iterable. So we can use a for loop to traverse it. On each iteration, the returned object is a JSON object with row data.
var rs = Ax.db.executeQuery( "SELECT tabid, tabname, nrows, created FROM systables WHERE tabname='systables'" ); for (var row of rs) { console.log(row.tabid + "," + row.tabname); }
data
1,systables
2.1.2 Get current Row Number in a Resultset iteration
The ResulSet object is iterable. In each iteration an internal row counter is incremente, so you can know how many rows are you currently retrieved from the Resultset. You can access this counter by callint getRow() method..
const rs = Ax.db.executeQuery(` <select first='10'> <columns>tabname</columns> <from table='systables'/> </select>`); var currentRow = 0; for (var systables of rs) { console.log("ROW = " + rs.getRow() + " TABNAME=" + systables.tabname); }
Console result
ROW = 1 TABNAME=systables
ROW = 2 TABNAME=syscolumns
ROW = 3 TABNAME=sysindices
ROW = 4 TABNAME=systabauth
ROW = 5 TABNAME=syscolauth
ROW = 6 TABNAME=sysviews
ROW = 7 TABNAME=sysusers
ROW = 8 TABNAME=sysdepend
ROW = 9 TABNAME=syssynonyms
ROW = 10 TABNAME=syssyntable
2.2 executePreparedQuery
This method is equivalent to executing executeQuery method, but it adds an abstraction layer to make prepared statements constructions easier.
SQL Text can include tags :{varname} which are replaced by placeholders (?). The object parameter contains at last the variables used in the tags which are used to make the variable bindings in the proper order.
var rs = Ax.db.executePreparedQuery(` SELECT * FROM systables WHERE (tabname = :{tab1} OR tabname = :{tab2} ) AND tabid < :{maxtabid} `, {"maxtabid" : 100, "tab1":"syscolumns", "tab2" : "sysindexes", "tab3" : "systables" } ); console.log(rs); rs.close();
2.3 executeGet
The method executeGet
is simplified query for single row / column values. For example,
to get the count(*) of some table we have several options.
-
Using executeQuery and iterating to first row to convert it to JSON.
Copyvar rs = Ax.db.executeQuery("SELECT COUNT(*) as count FROM systables"); var count; for (var row of rs) { count = row.count; } console.log(count);
88
-
Using executeQuery and toOne function to convert directly to a JSON object.
Copyvar row = Ax.db.executeQuery("SELECT COUNT(*) as count FROM systables").toOne(); count = row.count; console.log(count);
88
-
Using the
executeGet
method is quite simple.Copyvar count = Ax.db.executeGet("SELECT COUNT(*) FROM systables"); console.log(count);
88
Notice that in methods 1 and 2 we need to provide an alias for column name.
2.3.1 The data type returned
executeGet
returns the native databse type and may cause some
undesired side effects. In some databases (Informix for example) the
COUNT(*) returns a BigDecimal. This may cause a fail when comparing
the returned value with a given value depending the script engine.
The problem may be related when the value returned is BigDecimal or BigInteger. Nashorn compares a BigDecimal or BigInteger with a javascript number but Graal will not.
Nashorn script engine
<script type="nashorn"> var count = Ax.db.executeGet("SELECT COUNT(*) FROM systables WHERE tabid = -1"); console.log(count); console.log(count == 0); </script>
0
true
Graal script engine
<script type="graal"> var count = Ax.db.executeGet("SELECT COUNT(*) FROM systables WHERE tabid = -1"); console.log(count); console.log(count == 0); </script>
0
false
Use executeGetInt, executeGetLong or executegetDouble to get the appropiate data type to avoid script engine side effects.
2.4 executeScriptOrQuery
The executeScriptOrQuery statements executes the XSQL code in this PreparedStatement object and returns one ResultSet
object.
-
Calling one xsql script without named columns.
Copyvar message = "Hello world"; const rsXsql = Ax.db.executeScriptOrQuery(` <call> <args> <arg>${message}</arg> </args> <![CDATA[ <xsql-script> <args> <arg name='param1' type='string' /> </args> <body> <return> <param1 /> </return> </body> </xsql-script>]]> </call> `); // Get return data for (const row of rsXsql) { console.log(row['(constant_1)']); }
{(constant_1)=Hello world} Hello world
-
Calling one xsql script with named columns.
Copy<script> const rsXsql = Ax.db.executeScriptOrQuery(` <call into='col1'> <args> <arg>Hello world</arg> </args> <![CDATA[ <xsql-script> <args> <arg name='param1' type='string' /> </args> <body> <return> <param1 /> </return> </body> </xsql-script>]]> </call> `); // Get return data for (const row of rsXsql) { console.log(row.col1); } </script>
{col1=Hello world} Hello world
Passing null arguments
Al the above functions allow passing a dynamic numnbre of arguments. This can lead to issues when using Graal js engine. To avoid such issues it is recommended to wrap nullable values with the follwing function
Ax.db.nullable(a)
3 Executing statements
The execute method executes the SQL statement in a PreparedStatement object, which may be any kind of SQL statement. Some prepared statements return multiple results; the execute method handles these complex statements as well as the simpler form of statements handled by the methods executeQuery.
The execute statement returns a SQLCA
object.
3.1 SQLCA object
SQLCA
is called as a SQL communication Area. SQLCA
will have all the information like return code, error id,
error details, serial information, etc after database statement execution.
3.1.1 Rows affected count
The count
property stores the number of rows affected by an INSERT, DELETE or UPDATE operation. This information can also be
retrieved by calling the getCount()
method on SQLCA
class.
Ax.db.execute("CREATE TABLE IF NOT EXISTS test1 (a VARCHAR(3), b SMALLINT)"); Ax.db.execute("INSERT INTO test1 VALUES('a', 1)").getCount(); Ax.db.execute("INSERT INTO test1 VALUES('b', 2)").getCount(); Ax.db.execute("INSERT INTO test1 VALUES('c', 3)").getCount(); var updated = Ax.db.execute("UPDATE test1 SET b = b + 1").getCount(); console.log(updated + " rows updated"); Ax.db.execute('DROP TABLE test1');
3 rows updated
3.1.2 Last serial inserted
The serial
property stores the serial value stored in a serial column from last INSERT executed.
This information can also be retrieved by calling the getSerial()
method on SQLCA
class.
Ax.db.execute("CREATE TABLE IF NOT EXISTS test2 (a SERIAL, b CHAR(3))"); console.log(Ax.db.execute("INSERT INTO test2 VALUES(0, 'a')").getSerial()); console.log(Ax.db.execute("INSERT INTO test2 VALUES(0, 'b')").getSerial()); console.log(Ax.db.execute("INSERT INTO test2 VALUES(0, 'c')").getSerial()); Ax.db.execute('DROP TABLE test2');
1
2
3
3.1.3 Time of statement
You can obtain the time in milliseconds of last operation accessing time
member on SQLCA
object.
<script> Ax.db.execute("CREATE TEMP TABLE IF NOT EXISTS test2 (a SERIAL, b CHAR(3))"); console.log(Ax.db.execute("INSERT INTO test2 VALUES(0, 'a')").time); Ax.db.execute('DROP TABLE test2'); </script>
0
3.2 NULL Bindigs Replacement
Axional Studio tries to make smart replacements when binding variables have null values. This will make where conditions to work when you want to compare a table column equal to a null value.
This kind of statement:
var m_colval = null; Ax.db.execute(`UPDATE tab1 SET col1 = 0 WHERE col1 = ?`, m_colval);
Will be replaced at execution runtime by SQL Statement:
UPDATE tab1 SET col1 = 0 WHERE col1 IS NULL
This is nice behavour when applied only in where conditions, but this is done in the shole statement, so, this statement:
UPDATE tab1 SET col1 = ? WHERE col1 = ?
Can be replaced bu:
UPDATE tab1 SET col1 Is NULL WHERE col1 Is NULL
Throwing a SQL Syntax Error. If you want to avoid this behavour in some pieces of your SQL code you can replace " = ?" by " = ( ? )"to disable the smart replacement of this binding if null.
Ax.db.execute("DROP TABLE IF EXISTS t1_test"); Ax.db.execute("CREATE TEMP TABLE t1_test( col1 SMALLINT, col2 SMALLINT)"); Ax.db.insert("t1", [{col1:1,col2:1},{col1:null,col2:2}]); m_valcol1 = null; m_valcol2 = 1; Ax.db.execute(`UPDATE t1 SET col1 = (?) WHERE col2 = ?`, m_valcol1, m_valcol2);
4 Select statement
The select statement may produce two types of return values:
- A
ResultSet
, when number of rows are undetermined. - A JSON object, when one and only one row is returned.
4.1 Getting a ResultSet
The response for a database query is a SQL ResultSet
is a set of rows, as well as metadata about the query such as the column names,
and the types and sizes of each column.
A ResultSet
is effectively a table. The ORDER BY clause can be used in a query to impose a certain sort condition on the rows.
Without that clause, there is no guarantee whatsoever on the order in which the rows are returned.
The ResultSet
object implements the Iterable interface so it can be interated using Javascript for ... of
statement.
<script> Ax.db.execute('DROP TABLE IF EXISTS cars'); Ax.db.execute(`CREATE TABLE cars( seqno SERIAL NOT NULL, model VARCHAR(25), mpg FLOAT, cylinders INT, displacement FLOAT, horsepower INT, weight INT, acceleration FLOAT, year INT, origin VARCHAR(10), PRIMARY KEY (seqno) );`); var rows = [ { model: "chevrolet chevelle malibu", mpg:18, cylinders:8, displacement:307, horsepower:130, weight:3504, acceleration:12, year:70, origin: "US", }, { model: "buick skylark 320", mpg:15, cylinders:8, displacement:350, horsepower:165, weight:3693, acceleration:11.5, year:70, origin: "US", }, { model: "plymouth satellite", mpg:18, cylinders:8, displacement:318, horsepower:150, weight:3436, acceleration:11, year:70, origin: "US", }, { model: "amc rebel sst", mpg:16, cylinders:8, displacement:304, horsepower:150, weight:3433, acceleration:12, year:70, origin: "US", } ]; Ax.db.insert("cars", rows); var rs_cars = Ax.db.executeQuery("SELECT * FROM cars"); for (var row of rs_cars) { console.log(row); } rs_cars.close(); Ax.db.execute('DROP TABLE cars'); </script>
{cylynders=null, acceleration=11.5, seqno=2, horsepower=165, mpg=15, year=70, origin=US, weight=3693, model=buick skylark 320, displacement=350}
{cylynders=null, acceleration=11, seqno=3, horsepower=150, mpg=18, year=70, origin=US, weight=3436, model=plymouth satellite, displacement=318}
{cylynders=null, acceleration=12, seqno=4, horsepower=150, mpg=16, year=70, origin=US, weight=3433, model=amc rebel sst, displacement=304}
4.2 Getting one JSON object
Some times we want a single object so we would like to avoid the need to iterate the ResultSet
to get it.
Usually, using toOne() method is enough as it returns a ResultSetRowMap
class that is almost similar to a JSON Object,
but if you require a string JSON representation (for example to return it into a REST API), you can convert it by using toJSON() method.
Ax.db.execute('DROP TABLE IF EXISTS cars'); Ax.db.execute(`CREATE TABLE cars( seqno SERIAL NOT NULL, model VARCHAR(25), mpg FLOAT, cylinders INT, displacement FLOAT, horsepower INT, weight INT, acceleration FLOAT, year INT, origin VARCHAR(10), PRIMARY KEY (seqno) );`); var rows = [ { model: "chevrolet chevelle malibu", mpg:18, cylinders:8, displacement:307, horsepower:130, weight:3504, acceleration:12, year:70, origin: "US", }, { model: "buick skylark 320", mpg:15, cylinders:8, displacement:350, horsepower:165, weight:3693, acceleration:11.5, year:70, origin: "US", }, { model: "plymouth satellite", mpg:18, cylinders:8, displacement:318, horsepower:150, weight:3436, acceleration:11, year:70, origin: "US", }, { model: "amc rebel sst", mpg:16, cylinders:8, displacement:304, horsepower:150, weight:3433, acceleration:12, year:70, origin: "US", } ]; Ax.db.insert("cars", rows); let rs = Ax.db.executeQuery("SELECT * FROM cars WHERE seqno = 2"); var row = rs.toOne(); console.log(typeof(row)); console.log(row); var json = row.toJSON(); console.log(typeof(json)); console.log(json); rs.close(); Ax.db.execute('DROP TABLE cars');
object
{cylynders=null, acceleration=11.5, seqno=2, horsepower=165, mpg=15, year=70, origin=US, weight=3693, model=buick skylark 320, displacement=350}
string
{cylynders=null, acceleration=11.5, seqno=2, horsepower=165, mpg=15, year=70, origin=US, weight=3693, model=buick skylark 320, displacement=350}
If SQL statement returns more than one row it will fail with an SQLException as only one row is expected.
Error description returned by toOne() method is "A subquery has returned more than one row" by default. You can configure the error message returned in case more than one row are present in Resultset when executing toOne() just passing message description as a parameter.
try { Ax.db.executeQuery(`SELECT * FROM systables`).toOne(`systables duplicated`); } catch(Err) { console.log(Err.message); }
systables duplicated
4.2.1 Ensuring row exists
If no row exists an empty JSON object is returned. But in many cases we would like to stop an application if some required data is missing.
You can use the setRequired(message)
function to fire an exception is no row is found.
Ax.db.execute('DROP TABLE IF EXISTS cars'); Ax.db.execute(`CREATE TABLE cars( seqno SERIAL NOT NULL, model VARCHAR(25), mpg FLOAT, cylinders INT, displacement FLOAT, horsepower INT, weight INT, acceleration FLOAT, year INT, origin VARCHAR(10), PRIMARY KEY (seqno) );`); var rows = [ { model: "chevrolet chevelle malibu", mpg:18, cylinders:8, displacement:307, horsepower:130, weight:3504, acceleration:12, year:70, origin: "US", }, { model: "buick skylark 320", mpg:15, cylinders:8, displacement:350, horsepower:165, weight:3693, acceleration:11.5, year:70, origin: "US", }, { model: "plymouth satellite", mpg:18, cylinders:8, displacement:318, horsepower:150, weight:3436, acceleration:11, year:70, origin: "US", }, { model: "amc rebel sst", mpg:16, cylinders:8, displacement:304, horsepower:150, weight:3433, acceleration:12, year:70, origin: "US", } ]; Ax.db.insert("cars", rows); let rs = Ax.db.executeQuery("SELECT * FROM cars WHERE seqno = 99"); var row = rs.toOne().setRequired("No car found"); Ax.db.execute('DROP TABLE cars');
java.sql.SQLException: No car found
4.3 Getting a single value
To get a single column like when we want to select a COUNT(*) we can use a fastest way
avoiding either the need of a ResultSet
nor the JSON object. We will get only a single
value from a single row.
<script> Ax.db.execute('DROP TABLE IF EXISTS cars'); Ax.db.execute(`CREATE TABLE cars( seqno SERIAL NOT NULL, model VARCHAR(25), mpg FLOAT, cylinders INT, displacement FLOAT, horsepower INT, weight INT, acceleration FLOAT, year INT, origin VARCHAR(10), PRIMARY KEY (seqno) );`); var rows = [ { model: "chevrolet chevelle malibu", mpg:18, cylinders:8, displacement:307, horsepower:130, weight:3504, acceleration:12, year:70, origin: "US", }, { model: "buick skylark 320", mpg:15, cylinders:8, displacement:350, horsepower:165, weight:3693, acceleration:11.5, year:70, origin: "US", }, { model: "plymouth satellite", mpg:18, cylinders:8, displacement:318, horsepower:150, weight:3436, acceleration:11, year:70, origin: "US", }, { model: "amc rebel sst", mpg:16, cylinders:8, displacement:304, horsepower:150, weight:3433, acceleration:12, year:70, origin: "US", } ]; Ax.db.insert("cars", rows); var count = Ax.db.executeGet("SELECT COUNT(*) FROM cars"); console.log("count is " + count); Ax.db.execute('DROP TABLE cars'); </script>
count is 3
If SQL statement contains more than one column or returns more than one row it will fail with an SQLException.
4.4 Escape strings to prevent SQL Injection
To avoid SQL Injection if you don't use prepared statements and embed variable content directly inside SQL Statement, you should escape this string to avoid SQL Injection.
var str_tabname = "' OR 1=1; --"; var sqlstmt = `SELECT * FROM systables WHERE tabname = '${Ax.db.escape(str_tabname)}'`; var tab = Ax.db.executeQuery(sqlstmt).toOne(); console.log(tab);
{}
5 Database ResultSets
You can perform database querys by using the executeQuery
method. This method returns
a ResultSet
object.
A ResultSet
object maintains a cursor pointing to its current row of data. Initially the cursor
is positioned before the first row. The next method moves the cursor to the next row, and because
it returns false when there are no more rows in the ResultSet
object, it can be used in a while
loop to iterate through the result set.
ResultSet
object is iterable so it can be travesed using the for
or for each
statement.
On each iteration, next row fetched is returned as a JSON object.
5.1 ResultSet close
Database resultsets consume database resources while open. Application will automatically
take care of ResultSet
close when:
- After a call to next() with no results, if
ResultSet
is forward only it will be automatically closed. - Affer a call to toMemory(),
ResultSet
is converted to MemoryResultSet
and original database cursor is closed. - Affer
ResultSet
iteration, ifResultSet
is forward only it will be automatically closed. - At the end of the script, all
ResultSet
still open will be closed. A warning message will be shown in server console.
Even so, you should better take care of closing a ResultSet
when it's no loger used.
<script> var rs = Ax.db.executeQuery(`SELECT tabname FROM systables`); for (var syst of rs) { console.log("ROW=" + rs.getRow() + " TABNAME=" + syst.tabname); if (rs.getRow() == 3) { // Breaking cursor iteration. // ResultSet is not going to be consumed, so we need to close it explicitely. rs.close(); break; } } </script>
Not closing open resultset statements can also derive into error "Can not re-use statement while cursor open". Ensure you close all resultset statements after using them.
var rs = Ax.db.executeQuery(`SELECT tabid FROM systables`); for (var syst of rs) { var rs_cols = Ax.db.executeQuery(`SELECT * FROM syscolumns WHERE tabid = ?`, syst.tabid); for (var sysc of rs_cols) { // Exit on first row to force not consuming all cursor statement break; } // rs_cols is not fully consumed, so we need to close it explicitly // to avoid "Can not re-use statement while cursor open" error if (!rs_cols.isClosed()) { rs_cols.close(); } } rs.close();
5.2 ResultSet holdabiliy
Result set holdability is the ability to specify whether cursors (or a result set as java.sql.ResultSet
objects)
should be held open or closed at the end of a transaction. A holdable cursor, or result set, is one that does not
automatically close when the transaction that contains the cursor is committed.
By default javascript ResultSets are holdable, so they survive a transaction commit or rollback.
5.3 ResultSetRowMap object
When iterating a ResultSet
you will get a map of type ResultSetRowMap
. This object has some
extensions that are very useful.
Return | Method | Description |
---|---|---|
String | toJSON() | Returns the JSON representation of this object. |
boolean | hasChanged() | Returns true if map has been changed. |
ResultSetRowMap
|
getChanged() | Returns a new ResultSetRowMap with values that have changed since last call. |
ResultSetRowMap
|
setNotFound(String msg) | Throws an exception with given message it map contains no data (isNotFound()). Otherwise returns the map itself |
boolean | isNotFound() | Returns true if map contains no data as a result of a query with no results. Map may still contain all column keys but all are null. |
5.3.1 ResultSet iteration
During iteration, the object returned is a map of type ResultSetRowMap
var rs = Ax.db.executeQuery("SELECT tabname, created FROM systables WHERE tabid < 3"); for each (var row in rs) { // row is a JSON object with database row data console.log(row) }
{
"tabname": "systables",
"created": "2020-05-08"
}
{
"tabname": "syscolumns",
"created": "2020-05-08"
}
5.3.2 Returning a single row object
ResultSet
obtained by executing Ax.db.executeQuery provides some methods to obtain a single row or single value from cursor returned.
Depending method used, it can control if only one row is selected if at least one row is selected or return first row selected.
All this functions return an ResultSetRowMap
object with row data and implements isNotFound() method to know if some data has been returned by ResultSet
or not
Return single row
The method toOne()
ensures data contains 0 or 1 row only.
If more that one rows are returned, the statement will fail with an exception.
var m_systables = Ax.db.executeQuery(`SELECT * FROM systables where tabname = ?`, 'systables').toOne(); console.log("notfound:" + m_systables.isNotFound()); var m_systables = Ax.db.executeQuery(`SELECT * FROM systables where tabname = ?`, 'XXX').toOne(); console.log("notfound:" + m_systables.isNotFound());
notfound:false
notfound:true
Notice that the JavaScript object returned (a Map) contains an special function to determine is row has been found. And that when no data is found, the object contains all columns with null values.
Return first Row
The method firstOne()
returns first row of ResultSet
, whenever number of rows is contained by ResultSet
.
var m_systables = Ax.db.executeQuery(`SELECT * FROM systables where tabname like 'sys%'`).firstOne(); console.log("data:" + m_systables); console.log("notfound:" + m_systables.isNotFound());
notfound:false
notfound:true
Notice that the JavaScript object returned (a Map) contains an special function to determine is row has been found. And that when no data is found, the object contains all columns with null values.
Automatic fail if notfound
In some cases, we need a database rows exists to continue application. If row
does not exists we should stop application as it's a failure. We can automatically
setup this controls by using setRequired(message)
method.
For example, if you some data is required and application can't continue without it, you can use this method to prevent that situations.
<script> var m_tabname = "UndefinedTable"; // This call will fail with given message if no data is found var m_row = Ax.db .executeQuery('SELECT * FROM systables WHERE tabname = ?', m_tabname) .toOne() .setRequired(`Table ${m_tabname} not found.`); </script>
java.sql.SQLException: Table UndefinedTable not found.
at deister.axional.server.jdbc.resultset.iterator.ResultSetRowMap.setRequired(ResultSetRowMap.java:172)
...
5.3.3 Determine if values changed
You can select a tuple from a database using a ResultSetRowMap
, update some values
and automatically determine which values changed using getChanged()
to generate
a new map with them to be used to perform a database update.
<script> Ax.db.execute("DROP TABLE IF EXISTS t1"); Ax.db.execute("CREATE TABLE t1(a smallint, b varchar(10), c integer)"); Ax.db.execute("INSERT INTO t1 VALUES(1, 'Animal', 5000)"); Ax.db.execute("INSERT INTO t1 VALUES(2, 'Vegetal', 6000)"); var row = Ax.db.executeQuery("SELECT * FROM t1 WHERE a = 1").toOne(); console.log("--- ROW ---"); console.log(row); console.log("--- ROW CHANGED ---"); row["c"] = 9000; console.log(row.hasChanged()); console.log(row.getChanged()); console.log("--- ROW UPDATE ---"); Ax.db.update("t1", row.getChanged(), "a=1"); var rs = Ax.db.executeQuery("SELECT * FROM t1 ORDER BY a"); console.log(rs); rs.close(); Ax.db.execute('DROP TABLE t1'); </script>
--- ROW ---
{
"a": 1,
"b": "Animal",
"c": 5000,
"d": 5000
}
--- ROW CHANGED ---
true
{
"c": 9000
}
--- TYPE CHANGED AND VALUE NOT CHANGED: ROW NOT CHANGED ---
false
--- ROW UPDATE ---
+--------+-----------+--------+----------+
|t1 |t1 |t1 |t1 |
|a |b |c |d |
|smallint|varchar(10)|smallint|int |
+--------+-----------+--------+----------+
|1 |Animal |9000 |5000 |
|2 |Vegetal |6000 |6000 |
+--------+-----------+--------+----------+
5.4 Getting Rows from ResultSet
The easiest way to get a row from a ResultSet
is to get a ResultsetRowMap object.
5.4.1 Traversing using next
As we have seen, a ResultSet
is converted to ResultsetRowMap on every iteration using toRow
.
<script> var rs = Ax.db.executeQuery("SELECT COUNT(*) count FROM systables"); if (rs.next()) { console.log(rs.toRow()); } rs.close(); </script>
{count=92}
5.4.2 Traversing using iterator
Using an iterator is more easy. The variable row
is a ResultsetRowMap.
<script> var rs = Ax.db.executeQuery("SELECT COUNT(*) count FROM systables"); for (var row of rs) { console.log(row); } </script>
{count=92}
5.4.3 Converting to single row
If we know a query will return only one value we can avoid loop iteration and use direct row to ResultsetRowMap conversion.
<script> var rs = Ax.db.executeQuery("SELECT COUNT(*) count FROM systables"); console.log(rs.toOne()); rs.close(); </script>
{count=92}
5.5 ResultSet using Cursor for Update
The purpose of the FOR UPDATE in a cursor ResultSet
is to let the database server know that the program can update (or delete) any row that it fetches.
The database server places a more demanding lock on rows that are fetched through an update cursor and a less demanding lock when it fetches a row
for a cursor that is not declared with that keyword. This action results in better performance for ordinary cursors and a higher level of concurrent use in a multiprocessing system.
To declare a ResultSet
(Cursor) for update you need to add the "FOR UPDATE" keyword at the end of the SELECT statement and to use the special method executeQueryForUpdate to declare
the cursor.
RESTRICTIONS:
A SELECT statement that includes the FOR UPDATE clause must conform to the following restrictions:
- The statement can select data from only one table.
- The statement cannot include any aggregate functions.
- The statement cannot include any of the following clauses or keywords: DISTINCT, EXCEPT, FOR READ ONLY, GROUP BY, INTO TEMP, INTERSECT, INTO EXTERNAL, MINUS, ORDER BY, UNION, UNIQUE.
Ax.db.execute(`DROP TABLE IF EXISTS test_concurrency`); Ax.db.execute(`CREATE TEMP TABLE test_concurrency(codigo CHAR(10), estado SMALLINT)`); Ax.db.execute(`INSERT INTO test_concurrency VALUES('A', 0)`); Ax.db.execute(`INSERT INTO test_concurrency VALUES('B', 0)`); var sql = "SELECT rowid, * FROM test_concurrency WHERE estado = 0 FOR UPDATE"; var rs1 = Ax.db.executeQueryForUpdate(sql); /** * PROCESS EVERY ROW, MARKING ESTADO AS SOON AS ROW IF BEING TAKEN TO AVOID * A SECOND PROCESS RELOADS IT. */ for (var row of rs1) { /** * Update the row immediately to avoid other thread takes it * using the update and updateRow clauses. */ rs1.update("estado", 1); rs1.updateRow() // Update current row in cursor // rs1.deleteRow() // Use this method to delete the current row in cursor } rs1.close(); return Ax.db.executeQuery(`SELECT * FROM test_concurrency`);
You cannot use transaction control methods like begin or commit work inside a cursor declared "for update". Creating explicit transactions inside this kind of cursor resultsets will nake your program fail as described at https://stackoverflow.com/questions/32016494/informix-jbdc-hold-cursors-over-commit
En theory, holdable cursors for update are only supported by Informix as described at https://4js.com/online_documentation/fjs-fgl-2.50.02-manual-html/c_fgl_sql_programming_078.html
6 Pivot ResultSet
ResultSet
has a pivot(<Options>) method that allows to pivot or transpose row values from defined columns into resultset columns dynamically.
You can use methods in "options" to configure how the pivot method should work:
Method | Description |
---|---|
setPivotColumnNames(Array<String>) | Receive and array of resultset column names. The values for this column will be used to pivot and create as many columns as values are found in this column. |
setClearGroups(Boolean) | If executed with true, all row columns with repated values are cleared and showed as "null". This tries to emulate grouped columns in reports. |
setHasMeasuresInRows(Boolean) | Creates a virtual column "Measures" and show for each row the "measured value" corresponding to each row. This is only interesting if you define multiple columns for measures. In this case, this method will control if each measure column is show as a row or all measured values are expanded as columns or an individual row. |
setColumnPrefix(String) | The column name is created by default with pivot column values. You can use this method to prepend a text to the column name. |
var rs = Ax.db.executeScrollableQuery(`SELECT FIRST 8 tabid, colname, coltype, "*" typemark FROM syscolumns WHERE coltype BETWEEN 0 and 256 ORDER BY 1 ASC, 2`); console.log("Resulset:"); console.log(rs); var rsp = rs.pivot(options => { options.setPivotColumnNames(['coltype']); options.setMeasureColumnNames(['typemark']); options.setMeasureColumnLabels(['Value']); options.setPivotSort({"coltype":"ASC"}); options.setClearGroups(false); options.setGroupMeasures(false); options.setHasMeasuresInRows(false); options.setColumnPrefix("prefix_"); }); console.log("Pivot ResultSet:"); console.log(rsp);
Resulset:
+----------+------------+----------+----------+
|syscolumns|syscolumns |syscolumns|syscolumns|
|tabid |colname |coltype |typemark |
|int |varchar(128)|smallint |char(1) |
+----------+------------+----------+----------+
|1 |am_id |2 |* |
|1 |created |7 |* |
|1 |dbname |13 |* |
|1 |fextsize |2 |* |
|1 |flags |1 |* |
|1 |locklevel |0 |* |
|1 |ncols |1 |* |
|1 |nextsize |2 |* |
+----------+------------+----------+----------+
Pivot ResultSet:
+-------+---------+--------+--------+--------+--------+--------+
|<null> |<null> |<null> |<null> |<null> |<null> |<null> |
|tabid |colname |prefix_5|prefix_4|prefix_1|prefix_2|prefix_3|
|tabid |colname |0 |1 |2 |7 |13 |
|integer|char(0) |Value |Value |Value |Value |Value |
| | |char(0) |char(0) |char(0) |char(0) |char(0) |
+-------+---------+--------+--------+--------+--------+--------+
|1 |am_id | | |* | | |
|1 |created | | | |* | |
|1 |dbname | | | | |* |
|1 |fextsize | | |* | | |
|1 |flags | |* | | | |
|1 |locklevel|* | | | | |
|1 |ncols | |* | | | |
|1 |nextsize | | |* | | |
+-------+---------+--------+--------+--------+--------+--------+
We use Ax.db.executeScrollableQuery because we show the Resultset twice before and after using Pivot to print with console.log(), the normal thing is to use Ax.db.executeQuery.
Example showing Cursor Iterator SPL Function usage to fill date gaps
/** * Create cursor iterator SPL */ Ax.db.execute(`CREATE OR REPLACE FUNCTION function_iterator_date( p_start_date date, p_end_date date) RETURNING DATE; DEFINE m_date date; DEFINE m_cont integer; LET m_date = p_start_date; WHILE 1=1 IF (m_date > p_end_date) THEN EXIT WHILE; END IF; RETURN m_date WITH RESUME; LET m_date = m_date + 1; END WHILE; END FUNCTION`); /** * Create temp table */ Ax.db.execute(`DROP TABLE IF EXISTS test1`); Ax.db.execute(` create temp table test1( banco char(10), fecha date, importe integer );`); Ax.db.execute(`insert into test1 values("BBVA", TODAY , 100);`); Ax.db.execute(`insert into test1 values("BBVA", TODAY +1, 200);`); Ax.db.execute(`insert into test1 values("BBVA", TODAY +3, 300);`); Ax.db.execute(`insert into test1 values("BBVA", TODAY +6, 820);`); Ax.db.execute(`insert into test1 values("BBVA", TODAY +8, 430);`); Ax.db.execute(`insert into test1 values("BCP", TODAY , 100);`); Ax.db.execute(`insert into test1 values("BCP", TODAY +6, 820);`); console.log("Table test1:"); console.log(Ax.db.executeQuery(`SELECT * FROM test1 ORDER BY 1, 2`)); /** * Resultset using iterator SPL */ var rs = Ax.db.executeQuery(` SELECT banco, vtable.fecha_pivot AS fecha_pivot, -- This CASE WHEN avoids value duplication due to cartesian product CASE WHEN vtable.fecha_pivot = fecha THEN importe ELSE 0 END importe FROM test1, TABLE(function_iterator_date(TODAY - 1, TODAY + 10)) AS vtable(fecha_pivot) ORDER BY 1, 2`).toMemory(); console.log("Resultset using iterator SPL"); console.log(rs); /** * Pivot ResultSet */ var rs_pivot = rs.pivot(options => { options.setPivotColumnNames(['fecha_pivot']); options.setMeasureColumnNames(['importe']); options.setMeasureColumnLabels(['']); options.setPivotSort({"fecha_pivot":"ASC"}); }); console.log("Resultset Pivot:"); console.log(rs_pivot);
6.1 Pivot and transform into report with totals
Transform the pivot into a report and add the totals by column.
/** * Create temp table */ Ax.db.execute(`DROP TABLE IF EXISTS test1`); Ax.db.execute(` create temp table test1( banco char(10), fecha date, importe integer );`); Ax.db.execute(`insert into test1 values("BBVA", TODAY , 100);`); Ax.db.execute(`insert into test1 values("BBVA", TODAY +1, 200);`); Ax.db.execute(`insert into test1 values("BBVA", TODAY +3, 300);`); Ax.db.execute(`insert into test1 values("BBVA", TODAY +6, 820);`); Ax.db.execute(`insert into test1 values("BBVA", TODAY +8, 430);`); Ax.db.execute(`insert into test1 values("BCP", TODAY , 100);`); Ax.db.execute(`insert into test1 values("BCP", TODAY +6, 820);`); console.log("Table test1:"); console.log(Ax.db.executeQuery(`SELECT * FROM test1 ORDER BY 1, 2`)); /** * Resultset with stretches for 3 days */ var mDiasEnTramo = 3; var rs = Ax.db.executeQuery(` SELECT banco, fecha - MOD((fecha - TODAY), ${mDiasEnTramo}) || " : " || fecha - MOD((fecha - TODAY), ${mDiasEnTramo}) + ${mDiasEnTramo} - 1 AS fecha_pivot, importe FROM test1 ORDER BY 1, 2`).toMemory(); console.log("Resultset with stretches for 3 days:"); console.log(rs); /** * Pivot ResultSet */ var rs_pivot = rs.pivot(options => { options.setPivotColumnNames(['fecha_pivot']); options.setMeasureColumnNames(['importe']); options.setMeasureColumnLabels(['']); options.setPivotSort({"fecha_pivot":"ASC"}); }); console.log("Resultset Pivot:"); console.log(rs_pivot); /** * Transform to report to add totals */ var rs_report = new Ax.rs.Report(rs_pivot); /** * Add totals to pivot measure columns produced by pivot on "importe" measure */ var measureColumns = rs_pivot.getPivotResultSetMetaData().getPivotMeasureColumns()["importe"]; for (var measureColumn of measureColumns) { rs_report.setTotalBy(measureColumn, "SUM"); } /** * Pivot converted to report with totals */ console.log("PIVOT REPORT WITH TOTALS:"); console.log(rs_report);
Table test1:
+----------+----------+----------+
|test1 |test1 |test1 |
|banco |fecha |importe |
|char(10) |date |int |
+----------+----------+----------+
|BBVA |08-25-2022|100 |
|BBVA |08-26-2022|200 |
|BBVA |08-28-2022|300 |
|BBVA |08-31-2022|820 |
|BBVA |09-02-2022|430 |
|BCP |08-25-2022|100 |
|BCP |08-31-2022|820 |
+----------+----------+----------+
Resultset with stretches for 3 days:
+--------+-----------------------+-------+
|test1 |test1 |test1 |
|banco |fecha_pivot |importe|
|char(10)|varchar(83) |int |
+--------+-----------------------+-------+
|BBVA |25-08-2022 : 27-08-2022|100 |
|BBVA |25-08-2022 : 27-08-2022|200 |
|BBVA |28-08-2022 : 30-08-2022|300 |
|BBVA |31-08-2022 : 02-09-2022|820 |
|BBVA |31-08-2022 : 02-09-2022|430 |
|BCP |25-08-2022 : 27-08-2022|100 |
|BCP |31-08-2022 : 02-09-2022|820 |
+--------+-----------------------+-------+
Resultset Pivot:
+-------+----------+----------+----------+
|<null> |<null> |<null> |<null> |
|banco |c1 |c2 |c3 |
|banco |25-08-2022|28-08-2022|31-08-2022|
|char(0)|: 27-08-20|: 30-08-20|: 02-09-20|
| |22 |22 |22 |
| |integer |integer |integer |
+-------+----------+----------+----------+
|BBVA |300 |300 |1,250 |
|BCP |100 | |820 |
+-------+----------+----------+----------+
PIVOT REPORT WITH TOTALS:
+-------+-------+-------+-------+
|banco |c1 |c2 |c3 |
|char(0)|integer|integer|integer|
+-------+-------+-------+-------+
|BBVA |300 |300 |1,250 |
|BCP |100 | |820 |
|SUM |400 |300 |2,070 |
+-------+-------+-------+-------+
6.2 Force Pivot Column Values
/** * Prepare Pivot Values and Create temp table */ var cur_date = new Ax.util.Date(); var axis_values = [] for (x = 1; x < 10; x++) { axis_values.push(new Ax.sql.Date(cur_date.getTime())); cur_date = cur_date.addDay(1); } console.log("Pivot Column Values"); console.log(axis_values); Ax.db.execute(`DROP TABLE IF EXISTS test1`); Ax.db.execute(` create temp table test1( banco char(10), fecha date, importe integer );`); Ax.db.execute(`insert into test1 values("BBVA", TODAY , 100);`); Ax.db.execute(`insert into test1 values("BBVA", TODAY +1, 200);`); Ax.db.execute(`insert into test1 values("BBVA", TODAY +3, 300);`); Ax.db.execute(`insert into test1 values("BBVA", TODAY +6, 820);`); Ax.db.execute(`insert into test1 values("BBVA", TODAY +8, 430);`); Ax.db.execute(`insert into test1 values("BCP", TODAY , 100);`); Ax.db.execute(`insert into test1 values("BCP", TODAY +6, 820);`); /** * Resultset to Pivot */ var rs = Ax.db.executeQuery(` SELECT banco, fecha AS fecha_pivot, importe FROM test1 ORDER BY 2`).toMemory(); /* +-------+----------+----------+----------+----------+----------+ |<null> |<null> |<null> |<null> |<null> |<null> | |banco |c1 |c2 |c3 |c4 |c5 | |banco |2022-09-05|2022-09-06|2022-09-08|2022-09-11|2022-09-13| |char(0)|integer |integer |integer |integer |integer | +-------+----------+----------+----------+----------+----------+ |BBVA |100 |200 |300 |820 |430 | |BCP |100 | | |820 | | +-------+----------+----------+----------+----------+----------+ */ console.log("Original Resultset"); console.log(rs); /** * Pivot ResultSet */ var rs_pivot = rs.pivot(options => { options.setPivotColumnNames(['fecha_pivot']); options.setPivotColumnValues('fecha_pivot', axis_values); options.setMeasureColumnNames(['importe']); options.setMeasureColumnLabels(['']); options.setPivotSort({"fecha_pivot":"ASC"}); }); console.log("Resultset Pivot:"); console.log(rs_pivot); /** * Show pivot debug */ console.log(rs_pivot.getPivotResultSetMetaData().getLog());
Next example shows a pivot of multiple columns, setting default values for each of the column pivot axis:
/** * Prepare Pivot Values and Create temp table */ var cur_date = new Ax.util.Date(); var axis_values_date = [] var axis_values_city = ['Barcelona', 'Valencia', 'Toledo'] for (x = 1; x < 8; x++) { axis_values_date.push(new Ax.sql.Date(cur_date.getTime())); cur_date = cur_date.addDay(1); } console.log("Pivot Column Values"); console.log(axis_values_date); Ax.db.execute(`DROP TABLE IF EXISTS test1`); Ax.db.execute(` create temp table test1( banco char(10), city varchar(15), fecha date, importe integer );`); Ax.db.execute(`insert into test1 values("BBVA", 'Barcelona', TODAY , 100);`); Ax.db.execute(`insert into test1 values("BBVA", 'Barcelona', TODAY +1, 200);`); Ax.db.execute(`insert into test1 values("BBVA", 'Toledo', TODAY +3, 300);`); Ax.db.execute(`insert into test1 values("BBVA", 'Barcelona', TODAY +6, 820);`); Ax.db.execute(`insert into test1 values("BCP", 'Toledo', TODAY , 100);`); Ax.db.execute(`insert into test1 values("BCP", 'Barcelona', TODAY +6, 820);`); /** * Resultset to Pivot */ var rs = Ax.db.executeQuery(` SELECT banco, city, fecha AS fecha_pivot, importe FROM test1 ORDER BY 2`).toMemory(); console.log("Original Resultset"); console.log(rs); /** * Pivot ResultSet */ var rs_pivot = rs.pivot(options => { options.setPivotColumnNames(['fecha_pivot', 'city']); options.setPivotColumnValues('fecha_pivot', axis_values_date); options.setPivotColumnValues('city', axis_values_city); options.setMeasureColumnNames(['importe']); options.setMeasureColumnLabels(['']); options.setPivotSort({"city" : "ASC", "fecha_pivot":"ASC"}); }); console.log("Resultset Pivot:"); console.log(rs_pivot); /** * Show pivot debug */ console.log(rs_pivot.getPivotResultSetMetaData().getLog());
6.3 Explore Pivot metadata
Explore metadata and debug of pivot of preview example.
/** * Create temp table */ Ax.db.execute(`DROP TABLE IF EXISTS test1`); Ax.db.execute(` create temp table test1( banco char(10), fecha date, importe integer );`); Ax.db.execute(`insert into test1 values("BBVA", TODAY , 100);`); Ax.db.execute(`insert into test1 values("BBVA", TODAY +1, 200);`); Ax.db.execute(`insert into test1 values("BBVA", TODAY +3, 300);`); Ax.db.execute(`insert into test1 values("BBVA", TODAY +6, 820);`); Ax.db.execute(`insert into test1 values("BBVA", TODAY +8, 430);`); Ax.db.execute(`insert into test1 values("BCP", TODAY , 100);`); Ax.db.execute(`insert into test1 values("BCP", TODAY +6, 820);`); /** * Resultset with stretches for 3 days */ var mDiasEnTramo = 3; var rs = Ax.db.executeQuery(` SELECT banco, fecha - MOD((fecha - TODAY), ${mDiasEnTramo}) || " : " || fecha - MOD((fecha - TODAY), ${mDiasEnTramo}) + ${mDiasEnTramo} - 1 AS fecha_pivot, importe FROM test1 ORDER BY 1, 2`).toMemory(); /** * Pivot ResultSet */ var rs_pivot = rs.pivot(options => { options.setPivotColumnNames(['fecha_pivot']); options.setMeasureColumnNames(['importe']); options.setMeasureColumnLabels(['']); options.setPivotSort({"fecha_pivot":"ASC"}); }); /** * Explore pivot metadata */ console.log("- PIVOT METADATA:"); console.log(rs_pivot.getPivotResultSetMetaData()); console.log("- PIVOT GROUP LENGTH:"); console.log(rs_pivot.getPivotResultSetMetaData().getPivotGroupLength()); console.log("- PIVOT MEASURE NAMES:"); console.log(rs_pivot.getPivotResultSetMetaData().getPivotMeasureNames()); console.log("- PIVOT MEASURE COLUMS:"); console.log(rs_pivot.getPivotResultSetMetaData().getPivotMeasureColumns()); console.log("- PIVOT COLUMN NAMES:"); console.log(rs_pivot.getPivotResultSetMetaData().getPivotColumnNames()); console.log("- PIVOT COLUMN TYPES:"); console.log(rs_pivot.getPivotResultSetMetaData().getPivotColumnTypes()); /** * Show pivot debug */ console.log("- PIVOT DEBUG:"); console.log(rs_pivot.getPivotResultSetMetaData().getLog());
- PIVOT METADATA:
SQLResultSetPivotMetaData[groupSize=1, columnNames=[12], columnTypes=[fecha_pivot], measureNames=[importe], measureColumns={importe=[c1, c2, c3]}]
- PIVOT GROUP LENGTH:
1
- PIVOT MEASURE NAMES:
[importe]
- PIVOT MEASURE COLUMS:
{
"importe": [
"c1",
"c2",
"c3"
]
}
- PIVOT COLUMN NAMES:
[fecha_pivot]
- PIVOT COLUMN TYPES:
[12]
- PIVOT DEBUG:
<!-- ================================================= BEGIN pivot -->
<function='pivot' class='deister.axional.server.jdbc.resultset.memory.pivot.Pivot' file='Pivot.java' line='158'>
<arguments>
<element attr='column names'>[fecha_pivot]</element>
<element attr='measure names'>[importe]</element>
<element attr='measure labels'>[]</element>
<element attr='hasMeasuresInRows'>false</element>
<element attr='clearGroups'>false</element>
<element attr='groupMeasuresTogether'>false</element>
<element attr='pivotSort'>{fecha_pivot=ASC}</element>
</arguments>
<rowsdata info='pivot-input'>
+-----+-----------------------+-------+
|banco|fecha_pivot |importe|
+-----+-----------------------+-------+
|BBVA |25-08-2022 : 27-08-2022|100 |
|BBVA |25-08-2022 : 27-08-2022|200 |
|BBVA |28-08-2022 : 30-08-2022|300 |
|BBVA |31-08-2022 : 02-09-2022|820 |
|BBVA |31-08-2022 : 02-09-2022|430 |
|BCP |25-08-2022 : 27-08-2022|100 |
|BCP |31-08-2022 : 02-09-2022|820 |
+-----+-----------------------+-------+
</rowsdata>
<element attr='MetaData: colnames'>[banco]</element>
<element attr='MetaData: collabel'>[banco]</element>
<element attr='MetaData: coltypes'>[1]</element>
<element attr='MetaData: colhiden'>[false]</element>
<horizontal-sort>
<element attr='Measures at start'>false</element>
<element attr='Sorting on pivot levels'>[fecha_pivot]</element>
<element attr='Columns before sort'>[25-08-2022 : 27-08-2022_importe, 28-08-2022 : 30-08-2022_importe, 31-08-2022 : 02-09-2022_importe]</element>
<element attr='Sort row types'>[ASC]</element>
<adding-comparators>
<loopItem id='add-comparator'>0</loopItem>
</adding-comparators>
<sort-by-groups>
<foreach-column-pivot>
<loopItem id='column'>c1</loopItem>
<loopItem id='column'>c2</loopItem>
<info>Checking if prev measure (importe) == next measure (importe) result=true<info/>
<loopItem id='column'>c3</loopItem>
<info>Checking if prev measure (importe) == next measure (importe) result=true<info/>
</foreach-column-pivot>
<element attr='Post-Sorting (#=3)'>[25-08-2022 : 27-08-2022_importe, 28-08-2022 : 30-08-2022_importe, 31-08-2022 : 02-09-2022_importe]</element>
<info>Sorting[0] type[ASC] 28-08-2022 : 30-08-2022 25-08-2022 : 27-08-2022 EQ=3<info/>
<info>Sorting[0] type[ASC] 31-08-2022 : 02-09-2022 28-08-2022 : 30-08-2022 EQ=1<info/>
</sort-by-groups>
<info>Columns after sort [25-08-2022 : 27-08-2022_importe, 28-08-2022 : 30-08-2022_importe, 31-08-2022 : 02-09-2022_importe]<info/>
</horizontal-sort>
<foreach-column-pivot>
<loopItem id='column'>c1</loopItem>
<loopItem id='column'>c2</loopItem>
<loopItem id='column'>c3</loopItem>
</foreach-column-pivot>
<element attr='MetaData: colnames'>[banco, c1, c2, c3]</element>
<element attr='MetaData: collabel'>[banco, 25-08-2022 : 27-08-2022_, 28-08-2022 : 30-08-2022_, 31-08-2022 : 02-09-2022_]</element>
<element attr='MetaData: coltypes'>[1, 4, 4, 4]</element>
<element attr='MetaData: colhiden'>[false, false, false, false]</element>
<info>Processing (rows first), foreach row -> foreach measure<info/>
<element attr='Input resultset'>3 col(s), 7 row(s) [banco, fecha_pivot, importe]</element>
<element attr='Output resultset'>4 col(s), 2 row(s) [banco, c1, c2, c3]</element>
<ResultSetPivotData>
<element attr='PivotGroupLength'>1</element>
<element attr='PivotColumnNames'>[fecha_pivot]</element>
<element attr='PivotColumnTypes'>[12]</element>
<element attr='PivotMesaureNames'>[importe]</element>
<element attr='PivotMeasureColumns'>{importe=[c1, c2, c3]}</element>
</ResultSetPivotData>
<vertical-sort>
<loopItem id='Sort NOT applies to measure'>importe</loopItem>
</vertical-sort>
<store-dimensions-into-metadata>
<loopItem id='c1'>[25-08-2022 : 27-08-2022]</loopItem>
<loopItem id='c2'>[28-08-2022 : 30-08-2022]</loopItem>
<loopItem id='c3'>[31-08-2022 : 02-09-2022]</loopItem>
</store-dimensions-into-metadata>
<rowsdata info='pivot-output'>
+-----+---+---+-----+
|banco|c1 |c2 |c3 |
+-----+---+---+-----+
|BBVA |300|300|1,250|
|BCP |100| |820 |
+-----+---+---+-----+
</rowsdata>
</function>
<!-- ================================================= END pivot -->
7 ResultSet to HTML
To convert a resultset to HTML there are methods:
Return | Method | Description |
---|---|---|
String | {resultset}.toHTML() | Returns a string representation a conversion of resultset to HTML code |
toHTML() method requires rewindable cursor, so you're required to convert resultset to memory resultset before using this method.
function xx() { ... var rs = Ax.db.executeQuery(`SELECT FIRST 2 * FROM systables`).toMemory(); console.log(rs.toHTML(options => { options.setEmitFullHTML(false); //options.setEmitHeadHTML(true); //options.setEmitBodyHTML(true); options.setEmitGlobalStyles(false); options.setEmitGroupStyles(false); })); }
8 ResultSet to JSON
There are multiple methods to convert a ResultSet
to native Javascript representation:
Return | Method | Description |
---|---|---|
String | {resultset}.asJSON() | Returns a string representation of a conversion of the resultset to JSON Object |
Array | {resultset}.toJSONArray() | Returns the resultset as a Native JSON Object (Array of objects). |
Array | {resultset}.toArray() | Returns one Array of Arrays containing resultset row values |
Array | {resultset}.toArray(colname) | Returns one Array of the values of one column in the rows of the ResultSet
|
Object | {resultset}.toJSON() | Returns a JSON Object with an internal declaration of resultset structure and data. |
Object | {resultset}.toMapByKey(colname1, ...) | Returns a Object with keys from the values of the specified columns separated by ":". Each key maos ti an object representing the resultset row. |
All this methods do not close the resultset. Avoid return rs.asJSON(), rs.toJSONArray(), etc. in functions. Instead, get result into a variable, close resultset and then return variable.
function xx() { ... var result = rs.toJSON(); rs.close(); return result; }
8.1 Convert to ResultSet Representation: toJSON()
To obtain an String with Resultset Representation in JSON, you can use toJSON() method of JSResultSet
Class
var rs = Ax.db.executeQuery("SELECT FIRST 3 tabid, tabname FROM systables"); console.log(rs.toJSON()); rs.close();
{
"rows": [
[
1,
"systables"
],
[
2,
"syscolumns"
],
[
3,
"sysindices"
],
],
"cols": [
{
"columnName": "tabid",
"columnType": 4,
"columnIndex": 1,
"precision": 10,
"scale": 0,
"tableName": "systables",
"schemaName": "",
"catalogName": "",
"columnClassName": "java.lang.Integer",
"columnLabel": "tabid",
"columnTypeName": "serial",
"columnDisplaySize": 10,
"isAutoIncrement": true,
"isCaseSensitive": false,
"isCurrency": false,
"isReadOnly": false,
"isSearchable": true,
"isSigned": false,
"isWritable": true,
"isDefinitelyWritable": true,
"isNullable": 0,
},
{
"columnName": "tabname",
"columnType": 12,
"columnIndex": 2,
"precision": 128,
"scale": 0,
"tableName": "systables",
"schemaName": "",
...
}
],
"hasMore": false,
"title": null,
"attributes": null,
"hasMore": false
}
8.2 Convert to String in JSON Representation: asJSON()
Method asJSON() Convert a Resultset to a String with a JSON Object representation.
var rs = Ax.db.executeQuery("SELECT FIRST 3 tabid, tabname FROM systables"); var js = rs.asJSON(); console.log(typeof(js); console.log(js); rs.close();
string
[
{
"tabid": 1,
"tabname": "systables"
},
{
"tabid": 2,
"tabname": "syscolumns"
},
{
"tabid": 3,
"tabname": "sysindices"
}
]
8.3 Convert to native JSON Object (Array of objects)
Method toJSONArray() Convert a Resultset to a native JSON Object.
var rs = Ax.db.executeQuery("SELECT FIRST 3 tabid, tabname FROM systables"); var js = rs.toJSONArray(); console.log(typeof(js); console.log(js); rs.close();
object
[{
"tabid": 1,
"tabname": "systables"
}, {
"tabid": 2,
"tabname": "syscolumns"
}, {
"tabid": 3,
"tabname": "sysindices"
}]
8.4 Convert to Java (Array of Arrays)
Method toArray() Convert a Resultset to a Java Array Object.
var rs = Ax.db.executeQuery("SELECT FIRST 3 tabid, tabname FROM systables"); var js = rs.toArray(); console.log(typeof(js)); console.log(js); for (r = 0; r < js.length; r++) { console.log(`Row ${r}`); for (var c = 0; c < js[r].length; c++) { console.log(js[r][c]); } } rs.close();
object
[[Ljava.lang.Object;@34e04854, [Ljava.lang.Object;@53159100, [Ljava.lang.Object;@4c34c1ac]
Row 0
1
systables
Row 1
2
syscolumns
Row 2
3
sysindices
8.5 Convert to JS Object by Keys (Object of Objects)
Returns a Object with keys from the values of the specified columns separated by ":". Each key maos ti an object representing the resultset row.
Usage: this method can be used for creating memory caches referenced by a known key
var rs = Ax.db.executeQuery("SELECT FIRST 3 * FROM systables"); var js = rs.toMapByKey("tabid", "tabname"); for (var key in js) { console.log("==========================="); console.log("KEY: [" + key + "]"); console.log("---------------------------"); console.log(js[key]); } rs.close(); console.log(js[js.asKey(1, "systables")]);
9 ResultSet to PDF
Every ResultSet
can be converted automatically to Pdf and processed as an stream easily by using toPDF() method.
var rs = Ax.db.executeQuery("SELECT COUNT(*) count FROM systables"); new Ax.io.File("/tmp/resultset.pdf").write(rs.toPDF()); rs.close();
10 ResultSet to XML
<script> var rs = Ax.db.executeQuery("SELECT FIRST 3 tabid, tabname FROM systables"); var xml = "<sqlresponse>\n<rowset>\n"; for (let row of rs) { xml += " <r>\n"; for (obj in row) { xml += " <c>" + row[obj] + "</c>\n"; } xml += " </r>\n"; } xml += "</rowset>\n</sqlresponse>"; console.log(xml); </script>
<sqlresponse>
<rowset>
<r>
<c>1</c>
<c>systables</c>
</r>
<r>
<c>2</c>
<c>syscolumns</c>
</r>
<r>
<c>3</c>
<c>sysindices</c>
</r>
</rowset>
</sqlresponse>
11 ResultSet to CSV
<script> var rs = Ax.db.executeQuery("SELECT FIRST 3 tabid, tabname FROM systables"); var blob = new Ax.sql.Blob("csv_resultset.csv"); new Ax.rs.Writer(rs).csv(options => { options.setResource(blob); }); console.log(blob.getContent()); </script>
tabid,tabname
1,systables
2,syscolumns
3,sysindices
12 Memory ResultSets
You can generate virtual in memory resultsets and return them to client as as database resultset. This kind of resultset are very useful to perform data transformation prior returning them to client applications.
In the following example a ResultSet
with two columns is build and returned to client.
<script> function fibonacci(num) { if (num <= 1) return 1; return fibonacci(num - 1) + fibonacci(num - 2); } var rs = new Ax.rs.Reader().memory(options => { options.setColumnNames([ "number", "fibonacci" ]); options.setColumnTypes([ Ax.sql.Types.INTEGER, Ax.sql.Types.DOUBLE ]); }); for (var idx = 1; idx < 10; idx++) rs.rows().add([idx, fibonacci(idx)]); console.log(rs); // Iterate Memory cursor for each (var row in rs) { console.log(row['number'] + " " + row['fibonacci']); } return rs; </script>
+-------+---------+
|number |fibonacci|
|double |decimal |
+-------+---------+
| 1.000| 1.000|
| 2.000| 2.000|
| 3.000| 3.000|
| 4.000| 5.000|
| 5.000| 8.000|
| 6.000| 13.000|
| 7.000| 21.000|
| 8.000| 34.000|
| 9.000| 55.000|
| 10.000| 89.000|
+-------+---------+
1 1
2 2
3 3
4 5
5 8
6 13
7 21
8 34
9 55
12.1 Updating Memory ResultSet Content
// ============================================================================ // Shows how to update current row or a set of rows in memory resultsets // ============================================================================ var rs = Ax.db.executeQuery(` SELECT tabid, tabname, 0 data FROM systables WHERE tabid < 5 `).toMemory(); // +------+-------------+----+ // |FROM |FROM |FROM| // |tabid |tabname |data| // |serial|nvarchar(128)|int | // +------+-------------+----+ // |1 |systables |0 | // |2 |syscolumns |0 | // |3 |sysindices |0 | // |4 |systabauth |0 | // +------+-------------+----+ console.log(rs); // Position Resutset in a row rs.absolute(1); // Update current row rs.updateRow({ "data" : 10 }); // Update a set of rows matching filter expression rs.updateRows({ "data" : 20 }, { "tabid" : 2 }); // +------+-------------+----+ // |FROM |FROM |FROM| // |tabid |tabname |data| // |serial|nvarchar(128)|int | // +------+-------------+----+ // |1 |systables |10 | // |2 |syscolumns |20 | // |3 |sysindices |0 | // |4 |systabauth |0 | // +------+-------------+----+ console.log(rs); // Update current row for (var row of rs) { rs.updateRow({ "data" : -row.tabid }); } // +------+-------------+----+ // |FROM |FROM |FROM| // |tabid |tabname |data| // |serial|nvarchar(128)|int | // +------+-------------+----+ // |1 |systables |-1 | // |2 |syscolumns |-2 | // |3 |sysindices |-3 | // |4 |systabauth |-4 | // +------+-------------+----+ console.log(rs);
12.2 Removing rows from Memory ResultSet
var rs = new Ax.rs.Reader().memory(options => { options.setColumnNames([ "seq", "part", "brand", "price" ]); options.setColumnTypes([ Ax.sql.Types.INTEGER, Ax.sql.Types.CHAR, Ax.sql.Types.INTEGER, Ax.sql.Types.DOUBLE ]); options.setColumnScales([ 0, 0, 0, 3 ]); }); rs.rows().add([1, 'P01', "A", 20.75 ]); // DEL rs.rows().add([2, 'P90', "A", null ]); rs.rows().add([3, 'P01', "B", 30.25 ]); rs.rows().add([5, 'P01', "A", 8.00 ]); // DEL rs.rows().add([6, 'P01', "A", 5.99 ]); // DEL rs.rows().add([7, 'P90', "B", 15.01 ]); console.log(rs); // +-------+--------+-------+------+ // |<null> |<null> |<null> |<null>| // |seq |part |brand |price | // |integer|char(40)|integer|double| // +-------+--------+-------+------+ // |1 |P01 |A |20.750| // |2 |P90 |A | | // |3 |P01 |B |30.250| // |5 |P01 |A |8 | // |6 |P01 |A |5.990 | // |7 |P90 |B |15.010| // +-------+--------+-------+------+ rs.deleteRows( { "part" : "P01" , "brand" : "A" } ); console.log(rs); // +-------+--------+-------+------+ // |<null> |<null> |<null> |<null>| // |seq |part |brand |price | // |integer|char(40)|integer|double| // +-------+--------+-------+------+ // |2 |P90 |A | | // |3 |P01 |B |30.250| // |7 |P90 |B |15.010| // +-------+--------+-------+------+
13 Data mapping
13.1 Java to Javascript
Objects returned from database are the correspoding Java objects for each column data type. Javascript will work natively for String, integers and floating point numbers. And will use the Java wrapping for Date, Decimal and Blob data types as they have no corresponding Javascript equivalent.
Java | Javascript |
---|---|
Map | JSON |
List | Array |
Boolean | Native boolean |
Integer | Native number |
Long | Native number |
Float | Native number |
Double | Native number |
String | Native string |
Date | wrapper of Date |
Decimal | wrapper of Decimal |
Blob | wrapper of Blob |
13.2 Javascript to Java
Native objects passed form Javascript to Java are converted to Java types. For example, you can pass a Javascript native date as parameter for database date.
Javascript | Java |
---|---|
JSON object | Map |
Native Array | java.util.List |
Native Date | java.util.Date |
Native Number | java.lang.Double |
Native String | java.lang.String |