不要怂,就是干,撸起袖子干!

Commit d87330ef by Jan Aagaard Meier

Support for specifying indexes on a model

1 parent 32594fea
......@@ -4,6 +4,9 @@ Notice: All 1.7.x changes are present in 2.0.x aswell
- [FEATURE] Added to option of setting a timezone offset in the sequelize constructor (`timezone` option). This timezone is used when initializing a connection (using `SET TIME ZONE` or equivalent), and when converting a timestamp string from the DB to a JS date with mysql (postgres stores the timezone, so for postgres we rely on what's in the DB).
- [FEATURE] Allow setting plural and singular name on the model (`options.name` in `sequelize.define`) and in associations (`options.as`) to circumvent issues with weird pluralization.
- [BUG] Hid `dottie.transform` on raw queries behind a flag (`nest`) [#2064](https://github.com/sequelize/sequelize/pull/2064)
- [FEATURE] Added support for passing an `indexes` array in options to `sequelize.define`. [#1485](https://github.com/sequelize/sequelize/issues/1485). See API reference for details.
- [FEATURE/INTERNALS] Standardized the output from `QueryInterface.showIndex`.
>>>>>>> Support for specifying indexes on a model
- [BUG] Fixed problems with transcation parameter being removed / not passed on in associations [#1789](https://github.com/sequelize/sequelize/issues/1789) and [#1968](https://github.com/sequelize/sequelize/issues/1968)
- [BUG] Fix problem with minConnections. [#2048](https://github.com/sequelize/sequelize/issues/2048)
- [INTERNALS] Replaced lingo with inflection
......
......@@ -676,6 +676,7 @@ module.exports = (function() {
mainAttributes = [mainTableAs + '.*'];
}
if (options.include) {
var generateJoinQueries = function(include, parentTable) {
var table = include.model.getTableName()
......@@ -946,7 +947,6 @@ module.exports = (function() {
mainQueryItems.push(' HAVING ' + options.having);
}
}
// Add ORDER to sub or main query
if (options.order) {
var mainQueryOrder = [];
......
......@@ -86,16 +86,8 @@ module.exports = (function() {
defaultValue: _result.Default
};
});
} else if (this.sql.toLowerCase().indexOf('show index from') === 0) {
result = Utils._.uniq(result.map(function(result) {
return {
name: result.Key_name,
tableName: result.Table,
unique: (result.Non_unique !== 1)
};
}), false, function(row) {
return row.name;
});
} else if (this.isShowIndexesQuery()) {
result = this.handleShowIndexesQuery(data);
}
} else if (this.isCallQuery()) {
result = data[0];
......
'use strict';
var Utils = require('../../utils')
, AbstractQuery = require('../abstract/query');
, MysqlQuery = require('../mysql/query');
module.exports = (function() {
var Query = function(client, sequelize, callee, options) {
......@@ -22,7 +22,7 @@ module.exports = (function() {
});
};
Utils.inherit(Query, AbstractQuery);
Utils.inherit(Query, MysqlQuery);
Query.prototype.run = function(sql) {
this.sql = sql;
......
......@@ -222,6 +222,8 @@ module.exports = (function() {
},
addIndexQuery: function(tableName, attributes, options) {
options = options || {};
var transformedAttributes = attributes.map(function(attribute) {
if (typeof attribute === 'string') {
return this.quoteIdentifier(attribute);
......@@ -250,11 +252,24 @@ module.exports = (function() {
return (typeof attribute === 'string') ? attribute : attribute.attribute;
}.bind(this));
if (options.unique) {
options.indicesType = 'UNIQUE';
} else {
options.indicesType = options.indicesType || options.type;
}
if (options.name) {
options.indexName = options.name;
}
if (options.method) {
options.indexType = options.method;
}
options = Utils._.extend({
indicesType: null,
indexName: Utils.inflection.underscore(tableName + '_' + onlyAttributeNames.join('_')),
parser: null
}, options || {});
}, options);
return Utils._.compact([
'CREATE', options.indicesType, 'INDEX', options.indexName,
......
......@@ -46,5 +46,39 @@ module.exports = (function() {
return promise;
};
Query.prototype.isShowIndexesQuery = function () {
return this.sql.toLowerCase().indexOf('show index from') === 0;
};
Query.prototype.handleShowIndexesQuery = function (data) {
// Group by index name, and collect all fields
data = Utils._.foldl(data, function (acc, item) {
if (!(item.Key_name in acc)) {
acc[item.Key_name] = item;
item.fields = [];
}
acc[item.Key_name].fields[item.Seq_in_index - 1] = {
attribute: item.Column_name,
length: item.Sub_part || undefined,
order: item.Collation === 'A' ? 'ASC' : null
};
delete item.column_name;
return acc;
}, {});
return Utils._.map(data, function(item) {
return {
primary: item.Key_name === 'PRIMARY',
fields: item.fields,
name: item.Key_name,
tableName: item.Table,
unique: (item.Non_unique !== 1),
type: item.Index_type,
};
});
};
return Query;
})();
......@@ -353,6 +353,7 @@ module.exports = (function() {
},
addIndexQuery: function(tableName, attributes, options) {
options = options || {};
var transformedAttributes = attributes.map(function(attribute) {
if (typeof attribute === 'string') {
return this.quoteIdentifier(attribute);
......@@ -365,8 +366,8 @@ module.exports = (function() {
result += this.quoteIdentifier(attribute.attribute);
if (attribute.length) {
result += '(' + attribute.length + ')';
if (attribute.collate) {
result += ' COLLATE ' + this.quoteIdentifier(attribute.collate);
}
if (attribute.order) {
......@@ -381,22 +382,40 @@ module.exports = (function() {
return (typeof attribute === 'string') ? attribute : attribute.attribute;
}.bind(this));
if (options.name) {
options.indexName = options.name;
}
if (options.method) {
options.indexType = options.method;
}
var indexTable = tableName.split('.');
options = Utils._.extend({
indicesType: null,
indicesType: '',
type: '',
indexName: Utils.inflection.underscore(indexTable[indexTable.length - 1] + '_' + onlyAttributeNames.join('_')),
parser: null
}, options || {});
}, options);
if (options.unique || options.indicesType.toLowerCase() === 'unique' || options.type.toLowerCase() === 'unique') {
options.indicesType = 'UNIQUE';
} else {
delete options.indicesType;
}
return Utils._.compact([
'CREATE', options.indicesType, 'INDEX', this.quoteIdentifiers(options.indexName),
'CREATE', options.indicesType, 'INDEX',
options.concurrently ? 'CONCURRENTLY' : undefined,
this.quoteIdentifiers(options.indexName),
'ON', this.quoteIdentifiers(tableName), (options.indexType ? ('USING ' + options.indexType) : undefined),
'(' + transformedAttributes.join(', ') + ')'
]).join(' ');
},
showIndexQuery: function(tableName, options) {
var query = "SELECT relname FROM pg_class WHERE oid IN ( SELECT indexrelid FROM pg_index, pg_class WHERE pg_class.relname='<%= tableName %>' AND pg_class.oid=pg_index.indrelid);";
// This is ARCANE!
var query = "SELECT i.relname AS name, ix.indisprimary AS primary, ix.indisunique AS unique, ix.indkey AS indkey, array_agg(a.attnum) as column_indexes, array_agg(a.attname) AS column_names, pg_get_indexdef(ix.indexrelid) AS definition FROM pg_class t, pg_class i, pg_index ix, pg_attribute a WHERE t.oid = ix.indrelid AND i.oid = ix.indexrelid AND a.attrelid = t.oid AND a.attnum = ANY(ix.indkey) AND t.relkind = 'r' and t.relname = '<%= tableName %>' GROUP BY i.relname, ix.indexrelid, ix.indisprimary, ix.indisunique, ix.indkey ORDER BY i.relname;";
return Utils._.template(query)({ tableName: tableName });
},
......
......@@ -91,7 +91,36 @@ module.exports = (function() {
return results;
}
if (self.isSelectQuery()) {
if (self.isShowIndexesQuery()) {
results.forEach(function (result) {
var attributes = /ON .*? (?:USING .*?\s)?\((.*)\)/gi.exec(result.definition)[1].split(',')
, field
, attribute
, columns;
// Map column index in table to column name
columns = Utils._.zipObject(
result.column_indexes,
self.sequelize.queryInterface.QueryGenerator.fromArray(result.column_names)
);
delete result.column_indexes;
delete result.column_names;
// Indkey is the order of attributes in the index, specified by a string of attribute indexes
result.fields = result.indkey.split(' ').map(function (indKey, index) {
field = columns[indKey];
attribute = attributes[index];
return {
attribute: field,
collation: attribute.match(/COLLATE "(.*?)"/) ? /COLLATE "(.*?)"/.exec(attribute)[1] : undefined,
order: attribute.indexOf('DESC') !== -1 ? 'DESC' : attribute.indexOf('ASC') !== -1 ? 'ASC': undefined,
length: undefined,
};
});
delete result.columns;
});
return results;
} else if (self.isSelectQuery()) {
if (self.sql.toLowerCase().indexOf('select c.column_name') === 0) {
result = {};
......@@ -192,6 +221,10 @@ module.exports = (function() {
return this;
};
Query.prototype.isShowIndexesQuery = function () {
return this.sql.indexOf('pg_get_indexdef') || this.sql.indexOf('pg_index');
};
Query.prototype.getInsertIdField = function() {
return 'id';
};
......
......@@ -3,7 +3,8 @@
var Utils = require('../../utils')
, DataTypes = require('../../data-types')
, SqlString = require('../../sql-string')
, Transaction = require('../../transaction');
, Transaction = require('../../transaction')
, util = require('util');
var MySqlQueryGenerator = Utils._.extend(
Utils._.clone(require('../abstract/query-generator')),
......@@ -305,6 +306,60 @@ module.exports = (function() {
return fields;
},
addIndexQuery: function(tableName, attributes, options) {
options = options || {};
var transformedAttributes = attributes.map(function(attribute) {
if (typeof attribute === 'string') {
return this.quoteIdentifier(attribute);
} else {
var result = '';
if (!attribute.attribute) {
throw new Error('The following index attribute has no attribute: ' + util.inspect(attribute));
}
result += this.quoteIdentifier(attribute.attribute);
if (attribute.collate) {
result += 'COLLATE ' + attribute.collate;
}
if (attribute.order) {
result += ' ' + attribute.order;
}
return result;
}
}.bind(this));
var onlyAttributeNames = attributes.map(function(attribute) {
return (typeof attribute === 'string') ? attribute : attribute.attribute;
}.bind(this));
if (options.name) {
options.indexName = options.name;
}
options = Utils._.extend({
indicesType: '',
type: '',
indexName: Utils.inflection.underscore(tableName + '_' + onlyAttributeNames.join('_')),
parser: null
}, options);
if (options.unique || options.indicesType.toLowerCase() === 'unique' || options.type.toLowerCase() === 'unique') {
options.indicesType = 'UNIQUE';
} else {
delete options.indicesType;
}
return Utils._.compact([
'CREATE', options.indicesType, 'INDEX', options.indexName,
'ON', this.quoteIdentifiers(tableName), '(' + transformedAttributes.join(', ') + ')'
]).join(' ');
},
showIndexQuery: function(tableName) {
var sql = "PRAGMA INDEX_LIST(<%= tableName %>)";
return Utils._.template(sql, { tableName: this.quoteIdentifiers(tableName) });
......
......@@ -97,14 +97,9 @@ module.exports = (function() {
} else if (self.isShowOrDescribeQuery()) {
result = results;
} else if (self.sql.indexOf('PRAGMA INDEX_LIST') !== -1) {
// this is the sqlite way of getting the indexes of a table
result = results.map(function(result) {
return {
name: result.name,
tableName: result.name.split('_')[0],
unique: (result.unique === 0)
};
});
result = self.handleShowIndexesQuery(results);
} else if (self.sql.indexOf('PRAGMA INDEX_INFO') !== -1) {
result = results;
} else if (self.sql.indexOf('PRAGMA TABLE_INFO') !== -1) {
// this is the sqlite way of getting the metadata of a table
result = {};
......@@ -159,7 +154,7 @@ module.exports = (function() {
if (tableName !== 'sqlite_master') {
return new Utils.Promise(function(resolve) {
// get the column types
self.database.all('PRAGMA table_info(' + tableName + ')', function(err, results) {
self.database.all('PRAGMA table_info(`' + tableName + '`)', function(err, results) {
if (!err) {
for (var i = 0, l = results.length; i < l; i++) {
columnTypes[tableName + '.' + results[i].name] = columnTypes[results[i].name] = results[i].type;
......@@ -178,6 +173,29 @@ module.exports = (function() {
});
};
Query.prototype.handleShowIndexesQuery = function (data) {
var self = this;
// Sqlite returns indexes so the last one that was defined last is returned first. Lets reverse that!
return this.sequelize.Promise.map(data.reverse(), function (item) {
item.fields = [];
item.primary = false;
item.unique = !!item.unique;
return self.run('PRAGMA INDEX_INFO(' + item.name + ')').then(function (columns) {
columns.forEach(function (column) {
item.fields[column.seqno] = {
attribute: column.name,
length: undefined,
order: undefined,
};
});
return item;
});
});
};
Query.prototype.getDatabaseMethod = function() {
if (this.isInsertQuery() || this.isUpdateQuery() || (this.sql.toLowerCase().indexOf('CREATE TEMPORARY TABLE'.toLowerCase()) !== -1) || this.options.type === QueryTypes.BULKDELETE) {
return 'run';
......
......@@ -383,12 +383,16 @@ module.exports = (function() {
var self = this
, attributes = this.tableAttributes;
return Promise.resolve().then(function () {
return Promise.resolve().bind(this).then(function () {
if (options.force) {
return self.drop(options);
return this.drop(options);
}
}).then(function () {
return self.QueryInterface.createTable(self.getTableName(options), attributes, options);
return this.QueryInterface.createTable(this.getTableName(options), attributes, options);
}).then(function () {
return Promise.map(this.options.indexes, function (index) {
return self.QueryInterface.addIndex(self.getTableName(options), index.fields, index);
});
}).return(this);
};
......
......@@ -351,6 +351,13 @@ module.exports = (function() {
* @param {Object} [options.name] An object with two attributes, `singular` and `plural`, which are used when this model is associated to others.
* @param {String} [options.name.singular=inflection.singularize(modelName)]
* @param {String} [options.name.plural=inflection.pluralize(modelName)]
* @param {Array<Object>} [options.indexes]
* @param {String} [options.indexes[].name] The name of the index. Defaults to model name + _ + fields concatenated
* @param {String} [options.indexes[].type] Index type. Only used by mysql. One of `UNIQUE`, `FULLTEXT` and `SPATIAL`
* @param {String} [options.indexes[].method] The method to create the index by (`USING` statement in SQL). BTREE and HASH are supported by mysql and postgres, and postgres additionally supports GIST and GIN.
* @param {Boolean} [options.indexes[].unique=false] Should the index by unique? Can also be triggered by setting type to `UNIQUE`
* @param {Boolean} [options.indexes[].concurrently=false] PostgreSQL will build the index without taking any write locks. Postgres only
* @param {Array<String|Object} [options.indexes[].fields] An array of the fields to index. Each field can either be a string containing the name of the field, or an object with the following attributes: `attribute` (field name), `length` (create a prefix index of length chars), `order` (the direction the column should be sorted in), `collate` (the collation (sort order) for the column)
* @param {String|Boolean} [options.createdAt] Override the name of the createdAt column if a string is provided, or disable it if false. Timestamps must be true
* @param {String|Boolean} [options.updatedAt] Override the name of the updatedAt column if a string is provided, or disable it if false. Timestamps must be true
* @param {String|Boolean} [options.deletedAt] Override the name of the deletedAt column if a string is provided, or disable it if false. Timestamps must be true
......@@ -388,7 +395,8 @@ module.exports = (function() {
name: {
plural: Utils.inflection.pluralize(modelName),
singular: Utils.inflection.singularize(modelName)
}
},
indexes: [],
}, options);
options.omitNull = globalOptions.omitNull;
......
......@@ -328,6 +328,89 @@ describe(Support.getTestDialectTeaser("DAOFactory"), function () {
})
})
})
it('should allow the user to specify indexes in options', function () {
var Model = this.sequelize.define('model', {
fieldA: Sequelize.STRING,
fieldB: Sequelize.INTEGER,
fieldC: Sequelize.STRING
}, {
indexes: [
{
name: 'a_b_uniq',
unique: true,
method: 'BTREE',
fields: ['fieldB', {attribute:'fieldA', collate: 'en_US', order: 'DESC', length: 5}]
},
{
type: 'FULLTEXT',
fields: ['fieldC'],
concurrently: true
},
],
engine: 'MyISAM'
})
return this.sequelize.sync().bind(this).then(function () {
return this.sequelize.queryInterface.showIndex(Model.tableName);
}).spread(function () {
var primary, idx1, idx2;
if (dialect === 'sqlite') {
// PRAGMA index_info does not return the primary index
idx1 = arguments[0];
idx2 = arguments[1];
expect(idx1.fields).to.deep.equal([
{ attribute: 'fieldB', length: undefined, order: undefined},
{ attribute: 'fieldA', length: undefined, order: undefined},
]);
expect(idx2.fields).to.deep.equal([
{ attribute: 'fieldC', length: undefined, order: undefined}
]);
} else if (dialect === 'postgres') {
// Postgres returns indexes in alphabetical order
primary = arguments[2];
idx1 = arguments[0];
idx2 = arguments[1];
expect(idx1.fields).to.deep.equal([
{ attribute: 'fieldB', length: undefined, order: undefined},
{ attribute: 'fieldA', length: undefined, order: 'DESC', collate: 'en_US'},
]);
expect(idx2.fields).to.deep.equal([
{ attribute: 'fieldC', length: undefined, order: null}
]);
} else {
// And finally mysql returns the primary first, and then the rest in the order they were defined
primary = arguments[0];
idx1 = arguments[1];
idx2 = arguments[2];
expect(primary.primary).to.be.ok;
expect(idx1.type).to.equal('BTREE');
expect(idx2.type).to.equal('FULLTEXT');
expect(idx1.fields).to.deep.equal([
{ attribute: 'fieldB', length: undefined, order: 'ASC'},
{ attribute: 'fieldA', length: 5, order: 'ASC'},
]);
expect(idx2.fields).to.deep.equal([
{ attribute: 'fieldC', length: undefined, order: null}
]);
}
expect(idx1.name).to.equal('a_b_uniq');
expect(idx1.unique).to.be.ok;
expect(idx2.name).to.equal('models_field_c');
expect(idx2.unique).not.to.be.ok;
});
});
})
describe('build', function() {
......
Markdown is supported
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!