The SQL-data change statements are a subset of the SQL-data statements; this also contains the SELECT query statement,
which strictly speaking is part of the DQL
, not the DML
. In common practice though, this distinction is not made and
SELECT is widely considered to be part of DML
, so the DML
consists of all SQL-data statements,
not only the SQL-data change statements.
Data manipulation languages have their functional capability organized by the initial word in a statement, which is almost always a verb. In the case of SQL, these verbs are:
-
SELECT ... FROM ... WHERE ... (strictly speaking
DQL
) - SELECT ... INTO ...
- INSERT INTO ... VALUES ...
- UPDATE ... SET ... WHERE ...
- DELETE FROM ... WHERE ...
Method | Return |
---|---|
JSSQLCA
|
insert(String tableName, JSON rowData) |
JSSQLCA
|
delete(String tableName, JSON pkValues) |
JSSQLCA
|
update(String tableName, JSON rowdata) |
JSSQLCA
|
update(String tableName, JSON keysMap, JSON dataMap) |
JSSQLCA
|
update(String tableName, JSON dataMap, String condition) |
JSSQLCA
|
insertOrUpdate(String tableName, JSON rowData) |
JSSQLCA
|
insertOrUpdate(String tableName, JSON pkValues, JSON dataMap) |
JSSQLCA
|
updateOrInsert(String tableName, JSON rowData) |
JSSQLCA
|
updateOrInsert(String tableName, JSON pkValues, JSON dataMap) |
1 Sample table
We will use this table in the examples below.
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) );
2 Insert statement
The insert statement takes a JSON
or array of JSON
objects and automatically performs the mapping
to database fields.
Return | Method | Description |
---|---|---|
SQLCA
|
insert(String table, JSON row) |
Insert a JSON object |
int | insert(String table, Array<JSON > row) |
Insert an array of JSON objects |
2.1 Insert a row
You can insert JSON
object by simply passing it as argument to insert function.
The insert operation returns a SQLCA
structure containing among other information the serial value
for any autoincrement column present in the table or the rowid value of the new row inserted.
<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 row = { model: "chevrolet chevelle malibu", mpg:18, cylinders:8, displacement:307, horsepower:130, weight:3504, acceleration:12, year:70, origin: "US", } var serial = Ax.db.insert("cars", row).getSerial(); console.log("New serial is " + serial); let rs = Ax.db.executeQuery("SELECT * FROM cars"); console.log(rs); rs.close(); Ax.db.execute('DROP TABLE cars'); </script>
New serial is 5
+----------+-------------------------+----------------+----------+----------------+----------+----------+----------------+----------+----------+
|seqno |model |mpg |cylynders |displacement |horsepower|weight |acceleration |year |origin |
+----------+-------------------------+----------------+----------+----------------+----------+----------+----------------+----------+----------+
| 1|chevrolet chevelle malibu| 18.0| 8| 307.0| 130| 3504| 12.0| 70|US |
+----------+-------------------------+----------------+----------+----------------+----------+----------+----------------+----------+----------+
2.2 Insert an array
Insert from a JSON
array of objects is simple too by passing the array of JSON
rows to the insert statement.
Returns the number of rows inserted (the number of rows in the array).
<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: "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"); console.log(rs); rs.close(); Ax.db.execute('DROP TABLE cars'); </script>
+----------+-------------------------+----------------+----------+----------------+----------+----------+----------------+----------+----------+
|seqno |model |mpg |cylynders |displacement |horsepower|weight |acceleration |year |origin |
+----------+-------------------------+----------------+----------+----------------+----------+----------+----------------+----------+----------+
| 1|chevrolet chevelle malibu| 18.0| 8| 307.0| 130| 3504| 12.0| 70|US |
| 2|buick skylark 320 | 15.0| 8| 350.0| 165| 3693| 11.5| 70|US |
| 3|plymouth satellite | 18.0| 8| 318.0| 150| 3436| 11.0| 70|US |
| 4|amc rebel sst | 16.0| 8| 304.0| 150| 3433| 12.0| 70|US |
+----------+-------------------------+----------------+----------+----------------+----------+----------+----------------+----------+----------+
2.3 Batch insert
<script> // ---------------------------------------------- // Insert rows in batch mode // ---------------------------------------------- var NROWS = 10000; var t1 = new Date(); console.log("Batch insert starts at: " + t1); Ax.db.execute(`DROP TABLE IF EXISTS t_10K;`); Ax.db.execute(`CREATE TEMP TABLE t_10K( seqno serial, c1 integer, c2 varchar(20) )`); // Define insert batch on table t_10k comminting each 1000 operations var batch = Ax.db.insertBatch("t_10K"); batch.setBatchSize(1000); for (var i = 0; i < NROWS; i++) { batch.addBatch({"seqno": 0, "c1" : 456 , "c2" : "TEST2" }); } rowsInserted = batch.close(); var t2 = new Date(); var dif = (t2.getTime() - t1.getTime()) / 1000; console.log("Batch insert end. Rows inserted:" + rowsInserted + " Time:" + dif + " seconds."); // ---------------------------------------------- // Insert rows in regular mode // ---------------------------------------------- t1 = new Date(); console.log("Regular insert starts at: " + t1); Ax.db.execute(`DROP TABLE IF EXISTS t_10K;`); Ax.db.execute(`CREATE TEMP TABLE t_10K( seqno serial, c1 integer, c2 varchar(20) )`); rowsInserted = 0; for (var i = 0; i < NROWS; i++) { rowsInserted++; batch.addBatch({"seqno": 0, "c1" : 456 , "c2" : "TEST2" }); } t2 = new Date(); dif = (t2.getTime() - t1.getTime()) / 1000; console.log("Regular insert end. Rows inserted:" + rowsInserted + " Time:" + dif + " seconds."); Ax.db.execute('DROP TABLE t_10K'); </script>
Batch insert starts at: Tue Apr 09 2019 15:10:08 GMT+0200 (CEST)
Batch insert end. Rows inserted:10000 Time:0.609 seconds.
Regular insert starts at: Tue Apr 09 2019 15:10:09 GMT+0200 (CEST)
Regular insert end. Rows inserted:10000 Time:22.379 seconds.
3 Update statement
The update statement takes a JSON
object as row and optional JSON
object
as primary key.
Return | Method | Description | Temp table |
---|---|---|---|
SQLCA
|
update(String table, JSON row) |
(1) Updates a JSON object using automatic primary key discovery. It does not work with temporary tables as
primary key can not be automatically determined. |
|
SQLCA
|
update(String table, JSON row, String condition) |
(2) Updates a JSON object using automatic primary key discovery and condition. If there is no primary key
the condition is used alone to build the where clause. |
|
SQLCA
|
update(String table, JSON row, JSON key) |
Updates a JSON object using given primary key. It works with temporary tables. |
|
SQLCA
|
update(String tableName, JSON row, JSON key, String condition) |
Updates a JSON object given primary key and sql condition. The SQL seems not necessary but can be used for injected filtering |
3.1 Row update using primary key discovery
We can do a partial update providing in data the primary key values (or serial as in the example). Application will determine the table primary key or serial and do the appropriate data mapping to perform the update.
<script> var NROWS = 5; Ax.db.execute(`DROP TABLE IF EXISTS t1;`); Ax.db.execute(`CREATE TABLE t1( c1 integer primary key not null, c2 varchar(10), c3 integer default 1 )`); for (var idx = 1; idx < NROWS; idx++) { Ax.db.execute(`INSERT INTO t1(c1, c2) VALUES(${idx}, 'hello${idx}');`); } // (1) // On TEMP table will fail: No primary key or serial found for table t1 Ax.jsunit.assertEquals(1, Ax.db.update("t1", { "c2" : "bye1" , "c1": 1 }).getCount()); // (2) Ax.jsunit.assertEquals(1, Ax.db.update("t1", { "c2" : "bye2" }, "c1 = 2").getCount()); // (3) Ax.jsunit.assertEquals(1, Ax.db.update("t1", { "c2" : "bye3" }, { "c1" : 3} ).getCount()); // (4) Ax.jsunit.assertEquals(1, Ax.db.update("t1", { "c2" : "bye4" }, { "c1": 4 }, "c3 = 1").getCount()); // Results let rs = Ax.db.executeQuery("SELECT * FROM t1"); console.log(rs); rs.close(); Ax.db.execute('DROP TABLE t1'); </script>
+----------+-----------+----------+
|c1 |c2 |c3 |
|int |varchar(10)|int |
+----------+-----------+----------+
| 1|bye1 | 1|
| 2|bye2 | 1|
| 3|bye3 | 1|
| 4|bye4 | 1|
+----------+-----------+----------+
If no primary key or serial is present on table or data of for that columns is not provided, update will not be possible and operation will fail with an exception message about data is required for operation.
3.2 Row update with primary key specified
We can provide the primary key as an optional parameter. In general this is not need but it's optional.
<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 rowI = { model: "chevrolet chevelle malibu", mpg:18, cylinders:8, displacement:307, horsepower:130, weight:3504, acceleration:12, year:70, origin: "US", }; var serial = Ax.db.insert("cars", rowI).getSerial(); var row = { model: "chevrolet chevelle 3", } var pk = { seqno: 1 } var sqlca = Ax.db.update("cars", row, pk); console.log(sqlca.count + " row(s) updated"); let rs = Ax.db.executeQuery("SELECT * FROM cars"); console.log(rs); rs.close(); Ax.db.execute('DROP TABLE cars'); </script>
1 row(s) updated
+----------+-------------------------+----------------+----------+----------------+----------+----------+----------------+----------+----------+
|seqno |model |mpg |cylynders |displacement |horsepower|weight |acceleration |year |origin |
+----------+-------------------------+----------------+----------+----------------+----------+----------+----------------+----------+----------+
| 1|chevrolet chevelle 3 | 18.0| | 307.0| 130| 3504| 12.0| 70|US |
| 2|buick skylark 320 | 15.0| | 350.0| 165| 3693| 11.5| 70|US |
| 3|plymouth satellite | 18.0| | 318.0| 150| 3436| 11.0| 70|US |
| 4|amc rebel sst | 16.0| | 304.0| 150| 3433| 12.0| 70|US |
+----------+-------------------------+----------------+----------+----------------+----------+----------+----------------+----------+----------+
The update operation returns a SQLCA
structure containing the number of rows updated.
Giving a bad primary key may cause a wrong update affecting non desired rows.
3.3 Row update with sql condition
We can provide one sql condition as an optional parameter.
<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 rowI = { model: "chevrolet chevelle malibu", mpg:18, cylinders:8, displacement:307, horsepower:130, weight:3504, acceleration:12, year:70, origin: "US", }; var serial = Ax.db.insert("cars", rowI).getSerial(); var datamap = { model: "ferrari 458", } var sqlca = Ax.db.update("cars", datamap ,"seqno=1"); console.log(sqlca.count + " row(s) updated"); let rs = Ax.db.executeQuery("SELECT * FROM cars"); console.log(rs); rs.close(); Ax.db.execute('DROP TABLE cars'); </script>
1 row(s) updated
+----------+-------------------------+----------------+----------+----------------+----------+----------+----------------+----------+----------+
|seqno |model |mpg |cylynders |displacement |horsepower|weight |acceleration |year |origin |
+----------+-------------------------+----------------+----------+----------------+----------+----------+----------------+----------+----------+
| 1|ferrarri 458 | 18.0| | 307.0| 130| 3504| 12.0| 70|US |
| 2|buick skylark 320 | 15.0| | 350.0| 165| 3693| 11.5| 70|US |
| 3|plymouth satellite | 18.0| | 318.0| 150| 3436| 11.0| 70|US |
| 4|amc rebel sst | 16.0| | 304.0| 150| 3433| 12.0| 70|US |
+----------+-------------------------+----------------+----------+----------------+----------+----------+----------------+----------+----------+
The update operation returns a SQLCA
structure containing the number of rows updated.
Giving a bad primary key may cause a wrong update affecting non desired rows.
3.4 Batch Update
Ax.db.update operation is a highly dynamic and powerfull instruction, but also a little bit slow, as it should evaluate objects received as parameters, prepare the update statement, set up parameters and execute the UPDATE operation.
If you need to execute hundreds of update operations on same table with same parameters, executing all this sequence of operations each row to update is a waste of time. That's why Batch update operations emerges:
A batch update is a batch of updates grouped together, and sent to the database in one "batch", rather than sending the updates one by one. Sending a batch of updates to the database in one go, is faster than sending them one by one, waiting for each one to finish.
This procedure includes other performance techniques like single prepare statement operation, avoiding prepare statement each time the update is executed with new data.
Return | Method | Description |
---|---|---|
JSUpdateBatch | updateBatch(String tabname) | Creates an update batch object to update table passed as parameter |
JSUpdateBatch | setBatchSize(int statements) | Defines the number of statements execute to automatic commit of batch statements to server. Default commit number is 1000. |
void | setWhereCondition(String Condition) | Setup a String SQL Where Condition to be added to the update where condition constructed from object.This allows to create a batch update with a complex static where condition. E.g. using EXIST, CASE, etc. in the where condition. |
void | addBatch(Json setCols, Json whereCols) | Executes an update in batch mode. Update is not sent inmediatly to server, but stored in a batch chunk. Objects defining columns to update or columns to define where condition, must have same structure. E.g. you cannot add new columns to objects and use same "Update Batch" object. Where Condition setup from setWhereCondition method is added to the where condition constructed from Json whereCols. |
int | close() | Sends remaining batch operations not sent to server and returns the total number of rows correctly updated since object was created. |
<script> // ---------------------------------------------- // Create test table // ---------------------------------------------- var NROWS = 10000; Ax.db.execute(`DROP TABLE IF EXISTS t_10K;`); if (!Ax.db.existsTable("t_100K")) { console.log("Creating test table t_10K"); Ax.db.execute(`CREATE TEMP TABLE t_10K( seqno serial, c1 integer, c2 varchar(20) )`); for (var i = 0; i < NROWS; i++) { Ax.db.execute(`INSERT INTO t_10K(seqno, c1, c2) VALUES(0, 921, 'TEST')`); } Ax.db.execute(`CREATE INDEX i_t_10K ON t_10K(seqno)`); } // ---------------------------------------------- // Batch update // ---------------------------------------------- var t1 = new Date(); console.log("Batch update start at: " + t1); // Define update batch on table t_10k comminting each 1000 operations var batch = Ax.db.updateBatch("t_10K"); batch.setBatchSize(1000); batch.setWhereCondition("c2 IS NOT NULL"); var rs = Ax.db.executeQuery(`SELECT seqno, c1, c2 FROM t_10K`); for (var row of rs) { batch.addBatch( {"c1" : 456 , "c2" : "TEST2" }, {"seqno" : row.seqno}); } rowsUpdated = batch.close(); var t2 = new Date(); var dif = (t2.getTime() - t1.getTime()) / 1000; console.log("Batch update end. Rows updated:" + rowsUpdated + " Time:" + dif + " seconds."); // ---------------------------------------------- // Regular update // ---------------------------------------------- t1 = new Date(); console.log("Regular update start at: " + t1); rowsUpdated = 0; var rs2 = Ax.db.executeQuery(`SELECT seqno, c1, c2 FROM t_10K`); for (var row of rs2) { rowsUpdated++; Ax.db.update("t_10K", {"c1" : 456 , "c2" : "TEST2" }, {"seqno" : row.seqno}); } t2 = new Date(); dif = (t2.getTime() - t1.getTime()) / 1000; console.log("Regular update end. Rows updated:" + rowsUpdated + " Time:" + dif + " seconds."); Ax.db.execute('DROP TABLE t_10K'); </script>
4 Delete statement
The delete operation taks a JSON
object with either primary key or serial value. Ax.db.delete returns a SQLCA
structure containing the number of rows deleted, but if you only care about this measure, you can call
getCount() method from SQLCA
object to get the number or rows deleted.
Return | Method | Description | Temp table |
---|---|---|---|
SQLCA
|
delete(String table, JSON key) |
(1) Deletes rows from table using the specfied key vaules | |
SQLCA
|
delete(String table, String condition) | (2) Deletes rows from table using the specfied where condition | |
SQLCA
|
delete(String table, JSON key, String condition) |
(3) Deletes rows from table using the specfied key vaules and where condition |
<script> var NROWS = 5; Ax.db.execute(`DROP TABLE IF EXISTS t1;`); Ax.db.execute(`CREATE TABLE t1( c1 integer primary key not null, c2 varchar(10), c3 integer default 1 )`); for (var idx = 1; idx < NROWS; idx++) { Ax.db.execute(`INSERT INTO t1(c1, c2) VALUES(${idx}, 'hello${idx}');`); } // (1) Ax.jsunit.assertEquals(1, Ax.db.delete("t1", { "c1": 1 }).getCount()); // (2) Ax.jsunit.assertEquals(1, Ax.db.delete("t1", "c1 = 3").getCount()); // (3) Ax.jsunit.assertEquals(1, Ax.db.delete("t1", { "c1": 2 }, "c3 = 1").getCount()); // Results let rs = Ax.db.executeQuery("SELECT * FROM t1"); console.log(rs); rs.close(); Ax.db.execute('DROP TABLE t1'); </script>
+----------+-----------+----------+
|c1 |c2 |c3 |
|int |varchar(10)|int |
+----------+-----------+----------+
| 4|hello4 | 1|
+----------+-----------+----------+
5 Update or Insert statements
Two methods provide combined opetations to perform update and insert operations.
-
updateOrInsert
: performs update operation, if no row updated then performs an insert. -
insertOrUpdate
: performs insert operation, if row already exists the performs an update.
Using one method or other, is just a matter of performance gain. If programmer assumes that usualy the final SQL operation will be an update, then it's better to use updateOrInsert, if usualy an insert is expected then use insertOrUpdate.
Return | Method | Description |
---|---|---|
JSSQLCA
|
updateOrInsert(String table, JSON row) |
Updates or Inserts a JSON object using automatic primary key discovery |
JSSQLCA
|
updateOrInsert(String table, JSON row, JSON key) |
Updates or Inserts a JSON object using given primary key |
JSSQLCA
|
insertOrUpdate(String tableName, JSON rowData) |
Inserts a JSON object. If insert fails with duplicated row, an update is executed by autodiscovering primary key from row data. |
JSSQLCA
|
insertOrUpdate(String tableName, JSON dataMap, JSON keysMap) |
. |
5.1 Update or Insert
The update or insert statement combines both a update and optional insert operation if update has failed. This combined statement is very useful in some circumstances but it's specifically related for tables with primary key and without autoincrement columns.
To show the case we need a table with a primary and no autoincrement column.
CREATE TABLE state ( code char(2), sname char(15), primary key (code) ); INSERT INTO state VALUES('AL', 'ALABAMA'); INSERT INTO state VALUES('AK', 'ARKANSAS'); INSERT INTO state VALUES('AZ', 'ARIZONA'); INSERT INTO state VALUES('CA', 'CALIFORNIA');
This example shows how to use updateOrInsert method with key auto discovery.
<script> Ax.db.execute('DROP TABLE IF EXISTS state'); Ax.db.execute(`CREATE TABLE state ( code char(2), sname char(15), primary key (code) );`); Ax.db.execute(`INSERT INTO state VALUES('AL', 'ALABAMA');`); Ax.db.execute(`INSERT INTO state VALUES('AK', 'ARKANSAS');`); Ax.db.execute(`INSERT INTO state VALUES('AZ', 'ARIZONA');`); Ax.db.execute(`INSERT INTO state VALUES('CA', 'CALIFORNIA');`); var row={ code : "CA", sname : "California" }; Ax.db.updateOrInsert('state', row); var row2={ code : "CO", sname : "Colorado" }; Ax.db.updateOrInsert('state', row2); var rs = Ax.db.executeQuery("SELECT * FROM state"); console.log(rs); rs.close(); Ax.db.execute('DROP TABLE state'); </script>
+----+---------------+
|code|sname |
+----+---------------+
|AL |ALABAMA |
|AK |ARKANSAS |
|AZ |ARIZONA |
|CA |California |
|CO |Colorado |
+----+---------------+
5.2 Insert or Update
The insert or update statement tries to execute an insert operation into table with data provided. If row already exists and a duplicated row is received from insert, operation, then an update statement is executed. This combined statement requires a unique index or primary key in table.
This example shows how to use insertOrUpdate method with auto discovery or keys.
<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 rowI = { model: "chevrolet chevelle malibu", mpg:18, cylinders:8, displacement:307, horsepower:130, weight:3504, acceleration:12, year:70, origin: "US", }; var serial = Ax.db.insert("cars", rowI).getSerial(); var row = { seqno: 1, model: "chevrolet chevelle 2", } Ax.db.insertOrUpdate("cars", row); let rs = Ax.db.executeQuery("SELECT * FROM cars"); console.log(rs); rs.close(); Ax.db.execute('DROP TABLE cars'); </script>
+----------+-------------------------+----------------+----------+----------------+----------+----------+----------------+----------+----------+
|seqno |model |mpg |cylynders |displacement |horsepower|weight |acceleration |year |origin |
+----------+-------------------------+----------------+----------+----------------+----------+----------+----------------+----------+----------+
| 1|chevrolet chevelle 2 | 18.0| 8| 307.0| 130| 3504| 12.0| 70|US |
| 2|buick skylark 320 | 15.0| 8| 350.0| 165| 3693| 11.5| 70|US |
| 3|plymouth satellite | 18.0| 8| 318.0| 150| 3436| 11.0| 70|US |
| 4|amc rebel sst | 16.0| 8| 304.0| 150| 3433| 12.0| 70|US |
+----------+-------------------------+----------------+----------+----------------+----------+----------+----------------+----------+----------+
If no primary key or serial is present on table or data of for that columns is not provided, update will not be possible and operation will fail with an exception indication data is required for operation.
6 Moving (reordering) rows
A simple operation typically need in some web interfaces is related to data reordering.
Asuming we have a table with rows ordered using a sequence number, we can use the move
operation to move one row before or after other row.
The SQL operations required will be performed automatically. Let's see and example:
<script> Ax.db.execute(` DROP TABLE IF EXISTS fruits; `); Ax.db.execute(` CREATE TABLE IF NOT EXISTS fruits( seqno SMALLINT, fruit VARCHAR(30) ) `); Ax.db.execute("INSERT INTO fruits VALUES (1, 'Banana')"); Ax.db.execute("INSERT INTO fruits VALUES (2, 'Mango')"); Ax.db.execute("INSERT INTO fruits VALUES (3, 'Apple')"); Ax.db.execute("INSERT INTO fruits VALUES (4, 'Carrot')"); Ax.db.execute("INSERT INTO fruits VALUES (5, 'Lemon')"); // Source data console.log("SOURCE"); let rs = Ax.db.executeQuery("SELECT * FROM fruits ORDER BY seqno"); console.log(rs); rs.close(); // Move row 3 to 4 console.log("3 to 4"); Ax.db.moveTableRow("fruits", "seqno", 3, 4); rs = Ax.db.executeQuery("SELECT * FROM fruits ORDER BY seqno"); console.log(rs); rs.close(); // Move row 5 to 1 console.log("5 to 1"); Ax.db.moveTableRow("fruits", "seqno", 5, 1); rs = Ax.db.executeQuery("SELECT * FROM fruits ORDER BY seqno"); console.log(rs); rs.close(); Ax.db.execute('DROP TABLE fruits'); </script>
SOURCE
+--------+------------------------------+
|seqno |fruit |
+--------+------------------------------+
| 1|Banana |
| 2|Mango |
| 3|Apple |
| 4|Carrot |
| 5|Lemon |
+--------+------------------------------+
3 to 4
+--------+------------------------------+
|seqno |fruit |
+--------+------------------------------+
| 1|Banana |
| 2|Mango |
| 3|Carrot |
| 4|Apple |
| 5|Lemon |
+--------+------------------------------+
5 to 1
+--------+------------------------------+
|seqno |fruit |
+--------+------------------------------+
| 1|Lemon |
| 2|Banana |
| 3|Mango |
| 4|Carrot |
| 5|Apple |
+--------+------------------------------+
Notice that operation takes 1=1
as last argument indicating operation affects
all rows.