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

feat: support multiple rows update #4

Open
wants to merge 1 commit into
base: master
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
39 changes: 39 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -154,6 +154,45 @@ console.log(result);
changedRows: 1 }
```

- Update multiple rows with each row has a primary key: `id`

```js
let rows = [{
id: 123,
name: 'fengmk2',
fieldA: 'fieldA value',
}, {
id: 456,
name: 'luckydrq',
fieldB: 'fieldB value'
}];
let result = yield db.updateRows('table-name', rows);

=> UPDATE `table-name`
SET name = CASE id
WHEN 123 THEN 'fengmk2'
WHEN 456 THEN 'luckydrq'
END,
fieldA = CASE id
WHEN 123 THEN 'filedA value'
END,
fieldB = CASE id
WHEN 456 THEN 'fieldB value'
END
WHERE id IN(123, 456)

console.log(result);
{
fieldCount: 0,
affectedRows: 2,
insertId: 0,
serverStatus: 2,
warningCount: 0,
message: '',
protocol41: true,
changedRows: 2 }
```

### Get

- Get a row
Expand Down
101 changes: 97 additions & 4 deletions lib/operator.js
Original file line number Diff line number Diff line change
Expand Up @@ -14,7 +14,10 @@
* Module dependencies.
*/

const util = require('util');
const debug = require('debug')('ali-rds:operator');
const toArray = require('json-to-array');
const merge = require('array-merges');
const SqlString = require('./sqlstring');
const literals = require('./literals');

Expand Down Expand Up @@ -63,7 +66,7 @@ proto.count = function* (table, where) {
let sql = this.format('SELECT COUNT(*) as count FROM ??', [table]) +
this._where(where);
debug('count(%j, %j) \n=> %j', table, where, sql);
var rows = yield this.query(sql);
let rows = yield this.query(sql);
return rows[0].count;
};

Expand Down Expand Up @@ -116,8 +119,8 @@ proto.insert = function* (table, rows, options) {
let params = [table, options.columns];
let strs = [];
for (let i = 0; i < rows.length; i++) {
var values = [];
var row = rows[i];
let values = [];
let row = rows[i];
for (let j = 0; j < options.columns.length; j++) {
values.push(row[options.columns[j]]);
}
Expand Down Expand Up @@ -148,7 +151,7 @@ proto.update = function* (table, row, options) {
let sets = [];
let values = [];
for (let i = 0; i < options.columns.length; i++) {
var column = options.columns[i];
let column = options.columns[i];
if (column in options.where) {
continue;
}
Expand All @@ -163,6 +166,96 @@ proto.update = function* (table, row, options) {
return yield this.query(sql);
};

/**
* Update multiple rows from a table
* @see http://stackoverflow.com/questions/2528181/update-multiple-rows-with-one-query
*
* @param {String} table table name
* @param {Array} rows row obj with a primary key `id`
* @return {Object} result
*/
proto.updateRows = function* (table, rows) {
if (!Array.isArray(rows)) {
rows = [rows];
}

let escape = this.escape;
let escapeId = this.escapeId;
let ids = [];
let rowArr = rows
.map(function(row) {
// {a: b, c: d} => [[a, b], [c, d]]
if (!row.hasOwnProperty('id')) {
throw new Error('Can\' update rows. Make sure each row has a id');
}

// escape first
row.id = escape(row.id);
ids.push(row.id);
return toArray(row, { excepts: ['id'] });
})
.reduce(function(prev, curr) {
// merge([[a, b]], [[a, c]]) => [[a, [b, c]]]
prev = merge(prev, curr, {
equal: equal,
onMerge: onMerge
});
return prev;
}, []);

function equal(prev, next) {
return prev[0] === next[0];
}

function onMerge(prev, next) {
if (Array.isArray(prev[1])) {
prev[1].push(next[1]);
} else {
prev[1] = [prev[1], next[1]];
}
return [[prev[0], prev[1]]];
}

// id 查找规则。多条记录可能拥有相同的key, value。
// 通过{id}_{key}做key,是唯一的。
let idMap = {};
function getId(key, value) {
for (let i = 0; i < rows.length; i++) {
if (rows[i][key] === value) {
let hashKey = rows[i].id + '_' + key;
if (idMap[hashKey]) {
continue;
} else {
idMap[hashKey] = true;
return rows[i].id;
}
}
}
return null;
}

let clauseTemplate = 'UPDATE %s SET %s WHERE id IN (%s)';
let subClauseTemplate = '%s = CASE id %s END';
let loopClauseTemplate = 'WHEN %s THEN %s';
let clauseArr = [];
table = escapeId(table);
rowArr.forEach(function(tuple) {
let key = tuple[0], values = Array.isArray(tuple[1]) ? tuple[1] : [tuple[1]];
let loopArr = [];
values.forEach(function(value) {
let id = getId(key, value);
if (id) {
value = escape(value);
loopArr.push(util.format(loopClauseTemplate, id, value));
}
});
clauseArr.push(util.format(subClauseTemplate, escapeId(key), loopArr.join(' ')));
});
let sql = util.format(clauseTemplate, table, clauseArr.join(','), ids.join(','));
debug('update(%j, %j, %j) \n=> %j', table, JSON.stringify(rows), sql);
return yield this.query(sql);
};

proto.delete = function* (table, where) {
let sql = this.format('DELETE FROM ??', [table]) +
this._where(where);
Expand Down
2 changes: 2 additions & 0 deletions package.json
Original file line number Diff line number Diff line change
Expand Up @@ -15,7 +15,9 @@
"cnpm": "npm install --registry=https://registry.npm.taobao.org"
},
"dependencies": {
"array-merges": "^0.1.0",
"debug": "~2.2.0",
"json-to-array": "^0.1.0",
"mysql": "~2.7.0"
},
"devDependencies": {
Expand Down
38 changes: 38 additions & 0 deletions test/operator.test.js
Original file line number Diff line number Diff line change
Expand Up @@ -15,9 +15,18 @@
*/

const assert = require('assert');
const rds = require('..');
const config = require('./config');
const Operator = require('../lib/operator');

describe('operator.test.js', function () {
const prefix = 'prefix-' + process.version + '-';
const table = 'user';
Copy link
Member Author

Choose a reason for hiding this comment

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

这里表名换了。。不知道为什么,在我的rds里无法创建名字为ali-sdk-test-user的表,可能是中划线的问题?

before(function* () {
this.db = rds(config);
yield this.db.query('delete from ?? where name like ?', [table, prefix + '%']);
});

describe('_where(where)', function () {
it('should get where sql', function () {
let op = new Operator();
Expand Down Expand Up @@ -52,4 +61,33 @@ describe('operator.test.js', function () {
}
});
});

describe('updateRows()', function() {
before(function* () {
yield this.db.query('insert into ??(name, email, gmt_create, gmt_modified) \
values(?, ?, now(), now())',
[table, prefix + 'luckydrq', prefix + '[email protected]']);
yield this.db.query('insert into ??(name, email, gmt_create, gmt_modified) \
values(?, ?, now(), now())',
[table, prefix + 'luckydrq2', prefix + '[email protected]']);
});

it('should update multiple rows', function* () {
let rows = yield this.db.query('select * from ?? where email=? order by id',
[table, prefix + '[email protected]']);
console.log(rows);
assert.equal(rows.length, 2);
assert.equal(rows[0].name, prefix + 'luckydrq');
assert.equal(rows[1].name, prefix + 'luckydrq2');

rows[0].name = prefix + 'drq';
rows[1].email = prefix + '[email protected]';
yield this.db.updateRows(table, rows);
let updatedRows = yield this.db.query('select * from ?? where id in (?, ?)',
[table, rows[0].id, rows[1].id]);
console.log(updatedRows);
assert.equal(updatedRows[0].name, prefix + 'drq');
assert.equal(updatedRows[1].email, prefix + '[email protected]');
});
});
});