Skip to content

Commit

Permalink
feat: add sql.identifier utility (fixes #9)
Browse files Browse the repository at this point in the history
  • Loading branch information
gajus committed Jul 29, 2018
1 parent 71bb89a commit 12aa9e9
Show file tree
Hide file tree
Showing 6 changed files with 162 additions and 23 deletions.
16 changes: 16 additions & 0 deletions .README/VALUE_PLACEHOLDERS.md
Expand Up @@ -108,6 +108,22 @@ connection.query('INSERT INTO reservation_ticket (reservation_id, ticket_id) VAL

```

#### Creating dynamic delimited identifiers

[Delimited identifiers](https://www.postgresql.org/docs/current/static/sql-syntax-lexical.html#SQL-SYNTAX-IDENTIFIERS) are created by enclosing an arbitrary sequence of characters in double-quotes ("). To create create a delimited identifier, create an `sql` tag function placeholder value using `sql.identifier`, e.g.

```js
sql`SELECT ${'foo'} FROM ${sql.identifier(['bar', 'baz'])}`;

// {
// sql: 'SELECT ? FROM "bar"."baz"',
// values: [
// 'foo'
// ]
// }

```

#### Guarding against accidental unescaped input

When using tagged template literals, it is easy to forget to add the `sql` tag, i.e.
Expand Down
17 changes: 17 additions & 0 deletions README.md
Expand Up @@ -306,6 +306,23 @@ connection.query('INSERT INTO reservation_ticket (reservation_id, ticket_id) VAL

```

<a name="slonik-value-placeholders-tagged-template-literals-creating-dynamic-delimited-identifiers"></a>
#### Creating dynamic delimited identifiers

[Delimited identifiers](https://www.postgresql.org/docs/current/static/sql-syntax-lexical.html#SQL-SYNTAX-IDENTIFIERS) are created by enclosing an arbitrary sequence of characters in double-quotes ("). To create create a delimited identifier, create an `sql` tag function placeholder value using `sql.identifier`, e.g.

```js
sql`SELECT ${'foo'} FROM ${sql.identifier(['bar', 'baz'])}`;

// {
// sql: 'SELECT ? FROM "bar"."baz"',
// values: [
// 'foo'
// ]
// }

```

<a name="slonik-value-placeholders-tagged-template-literals-guarding-against-accidental-unescaped-input"></a>
#### Guarding against accidental unescaped input

Expand Down
30 changes: 15 additions & 15 deletions package.json
Expand Up @@ -17,30 +17,30 @@
"pg": "^7.4.3",
"pg-connection-string": "^2.0.0",
"pretty-hrtime": "^1.0.3",
"roarr": "^2.3.0",
"roarr": "^2.5.0",
"serialize-error": "^2.1.0",
"stack-trace": "0.0.10",
"ulid": "^2.3.0"
},
"description": "A PostgreSQL client with strict types, detail logging and assertions.",
"devDependencies": {
"@babel/cli": "^7.0.0-beta.51",
"@babel/core": "^7.0.0-beta.51",
"@babel/plugin-transform-flow-strip-types": "^7.0.0-beta.51",
"@babel/preset-env": "^7.0.0-beta.51",
"@babel/register": "^7.0.0-beta.51",
"@babel/cli": "^7.0.0-beta.55",
"@babel/core": "^7.0.0-beta.55",
"@babel/plugin-transform-flow-strip-types": "^7.0.0-beta.55",
"@babel/preset-env": "^7.0.0-beta.55",
"@babel/register": "^7.0.0-beta.55",
"ava": "^1.0.0-beta.6",
"babel-plugin-istanbul": "^5.0.0",
"babel-plugin-istanbul": "^5.0.1",
"coveralls": "^3.0.2",
"eslint": "^5.0.1",
"eslint-config-canonical": "^10.3.2",
"flow-bin": "^0.75.0",
"flow-copy-source": "^2.0.1",
"eslint": "^5.2.0",
"eslint-config-canonical": "^11.0.0",
"flow-bin": "^0.77.0",
"flow-copy-source": "^2.0.2",
"gitdown": "^2.5.2",
"husky": "^1.0.0-rc.9",
"nyc": "^13.0.0",
"semantic-release": "^15.6.1",
"sinon": "^6.0.1"
"husky": "^1.0.0-rc.13",
"nyc": "^13.0.1",
"semantic-release": "^15.8.1",
"sinon": "^6.1.4"
},
"engines": {
"node": ">=8.0"
Expand Down
54 changes: 47 additions & 7 deletions src/index.js
Expand Up @@ -25,6 +25,7 @@ import {
UniqueIntegrityConstraintViolationError
} from './errors';
import {
escapeIdentifier,
mapTaggedTemplateLiteralInvocation,
normalizeAnonymousValuePlaceholders,
normalizeNamedValuePlaceholders,
Expand All @@ -46,6 +47,7 @@ import type {
InternalQueryOneFirstFunctionType,
InternalQueryOneFunctionType,
InternalTransactionFunctionType,
QueryIdentifierType,
TaggledTemplateLiteralInvocationType
} from './types';
import Logger from './Logger';
Expand Down Expand Up @@ -81,6 +83,50 @@ const log = Logger.child({

const ulid = ulidFactory(detectPrng(true));

const sql = (parts: $ReadOnlyArray<string>, ...values: $ReadOnlyArray<AnonymouseValuePlaceholderValueType>): TaggledTemplateLiteralInvocationType => {
let raw = '';

const bindings = [];

let index = 0;

for (const part of parts) {
const value = values[index++];

raw += part;

if (index >= parts.length) {
// eslint-disable-next-line no-continue
continue;
}

if (value && Array.isArray(value.names) && value.type === 'IDENTIFIER') {
raw += value.names.map(escapeIdentifier).join('.');

// eslint-disable-next-line no-continue
continue;
} else {
raw += '?';

bindings.push(value);
}
}

return {
sql: raw,
values: bindings
};
};

sql.identifier = (names: $ReadOnlyArray<string>): QueryIdentifierType => {
// @todo Replace `type` with a symbol once Flow adds symbol support
// @see https://github.com/facebook/flow/issues/810
return {
names,
type: 'IDENTIFIER'
};
};

export type {
DatabaseConnectionType,
DatabasePoolConnectionType,
Expand All @@ -96,6 +142,7 @@ export {
NotFoundError,
NotNullIntegrityConstraintViolationError,
SlonikError,
sql,
UniqueIntegrityConstraintViolationError
};

Expand Down Expand Up @@ -444,13 +491,6 @@ export const transaction: InternalTransactionFunctionType = async (connection, h
}
};

export const sql = (parts: $ReadOnlyArray<string>, ...values: $ReadOnlyArray<AnonymouseValuePlaceholderValueType>): TaggledTemplateLiteralInvocationType => {
return {
sql: parts.join('?'),
values
};
};

export const createConnection = async (
connectionConfiguration: DatabaseConfigurationType,
clientConfiguration: ClientConfigurationType = defaultClientConfiguration
Expand Down
8 changes: 7 additions & 1 deletion src/types.js
Expand Up @@ -88,14 +88,20 @@ export type NormalizedQueryType = {|
+values: $ReadOnlyArray<*>
|};

export type QueryIdentifierType = {|
names: $ReadOnlyArray<string>,
type: 'IDENTIFIER'
|};

type QueryPrimitiveValueType = string | number | null;

export type AnonymouseValuePlaceholderValueType =

// INSERT ... VALUES ? => INSERT ... VALUES (1, 2, 3); [[1, 2, 3]]
// INSERT ... VALUES ? => INSERT ... VALUES (1), (2), (3); [[[1], [2], [3]]]
$ReadOnlyArray<QueryPrimitiveValueType | $ReadOnlyArray<QueryPrimitiveValueType>> |
QueryPrimitiveValueType;
QueryPrimitiveValueType |
QueryIdentifierType;

export type NamedValuePlaceholderValuesType = {
+[key: string]: string | number | null
Expand Down
60 changes: 60 additions & 0 deletions test/slonik/sql.js
@@ -0,0 +1,60 @@
// @flow

import test from 'ava';
import {
sql
} from '../../src';

test('creates an object describing a query', (t) => {
const query = sql`SELECT 1`;

t.deepEqual(query, {
sql: 'SELECT 1',
values: []
});
});

test('creates an object describing query value bindings', (t) => {
const query = sql`SELECT ${'foo'}`;

t.deepEqual(query, {
sql: 'SELECT ?',
values: [
'foo'
]
});
});

test('creates an object describing query value bindings (multiple)', (t) => {
const query = sql`SELECT ${'foo'} FROM ${'bar'}`;

t.deepEqual(query, {
sql: 'SELECT ? FROM ?',
values: [
'foo',
'bar'
]
});
});

test('creates an object describing a query with inlined identifiers', (t) => {
const query = sql`SELECT ${'foo'} FROM ${sql.identifier(['bar'])}`;

t.deepEqual(query, {
sql: 'SELECT ? FROM "bar"',
values: [
'foo'
]
});
});

test('creates an object describing a query with inlined identifiers (specifier)', (t) => {
const query = sql`SELECT ${'foo'} FROM ${sql.identifier(['bar', 'baz'])}`;

t.deepEqual(query, {
sql: 'SELECT ? FROM "bar"."baz"',
values: [
'foo'
]
});
});

0 comments on commit 12aa9e9

Please sign in to comment.