This section describes SQL tricks to avoid bad or non-performant SQL operations.

1 Union to force cartesian products

This is a usual business case when we have a value in a column but this can be overriden by a value split in another child table.

Let's construct the base example:

Copy
drop table if exists tt1;
create temp table tt1(
    c1 integer,
    c2 char(10),
    c3 integer
);
insert into tt1 values(1, "T1-1", 192);
insert into tt1 values(2, "T1-2", 193);
drop table if exists tt2;
create temp table tt2(
    x1 integer,
    x2 integer
);
insert into tt2 values(1, 21);
insert into tt2 values(1, 22);

Relation between table tt1 and table tt2 is the column c1 but not all rows in table tt1 has a child in table tt2.

Traditionaly, getting a cartesian product of tables tt1 and tt2 is done using a union clause:

Copy
SELECT tt1.c1, tt1.c2, tt1.c3
  FROM tt1
 WHERE NOT EXISTS (SELECT * FROM tt2 WHERE tt2.c1 = tt1.c1)
 
 UNION ALL
 
SELECT tt1.c1, tt1.c2, tt2.x2
  FROM tt1, tt2
 WHERE tt2.c1 = tt1.c1

As you can imagine this is an ineficient code, because requires to complete scans to table tt1 and executing the not exists clause for each row retrieved by first SELECT.

First alternative is using LEFT JOIN clause. This method allows to perform a cartesian product and retrieve rows from tt1 even if no relatio with tt2 exists.

Copy
SELECT tt1.c1, tt1.c2, NVL(tt2.x2, tt1.c3)
  FROM tt1
       LEFT JOIN tt2 ON tt1.c1 = tt2.x1

And more complex alternative is to use multiset clause, that allows to retrieve less rows and process results at the client/program level iterating the multiset struct.

Copy
SELECT tt1.*, MULTISET((SELECT * FROM tt2 WHERE tt1.c1 = tt2.x1)) FROM tt1;

This last method, hasa a caveat that is the limit of total row size to 32k (including multiset data). So you must know that child table will not have a huge amount of rows.

2 CTE and Derived Tables

There is a common usage pattern for SQL to store some filtered information into a temporary table and reuse this table as a source of a more complex SELECT statement.

We can see an example of this pattern in this code:

Copy
<select intotemp='@tmp_1'>
  <columns>capuntes.empcode, capuntes.fecha, capuntes.asient</columns>
  <from table='capuntes' />
  <where>$0</where>
  <group>1, 2, 3</group>
  <having>SUM(capuntes.debe) != SUM(capuntes.haber)</having>
</select>

<select>
  <columns>
       @tmp_1.empcode,   @tmp_1.fecha,    @tmp_1.asient,
       capuntes.orden,  capuntes.apteid,  capuntes.jusser, capuntes.docser,
       capuntes.proyec, capuntes.seccio,  capuntes.cuenta, capuntes.codcon,
       capuntes.concep, capuntes.debe,    capuntes.haber,
       (capuntes.debe - capuntes.haber) <alias name='saldo' />
  </columns>
  <from table='@tmp_1'>
    <join table='capuntes'>
      <on>@tmp_1.empcode = capuntes.empcode</on>
      <on>@tmp_1.fecha   = capuntes.fecha</on>
      <on>@tmp_1.asient  = capuntes.asient</on>
    </join>
  </from>
</select>

Modern ANSI SQL allows other methods to simplify temporary table usage and extend SQL functionality. We can reformulate this SQL using advanced SQL patterns name Common Table Expressions (CTE) amd Derived Tables.

2.1 Common Table Expression

A common table expression (CTE) is a named temporary result set that exists within the scope of a single statement and that can be referred to later within that statement.

It is declared at the front of the statement that will use it using the new “WITH” keyword:

Copy
WITH cte-name AS (select-statement) ...

The primary purpose is to simplify the SQL that follows it by moving out a sub-query into a separate object to reduce complexity or repetition.

Using our SQL report statement, we can simplify temporary usage rewriting the SQL Statement using CTE:

