Follow mysql recommendations for handling booleans

Per http://dev.mysql.com/doc/refman/5.7/en/numeric-type-overview.html
`BOOL` and `BOOLEAN` is alias for `TINYINT(1)` thus we should make
sure discover can handle as such.

Introducing three flags:

* treatCHAR1AsString
  default false - treats CHAR(1) as a String instead of a Boolean
* treatBIT1AsBit
  default true - treats BIT(1) as a Boolean instead of a Binary
* treatTINYINT1AsTinyInt
  default true - treats TINYINT(1) as a Boolean instead of a Number

The default handling for CHAR(1) is legacy backward compability due to
custom to use a CHAR(1) to store 'Y', 'N', '0', '1', etc...
This commit is contained in:
Carl Fürstenberg 2016-10-05 16:07:03 +02:00 committed by Simon Ho
parent 160e8dae72
commit 5383c4c0ff
3 changed files with 171 additions and 7 deletions

View File

@ -203,6 +203,7 @@ function mixinDiscovery(MySQL, mysql) {
' character_maximum_length AS "dataLength",' +
' numeric_precision AS "dataPrecision",' +
' numeric_scale AS "dataScale",' +
' column_type AS "columnType",' +
' is_nullable = \'YES\' AS "nullable"' +
' FROM information_schema.columns' +
' WHERE table_schema=' + mysql.escape(schema) +
@ -216,6 +217,7 @@ function mixinDiscovery(MySQL, mysql) {
' character_maximum_length AS "dataLength",' +
' numeric_precision AS "dataPrecision",' +
' numeric_scale AS "dataScale",' +
' column_type AS "columnType",' +
' is_nullable = \'YES\' AS "nullable"' +
' FROM information_schema.columns' +
(table ? ' WHERE table_name=' + mysql.escape(table) : ''),
@ -240,6 +242,22 @@ function mixinDiscovery(MySQL, mysql) {
}
table = args.table;
options = args.options;
// Recommended MySQL 5.7 Boolean scheme. See
// http://dev.mysql.com/doc/refman/5.7/en/numeric-type-overview.html
// Currently default is the inverse of the recommendation for backward compatibility.
var defaultOptions = {
treatCHAR1AsString: false,
treatBIT1AsBit: true,
treatTINYINT1AsTinyInt: true,
};
for (var opt in defaultOptions) {
if (defaultOptions.hasOwnProperty(opt) && !options.hasOwnProperty(opt)) {
options[opt] = defaultOptions[opt];
}
}
cb = args.cb;
var sql = queryColumns(schema, table);
@ -248,7 +266,7 @@ function mixinDiscovery(MySQL, mysql) {
cb(err, results);
} else {
results.map(function(r) {
r.type = self.buildPropertyType(r);
r.type = self.buildPropertyType(r, options);
r.nullable = r.nullable ? 'Y' : 'N';
});
cb(err, results);
@ -404,20 +422,18 @@ function mixinDiscovery(MySQL, mysql) {
this.execute(sql, cb);
};
MySQL.prototype.buildPropertyType = function(columnDefinition) {
MySQL.prototype.buildPropertyType = function(columnDefinition, options) {
var mysqlType = columnDefinition.dataType;
var columnType = columnDefinition.columnType;
var dataLength = columnDefinition.dataLength;
var type = mysqlType.toUpperCase();
switch (type) {
case 'CHAR':
if (dataLength === 1) {
// Treat char(1) as boolean
if (!options.treatCHAR1AsString && columnType === 'char(1)') {
// Treat char(1) as boolean ('Y', 'N', 'T', 'F', '0', '1')
return 'Boolean';
} else {
return 'String';
}
break;
case 'VARCHAR':
case 'TINYTEXT':
case 'MEDIUMTEXT':
@ -433,8 +449,16 @@ function mixinDiscovery(MySQL, mysql) {
case 'BINARY':
case 'VARBINARY':
case 'BIT':
// treat BIT(1) as boolean as it's 1 or 0
if (!options.treatBIT1AsBit && columnType === 'bit(1)') {
return 'Boolean';
}
return 'Binary';
case 'TINYINT':
// treat TINYINT(1) as boolean as it is aliased as BOOL and BOOLEAN in mysql
if (!options.treatTINYINT1AsTinyInt && columnType === 'tinyint(1)') {
return 'Boolean';
}
case 'SMALLINT':
case 'INT':
case 'MEDIUMINT':
@ -449,6 +473,9 @@ function mixinDiscovery(MySQL, mysql) {
return 'Date';
case 'POINT':
return 'GeoPoint';
case 'BOOL':
case 'BOOLEAN':
return 'Boolean';
default:
return 'String';
}

View File

@ -271,4 +271,138 @@ describe('Discover and build models', function() {
done();
});
});
describe('discoverModelProperties() flags', function() {
context('with default flags', function() {
var models, schema;
before(discoverAndBuildModels);
it('handles CHAR(1) as Boolean', function() {
assert(schema.properties.enabled);
assert.strictEqual(schema.properties.enabled.type, Boolean);
});
it('handles BIT(1) as Bit', function() {
assert(schema.properties.disabled);
assert.strictEqual(schema.properties.disabled.type, Buffer);
});
it('handles TINYINT(1) as Number', function() {
assert(schema.properties.active);
assert.strictEqual(schema.properties.active.type, Number);
});
function discoverAndBuildModels(done) {
db.discoverAndBuildModels('INVENTORY', {
owner: 'STRONGLOOP',
visited: {},
associations: true,
}, function(err, models_) {
models = models_;
schema = models.Inventory.definition;
done(err);
});
}
});
context('with flag treatCHAR1AsString = true', function() {
var models, schema;
before(discoverAndBuildModels);
it('handles CHAR(1) as String', function() {
assert(schema.properties.enabled);
assert.strictEqual(schema.properties.enabled.type, String);
});
it('handles BIT(1) as Binary', function() {
assert(schema.properties.disabled);
assert.strictEqual(schema.properties.disabled.type, Buffer);
});
it('handles TINYINT(1) as Number', function() {
assert(schema.properties.active);
assert.strictEqual(schema.properties.active.type, Number);
});
function discoverAndBuildModels(done) {
db.discoverAndBuildModels('INVENTORY', {
owner: 'STRONGLOOP',
visited: {},
associations: true,
treatCHAR1AsString: true,
}, function(err, models_) {
models = models_;
schema = models.Inventory.definition;
done(err);
});
}
});
context('with flag treatBIT1AsBit = false', function() {
var models, schema;
before(discoverAndBuildModels);
it('handles CHAR(1) as Boolean', function() {
assert(schema.properties.enabled);
assert.strictEqual(schema.properties.enabled.type, Boolean);
});
it('handles BIT(1) as Boolean', function() {
assert(schema.properties.disabled);
assert.strictEqual(schema.properties.disabled.type, Boolean);
});
it('handles TINYINT(1) as Number', function() {
assert(schema.properties.active);
assert.strictEqual(schema.properties.active.type, Number);
});
function discoverAndBuildModels(done) {
db.discoverAndBuildModels('INVENTORY', {
owner: 'STRONGLOOP',
visited: {},
associations: true,
treatBIT1AsBit: false,
}, function(err, models_) {
models = models_;
schema = models.Inventory.definition;
done(err);
});
}
});
context('with flag treatTINYINT1AsTinyInt = false', function() {
var models, schema;
before(discoverAndBuildModels);
it('handles CHAR(1) as Boolean', function() {
assert(schema.properties.enabled);
assert.strictEqual(schema.properties.enabled.type, Boolean);
});
it('handles BIT(1) as Binary', function() {
assert(schema.properties.disabled);
assert.strictEqual(schema.properties.disabled.type, Buffer);
});
it('handles TINYINT(1) as Boolean', function() {
assert(schema.properties.active);
assert.strictEqual(schema.properties.active.type, Boolean);
});
function discoverAndBuildModels(done) {
db.discoverAndBuildModels('INVENTORY', {
owner: 'STRONGLOOP',
visited: {},
associations: true,
treatTINYINT1AsTinyInt: false,
}, function(err, models_) {
if (err) return done(err);
models = models_;
schema = models.Inventory.definition;
done();
});
}
});
});
});

View File

@ -61,6 +61,9 @@ CREATE TABLE `INVENTORY` (
`LOCATION_ID` varchar(20) NOT NULL,
`AVAILABLE` int(11) DEFAULT NULL,
`TOTAL` int(11) DEFAULT NULL,
`ACTIVE` BOOLEAN DEFAULT TRUE,
`DISABLED` BIT(1) DEFAULT 0,
`ENABLED` CHAR(1) DEFAULT 'Y',
PRIMARY KEY (`PRODUCT_ID`,`LOCATION_ID`),
KEY `LOCATION_FK` (`LOCATION_ID`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;