query-generator.js
11 KB
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
'use strict';
const Utils = require('../../utils');
const QueryGenerator = {
dialect: 'mysql',
createSchema() {
return 'SHOW TABLES';
},
showSchemasQuery() {
return 'SHOW TABLES';
},
versionQuery() {
return 'SELECT VERSION() as `version`';
},
createTableQuery(tableName, attributes, options) {
options = Utils._.extend({
engine: 'InnoDB',
charset: null
}, options || {});
const query = 'CREATE TABLE IF NOT EXISTS <%= table %> (<%= attributes%>) ENGINE=<%= engine %><%= comment %><%= charset %><%= collation %><%= initialAutoIncrement %>';
const primaryKeys = [];
const foreignKeys = {};
const attrStr = [];
for (const attr in attributes) {
if (attributes.hasOwnProperty(attr)) {
const dataType = attributes[attr];
let match;
if (Utils._.includes(dataType, 'PRIMARY KEY')) {
primaryKeys.push(attr);
if (Utils._.includes(dataType, 'REFERENCES')) {
// MySQL doesn't support inline REFERENCES declarations: move to the end
match = dataType.match(/^(.+) (REFERENCES.*)$/);
attrStr.push(this.quoteIdentifier(attr) + ' ' + match[1].replace(/PRIMARY KEY/, ''));
foreignKeys[attr] = match[2];
} else {
attrStr.push(this.quoteIdentifier(attr) + ' ' + dataType.replace(/PRIMARY KEY/, ''));
}
} else if (Utils._.includes(dataType, 'REFERENCES')) {
// MySQL doesn't support inline REFERENCES declarations: move to the end
match = dataType.match(/^(.+) (REFERENCES.*)$/);
attrStr.push(this.quoteIdentifier(attr) + ' ' + match[1]);
foreignKeys[attr] = match[2];
} else {
attrStr.push(this.quoteIdentifier(attr) + ' ' + dataType);
}
}
}
const values = {
table: this.quoteTable(tableName),
attributes: attrStr.join(', '),
comment: options.comment && Utils._.isString(options.comment) ? ' COMMENT ' + this.escape(options.comment) : '',
engine: options.engine,
charset: (options.charset ? ' DEFAULT CHARSET=' + options.charset : ''),
collation: (options.collate ? ' COLLATE ' + options.collate : ''),
initialAutoIncrement: (options.initialAutoIncrement ? ' AUTO_INCREMENT=' + options.initialAutoIncrement : '')
};
const pkString = primaryKeys.map(pk => this.quoteIdentifier(pk)).join(', ');
if (!!options.uniqueKeys) {
Utils._.each(options.uniqueKeys, (columns, indexName) => {
if (!columns.singleField) { // If it's a single field its handled in column def, not as an index
if (!Utils._.isString(indexName)) {
indexName = 'uniq_' + tableName + '_' + columns.fields.join('_');
}
values.attributes += ', UNIQUE ' + this.quoteIdentifier(indexName) + ' (' + Utils._.map(columns.fields, this.quoteIdentifier).join(', ') + ')';
}
});
}
if (pkString.length > 0) {
values.attributes += ', PRIMARY KEY (' + pkString + ')';
}
for (const fkey in foreignKeys) {
if (foreignKeys.hasOwnProperty(fkey)) {
values.attributes += ', FOREIGN KEY (' + this.quoteIdentifier(fkey) + ') ' + foreignKeys[fkey];
}
}
return Utils._.template(query)(values).trim() + ';';
},
showTablesQuery() {
return 'SHOW TABLES;';
},
addColumnQuery(table, key, dataType) {
const definition = this.attributeToSQL(dataType, {
context: 'addColumn',
tableName: table,
foreignKey: key
});
return `ALTER TABLE ${this.quoteTable(table)} ADD ${this.quoteIdentifier(key)} ${definition};`;
},
removeColumnQuery(tableName, attributeName) {
return `ALTER TABLE ${this.quoteTable(tableName)} DROP ${this.quoteIdentifier(attributeName)};`;
},
changeColumnQuery(tableName, attributes) {
const attrString = [];
const constraintString = [];
for (const attributeName in attributes) {
let definition = attributes[attributeName];
if (definition.match(/REFERENCES/)) {
const fkName = this.quoteIdentifier(tableName + '_' + attributeName + '_foreign_idx');
const attrName = this.quoteIdentifier(attributeName);
definition = definition.replace(/.+?(?=REFERENCES)/,'');
constraintString.push(`${fkName} FOREIGN KEY (${attrName}) ${definition}`);
} else {
attrString.push('`' + attributeName + '` `' + attributeName + '` ' + definition);
}
}
let finalQuery = '';
if (attrString.length) {
finalQuery += 'CHANGE ' + attrString.join(', ');
finalQuery += constraintString.length ? ' ' : '';
}
if (constraintString.length) {
finalQuery += 'ADD CONSTRAINT ' + constraintString.join(', ');
}
return `ALTER TABLE ${this.quoteTable(tableName)} ${finalQuery};`;
},
renameColumnQuery(tableName, attrBefore, attributes) {
const attrString = [];
for (const attrName in attributes) {
const definition = attributes[attrName];
attrString.push('`' + attrBefore + '` `' + attrName + '` ' + definition);
}
return `ALTER TABLE ${this.quoteTable(tableName)} CHANGE ${attrString.join(', ')};`;
},
upsertQuery(tableName, insertValues, updateValues, where, rawAttributes, options) {
options.onDuplicate = 'UPDATE ';
options.onDuplicate += Object.keys(updateValues).map(key => {
key = this.quoteIdentifier(key);
return key + '=VALUES(' + key +')';
}).join(', ');
return this.insertQuery(tableName, insertValues, rawAttributes, options);
},
deleteQuery(tableName, where, options) {
options = options || {};
const table = this.quoteTable(tableName);
if (options.truncate === true) {
// Truncate does not allow LIMIT and WHERE
return 'TRUNCATE ' + table;
}
where = this.getWhereConditions(where);
let limit = '';
if (Utils._.isUndefined(options.limit)) {
options.limit = 1;
}
if (!!options.limit) {
limit = ' LIMIT ' + this.escape(options.limit);
}
let query = 'DELETE FROM ' + table;
if (where) query += ' WHERE ' + where;
query += limit;
return query;
},
showIndexesQuery(tableName, options) {
return 'SHOW INDEX FROM ' + this.quoteTable(tableName) + ((options || {}).database ? ' FROM `' + options.database + '`' : '');
},
removeIndexQuery(tableName, indexNameOrAttributes) {
let indexName = indexNameOrAttributes;
if (typeof indexName !== 'string') {
indexName = Utils.inflection.underscore(tableName + '_' + indexNameOrAttributes.join('_'));
}
return `DROP INDEX ${indexName} ON ${this.quoteTable(tableName)}`;
},
attributeToSQL(attribute, options) {
if (!Utils._.isPlainObject(attribute)) {
attribute = {
type: attribute
};
}
let template = attribute.type.toString({ escape: this.escape.bind(this) });
if (attribute.allowNull === false) {
template += ' NOT NULL';
}
if (attribute.autoIncrement) {
template += ' auto_increment';
}
// Blobs/texts cannot have a defaultValue
if (attribute.type !== 'TEXT' && attribute.type._binary !== true && Utils.defaultValueSchemable(attribute.defaultValue)) {
template += ' DEFAULT ' + this.escape(attribute.defaultValue);
}
if (attribute.unique === true) {
template += ' UNIQUE';
}
if (attribute.primaryKey) {
template += ' PRIMARY KEY';
}
if (attribute.after) {
template += ' AFTER ' + this.quoteIdentifier(attribute.after);
}
if (attribute.references) {
if (options && options.context === 'addColumn' && options.foreignKey) {
const attrName = this.quoteIdentifier(options.foreignKey);
const fkName = this.quoteIdentifier(`${options.tableName}_${attrName}_foreign_idx`);
template += `, ADD CONSTRAINT ${fkName} FOREIGN KEY (${attrName})`;
}
template += ' REFERENCES ' + this.quoteTable(attribute.references.model);
if (attribute.references.key) {
template += ' (' + this.quoteIdentifier(attribute.references.key) + ')';
} else {
template += ' (' + this.quoteIdentifier('id') + ')';
}
if (attribute.onDelete) {
template += ' ON DELETE ' + attribute.onDelete.toUpperCase();
}
if (attribute.onUpdate) {
template += ' ON UPDATE ' + attribute.onUpdate.toUpperCase();
}
}
return template;
},
attributesToSQL(attributes, options) {
const result = {};
for (const key in attributes) {
const attribute = attributes[key];
result[attribute.field || key] = this.attributeToSQL(attribute, options);
}
return result;
},
findAutoIncrementField(factory) {
const fields = [];
for (const name in factory.attributes) {
if (factory.attributes.hasOwnProperty(name)) {
const definition = factory.attributes[name];
if (definition && definition.autoIncrement) {
fields.push(name);
}
}
}
return fields;
},
quoteIdentifier(identifier) {
if (identifier === '*') return identifier;
return Utils.addTicks(identifier, '`');
},
/**
* Generates an SQL query that returns all foreign keys of a table.
*
* @param {String} tableName The name of the table.
* @param {String} schemaName The name of the schema.
* @return {String} The generated sql query.
*/
getForeignKeysQuery(tableName, schemaName) {
return "SELECT CONSTRAINT_NAME as constraint_name FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE where TABLE_NAME = '" + tableName + /* jshint ignore: line */
"' AND CONSTRAINT_NAME!='PRIMARY' AND CONSTRAINT_SCHEMA='" + schemaName + "' AND REFERENCED_TABLE_NAME IS NOT NULL;"; /* jshint ignore: line */
},
/**
* Generates an SQL query that returns the foreign key constraint of a given column.
*
* @param {String} tableName The name of the table.
* @param {String} columnName The name of the column.
* @return {String} The generated sql query.
*/
getForeignKeyQuery(table, columnName) {
let tableName = table.tableName || table;
if (table.schema) {
tableName = table.schema + '.' + tableName;
}
return 'SELECT CONSTRAINT_NAME as constraint_name'
+ ' FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE'
+ ' WHERE (REFERENCED_TABLE_NAME = ' + wrapSingleQuote(tableName)
+ ' AND REFERENCED_COLUMN_NAME = ' + wrapSingleQuote(columnName)
+ ') OR (TABLE_NAME = ' + wrapSingleQuote(tableName)
+ ' AND COLUMN_NAME = ' + wrapSingleQuote(columnName)
+ ')';
},
/**
* Generates an SQL query that removes a foreign key from a table.
*
* @param {String} tableName The name of the table.
* @param {String} foreignKey The name of the foreign key constraint.
* @return {String} The generated sql query.
*/
dropForeignKeyQuery(tableName, foreignKey) {
return 'ALTER TABLE ' + this.quoteTable(tableName) + ' DROP FOREIGN KEY ' + this.quoteIdentifier(foreignKey) + ';';
}
};
// private methods
function wrapSingleQuote(identifier){
return Utils.addTicks(identifier, '\'');
}
module.exports = Utils._.extend(Utils._.clone(require('../abstract/query-generator')), QueryGenerator);