node-oracledb/test/plsqlBindIndexedTable2.js

713 lines
24 KiB
JavaScript
Raw Normal View History

2022-04-19 08:06:36 +08:00
/* Copyright (c) 2015, 2022, Oracle and/or its affiliates. */
2017-06-14 09:54:45 +08:00
/******************************************************************************
*
* This software is dual-licensed to you under the Universal Permissive License
* (UPL) 1.0 as shown at https://oss.oracle.com/licenses/upl and Apache License
* 2.0 as shown at https://www.apache.org/licenses/LICENSE-2.0. You may choose
* either license.
2017-06-14 09:54:45 +08:00
*
* If you elect to accept the software under the Apache License, Version 2.0,
* the following applies:
*
* Licensed under the Apache License, Version 2.0 (the "License");
* you may not use this file except in compliance with the License.
2017-06-14 09:54:45 +08:00
* You may obtain a copy of the License at
*
* https://www.apache.org/licenses/LICENSE-2.0
2017-06-14 09:54:45 +08:00
*
* Unless required by applicable law or agreed to in writing, software
* distributed under the License is distributed on an "AS IS" BASIS,
* WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
2017-06-14 09:54:45 +08:00
* See the License for the specific language governing permissions and
* limitations under the License.
*
* NAME
* 44. plsqlBindIndexedTable2.js
*
* DESCRIPTION
* Testing PL/SQL indexed tables (associative arrays).
*
*****************************************************************************/
'use strict';
var oracledb = require('oracledb');
var should = require('should');
var async = require('async');
var dbConfig = require('./dbconfig.js');
describe('44. plsqlBindIndexedTable2.js', function() {
var credentials = {
user: dbConfig.user,
password: dbConfig.password,
connectString: dbConfig.connectString
};
var connection = null;
beforeEach(function(done) {
async.series([
function(callback) {
oracledb.getConnection(credentials, function(err, conn) {
should.not.exist(err);
connection = conn;
callback();
});
},
function createTab(callback) {
var proc = "BEGIN \n" +
" DECLARE \n" +
" e_table_missing EXCEPTION; \n" +
" PRAGMA EXCEPTION_INIT(e_table_missing, -00942);\n " +
" BEGIN \n" +
" EXECUTE IMMEDIATE ('DROP TABLE nodb_waveheight PURGE'); \n" +
" EXCEPTION \n" +
" WHEN e_table_missing \n" +
" THEN NULL; \n" +
" END; \n" +
" EXECUTE IMMEDIATE (' \n" +
" CREATE TABLE nodb_waveheight (beach VARCHAR2(50), depth NUMBER) \n" +
" '); \n" +
"END; ";
connection.execute(
proc,
function(err) {
should.not.exist(err);
callback();
}
);
},
function createPkg(callback) {
var proc = "CREATE OR REPLACE PACKAGE nodb_beachpkg IS\n" +
" TYPE beachType IS TABLE OF VARCHAR2(30) INDEX BY BINARY_INTEGER;\n" +
" TYPE depthType IS TABLE OF NUMBER INDEX BY BINARY_INTEGER;\n" +
" PROCEDURE array_in(beaches IN beachType, depths IN depthType);\n" +
" PROCEDURE array_out(beaches OUT beachType, depths OUT depthType); \n" +
" PROCEDURE array_inout(beaches IN OUT beachType, depths IN OUT depthType); \n" +
"END;";
connection.execute(
proc,
function(err) {
should.not.exist(err);
callback();
}
);
},
function(callback) {
var proc = "CREATE OR REPLACE PACKAGE BODY nodb_beachpkg IS \n" +
" PROCEDURE array_in(beaches IN beachType, depths IN depthType) IS \n" +
" BEGIN \n" +
" IF beaches.COUNT <> depths.COUNT THEN \n" +
" RAISE_APPLICATION_ERROR(-20000, 'Array lengths must match for this example.'); \n" +
" END IF; \n" +
" FORALL i IN INDICES OF beaches \n" +
" INSERT INTO nodb_waveheight (beach, depth) VALUES (beaches(i), depths(i)); \n" +
" END; \n" +
" PROCEDURE array_out(beaches OUT beachType, depths OUT depthType) IS \n" +
" BEGIN \n" +
" SELECT beach, depth BULK COLLECT INTO beaches, depths FROM nodb_waveheight; \n" +
" END; \n" +
" PROCEDURE array_inout(beaches IN OUT beachType, depths IN OUT depthType) IS \n" +
" BEGIN \n" +
" IF beaches.COUNT <> depths.COUNT THEN \n" +
" RAISE_APPLICATION_ERROR(-20001, 'Array lenghts must match for this example.'); \n" +
" END IF; \n" +
" FORALL i IN INDICES OF beaches \n" +
" INSERT INTO nodb_waveheight (beach, depth) VALUES (beaches(i), depths(i)); \n" +
" SELECT beach, depth BULK COLLECT INTO beaches, depths FROM nodb_waveheight ORDER BY 1; \n" +
" END; \n " +
"END;";
connection.execute(
proc,
function(err) {
should.not.exist(err);
callback();
}
);
},
function(callback) {
connection.commit(function(err) {
should.not.exist(err);
callback();
});
}
], done);
}); // before
afterEach(function(done) {
async.series([
function(callback) {
connection.execute(
"DROP TABLE nodb_waveheight PURGE",
function(err) {
should.not.exist(err);
callback();
}
);
},
function(callback) {
connection.execute(
"DROP PACKAGE nodb_beachpkg",
function(err) {
should.not.exist(err);
callback();
}
);
},
function(callback) {
connection.release(function(err) {
should.not.exist(err);
callback();
});
},
], done);
}); // after
it('44.1 example case', function(done) {
async.series([
// Pass arrays of values to a PL/SQL procedure
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_in(:beach_in, :depth_in); END;",
{
beach_in: { type: oracledb.STRING,
dir: oracledb.BIND_IN,
val: ["Malibu Beach", "Bondi Beach", "Waikiki Beach"] },
depth_in: { type: oracledb.NUMBER,
dir: oracledb.BIND_IN,
val: [45, 30, 67]
}
},
function(err) {
should.not.exist(err);
callback();
}
);
},
// Fetch arrays of values from a PL/SQL procedure
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_out(:beach_out, :depth_out); END;",
{
beach_out: { type: oracledb.STRING,
dir: oracledb.BIND_OUT,
maxArraySize: 3 },
depth_out: { type: oracledb.NUMBER,
dir: oracledb.BIND_OUT,
maxArraySize: 3 }
},
function(err, result) {
should.not.exist(err);
// console.log(result.outBinds);
(result.outBinds.beach_out).should.eql([ 'Malibu Beach', 'Bondi Beach', 'Waikiki Beach' ]);
(result.outBinds.depth_out).should.eql([45, 30, 67]);
callback();
}
);
},
function(callback) {
connection.rollback(function(err) {
should.not.exist(err);
callback();
});
},
// Return input arrays sorted by beach name
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_inout(:beach_inout, :depth_inout); END;",
{
beach_inout: { type: oracledb.STRING,
dir: oracledb.BIND_INOUT,
val: ["Port Melbourne Beach", "Eighty Mile Beach", "Chesil Beach"],
maxArraySize: 3},
depth_inout: { type: oracledb.NUMBER,
dir: oracledb.BIND_INOUT,
val: [8, 3, 70],
maxArraySize: 3}
},
function(err, result) {
should.not.exist(err);
//console.log(result.outBinds);
(result.outBinds.beach_inout).should.eql([ 'Chesil Beach', 'Eighty Mile Beach', 'Port Melbourne Beach' ]);
(result.outBinds.depth_inout).should.eql([ 70, 3, 8 ]);
callback();
}
);
}
], done);
}); // 44.1
it('44.2 example case binding by position', function(done) {
async.series([
// Pass arrays of values to a PL/SQL procedure
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_in(:1, :2); END;",
[
{ type: oracledb.STRING,
dir: oracledb.BIND_IN,
val: ["Malibu Beach", "Bondi Beach", "Waikiki Beach"] },
{ type: oracledb.NUMBER,
dir: oracledb.BIND_IN,
val: [45, 30, 67]
}
],
function(err) {
should.not.exist(err);
callback();
}
);
},
// Fetch arrays of values from a PL/SQL procedure
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_out(:1, :2); END;",
[
{ type: oracledb.STRING,
dir: oracledb.BIND_OUT,
maxArraySize: 3 },
{ type: oracledb.NUMBER,
dir: oracledb.BIND_OUT,
maxArraySize: 3 }
],
function(err, result) {
should.not.exist(err);
// console.log(result.outBinds);
(result.outBinds[0]).should.eql([ 'Malibu Beach', 'Bondi Beach', 'Waikiki Beach' ]);
(result.outBinds[1]).should.eql([45, 30, 67]);
callback();
}
);
},
function(callback) {
connection.rollback(function(err) {
should.not.exist(err);
callback();
});
},
// Return input arrays sorted by beach name
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_inout(:1, :2); END;",
[
{ type: oracledb.STRING,
dir: oracledb.BIND_INOUT,
val: ["Port Melbourne Beach", "Eighty Mile Beach", "Chesil Beach"],
maxArraySize: 3},
{ type: oracledb.NUMBER,
dir: oracledb.BIND_INOUT,
val: [8, 3, 70],
maxArraySize: 3}
],
function(err, result) {
should.not.exist(err);
// console.log(result.outBinds);
(result.outBinds[0]).should.eql([ 'Chesil Beach', 'Eighty Mile Beach', 'Port Melbourne Beach' ]);
(result.outBinds[1]).should.eql([ 70, 3, 8 ]);
callback();
}
);
}
], done);
});
it('44.3 default binding type and direction with binding by name', function(done) {
async.series([
// Pass arrays of values to a PL/SQL procedure
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_in(:beach_in, :depth_in); END;",
{
beach_in: { //type: oracledb.STRING,
2017-06-17 07:40:09 +08:00
//dir: oracledb.BIND_IN,
2017-06-14 09:54:45 +08:00
val: ["Malibu Beach", "Bondi Beach", "Waikiki Beach"] },
depth_in: { type: oracledb.NUMBER,
dir: oracledb.BIND_IN,
val: [45, 30, 67]
}
},
function(err) {
should.not.exist(err);
callback();
}
);
},
// Fetch arrays of values from a PL/SQL procedure
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_out(:beach_out, :depth_out); END;",
{
beach_out: { type: oracledb.STRING,
dir: oracledb.BIND_OUT,
maxArraySize: 3 },
depth_out: { type: oracledb.NUMBER,
dir: oracledb.BIND_OUT,
maxArraySize: 3 }
},
function(err, result) {
should.not.exist(err);
// console.log(result.outBinds);
(result.outBinds.beach_out).should.eql([ 'Malibu Beach', 'Bondi Beach', 'Waikiki Beach' ]);
(result.outBinds.depth_out).should.eql([45, 30, 67]);
callback();
}
);
},
function(callback) {
connection.rollback(function(err) {
should.not.exist(err);
callback();
});
},
// Return input arrays sorted by beach name
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_inout(:beach_inout, :depth_inout); END;",
{
beach_inout: { type: oracledb.STRING,
dir: oracledb.BIND_INOUT,
val: ["Port Melbourne Beach", "Eighty Mile Beach", "Chesil Beach"],
maxArraySize: 3},
depth_inout: { type: oracledb.NUMBER,
dir: oracledb.BIND_INOUT,
val: [8, 3, 70],
maxArraySize: 3}
},
function(err, result) {
should.not.exist(err);
//console.log(result.outBinds);
(result.outBinds.beach_inout).should.eql([ 'Chesil Beach', 'Eighty Mile Beach', 'Port Melbourne Beach' ]);
(result.outBinds.depth_inout).should.eql([ 70, 3, 8 ]);
callback();
}
);
}
], done);
}); // 44.3
it('44.4 default binding type and direction with binding by position', function(done) {
async.series([
// Pass arrays of values to a PL/SQL procedure
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_in(:1, :2); END;",
[
{ type: oracledb.STRING,
2017-06-17 07:40:09 +08:00
// dir: oracledb.BIND_IN,
2017-06-14 09:54:45 +08:00
val: ["Malibu Beach", "Bondi Beach", "Waikiki Beach"] },
{ type: oracledb.NUMBER,
dir: oracledb.BIND_IN,
val: [45, 30, 67]
}
],
function(err) {
should.not.exist(err);
callback();
}
);
},
// Fetch arrays of values from a PL/SQL procedure
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_out(:1, :2); END;",
[
{ type: oracledb.STRING,
dir: oracledb.BIND_OUT,
maxArraySize: 3 },
{ type: oracledb.NUMBER,
dir: oracledb.BIND_OUT,
maxArraySize: 3 }
],
function(err, result) {
should.not.exist(err);
// console.log(result.outBinds);
(result.outBinds[0]).should.eql([ 'Malibu Beach', 'Bondi Beach', 'Waikiki Beach' ]);
(result.outBinds[1]).should.eql([45, 30, 67]);
callback();
}
);
},
function(callback) {
connection.rollback(function(err) {
should.not.exist(err);
callback();
});
},
// Return input arrays sorted by beach name
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_inout(:1, :2); END;",
[
{ type: oracledb.STRING,
dir: oracledb.BIND_INOUT,
val: ["Port Melbourne Beach", "Eighty Mile Beach", "Chesil Beach"],
maxArraySize: 3},
{ type: oracledb.NUMBER,
dir: oracledb.BIND_INOUT,
val: [8, 3, 70],
maxArraySize: 3}
],
function(err, result) {
should.not.exist(err);
// console.log(result.outBinds);
(result.outBinds[0]).should.eql([ 'Chesil Beach', 'Eighty Mile Beach', 'Port Melbourne Beach' ]);
(result.outBinds[1]).should.eql([ 70, 3, 8 ]);
callback();
}
);
}
], done);
});
it('44.5 null elements in String and Number arrays', function(done) {
async.series([
// Pass arrays of values to a PL/SQL procedure
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_in(:beach_in, :depth_in); END;",
{
beach_in: { type: oracledb.STRING,
dir: oracledb.BIND_IN,
val: ["Malibu Beach", "Bondi Beach", null, "Waikiki Beach", '', null] },
depth_in: { type: oracledb.NUMBER,
dir: oracledb.BIND_IN,
val: [null, null, 45, 30, 67, null, ]
}
},
function(err) {
2023-02-21 09:33:06 +08:00
callback(err);
2017-06-14 09:54:45 +08:00
}
);
},
// Fetch arrays of values from a PL/SQL procedure
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_out(:beach_out, :depth_out); END;",
{
beach_out: { type: oracledb.STRING,
dir: oracledb.BIND_OUT,
maxArraySize: 10 },
depth_out: { type: oracledb.NUMBER,
dir: oracledb.BIND_OUT,
maxArraySize: 10 }
},
function(err, result) {
should.not.exist(err);
// console.log(result.outBinds);
(result.outBinds.beach_out).should.eql([ 'Malibu Beach', 'Bondi Beach', null, 'Waikiki Beach', null, null ]);
(result.outBinds.depth_out).should.eql([ null, null, 45, 30, 67, null ]);
callback();
}
);
},
function(callback) {
connection.rollback(function(err) {
should.not.exist(err);
callback();
});
},
// Return input arrays sorted by beach name
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_inout(:beach_inout, :depth_inout); END;",
{
beach_inout: { type: oracledb.STRING,
dir: oracledb.BIND_INOUT,
val: ["Port Melbourne Beach", "Eighty Mile Beach", '', "Chesil Beach", null, ''],
maxArraySize: 10},
depth_inout: { type: oracledb.NUMBER,
dir: oracledb.BIND_INOUT,
val: [null, 8, null, 3, null, 70],
maxArraySize: 10}
},
function(err, result) {
should.not.exist(err);
// console.log(result.outBinds);
(result.outBinds.beach_inout).should.eql([ 'Chesil Beach', 'Eighty Mile Beach', 'Port Melbourne Beach', null, null, null ]);
(result.outBinds.depth_inout).should.eql([ 3, 8, null, null, 70, null ]);
callback();
}
);
}
], done);
}); // 44.5
it('44.6 empty array for BIND_IN and BIND_INOUT', function(done) {
async.series([
// Pass arrays of values to a PL/SQL procedure
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_in(:beach_in, :depth_in); END;",
{
beach_in: { type: oracledb.STRING,
dir: oracledb.BIND_IN,
val: [] },
depth_in: { type: oracledb.NUMBER,
dir: oracledb.BIND_IN,
val: []
}
},
function(err) {
2023-02-21 09:33:06 +08:00
callback(err);
2017-06-14 09:54:45 +08:00
}
);
},
// Return input arrays sorted by beach name
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_inout(:beach_inout, :depth_inout); END;",
{
beach_inout: { type: oracledb.STRING,
dir: oracledb.BIND_INOUT,
val: [],
maxArraySize: 0
},
depth_inout: { type: oracledb.NUMBER,
dir: oracledb.BIND_INOUT,
val: [],
maxArraySize: 3}
},
function(err) {
should.exist(err);
2023-02-21 09:33:06 +08:00
(err.message).should.startWith('NJS-007:');
2017-06-14 09:54:45 +08:00
callback();
}
);
}
], done);
}); // 44.6
it('44.7 empty array for BIND_OUT', function(done) {
async.series([
function(callback) {
var proc = "CREATE OR REPLACE PACKAGE\n" +
"oracledb_testpack\n" +
"IS\n" +
" TYPE stringsType IS TABLE OF VARCHAR2(2000) INDEX BY BINARY_INTEGER;\n" +
" PROCEDURE test(p OUT stringsType);\n" +
"END;";
connection.execute(
proc,
function(err) {
should.not.exist(err);
callback();
}
);
},
function(callback) {
var proc = "CREATE OR REPLACE PACKAGE BODY\n" +
"oracledb_testpack\n" +
"IS\n" +
" PROCEDURE test(p OUT stringsType) IS BEGIN NULL; END;\n" +
"END;";
connection.execute(
proc,
function(err) {
should.not.exist(err);
callback();
}
);
},
function(callback) {
connection.execute(
"BEGIN oracledb_testpack.test(:0); END;",
[
{type: oracledb.STRING, dir: oracledb.BIND_OUT, maxArraySize: 1}
],
function(err, result) {
should.not.exist(err);
result.outBinds[0].should.eql([]);
callback();
}
);
},
function(callback) {
connection.execute(
"DROP PACKAGE oracledb_testpack",
function(err) {
should.not.exist(err);
callback();
}
);
}
], done);
}); // 44.7
it('44.8 maxSize option applies to each elements of an array', function(done) {
async.series([
// Pass arrays of values to a PL/SQL procedure
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_in(:beach_in, :depth_in); END;",
{
beach_in: { type: oracledb.STRING,
dir: oracledb.BIND_IN,
val: ["Malibu", "Bondi", "Waikiki"] },
depth_in: { type: oracledb.NUMBER,
dir: oracledb.BIND_IN,
val: [45, 30, 67]
}
},
function(err) {
2023-02-21 09:33:06 +08:00
callback(err);
2017-06-14 09:54:45 +08:00
}
);
},
// Fetch arrays of values from a PL/SQL procedure
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_out(:beach_out, :depth_out); END;",
{
beach_out: { type: oracledb.STRING,
dir: oracledb.BIND_OUT,
maxArraySize: 3,
maxSize: 6 },
depth_out: { type: oracledb.NUMBER,
dir: oracledb.BIND_OUT,
maxArraySize: 3 }
},
function(err) {
2017-08-16 13:14:39 +08:00
should.exist(err);
(err.message).should.startWith('ORA-06502:');
// ORA-06502: PL/SQL: numeric or value error: host bind array too small
2017-06-14 09:54:45 +08:00
callback();
}
);
},
function(callback) {
connection.rollback(function(err) {
2023-02-21 09:33:06 +08:00
callback(err);
2017-06-14 09:54:45 +08:00
});
},
// Return input arrays sorted by beach name
function(callback) {
connection.execute(
"BEGIN nodb_beachpkg.array_inout(:beach_inout, :depth_inout); END;",
{
beach_inout: { type: oracledb.STRING,
dir: oracledb.BIND_INOUT,
val: ["Port Melbourne Beach", "Eighty Mile Beach", "Chesil Beach"],
maxArraySize: 3,
maxSize : 5},
depth_inout: { type: oracledb.NUMBER,
dir: oracledb.BIND_INOUT,
val: [8, 3, 70],
maxArraySize: 3}
},
function(err) {
should.exist(err);
2023-02-21 09:33:06 +08:00
(err.message).should.startWith('NJS-058:');
2017-06-14 09:54:45 +08:00
callback();
}
);
}
], done);
}); // 44.8
});