Copy
WITH mytab AS 
(
SELECT empcode, fecha, asient
  FROM capuntes
 WHERE $0
 GROUP BY 1, 2, 3
 HAVING SUM(debe - haber) != 0
 )

 SELECT mytab.*, capuntes.cuenta, capuntes.debe, capuntes.haber
   FROM mytab
        INNER JOIN capuntes ON capuntes.empcode = mytab.empcode 
                           AND capuntes.fecha   = mytab.fecha 
                           AND capuntes.asient  = mytab.asient;

2.2 Derived Tables

An alternative is to use a “derived table” or “table expression” as below:

Copy
SELECT mytab.*, capuntes.cuenta, capuntes.debe, capuntes.haber
   FROM (
        SELECT empcode, fecha, asient
          FROM capuntes
         WHERE $0
         GROUP BY 1, 2, 3
         HAVING SUM(debe - haber) != 0
        ) AS mytab
        INNER JOIN capuntes ON capuntes.empcode = mytab.empcode 
                           AND capuntes.fecha   = mytab.fecha 
                           AND capuntes.asient  = mytab.asient;

Derived tables allows to execute a SQL Statement and "project" this resultset as a TABLE that can be used in a SQL Statement.

Caveats using derived tables is than you can't perform relationships from outside where creating the derived table. Focusing in our SELECT example, first, the statement "SELECT empcode, fecha, asient..." on its own, creates an internal temporary table and names it as mytab. Next,the global SQL is executed and you can use this internal temporary table as you want.

3 Multiuser Environment and Process Concurrency

In processes to be executed in a multiuser environment, programmer should be aware of concurrency paradigm

When creatng a program, always think about this program could be executed more than once at the same time. in a process design you should avoid the same rows to be processed twice by concurrent executions. There are some design patterns to avoid this, each having their pros and cons.

This chapter describes this design methods and gives the information to allow you to choose wich method fits best your requirements.

3.1 Using Cursor for Update

Copy
/**
 * Example to test concurrency processing of the same table by
 * multiple threads (emulated here without threads) using the
 * SELECT FOR UPDATE.
 *
 * The SELECT FOR UPDATE statement is used to order transactions by controlling concurrent access to one or more rows of a table.
 *
 * It works by locking the rows returned by a selection query, such that other transactions trying to access those rows are 
 * forced to wait for the transaction that locked the rows to finish. These other transactions are effectively put into
 * a queue based on when they tried to read the value of the locked rows.
 *
 */
 
 /**
  * PREPARE TABLE
  */
function createTables()
{  
	Ax.db.execute("DROP TABLE IF EXISTS test_concurrency");
	Ax.db.execute("CREATE TABLE test_concurrency(id serial PRIMARY KEY, key char(10), estado integer default 0 not null)");
	for (var idx = 0; idx < 10; idx++)
		Ax.db.execute(`INSERT INTO test_concurrency (key) VALUES ('X${idx}')`);
	
	console.log(Ax.db.executeQuery("SELECT * FROM test_concurrency"));
}


function processTable()
{
	/**
	 * use a global transaction (can not place transactions in the loop)
	 */
	Ax.db.beginWork();
	
	/**
	 * Use the RETAIN UPDATE LOCKS option to affect the behavior of the database server when 
	 * it handles a SELECT ... FOR UPDATE statement.
	 *
	 * In a database with the isolation level set to Dirty Read, Committed Read, or Cursor Stability,
	 * the database server places an update lock on a fetched row of a SELECT ... FOR UPDATE statement.
	 * When you turn on the RETAIN UPDATE LOCKS option, the database server retains the update lock until 
	 * the end of the transaction rather than releasing it at the next subsequent FETCH or when the cursor 
	 * is closed. This option prevents other users from placing an exclusive lock on the updated row before 
	 * the current user reaches the end of the transaction.
	 *	
	 * You can use this option to achieve the same locking effects but avoid the overhead of dummy updates
	 * or the repeatable read isolation level.
	 *
	 * NOTICE: studio changes back to DIRTY READ WHEN connection is returned to jdbc pool.
	 *
	 */
	 
	 /**
	  * This option is not really need here cause we make an update immediately.
	  * If we did not make the update of "estado" till the end, the it's required
	  */
	// Ax.db.execute("SET ISOLATION TO COMMITTED READ LAST COMMITTED RETAIN UPDATE LOCKS;");
   
	/**
	 * DECLARE cursor FOR UPDATE using executeQueryForUpdate and "FOR UPDATE" clause
	 */ 
	
	var sql = "SELECT * 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()
	   	
	   	/**
	   	 * On a second read ... try to get all rows
	   	 */
		var rs2 = Ax.db.executeQueryForUpdate(sql);
		var count = 0;
		while (rs2.next()) {
		   	rs2.update("estado", 2);
		   	rs2.updateRow()
			count++;
		}
		rs2.close();
		console.log("Pending " + count);
	}
	    
	Ax.db.commitWork();
}

