aboutsummaryrefslogtreecommitdiffstats
path: root/infrastructure/framework-src/modules/sqlbase/sqlobj.js
blob: 4bc1263d3e9b87b70d4b01deb884874e6f8601a3 (plain) (blame)
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
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
/**
 * Copyright 2009 Google Inc.
 * 
 * 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
 * 
 *      http://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.
 */

import("cache_utils.syncedWithCache");
import("sqlbase.sqlcommon.*");
import("jsutils.*");

jimport("java.lang.System.out.println");
jimport("java.sql.Statement");

function _withCache(name, fn) {
  return syncedWithCache('sqlobj.'+name, fn);
}

function getIdColspec() {
  return ('INT NOT NULL '+autoIncrementClause()+' PRIMARY KEY');
}

function getLongtextColspec(extra) {
  var spec = getSqlBase().longTextType();
  if (extra) {
    spec = (spec + " " + extra);
  }
  return spec;
}

function getBoolColspec(extra) {
  var spec;
  if (isMysql()) {
    spec = 'TINYINT(1)';
  } else {
    spec = 'SMALLINT';
  }
  if (extra) {
    spec = (spec + " " + extra);
  }
  return spec;
}

function getDateColspec(extra) {
  var spec;
  if (isMysql()) {
    spec = 'DATETIME';
  } else {
    spec = 'TIMESTAMP';
  }
  if (extra) {
    spec = (spec + " " + extra);
  }
  return spec;
}

function _bq(x) { return btquote(x); }

/*
 * for debugging queries
 */
function _qdebug(q) {
  if (appjet.config.debugSQL) {
    println(q);
  }
}

/** executeFn is either "execute" or "executeUpdate" "executeQuery" */
function _execute(stmnt, executeFn) {
  if (!executeFn) {
    executeFn = 'execute';
  }
  return withConnection(function(conn) {
    var pstmnt = conn.prepareStatement(stmnt);
    return closing(pstmnt, function() {
      _qdebug(stmnt);
      return pstmnt[executeFn]();
    });
  });
}

function _executeUpdate(stmnt) {
  return _execute(stmnt, 'executeUpdate');
}

function _executeQuery(stmnt) {
  return _execute(stmnt, 'executeQuery');
}

/*
 * Not all SQL/JS types supported.
 */
function _getJsValFromResultSet(rs, type, colName) {
  var r;
  if (type == java.sql.Types.VARCHAR ||
      type == java.sql.Types.LONGVARCHAR ||
      type == java.sql.Types.CHAR) {
    r = String(rs.getString(colName));
  } else if (type == java.sql.Types.TIMESTAMP) {
    var t = rs.getTimestamp(colName);
    if (t) {
      r = new Date(t.getTime());
    } else {
      r = null;
    }
  } else if (type == java.sql.Types.INTEGER ||
             type == java.sql.Types.SMALLINT ||
             type == java.sql.Types.TINYINT) {
    r = rs.getInt(colName);
  } else if (type == java.sql.Types.BIT) {
    r = rs.getBoolean(colName);
  } else {
    throw Error("Cannot fetch sql type ID "+type+" (columnName = "+colName+")");
  }

  if (rs.wasNull()) {
    r = null;
  }
  return r;
}

function _lookupColumnType(tableName, columnName) {
  return withConnection(function(conn) {
    var metadata = conn.getMetaData();
    var rs = metadata.getColumns(null, null, tableName, columnName);
    if (!rs) {
      throw Error("Table '"+tableName+"' does not appear to have colum '"+columnName+"'.");
    }
    var rsmd = rs.getMetaData();
    var colCount = rsmd.getColumnCount();
//    rs.first();
    rs.next();
    var type = rs.getInt("DATA_TYPE");
    return type;
  });
}

/* cached, on misses calls _lookuParameterType */
function _getParameterType(tableName, columnName) {
  var key = [tableName, columnName].join(".");
  return _withCache('column-types', function(cache) {
    if (!cache[key]) {
      cache[key] = _lookupColumnType(tableName, columnName);
    }
    return cache[key];
  });
}

/*
 * Not all SQL/JS types supported.
 */
function _setPreparedValues(tableName, pstmnt, keyList, obj, indexOffset) {
  if (!indexOffset) { indexOffset = 0; }

  for (var i = 1; i <= keyList.length; i++) {
    var k = keyList[i-1];
    var v = obj[k];
    var j = i + indexOffset;

    if (v === undefined) {
      throw Error("value is undefined for key "+k);
    }

    if (v === null) {
      var type = _getParameterType(tableName, k);
      pstmnt.setNull(j, type);
    } else if (typeof(v) == 'string') {
      pstmnt.setString(j, v);
    } else if (typeof(v) == 'number') {
      pstmnt.setInt(j, v);
    } else if (typeof(v) == 'boolean') {
      pstmnt.setBoolean(j, v);
    } else if (v.valueOf && v.getDate && v.getHours) {
      pstmnt.setTimestamp(j, new java.sql.Timestamp(+v));
    } else {
      throw Error("Cannot insert this type of javascript object: "+typeof(v)+" (key="+k+", value = "+v+")");
    }
  }
}

