Skip to content

Commit

Permalink
feat: add updateDistinct
Browse files Browse the repository at this point in the history
  • Loading branch information
gajus committed Jun 22, 2019
1 parent 0d364cc commit 59199d1
Show file tree
Hide file tree
Showing 10 changed files with 279 additions and 26 deletions.
3 changes: 3 additions & 0 deletions .README/README.md
Original file line number Diff line number Diff line change
Expand Up @@ -15,4 +15,7 @@ Utilities for manipulating data in PostgreSQL database using [Slonik](https://gi
## Usage

{"gitdown": "include", "file": "./UPDATE.md"}

{"gitdown": "include", "file": "./UPDATE_DISTINCT.md"}

{"gitdown": "include", "file": "./UPSERT.md"}
2 changes: 1 addition & 1 deletion .README/UPDATE.md
Original file line number Diff line number Diff line change
Expand Up @@ -8,7 +8,7 @@ import {
/**
* @param connection Instance of Slonik connection.
* @param {string} tableName Target table name.
* @param {Object.<string, ValueExpression>} Object describing the desired column values.
* @param {Object.<string, ValueExpression>} namedValueBindings Object describing the desired column values.
* @param {Object.<string, EqualPredicate>} [booleanExpressionValues] Object describing the boolean expression used to construct WHERE condition.
*/
update;
Expand Down
74 changes: 74 additions & 0 deletions .README/UPDATE_DISTINCT.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,74 @@
### `updateDistinct`

```js
import {
updateDistinct
} from 'slonik-utilities';

/**
* @param connection Instance of Slonik connection.
* @param {string} tableName Target table name.
* @param {Object.<string, ValueExpression>} namedValueBindings Object describing the desired column values.
* @param {Object.<string, EqualPredicate>} [booleanExpressionValues] Object describing the boolean expression used to construct WHERE condition.
*/
updateDistinct;

```

Constructs and executes `UPDATE` query matching only rows with distinct values.

#### Example: Update all rows

Operation:

```js
update(
connection,
'user',
{
givenName: 'foo'
}
);

```

Is equivalent to:

```sql
UPDATE "user"
SET
"given_name" = $1
WHERE
"given_name" IS DISTINCT FROM $1;

```

#### Example: Update rows matching a boolean WHERE condition

Operation:

```js
update(
connection,
'user',
{
givenName: 'foo'
},
{
lastName: 'bar'
}
);

```

Is equivalent to:

```sql
UPDATE "user"
SET
"given_name" = $1
WHERE
"last_name" = $2 AND
"given_name" IS DISTINCT FROM $1;

```
2 changes: 1 addition & 1 deletion package.json
Original file line number Diff line number Diff line change
Expand Up @@ -25,7 +25,7 @@
"lodash": "^4.17.11",
"roarr": "^2.13.2",
"serialize-error": "^4.1.0",
"slonik": "^16.19.7"
"slonik": "^16.20.0"
},
"description": "Utilities for manipulating data in PostgreSQL database using Slonik.",
"devDependencies": {
Expand Down
1 change: 1 addition & 0 deletions src/index.js
Original file line number Diff line number Diff line change
Expand Up @@ -2,5 +2,6 @@

export {
update,
updateDistinct,
upsert
} from './routines';
1 change: 1 addition & 0 deletions src/routines/index.js
Original file line number Diff line number Diff line change
@@ -1,4 +1,5 @@
// @flow

export {default as update} from './update';
export {default as updateDistinct} from './updateDistinct';
export {default as upsert} from './upsert';
59 changes: 59 additions & 0 deletions src/routines/updateDistinct.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,59 @@
// @flow

import {
normalizeIdentifier,
sql
} from 'slonik';
import type {
DatabaseConnectionType,
ValueExpressionType
} from 'slonik';

type NamedValueBindingsType = {
+[key: string]: ValueExpressionType
};

export default async (
connection: DatabaseConnectionType,
tableName: string,
namedValueBindings: NamedValueBindingsType,

// eslint-disable-next-line flowtype/no-weak-types
booleanExpressionValues: Object = null
) => {
const assignmentList = sql.assignmentList(namedValueBindings);

let booleanExpression = sql.booleanExpression(
Object
.entries(namedValueBindings)
.map(([key, value]) => {
// $FlowFixMe
return sql.raw('$1 IS DISTINCT FROM $2', [sql.identifier([normalizeIdentifier(key)]), value]);
}),
'OR'
);

if (booleanExpressionValues) {
booleanExpression = sql.booleanExpression(
[
booleanExpression,
sql.booleanExpression(
Object
.entries(booleanExpressionValues)
.map(([key, value]) => {
// $FlowFixMe
return sql.comparisonPredicate(sql.identifier([key]), '=', value);
}),
'AND'
)
],
'AND'
);
}

await connection.query(sql`
UPDATE ${sql.identifier([tableName])}
SET ${assignmentList}
WHERE ${booleanExpression}
`);
};
16 changes: 8 additions & 8 deletions test/slonik-utilities/routines/update.js
Original file line number Diff line number Diff line change
Expand Up @@ -29,9 +29,9 @@ test('executes UPDATE query without WHERE condition (single column)', async (t)
}
);

t.assert(connection.query.callCount === 1);
t.is(connection.query.callCount, 1);

t.assert(normalizeQuery(connection.query.firstCall.args[0].sql) === 'UPDATE "foo" SET "bar" = $1');
t.is(normalizeQuery(connection.query.firstCall.args[0].sql), 'UPDATE "foo" SET "bar" = $1');
t.deepEqual(connection.query.firstCall.args[0].values, [
'baz'
]);
Expand All @@ -50,9 +50,9 @@ test('executes UPDATE query without WHERE condition (multiple columns)', async (
}
);

t.assert(connection.query.callCount === 1);
t.is(connection.query.callCount, 1);

t.assert(normalizeQuery(connection.query.firstCall.args[0].sql) === 'UPDATE "foo" SET "bar_0" = $1, "bar_1" = $2, "bar_2" = $3');
t.is(normalizeQuery(connection.query.firstCall.args[0].sql), 'UPDATE "foo" SET "bar_0" = $1, "bar_1" = $2, "bar_2" = $3');
t.deepEqual(connection.query.firstCall.args[0].values, [
'baz0',
'baz1',
Expand All @@ -73,9 +73,9 @@ test('executes UPDATE query without WHERE condition (SQL token)', async (t) => {
}
);

t.assert(connection.query.callCount === 1);
t.is(connection.query.callCount, 1);

t.assert(normalizeQuery(connection.query.firstCall.args[0].sql) === 'UPDATE "foo" SET "bar_0" = $1, "bar_1" = to_timestamp($2), "bar_2" = $3');
t.is(normalizeQuery(connection.query.firstCall.args[0].sql), 'UPDATE "foo" SET "bar_0" = $1, "bar_1" = to_timestamp($2), "bar_2" = $3');
t.deepEqual(connection.query.firstCall.args[0].values, [
'baz0',
'baz1',
Expand All @@ -97,9 +97,9 @@ test('executes UPDATE query with WHERE condition (AND boolean expression short-h
}
);

t.assert(connection.query.callCount === 1);
t.is(connection.query.callCount, 1);

t.assert(normalizeQuery(connection.query.firstCall.args[0].sql) === 'UPDATE "foo" SET "bar" = $1 WHERE ("qux" = $2)');
t.is(normalizeQuery(connection.query.firstCall.args[0].sql), 'UPDATE "foo" SET "bar" = $1 WHERE ("qux" = $2)');
t.deepEqual(connection.query.firstCall.args[0].values, [
'baz',
'quux'
Expand Down
115 changes: 115 additions & 0 deletions test/slonik-utilities/routines/updateDistinct.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,115 @@
// @flow

import {
sql
} from 'slonik';
import test from 'ava';
import sinon from 'sinon';
import updateDistinct from '../../../src/routines/updateDistinct';
import normalizeQuery from '../../helpers/normalizeQuery';

const createConnection = () => {
const query = sinon.stub();

const connection = {
query
};

return connection;
};

test('executes UPDATE query without WHERE condition (single column)', async (t) => {
const connection = createConnection();

await updateDistinct(
connection,
'foo',
{
bar: 'baz'
}
);

t.is(connection.query.callCount, 1);

t.is(normalizeQuery(connection.query.firstCall.args[0].sql), 'UPDATE "foo" SET "bar" = $1 WHERE ("bar" IS DISTINCT FROM $2)');
t.deepEqual(connection.query.firstCall.args[0].values, [
'baz',
'baz'
]);
});

test('executes UPDATE query without WHERE condition (multiple columns)', async (t) => {
const connection = createConnection();

await updateDistinct(
connection,
'foo',
{
bar0: 'baz0',
bar1: 'baz1',
bar2: 'baz2'
}
);

t.is(connection.query.callCount, 1);

t.is(normalizeQuery(connection.query.firstCall.args[0].sql), 'UPDATE "foo" SET "bar_0" = $1, "bar_1" = $2, "bar_2" = $3 WHERE ("bar_0" IS DISTINCT FROM $4 OR "bar_1" IS DISTINCT FROM $5 OR "bar_2" IS DISTINCT FROM $6)');
t.deepEqual(connection.query.firstCall.args[0].values, [
'baz0',
'baz1',
'baz2',
'baz0',
'baz1',
'baz2'
]);
});

test('executes UPDATE query without WHERE condition (SQL token)', async (t) => {
const connection = createConnection();

await updateDistinct(
connection,
'foo',
{
bar0: 'baz0',
bar1: sql.raw('to_timestamp($1)', ['baz1']),
bar2: 'baz2'
}
);

t.is(connection.query.callCount, 1);

t.is(normalizeQuery(connection.query.firstCall.args[0].sql), 'UPDATE "foo" SET "bar_0" = $1, "bar_1" = to_timestamp($2), "bar_2" = $3 WHERE ("bar_0" IS DISTINCT FROM $4 OR "bar_1" IS DISTINCT FROM to_timestamp($5) OR "bar_2" IS DISTINCT FROM $6)');
t.deepEqual(connection.query.firstCall.args[0].values, [
'baz0',
'baz1',
'baz2',
'baz0',
'baz1',
'baz2'
]);
});

test('executes UPDATE query with WHERE condition (AND boolean expression short-hand; single comparison predicate)', async (t) => {
const connection = createConnection();

await updateDistinct(
connection,
'foo',
{
bar: 'baz'
},
{
qux: 'quux'
}
);

t.is(connection.query.callCount, 1);

t.is(normalizeQuery(connection.query.firstCall.args[0].sql), 'UPDATE "foo" SET "bar" = $1 WHERE (("bar" IS DISTINCT FROM $2) AND ("qux" = $3))');
t.deepEqual(connection.query.firstCall.args[0].values, [
'baz',
'baz',
'quux'
]);
});
Loading

0 comments on commit 59199d1

Please sign in to comment.