createTables();
processTable();

/**
 * RESUME
 */

/**
 *  1 row  has estado = 1
 *  9 rows has estado = 2
 */
console.log(Ax.db.executeQuery("SELECT * FROM test_concurrency"));
var estado1 = Ax.db.executeGet("SELECT count(*) FROM test_concurrency WHERE estado = 1");
var estado2 = Ax.db.executeGet("SELECT count(*) FROM test_concurrency WHERE estado = 2");

console.log("ESTADO1: " + estado1);
console.log("ESTADO2: " + estado2);

Ax.junit.assertEquals(1, estado1);
Ax.junit.assertEquals(9, estado2);

3.2 Ensure singleton execution

Copy
/**
 * Example to prevent multiple threads processing same table via a cron
 * style scheduler. It is a way to implement an exclusive use of a table
 * without locking it.
 *
 * The idea is very simple by using a table with a primary key where
 * we store our process name. Only one process name can be inserted
 * in the table. So any sencond process will fail till we delete
 * the row in the process table.
 *
 * The pseudo code looks like:
 *
 * 	begin work
 *  insert into process table (process_id)
 * 	commit work
 *
 *  try {
 *      process table
 *  } finally {
 * 		begin work
 * 	 	delete from process table (process_id)
 * 		commit work
 *  }
 *
 */
 
 /**
  * PREPARE TABLE
  */
function createTables()
{  
    // Tabla de procesos
	Ax.db.execute("DROP TABLE IF EXISTS test_process_lock");
	Ax.db.execute("CREATE TABLE test_process_lock(key CHAR(10) PRIMARY KEY not null)");
	
	
	Ax.db.execute("DROP TABLE IF EXISTS test_concurrency");
	Ax.db.execute("CREATE TABLE test_concurrency(id serial PRIMARY KEY, key char(10), estado integer default 0 not null)");
	for (var idx = 0; idx < 10; idx++)
		Ax.db.execute(`INSERT INTO test_concurrency (key) VALUES ('X${idx}')`);
	
	console.log(Ax.db.executeQuery("SELECT * FROM test_concurrency"));
}

 /**
  * Create a lock and make it permanent
  */
function lock(key)
{
	Ax.db.beginWork();
	Ax.db.execute(`INSERT INTO test_process_lock VALUES('${key}')`);
	Ax.db.commitWork();
}

 /**
  * Delete the lock and commit
  */
function unlock(key)
{
	Ax.db.beginWork();
	Ax.db.execute(`DELETE FROM test_process_lock WHERE key = '${key}'`);
	Ax.db.commitWork();
}	

/**
 *  Demo function
 */
function processTable()
{
	/**
	 * Global process for all or nothing (depending on needs)
	 */
 	Ax.db.beginWork();
 	
	/**
	 * DECLARE cursor FOR UPDATE using executeQueryForUpdate and "FOR UPDATE" clause
	 */ 
	var rs1 = Ax.db.executeQuery("SELECT * FROM test_concurrency WHERE estado = 0");
	
	/**
	 * PROCESS EVERY ROW, MARKING ESTADO AS SOON AS ROW IF BEING TAKEN TO AVOID
	 * A SECOND PROCESS RELOADS IT.
	 */
	for (var row of rs1) {
	
		/**
		 * Maybe begin/commit here  (depending on needs)
		 */
		Ax.db.execute("UPDATE test_concurrency SET estado = 1 WHERE id = ?", row.id);
	}
	
	/**
	 * Global process for all or nothing (depending on needs)
	 */
 	Ax.db.commitWork();
}

var processName = "RP-GCOMPEDH";

createTables();

/**
 * Block process, any other will fail with unique index ...
 * This ensures the process will only be run by my processs
 */
lock(processName);

// Other call from other process will fail.
// lock(processName);