function _resultRowToJsObj(resultSet) {
  var resultObj = {};

  var metaData = resultSet.getMetaData();
  var colCount = metaData.getColumnCount();
  for (var i = 1; i <= colCount; i++) {
    var colName = metaData.getColumnName(i);
    var type = metaData.getColumnType(i);
    resultObj[colName] = _getJsValFromResultSet(resultSet, type, colName);
  }

  return resultObj;
}

/*
 * Inserts the object into the given table, and returns auto-incremented ID if any.
 */
function insert(tableName, obj) {
  var keyList = keys(obj);

  var stmnt = "INSERT INTO "+_bq(tableName)+" (";
  stmnt += keyList.map(function(k) { return _bq(k); }).join(', ');
  stmnt += ") VALUES (";
  stmnt += keyList.map(function(k) { return '?'; }).join(', ');
  stmnt += ")";

  return withConnection(function(conn) {
    var pstmnt = conn.prepareStatement(stmnt, Statement.RETURN_GENERATED_KEYS);
    return closing(pstmnt, function() {
      _setPreparedValues(tableName, pstmnt, keyList, obj, 0);
      _qdebug(stmnt);
      pstmnt.executeUpdate();
      var rs = pstmnt.getGeneratedKeys();
      if (rs != null) {
        return closing(rs, function() {
          if (rs.next()) {
            return rs.getInt(1);
          }
        });
      }
    });
  });
};

/*
 * Selects a single object given the constraintMap.  If there are more
 * than 1 objects that match, it will return a single one of them
 * (unspecified which one).  If no objects match, returns null.
 *
 * constraints is a javascript object of column names to values.
 *  Currently only supports string equality of constraints.
 */
function selectSingle(tableName, constraints) {
  var keyList = keys(constraints);

  var stmnt = "SELECT * FROM "+_bq(tableName)+" WHERE (";
  stmnt += keyList.map(function(k) { return '('+_bq(k)+' = '+'?)'; }).join(' AND ');
  stmnt += ')';
  if (isMysql()) {
    stmnt += ' LIMIT 1';
  }

  return withConnection(function(conn) {
    var pstmnt = conn.prepareStatement(stmnt);
    return closing(pstmnt, function() {
      _setPreparedValues(tableName, pstmnt, keyList, constraints, 0);
      _qdebug(stmnt);
      var resultSet = pstmnt.executeQuery();
      return closing(resultSet, function() {
        if (!resultSet.next()) {
          return null;
        }
        return _resultRowToJsObj(resultSet);
      });
    });
  });
}

function _makeConstraintString(key, value) {
  if (typeof(value) != 'object' || ! (value instanceof Array)) {
    return '('+_bq(key)+' = ?)';
  } else {
    var comparator = value[0];
    return '('+_bq(key)+' '+comparator+' ?)';
  }
}

function _preparedValuesConstraints(constraints) {
  var c = {};
  eachProperty(constraints, function(k, v) {
    c[k] = (typeof(v) != 'object' || ! (v instanceof Array) ? v : v[1]);
  });
  return c;
}

function selectMulti(tableName, constraints, options) {
  if (!options) {
    options = {};
  }

  var constraintKeys = keys(constraints);

  var stmnt = "SELECT * FROM "+_bq(tableName)+" ";

  if (constraintKeys.length > 0) {
    stmnt += "WHERE (";
    stmnt += constraintKeys.map(function(key) { 
        return _makeConstraintString(key, constraints[key]);
      }).join(' AND ');
    stmnt += ')';
  }

  if (options.orderBy) {
    var orderEntries = [];
    options.orderBy.split(",").forEach(function(orderBy) {
      var asc = "ASC";
      if (orderBy.charAt(0) == '-') {
        orderBy = orderBy.substr(1);
        asc = "DESC";
      }
      orderEntries.push(_bq(orderBy)+" "+asc);
    });
    stmnt += " ORDER BY "+orderEntries.join(", ");
  }
  
  if (options.limit) {
    stmnt += " LIMIT "+options.limit;
  }

  return withConnection(function(conn) {
    var pstmnt = conn.prepareStatement(stmnt);
    return closing(pstmnt, function() {
      _setPreparedValues(
        tableName, pstmnt, constraintKeys, 
        _preparedValuesConstraints(constraints), 0);

      _qdebug(stmnt);
      var resultSet = pstmnt.executeQuery();
      var resultArray = [];

      return closing(resultSet, function() {
        while (resultSet.next()) {
          resultArray.push(_resultRowToJsObj(resultSet));
        }

        return resultArray;
      });
    });
  });
}

/* returns number of rows updated */
function update(tableName, constraints, obj) {
  var objKeys = keys(obj);
  var constraintKeys = keys(constraints);

  var stmnt = "UPDATE "+_bq(tableName)+" SET ";
  stmnt += objKeys.map(function(k) { return ''+_bq(k)+' = ?'; }).join(', ');
  stmnt += " WHERE (";
  stmnt += constraintKeys.map(function(k) { return '('+_bq(k)+' = ?)'; }).join(' AND ');
  stmnt += ')';

  return withConnection(function(conn) {
    var pstmnt = conn.prepareStatement(stmnt);
    return closing(pstmnt, function() {
      _setPreparedValues(tableName, pstmnt, objKeys, obj, 0);
      _setPreparedValues(tableName, pstmnt, constraintKeys, constraints, objKeys.length);
      _qdebug(stmnt);
      return pstmnt.executeUpdate();
    });
  });
}

