mirror of
https://github.com/knex/knex.git
synced 2025-12-30 00:30:14 +00:00
Fixes #319. Inserting multiple rows with default values
This commit is contained in:
parent
9ecd443417
commit
72cf342273
@ -65,11 +65,18 @@ QueryCompiler_Oracle.prototype.insert = function() {
|
||||
returning = [returning];
|
||||
}
|
||||
|
||||
if (_.isArray(self.single.insert) && (self.single.insert.length === 1) && _.isEmpty(self.single.insert[0])) {
|
||||
self.single.insert = [];
|
||||
}
|
||||
|
||||
if (_.isEmpty(self.single.insert) && !_.isFunction(this.single.insert)) {
|
||||
return self._addReturningToSqlAndConvert('insert into ' + self.tableName + ' (' + self.formatter.wrap(self.single.returning) + ') values (default)', returning, self.tableName);
|
||||
}
|
||||
|
||||
var insertData = self._prepInsert(self.single.insert);
|
||||
|
||||
var sql = {};
|
||||
|
||||
if (_.isString(insertData)) {
|
||||
return self._addReturningToSqlAndConvert('insert into ' + self.tableName + ' ' + insertData, returning);
|
||||
}
|
||||
@ -78,23 +85,36 @@ QueryCompiler_Oracle.prototype.insert = function() {
|
||||
return self._addReturningToSqlAndConvert('insert into ' + self.tableName + ' (' + self.formatter.columnize(insertData.columns) + ') values (' + self.formatter.parameterize(insertData.values[0]) + ')', returning, self.tableName);
|
||||
}
|
||||
|
||||
var sql = {};
|
||||
var insertDefaultsOnly = (insertData.columns.length === 0);
|
||||
|
||||
sql.sql = 'begin ' +
|
||||
_.map(insertData.values, function (value) {
|
||||
var returningHelper;
|
||||
var parameterizedValues = self.formatter.parameterize(value);
|
||||
var parameterizedValues = !insertDefaultsOnly ? self.formatter.parameterize(value) : '';
|
||||
var returningValues = _.isArray(returning) ? returning : [returning];
|
||||
var subSql = 'insert into ' + self.tableName + ' ';
|
||||
|
||||
if (returning) {
|
||||
returningHelper = new ReturningHelper(returningValues.join(':'));
|
||||
sql.outParams = (sql.outParams || []).concat(returningHelper);
|
||||
}
|
||||
|
||||
var subSql = 'insert into ' + self.tableName + ' (' + self.formatter.columnize(insertData.columns) + ') values (' + parameterizedValues + ')' + (returning ? ' returning ROWID into ' + self.formatter.parameter(returningHelper) : '');
|
||||
if (insertDefaultsOnly) {
|
||||
// no columns given so only the default value
|
||||
subSql += '(' + self.formatter.wrap(self.single.returning) + ') values (default)';
|
||||
} else {
|
||||
subSql += '(' + self.formatter.columnize(insertData.columns) + ') values (' + parameterizedValues + ')';
|
||||
}
|
||||
subSql += (returning ? ' returning ROWID into ' + self.formatter.parameter(returningHelper) : '');
|
||||
|
||||
// pre bind position because subSql is an execute immediate parameter
|
||||
// later position binding will only convert the ? params
|
||||
subSql = self.formatter.client.positionBindings(subSql);
|
||||
return 'execute immediate \'' + subSql.replace(/'/g, "''") + '\' using ' + parameterizedValues + (returning ? ', out ?' : '') + ';';
|
||||
return 'execute immediate \'' + subSql.replace(/'/g, "''") +
|
||||
((parameterizedValues || returning) ? '\' using ' : '') +
|
||||
parameterizedValues +
|
||||
((parameterizedValues && returning) ? ', ' : '') +
|
||||
(returning ? 'out ?' : '') + ';';
|
||||
}
|
||||
).join(' ') +
|
||||
'end;';
|
||||
|
||||
@ -39,10 +39,39 @@ QueryCompiler_PG.prototype.truncate = function() {
|
||||
// Used when the insert call is empty.
|
||||
QueryCompiler_PG.prototype._emptyInsertValue = 'default values';
|
||||
|
||||
// is used if the an array with multiple empty values supplied
|
||||
QueryCompiler_PG.prototype._defaultInsertValue = 'default';
|
||||
|
||||
// Compiles an `insert` query, allowing for multiple
|
||||
// inserts using a single query statement.
|
||||
QueryCompiler_PG.prototype.insert = function() {
|
||||
var sql = QueryCompiler.prototype.insert.call(this);
|
||||
var self = this;
|
||||
var insertValues = this.single.insert;
|
||||
|
||||
var sql = 'insert into ' + this.tableName + ' ';
|
||||
|
||||
if (_.isArray(insertValues) && (insertValues.length === 1) && _.isEmpty(insertValues[0])) {
|
||||
insertValues = [];
|
||||
}
|
||||
|
||||
if (_.isEmpty(insertValues) && !_.isFunction(insertValues)) {
|
||||
sql += this._emptyInsertValue;
|
||||
} else {
|
||||
var insertData = this._prepInsert(insertValues);
|
||||
|
||||
if (_.isString(insertData)) {
|
||||
sql += insertData;
|
||||
} else {
|
||||
if (insertData.columns.length) {
|
||||
sql += '(' + this.formatter.columnize(insertData.columns) + ') values (' +
|
||||
_.map(insertData.values, this.formatter.parameterize, this.formatter).join('), (') + ')';
|
||||
} else {
|
||||
// if there is no target column only insert default values
|
||||
sql += '(' + self.formatter.wrap(self.single.returning) + ') values ' + _.map(insertData.values, function () { return '(' + (self._defaultInsertValue || '') + ')'; }).join(', ');
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
var returning = this.single.returning;
|
||||
return {
|
||||
sql: sql + this._returning(returning),
|
||||
|
||||
@ -38,7 +38,12 @@ QueryCompiler_SQLite3.prototype.forUpdate = function() {
|
||||
QueryCompiler_SQLite3.prototype.insert = function() {
|
||||
var insert = this.single.insert;
|
||||
var sql = 'insert into ' + this.tableName + ' ';
|
||||
if (_.isEmpty(this.single.insert) && !_.isFunction(this.single.insert)) {
|
||||
|
||||
if (_.isArray(insert) && (insert.length === 1) && _.isEmpty(insert[0])) {
|
||||
insert = [];
|
||||
}
|
||||
|
||||
if (_.isEmpty(insert) && !_.isFunction(insert)) {
|
||||
return sql + 'default values';
|
||||
}
|
||||
var insertData = this._prepInsert(insert);
|
||||
|
||||
@ -64,16 +64,30 @@ QueryCompiler.prototype.pluck = function() {
|
||||
// Compiles an "insert" query, allowing for multiple
|
||||
// inserts using a single query statement.
|
||||
QueryCompiler.prototype.insert = function() {
|
||||
var self = this;
|
||||
var insertValues = this.single.insert;
|
||||
|
||||
var sql = 'insert into ' + this.tableName + ' ';
|
||||
if (_.isEmpty(this.single.insert) && !_.isFunction(this.single.insert)) {
|
||||
|
||||
if (_.isArray(insertValues) && (insertValues.length === 1) && _.isEmpty(insertValues[0])) {
|
||||
insertValues = [];
|
||||
}
|
||||
|
||||
if (_.isEmpty(insertValues) && !_.isFunction(insertValues)) {
|
||||
sql += this._emptyInsertValue;
|
||||
} else {
|
||||
var insertData = this._prepInsert(this.single.insert);
|
||||
var insertData = this._prepInsert(insertValues);
|
||||
|
||||
if (_.isString(insertData)) {
|
||||
sql += insertData;
|
||||
} else {
|
||||
sql += '(' + this.formatter.columnize(insertData.columns) + ') values (' +
|
||||
_.map(insertData.values, this.formatter.parameterize, this.formatter).join('), (') + ')';
|
||||
if (insertData.columns.length) {
|
||||
sql += '(' + this.formatter.columnize(insertData.columns) + ') values (' +
|
||||
_.map(insertData.values, this.formatter.parameterize, this.formatter).join('), (') + ')';
|
||||
} else {
|
||||
// if there is no target column only insert default values
|
||||
sql += '() values ' + _.map(insertData.values, function () { return '(' + (self._defaultInsertValue || '') + ')'; }).join(', ');
|
||||
}
|
||||
}
|
||||
}
|
||||
return sql;
|
||||
|
||||
@ -393,6 +393,87 @@ module.exports = function(knex) {
|
||||
});
|
||||
});
|
||||
|
||||
|
||||
it('should handle empty arrays inserts', function() {
|
||||
|
||||
return knex.schema
|
||||
.createTable('test_default_table2', function(qb) {
|
||||
qb.increments().primary();
|
||||
qb.string('string').defaultTo('hello');
|
||||
qb.tinyint('tinyint').defaultTo(0);
|
||||
qb.text('text').nullable();
|
||||
}).then(function() {
|
||||
return knex('test_default_table2').insert([{}], 'id').testSql(function(tester) {
|
||||
tester(
|
||||
'mysql',
|
||||
'insert into `test_default_table2` () values ()',
|
||||
[],
|
||||
[1]
|
||||
);
|
||||
tester(
|
||||
'postgresql',
|
||||
'insert into "test_default_table2" default values returning "id"',
|
||||
[],
|
||||
[1]
|
||||
);
|
||||
tester(
|
||||
'sqlite3',
|
||||
'insert into "test_default_table2" default values',
|
||||
[],
|
||||
[1]
|
||||
);
|
||||
tester(
|
||||
'oracle',
|
||||
"insert into \"test_default_table2\" (\"id\") values (default) returning ROWID into ?",
|
||||
[function (v) {return v.toString() === '[object ReturningHelper:id]';}],
|
||||
[1]
|
||||
);
|
||||
|
||||
});
|
||||
});
|
||||
});
|
||||
|
||||
it('should handle multiple default inserts with returning only', function() {
|
||||
if (knex.client.dialect === 'sqlite3') {
|
||||
console.log('not tested for sqlite3');
|
||||
return;
|
||||
}
|
||||
|
||||
return knex.schema
|
||||
.createTable('test_default_table3', function(qb) {
|
||||
qb.increments().primary();
|
||||
qb.string('string').defaultTo('hello');
|
||||
qb.tinyint('tinyint').defaultTo(0);
|
||||
qb.text('text').nullable();
|
||||
}).then(function() {
|
||||
return knex('test_default_table3').insert([{}, {}], 'id').testSql(function(tester) {
|
||||
tester(
|
||||
'mysql',
|
||||
'insert into `test_default_table3` () values (), ()',
|
||||
[],
|
||||
[1]
|
||||
);
|
||||
tester(
|
||||
'postgresql',
|
||||
'insert into "test_default_table3" ("id") values (default), (default) returning "id"',
|
||||
[],
|
||||
[1, 2]
|
||||
);
|
||||
tester(
|
||||
'oracle',
|
||||
"begin execute immediate 'insert into \"test_default_table3\" (\"id\") values (default) returning ROWID into :1' using out ?; execute immediate 'insert into \"test_default_table3\" (\"id\") values (default) returning ROWID into :1' using out ?;end;",
|
||||
[function (v) {return v.toString() === '[object ReturningHelper:id]';}, function (v) {return v.toString() === '[object ReturningHelper:id]';}],
|
||||
[1, 2]
|
||||
);
|
||||
|
||||
});
|
||||
}).then(function () {
|
||||
return knex('test_default_table3').then(function (rows) {
|
||||
expect(rows.length).to.equal(2);
|
||||
});
|
||||
});
|
||||
});
|
||||
|
||||
it('should take an array of columns to return in oracle or postgres', function() {
|
||||
var insertData = {
|
||||
account_id: 10,
|
||||
|
||||
@ -32,6 +32,8 @@ module.exports = function(knex) {
|
||||
.dropTableIfExists('migration_test_2')
|
||||
.dropTableIfExists('migration_test_2_1')
|
||||
.dropTableIfExists('test_default_table')
|
||||
.dropTableIfExists('test_default_table2')
|
||||
.dropTableIfExists('test_default_table3')
|
||||
.dropTableIfExists('knex_migrations')
|
||||
.dropTableIfExists('bool_test')
|
||||
]);
|
||||
|
||||
@ -1181,6 +1181,213 @@ module.exports = function(qb, clientName, aliasName) {
|
||||
});
|
||||
});
|
||||
|
||||
it("insert with only default values", function() {
|
||||
testsql(qb().into('users').insert(), {
|
||||
mysql: {
|
||||
sql: 'insert into `users` () values ()',
|
||||
bindings: []
|
||||
},
|
||||
oracle: {
|
||||
sql: 'insert into "users" ("undefined") values (default)',
|
||||
bindings: []
|
||||
},
|
||||
default: {
|
||||
sql: 'insert into "users" default values',
|
||||
bindings: []
|
||||
}
|
||||
});
|
||||
});
|
||||
|
||||
it("insert with empty array should insert default values", function() {
|
||||
testsql(qb().into('users').insert([]), {
|
||||
mysql: {
|
||||
sql: 'insert into `users` () values ()',
|
||||
bindings: []
|
||||
},
|
||||
oracle: {
|
||||
// Oracle dialect needs at least on return column to work correctly
|
||||
sql: 'insert into "users" ("undefined") values (default)',
|
||||
bindings: []
|
||||
},
|
||||
default: {
|
||||
sql: 'insert into "users" default values',
|
||||
bindings: []
|
||||
}
|
||||
});
|
||||
});
|
||||
|
||||
it("insert with empty array should insert default values and returning", function() {
|
||||
testsql(qb().into('users').insert([], 'id'), {
|
||||
mysql: {
|
||||
sql: 'insert into `users` () values ()',
|
||||
bindings: []
|
||||
},
|
||||
postgres: {
|
||||
sql: 'insert into "users" default values returning "id"',
|
||||
bindings: []
|
||||
},
|
||||
oracle: {
|
||||
sql: 'insert into "users" ("id") values (default) returning ROWID into ?',
|
||||
bindings: function (bindings) {
|
||||
expect(bindings.length).to.equal(1);
|
||||
expect(bindings[0].toString()).to.equal('[object ReturningHelper:id]');
|
||||
}
|
||||
},
|
||||
default: {
|
||||
sql: 'insert into "users" default values',
|
||||
bindings: []
|
||||
}
|
||||
});
|
||||
});
|
||||
|
||||
it("insert with array with empty object and returning", function() {
|
||||
testsql(qb().into('users').insert([{}], 'id'), {
|
||||
mysql: {
|
||||
sql: 'insert into `users` () values ()',
|
||||
bindings: []
|
||||
},
|
||||
sqlite3: {
|
||||
sql: 'insert into "users" default values',
|
||||
bindings: []
|
||||
},
|
||||
postgres: {
|
||||
sql: 'insert into "users" default values returning "id"',
|
||||
bindings: []
|
||||
},
|
||||
oracle: {
|
||||
sql: "insert into \"users\" (\"id\") values (default) returning ROWID into ?",
|
||||
bindings: function (bindings) {
|
||||
expect(bindings.length).to.equal(1);
|
||||
expect(bindings[0].toString()).to.equal('[object ReturningHelper:id]');
|
||||
}
|
||||
},
|
||||
default: {
|
||||
sql: 'insert into "users" default values',
|
||||
bindings: []
|
||||
}
|
||||
});
|
||||
});
|
||||
|
||||
it("insert with array with null value and returning", function() {
|
||||
testsql(qb().into('users').insert([null], 'id'), {
|
||||
mysql: {
|
||||
sql: 'insert into `users` () values ()',
|
||||
bindings: []
|
||||
},
|
||||
sqlite3: {
|
||||
sql: 'insert into "users" default values',
|
||||
bindings: []
|
||||
},
|
||||
postgres: {
|
||||
sql: 'insert into "users" default values returning "id"',
|
||||
bindings: []
|
||||
},
|
||||
oracle: {
|
||||
sql: "insert into \"users\" (\"id\") values (default) returning ROWID into ?",
|
||||
bindings: function (bindings) {
|
||||
expect(bindings.length).to.equal(1);
|
||||
expect(bindings[0].toString()).to.equal('[object ReturningHelper:id]');
|
||||
}
|
||||
},
|
||||
default: {
|
||||
sql: 'insert into "users" default values',
|
||||
bindings: []
|
||||
}
|
||||
});
|
||||
});
|
||||
|
||||
it("insert with array of multiple null values ", function() {
|
||||
testsql(qb().into('users').insert([null, null]), {
|
||||
mysql: {
|
||||
sql: 'insert into `users` () values (), ()',
|
||||
bindings: []
|
||||
},
|
||||
sqlite3: {
|
||||
// This does not work
|
||||
// Not possible to insert multiple default value rows at once with sqlite
|
||||
sql: 'insert into "users" () select union all select ',
|
||||
bindings: []
|
||||
},
|
||||
oracle: {
|
||||
// This does not work
|
||||
// It's not possible to insert default value without knowing at least one column
|
||||
sql: "begin execute immediate 'insert into \"users\" (\"undefined\") values (default); execute immediate 'insert into \"users\" (\"undefined\") values (default);end;",
|
||||
bindings: []
|
||||
},
|
||||
postgres: {
|
||||
// This does not work
|
||||
// Postgres does not support inserting multiple default values without specifying a column
|
||||
sql: "insert into \"users\" (\"undefined\") values (default), (default)",
|
||||
bindings: []
|
||||
},
|
||||
default: {
|
||||
sql: 'insert into "users" default values',
|
||||
bindings: []
|
||||
}
|
||||
});
|
||||
});
|
||||
|
||||
it("insert with multiple array of empty values", function() {
|
||||
testsql(qb().into('users').insert([{}, {}]), {
|
||||
mysql: {
|
||||
sql: 'insert into `users` () values (), ()',
|
||||
bindings: []
|
||||
},
|
||||
sqlite3: {
|
||||
// This does not work
|
||||
// Not possible to insert multiple default value rows at once with sqlite
|
||||
sql: 'insert into "users" () select union all select ',
|
||||
bindings: []
|
||||
},
|
||||
oracle: {
|
||||
// This does not work
|
||||
// It's not possible to insert default value without knowing at least one column
|
||||
sql: "begin execute immediate 'insert into \"users\" (\"undefined\") values (default); execute immediate 'insert into \"users\" (\"undefined\") values (default);end;",
|
||||
bindings: []
|
||||
},
|
||||
postgres: {
|
||||
// This does not work
|
||||
// Postgres does not support inserting multiple default values without specifying a column
|
||||
sql: "insert into \"users\" (\"undefined\") values (default), (default)",
|
||||
bindings: []
|
||||
},
|
||||
default: {
|
||||
sql: 'insert into "users" default values',
|
||||
bindings: []
|
||||
}
|
||||
});
|
||||
});
|
||||
|
||||
it("insert with multiple empty values with returning", function() {
|
||||
testsql(qb().into('users').insert([null, null], 'id'), {
|
||||
mysql: {
|
||||
sql: 'insert into `users` () values (), ()',
|
||||
bindings: []
|
||||
},
|
||||
sqlite3: {
|
||||
// It's not possible to insert multiple default value rows at once with sqlite
|
||||
sql: 'insert into "users" () select union all select ',
|
||||
bindings: []
|
||||
},
|
||||
oracle: {
|
||||
sql: "begin execute immediate 'insert into \"users\" (\"id\") values (default) returning ROWID into :1' using out ?; execute immediate 'insert into \"users\" (\"id\") values (default) returning ROWID into :1' using out ?;end;",
|
||||
bindings: function (bindings) {
|
||||
expect(bindings.length).to.equal(2);
|
||||
expect(bindings[0].toString()).to.equal('[object ReturningHelper:id]');
|
||||
expect(bindings[1].toString()).to.equal('[object ReturningHelper:id]');
|
||||
}
|
||||
},
|
||||
postgres: {
|
||||
sql: 'insert into "users" ("id") values (default), (default) returning "id"',
|
||||
bindings: []
|
||||
},
|
||||
default: {
|
||||
sql: 'not checked',
|
||||
bindings: []
|
||||
}
|
||||
});
|
||||
});
|
||||
|
||||
it("update method", function() {
|
||||
testsql(qb().update({'email': 'foo', 'name': 'bar'}).table('users').where('id', '=', 1), {
|
||||
mysql: {
|
||||
|
||||
Loading…
x
Reference in New Issue
Block a user