diff --git a/lib/mysql.js b/lib/mysql.js index 82048a5..deb7b01 100644 --- a/lib/mysql.js +++ b/lib/mysql.js @@ -8,13 +8,22 @@ exports.initialize = function initializeSchema(schema, callback) { if (!mysql) return; var s = schema.settings; + + s.collation = (s.collation || 'utf8mb4_general_ci'); + s.charset = (s.charset || 'utf8mb4'); + s.supportBigNumbers = (s.supportBigNumbers || false); + s.timezone = (s.timezone || 'local'); + schema.client = mysql.createConnection({ host: s.host || 'localhost', port: s.port || 3306, user: s.username, password: s.password, + timezone: s.timezone, debug: s.debug, - socketPath: s.socketPath + socketPath: s.socketPath, + charset: s.collation, // Correct by docs despite seeming odd. + supportBigNumbers: s.supportBigNumbers }); schema.client.on('error', function (err) { @@ -24,13 +33,16 @@ exports.initialize = function initializeSchema(schema, callback) { schema.adapter = new MySQL(schema.client); schema.adapter.schema = schema; - // schema.client.query('SET TIME_ZONE = "+04:00"', callback); schema.client.query('USE `' + s.database + '`', function (err) { if (err) { if (err.message.match(/(^|: )unknown database/i)) { var dbName = s.database; - schema.client.query('CREATE DATABASE ' + dbName, function (error) { + var charset = s.charset; + var collation = s.collation; + var q = 'CREATE DATABASE ' + dbName + ' CHARACTER SET ' + charset + ' COLLATE ' + collation; + schema.client.query(q, function (error) { if (!error) { + console.log('go'); schema.client.query('USE ' + s.database, callback); } else { throw error; @@ -520,9 +532,17 @@ MySQL.prototype.alterTable = function (model, actualFields, actualIndexes, done, } function changed(newSettings, oldSettings) { - if (oldSettings.Null === 'YES' && (newSettings.allowNull === false || newSettings.null === false)) return true; - if (oldSettings.Null === 'NO' && !(newSettings.allowNull === false || newSettings.null === false)) return true; - if (oldSettings.Type.toUpperCase() !== datatype(newSettings)) return true; + 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 (oldSettings.Null === 'NO') { // Did not allow null and now does. + if(newSettings.allowNull === true) return true; + if(newSettings.null === true) return true; + if(newSettings.null === undefined && newSettings.allowNull === undefined) return true; + } + + if (oldSettings.Type.toUpperCase() !== datatype(newSettings).toUpperCase()) return true; return false; } }; @@ -589,8 +609,9 @@ MySQL.prototype.indexSettingsSQL = function (model, prop) { MySQL.prototype.propertySettingsSQL = function (model, prop) { var p = this._models[model].properties[prop]; - return datatype(p) + ' ' + + var line = datatype(p) + ' ' + (p.allowNull === false || p['null'] === false ? 'NOT NULL' : 'NULL'); + return line; }; function datatype(p) { @@ -599,24 +620,179 @@ function datatype(p) { default: case 'String': case 'JSON': - dt = 'VARCHAR(' + (p.limit || 255) + ')'; + dt = columnType(p, 'VARCHAR'); + dt = stringOptionsByType(p, dt); break; case 'Text': - dt = 'TEXT'; + dt = columnType(p, 'TEXT'); + dt = stringOptionsByType(p, dt); break; case 'Number': - dt = 'INT(' + (p.limit || 11) + ')'; + dt = columnType(p, 'INT'); + dt = numericOptionsByType(p, dt); break; case 'Date': - dt = 'DATETIME'; + dt = columnType(p, 'DATETIME'); // Currently doesn't need options. break; case 'Boolean': - dt = 'TINYINT(1)'; + dt = 'TINYINT(1)'; break; case 'Point': - dt = 'POINT'; + dt = 'POINT'; 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': + case 'char': + dt += '(' + (p.limit || 255) + ')'; + 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; +} diff --git a/test/imported.test.js b/test/imported.test.js index 5ef2910..5a010a9 100644 --- a/test/imported.test.js +++ b/test/imported.test.js @@ -6,5 +6,6 @@ describe('mysql imported features', function() { require('jugglingdb/test/common.batch.js'); require('jugglingdb/test/include.test.js'); + require('./migration.test.js'); }); diff --git a/test/migration.test.js b/test/migration.test.js new file mode 100644 index 0000000..9d18943 --- /dev/null +++ b/test/migration.test.js @@ -0,0 +1,398 @@ +var should = require('./init.js'); +var assert = require('assert'); +var Schema = require('jugglingdb').Schema; + +var db, UserData, StringData, NumberData, DateData; + +describe('migrations', function() { + + before(setup); + + it('should run migration', function(done) { + db.automigrate(function(){ + done(); + }); + }); + + it('UserData should have correct columns', function(done) { + getFields('UserData', function(err, fields) { + assert.deepEqual(fields, { + id: { + Field: 'id', + Type: 'int(11)', + Null: 'NO', + Key: 'PRI', + Default: null, + Extra: 'auto_increment' }, + email: { + Field: 'email', + Type: 'varchar(255)', + Null: 'NO', + Key: 'MUL', + Default: null, + Extra: '' }, + name: { + Field: 'name', + Type: 'varchar(255)', + Null: 'YES', + Key: '', + Default: null, + Extra: '' }, + bio: { + Field: 'bio', + Type: 'text', + Null: 'YES', + Key: '', + Default: null, + Extra: '' }, + birthDate: { + Field: 'birthDate', + Type: 'datetime', + Null: 'YES', + Key: '', + Default: null, + Extra: '' }, + pendingPeriod: { + Field: 'pendingPeriod', + Type: 'int(11)', + Null: 'YES', + Key: '', + Default: null, + Extra: '' }, + createdByAdmin: { + Field: 'createdByAdmin', + Type: 'tinyint(1)', + Null: 'YES', + Key: '', + Default: null, + Extra: '' } + }); + done(); + }); + }); + + it('UserData should have correct indexes', function(done) { + // Note: getIdexes truncates multi-key indexes to the first member. Hence index1 is correct. + getIndexes('UserData', function(err, fields) { + assert.deepEqual(fields, { PRIMARY: + { Table: 'UserData', + Non_unique: 0, + Key_name: 'PRIMARY', + Seq_in_index: 1, + Column_name: 'id', + Collation: 'A', + Cardinality: 0, + Sub_part: null, + Packed: null, + Null: '', + Index_type: 'BTREE', + Comment: '', + Index_comment: '' }, + email: + { Table: 'UserData', + Non_unique: 1, + Key_name: 'email', + Seq_in_index: 1, + Column_name: 'email', + Collation: 'A', + Cardinality: 0, + Sub_part: 191, + Packed: null, + Null: '', + Index_type: 'BTREE', + Comment: '', + Index_comment: '' }, + index0: + { Table: 'UserData', + Non_unique: 1, + Key_name: 'index0', + Seq_in_index: 1, + Column_name: 'email', + Collation: 'A', + Cardinality: 0, + Sub_part: 191, + Packed: null, + Null: '', + Index_type: 'BTREE', + Comment: '', + Index_comment: '' } + }); + done(); + }); + }); + + it('StringData should have correct columns', function(done) { + getFields('StringData', function(err, fields) { + assert.deepEqual(fields, { id: + { Field: 'id', + Type: 'int(11)', + Null: 'NO', + Key: 'PRI', + Default: null, + Extra: 'auto_increment' }, + smallString: + { Field: 'smallString', + Type: 'char(127)', + Null: 'NO', + Key: 'MUL', + Default: null, + Extra: '' }, + mediumString: + { Field: 'mediumString', + Type: 'varchar(255)', + Null: 'NO', + Key: '', + Default: null, + Extra: '' }, + tinyText: + { Field: 'tinyText', + Type: 'tinytext', + Null: 'YES', + Key: '', + Default: null, + Extra: '' }, + giantJSON: + { Field: 'giantJSON', + Type: 'longtext', + Null: 'YES', + Key: '', + Default: null, + Extra: '' }, + text: + { Field: 'text', + Type: 'varchar(1024)', + Null: 'YES', + Key: '', + Default: null, + Extra: '' } + }); + done(); + }); + }); + + it('NumberData should have correct columns', function(done) { + getFields('NumberData', function(err, fields) { + assert.deepEqual(fields, { + id: + { Field: 'id', + Type: 'int(11)', + Null: 'NO', + Key: 'PRI', + Default: null, + Extra: 'auto_increment' }, + number: + { Field: 'number', + Type: 'decimal(10,3) unsigned', + Null: 'NO', + Key: 'MUL', + Default: null, + Extra: '' }, + tinyInt: + { Field: 'tinyInt', + Type: 'tinyint(2)', + Null: 'YES', + Key: '', + Default: null, + Extra: '' }, + mediumInt: + { Field: 'mediumInt', + Type: 'mediumint(8) unsigned', + Null: 'YES', + Key: '', + Default: null, + Extra: '' }, + floater: + { Field: 'floater', + Type: 'double(14,6)', + Null: 'YES', + Key: '', + Default: null, + Extra: '' } + }); + done(); + }); + }); + + it('DateData should have correct columns', function(done) { + getFields('DateData', function(err, fields) { + assert.deepEqual(fields, { + id: + { Field: 'id', + Type: 'int(11)', + Null: 'NO', + Key: 'PRI', + Default: null, + Extra: 'auto_increment' }, + dateTime: + { Field: 'dateTime', + Type: 'datetime', + Null: 'YES', + Key: '', + Default: null, + Extra: '' }, + timestamp: + { Field: 'timestamp', + Type: 'timestamp', + Null: 'YES', + Key: '', + Default: null, + Extra: '' } + }); + done(); + }); + }); + + it('should autoupgrade', function(done) { + var userExists = function(cb) { + query('SELECT * FROM UserData', function(err, res) { + cb(!err && res[0].email == 'test@example.com'); + }); + } + + UserData.create({email: 'test@example.com'}, function(err, user) { + assert.ok(!err, 'Could not create user'); + userExists(function(yep) { + assert.ok(yep, 'User does not exist'); + }); + UserData.defineProperty('email', { type: String }); + UserData.defineProperty('name', {type: String, dataType: 'char', limit: 50}); + UserData.defineProperty('newProperty', {type: Number, unsigned: true, dataType: 'bigInt'}); + // UserData.defineProperty('pendingPeriod', false); This will not work as expected. + db.autoupdate( function(err) { + getFields('UserData', function(err, fields) { + // change nullable for email + assert.equal(fields.email.Null, 'YES', 'Email does not allow null'); + // change type of name + assert.equal(fields.name.Type, 'char(50)', 'Name is not char(50)'); + // add new column + assert.ok(fields.newProperty, 'New column was not added'); + if (fields.newProperty) { + assert.equal(fields.newProperty.Type, 'bigint(20) unsigned', 'New column type is not bigint(20) unsigned'); + } + // drop column - will not happen. + // assert.ok(!fields.pendingPeriod, 'Did not drop column pendingPeriod'); + // user still exists + userExists(function(yep) { + assert.ok(yep, 'User does not exist'); + done(); + }); + }); + }); + }); + }); + + it('should check actuality of schema', function(done) { + // 'drop column' + UserData.schema.isActual(function(err, ok) { + assert.ok(ok, 'schema is not actual (should be)'); + UserData.defineProperty('essay', {type: Schema.Text}); + // UserData.defineProperty('email', false); Can't undefine currently. + UserData.schema.isActual(function(err, ok) { + assert.ok(!ok, 'schema is actual (shouldn\t be)'); + done() + }); + }); + }); + + it('should disconnect when done', function(done) { + db.disconnect(); + done() + }); + +}); + +function setup(done) { + db = getSchema(); + + UserData = db.define('UserData', { + email: { type: String, null: false, index: true }, + name: String, + bio: Schema.Text, + birthDate: Date, + pendingPeriod: Number, + createdByAdmin: Boolean, + } , { indexes: { + index0: { + columns: 'email, createdByAdmin' + } + } + }); + + StringData = db.define('StringData', { + smallString: {type: String, null: false, index: true, dataType: 'char', limit: 127}, + mediumString: {type: String, null: false, dataType: 'varchar', limit: 255}, + tinyText: {type: String, dataType: 'tinyText'}, + giantJSON: {type: Schema.JSON, dataType: 'longText'}, + text: {type: Schema.Text, dataType: 'varchar', limit: 1024} + }); + + NumberData = db.define('NumberData', { + number: {type: Number, null: false, index: true, unsigned: true, dataType: 'decimal', precision: 10, scale: 3}, + tinyInt: {type: Number, dataType: 'tinyInt', display: 2}, + mediumInt: {type: Number, dataType: 'mediumInt', unsigned: true}, + floater: {type: Number, dataType: 'double', precision: 14, scale: 6} + }); + + DateData = db.define('DateData', { + dateTime: {type: Date, dataType: 'datetime'}, + timestamp: {type: Date, dataType: 'timestamp'} + }); + + blankDatabase(db, done); + +} + +var query = function (sql, cb) { + db.adapter.query(sql, cb); +}; + +var blankDatabase = function (db, cb) { + var dbn = db.settings.database; + var cs = db.settings.charset; + var co = db.settings.collation; + query('DROP DATABASE IF EXISTS ' + dbn, function(err) { + var q = 'CREATE DATABASE ' + dbn + ' CHARACTER SET ' + cs + ' COLLATE ' + co; + // console.log(q); + query(q, function(err) { + query('USE '+ dbn, cb); + }); + }); +}; + +getFields = function (model, cb) { + query('SHOW FIELDS FROM ' + model, function(err, res) { + if (err) { + cb(err); + } else { + var fields = {}; + res.forEach(function(field){ + fields[field.Field] = field; + }); + cb(err, fields); + } + }); +} + +getIndexes = function (model, cb) { + query('SHOW INDEXES FROM ' + model, function(err, res) { + if (err) { + console.log(err); + cb(err); + } else { + var indexes = {}; + // Note: this will only show the first key of compound keys + res.forEach(function(index) { + if (parseInt(index.Seq_in_index, 10) == 1) { + indexes[index.Key_name] = index + } + }); + cb(err, indexes); + } + }); +}; + + + + + +