Skip to content

Commit

Permalink
feat: pg-typed distinct (#216)
Browse files Browse the repository at this point in the history
  • Loading branch information
ForbesLindesay authored Jan 20, 2022
1 parent e8983f2 commit ab76428
Show file tree
Hide file tree
Showing 4 changed files with 198 additions and 145 deletions.
30 changes: 10 additions & 20 deletions docs/pg-bulk.md
Original file line number Diff line number Diff line change
Expand Up @@ -149,15 +149,11 @@ This is equivalent to:
```javascript
async function getUsers() {
await database.query(sql`
SELECT users.email, users.date_of_birth FROM users
INNER JOIN (
SELECT email, date_of_birth FROM users
WHERE (email, favorite_color) IN (
SELECT
UNNEST(${[`[email protected]`, `[email protected]`]}::TEXT[]) AS email,
UNNEST(${[`red`, `blue`]}::TEXT[]) AS favorite_color
) AS bulk_query
ON (
users.email=bulk_query.email
AND users.color=bulk_query.color
UNNEST(${['[email protected]', '[email protected]']}::TEXT[]),
UNNEST(${['red', 'blue']}::TEXT[])
)
ORDER BY email ASC
LIMIT 100
Expand Down Expand Up @@ -216,9 +212,9 @@ async function updateFavoriteColors() {
FROM
(
SELECT
UNNEST(${[`[email protected]`, `[email protected]`]}::TEXT[])
UNNEST(${['[email protected]', '[email protected]']}::TEXT[])
AS email,
UNNEST(${[`indigo`, `orange`]}::TEXT[])
UNNEST(${['indigo', 'orange']}::TEXT[])
AS updated_value_of_favorite_color
) AS bulk_query
WHERE
Expand Down Expand Up @@ -271,16 +267,10 @@ This is equivalent to:
async function getUsers() {
await database.query(sql`
DELETE FROM users
WHERE EXISTS(
SELECT *
FROM
(
UNNEST(${[`[email protected]`, `[email protected]`]}::TEXT[]) AS email,
UNNEST(${[`red`, `blue`]}::TEXT[]) AS favorite_color
) AS bulk_query
WHERE
users.email=bulk_query.email
AND users.color=bulk_query.color
WHERE (email, favorite_color) IN (
SELECT
UNNEST(${['[email protected]', '[email protected]']}::TEXT[]),
UNNEST(${['red', 'blue']}::TEXT[])
)
`);
}
Expand Down
23 changes: 23 additions & 0 deletions docs/pg-typed.md
Original file line number Diff line number Diff line change
Expand Up @@ -379,6 +379,29 @@ export async function getEmailsAlphabetical() {
}
```

### orderByAscDistinct(key) / orderByDescDistinct(key)

Sort the records by the provided key and only return the first occurrence of each key. You can chain multiple calls to `orderByAscDistinct` or `orderByDescDistinct` with different keys to require more columns to have distinct value.

```typescript
import db, {users} from './database';

export async function getLatestPostVersions() {
return await post_versions(db)
.find()
.orderByAscDistinct(`id`)
.orderByDesc(`version`)
.all();
}
export async function getOldestPostVersions() {
return await post_versions(db)
.find()
.orderByAscDistinct(`id`)
.orderByAsc(`version`)
.all();
}
```

### limit(count)

Return the first `count` rows. N.B. you can only use this method if you have first called `orderByAsc` or `orderByDesc` at least once.
Expand Down
140 changes: 59 additions & 81 deletions packages/pg-bulk/src/index.ts
Original file line number Diff line number Diff line change
Expand Up @@ -15,10 +15,14 @@ export interface BulkInsertOptions<TColumnToInsert extends ColumnName>
readonly records: readonly any[];
}

export interface BulkSelectOptions<TWhereColumn extends ColumnName>
export interface BulkConditionOptions<TWhereColumn extends ColumnName>
extends BulkOperationOptions<TWhereColumn> {
readonly whereColumnNames: readonly TWhereColumn[];
readonly whereConditions: readonly any[];
}
export interface BulkSelectOptions<TWhereColumn extends ColumnName>
extends BulkConditionOptions<TWhereColumn> {
readonly distinctColumnNames?: readonly string[];
readonly selectColumnNames?: readonly string[];
readonly orderBy?: readonly {
readonly columnName: string;
Expand All @@ -37,10 +41,7 @@ export interface BulkUpdateOptions<
}

export interface BulkDeleteOptions<TWhereColumn extends ColumnName>
extends BulkOperationOptions<TWhereColumn> {
readonly whereColumnNames: readonly TWhereColumn[];
readonly whereConditions: readonly any[];
}
extends BulkConditionOptions<TWhereColumn> {}

function tableId<TColumnName extends ColumnName>(
options: BulkOperationOptions<TColumnName>,
Expand All @@ -51,7 +52,7 @@ function tableId<TColumnName extends ColumnName>(
: sql.ident(options.tableName);
}

function selectionSet<TColumnName extends ColumnName>(
function select<TColumnName extends ColumnName>(
columns: readonly {
readonly name: TColumnName;
readonly alias?: ColumnName;
Expand All @@ -62,7 +63,7 @@ function selectionSet<TColumnName extends ColumnName>(
) {
const {database, columnTypes, serializeValue} = options;
const {sql} = database;
return sql.join(
return sql`SELECT ${sql.join(
columns.map(({name, alias, getValue}) => {
const typeName = columnTypes[name];
if (!typeName) {
Expand All @@ -74,39 +75,7 @@ function selectionSet<TColumnName extends ColumnName>(
})}::${typeName}[])${alias ? sql` AS ${sql.ident(alias)}` : sql``}`;
}),
`,`,
);
}

function selection<TColumnName extends ColumnName>(
columns: readonly {
readonly name: TColumnName;
readonly alias?: ColumnName;
readonly getValue?: (record: any) => unknown;
}[],
records: readonly any[],
options: BulkOperationOptions<TColumnName>,
) {
const {database} = options;
const {sql} = database;
return sql`(SELECT ${selectionSet(columns, records, options)}) AS bulk_query`;
}

function condition<TColumnName extends ColumnName>(
columnNames: readonly TColumnName[],
options: BulkOperationOptions<TColumnName>,
) {
const {database, tableName} = options;
const {sql} = database;
return sql.join(
columnNames.map(
(columnName) =>
sql`${sql.ident(tableName, columnName)} = ${sql.ident(
`bulk_query`,
columnName,
)}`,
),
` AND `,
);
)}`;
}

export async function bulkInsert<TColumnToInsert extends ColumnName>(
Expand All @@ -118,53 +87,59 @@ export async function bulkInsert<TColumnToInsert extends ColumnName>(
sql`INSERT INTO ${tableId(options)} (${sql.join(
columnsToInsert.map((columnName) => sql.ident(columnName)),
`,`,
)}) SELECT ${selectionSet(
)}) ${select(
columnsToInsert.map((name) => ({name})),
records,
options,
)}`,
);
}

export function bulkCondition<TWhereColumn extends ColumnName>(
options: BulkConditionOptions<TWhereColumn>,
): SQLQuery {
const {database, whereColumnNames, whereConditions} = options;
const {sql} = database;
return sql`(${sql.join(
whereColumnNames.map((columnName) => sql.ident(columnName)),
`,`,
)}) IN (${select(
whereColumnNames.map((columnName) => ({name: columnName})),
whereConditions,
options,
)})`;
}

export async function bulkSelect<TWhereColumn extends ColumnName>(
options: BulkSelectOptions<TWhereColumn>,
): Promise<any[]> {
const {
database,
tableName,
whereColumnNames,
whereConditions,
selectColumnNames,
orderBy,
limit,
} = options;
const {database, distinctColumnNames, selectColumnNames, orderBy, limit} =
options;
const {sql} = database;
return await database.query(
sql.join(
[
sql`SELECT ${
selectColumnNames
? sql.join(
selectColumnNames.map((columnName) =>
sql.ident(tableName, columnName),
),
',',
)
: sql`${sql.ident(tableName)}.*`
} FROM ${tableId(options)} INNER JOIN ${selection(
whereColumnNames.map((columnName) => ({
name: columnName,
alias: columnName,
})),
whereConditions,
options,
)} ON (${condition(whereColumnNames, options)})`,
sql`SELECT`,
distinctColumnNames?.length
? sql`DISTINCT ON (${sql.join(
distinctColumnNames.map((columnName) => sql.ident(columnName)),
`,`,
)})`
: null,
selectColumnNames
? sql.join(
selectColumnNames.map((columnName) => sql.ident(columnName)),
',',
)
: sql`*`,
sql`FROM ${tableId(options)} WHERE`,
bulkCondition(options),
orderBy?.length
? sql`ORDER BY ${sql.join(
orderBy.map((q) =>
q.direction === 'ASC'
? sql`${sql.ident(tableName, q.columnName)} ASC`
: sql`${sql.ident(tableName, q.columnName)} DESC`,
? sql`${sql.ident(q.columnName)} ASC`
: sql`${sql.ident(q.columnName)} DESC`,
),
sql`, `,
)}`
Expand All @@ -180,7 +155,8 @@ export async function bulkUpdate<
TWhereColumn extends ColumnName,
TSetColumn extends ColumnName,
>(options: BulkUpdateOptions<TWhereColumn, TSetColumn>): Promise<void> {
const {database, whereColumnNames, setColumnNames, updates} = options;
const {database, tableName, whereColumnNames, setColumnNames, updates} =
options;
const {sql} = database;
await database.query(
sql`UPDATE ${tableId(options)} SET ${sql.join(
Expand All @@ -192,7 +168,7 @@ export async function bulkUpdate<
)}`,
),
`,`,
)} FROM ${selection(
)} FROM (${select(
[
...whereColumnNames.map((columnName) => ({
name: columnName,
Expand All @@ -207,23 +183,25 @@ export async function bulkUpdate<
],
updates,
options,
)} WHERE ${condition(whereColumnNames, options)}`,
)}) AS bulk_query WHERE ${sql.join(
whereColumnNames.map(
(columnName) =>
sql`${sql.ident(tableName, columnName)} = ${sql.ident(
`bulk_query`,
columnName,
)}`,
),
` AND `,
)}`,
);
}

export async function bulkDelete<TWhereColumn extends ColumnName>(
options: BulkDeleteOptions<TWhereColumn>,
): Promise<void> {
const {database, whereColumnNames, whereConditions} = options;
const {database} = options;
const {sql} = database;
await database.query(
sql`DELETE FROM ${tableId(options)} WHERE EXISTS (SELECT * FROM ${selection(
whereColumnNames.map((columnName) => ({
name: columnName,
alias: columnName,
})),
whereConditions,
options,
)} WHERE ${condition(whereColumnNames, options)})`,
sql`DELETE FROM ${tableId(options)} WHERE ${bulkCondition(options)}`,
);
}
Loading

0 comments on commit ab76428

Please sign in to comment.