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

user/support-filter-by-roles #398

Open
wants to merge 12 commits into
base: main
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
3 changes: 1 addition & 2 deletions packages/slonik/src/dbFilters.ts
Original file line number Diff line number Diff line change
@@ -1,8 +1,7 @@
import humps from "humps";
import { sql } from "slonik";

import { FilterInput } from "./types";

import type { FilterInput } from "./types";
import type { IdentifierSqlToken, FragmentSqlToken } from "slonik";

const applyFilter = (
Expand Down
7 changes: 7 additions & 0 deletions packages/user/README.md
Original file line number Diff line number Diff line change
Expand Up @@ -186,4 +186,11 @@ const config: ApiConfig = {
```
**_NOTE:_** Each above overrridden elements is a wrapper function. For example to override `emailPasswordSignUpPOST` see [emailPasswordSignUpPOST](src/supertokens/recipes/config/third-party-email-password/emailPasswordSignUpPost.ts).

## Filter users by roles
To filter users by roles in users endpoint, supported operators are `eq` and `in`. For example, following is the value of `filters` key for users endpoint.
```json
{"key": "roles", "operator": "eq", "value": "ADMIN"}
```
`value` is a string containing a single role or multiple roles joined by comma. Unsuppored operators will simply ignores the filtering.

## Context
170 changes: 170 additions & 0 deletions packages/user/src/model/users/dbFilters.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,170 @@
import humps from "humps";
import { sql } from "slonik";

import type { FilterInput } from "@dzangolab/fastify-slonik";
import type { IdentifierSqlToken, FragmentSqlToken } from "slonik";

const applyFilter = (
filter: FilterInput,
tableIdentifier: IdentifierSqlToken
) => {
const key = humps.decamelize(filter.key);
const operator = filter.operator || "eq";
const not = filter.not || false;
let value: FragmentSqlToken | string = filter.value;

const databaseField = sql.identifier([...tableIdentifier.names, key]);

let clauseOperator;

if (operator === "eq" && ["null", "NULL"].includes(value)) {
clauseOperator = not ? sql.fragment`IS NOT NULL` : sql.fragment`IS NULL`;

return sql.fragment`${databaseField} ${clauseOperator}`;
}

switch (operator) {
case "ct":
case "sw":
case "ew": {
const valueString = {
ct: `%${value}%`, // contains
ew: `%${value}`, // ends with
sw: `${value}%`, // starts with
};

value = valueString[operator];
clauseOperator = not ? sql.fragment`NOT ILIKE` : sql.fragment`ILIKE`;
break;
}
case "eq":
default: {
clauseOperator = not ? sql.fragment`!=` : sql.fragment`=`;
break;
}
case "gt": {
clauseOperator = not ? sql.fragment`<` : sql.fragment`>`;
break;
}
case "gte": {
clauseOperator = not ? sql.fragment`<` : sql.fragment`>=`;
break;
}
case "lte": {
clauseOperator = not ? sql.fragment`>` : sql.fragment`<=`;
break;
}
case "lt": {
clauseOperator = not ? sql.fragment`>` : sql.fragment`<`;
break;
}
case "in": {
clauseOperator = not ? sql.fragment`NOT IN` : sql.fragment`IN`;
value = sql.fragment`(${sql.join(value.split(","), sql.fragment`, `)})`;
break;
}
case "bt": {
clauseOperator = not ? sql.fragment`NOT BETWEEN` : sql.fragment`BETWEEN`;
value = sql.fragment`${sql.join(value.split(","), sql.fragment` AND `)}`;
break;
}
}

return sql.fragment`${databaseField} ${clauseOperator} ${value}`;
};

const applyFiltersToQuery = (
filters: FilterInput,
tableIdentifier: IdentifierSqlToken,
not = false
) => {
const andFilter: FragmentSqlToken[] = [];
const orFilter: FragmentSqlToken[] = [];
let queryFilter;

const applyFilters = (
filters: FilterInput,
tableIdentifier: IdentifierSqlToken,
not = false
) => {
if (filters.AND) {
for (const filterData of filters.AND) {
applyFilters(filterData, tableIdentifier);
}
} else if (filters.OR) {
for (const filterData of filters.OR) {
applyFilters(filterData, tableIdentifier, true);
}
} else {
const query =
humps.decamelize(filters.key) === "roles"
? applyRolesFilter(filters, tableIdentifier)
: applyFilter(filters, tableIdentifier);

if (not) {
orFilter.push(query);
} else {
andFilter.push(query);
}
}
};

applyFilters(filters, tableIdentifier, not);

if (andFilter.length > 0 && orFilter.length > 0) {
queryFilter = sql.join(
[
sql.fragment`(${sql.join(andFilter, sql.fragment` AND `)})`,
sql.fragment`(${sql.join(orFilter, sql.fragment` OR `)})`,
],
sql.fragment`${filters.AND ? sql.fragment` AND ` : sql.fragment` OR `}`
);
} else if (andFilter.length > 0) {
queryFilter = sql.join(andFilter, sql.fragment` AND `);
} else if (orFilter.length > 0) {
queryFilter = sql.join(orFilter, sql.fragment` OR `);
}

return queryFilter ? sql.fragment`WHERE ${queryFilter}` : sql.fragment``;
};

const applyRolesFilter = (
filter: FilterInput,
// eslint-disable-next-line @typescript-eslint/no-unused-vars
tableIdentifier: IdentifierSqlToken
) => {
const { operator, value } = filter;
const not = filter.not || false;

const notFragment = not ? sql.fragment`NOT` : sql.fragment``;

switch (operator) {
case "eq": {
const valueFragment = value.split(",").sort();

return sql.fragment`${notFragment}
(
SELECT jsonb_agg(value ORDER BY value) AS sorted_array
FROM jsonb_array_elements_text(user_role.role)
) = ${sql.jsonb(valueFragment)}`;
}

case "in": {
const valueFragment = sql.fragment`(${sql.join(
value.split(","),
sql.fragment`, `
)})`;

return sql.fragment`${notFragment} EXISTS
(
SELECT roles
FROM jsonb_array_elements_text(user_role.role) as roles
WHERE roles IN ${valueFragment}
)`;
}
}

return sql.fragment`TRUE`;
};

export { applyFiltersToQuery };
17 changes: 15 additions & 2 deletions packages/user/src/model/users/sql.ts
Original file line number Diff line number Diff line change
@@ -1,9 +1,22 @@
import humps from "humps";
import { sql } from "slonik";

import type { SortInput } from "@dzangolab/fastify-slonik";
import { applyFiltersToQuery } from "./dbFilters";

import type { FilterInput, SortInput } from "@dzangolab/fastify-slonik";
import type { IdentifierSqlToken } from "slonik";

const createFilterFragment = (
filters: FilterInput | undefined,
tableIdentifier: IdentifierSqlToken
) => {
if (filters) {
return applyFiltersToQuery(filters, tableIdentifier);
}

return sql.fragment``;
};

const createSortFragment = (
tableIdentifier: IdentifierSqlToken,
sort?: SortInput[]
Expand Down Expand Up @@ -60,4 +73,4 @@ const createSortRoleFragment = (
return sql.fragment`ORDER BY ${identifier} ${direction}`;
};

export { createSortFragment, createSortRoleFragment };
export { createFilterFragment, createSortFragment, createSortRoleFragment };
35 changes: 32 additions & 3 deletions packages/user/src/model/users/sqlFactory.ts
Original file line number Diff line number Diff line change
@@ -1,19 +1,24 @@
import {
DefaultSqlFactory,
createLimitFragment,
createFilterFragment,
createTableIdentifier,
} from "@dzangolab/fastify-slonik";
import humps from "humps";
import { QueryResultRow, QuerySqlToken, sql } from "slonik";
import { sql } from "slonik";
import { z } from "zod";

import { createSortFragment, createSortRoleFragment } from "./sql";
import {
createFilterFragment,
createSortFragment,
createSortRoleFragment,
} from "./sql";

import type {
SqlFactory,
FilterInput,
SortInput,
} from "@dzangolab/fastify-slonik";
import type { QueryResultRow, QuerySqlToken } from "slonik";

/* eslint-disable brace-style */
class UserSqlFactory<
Expand All @@ -26,6 +31,30 @@ class UserSqlFactory<
{
/* eslint-enabled */

getCountSql = (filters?: FilterInput): QuerySqlToken => {
const tableIdentifier = createTableIdentifier(this.table, this.schema);

const countSchema = z.object({
count: z.number(),
});

return sql.type(countSchema)`
SELECT COUNT(*)
FROM (
SELECT
${this.getTableFragment()}.*,
COALESCE(user_role.role, '[]') AS roles
FROM ${this.getTableFragment()}
LEFT JOIN LATERAL (
SELECT jsonb_agg(ur.role) AS role
FROM "public"."st__user_roles" as ur
WHERE ur.user_id = users.id
) AS user_role ON TRUE
${createFilterFragment(filters, tableIdentifier)}
) as count;
`;
};

getFindByIdSql = (id: number | string): QuerySqlToken => {
return sql.type(this.validationSchema)`
SELECT
Expand Down