From 859d818d7e327d1ff590d363dfbf3135d8c90454 Mon Sep 17 00:00:00 2001 From: Hang Jiang Date: Sun, 30 Sep 2018 20:01:55 +0800 Subject: [PATCH] feat: update multiple rows (#55) --- README.md | 69 +++++++++++++++ lib/operator.js | 129 +++++++++++++++++++++++++++- test/async.js | 219 +++++++++++++++++++++++++++++++++++++++++++++++- 3 files changed, 412 insertions(+), 5 deletions(-) diff --git a/README.md b/README.md index 4eb6243..6b2d271 100644 --- a/README.md +++ b/README.md @@ -158,6 +158,74 @@ console.log(result); changedRows: 1 } ``` +### Update multiple rows + +- Update multiple rows with primary key: `id` + +```js +let options = [{ + id: 123, + name: 'fengmk2', + email: 'm@fengmk2.com', + otherField: 'other field value', + modifiedAt: db.literals.now, // `now()` on db server +}, { + id: 124, + name: 'fengmk2_2', + email: 'm@fengmk2_2.com', + otherField: 'other field value 2', + modifiedAt: db.literals.now, // `now()` on db server +}] +let result = yield db.updateRows('table-name', options); +console.log(result); +{ fieldCount: 0, + affectedRows: 2, + insertId: 0, + serverStatus: 2, + warningCount: 0, + message: '(Rows matched: 2 Changed: 2 Warnings: 0', + protocol41: true, + changedRows: 2 } +``` + +- Update multiple rows with `row` and `where` properties + + +```js +let options = [{ + row: { + email: 'm@fengmk2.com', + otherField: 'other field value', + modifiedAt: db.literals.now, // `now()` on db server + }, + where: { + id: 123, + name: 'fengmk2', + } +}, { + row: { + email: 'm@fengmk2_2.com', + otherField: 'other field value2', + modifiedAt: db.literals.now, // `now()` on db server + }, + where: { + id: 124, + name: 'fengmk2_2', + } +}] +let result = yield db.updateRows('table-name', options); +console.log(result); +{ fieldCount: 0, + affectedRows: 2, + insertId: 0, + serverStatus: 2, + warningCount: 0, + message: '(Rows matched: 2 Changed: 2 Warnings: 0', + protocol41: true, + changedRows: 2 } +``` + + ### Get - Get a row @@ -317,6 +385,7 @@ TBD - *get(table, where, options) - *insert(table, row[s], options) - *update(table, row, options) +- *updateRows(table, options) - *delete(table, where) - *count(table, where) diff --git a/lib/operator.js b/lib/operator.js index 7696801..e68be2e 100644 --- a/lib/operator.js +++ b/lib/operator.js @@ -142,7 +142,6 @@ proto.insert = function* (table, rows, options) { }; proto.update = function* (table, row, options) { - // TODO: support multi rows options = options || {}; if (!options.columns) { options.columns = Object.keys(row); @@ -174,6 +173,134 @@ proto.update = function* (table, row, options) { return yield this.query(sql); }; +/** + * + * Update multiple rows from a table + * + * UPDATE `table_name` SET + * `column1` CASE + * WHEN condition1 THEN 'value11' + * WHEN condition2 THEN 'value12' + * WHEN condition3 THEN 'value13' + * ELSE `column1` END, + * `column2` CASE + * WHEN condition1 THEN 'value21' + * WHEN condition2 THEN 'value22' + * WHEN condition3 THEN 'value23' + * ELSE `column2` END + * WHERE condition + * + * See MySQL Case Syntax: https://dev.mysql.com/doc/refman/5.7/en/case.html + * + * @param {String} table table name + * @param {Array} options Object Arrays + * each Object needs a primary key `id`, or each Object has `row` and `where` properties + * e.g. + * [{ id: 1, name: 'fengmk21' }] + * or [{ row: { name: 'fengmk21' }, where: { id: 1 } }] + * @return {object} update result + */ +proto.updateRows = function* (table, options) { + if (!Array.isArray(options)) { + throw new Error('Options should be array'); + } + + /** + * { + * column: { + * when: [ 'WHEN condition1 THEN ?', 'WHEN condition12 THEN ?' ], + * then: [ value1, value1 ] + * } + * } + */ + const SQL_CASE = {}; + // e.g. { id: [], column: [] } + const WHERE = {}; + + options.forEach(option => { + + if (!option.hasOwnProperty('id') && !(option.row && option.where)) { + throw new Error('Can not auto detect updateRows condition, please set option.row and option.where, or make sure option.id exists'); + } + + // convert { id, column } to { row: { column }, where: { id } } + if (option.hasOwnProperty('id')) { + const where = { id: option.id }; + const row = Object.keys(option).reduce((result, key) => { + if (key !== 'id') { + result[key] = option[key]; + } + return result; + }, {}); + option = { row, where }; + } + + let where = this._where(option.where); + where = where.indexOf('WHERE') === -1 ? where : where.substring(where.indexOf('WHERE') + 5); + for (const key in option.row) { + if (!SQL_CASE[key]) { + SQL_CASE[key] = { when: [], then: [] }; + } + SQL_CASE[key].when.push(' WHEN ' + where + ' THEN ? '); + SQL_CASE[key].then.push(option.row[key]); + } + + for (const key in option.where) { + if (!WHERE[key]) { + WHERE[key] = []; + } + if (WHERE[key].indexOf(option.where[key]) === -1) { + WHERE[key].push(option.where[key]); + } + } + }); + + let SQL = [ 'UPDATE ?? SET ' ]; + let VALUES = [ table ]; + + const TEMPLATE = []; + for (const key in SQL_CASE) { + let templateSql = ' ?? = CASE '; + VALUES.push(key); + templateSql += SQL_CASE[key].when.join(' '); + VALUES = VALUES.concat(SQL_CASE[key].then); + templateSql += ' ELSE ?? END '; + TEMPLATE.push(templateSql); + VALUES.push(key); + } + + SQL += TEMPLATE.join(' , '); + SQL += this._where(WHERE); + + /** + * e.g. + * + * updateRows(table, [ + * {id: 1, name: 'fengmk21', email: 'm@fengmk21.com'}, + * {id: 2, name: 'fengmk22', email: 'm@fengmk22.com'}, + * {id: 3, name: 'fengmk23', email: 'm@fengmk23.com'}, + * ]) + * + * UPDATE `ali-sdk-test-user` SET + * `name` = + * CASE + * WHEN `id` = 1 THEN 'fengmk21' + * WHEN `id` = 2 THEN 'fengmk22' + * WHEN `id` = 3 THEN 'fengmk23' + * ELSE `name` END, + * `email` = + * CASE + * WHEN `id` = 1 THEN 'm@fengmk21.com' + * WHEN `id` = 2 THEN 'm@fengmk22.com' + * WHEN `id` = 3 THEN 'm@fengmk23.com' + * ELSE `email` END + * WHERE `id` IN (1, 2, 3) + */ + const sql = this.format(SQL, VALUES); + debug('updateRows(%j, %j) \n=> %j', table, options, sql); + return yield this.query(sql); +}; + proto.delete = function* (table, where) { const sql = this.format('DELETE FROM ??', [ table ]) + this._where(where); diff --git a/test/async.js b/test/async.js index fbe75e0..387965d 100644 --- a/test/async.js +++ b/test/async.js @@ -718,10 +718,27 @@ describe('async.test.js', function() { }); assert.equal(user.email, prefix + 'm@fengmk2-update.com'); - let result = await this.db.update(table, { + let result; + + try { + result = await this.db.update(table, { + name: prefix + 'fengmk2-update', + email: prefix + 'm@fengmk2-update2.com', + gmt_create: 'now()', // invalid date + gmt_modified: this.db.literals.now, + }, { + where: { + name: prefix + 'fengmk2-update', + }, + }); + } catch (error) { + assert.equal(error.message, "ER_TRUNCATED_WRONG_VALUE: Incorrect datetime value: 'now()' for column 'gmt_create' at row 1"); + } + + result = await this.db.update(table, { name: prefix + 'fengmk2-update', email: prefix + 'm@fengmk2-update2.com', - gmt_create: 'now()', // invalid date + gmt_create: new Date('2000'), gmt_modified: this.db.literals.now, }, { where: { @@ -733,8 +750,8 @@ describe('async.test.js', function() { user = await this.db.get(table, { name: prefix + 'fengmk2-update', }); - assert.equal(user.email, prefix + 'm@fengmk2-update2.com'); - assert.equal(user.gmt_create, '0000-00-00 00:00:00'); + assert.deepEqual(user.email, prefix + 'm@fengmk2-update2.com'); + assert.deepEqual(new Date(user.gmt_create), new Date('2000')); assert(user.gmt_modified instanceof Date); user.email = prefix + 'm@fengmk2-update3.com'; @@ -747,6 +764,200 @@ describe('async.test.js', function() { }); }); + describe('updateRows(table, rows)', function() { + before(async function() { + await this.db.insert(table, [{ + name: prefix + 'fengmk2-updateRows1', + email: prefix + 'm@fengmk2-updateRows1.com', + gmt_create: this.db.literals.now, + gmt_modified: this.db.literals.now, + }, { + name: prefix + 'fengmk2-updateRows2', + email: prefix + 'm@fengmk2-updateRows2.com', + gmt_create: this.db.literals.now, + gmt_modified: this.db.literals.now, + }]); + }); + + it('should throw error when param options is not an array', async function() { + try { + await this.db.updateRows(table, {}); + throw new Error('should not run this'); + } catch (err) { + assert.equal(err.message, 'Options should be array'); + } + }); + + it('should throw error when rows has neither primary key `id` nor `row` and `where` properties', async function() { + try { + await this.db.updateRows(table, [{ + name: prefix + 'fengmk2-updateRows1-updated', + }]); + throw new Error('should not run this'); + } catch (err) { + assert.equal(err.message, 'Can not auto detect updateRows condition, please set option.row and option.where, or make sure option.id exists'); + } + }); + + it('should get and update with primary key `id`', async function() { + const rows = [{ + name: prefix + 'fengmk2-updateRows1-again', + email: prefix + 'm@fengmk2-updateRows1-again.com', + gmt_create: this.db.literals.now, + gmt_modified: this.db.literals.now, + }, { + name: prefix + 'fengmk2-updateRows2-again', + email: prefix + 'm@fengmk2-updateRows2-again.com', + gmt_create: this.db.literals.now, + gmt_modified: this.db.literals.now, + }]; + await this.db.insert(table, rows); + + const names = rows.map(item => item.name); + let users = await this.db.select(table, { + where: { name: names }, + }); + + users = users.map((item, index) => { + item.email = prefix + 'm@fengmk2-updateRows-again-updated' + (index + 1) + '.com'; + item.gmt_create = new Date('1970'); + return item; + }); + + const result = await this.db.updateRows(table, users); + assert.equal(result.affectedRows, 2); + + const rowsUpdated = await this.db.select(table, { + where: { name: names }, + }); + assert.deepEqual(users.map(o => o.email), rowsUpdated.map(o => o.email)); + }); + + it('should update exists rows with primary key `id`', async function() { + const names = [ + prefix + 'fengmk2-updateRows1', + prefix + 'fengmk2-updateRows2', + ]; + const emails = [ + prefix + 'm@fengmk2-updateRows1.com', + prefix + 'm@fengmk2-updateRows2.com', + ]; + let users = await this.db.select(table, { + where: { name: names }, + }); + assert.deepEqual(users.map(o => o.email), emails); + + users = users.map((item, index) => { + item.email = prefix + 'm@fengmk2-updateRows-updated' + (index + 1) + '.com'; + item.gmt_create = new Date('1970'); + return item; + }); + + let result = await this.db.updateRows(table, users); + assert.equal(result.affectedRows, 2); + + users = await this.db.select(table, { + where: { name: names }, + }); + assert.deepEqual(users.map(o => o.email), [ + prefix + 'm@fengmk2-updateRows-updated1.com', + prefix + 'm@fengmk2-updateRows-updated2.com', + ]); + + const newGmtCreate = new Date('2000'); + users = users.map((item, index) => { + const newItem = { + id: item.id, + email: prefix + 'm@fengmk2-updateRows-again-updated' + (index + 1) + '.com', + }; + if (index >= 1) { + newItem.gmt_create = newGmtCreate; + } + return newItem; + }); + result = await this.db.updateRows(table, users); + assert.equal(result.affectedRows, 2); + users = await this.db.select(table, { + where: { name: names }, + }); + assert.deepEqual(users[0].gmt_create, new Date('1970')); + assert.deepEqual(users[1].gmt_create, newGmtCreate); + assert.deepEqual(users.map(o => o.email), [ + prefix + 'm@fengmk2-updateRows-again-updated1.com', + prefix + 'm@fengmk2-updateRows-again-updated2.com', + ]); + }); + + it('should update rows with `row` and `where` properties', async function() { + const users = [{ + name: prefix + 'fengmk2-updateRows0001', + email: prefix + 'm@fengmk2-updateRows0001.com', + }, { + name: prefix + 'fengmk2-updateRows0002', + email: prefix + 'm@fengmk2-updateRows0002.com', + }, { + name: prefix + 'fengmk2-updateRows0003', + email: prefix + 'm@fengmk2-updateRows0003.com', + }]; + await this.db.insert(table, users); + let gmtModified = new Date('2050-01-01'); + let newUsers = [{ + row: { + email: prefix + 'm@fengmk2-updateRows0001.com-updated1', + gmt_modified: gmtModified, + }, + where: { + name: prefix + 'fengmk2-updateRows0001', + }, + }, { + row: { + email: prefix + 'm@fengmk2-updateRows0002.com-updated2', + gmt_modified: gmtModified, + }, + where: { + name: prefix + 'fengmk2-updateRows0002', + }, + }, { + row: { + email: prefix + 'm@fengmk2-updateRows0003.com-updated3', + gmt_modified: gmtModified, + }, + where: { + name: prefix + 'fengmk2-updateRows0003', + }, + }]; + await this.db.updateRows(table, newUsers); + let updatedUsers = await this.db.select(table, { + where: { name: newUsers.map(item => item.where.name) }, + }); + assert.deepEqual( + newUsers.map(o => ({ email: o.row.email, gmt_modified: new Date(o.row.gmt_modified) })), + updatedUsers.map(o => ({ email: o.email, gmt_modified: new Date(o.gmt_modified) })), + ); + + gmtModified = new Date('2100-01-01'); + newUsers = updatedUsers.map(item => ({ + row: { + email: item.email + '-again', + gmt_modified: gmtModified, + }, + where: { + id: item.id, + name: item.name, + }, + })); + await this.db.updateRows(table, newUsers); + + updatedUsers = await this.db.select(table, { + where: { name: newUsers.map(item => item.where.name) }, + }); + assert.deepEqual( + newUsers.map(o => ({ email: o.row.email, gmt_modified: new Date(o.row.gmt_modified) })), + updatedUsers.map(o => ({ email: o.email, gmt_modified: new Date(o.gmt_modified) })), + ); + }); + }); + describe('delete(table, where)', function() { before(async function() { let result = await this.db.insert(table, {