UNPKG

ibm_db

Version:

IBM DB2 and IBM Informix bindings for node

1,188 lines (921 loc) 72.6 kB
# ibm_db API Documentation ## Database APIs **APIs for creating and droping Database using node.js application** * [.createDbSync(dbName, connectionString, [options])](#create-and-drop-database-apis) * [.dropDBSync(dbName, connectionString)](#-dropdbsyncdbname-connectionstring) **Database APIs** 1. [.open(connectionString, [options,] callback)](#1-openconnectionstring-options-callback) 2. [.openSync(connectionString)](#-2-opensyncconnectionstring-options) 3. [.query(sqlQuery [, bindingParameters], callback)](#-3-querysqlquery--bindingparameters-callback) 4. [.querySync(sqlQuery [, bindingParameters])](#-4-querysyncsqlquery--bindingparameters) 5. [.queryStream(sqlQuery [, bindingParameters])](#-5-querystreamsqlquery--bindingparameters) 6. [.queryResult(sqlQuery [, bindingParameters], callback)](#-6-queryresultsqlquery--bindingparameters-callback) 7. [.queryResultSync(sqlQuery [, bindingParameters])](#-7-queryresultsyncsqlquery--bindingparameters) 8. [.close(callback)](#-8-closecallback) 9. [.closeSync()](#-9-closesync) 10. [.prepare(sql, callback)](#-10-preparesql-callback) 11. [.prepareSync(sql)](#-11-preparesyncsql) 12. [.bind(bindingParameters, callback)](#-12-bindbindingparameters-callback) 13. [.bindSync(bindingParameters)](#-13-bindsyncbindingparameters) 14. [.execute([bindingParameters], callback)](#-14-executebindingparameters-callback) 15. [.executeSync([bindingParameters])](#-15-executesyncbindingparameters) 16. [.executeNonQuery([bindingParameters], callback)](#-16-executenonquerybindingparameters-callback) 17. [.executeNonQuerySync([bindingParameters])](#-17-executenonquerysyncbindingparameters) 18. [stmt.close(callback)](#-18-stmtclosecallback) 19. [stmt.closeSync()](#-19-stmtclosesync) 20. [.fetch(option, callback)](#-20-fetchoption-callback) 21. [.fetchSync(option)](#-21-fetchsyncoption) 22. [.fetchAll(option, callback)](#-22-fetchalloption-callback) 23. [.fetchAllSync(option)](#-23-fetchallsyncoption) 24. [.getData(colNum, Size, callback)](#-24-getdatacolnum-size-callback) 25. [.getDataSync(colNum, Size)](#-25-getdatasynccolnum-size) 26. [result.close(callback)](#-26-resultclosecallback) 27. [result.closeSync()](#-27-resultclosesync) 28. [.beginTransaction(callback)](#-28-begintransactioncallback) 29. [.beginTransactionSync()](#-29-begintransactionsync) 30. [.commitTransaction(callback)](#-30-committransactioncallback) 31. [.commitTransactionSync()](#-31-committransactionsync) 32. [.rollbackTransaction(callback)](#-32-rollbacktransactioncallback) 33. [.rollbackTransactionSync()](#-33-rollbacktransactionsync) 34. [.setIsolationLevel(isolationLevel)](#-34-setisolationlevelisolationlevel) 35. [.getColumnNamesSync()](#-35-getcolumnnamessync) 36. [.getColumnMetadataSync()](#-36-getcolumnmetadatasync) 37. [.getSQLErrorSync()](#-37-getsqlerrorsync) 38. [.debug(value)](#-38-debugvalue) 39. [.executeFileSync(sqlFile,[delimiter],[outputFile])](#-39-executefilesyncsqlfiledelimiteroutputfile) 40. [.executeFile(sqlFile,[delimiter],[outputFile])](#-40-executefilesqlfiledelimiteroutputfile) 41. [.setAttr(attributeName, value, callback)](#-41-setattrattributename-value-callback) 42. [.setAttrSync(attributeName, value)](#-42-setattrsyncattributename-value) 43. [.getInfo(infoType, [infoLength], callback)](#-43-getinfoinfotype-infolength-callback) 44. [.getInfoSync(infoType, [infoLength])](#-44-getinfosyncinfotype-infolength) 45. [.getTypeInfo(dataType, callback)](#-45-gettypeinfodatatype-callback) 46. [.getTypeInfoSync(dataType)](#-46-gettypeinfosyncdatatype) 47. [.getFunctions(functionId, callback)](#-47-getfunctionsfunctionid-callback) 48. [.getFunctionsSync(functionId)](#-48-getfunctionssyncfunctionid) * [**Connection Pooling APIs**](#connection-pooling-apis) * [**bindingParameters**](#bindingparameters) * [**CALL Statement**](#call-statement) ### <a name="openApi"></a> 1) .open(connectionString, [options,] callback) Open a connection to a database. * **connectionString** - The connection string for your database. * For distributed platforms, the connection string is typically defined as: `DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=username;PWD=passwd` * For z/OS, the ODBC driver makes both local and remote connections using DSN, UID and PWD. The connection string is typically defined as: `DSN=dbname;UID=username;PWD=passwd`. To connect to remote Db2 databases, the connectivity information will need to be set up in the Communications Database (CDB). Please refer to scenario 1 in the following [article](https://www.ibm.com/developerworks/data/library/techarticle/0310chong/0310chong.html). For a complete list of supported configuration keywords, please refer to [CLI/ODBC configuration keywords](https://www.ibm.com/support/knowledgecenter/en/SSEPGG_11.1.0/com.ibm.db2.luw.apdv.cli.doc/doc/r0007964.html) * Selecting default schema is also supported using `CURRENTSCHEMA=schemaname;` (or CurrentSchema) * **options** - _OPTIONAL_ - Object type. Can be used to avoid multiple loading of native ODBC library for each call of `.open`. Also, can be used to pass connectTimeout value and systemNaming(true/false) for i5/OS server. * **callback** - `callback (err, conn)` ```javascript var ibmdb = require("ibm_db") , connStr = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=username;PWD=passwd"; ibmdb.open(connStr, function (err, connection) { if (err) { console.log(err); return; } connection.query("select 1 from sysibm.sysdummy1", function (err1, rows) { if (err1) console.log(err1); else console.log(rows); connection.close(function(err2) { if(err2) console.log(err2); }); }); }); ``` * <a name="SSLConnection"></a> **Secure Database Connection using SSL/TSL** - ibm_db supports secure connection to Database Server over SSL same as ODBC/CLI driver. If you have SSL Certificate from server or an CA signed certificate, just use it in connection string as below: ```javascript connStr = "DATABASE=database;HOSTNAME=hostname;PORT=port;Security=SSL;SSLServerCertificate=<cert.arm_file_path>;PROTOCOL=TCPIP;UID=username;PWD=passwd;"; ``` > Note the two extra keywords **Security** and **SSLServerCertificate** used in connection string. `SSLServerCertificate` should point to the SSL Certificate from server or an CA signed certificate. Also, `PORT` must be `SSL` port and not the TCPI/IP port. Make sure Db2 server is configured to accept connection on SSL port else `ibm_db` will throw SQL30081N error. > Value of `SSLServerCertificate` keyword must be full path of a certificate file generated for client authentication. It normally has `*.arm` or `*.cert` or `*.pem` extension. `ibm_db` do not support `*.jks` format file as it is not a certificate file but a Java KeyStore file, extract certificate from it using keytool and then use the cert file. > `ibm_db` uses IBM ODBC/CLI Driver for connectivity and it do not support a `*.jks` file as keystoredb as `keystore.jks` is meant for Java applications. Note that `*.jks` file is a `Java Key Store` file and it is not an SSL Certificate file. You can extract SSL certificate from JKS file using below `keytool` command: ``` keytool -exportcert -alias your_certificate_alias -file client_cert.cert -keystore keystore.jks ``` Now, you can use the generated `client_cert.cert` as the value of `SSLServerCertificate` in connection string. > `ibm_db` supports only ODBC/CLI Driver keywords in connection string: https://www.ibm.com/docs/en/db2/11.5?topic=odbc-cliodbc-configuration-keywords > Do not use keyworkds like `sslConnection=true` in connection string as it is a JDBC connection keyword and ibm_db ignores it. Corresponding ibm_db connection keyword for `sslConnection` is `Security` hence, use `Security=SSL;` in connection string instead. * To connect to dashDB in IBM Cloud, use below connection string: ``` connStr = "DATABASE=database;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=username;PWD=passwd;Security=SSL"; ``` > We just need to add **Security=SSL** in connection string to have a secure connection against Db2 server in IBM Cloud. **Note:** You can also create a KeyStore DB using GSKit command line tool and use it in connection string along with other keywords as documented in [DB2 Infocenter](http://www.ibm.com/support/knowledgecenter/en/SSEPGG_11.5.0/com.ibm.db2.luw.admin.sec.doc/doc/t0053518.html). If you have created a KeyStore DB using GSKit using password or you have got *.kdb file with *.sth file, use connection string in below format: ``` connStr = "DATABASE=database;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=db2pwd;" + "Security=SSL;SslClientKeystoredb=C:/client.kdb;SSLClientKeystash=C:/client.sth;"; OR, connStr = "DATABASE=database;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=db2pwd;" + "Security=SSL;SslClientKeystoredb=C:/client.kdb;SSLClientKeystoreDBPassword=kdbpasswd;"; ``` > If you have downloaded `IBMCertTrustStore` from IBM site, ibm_db will not work with it; you need to download `Secure Connection Certificates.zip` file that comes for IBM DB2 Command line tool(CLP). `Secure Connection Certificates.zip` has *.kdb and *.sth files that should be used as the value of `SSLClientKeystoreDB` and `SSLClientKeystash` in connection string. ### <a name="openSyncApi"></a> 2) .openSync(connectionString [,options]) Synchronously open a connection to a database. * **connectionString** - The connection string for your database * **options** - _OPTIONAL_ - Object type. Can be used to avoid multiple loading of native ODBC library for each call of `.open`. Also, can be used to pass connectTimeout value and systemNaming value for i5/OS server. ```javascript var ibmdb = require("ibm_db"), connString = "DATABASE=database;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=username;PWD=password;"; try { var option = { connectTimeout : 40, systemNaming : true };// Connection Timeout after 40 seconds. var conn = ibmdb.openSync(connString, option); conn.query("select * from customers fetch first 10 rows only", function (err, rows) { if (err) { console.log(err); } else { console.log(rows); } conn.close(); }); } catch (e) { console.log(e.message); } ``` ### <a name="queryApi"></a> 3) .query(sqlQuery [, bindingParameters], callback) Issue an asynchronous SQL query to the database which is currently open. * **sqlQuery** - The SQL query to be executed or an Object in the form {"sql": sqlQuery, "params":bindingParameters, "noResults": noResultValue, "ArraySize": n}. noResults accepts only true or false values. If true - query() will not return any result. "sql" field is mandatory in Object, others are _OPTIONAL_. For **Array Insert**, `ArraySize` must be passed and sqlQuery must be an object. Check [test-array-insert.js](https://github.com/ibmdb/node-ibm_db/blob/master/test/test-array-insert.js) for example. * **bindingParameters** - _OPTIONAL_ - An array of values that will be bound to any '?' characters in `sqlQuery`. bindingParameters in sqlQuery Object takes precedence over it. * **callback** - `callback (err, rows, sqlca)` ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=database;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=username;PWD=password;" ; ibmdb.open(cn, function (err, conn) { if (err) { return console.log(err); } // we now have an open connection to the database, so lets get some data. // Execute multiple query and get multiple result sets. // In case of multiple resultset, query will return an array of result sets. conn.query("select 1 from sysibm.sysdummy1;select 2 from sysibm.sysdummy1;" + "select 3 from sysibm.sysdummy1", function (err, rows, sqlca) { if (err) { console.log(err); } else { console.log(rows); // rows = [ [ { '1': 1 } ], [ { '1': 2 } ], [ { '1': 3 } ] ] } }); }); ``` Example for Array Insert: ```javascript var param1 = {ParamType:"ARRAY", DataType:1, Data:[4,5,6,7,8]}; var param2 = {ParamType:"ARRAY", DataType:"DOUBLE", Data:[4.1,5.3,6.14,7,8.3]}; var param3 = {ParamType:"ARRAY", DataType:1, Data:[0,1,false,true,0]}; var namearr = ["Row 10", "Row 203456", "Row 30", "Row 40", "Last Row"]; var param4 = {ParamType:"ARRAY", DataType:1, Data:namearr, Length:8}; // *** Use "Length: <maxDataLen>" in param Object for unequal size of data. // Default value is the length of first member of Array. var queryOptions = {sql:"insert into arrtab values (?, ?, ?, ?)", params: [param1, param2, param3, param4], ArraySize:5}; conn.querySync("create table arrtab (c1 int, c2 double, c3 boolean, c4 varchar(10))"); conn.query(queryOptions, function(err, result) { if(err) console.log(err); else { var data = conn.querySync("select * from arrtab"); console.log("\nSelected data for table ARRTAB =\n", data); } }); ``` ### <a name="querySyncApi"></a> 4) .querySync(sqlQuery [, bindingParameters]) Synchronously issue a SQL query to the database that is currently open. * **sqlQuery** - The SQL query to be executed or an Object in the form {"sql": sqlQuery, "params":bindingParameters, "noResults": noResultValue, "ArraySize": n}. noResults accepts only true or false values. If true - query() will not return any result. If noResults is true for CALL statement, querySync returns only OutParams. "sql" field is mandatory in Object, others are optional. For **Array Insert**, `ArraySize` must be passed and sqlQuery must be an object. Check [test-array-insert.js](https://github.com/ibmdb/node-ibm_db/blob/master/test/test-array-insert.js) for example. * **bindingParameters** - _OPTIONAL_ - An array of values that will be bound to any '?' characters in `sqlQuery`. ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=database;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=username;PWD=password"; ibmdb.open(cn, function(err, conn){ //blocks until the query is completed and all data has been acquired var rows = conn.querySync("select * from customers fetch first 10 rows only"); console.log(rows); }); ``` Example for Array Insert: ```javascript var param1 = {ParamType:"ARRAY", DataType:1, Data:[4,5,6,7,8]}; var param2 = {ParamType:"ARRAY", DataType:"DOUBLE", Data:[4.1,5.3,6.14,7,8.3]}; var param3 = {ParamType:"ARRAY", DataType:1, Data:[0,1,false,true,0]}; var namearr = ["Row 10", "Row 20", "Row 30", "Row 40", "Last Row"]; var param4 = {ParamType:"ARRAY", DataType:1, Data:namearr, Length:8}; // *** Use "Length: <maxDataLen>" in param Object for unequal size of data. // Default value is the length of first member of Array. var queryOptions = {sql:"insert into arrtab values (?, ?, ?, ?)", params: [param1, param2, param3, param4], ArraySize:5}; conn.querySync("create table arrtab (c1 int, c2 double, c3 boolean, c4 varchar(10))"); conn.querySync(queryOptions); ``` ### <a name="queryStreamApi"></a> 5) .queryStream(sqlQuery [, bindingParameters]) Synchronously issue a SQL query to the database that is currently open and returns a Readable stream. Application can listen the events emmitted by returned stream and take action. * **sqlQuery** - The SQL query to be executed or an Object in the form {"sql": sqlQuery, "params":bindingParameters, "noResults": noResultValue, "ArraySize": n}. noResults accepts only true or false values. If true - query() will not return any result. "sql" field is mandatory in Object, others are optional. For **Array Insert**, `ArraySize` must be passed and sqlQuery must be an object. Check [test-array-insert.js](https://github.com/ibmdb/node-ibm_db/blob/master/test/test-array-insert.js) for example. * **bindingParameters** - _OPTIONAL_ - An array of values that will be bound to any '?' characters in `sqlQuery`. ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn, function(err, conn) { var stream = conn.queryStream("select 1 from sysibm.sysdummy1"); stream.once('data', function (result) { console.log(result); }).once('error', function (err) { conn.closeSync(); throw err; }).once('end', function () { conn.close(function(){ console.log("done.") }); }); }); ``` ### <a name="queryResultApi"></a> 6) .queryResult(sqlQuery, [, bindingParameters], callback) Issue an asynchronous SQL query to the database which is currently open and return (err, result, outparams) to callback function. `result` is ODBCResult object. Uisng `result`, call `result.fetchAllSync()` to retrieve all rows; call `result.getColumnMetadataSync()` to get meta data info or call `result.fetchSync()` to retrieve each row one by one and process. Execute `result.closeSync()` once done with the `result` object. `query` returns all the rows on call, but `queryResult` returns the result object and rows need to be fetched by the caller. * **sqlQuery** - The SQL query to be executed or an Object in the form {"sql": sqlQuery, "params":bindingParameters, "noResults": noResultValue, "ArraySize": n}. noResults accepts only true or false values. If true - queryResult() will not return any result object and value of result will be null. "sql" field is mandatory in Object, others are _OPTIONAL_. For **Array Insert**, `ArraySize` must be passed and sqlQuery must be an object. Check [test-array-insert.js](https://github.com/ibmdb/node-ibm_db/blob/master/test/test-array-insert.js) for example. * **bindingParameters** - _OPTIONAL_ - An array of values that will be bound to any ? characters (called parameter marker) in `sqlQuery`. bindingParameters in sqlQuery Object takes precedence over it. * **callback** - `callback (err, result, outparams)`. outparams is returned only for CALL statement with OUT parameters. Any resultset expected from SP should get retrieved using result.fetch apis. ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=database;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=username;PWD=password;" ; ibmdb.open(cn, function (err,conn) { if (err) return console.log(err); var query = 'select creator, name from sysibm.systables where 1 = ?'; conn.queryResult(query, [1], function (err, result) { if(err) { console.log(err); } else { console.log("data = ", result.fetchAllSync()); console.log("metadata = ", result.getColumnMetadataSync()); result.closeSync(); // Must call in application. conn.closeSync(); console.log("Executed ", ++loop, " times."); } }); }); ``` **Note:** Once you are done with the `result` object, must close it to avoid error when garbage collector of javascript free it. Not calling the `result.closeSync() may cause invalid handle error in application or no data. ### <a name="queryResultSyncApi"></a> 7) .queryResultSync(sqlQuery [, bindingParameters]) Synchronously issue a SQL query to the database that is currently open and return a result object to the callback function on success. In case of CALL statement with OUT parameters, it returns an array of [result, outparams]. `result` is an ODBCResult object that can be used to fetch rows. `querySync`API returns all the rows on call, but `queryResultSync` API returns the `ODBCResult` object using which application should call fetch APIs to get data. * **sqlQuery** - The SQL query to be executed or an Object in the form {"sql": sqlQuery, "params":bindingParameters, "noResults": noResultValue, "ArraySize": n}. noResults accepts only true or false values. If true - the value of `result` will be null. "sql" field is mandatory in Object, others are optional. For **Array Insert**, `ArraySize` must be passed and sqlQuery must be an object. Check [test-array-insert.js](https://github.com/ibmdb/node-ibm_db/blob/master/test/test-array-insert.js) for example. * **bindingParameters** - _OPTIONAL_ - An array of values that will be bound to any '?' characters in `sqlQuery`. ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=database;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=username;PWD=password"; ibmdb.open(cn, function(err, conn){ if (err) return console.log(err); var query = 'select creator, name from sysibm.systables'; var result = conn.queryResultSync(query); console.log("data = ", result.fetchAllSync()); console.log("metadata = ", result.getColumnMetadataSync()); result.closeSync(); // Must call to free to avoid application error. conn.closeSync(); }); ``` **Note:** Once you are done with the `result` object, must close it to avoid error when garbage collector of javascript free it. Not calling the `result.closeSync() may cause invalid handle error in application or no data. In case of CALL statement with OUT params, check result[0] is an object or not. ### <a name="closeApi"></a> 8) .close(callback) Close the currently opened database. * **callback** - `callback (err)` ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn, function (err, conn) { if (err) { return console.log(err); } //we now have an open connection to the database conn.close(function (err) { console.log("the database connection is now closed"); }); }); ``` ### <a name="closeSyncApi"></a> 9) .closeSync() Synchronously close the currently opened database. ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn, function(err, conn){ if (err) return console.log(err); //Blocks until the connection is closed conn.closeSync(); }); var conn = ibmdb.openSync(connString, option); conn.closeSync(); ``` ### <a name="prepareApi"></a> 10) .prepare(sql, callback) Prepare a statement for execution. * **sql** - SQL string to prepare * **callback** - `callback (err, stmt)` Returns a `Statement` object via the callback ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn,function(err,conn){ conn.prepare("insert into hits (col1, col2) VALUES (?, ?)", function (err, stmt) { if (err) { //could not prepare for some reason console.log(err); return conn.closeSync(); } //Bind and Execute the statment asynchronously stmt.execute(['something', 42], function (err, result) { if( err ) console.log(err); else result.closeSync(); //Close the connection conn.close(function(err){}); }); }); }); ``` ### <a name="prepareSyncApi"></a> 11) .prepareSync(sql) Synchronously prepare a statement for execution. * **sql** - SQL string to prepare Returns a `Statement` object ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn,function(err,conn){ var stmt = conn.prepareSync("select * from employee where empid = ?"); //Bind and Execute the statment asynchronously stmt.execute([142], function (err, result) { data = result.fetchAllSync(); console.log(data); result.closeSync(); stmt.closeSync(); //Close the connection conn.close(function(err){}); }); }); ``` ### <a name="bindApi"></a> 12) .bind(bindingParameters, callback) Binds the parameters for prepared statement. * **bindingParameters** - An array of values that will be bound to any '?' characters in prepared sql statement. Values can be array or object itself. Check [bindingParameters](#bindParameters) doc for detail. * **callback** - `callback (err)` * For **ARRAY INSERT** - Each value should be an array of size passed as `ArraySize` in query() APIs or equal to the value of attribute SQL_ATTR_PARAMSET_SIZE set using setAttr() APIs for prepared statement. ### <a name="bindSyncApi"></a> 13) .bindSync(bindingParameters) Binds the parameters for prepared statement synchronously. If `bindSync()` is used, then no need to pass `bindingParameters` to next `execute()` or `executeSync()` statement. * **bindingParameters** - An array of values that will be bound to any '?' characters in prepared sql statement. Values can be array or object itself. Check [bindingParameters](#bindParameters) doc for detail. * For **ARRAY INSERT** - Each value should be an array of size passed as `ArraySize` in query() APIs or equal to the value of attribute SQL_ATTR_PARAMSET_SIZE set using setAttr() APIs for prepared statement. ### <a name="executeApi"></a> 14) .execute([bindingParameters], callback) Execute a prepared statement. * **bindingParameters** - OPTIONAL - An array of values that will be bound to any '?' characters in prepared sql statement. Values can be array or object itself. Check [bindingParameters](#bindParameters) doc for detail. * **callback** - `callback (err, result, outparams)` outparams - will have result for INOUT and OUTPUT parameters of Stored Procedure. * For **ARRAY INSERT** - Statement attribute SQL_ATTR_PARAMSET_SIZE must be set before calling execute() API. Returns a `Statement` object via the callback ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn,function(err,conn){ conn.querySync("create table mytab (id int, photo BLOB(30K))"); conn.prepare("insert into mytab (id, photo) VALUES (?, ?)", function (err, stmt) { if (err) { //could not prepare for some reason console.log(err); return conn.closeSync(); } // Create params object var img = {ParamType:"FILE", DataType: "BLOB", "Data": "smile.jpg"}; //Bind and Execute the statment asynchronously stmt.execute([ 42, img ], function (err, result) { if( err ) console.log(err); else result.closeSync(); //Close the connection stmt.close(function(err){ if(err){ console.log(err) } conn.close(function(err){}); }); }); }); }); ``` ### <a name="executeSyncApi"></a> 15) .executeSync([bindingParameters]) Execute a prepared statement synchronously. * **bindingParameters** - OPTIONAL - An array of values that will be bound to any '?' characters in prepared sql statement. Values can be array or object itself. Check [bindingParameters](#bindParameters) doc for detail. Instead of passing bindingParameters to executeSync(), parameters can also be binded using bind() or bindSync() APIs. * For **ARRAY INSERT** - Statement attribute SQL_ATTR_PARAMSET_SIZE must be set before calling execute() API. Returns a `Statement` object. If prepared statement is a stored procedure with INOUT or OUT parameter, executeSync() returns an array of two elements in the form [stmt, outparams]. The first element of such array is an `Statement` object and second element is an `Array` of INOUT and OUTPUT parameters in sequence. ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn,function(err,conn){ var stmt = conn.prepareSync("select empname from emptable where empid = ?"); //Bind and Execute the statment asynchronously var result = stmt.executeSync([142]); var data = result.fetchAllSync({fetchMode:3}); // Fetch data in Array mode. console.log(data); result.closeSync(); stmt.closeSync(); //Close the connection conn.close(function(err){}); }); ``` ### <a name="executeNonQueryApi"></a> 16) .executeNonQuery([bindingParameters], callback) Execute a non query prepared statement and returns the number of rows affected in a table by the statement. * **bindingParameters** - OPTIONAL - An array of values that will be bound to any '?' characters in prepared sql statement. Values can be array or object itself. Check [bindingParameters](#bindParameters) doc for detail. * **callback** - `callback (err, affectedRowCount)` * For **ARRAY INSERT** - Statement attribute SQL_ATTR_PARAMSET_SIZE must be set before calling execute() API. It returns the number of rows in a table that were affected by an UPDATE, an INSERT, a DELETE, or a MERGE statement issued against the table, or a view based on the table. If no rows are affected, it returns -1 via the callback function. ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn,function(err,conn){ conn.querySync("create table mytab (id int, text varchar(30))"); conn.prepare("insert into mytab (id, text) VALUES (?, ?)", function (err, stmt) { if (err) { console.log(err); return conn.closeSync(); } //Bind and Execute the statment asynchronously stmt.executeNonQuery([ 42, 'hello world' ], function (err, ret) { if( err ) console.log(err); else console.log("Affected rows = " + ret); //Close the stmt and connection stmt.close(); conn.close(function(err){}); }); }); }); ``` ### <a name="executeNonQuerySyncApi"></a> 17) .executeNonQuerySync([bindingParameters]) Execute a non query prepared statement synchronously and returns the number of rows affected in a table by the statement. * **bindingParameters** - OPTIONAL - An array of values that will be bound to any '?' characters in prepared sql statement. Values can be array or object itself. Check [bindingParameters](#bindParameters) doc for detail. * For **ARRAY INSERT** - Statement attribute SQL_ATTR_PARAMSET_SIZE must be set before calling execute() API. It returns the number of rows in a table that were affected by an UPDATE, an INSERT, a DELETE, or a MERGE statement issued against the table, or a view based on the table. If no rows are affected, it returns -1. ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn,function(err,conn){ conn.querySync("create table mytab (id int, text varchar(30))"); conn.prepare("insert into mytab (id, text) VALUES (?, ?)", function (err, stmt) { if (err) { console.log(err); return conn.closeSync(); } //Bind and Execute the statment asynchronously var rowCount = stmt.executeNonQuerySync([ 42, 'hello world' ]); console.log("Affected rows = " + rowCount); //Close the stmt and connection stmt.closeSync(); conn.closeSync(); }); }); ``` ### <a name="stmtCloseApi"></a> 18) stmt.close(callback) Close the currently opened statement object and free resources. * **callback** - `callback (err)` ```javascript stmt.close(function(err) { if(err) console.log(err); }); //OR stmt.close(); //OR await stmt.close(); ``` ### <a name="stmtCloseSyncApi"></a> 19) stmt.closeSync() Synchronously close the currently opened statement object and free resources. ```javascript stmt.closeSync(); ``` ### <a name="fetchApi"></a> 20) .fetch(option, callback) Fetch a row of data from ODBCResult object asynchronously. * **option** - _OPTIONAL_ - Object type. * fetchMode - Format of returned row data. By default row data get returned in object form. option = {fetchMode:3} or option = {fetchMode: ibmdb.FETCH_ARRAY} will return row in array form. Default value of fetchMode is ibmdb.FETCH_OBJECT. * When option = {fetchMode : 0} or {fetchMode: ibmdb.FETCH_NODATA} is used, fetch() API do not return any result and application need to call result.getData() or result.getDataSync() API to retrieve data for a column. * **callback** - `callback (err, row)`. When no `callback` function is passed, fetch() will return Promise. ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn,function(err,conn){ conn.querySync("create table hits (col1 varchar(40), col2 int)"); conn.querySync("insert into hits values ('something', 42)"); conn.querySync("insert into hits values ('für', 43)"); conn.prepare("select * from hits", function (err, stmt) { if (err) { //could not prepare for some reason console.log(err); return conn.closeSync(); } stmt.execute(function (err, result) { if( err ) console.log(err); result.fetch((err, row) => { if(err) { console.log(err); } else { console.log("Row1 = ", row); result.fetch({fetchMode:ibmdb.FETCH_ARRAY}).then(row => { console.log("Row2 = ", row); result.closeSync(); conn.querySync("drop table hits"); //Close the connection conn.close(function(err){console.log("Connection Closed.");}); }).catch(err => console.log(err)); } }); }); }); }); ``` ### <a name="fetchSyncApi"></a> 21) .fetchSync(option) Fetch a row of data from ODBCResult object synchronously. * **option** - _OPTIONAL_ - Object type. * fetchMode - Format of returned row data. By default row data get returned in object form. option = {fetchMode:3} or option = {fetchMode: ibmdb.FETCH_ARRAY} will return row in array form. Default value of fetchMode is ibmdb.FETCH_OBJECT. * When option = {fetchMode : 0} or {fetchMode: ibmdb.FETCH_NODATA} is used, fetch() API do not return any result and application need to call result.getData() or result.getDataSync() API to retrieve data for a column. ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn,function(err,conn){ conn.querySync("create table hits (col1 varchar(40), col2 int)"); conn.querySync("insert into hits values ('something', 42)"); conn.querySync("insert into hits values ('für', 43)"); var stmt = conn.prepareSync("select * from hits"); var result = stmt.executeSync(); var data = 0; while( data = result.fetchSync({fetchMode:3}) ) { console.log(data); } result.closeSync(); conn.querySync("drop table hits"); conn.closeSync(); }); ``` ### <a name="fetchAllApi"></a> 22) .fetchAll(option, callback) Fetch all rows from ODBCResult object asynchronously for the executed statement. * **option** - _OPTIONAL_ - Object type. * fetchMode - Format of returned row data. By default row data get returned in object form. option = {fetchMode:3} will return rows in array form. {fetchMode:4} - return rows in object form. * **callback** - `callback (err, data, noOfColumns)` ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn,function(err,conn){ conn.querySync("create table hits (col1 varchar(40), col2 int)"); conn.querySync("insert into hits values ('something', 42)"); conn.querySync("insert into hits values ('für', 43)"); conn.prepare("select * from hits", function (err, stmt) { if (err) { //could not prepare for some reason console.log(err); return conn.closeSync(); } stmt.execute(function (err, result) { if( err ) console.log(err); result.fetchAll({fetchMode:4}, function (err, data, colcount) { if(err) { console.log(err); } else { console.log("Data = ", data); console.log("No of columns = ", colcount); } result.closeSync(); conn.querySync("drop table hits"); //Close the connection conn.close(function(err){console.log("Connection Closed.");}); }); }); }); }); ``` ### <a name="fetchAllSyncApi"></a> 23) .fetchAllSync(option) Fetch all rows from ODBCResult object Synchronously for the executed statement. * **option** - Optional object to specify return type of data. By default row data get returned in object form. option = {fetchMode:3} will return row in array form. ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn,function(err,conn){ conn.querySync("create table hits (col1 varchar(40), col2 int)"); conn.querySync("insert into hits values ('something', 42)"); conn.querySync("insert into hits values ('für', 43)"); var stmt = conn.prepareSync("select * from hits"); var result = stmt.executeSync(); var data = result.fetchAllSync(); console.log("Fetched data = ", data); result.closeSync(); conn.querySync("drop table hits"); conn.closeSync(); }); ``` For example of prepare once and execute many times with above fetch APIs, please see test file [test-fetch-apis.js](https://github.com/ibmdb/node-ibm_db/blob/master/test/test-fetch-apis.js). ### <a name="getDataApi"></a> 24) .getData(colNum, Size, callback) Retrive data for colNum of specified size from ODBCResult object asynchronously. * **colNum** - Integer - Column Number in the resultset starting from 1. * **Size** - Integer - Size of the data being retrieved. For fixed length data, it get ignored. * **callback** - `callback (err, row)`. When no `callback` function is passed, getData() will return Promise. ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn,function(err,conn){ conn.querySync("create table hits (col1 varchar(40), col2 int)"); conn.querySync("insert into hits values ('something', 42)"); conn.querySync("insert into hits values ('für', 43)"); var stmt = conn.prepareSync("select * from hits"); var result = stmt.executeSync(); result.fetch({fetchMode:0}) .then(() => { return result.getData(1, 4); }).then(data => { console.log(data); return result.getData(1, 5); }).then(data => { console.log(data); return result.getData(2, 5); }).then(data => { console.log(data); return result.getData(3, 5); }).then(data => { console.log(data); }).catch(err => console.log(err)); ``` See test file [test-fetch-apis.js](https://github.com/ibmdb/node-ibm_db/blob/master/test/test-fetch-apis.js) for detail example. ### <a name="getDataSyncApi"></a> 25) .getDataSync(colNum, Size) Retrive data for colNum of specified size from ODBCResult object synchronously. * **colNum** - Integer - Column Number in the resultset starting from 1. * **Size** - Integer - Size of the data being retrieved. For fixed length data, it get ignored. ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn,function(err,conn){ conn.querySync("create table hits (col1 varchar(40), col2 int)"); conn.querySync("insert into hits values ('something', 42)"); conn.querySync("insert into hits values ('für', 43)"); var stmt = conn.prepareSync("select * from hits"); var result = stmt.executeSync(); console.log(result.fetchSync({fetchMode:0})); console.log("First Row Data = "); console.log(result.getDataSync(1, 4)); console.log(result.getDataSync(1, 5)); console.log(result.getDataSync(2, 5)); console.log(result.getDataSync(3, 5)); result.fetchSync({fetchMode:0}); console.log("Second Row Data = "); console.log(result.getDataSync(1, 4)); console.log(result.getDataSync(1, 5)); console.log(result.getDataSync(2, 5)); console.log(result.getDataSync(3, 5)); result.closeSync(); conn.closeSync(); } ``` See test file [test-fetch-apis.js](https://github.com/ibmdb/node-ibm_db/blob/master/test/test-fetch-apis.js) for detail example. ### <a name="resultCloseApi"></a> 26) result.close(callback) Close the currently opened ODBC Result object and free resources. * **callback** - `callback (err)` ```javascript result.close(function(err) { if(err) console.log(err); }); //OR result.close(); //OR await result.close(); ``` ### <a name="resultCloseSyncApi"></a> 27) result.closeSync() Synchronously close the currently opened ODBC Result object and free resources. ```javascript result.closeSync(); ``` ### <a name="beginTransactionApi"></a> 28) .beginTransaction(callback) Begin a transaction * **callback** - `callback (err)` ### <a name="beginTransactionSyncApi"></a> 29) .beginTransactionSync() Synchronously begin a transaction ### <a name="commitTransactionApi"></a> 30) .commitTransaction(callback) Commit a transaction * **callback** - `callback (err)` ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn, function(err,conn) { conn.beginTransaction(function (err) { if (err) { //could not begin a transaction for some reason. console.log(err); return conn.closeSync(); } var result = conn.querySync("insert into customer (customerCode) values ('stevedave')"); conn.commitTransaction(function (err) { if (err) { //error during commit console.log(err); return conn.closeSync(); } console.log(conn.querySync("select * from customer where customerCode = 'stevedave'")); //Close the connection conn.closeSync(); }); }); }); ``` ### <a name="commitTransactionSyncApi"></a> 31) .commitTransactionSync() Synchronously commit a transaction ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn, function(err,conn) { conn.beginTransaction(function (err) { if (err) { //could not begin a transaction for some reason. console.log(err); return conn.closeSync(); } var result = conn.querySync("insert into customer (customerCode) values ('stevedave')"); conn.commitTransactionSync(); console.log(conn.querySync("select * from customer where customerCode = 'stevedave'")); //Close the connection conn.closeSync(); }); }); ``` ### <a name="rollbackTransactionApi"></a> 32) .rollbackTransaction(callback) Rollback a transaction * **callback** - `callback (err)` ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn, function(err,conn) { conn.beginTransaction(function (err) { if (err) { //could not begin a transaction for some reason. console.log(err); return conn.closeSync(); } var result = conn.querySync("insert into customer (customerCode) values ('stevedave')"); conn.rollbackTransaction(function (err) { if (err) { //error during rollback console.log(err); return conn.closeSync(); } console.log(conn.querySync("select * from customer where customerCode = 'stevedave'")); //Close the connection conn.closeSync(); }); }); }); ``` ### <a name="rollbackTransactionSyncApi"></a> 33) .rollbackTransactionSync() Synchronously rollback a transaction ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn, function(err,conn) { conn.beginTransaction(function (err) { if (err) { //could not begin a transaction for some reason. console.log(err); return conn.closeSync(); } var result = conn.querySync("insert into customer (customerCode) values ('stevedave')"); conn.rollbackTransactionSync(); console.log(conn.querySync("select * from customer where customerCode = 'stevedave'")); //Close the connection conn.closeSync(); }); }); ``` ### <a name="setIsolationLevelApi"></a> 34) .setIsolationLevel(isolationLevel) Synchronously sets the default isolation level passed as argument. It is only applicable when the default isolation level is used. It will have no effect if the application has specifically set the isolation level for a transaction. * **isolationLevel:** An integer representing the isolation level to be set. Its value must be only - 1|2|4|8|32. For details check this [doc](https://www.ibm.com/support/knowledgecenter/en/SSEPGG_11.1.0/com.ibm.db2.luw.apdv.cli.doc/doc/r0008832.html). ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.open(cn, function(err,conn) { conn.setIsolationLevel(2); // SQL_TXN_READ_COMMITTED conn.setIsolationLevel(4); // SQL_TXN_REPEATABLE_READ conn.querySync("create table mytab1 (c1 int, c2 varchar(10))"); }); ``` ### <a name="getColumnNamesSyncApi"></a> 35) .getColumnNamesSync() Synchronously retrieve the name of columns returned by the resulset. It operates on ODBCResult object. ```javascript conn.querySync("insert into mytab1 values ( 5, 'abc')"); conn.prepare("select * from mytab1", function (err, stmt) { stmt.execute(function(err, result) { console.log("Column Names = ", result.getColumnNamesSync()); result.closeSync(); conn.closeSync(); }); }); ``` ### <a name="getColumnMetadataSyncApi"></a> 36) .getColumnMetadataSync() Synchronously retrieve the metadata about columns returned by the resulset. It operates on ODBCResult object. ```javascript conn.querySync("insert into mytab1 values ( 5, 'abc')"); conn.prepare("select * from mytab1", function (err, stmt) { stmt.execute(function(err, result) { console.log("Column Names = ", result.getColumnNamesSync()); console.log("Column Meta Data = ", result.getColumnMetadataSync()); console.log("Fetched Data = ", result.fetchAllSync() ); result.closeSync(); conn.closeSync(); }); }); ``` ### <a name="getSQLErrorSyncApi"></a> 37) .getSQLErrorSync() Synchronously retrieve the sqlerror message and codes for last instruction executed on a statement handle using SQLGetDiagRec ODBC API. It operates on ODBCResult object. ```javascript conn.querySync("insert into mytab1 values ( 5, 'abc')"); conn.prepare("select * from mytab1", function (err, stmt) { stmt.execute(function(err, result) { console.log("Fetched Data = ", result.fetchAllSync() ); var problem = result.getSQLErrorSync(); if (problem.sqlcode < 0) { // This sqlcode is negative and is therefore an error console.log("SQLError = ", problem); } else if (problem.sqlcode > 0) { // This sqlcode is positive and is therefore a warning console.log("SQLWarning = ", problem); } result.closeSync(); conn.closeSync(); }); }); ``` ### <a name="enableDebugLogs"></a> 38) .debug(value) Enable console logs. debug(true) do not log params that may have sensitive data. Support for debug(2) added to dump bind params. * **value** - true/false/2. Any truthy value enables debug mode. ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=dbname;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=dbuser;PWD=xxx"; ibmdb.debug(true); // **==> ENABLE CONSOLE LOGS, but do not log params. <==** ibmdb.debug(2); // **==> ENABLE CONSOLE LOGS and log parameter values too if passed. <==** ibmdb.open(cn, function (err, connection) { if (err) { console.log(err); return; } connection.query("select 1 from sysibm.sysdummy1", function (err1, rows) { if (err1) console.log(err1); else console.log(rows); ibmdb.debug(false); // Disable console logs. connection.close(function(err2) { if(err2) console.log(err2); }); }); }); ``` ### <a name="executeFileSyncApi"></a> 39) .executeFileSync(sqlFile,[delimiter],[outputFile]) Synchronously issue multiple SQL query from the file to the database that is currently open. * **sqlFile** - sqlFile input should be Full Path of the file. sqlFile can be an Object in the form { "sql": sqlFile, "delimiter": delimiter, "outputfile": outputfile }. "sql" field is mandatory in Object. * **delimiter** - (_OPTIONAL_ only incase of default delimiter `;`) - If the sqlFile contains other delimiters it is mandatory to mention delimiter. Delimiter splits mutliple query in the sqlFile. * **outputfile** - _OPTIONAL_ - Outputfile should be Full Path of the file and only select queries data will be copied to outputfile splitted by the delimiter. If the outputfile already exists it will be overwritten. If the outputfile is not mentioned the result will be returned splitted by the delimiter. ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=database;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=username;PWD=password"; ibmdb.open(cn, function(err, conn){ conn.executeFileSync('sample2.txt', '%','out.txt'); var rows = conn.executeFileSync('sample2.txt', '%'); console.log(rows) }); ``` ### <a name="executeFileApi"></a> 40) .executeFile(sqlFile,[delimiter],[outputFile]) Asynchronously issue multiple SQL query from the file to the database that is currently open. * **sqlFile** - sqlFile input should be Full Path of the file. sqlFile can be an Object in the form { "sql": sqlFile, "delimiter": delimiter, "outputfile": outputfile }. "sql" field is mandatory in Object. * **delimiter** - (_OPTIONAL_ only incase of default delimiter `;`) - If the sqlFile contains other delimiters it is mandatory to mention delimiter. Delimiter splits mutliple query in the sqlFile. * **outputfile** - _OPTIONAL_ - Outputfile should be Full Path of the file and only select queries data will be copied to outputfile splitted by the delimiter. If the outputfile already exists it will be overwritten. If the outputfile is not mentioned the result will be returned splitted by the delimiter. ```javascript var ibmdb = require("ibm_db") , cn = "DATABASE=database;HOSTNAME=hostname;PORT=port;PROTOCOL=TCPIP;UID=username;PWD=password"; ibmdb.o