function updateSingle(tableName, constraints, obj) {
  var count = update(tableName, constraints, obj);
  if (count != 1) {
    throw Error("save count != 1.  instead, count = "+count);
  }
}

function deleteRows(tableName, constraints) {
  var constraintKeys = keys(constraints);
  var stmnt = "DELETE FROM "+_bq(tableName)+" WHERE (";
  stmnt += constraintKeys.map(function(k) { return '('+_bq(k)+' = ?)'; }).join(' AND ');
  stmnt += ')';
  withConnection(function(conn) {
    var pstmnt = conn.prepareStatement(stmnt);
    closing(pstmnt, function() {
      _setPreparedValues(tableName, pstmnt, constraintKeys, constraints);
      _qdebug(stmnt);
      pstmnt.executeUpdate();
    });
  })
}

//----------------------------------------------------------------
// table management
//----------------------------------------------------------------

/*
 * Create a SQL table, specifying column names and types with a
 * javascript object.
 */
function createTable(tableName, colspec, indices) {
  if (doesTableExist(tableName)) {
    return;
  }

  var stmnt = "CREATE TABLE "+_bq(tableName)+ " (";
  stmnt += keys(colspec).map(function(k) { return (_bq(k) + ' ' + colspec[k]); }).join(', ');
  if (indices) {
    stmnt += ', ' + keys(indices).map(function(k) { return 'INDEX (' + _bq(k) + ')'; }).join(', ');
  }
  stmnt += ')'+createTableOptions();
  _execute(stmnt);
}

function dropTable(tableName) {
  _execute("DROP TABLE "+_bq(tableName));
}

function dropAndCreateTable(tableName, colspec, indices) {
  if (doesTableExist(tableName)) {
    dropTable(tableName);
  }

  return createTable(tableName, colspec, indices);
}

function renameTable(oldName, newName) {
  _executeUpdate("RENAME TABLE "+_bq(oldName)+" TO "+_bq(newName));
}

function modifyColumn(tableName, columnName, newSpec) {
  _executeUpdate("ALTER TABLE "+_bq(tableName)+" MODIFY "+_bq(columnName)+" "+newSpec);
}

function alterColumn(tableName, columnName, alteration) {
  var q = "ALTER TABLE "+_bq(tableName)+" ALTER COLUMN "+_bq(columnName)+" "+alteration;
  _executeUpdate(q);
}

function changeColumn(tableName, columnName, newSpec) {
  var q = ("ALTER TABLE "+_bq(tableName)+" CHANGE COLUMN "+_bq(columnName)
           +" "+newSpec);
  _executeUpdate(q);
}

function addColumns(tableName, colspec) {
  inTransaction(function(conn) {
    eachProperty(colspec, function(name, definition) {
      var stmnt = "ALTER TABLE "+_bq(tableName)+" ADD COLUMN "+_bq(name)+" "+definition;
      _executeUpdate(stmnt);
    });
  });
}

function dropColumn(tableName, columnName) {
  var stmnt = "ALTER TABLE "+_bq(tableName)+" DROP COLUMN "+_bq(columnName);
  _executeUpdate(stmnt);
}

function listTables() {
  return withConnection(function(conn) {
    var metadata = conn.getMetaData();
    var resultSet = metadata.getTables(null, null, null, null);
    var resultArray = [];

    return closing(resultSet, function() {
      while (resultSet.next()) {
        resultArray.push(resultSet.getString("TABLE_NAME"));
      }
      return resultArray;
    });
  });
}

function setTableEngine(tableName, engineName) {
  var stmnt = "ALTER TABLE "+_bq(tableName)+" ENGINE="+_bq(engineName);
  _executeUpdate(stmnt);
}

function getTableEngine(tableName) {
  if (!isMysql()) {
    throw Error("getTableEngine() only supported by MySQL database type.");
  }

  var tableEngines = {};

  withConnection(function(conn) {
    var stmnt = "show table status";
    var pstmnt = conn.prepareStatement(stmnt);
    closing(pstmnt, function() {
      _qdebug(stmnt);
      var resultSet = pstmnt.executeQuery();
      closing(resultSet, function() {
        while (resultSet.next()) {
          var n = resultSet.getString("Name");
          var eng = resultSet.getString("Engine");
          tableEngines[n] = eng;
        }
      });
    });
  });

  return tableEngines[tableName];
}

function createIndex(tableName, columns) {
  var indexName = "idx_"+(columns.join("_"));
  var stmnt = "CREATE INDEX "+_bq(indexName)+" on "+_bq(tableName)+" (";
  stmnt += columns.map(_bq).join(", ");
  stmnt += ")";
  _executeUpdate(stmnt);
}