From be54c1a407b65b9a88274873ca194528daa11903 Mon Sep 17 00:00:00 2001 From: Raymond Feng Date: Wed, 13 May 2015 10:17:15 -0700 Subject: [PATCH] Refactor the code to use base SqlConnector --- .gitignore | 1 + docs.json | 16 - lib/discovery.js | 309 +++++---- lib/enumFactory.js | 27 +- lib/migration.js | 616 +++++++++++++++++ lib/mysql.js | 1255 ++++++----------------------------- test/connection.test.js | 30 +- test/datatypes.test.js | 2 +- test/migration.test.js | 12 +- test/mysql.discover.test.js | 11 + 10 files changed, 1064 insertions(+), 1215 deletions(-) delete mode 100644 docs.json create mode 100644 lib/migration.js diff --git a/.gitignore b/.gitignore index ce899f0..5b2da1d 100644 --- a/.gitignore +++ b/.gitignore @@ -3,3 +3,4 @@ coverage *.tgz *.xml .loopbackrc +.idea diff --git a/docs.json b/docs.json deleted file mode 100644 index 339b0c1..0000000 --- a/docs.json +++ /dev/null @@ -1,16 +0,0 @@ -{ - "content": [ - { - "title": "LoopBack MySQL Connector API", - "depth": 2 - }, - "lib/mysql.js", - { - "title": "MySQL Discovery API", - "depth": 2 - }, - "lib/discovery.js" - ], - "codeSectionDepth": 3 -} - diff --git a/lib/discovery.js b/lib/discovery.js index 8e45e14..c900073 100644 --- a/lib/discovery.js +++ b/lib/discovery.js @@ -1,21 +1,46 @@ module.exports = mixinDiscovery; -function mixinDiscovery(MySQL) { +/*! + * @param {MySQL} MySQL connector class + * @param {Object} mysql mysql driver + */ +function mixinDiscovery(MySQL, mysql) { var async = require('async'); function paginateSQL(sql, orderBy, options) { options = options || {}; - var limit = ''; + var limitClause = ''; if (options.offset || options.skip || options.limit) { - limit = ' LIMIT ' + (options.offset || options.skip || 0); // Offset starts from 0 + // Offset starts from 0 + var offset = Number(options.offset || options.skip || 0); + if (isNaN(offset)) { + offset = 0; + } + limitClause = ' LIMIT ' + offset; if (options.limit) { - limit = limit + ',' + options.limit; + var limit = Number(options.limit); + if (isNaN(limit)) { + limit = 0; + } + limitClause = limitClause + ',' + limit; } } if (!orderBy) { sql += ' ORDER BY ' + orderBy; } - return sql + limit; + return sql + limitClause; + } + + /*! + * Build sql for listing schemas (databases in MySQL) + * @params {Object} [options] Options object + * @returns {String} The SQL statement + */ + function querySchemas(options) { + var sql = 'SELECT catalog_name as "catalog",' + + ' schema_name as "schema"' + + ' FROM information_schema.schemata'; + return paginateSQL(sql, 'schema_name', options); } /*! @@ -25,17 +50,24 @@ function mixinDiscovery(MySQL) { */ function queryTables(options) { var sqlTables = null; - var owner = options.owner || options.schema; + var schema = options.owner || options.schema; - if (options.all && !owner) { - sqlTables = paginateSQL('SELECT \'table\' AS "type", table_name AS "name", table_schema AS "owner"' - + ' FROM information_schema.tables', 'table_schema, table_name', options); - } else if (owner) { - sqlTables = paginateSQL('SELECT \'table\' AS "type", table_name AS "name", table_schema AS "owner"' - + ' FROM information_schema.tables WHERE table_schema=\'' + owner + '\'', 'table_schema, table_name', options); + if (options.all && !schema) { + sqlTables = paginateSQL('SELECT \'table\' AS "type",' + + ' table_name AS "name", table_schema AS "owner"' + + ' FROM information_schema.tables', + 'table_schema, table_name', options); + } else if (schema) { + sqlTables = paginateSQL('SELECT \'table\' AS "type",' + + ' table_name AS "name", table_schema AS "schema"' + + ' FROM information_schema.tables' + + ' WHERE table_schema=' + mysql.esacpe(schema), + 'table_schema, table_name', options); } else { - sqlTables = paginateSQL('SELECT \'table\' AS "type", table_name AS "name",' - + ' table_schema AS "owner" FROM information_schema.tables WHERE table_schema=SUBSTRING_INDEX(USER(),\'@\',1)', + sqlTables = paginateSQL('SELECT \'table\' AS "type",' + + ' table_name AS "name", ' + + ' table_schema AS "owner" FROM information_schema.tables' + + ' WHERE table_schema=SUBSTRING_INDEX(USER(),\'@\',1)', 'table_name', options); } return sqlTables; @@ -50,32 +82,48 @@ function mixinDiscovery(MySQL) { var sqlViews = null; if (options.views) { - var owner = options.owner || options.schema; + var schema = options.owner || options.schema; - if (options.all && !owner) { - sqlViews = paginateSQL('SELECT \'view\' AS "type", table_name AS "name",' - + ' table_schema AS "owner" FROM information_schema.views', + if (options.all && !schema) { + sqlViews = paginateSQL('SELECT \'view\' AS "type",' + + ' table_name AS "name",' + + ' table_schema AS "owner"' + + ' FROM information_schema.views', 'table_schema, table_name', options); - } else if (owner) { - sqlViews = paginateSQL('SELECT \'view\' AS "type", table_name AS "name",' - + ' table_schema AS "owner" FROM information_schema.views WHERE table_schema=\'' + owner + '\'', + } else if (schema) { + sqlViews = paginateSQL('SELECT \'view\' AS "type",' + + ' table_name AS "name",' + + ' table_schema AS "owner"' + + ' FROM information_schema.views' + + ' WHERE table_schema=' + mysql.esacpe(schema), 'table_schema, table_name', options); } else { - sqlViews = paginateSQL('SELECT \'view\' AS "type", table_name AS "name",' - + ' table_schema AS "owner" FROM information_schema.views', + sqlViews = paginateSQL('SELECT \'view\' AS "type",' + + ' table_name AS "name",' + + ' table_schema AS "owner"' + + ' FROM information_schema.views', 'table_name', options); } } return sqlViews; } + MySQL.prototype.discoverDatabaseSchemas = function(options, cb) { + if (!cb && typeof options === 'function') { + cb = options; + options = {}; + } + options = options || {}; + this.execute(querySchemas(options), cb); + }; + /** * Discover model definitions * * @param {Object} options Options for discovery * @param {Function} [cb] The callback function */ - MySQL.prototype.discoverModelDefinitions = function (options, cb) { + MySQL.prototype.discoverModelDefinitions = function(options, cb) { if (!cb && typeof options === 'function') { cb = options; options = {}; @@ -83,16 +131,16 @@ function mixinDiscovery(MySQL) { options = options || {}; var self = this; - var calls = [function (callback) { - self.query(queryTables(options), callback); + var calls = [function(callback) { + self.execute(queryTables(options), callback); }]; if (options.views) { - calls.push(function (callback) { - self.query(queryViews(options), callback); + calls.push(function(callback) { + self.execute(queryViews(options), callback); }); } - async.parallel(calls, function (err, data) { + async.parallel(calls, function(err, data) { if (err) { cb(err, data); } else { @@ -125,7 +173,7 @@ function mixinDiscovery(MySQL) { throw new Error('options must be an object: ' + options); } return { - owner: options.owner || options.schema, + schema: options.owner || options.schema, table: table, options: options, cb: cb @@ -134,35 +182,37 @@ function mixinDiscovery(MySQL) { /*! * Build the sql statement to query columns for a given table - * @param owner + * @param schema * @param table * @returns {String} The sql statement */ - function queryColumns(owner, table) { + function queryColumns(schema, table) { var sql = null; - if (owner) { + if (schema) { sql = paginateSQL('SELECT table_schema AS "owner",' + - ' table_name AS "tableName", column_name AS "columnName",' + - ' data_type AS "dataType",' + - ' character_maximum_length AS "dataLength",' + - ' numeric_precision AS "dataPrecision",' + - ' numeric_scale AS "dataScale",' + - ' is_nullable = \'YES\' AS "nullable"' + - ' FROM information_schema.columns' + - ' WHERE table_schema=\'' + owner + '\'' + - (table ? ' AND table_name=\'' + table + '\'' : ''), - 'table_name, ordinal_position', {}); + ' table_name AS "tableName",' + + ' column_name AS "columnName",' + + ' data_type AS "dataType",' + + ' character_maximum_length AS "dataLength",' + + ' numeric_precision AS "dataPrecision",' + + ' numeric_scale AS "dataScale",' + + ' is_nullable = \'YES\' AS "nullable"' + + ' FROM information_schema.columns' + + ' WHERE table_schema=' + mysql.escape(schema) + + (table ? ' AND table_name=' + mysql.escape(table) : ''), + 'table_name, ordinal_position', {}); } else { sql = paginateSQL('SELECT table_schema AS "owner",' + - ' table_name AS "tableName", column_name AS "columnName",' + - ' data_type AS "dataType",' + - ' character_maximum_length AS "dataLength",' + - ' numeric_precision AS "dataPrecision",' + - ' numeric_scale AS "dataScale",' + - ' is_nullable = \'YES\' AS "nullable"' + - ' FROM information_schema.columns' + - (table ? ' WHERE table_name=\'' + table + '\'' : ''), - 'table_name, ordinal_position', {}); + ' table_name AS "tableName",' + + ' column_name AS "columnName",' + + ' data_type AS "dataType",' + + ' character_maximum_length AS "dataLength",' + + ' numeric_precision AS "dataPrecision",' + + ' numeric_scale AS "dataScale",' + + ' is_nullable = \'YES\' AS "nullable"' + + ' FROM information_schema.columns' + + (table ? ' WHERE table_name=' + mysql.escape(table) : ''), + 'table_name, ordinal_position', {}); } return sql; } @@ -174,51 +224,57 @@ function mixinDiscovery(MySQL) { * @param {Function} [cb] The callback function * */ - MySQL.prototype.discoverModelProperties = function (table, options, cb) { + MySQL.prototype.discoverModelProperties = function(table, options, cb) { + var self = this; var args = getArgs(table, options, cb); - var owner = args.owner; - if(!owner){ - owner = inheritOwnerViaDataSource.call(this); + var schema = args.schema; + if (!schema) { + schema = this.getDefaultSchema(); } table = args.table; options = args.options; cb = args.cb; - var sql = queryColumns(owner, table); - var callback = function (err, results) { + var sql = queryColumns(schema, table); + var callback = function(err, results) { if (err) { cb(err, results); } else { - results.map(function (r) { - r.type = mysqlDataTypeToJSONType(r.dataType, r.dataLength); + results.map(function(r) { + r.type = self.buildPropertyType(r); r.nullable = r.nullable ? 'Y' : 'N'; }); cb(err, results); } }; - this.query(sql, callback); + this.execute(sql, callback); }; /*! * Build the sql statement for querying primary keys of a given table - * @param owner + * @param schema * @param table * @returns {string} */ -// http://docs.oracle.com/javase/6/docs/api/java/sql/DatabaseMetaData.html#getPrimaryKeys(java.lang.String, java.lang.String, java.lang.String) - function queryForPrimaryKeys(owner, table) { - var sql = 'SELECT table_schema AS "owner", ' - + 'table_name AS "tableName", column_name AS "columnName", ordinal_position AS "keySeq", constraint_name AS "pkName" FROM' - + ' information_schema.key_column_usage' - + ' WHERE constraint_name=\'PRIMARY\''; +// http://docs.oracle.com/javase/6/docs/api/java/sql/DatabaseMetaData.html +// #getPrimaryKeys(java.lang.String, java.lang.String, java.lang.String) + function queryPrimaryKeys(schema, table) { + var sql = 'SELECT table_schema AS "owner",' + + ' table_name AS "tableName",' + + ' column_name AS "columnName",' + + ' ordinal_position AS "keySeq",' + + ' constraint_name AS "pkName"' + + ' FROM information_schema.key_column_usage' + + ' WHERE constraint_name=\'PRIMARY\''; - if (owner) { - sql += ' AND table_schema=\'' + owner + '\''; + if (schema) { + sql += ' AND table_schema=' + mysql.escape(schema); } if (table) { - sql += ' AND table_name=\'' + table + '\''; + sql += ' AND table_name=' + mysql.escape(table); } - sql += ' ORDER BY table_schema, constraint_name, table_name, ordinal_position'; + sql += ' ORDER BY' + + ' table_schema, constraint_name, table_name, ordinal_position'; return sql; } @@ -228,40 +284,44 @@ function mixinDiscovery(MySQL) { * @param {Object} options The options for discovery * @param {Function} [cb] The callback function */ - MySQL.prototype.discoverPrimaryKeys = function (table, options, cb) { + MySQL.prototype.discoverPrimaryKeys = function(table, options, cb) { var args = getArgs(table, options, cb); - var owner = args.owner; - if(!owner){ - owner = inheritOwnerViaDataSource.call(this); + var schema = args.schema; + if (!schema) { + schema = this.getDefaultSchema(); } table = args.table; options = args.options; cb = args.cb; - var sql = queryForPrimaryKeys(owner, table); - this.query(sql, cb); + var sql = queryPrimaryKeys(schema, table); + this.execute(sql, cb); }; /*! * Build the sql statement for querying foreign keys of a given table - * @param owner + * @param schema * @param table * @returns {string} */ - function queryForeignKeys(owner, table) { + function queryForeignKeys(schema, table) { var sql = - 'SELECT table_schema AS "fkOwner", constraint_name AS "fkName", table_name AS "fkTableName",' - + ' column_name AS "fkColumnName", ordinal_position AS "keySeq",' - + ' referenced_table_schema AS "pkOwner", \'PRIMARY\' AS "pkName", ' - + ' referenced_table_name AS "pkTableName", referenced_column_name AS "pkColumnName"' - + ' FROM information_schema.key_column_usage' - + ' WHERE' - + ' constraint_name!=\'PRIMARY\' and POSITION_IN_UNIQUE_CONSTRAINT IS NOT NULL'; - if (owner) { - sql += ' AND table_schema=\'' + owner + '\''; + 'SELECT table_schema AS "fkOwner",' + + ' constraint_name AS "fkName",' + + ' table_name AS "fkTableName",' + + ' column_name AS "fkColumnName",' + + ' ordinal_position AS "keySeq",' + + ' referenced_table_schema AS "pkOwner", \'PRIMARY\' AS "pkName",' + + ' referenced_table_name AS "pkTableName",' + + ' referenced_column_name AS "pkColumnName"' + + ' FROM information_schema.key_column_usage' + + ' WHERE constraint_name!=\'PRIMARY\'' + + ' AND POSITION_IN_UNIQUE_CONSTRAINT IS NOT NULL'; + if (schema) { + sql += ' AND table_schema=' + mysql.escape(schema); } if (table) { - sql += ' AND table_name=\'' + table + '\''; + sql += ' AND table_name=' + mysql.escape(table); } return sql; } @@ -272,42 +332,47 @@ function mixinDiscovery(MySQL) { * @param {Object} options The options for discovery * @param {Function} [cb] The callback function */ - MySQL.prototype.discoverForeignKeys = function (table, options, cb) { + MySQL.prototype.discoverForeignKeys = function(table, options, cb) { var args = getArgs(table, options, cb); - var owner = args.owner; - if(!owner){ - owner = inheritOwnerViaDataSource.call(this); + var schema = args.schema; + if (!schema) { + schema = this.getDefaultSchema(); } table = args.table; options = args.options; cb = args.cb; - var sql = queryForeignKeys(owner, table); - this.query(sql, cb); + var sql = queryForeignKeys(schema, table); + this.execute(sql, cb); }; /*! - * Retrieves a description of the foreign key columns that reference the given table's primary key columns (the foreign keys exported by a table). + * Retrieves a description of the foreign key columns that reference the + * given table's primary key columns (the foreign keys exported by a table). * They are ordered by fkTableOwner, fkTableName, and keySeq. - * @param owner + * @param schema * @param table * @returns {string} */ - function queryExportedForeignKeys(owner, table) { - var sql = 'SELECT a.constraint_name AS "fkName", a.table_schema AS "fkOwner", a.table_name AS "fkTableName",' - + ' a.column_name AS "fkColumnName", a.ordinal_position AS "keySeq",' - + ' NULL AS "pkName", a.referenced_table_schema AS "pkOwner",' - + ' a.referenced_table_name AS "pkTableName", a.referenced_column_name AS "pkColumnName"' - + ' FROM' - + ' information_schema.key_column_usage a' - + ' WHERE a.position_in_unique_constraint IS NOT NULL'; - if (owner) { - sql += ' and a.referenced_table_schema=\'' + owner + '\''; + function queryExportedForeignKeys(schema, table) { + var sql = 'SELECT a.constraint_name AS "fkName",' + + ' a.table_schema AS "fkOwner",' + + ' a.table_name AS "fkTableName",' + + ' a.column_name AS "fkColumnName",' + + ' a.ordinal_position AS "keySeq",' + + ' NULL AS "pkName",' + + ' a.referenced_table_schema AS "pkOwner",' + + ' a.referenced_table_name AS "pkTableName",' + + ' a.referenced_column_name AS "pkColumnName"' + + ' FROM information_schema.key_column_usage a' + + ' WHERE a.position_in_unique_constraint IS NOT NULL'; + if (schema) { + sql += ' AND a.referenced_table_schema=' + mysql.escape(schema); } if (table) { - sql += ' and a.referenced_table_name=\'' + table + '\''; + sql += ' AND a.referenced_table_name=' + mysql.escape(table); } - sql += ' order by a.table_schema, a.table_name, a.ordinal_position'; + sql += ' ORDER BY a.table_schema, a.table_name, a.ordinal_position'; return sql; } @@ -318,21 +383,24 @@ function mixinDiscovery(MySQL) { * @param {Object} options The options for discovery * @param {Function} [cb] The callback function */ - MySQL.prototype.discoverExportedForeignKeys = function (table, options, cb) { + MySQL.prototype.discoverExportedForeignKeys = function(table, options, cb) { var args = getArgs(table, options, cb); - var owner = args.owner; - if(!owner){ - owner = inheritOwnerViaDataSource.call(this); + var schema = args.schema; + if (!schema) { + schema = this.getDefaultSchema(); } table = args.table; options = args.options; cb = args.cb; - var sql = queryExportedForeignKeys(owner, table); - this.query(sql, cb); + var sql = queryExportedForeignKeys(schema, table); + this.execute(sql, cb); }; - function mysqlDataTypeToJSONType(mysqlType, dataLength) { + MySQL.prototype.buildPropertyType = function (columnDefinition) { + var mysqlType = columnDefinition.dataType; + var dataLength = columnDefinition.dataLength; + var type = mysqlType.toUpperCase(); switch (type) { case 'CHAR': @@ -379,10 +447,11 @@ function mixinDiscovery(MySQL) { } } - function inheritOwnerViaDataSource(){ - if(this.dataSource && this.dataSource.settings && this.dataSource.settings.database){ + MySQL.prototype.getDefaultSchema = function() { + if (this.dataSource && this.dataSource.settings && + this.dataSource.settings.database) { return this.dataSource.settings.database; } return undefined; - } + }; } diff --git a/lib/enumFactory.js b/lib/enumFactory.js index 42c498a..f57f8e4 100644 --- a/lib/enumFactory.js +++ b/lib/enumFactory.js @@ -1,4 +1,4 @@ -var EnumFactory = function () { +var EnumFactory = function() { if (arguments.length > 0) { var Enum = function Enum(arg) { if (typeof arg === 'number' && arg % 1 == 0) { @@ -14,14 +14,31 @@ var EnumFactory = function () { } }; var dxList = []; - dxList.push(''); // Want empty value to be at index 0 to match MySQL Enum values and MySQL non-strict behavior. + // Want empty value to be at index 0 to match MySQL Enum values and + // MySQL non-strict behavior. + dxList.push(''); for (var arg in arguments) { arg = String(arguments[arg]); - Object.defineProperty(Enum, arg.toUpperCase(), {configurable: false, enumerable: true, value: arg, writable: false}); + Object.defineProperty(Enum, arg.toUpperCase(), { + configurable: false, + enumerable: true, + value: arg, + writable: false + }); dxList.push(arg); } - Object.defineProperty(Enum, '_values', {configurable: false, enumerable: false, value: dxList, writable: false}); - Object.defineProperty(Enum, '_string', {configurable: false, enumerable: false, value: stringified(Enum), writable: false}); + Object.defineProperty(Enum, '_values', { + configurable: false, + enumerable: false, + value: dxList, + writable: false + }); + Object.defineProperty(Enum, '_string', { + configurable: false, + enumerable: false, + value: stringified(Enum), + writable: false + }); Object.freeze(Enum); return Enum; } else { diff --git a/lib/migration.js b/lib/migration.js new file mode 100644 index 0000000..f1c18a5 --- /dev/null +++ b/lib/migration.js @@ -0,0 +1,616 @@ +var async = require('async'); +module.exports = mixinMigration; + +/*! + * @param {MySQL} MySQL connector class + * @param {Object} mysql mysql driver + */ +function mixinMigration(MySQL, mysql) { + /** + * Perform autoupdate for the given models + * @param {String[]} [models] A model name or an array of model names. + * If not present, apply to all models + * @param {Function} [cb] The callback function + */ + MySQL.prototype.autoupdate = function(models, cb) { + var self = this; + + if ((!cb) && ('function' === typeof models)) { + cb = models; + models = undefined; + } + // First argument is a model name + if ('string' === typeof models) { + models = [models]; + } + + models = models || Object.keys(this._models); + + async.each(models, function(model, done) { + if (!(model in self._models)) { + return process.nextTick(function() { + done(new Error('Model not found: ' + model)); + }); + } + var table = self.tableEscaped(model); + self.execute('SHOW FIELDS FROM ' + table, function(err, fields) { + self.execute('SHOW INDEXES FROM ' + table, function(err, indexes) { + if (!err && fields && fields.length) { + self.alterTable(model, fields, indexes, done); + } else { + self.createTable(model, done); + } + }); + }); + }, cb); + + }; + + /*! + * Create a DB table for the given model + * @param {string} model Model name + * @param cb + */ + MySQL.prototype.createTable = function(model, cb) { + var metadata = this.getModelDefinition(model).settings[this.name]; + var engine = metadata && metadata.engine; + var sql = 'CREATE TABLE ' + this.tableEscaped(model) + + ' (\n ' + this.buildColumnDefinitions(model) + '\n)'; + if (engine) { + sql += 'ENGINE=' + engine + '\n'; + } + this.execute(sql, cb); + }; + + /** + * Check if the models exist + * @param {String[]} [models] A model name or an array of model names. If not + * present, apply to all models + * @param {Function} [cb] The callback function + */ + MySQL.prototype.isActual = function(models, cb) { + var self = this; + var ok = false; + + if ((!cb) && ('function' === typeof models)) { + cb = models; + models = undefined; + } + // First argument is a model name + if ('string' === typeof models) { + models = [models]; + } + + models = models || Object.keys(this._models); + + async.each(models, function(model, done) { + var table = self.tableEscaped(model); + self.execute('SHOW FIELDS FROM ' + table, function(err, fields) { + self.execute('SHOW INDEXES FROM ' + table, function(err, indexes) { + self.alterTable(model, fields, indexes, function(err, needAlter) { + if (err) { + return done(err); + } else { + ok = ok || needAlter; + done(err); + } + }, true); + }); + }); + }, function(err) { + if (err) { + return err; + } + cb(null, !ok); + }); + }; + + MySQL.prototype.alterTable = function(model, actualFields, actualIndexes, done, checkOnly) { + var self = this; + var m = this.getModelDefinition(model); + var propNames = Object.keys(m.properties).filter(function(name) { + return !!m.properties[name]; + }); + var indexes = m.settings.indexes || {}; + var indexNames = Object.keys(indexes).filter(function(name) { + return !!m.settings.indexes[name]; + }); + var sql = []; + var ai = {}; + + if (actualIndexes) { + actualIndexes.forEach(function(i) { + var name = i.Key_name; + if (!ai[name]) { + ai[name] = { + info: i, + columns: [] + }; + } + ai[name].columns[i.Seq_in_index - 1] = i.Column_name; + }); + } + var aiNames = Object.keys(ai); + + // change/add new fields + propNames.forEach(function(propName) { + if (m.properties[propName] && self.id(model, propName)) return; + var found; + if (actualFields) { + actualFields.forEach(function(f) { + if (f.Field === propName) { + found = f; + } + }); + } + + if (found) { + actualize(propName, found); + } else { + sql.push('ADD COLUMN ' + self.client.escapeId(propName) + ' ' + + self.buildColumnDefinition(model, propName)); + } + }); + + // drop columns + if (actualFields) { + actualFields.forEach(function(f) { + var notFound = !~propNames.indexOf(f.Field); + if (m.properties[f.Field] && self.id(model, f.Field)) return; + if (notFound || !m.properties[f.Field]) { + sql.push('DROP COLUMN ' + self.client.escapeId(f.Field)); + } + }); + } + + // remove indexes + aiNames.forEach(function(indexName) { + if (indexName === 'PRIMARY' || + (m.properties[indexName] && self.id(model, indexName))) return; + if (indexNames.indexOf(indexName) === -1 && !m.properties[indexName] || + m.properties[indexName] && !m.properties[indexName].index) { + sql.push('DROP INDEX ' + self.client.escapeId(indexName)); + } else { + // first: check single (only type and kind) + if (m.properties[indexName] && !m.properties[indexName].index) { + // TODO + return; + } + // second: check multiple indexes + var orderMatched = true; + if (indexNames.indexOf(indexName) !== -1) { + m.settings.indexes[indexName].columns.split(/,\s*/).forEach( + function(columnName, i) { + if (ai[indexName].columns[i] !== columnName) orderMatched = false; + }); + } + if (!orderMatched) { + sql.push('DROP INDEX ' + self.client.escapeId(indexName)); + delete ai[indexName]; + } + } + }); + + // add single-column indexes + propNames.forEach(function(propName) { + var i = m.properties[propName].index; + if (!i) { + return; + } + var found = ai[propName] && ai[propName].info; + if (!found) { + var pName = self.client.escapeId(propName); + var type = ''; + var kind = ''; + if (i.type) { + type = 'USING ' + i.type; + } + if (kind && type) { + sql.push('ADD ' + kind + ' INDEX ' + pName + + ' (' + pName + ') ' + type); + } else { + if (typeof i === 'object' && i.unique && i.unique === true) { + kind = "UNIQUE"; + } + sql.push('ADD ' + kind + ' INDEX ' + pName + ' ' + type + + ' (' + pName + ') '); + } + } + }); + + // add multi-column indexes + indexNames.forEach(function(indexName) { + var i = m.settings.indexes[indexName]; + var found = ai[indexName] && ai[indexName].info; + if (!found) { + var iName = self.client.escapeId(indexName); + var type = ''; + var kind = ''; + if (i.type) { + type = 'USING ' + i.type; + } + if (i.kind) { + kind = i.kind; + } + if (kind && type) { + sql.push('ADD ' + kind + ' INDEX ' + iName + + ' (' + i.columns + ') ' + type); + } else { + sql.push('ADD ' + kind + ' INDEX ' + type + ' ' + iName + + ' (' + i.columns + ')'); + } + } + }); + + if (sql.length) { + var query = 'ALTER TABLE ' + self.tableEscaped(model) + ' ' + + sql.join(',\n'); + if (checkOnly) { + done(null, true, {statements: sql, query: query}); + } else { + this.execute(query, done); + } + } else { + done(); + } + + function actualize(propName, oldSettings) { + var newSettings = m.properties[propName]; + if (newSettings && changed(newSettings, oldSettings)) { + var pName = self.client.escapeId(propName); + sql.push('CHANGE COLUMN ' + pName + ' ' + pName + ' ' + + self.buildColumnDefinition(model, propName)); + } + } + + function changed(newSettings, oldSettings) { + if (oldSettings.Null === 'YES') { + // Used to allow null and does not now. + if (!self.isNullable(newSettings)) { + return true; + } + } + if (oldSettings.Null === 'NO') { + // Did not allow null and now does. + if (self.isNullable(newSettings)) { + return true; + } + } + + if (oldSettings.Type.toUpperCase() !== + self.buildColumnType(newSettings).toUpperCase()) { + return true; + } + return false; + } + }; + + MySQL.prototype.buildColumnDefinitions = + MySQL.prototype.propertiesSQL = function(model) { + var self = this; + + var pks = this.idNames(model).map(function(i) { + return self.columnEscaped(model, i); + }); + + var definition = this.getModelDefinition(model); + var sql = []; + if (pks.length === 1) { + var idName = this.idName(model); + var idProp = this.getModelDefinition(model).properties[idName]; + if (idProp.generated) { + sql.push(self.columnEscaped(model, idName) + + ' INT(11) NOT NULL AUTO_INCREMENT PRIMARY KEY'); + } else { + idProp.nullable = false; + sql.push(self.columnEscaped(model, idName) + ' ' + + self.buildColumnDefinition(model, idName) + ' PRIMARY KEY'); + } + } + Object.keys(definition.properties).forEach(function(prop) { + if (self.id(model, prop) && pks.length === 1) { + return; + } + var colName = self.columnEscaped(model, prop); + sql.push(colName + ' ' + self.buildColumnDefinition(model, prop)); + }); + if (pks.length > 1) { + sql.push('PRIMARY KEY(' + pks.join(',') + ')'); + } + + var indexes = self.buildIndexes(model); + indexes.forEach(function(i) { + sql.push(i); + }); + return sql.join(',\n '); + }; + + MySQL.prototype.buildIndex = function(model, property) { + var prop = this.getModelDefinition(model).properties[property]; + var i = prop && prop.index; + if (!i) { + return ''; + } + var type = ''; + var kind = ''; + if (i.type) { + type = 'USING ' + i.type; + } + if (i.kind) { + kind = i.kind; + } + var columnName = this.columnEscaped(model, property); + if (kind && type) { + return (kind + ' INDEX ' + columnName + ' (' + columnName + ') ' + type); + } else { + if (typeof i === 'object' && i.unique && i.unique === true) { + kind = "UNIQUE"; + } + return (kind + ' INDEX ' + columnName + ' ' + type + ' (' + columnName + ') '); + } + }; + + MySQL.prototype.buildIndexes = function(model) { + var self = this; + var indexClauses = []; + var definition = this.getModelDefinition(model); + var indexes = definition.settings.indexes || {}; + // Build model level indexes + for (var index in indexes) { + var i = indexes[index]; + var type = ''; + var kind = ''; + if (i.type) { + type = 'USING ' + i.type; + } + if (i.kind) { + kind = i.kind; + } + var indexedColumns = []; + var indexName = this.escapeName(index); + if (Array.isArray(i.keys)) { + indexedColumns = i.keys.map(function(key) { + return self.columnEscaped(model, key); + }); + } + var columns = indexedColumns.join(',') || i.columns; + if (kind && type) { + indexClauses.push(kind + ' INDEX ' + indexName + ' (' + columns + ') ' + type); + } else { + indexClauses.push(kind + ' INDEX ' + type + ' ' + indexName + ' (' + columns + ')'); + } + } + + // Define index for each of the properties + for (var p in definition.properties) { + var propIndex = self.buildIndex(model, p); + if (propIndex) { + indexClauses.push(propIndex); + } + } + return indexClauses; + }; + + MySQL.prototype.buildColumnDefinition = function(model, prop) { + var p = this.getModelDefinition(model).properties[prop]; + var line = this.columnDataType(model, prop) + ' ' + + (this.isNullable(p) ? 'NULL' : 'NOT NULL'); + return line; + }; + + MySQL.prototype.columnDataType = function(model, property) { + var columnMetadata = this.columnMetadata(model, property); + var colType = columnMetadata && columnMetadata.dataType; + if (colType) { + colType = colType.toUpperCase(); + } + var prop = this.getModelDefinition(model).properties[property]; + if (!prop) { + return null; + } + var colLength = columnMetadata && columnMetadata.dataLength || + prop.length || prop.limit; + if (colType && colLength) { + return colType + '(' + colLength + ')'; + } + return this.buildColumnType(prop); + }; + + MySQL.prototype.buildColumnType = function buildColumnType(propertyDefinition) { + var dt = ''; + var p = propertyDefinition; + switch (p.type.name) { + default: + case 'JSON': + case 'Object': + case 'Any': + case 'Text': + dt = columnType(p, 'TEXT'); + dt = stringOptionsByType(p, dt); + break; + case 'String': + dt = columnType(p, 'VARCHAR'); + dt = stringOptionsByType(p, dt); + break; + case 'Number': + dt = columnType(p, 'INT'); + dt = numericOptionsByType(p, dt); + break; + case 'Date': + dt = columnType(p, 'DATETIME'); // Currently doesn't need options. + break; + case 'Boolean': + dt = 'TINYINT(1)'; + break; + case 'Point': + case 'GeoPoint': + dt = 'POINT'; + break; + case 'Enum': + dt = 'ENUM(' + p.type._string + ')'; + dt = stringOptions(p, dt); // Enum columns can have charset/collation. + break; + } + return dt; + }; + + function columnType(p, defaultType) { + var dt = defaultType; + if (p.dataType) { + dt = String(p.dataType); + } + return dt; + } + + function stringOptionsByType(p, columnType) { + switch (columnType.toLowerCase()) { + default: + case 'varchar': + // The maximum length for an ID column is 1000 bytes + // The maximum row size is 64K + var len = p.length || p.limit || + ((p.type !== String) ? 4096 : p.id ? 255 : 512); + columnType += '(' + len + ')'; + break; + case 'char': + len = p.length || p.limit || 255; + columnType += '(' + len + ')'; + break; + + case 'text': + case 'tinytext': + case 'mediumtext': + case 'longtext': + + break; + } + columnType = stringOptions(p, columnType); + return columnType; + } + + function stringOptions(p, columnType) { + if (p.charset) { + columnType += " CHARACTER SET " + p.charset; + } + if (p.collation) { + columnType += " COLLATE " + p.collation; + } + return columnType; + } + + function numericOptionsByType(p, columnType) { + switch (columnType.toLowerCase()) { + default: + case 'tinyint': + case 'smallint': + case 'mediumint': + case 'int': + case 'integer': + case 'bigint': + columnType = integerOptions(p, columnType); + break; + + case 'decimal': + case 'numeric': + columnType = fixedPointOptions(p, columnType); + break; + + case 'float': + case 'double': + columnType = floatingPointOptions(p, columnType); + break; + } + columnType = unsigned(p, columnType); + return columnType; + } + + function floatingPointOptions(p, columnType) { + var precision = 16; + var scale = 8; + if (p.precision) { + precision = Number(p.precision); + } + if (p.scale) { + scale = Number(p.scale); + } + if (p.precision && p.scale) { + columnType += '(' + precision + ',' + scale + ')'; + } else if (p.precision) { + columnType += '(' + precision + ')'; + } + return columnType; + } + + /* @TODO: Change fixed point to use an arbitrary precision arithmetic library. */ + /* Currently fixed point will lose precision because it's turned to non-fixed in */ + /* JS. Also, defaulting column to (9,2) and not allowing non-specified 'DECIMAL' */ + /* declaration which would default to DECIMAL(10,0). Instead defaulting to (9,2). */ + function fixedPointOptions(p, columnType) { + var precision = 9; + var scale = 2; + if (p.precision) { + precision = Number(p.precision); + } + if (p.scale) { + scale = Number(p.scale); + } + columnType += '(' + precision + ',' + scale + ')'; + return columnType; + } + + function integerOptions(p, columnType) { + var tmp = 0; + if (p.display || p.limit) { + tmp = Number(p.display || p.limit); + } + if (tmp > 0) { + columnType += '(' + tmp + ')'; + } else if (p.unsigned) { + switch (columnType.toLowerCase()) { + default: + case 'int': + columnType += '(10)'; + break; + case 'mediumint': + columnType += '(8)'; + break; + case 'smallint': + columnType += '(5)'; + break; + case 'tinyint': + columnType += '(3)'; + break; + case 'bigint': + columnType += '(20)'; + break; + } + } else { + switch (columnType.toLowerCase()) { + default: + case 'int': + columnType += '(11)'; + break; + case 'mediumint': + columnType += '(9)'; + break; + case 'smallint': + columnType += '(6)'; + break; + case 'tinyint': + columnType += '(4)'; + break; + case 'bigint': + columnType += '(20)'; + break; + } + } + return columnType; + } + + function unsigned(p, columnType) { + if (p.unsigned) { + columnType += ' UNSIGNED'; + } + return columnType; + } +} diff --git a/lib/mysql.js b/lib/mysql.js index 5e656e2..51c8125 100644 --- a/lib/mysql.js +++ b/lib/mysql.js @@ -4,9 +4,9 @@ var mysql = require('mysql'); var SqlConnector = require('loopback-connector').SqlConnector; +var ParameterizedSQL = SqlConnector.ParameterizedSQL; var EnumFactory = require('./enumFactory').EnumFactory; -var async = require('async'); var debug = require('debug')('loopback:connector:mysql'); /** @@ -18,14 +18,48 @@ var debug = require('debug')('loopback:connector:mysql'); * @param {Function} [callback] The callback function */ exports.initialize = function initializeDataSource(dataSource, callback) { - if (!mysql) { - return; - } + dataSource.driver = mysql; // Provide access to the native driver + dataSource.connector = new MySQL(dataSource.settings); + dataSource.connector.dataSource = dataSource; - var s = dataSource.settings; + defineMySQLTypes(dataSource); + dataSource.EnumFactory = EnumFactory; // factory for Enums. Note that currently Enums can not be registered. + + process.nextTick(function () { + callback && callback(); + }); +}; + +exports.MySQL = MySQL; + +function defineMySQLTypes(dataSource) { + var modelBuilder = dataSource.modelBuilder; + var defineType = modelBuilder.defineValueType ? + // loopback-datasource-juggler 2.x + modelBuilder.defineValueType.bind(modelBuilder) : + // loopback-datasource-juggler 1.x + modelBuilder.constructor.registerType.bind(modelBuilder.constructor); + + // The Point type is inherited from jugglingdb mysql adapter. + // LoopBack uses GeoPoint instead. + // The Point type can be removed at some point in the future. + defineType(function Point() { + }); +} + +/** + * @constructor + * Constructor for MySQL connector + * @param {Object} client The node-mysql client object + */ +function MySQL(settings) { + SqlConnector.call(this, 'mysql', settings); + + var s = settings || {}; if (s.collation) { - s.charset = s.collation.substr(0, s.collation.indexOf('_')); // Charset should be first 'chunk' of collation. + // Charset should be first 'chunk' of collation. + s.charset = s.collation.substr(0, s.collation.indexOf('_')); } else { s.collation = 'utf8_general_ci'; s.charset = 'utf8'; @@ -66,9 +100,9 @@ exports.initialize = function initializeDataSource(dataSource, callback) { } } - dataSource.client = mysql.createPool(options); + this.client = mysql.createPool(options); - dataSource.client.on('error', function (err) { + this.client.on('error', function (err) { dataSource.emit('error', err); dataSource.connected = false; dataSource.connecting = false; @@ -77,46 +111,6 @@ exports.initialize = function initializeDataSource(dataSource, callback) { if (debug.enabled) { debug('Settings: %j', s); } - - dataSource.connector = new MySQL(dataSource.client, s); - dataSource.connector.dataSource = dataSource; - - defineMySQLTypes(dataSource); - - dataSource.EnumFactory = EnumFactory; // factory for Enums. Note that currently Enums can not be registered. - - process.nextTick(function () { - callback && callback(); - }); -}; - -exports.MySQL = MySQL; - -function defineMySQLTypes(dataSource) { - var modelBuilder = dataSource.modelBuilder; - var defineType = modelBuilder.defineValueType ? - // loopback-datasource-juggler 2.x - modelBuilder.defineValueType.bind(modelBuilder) : - // loopback-datasource-juggler 1.x - modelBuilder.constructor.registerType.bind(modelBuilder.constructor); - - // The Point type is inherited from jugglingdb mysql adapter. - // LoopBack uses GeoPoint instead. - // The Point type can be removed at some point in the future. - defineType(function Point() { - }); -} - -/** - * @constructor - * Constructor for MySQL connector - * @param {Object} client The node-mysql client object - */ -function MySQL(client, settings) { - this.name = 'mysql'; - this._models = {}; - this.client = client; - this.settings = settings; } require('util').inherits(MySQL, SqlConnector); @@ -127,21 +121,16 @@ require('util').inherits(MySQL, SqlConnector); * @param {String} sql The SQL statement * @param {Function} [callback] The callback after the SQL statement is executed */ -MySQL.prototype.query = function (sql, callback) { +MySQL.prototype.executeSQL = function (sql, params, options, callback) { var self = this; - if (!this.dataSource.connected) { - return this.dataSource.once('connected', function () { - this.query(sql, callback); - }.bind(this)); - } var client = this.client; - var time = Date.now(); var debugEnabled = debug.enabled; var db = this.settings.database; - var log = this.log; - if (typeof callback !== 'function') throw new Error('callback should be a function'); + if (typeof callback !== 'function') { + throw new Error('callback should be a function'); + } if (debugEnabled) { - debug('SQL: %s', sql); + debug('SQL: %s, params: %j', sql, params); } function releaseConnectionAndCallback(connection, err, result) { @@ -150,36 +139,32 @@ MySQL.prototype.query = function (sql, callback) { } function runQuery(connection) { - connection.query(sql, function (err, data) { + connection.query(sql, params, function (err, data) { if (debugEnabled) { if (err) { - console.error('Error: %j', err); + debug('Error: %j', err); } debug('Data: ', data); } - if (log) { - log(sql, time); - } releaseConnectionAndCallback(connection, err, data); }); } client.getConnection(function (err, connection) { if (err) { - callback && callback(err); - return; + return callback && callback(err); } if (self.settings.createDatabase) { // Call USE db ... - connection.query('USE ' + client.escapeId(db), function (err) { + connection.query('USE ??', [db], function (err) { if (err) { if (err && err.message.match(/(^|: )unknown database/i)) { var charset = self.settings.charset; var collation = self.settings.collation; - var q = 'CREATE DATABASE ' + db + ' CHARACTER SET ' + charset + ' COLLATE ' + collation; - connection.query(q, function (err) { + var q = 'CREATE DATABASE ?? CHARACTER SET ?? COLLATE ??'; + connection.query(q, [db, charset, collation], function (err) { if (!err) { - connection.query('USE ' + client.escapeId(db), function (err) { + connection.query('USE ??', [db], function (err) { runQuery(connection); }); } else { @@ -201,26 +186,6 @@ MySQL.prototype.query = function (sql, callback) { }); }; -/** - * Create the data model in MySQL - * - * @param {String} model The model name - * @param {Object} data The model instance data - * @param {Function} [callback] The callback function - */ -MySQL.prototype.create = function (model, data, callback) { - var fields = this.toFields(model, data); - var sql = 'INSERT INTO ' + this.tableEscaped(model); - if (fields) { - sql += ' SET ' + fields; - } else { - sql += ' VALUES ()'; - } - this.query(sql, function (err, info) { - callback(err, info && info.insertId); - }); -}; - /** * Update if the model instance exists with the same id or create a new instance * @@ -228,63 +193,48 @@ MySQL.prototype.create = function (model, data, callback) { * @param {Object} data The model instance data * @param {Function} [callback] The callback function */ -MySQL.prototype.updateOrCreate = MySQL.prototype.save = function (model, data, callback) { - var mysql = this; - var fieldsNames = []; - var fieldValues = []; - var combined = []; - var props = this._models[model].properties; - Object.keys(data).forEach(function (key) { - if (props[key] || mysql.id(model, key)) { - var k = mysql.columnEscaped(model, key); - var v; - v = mysql.toDatabase(props[key], data[key], true); - if (v !== undefined) { - fieldsNames.push(k); - fieldValues.push(v); - if (!mysql.id(model, key)) { - combined.push(k + ' = ' + v); - } +MySQL.prototype.updateOrCreate = MySQL.prototype.save = + function(model, data, options, callback) { + var fields = this.buildFields(model, data); + + var sql = new ParameterizedSQL('INSERT INTO ' + this.tableEscaped(model)); + var columnValues = fields.columnValues; + var fieldNames = fields.names; + if (fieldNames.length) { + sql.merge('(' + fieldNames.join(',') + ')', ''); + var values = ParameterizedSQL.join(columnValues, ','); + values.sql = 'VALUES(' + values.sql + ')'; + sql.merge(values); + } else { + sql.merge(this.buildInsertDefaultValues(model, data, options)); + } + + sql.merge('ON DUPLICATE KEY UPDATE'); + var setValues = []; + for (var i = 0, n = fields.names.length; i < n; i++) { + if (!fields.properties[i].id) { + setValues.push(new ParameterizedSQL(fields.names[i] + '=' + + columnValues[i].sql, columnValues[i].params)); } } - }); - var sql = 'INSERT INTO ' + this.tableEscaped(model); - sql += ' (' + fieldsNames.join(', ') + ')'; - sql += ' VALUES (' + fieldValues.join(', ') + ')'; - sql += ' ON DUPLICATE KEY UPDATE ' + combined.join(', '); + sql.merge(ParameterizedSQL.join(setValues, ',')); - this.query(sql, function(err, info) { - if (!err && info && info.insertId) { - data.id = info.insertId; - } - var meta = {}; - if (info) { - // When using the INSERT ... ON DUPLICATE KEY UPDATE statement, - // the returned value is as follows: - // 1 for each successful INSERT. - // 2 for each successful UPDATE. - meta.isNewInstance = (info.affectedRows === 1); - } - callback(err, data, meta); - }); -}; - -MySQL.prototype.toFields = function (model, data) { - var self = this; - var fields = []; - var props = this._models[model].properties; - Object.keys(data).forEach(function (key) { - if (props[key]) { - var value = this.toDatabase(props[key], data[key], true); - if (undefined === value) { - return; + this.execute(sql.sql, sql.params, function(err, info) { + if (!err && info && info.insertId) { + data.id = info.insertId; } - fields.push(self.columnEscaped(model, key) + ' = ' + value); - } - }.bind(this)); - return fields.join(','); -}; + var meta = {}; + if (info) { + // When using the INSERT ... ON DUPLICATE KEY UPDATE statement, + // the returned value is as follows: + // 1 for each successful INSERT. + // 2 for each successful UPDATE. + meta.isNewInstance = (info.affectedRows === 1); + } + callback(err, data, meta); + }); + }; function dateToMysql(val) { return val.getUTCFullYear() + '-' + @@ -299,61 +249,52 @@ function dateToMysql(val) { } } +MySQL.prototype.getInsertedId = function(model, info) { + var insertedId = info && typeof info.insertId === 'number' ? + info.insertId : undefined; + return insertedId; +}; + /*! - * Convert property name/value to a DB column - * @param prop - * @param val - * @returns {*} + * Convert property name/value to an escaped DB column value + * @param {Object} prop Property descriptor + * @param {*} val Property value + * @returns {*} The escaped value of DB column */ -MySQL.prototype.toDatabase = function (prop, val, forCreate) { - if (val === null || val === undefined) { - return 'NULL'; - } - if (!forCreate && val.constructor.name === 'Object') { - var operator = Object.keys(val)[0] - val = val[operator]; - if (operator === 'between') { - return this.toDatabase(prop, val[0]) + - ' AND ' + - this.toDatabase(prop, val[1]); - } else if (operator === 'inq' || operator === 'nin') { - if (Array.isArray(val)) { //if value is array - for (var i = 0; i < val.length; i++) { - val[i] = this.toDatabase(prop, val[i]); - } - return val.join(','); - } else { - return this.toDatabase(prop, val); - } +MySQL.prototype.toColumnValue = function(prop, val) { + if (val == null) { + if (prop.autoIncrement || prop.id) { + return new ParameterizedSQL('DEFAULT'); } - return this.toDatabase(prop, val); + return null; } if (!prop) { - return this.client.escape(val); + return val; } if (prop.type === String) { - return this.client.escape(String(val)); + return String(val); } if (prop.type === Number) { if (isNaN(val)) { - val = null; + // FIXME: [rfeng] Should fail fast? + return val; } - return this.client.escape(val); + return val; } if (prop.type === Date) { - if (!val) { - return 'NULL'; - } if (!val.toUTCString) { val = new Date(val); } - return '"' + dateToMysql(val) + '"'; + return dateToMysql(val); } if (prop.type === Boolean) { - return val ? 1 : 0; + return !!val; } if (prop.type.name === 'GeoPoint') { - return val ? 'Point(' + val.lat + ',' + val.lng + ')' : 'NULL'; + return new ParameterizedSQL({ + sql: 'Point(?,?)', + params: [val.lat, val.lng] + }); } if (prop.type === Object) { return this._serializeObject(val); @@ -374,929 +315,137 @@ MySQL.prototype._serializeObject = function(obj) { } else { val = obj; } - return this.client.escape(val); + return val; }; /*! - * Convert the data from database - * @param model - * @param data - * @returns {*} + * Convert the data from database column to model property + * @param {object} Model property descriptor + * @param {*) val Column value + * @returns {*} Model property value */ -MySQL.prototype.fromDatabase = function (model, data) { - if (!data) { - return null; +MySQL.prototype.fromColumnValue = function(prop, val) { + if (val == null) { + return val; } - var props = this._models[model].properties; - var json = {}; - for (var p in props) { - var key = this.column(model, p); - var val = data[key]; - if (val === undefined) { - continue; + if (prop) { + switch (prop.type.name) { + case 'Number': + val = Number(val); + break; + case 'String': + val = String(val); + break; + case 'Date': + val = new Date(val.toString().replace(/GMT.*$/, 'GMT')); + break; + case 'Boolean': + val = Boolean(val); + break; + case 'GeoPoint': + case 'Point': + val = { + lat: val.x, + lng: val.y + }; + break; + case 'List': + case 'Array': + case 'Object': + case 'JSON': + if (typeof val === 'string') { + val = JSON.parse(val); + } + break; + default: + if (!Array.isArray(prop.type) && !prop.type.modelName) { + // Do not convert array and model types + val = prop.type(val); + } + break; } - if (val === null) { - json[p] = null; - continue; - } - if (props[p]) { - switch (props[p].type.name) { - case 'Number': - val = Number(val); - break; - case 'String': - val = String(val); - break; - case 'Date': - val = new Date(val.toString().replace(/GMT.*$/, 'GMT')); - break; - case 'Boolean': - val = Boolean(val); - break; - case 'GeoPoint': - case 'Point': - val = { - lat: val.x, - lng: val.y - }; - break; - case 'List': - case 'Array': - case 'Object': - case 'JSON': - break; - default: - if (!Array.isArray(props[p].type) && !props[p].type.modelName) { - // Do not convert array and model types - val = props[p].type(val); - } - break; - } - } - json[p] = val; } - return json; + return val; }; +/** + * Escape an identifier such as the column name + * @param {string} name A database identifier + * @returns {string} The escaped database identifier + */ MySQL.prototype.escapeName = function (name) { return this.client.escapeId(name); }; -MySQL.prototype.getColumns = function (model, props) { - var cols = this._models[model].properties; - if (!cols) { - return '*'; - } - var self = this; - var keys = Object.keys(cols); - if (Array.isArray(props) && props.length > 0) { - // No empty array, including all the fields - keys = props; - } else if ('object' === typeof props && Object.keys(props).length > 0) { - // { field1: boolean, field2: boolean ... } - var included = []; - var excluded = []; - keys.forEach(function (k) { - if (props[k]) { - included.push(k); - } else if ((k in props) && !props[k]) { - excluded.push(k); - } - }); - if (included.length > 0) { - keys = included; - } else if (excluded.length > 0) { - excluded.forEach(function (e) { - var index = keys.indexOf(e); - keys.splice(index, 1); - }); - } - } - var names = keys.map(function (c) { - return self.columnEscaped(model, c); - }); - return names.join(', '); -}; - -MySQL.prototype.buildWhere = function (model, conds) { - var where = this._buildWhere(model, conds); - return where? 'WHERE ' + where : ''; -}; - -MySQL.prototype._buildWhere = function (model, conds) { - if (conds === null || conds === undefined || (typeof conds !== 'object')) { - return ''; - } - var self = this; - var props = self._models[model].properties; - - var cs = []; - Object.keys(conds).forEach(function (key) { - if (key === 'and' || key === 'or') { - var clauses = conds[key]; - if (Array.isArray(clauses)) { - clauses = clauses.map(function (c) { - return '(' + self._buildWhere(model, c) + ')'; - }); - return cs.push(clauses.join(' ' + key.toUpperCase() + ' ')); - } - // The value is not an array, fall back to regular fields - } - var keyEscaped = self.columnEscaped(model, key); - var val = self.toDatabase(props[key], conds[key]); - if (conds[key] === null || conds[key] === undefined) { - cs.push(keyEscaped + ' IS NULL'); - } else if (conds[key] && conds[key].constructor.name === 'Object') { - var condType = Object.keys(conds[key])[0]; - var sqlCond = keyEscaped; - if ((condType === 'inq' || condType === 'nin') && val.length === 0) { - cs.push(condType === 'inq' ? 0 : 1); - return true; - } - switch (condType) { - case 'gt': - sqlCond += ' > '; - break; - case 'gte': - sqlCond += ' >= '; - break; - case 'lt': - sqlCond += ' < '; - break; - case 'lte': - sqlCond += ' <= '; - break; - case 'between': - sqlCond += ' BETWEEN '; - break; - case 'inq': - sqlCond += ' IN '; - break; - case 'nin': - sqlCond += ' NOT IN '; - break; - case 'neq': - sqlCond += val === 'NULL' ? ' IS NOT ' : ' != '; - break; - case 'like': - sqlCond += ' LIKE '; - break; - case 'nlike': - sqlCond += ' NOT LIKE '; - break; - } - sqlCond += (condType === 'inq' || condType === 'nin') ? '(' + val + ')' : val; - cs.push(sqlCond); - } else { - cs.push(keyEscaped + ' = ' + val); - } - }); - if (cs.length === 0) { - return ''; - } - return cs.join(' AND '); -} - -function buildOrderBy(self, model, order) { - if (typeof order === 'string') { - order = [order]; - } - return 'ORDER BY ' + order.map(function (o) { - var t = o.split(/[\s,]+/); - if (t.length === 1) { - return self.columnEscaped(model, o); - } - return self.columnEscaped(model, t[0]) + ' ' + t[1]; - }).join(', '); -} - -function buildLimit(limit, offset) { +/** + * Build the LIMIT clause + * @param {string} model Model name + * @param {number} limit The limit + * @param {number} offset The offset + * @returns {string} The LIMIT clause + */ +MySQL.prototype._buildLimit = function (model, limit, offset) { if (isNaN(limit)) { limit = 0; } if (isNaN(offset)) { offset = 0; } + if (!limit && !offset) { + return ''; + } return 'LIMIT ' + (offset ? (offset + ',' + limit) : limit); } -/** - * Find matching model instances by the filter - * - * @param {String} model The model name - * @param {Object} filter The filter - * @param {Function} [callback] The callback function - */ -MySQL.prototype.all = function all(model, filter, callback) { - var self = this; - // Order by id if no order is specified - filter = filter || {}; - if (!filter.order) { - var idNames = this.idNames(model); - if (idNames && idNames.length) { - filter.order = idNames; - } - } - - var sql = 'SELECT ' + this.getColumns(model, filter.fields) + ' FROM ' + this.tableEscaped(model); - - if (filter) { - - if (filter.where) { - sql += ' ' + self.buildWhere(model, filter.where); - } - - if (filter.order) { - sql += ' ' + buildOrderBy(self, model, filter.order); - } - - if (filter.limit) { - sql += ' ' + buildLimit(filter.limit, filter.skip || filter.offset || 0); - } - - } - - this.query(sql, function (err, data) { - if (err) { - return callback(err, []); - } - - var objs = data.map(function (obj) { - return self.fromDatabase(model, obj); - }); - if (filter && filter.include) { - this._models[model].model.include(objs, filter.include, callback); - } else { - callback(null, objs); - } - }.bind(this)); - - return sql; - -}; - -MySQL.prototype.count = function count(model, callback, where) { - - this.query('SELECT count(*) as cnt FROM ' + - this.tableEscaped(model) + ' ' + this.buildWhere(model, where), - function (err, res) { - if (err) { - return callback(err); - } - var c = (res && res[0] && res[0].cnt) || 0; - callback(err, c); - }); - -}; - -MySQL.prototype.update = -MySQL.prototype.updateAll = function(model, where, data, cb) { - var query = 'UPDATE ' + this.tableEscaped(model) + ' SET ' + - this.toFields(model, data) + ' ' + this.buildWhere(model, where); - this.query(query, function(err, info) { - var affectedRows = info && typeof info.affectedRows === 'number' ? - info.affectedRows : undefined; - cb && cb(err, {count: affectedRows}); - }); -}; - - -/** - * Delete instances for the given model - * - * @param {String} model The model name - * @param {Object} [where] The filter for where - * @param {Function} [callback] The callback function - * - */ -MySQL.prototype.destroyAll = function destroyAll(model, where, callback) { - if (!callback && 'function' === typeof where) { - callback = where; - where = undefined; - } - this.query('DELETE FROM ' - + this.tableEscaped(model) + ' ' + this.buildWhere(model, where || {}), - function(err, info) { - var affectedRows = info && typeof info.affectedRows === 'number' ? - info.affectedRows : undefined; - callback && callback(err, {count: affectedRows}); - }.bind(this)); +MySQL.prototype.applyPagination = function(model, stmt, filter) { + var limitClause = this._buildLimit(model, filter.limit, + filter.offset || filter.skip); + return stmt.merge(limitClause); }; /** - * Perform autoupdate for the given models - * @param {String[]} [models] A model name or an array of model names. If not present, apply to all models - * @param {Function} [cb] The callback function + * Get the place holder in SQL for identifiers, such as ?? + * @param {String} key Optional key, such as 1 or id + * @returns {String} The place holder */ -MySQL.prototype.autoupdate = function (models, cb) { - var self = this; - - if ((!cb) && ('function' === typeof models)) { - cb = models; - models = undefined; - } - // First argument is a model name - if ('string' === typeof models) { - models = [models]; - } - - models = models || Object.keys(this._models); - - async.each(models, function(model, done) { - if (!(model in self._models)) { - return process.nextTick(function() { - done(new Error('Model not found: ' + model)); - }); - } - var table = self.tableEscaped(model); - self.query('SHOW FIELDS FROM ' + table, function(err, fields) { - self.query('SHOW INDEXES FROM ' + table, function(err, indexes) { - if (!err && fields && fields.length) { - self.alterTable(model, fields, indexes, done); - } else { - self.createTable(model, done); - } - }); - }); - }, cb); - -}; - -/*! - * Create table - * @param model - * @param cb - */ -MySQL.prototype.createTable = function (model, cb) { - var metadata = this._models[model].settings[this.name]; - var engine = metadata && metadata.engine; - var sql = 'CREATE TABLE ' + this.tableEscaped(model) + - ' (\n ' + this.propertiesSQL(model) + '\n)'; - if (engine) { - sql += 'ENGINE=' + engine + '\n'; - } - this.query(sql, cb); +MySQL.prototype.getPlaceholderForIdentifier = function (key) { + return '??'; }; /** - * Check if the models exist - * @param {String[]} [models] A model name or an array of model names. If not present, apply to all models - * @param {Function} [cb] The callback function + * Get the place holder in SQL for values, such as :1 or ? + * @param {String} key Optional key, such as 1 or id + * @returns {String} The place holder */ -MySQL.prototype.isActual = function(models, cb) { - var self = this; - var ok = false; - - if ((!cb) && ('function' === typeof models)) { - cb = models; - models = undefined; - } - // First argument is a model name - if ('string' === typeof models) { - models = [models]; - } - - models = models || Object.keys(this._models); - - async.each(models, function(model, done) { - var table = self.tableEscaped(model); - self.query('SHOW FIELDS FROM ' + table, function(err, fields) { - self.query('SHOW INDEXES FROM ' + table, function(err, indexes) { - self.alterTable(model, fields, indexes, function(err, needAlter) { - if (err) { - return done(err); - } else { - ok = ok || needAlter; - done(err); - } - }, true); - }); - }); - }, function(err) { - if (err) { - return err; - } - cb(null, !ok); - }); +MySQL.prototype.getPlaceholderForValue = function (key) { + return '?'; }; -// Check if a property is nullable -function isNullable(p) { - if (p.required || p.id) { - return false; - } - if (p.nullable || p['null'] || p.allowNull) { - return true; - } - if (p.nullable === false || p['null'] === false || p.allowNull === false) { - return false; - } - return true; -} - -MySQL.prototype.alterTable = function (model, actualFields, actualIndexes, done, checkOnly) { - var self = this; - var m = this._models[model]; - var propNames = Object.keys(m.properties).filter(function (name) { - return !!m.properties[name]; - }); - var indexNames = m.settings.indexes ? Object.keys(m.settings.indexes).filter(function (name) { - return !!m.settings.indexes[name]; - }) : []; - var sql = []; - var ai = {}; - - if (actualIndexes) { - actualIndexes.forEach(function (i) { - var name = i.Key_name; - if (!ai[name]) { - ai[name] = { - info: i, - columns: [] - }; - } - ai[name].columns[i.Seq_in_index - 1] = i.Column_name; - }); - } - var aiNames = Object.keys(ai); - - // change/add new fields - propNames.forEach(function (propName) { - if (m.properties[propName] && self.id(model, propName)) return; - var found; - if (actualFields) { - actualFields.forEach(function (f) { - if (f.Field === propName) { - found = f; - } - }); - } - - if (found) { - actualize(propName, found); - } else { - sql.push('ADD COLUMN ' + self.client.escapeId(propName) + ' ' + - self.propertySettingsSQL(model, propName)); - } - }); - - // drop columns - if (actualFields) { - actualFields.forEach(function (f) { - var notFound = !~propNames.indexOf(f.Field); - if (m.properties[f.Field] && self.id(model, f.Field)) return; - if (notFound || !m.properties[f.Field]) { - sql.push('DROP COLUMN ' + self.client.escapeId(f.Field)); - } - }); - } - - // remove indexes - aiNames.forEach(function (indexName) { - if (indexName === 'PRIMARY' || (m.properties[indexName] && self.id(model, indexName))) return; - if (indexNames.indexOf(indexName) === -1 && !m.properties[indexName] || m.properties[indexName] && !m.properties[indexName].index) { - sql.push('DROP INDEX ' + self.client.escapeId(indexName)); - } else { - // first: check single (only type and kind) - if (m.properties[indexName] && !m.properties[indexName].index) { - // TODO - return; - } - // second: check multiple indexes - var orderMatched = true; - if (indexNames.indexOf(indexName) !== -1) { - m.settings.indexes[indexName].columns.split(/,\s*/).forEach(function (columnName, i) { - if (ai[indexName].columns[i] !== columnName) orderMatched = false; - }); - } - if (!orderMatched) { - sql.push('DROP INDEX ' + self.client.escapeId(indexName)); - delete ai[indexName]; - } - } - }); - - // add single-column indexes - propNames.forEach(function (propName) { - var i = m.properties[propName].index; - if (!i) { - return; - } - var found = ai[propName] && ai[propName].info; - if (!found) { - var pName = self.client.escapeId(propName); - var type = ''; - var kind = ''; - if (i.type) { - type = 'USING ' + i.type; - } - if (i.kind) { - // kind = i.kind; - } - if (kind && type) { - sql.push('ADD ' + kind + ' INDEX ' + pName + ' (' + pName + ') ' + type); - } else { - (typeof i === 'object' && i.unique && i.unique === true) && (kind = "UNIQUE"); - sql.push('ADD ' + kind + ' INDEX ' + pName + ' ' + type + ' (' + pName + ') '); - } - } - }); - - // add multi-column indexes - indexNames.forEach(function (indexName) { - var i = m.settings.indexes[indexName]; - var found = ai[indexName] && ai[indexName].info; - if (!found) { - var iName = self.client.escapeId(indexName); - var type = ''; - var kind = ''; - if (i.type) { - type = 'USING ' + i.type; - } - if (i.kind) { - kind = i.kind; - } - if (kind && type) { - sql.push('ADD ' + kind + ' INDEX ' + iName + ' (' + i.columns + ') ' + type); - } else { - sql.push('ADD ' + kind + ' INDEX ' + type + ' ' + iName + ' (' + i.columns + ')'); - } - } - }); - - if (sql.length) { - var query = 'ALTER TABLE ' + self.tableEscaped(model) + ' ' + sql.join(',\n'); - if (checkOnly) { - done(null, true, {statements: sql, query: query}); - } else { - this.query(query, done); - } - } else { - done(); - } - - function actualize(propName, oldSettings) { - var newSettings = m.properties[propName]; - if (newSettings && changed(newSettings, oldSettings)) { - var pName = self.client.escapeId(propName); - sql.push('CHANGE COLUMN ' + pName + ' ' + pName + ' ' + - self.propertySettingsSQL(model, propName)); - } - } - - function changed(newSettings, oldSettings) { - if (oldSettings.Null === 'YES') { // Used to allow null and does not now. - if (newSettings.allowNull === false) return true; - if (newSettings.null === false) return true; - if (newSettings.nullable === false) return true; - if (newSettings.required || newSettings.id) return true; - } - if (oldSettings.Null === 'NO') { // Did not allow null and now does. - if (newSettings.allowNull === true) return true; - if (newSettings.null === true) return true; - if (newSettings.nullable === true) return true; - if (newSettings.null === undefined && - newSettings.allowNull === undefined && - !newSettings.required && - !newSettings.id) return true; - } - - if (oldSettings.Type.toUpperCase() !== datatype(newSettings).toUpperCase()) - return true; - return false; - } +MySQL.prototype.getCountForAffectedRows = function(model, info) { + var affectedRows = info && typeof info.affectedRows === 'number' ? + info.affectedRows : undefined; + return affectedRows; }; -MySQL.prototype.propertiesSQL = function (model) { - var self = this; - - var pks = this.idNames(model).map(function (i) { - return self.columnEscaped(model, i); - }); - - var sql = []; - if (pks.length === 1) { - var idName = this.idName(model); - var idProp = this._models[model].properties[idName]; - if (idProp.generated) { - sql.push(self.columnEscaped(model, idName) + ' INT(11) NOT NULL AUTO_INCREMENT PRIMARY KEY'); - } else { - idProp.nullable = false; - sql.push(self.columnEscaped(model, idName) + ' ' + self.propertySettingsSQL(model, idName) + ' PRIMARY KEY'); - } - } - Object.keys(this._models[model].properties).forEach(function (prop) { - if (self.id(model, prop) && pks.length === 1) { - return; - } - var colName = self.columnEscaped(model, prop); - sql.push(colName + ' ' + self.propertySettingsSQL(model, prop)); - }); - if (pks.length > 1) { - sql.push('PRIMARY KEY(' + pks.join(',') + ')'); - } - - /* - var sql = ['`id` INT(11) NOT NULL AUTO_INCREMENT PRIMARY KEY']; - Object.keys(this._models[model].properties).forEach(function (prop) { - if (self.id(model, prop)) return; - sql.push('`' + prop + '` ' + self.propertySettingsSQL(model, prop)); - }); - */ - - // Declared in model index property indexes. - Object.keys(this._models[model].properties).forEach(function (prop) { - var i = self._models[model].properties[prop].index; - if (i) { - sql.push(self.singleIndexSettingsSQL(model, prop)); - } - }); - // Settings might not have an indexes property. - var dxs = this._models[model].settings.indexes; - if (dxs) { - Object.keys(this._models[model].settings.indexes).forEach(function (prop) { - sql.push(self.indexSettingsSQL(model, prop)); - }); - } - return sql.join(',\n '); -}; - -MySQL.prototype.singleIndexSettingsSQL = function (model, prop) { - // Recycled from alterTable single indexes above, more or less. - var i = this._models[model].properties[prop].index; - var type = ''; - var kind = ''; - if (i.type) { - type = 'USING ' + i.type; - } - if (i.kind) { - kind = i.kind; - } - var columnName = this.columnEscaped(model, prop); - if (kind && type) { - return (kind + ' INDEX ' + columnName + ' (' + columnName + ') ' + type); - } else { - (typeof i === 'object' && i.unique && i.unique === true) && (kind = "UNIQUE"); - return (kind + ' INDEX ' + columnName + ' ' + type + ' (' + columnName + ') '); - } -}; - -MySQL.prototype.indexSettingsSQL = function (model, prop) { - // Recycled from alterTable multi-column indexes above, more or less. - var i = this._models[model].settings.indexes[prop]; - var type = ''; - var kind = ''; - if (i.type) { - type = 'USING ' + i.type; - } - if (i.kind) { - kind = i.kind; - } - var columnName = this.columnEscaped(model, prop); - if (kind && type) { - return (kind + ' INDEX ' + columnName + ' (' + i.columns + ') ' + type); - } else { - return (kind + ' INDEX ' + type + ' ' + columnName + ' (' + i.columns + ')'); - } -}; - -MySQL.prototype.propertySettingsSQL = function (model, prop) { - var p = this._models[model].properties[prop]; - var line = this.columnDataType(model, prop) + ' ' + - (p.required || p.id || p.nullable === false || - p.allowNull === false || p['null'] === false ? - 'NOT NULL' : 'NULL'); - return line; -}; - -MySQL.prototype.columnDataType = function (model, property) { - var columnMetadata = this.columnMetadata(model, property); - var colType = columnMetadata && columnMetadata.dataType; - if (colType) { - colType = colType.toUpperCase(); - } - var prop = this._models[model].properties[property]; - if (!prop) { - return null; - } - var colLength = columnMetadata && columnMetadata.dataLength || prop.length; - if (colType) { - return colType + (colLength ? '(' + colLength + ')' : ''); - } - return datatype(prop); -}; - -function datatype(p) { - var dt = ''; - switch (p.type.name) { - default: - case 'JSON': - case 'Object': - case 'Any': - case 'Text': - dt = columnType(p, 'TEXT'); - dt = stringOptionsByType(p, dt); - break; - case 'String': - dt = columnType(p, 'VARCHAR'); - dt = stringOptionsByType(p, dt); - break; - case 'Number': - dt = columnType(p, 'INT'); - dt = numericOptionsByType(p, dt); - break; - case 'Date': - dt = columnType(p, 'DATETIME'); // Currently doesn't need options. - break; - case 'Boolean': - dt = 'TINYINT(1)'; - break; - case 'Point': - case 'GeoPoint': - dt = 'POINT'; - break; - case 'Enum': - dt = 'ENUM(' + p.type._string + ')'; - dt = stringOptions(p, dt); // Enum columns can have charset/collation. - break; - } - return dt; -} - -function columnType(p, defaultType) { - var dt = defaultType; - if (p.dataType) { - dt = String(p.dataType); - } - return dt; -} - -function stringOptionsByType(p, dt) { - switch (dt.toLowerCase()) { - default: - case 'varchar': - // The maximum length for an ID column is 1000 bytes - // The maximum row size is 64K - var len = p.length || p.limit || ((p.type !== String) ? 4096 : p.id ? 255: 512); - dt += '(' + len + ')'; - break; - case 'char': - len = p.length || p.limit || 255; - dt += '(' + len + ')'; - break; - - case 'text': - case 'tinytext': - case 'mediumtext': - case 'longtext': - - break; - } - dt = stringOptions(p, dt); - return dt; -} - -function stringOptions(p, dt) { - if (p.charset) { - dt += " CHARACTER SET " + p.charset; - } - if (p.collation) { - dt += " COLLATE " + p.collation; - } - return dt; -} - -function numericOptionsByType(p, dt) { - switch (dt.toLowerCase()) { - default: - case 'tinyint': - case 'smallint': - case 'mediumint': - case 'int': - case 'integer': - case 'bigint': - dt = integerOptions(p, dt); - break; - - case 'decimal': - case 'numeric': - dt = fixedPointOptions(p, dt); - break; - - case 'float': - case 'double': - dt = floatingPointOptions(p, dt); - break; - } - dt = unsigned(p, dt); - return dt; -} - -function floatingPointOptions(p, dt) { - var precision = 16; - var scale = 8; - if (p.precision) { - precision = Number(p.precision); - } - if (p.scale) { - scale = Number(p.scale); - } - if (p.precision && p.scale) { - dt += '(' + precision + ',' + scale + ')'; - } else if (p.precision) { - dt += '(' + precision + ')'; - } - return dt; -} - -/* @TODO: Change fixed point to use an arbitrary precision arithmetic library. */ -/* Currently fixed point will lose precision because it's turned to non-fixed in */ -/* JS. Also, defaulting column to (9,2) and not allowing non-specified 'DECIMAL' */ -/* declaration which would default to DECIMAL(10,0). Instead defaulting to (9,2). */ -function fixedPointOptions(p, dt) { - var precision = 9; - var scale = 2; - if (p.precision) { - precision = Number(p.precision); - } - if (p.scale) { - scale = Number(p.scale); - } - dt += '(' + precision + ',' + scale + ')'; - return dt; -} - -function integerOptions(p, dt) { - var tmp = 0; - if (p.display || p.limit) { - tmp = Number(p.display || p.limit); - } - if (tmp > 0) { - dt += '(' + tmp + ')'; - } else if (p.unsigned) { - switch (dt.toLowerCase()) { - default: - case 'int': - dt += '(10)'; - break; - case 'mediumint': - dt += '(8)'; - break; - case 'smallint': - dt += '(5)'; - break; - case 'tinyint': - dt += '(3)'; - break; - case 'bigint': - dt += '(20)'; - break; - } - } else { - switch (dt.toLowerCase()) { - default: - case 'int': - dt += '(11)'; - break; - case 'mediumint': - dt += '(9)'; - break; - case 'smallint': - dt += '(6)'; - break; - case 'tinyint': - dt += '(4)'; - break; - case 'bigint': - dt += '(20)'; - break; - } - } - return dt; -} - -function unsigned(p, dt) { - if (p.unsigned) { - dt += ' UNSIGNED'; - } - return dt; -} /** * Disconnect from MySQL */ -MySQL.prototype.disconnect = function () { +MySQL.prototype.disconnect = function (cb) { if (this.debug) { debug('disconnect'); } if (this.client) { - this.client.end(); + this.client.end(cb); + } else { + process.nextTick(cb); } }; MySQL.prototype.ping = function(cb) { - this.query('SELECT 1 AS result', cb); + this.execute('SELECT 1 AS result', cb); }; -require('./discovery')(MySQL); +require('./migration')(MySQL, mysql); +require('./discovery')(MySQL, mysql); diff --git a/test/connection.test.js b/test/connection.test.js index 0895083..d31360c 100644 --- a/test/connection.test.js +++ b/test/connection.test.js @@ -3,7 +3,7 @@ var assert = require('assert'); var db, DummyModel, odb; -describe('migrations', function () { +describe('connections', function () { before(function () { require('./init.js'); @@ -23,9 +23,9 @@ describe('migrations', function () { }); it('should disconnect first db', function (done) { - db.client.end(function () { - odb = getSchema(); - done() + db.disconnect(function () { + odb = getDataSource(); + done(); }); }); @@ -40,8 +40,8 @@ describe('migrations', function () { }); it('should drop db and disconnect all', function (done) { - db.connector.query('DROP DATABASE IF EXISTS ' + db.settings.database, function (err) { - db.client.end(function () { + db.connector.execute('DROP DATABASE IF EXISTS ' + db.settings.database, function (err) { + db.disconnect(function () { done(); }); }); @@ -52,16 +52,18 @@ function charsetTest(test_set, test_collo, test_set_str, test_set_collo, done) { query('DROP DATABASE IF EXISTS ' + odb.settings.database, function (err) { assert.ok(!err); - odb.client.end(function () { + odb.disconnect(function () { - db = getSchema({collation: test_set_collo, createDatabase: true}); + db = getDataSource({collation: test_set_collo, createDatabase: true}); DummyModel = db.define('DummyModel', {string: String}); db.automigrate(function () { - var q = 'SELECT DEFAULT_COLLATION_NAME FROM information_schema.SCHEMATA WHERE SCHEMA_NAME = ' + db.client.escape(db.settings.database) + ' LIMIT 1'; - db.connector.query(q, function (err, r) { + var q = 'SELECT DEFAULT_COLLATION_NAME' + + ' FROM information_schema.SCHEMATA WHERE SCHEMA_NAME = ' + + db.driver.escape(db.settings.database) + ' LIMIT 1'; + db.connector.execute(q, function (err, r) { assert.ok(!err); assert.ok(r[0].DEFAULT_COLLATION_NAME.match(test_collo)); - db.connector.query('SHOW VARIABLES LIKE "character_set%"', function (err, r) { + db.connector.execute('SHOW VARIABLES LIKE "character_set%"', function (err, r) { assert.ok(!err); var hit_all = 0; for (var result in r) { @@ -72,7 +74,7 @@ function charsetTest(test_set, test_collo, test_set_str, test_set_collo, done) { } assert.equal(hit_all, 4); }); - db.connector.query('SHOW VARIABLES LIKE "collation%"', function (err, r) { + db.connector.execute('SHOW VARIABLES LIKE "collation%"', function (err, r) { assert.ok(!err); var hit_all = 0; for (var result in r) { @@ -90,7 +92,7 @@ function charsetTest(test_set, test_collo, test_set_str, test_set_collo, done) { } function matchResult(result, variable_name, match) { - if (result.Variable_name == variable_name) { + if (result.Variable_name === variable_name) { assert.ok(result.Value.match(match)); return 1; } @@ -98,7 +100,7 @@ function matchResult(result, variable_name, match) { } var query = function (sql, cb) { - odb.connector.query(sql, cb); + odb.connector.execute(sql, cb); }; diff --git a/test/datatypes.test.js b/test/datatypes.test.js index c754ae7..998d876 100644 --- a/test/datatypes.test.js +++ b/test/datatypes.test.js @@ -95,7 +95,7 @@ function setup(done) { } var query = function (sql, cb) { - db.adapter.query(sql, cb); + db.adapter.execute(sql, cb); }; var blankDatabase = function (db, cb) { diff --git a/test/migration.test.js b/test/migration.test.js index 5b23430..ce41fb2 100644 --- a/test/migration.test.js +++ b/test/migration.test.js @@ -16,7 +16,7 @@ describe('migrations', function () { it('UserData should have correct columns', function (done) { getFields('UserData', function (err, fields) { - assert.deepEqual(fields, { + fields.should.be.eql({ id: { Field: 'id', Type: 'int(11)', @@ -75,7 +75,7 @@ describe('migrations', function () { // Note: getIndexes truncates multi-key indexes to the first member. // Hence index1 is correct. getIndexes('UserData', function (err, fields) { - assert.deepEqual(fields, { PRIMARY: { Table: 'UserData', + fields.should.be.eql({ PRIMARY: { Table: 'UserData', Non_unique: 0, Key_name: 'PRIMARY', Seq_in_index: 1, @@ -118,7 +118,7 @@ describe('migrations', function () { it('StringData should have correct columns', function (done) { getFields('StringData', function (err, fields) { - assert.deepEqual(fields, { + fields.should.be.eql({ idString: { Field: "idString", Type: 'varchar(255)', Null: 'NO', @@ -162,7 +162,7 @@ describe('migrations', function () { it('NumberData should have correct columns', function (done) { getFields('NumberData', function (err, fields) { - assert.deepEqual(fields, { + fields.should.be.eql({ id: { Field: 'id', Type: 'int(11)', Null: 'NO', @@ -200,7 +200,7 @@ describe('migrations', function () { it('DateData should have correct columns', function (done) { getFields('DateData', function (err, fields) { - assert.deepEqual(fields, { + fields.should.be.eql({ id: { Field: 'id', Type: 'int(11)', Null: 'NO', @@ -381,7 +381,7 @@ function setup(done) { } var query = function (sql, cb) { - db.adapter.query(sql, cb); + db.adapter.execute(sql, cb); }; var blankDatabase = function (db, cb) { diff --git a/test/mysql.discover.test.js b/test/mysql.discover.test.js index f0d749e..123e73d 100644 --- a/test/mysql.discover.test.js +++ b/test/mysql.discover.test.js @@ -12,6 +12,17 @@ before(function () { }); describe('discoverModels', function () { + describe('Discover database schemas', function() { + it('should return an array of db schemas', function(done) { + db.connector.discoverDatabaseSchemas(function(err, schemas) { + if (err) return done(err); + schemas.should.be.an.array; + schemas.length.should.be.above(0); + done(); + }); + }); + }); + describe('Discover models including views', function () { it('should return an array of tables and views', function (done) {