try {
	processTable();
} finally {
	/**
	* Ensure to unlock 
	*/ 
	unlock(processName);
}

console.log(Ax.db.executeQuery("SELECT * FROM test_concurrency"));

3.3 Emulate Could not do a physical read

Copy
/**
 * In a multi-user Informix Dynamic Server (IDS) environment where users have 
 * their isolation set higher than dirty read, and/or multiple users are 
 * performing update activity (i.e. insert, update or delete actions, rather than read-only), 
 * multiple users can all be attempting to place mutually exclusive locks on the same record.
 *
 *
 * Reproduce the Informix error -244: Could not do a physical-order read to fetch next row
 * 
 * A session 1 updates a row (or rows) in a transaction
 * A session 2 tries to update same row or rows in other transaction while transacton 1
 * is still not commited.
 * 
 * Session 2 will fail after a given timeout defined by the lock mode set in the connection.
 *
 * https://www.ibm.com/support/pages/sql-identify-users-involved-sessions-lock-contention
 *
 */

/**
  * PREPARE TABLE
  */
function createTables()
{  
	Ax.db.execute("DROP TABLE IF EXISTS test_concurrency");
	Ax.db.execute("CREATE TABLE test_concurrency(id serial PRIMARY KEY, key char(10), estado integer default 0 not null)");
	for (var idx = 0; idx < 10; idx++)
		Ax.db.execute(`INSERT INTO test_concurrency (key) VALUES ('X${idx}')`);
	
	console.log(Ax.db.executeQuery("SELECT rowid, * FROM test_concurrency"));
}

function updateTable(db)
{
	db.beginWork();
	db.execute("UPDATE test_concurrency SET key = 'XX' WHERE id = 1");
	// Keep transaction open
}

var db1 = Ax.db;
var db2 = Ax.db.cloned();
db2.execute("SET LOCK MODE TO WAIT 10");

var dbCode = Ax.db.getCode();

console.log("Create tables");
createTables();
console.log("First transaction on main connection");
updateTable(db1);

/**
 * No rows will be displayed cause we are running this 
 * SQL before second thread tries to update the table.
 * We should run it from dbstudio while the wait is on.
 */
console.log("Locks waiting ... (none will be seen, only if running from other thread while db2 executing the update)");
console.log(db2.executeQuery(`
select t.username, t.sid, s.username, s.sid, l.type locktype, l.dbsname, l.tabname, l.rowidlk rowid
  from sysmaster:syslocks l, sysmaster:syssessions s, sysmaster:syssessions t
 where s.sid     = l.owner
   and l.waiter  = t.sid
   and l.dbsname = '${dbCode}'
   and l.tabname = 'test_concurrency'
`));

/**
 * Show locks in place for the table. We will see:
 *
 *  X: Exclusive lock (on row)
 * IX: Intent exclusive (on table or index)
 */
console.log("Locks in place in the database and table (1)");
/*
+--------------------------------+----------+--------------------------------+----------+----------+----------------------------------------+----------------------------------------+----------+
|<null>                          |<null>    |<null>                          |<null>    |<null>    |<null>                                  |<null>                                  |<null>    |
|username                        |sid       |username                        |sid       |locktype  |dbsname                                 |tabname                                 |rowid     |
|char(32)                        |int       |char(32)                        |int       |varchar(4)|char(128)                               |char(128)                               |int       |
+--------------------------------+----------+--------------------------------+----------+----------+----------------------------------------+----------------------------------------+----------+
|informix                        |2612      |informix                        |2612      |IX        |stores_demo                             |test_concurrency                        |0         |
|informix                        |2612      |informix                        |2612      |X         |stores_demo                             |test_concurrency                        |257       |
+--------------------------------+----------+--------------------------------+----------+----------+----------------------------------------+----------------------------------------+----------+
 */
console.log(db2.executeQuery(`
select s.username, s.sid, l.type locktype, l.dbsname, l.tabname, l.rowidlk rowid
  from sysmaster:syslocks l, sysmaster:syssessions s
 where s.sid     = l.owner
   and l.dbsname = '${dbCode}'
   and l.tabname = 'test_concurrency'
  order by 1 ;
`));

/**
* This update will fail (after 10 seconds of wait), cause update 1 is still in progress
*/
console.log("Second transaction on another connection");
updateTable(db2);