Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Feature: update multiple rows. #55

Merged
merged 10 commits into from
Sep 30, 2018
69 changes: 69 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down Expand Up @@ -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)

Expand Down
126 changes: 125 additions & 1 deletion lib/operator.js
Original file line number Diff line number Diff line change
Expand Up @@ -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);
Expand Down Expand Up @@ -174,6 +173,131 @@ 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
* @param {String} table table name
* @param {Array<Object>} 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 } }]
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@nodejh 还有最后一个问题,如何 id 和 where 都不存在,会怎样?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@fengmk2 会抛错。

代码实现:

if (!option.hasOwnProperty('id') && !(option.row && option.where)) {

测试用例:

it('should throw error when rows has neither primary key `id` nor `row` and `where` properties', async function() {

* @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);
Expand Down
Loading