-
Notifications
You must be signed in to change notification settings - Fork 1.1k
/
selectobject.js
256 lines (210 loc) · 7.93 KB
/
selectobject.js
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
/* Copyright (c) 2019, 2023, Oracle and/or its affiliates. */
/******************************************************************************
*
* 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 http://www.apache.org/licenses/LICENSE-2.0. You may choose
* either license.
*
* 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.
* You may obtain a copy of the License at
*
* https://www.apache.org/licenses/LICENSE-2.0
*
* 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.
* See the License for the specific language governing permissions and
* limitations under the License.
*
* NAME
* selectobject.js
*
* DESCRIPTION
* Insert and query a named Oracle database object.
* Shows various ways to work with objects.
*
*****************************************************************************/
'use strict';
Error.stackTraceLimit = 50;
const oracledb = require('oracledb');
const dbConfig = require('./dbconfig.js');
// This example runs in both node-oracledb Thin and Thick modes.
//
// Optionally run in node-oracledb Thick mode
if (process.env.NODE_ORACLEDB_DRIVER_MODE === 'thick') {
// Thick mode requires Oracle Client or Oracle Instant Client libraries.
// On Windows and macOS Intel you can specify the directory containing the
// libraries at runtime or before Node.js starts. On other platforms (where
// Oracle libraries are available) the system library search path must always
// include the Oracle library path before Node.js starts. If the search path
// is not correct, you will get a DPI-1047 error. See the node-oracledb
// installation documentation.
let clientOpts = {};
// On Windows and macOS Intel platforms, set the environment
// variable NODE_ORACLEDB_CLIENT_LIB_DIR to the Oracle Client library path
if (process.platform === 'win32' || (process.platform === 'darwin' && process.arch === 'x64')) {
clientOpts = { libDir: process.env.NODE_ORACLEDB_CLIENT_LIB_DIR };
}
oracledb.initOracleClient(clientOpts); // enable node-oracledb Thick mode
}
console.log(oracledb.thin ? 'Running in thin mode' : 'Running in thick mode');
// If each object's attributes are accessed multiple times, it may be more
// efficient to fetch as simple JavaScriptobjects.
// oracledb.dbObjectAsPojo = true;
async function run() {
let connection, result;
try {
connection = await oracledb.getConnection(dbConfig);
//
// Create a table with a named type
//
const stmts = [
`DROP TABLE no_farmtab`,
`DROP TYPE dbfarmtype`,
`DROP TYPE dbharvesttype`,
`CREATE TYPE dbharvesttype AS VARRAY(10) OF VARCHAR2(20)`,
`CREATE TYPE dbfarmtype AS OBJECT (
farmername VARCHAR2(20),
harvest dbharvesttype)`,
`CREATE TABLE no_farmtab (id NUMBER, farm dbfarmtype)`
];
for (const s of stmts) {
try {
await connection.execute(s);
} catch (e) {
if (e.errorNum != 942 && e.errorNum != 4043)
console.error(e);
}
}
//
// Get a prototype object for the database DBHARVESTTYPE type.
//
// The case of the name is significant.
//
// getDbObjectClass() can require a round-trip so minimize calls
// to it. Pass a fully qualified type name when possible.
//
const FarmType = await connection.getDbObjectClass('DBFARMTYPE');
console.log('Farm Type:');
console.log(FarmType.prototype); // show attributes available
// Nested type
console.log('\nHarvest Type:');
console.log(FarmType.prototype.attributes.HARVEST.typeClass.prototype);
//
// Insert Method 1: pass a JavaScript object to the constructor.
//
// The JavaScript attribute names match the Oracle type
// attributes. These particular Oracle object attribute names
// were created case insensitively in the database. This is the
// default when quotes aren't used in the CREATE statement. In
// node-oracledb attributes created like this need to be
// uppercase.
//
console.log('\nA FarmType object:');
const farm1 = new FarmType(
{
FARMERNAME: 'MacDonald',
HARVEST: ['Apples', 'Pears', 'Peaches']
}
);
console.log(farm1);
await connection.execute(
`INSERT INTO no_farmtab (id, farm) VALUES (:id, :f)`,
{id: 1, f: farm1}
);
//
// Insert Method 2: set each attribute individually
//
console.log('\nA nested type:');
// Find the subtype prototype object.
//
// The commented getDbObjectClass() line has the same effect as
// the line above but will require a round-trip to the database
// because a fully qualified name was not used, meaning the type
// information couldn't be looked up in node-oracledb's type
// cache.
const HarvestType = FarmType.prototype.attributes.HARVEST.typeClass;
// const HarvestType = await connection.getDbObjectClass('DBHARVESTTYPE');
console.log(HarvestType);
console.log(HarvestType.toString());
const farm2 = new FarmType();
farm2.FARMERNAME = 'Giles';
farm2.HARVEST = new HarvestType(['carrots', 'peas']);
farm2.HARVEST.trim(1); // whoops! no peas
farm2.HARVEST.append('tomatoes'); // extend the collection
console.log(farm2.HARVEST.getValues());
await connection.execute(
`INSERT INTO no_farmtab (id, farm) VALUES (:id, :f)`,
{ id: 2, f: farm2 }
);
//
// Insert Method 3: use the prototype object for the bind 'type',
// and supply a JavaScript object directly for the 'val'
//
await connection.execute(
`INSERT INTO no_farmtab (id, farm) VALUES (:id, :f)`,
{ id: 3,
f: {
type: FarmType, // pass the prototype object
val: { // a JavaScript object that maps to the DB object
FARMERNAME: 'Smith',
HARVEST: [ 'pepper', 'cinnamon', 'nutmeg' ]
}
}
}
);
//
// Insert Method 4: use the Oracle type name.
// Note: use a fully qualified type name when possible.
//
await connection.execute(
`INSERT INTO no_farmtab (id, farm) VALUES (:id, :f)`,
{ id: 4,
f: {
type: 'DBFARMTYPE', // the name of the top level database type, case sensitive
val: { // a JavaScript object that maps to the DB object
FARMERNAME: 'Boy',
HARVEST: ['flowers', 'seedlings' ]
}
}
}
);
//
// Fetch an object back
//
console.log('\nQuerying:');
result = await connection.execute(
`SELECT id, farm FROM no_farmtab WHERE id = 1 `,
[],
// outFormat determines whether rows will be in arrays or JavaScript objects.
// It does not affect how the FARM column itself is represented.
{ outFormat: oracledb.OUT_FORMAT_OBJECT }
);
for (const row of result.rows) {
const farm = row.FARM; // a DbObject for the named Oracle type
console.log('\nFarm is:', farm); // the whole object
console.log('JSON', JSON.stringify(farm)); // Objects can be stringified
console.log('\nFarmer name', farm.FARMERNAME); // an attribute of the object
console.log('Harvest is:'); // iterate over the collection
for (const crop of farm.HARVEST) {
console.log(crop);
}
}
} catch (err) {
console.error(err);
} finally {
if (connection) {
try {
await connection.close();
} catch (err) {
console.error(err);
}
}
}
}
run();