diff --git a/.github/workflows/pg-meta-tests.yml b/.github/workflows/pg-meta-tests.yml new file mode 100644 index 0000000000..2392fc049c --- /dev/null +++ b/.github/workflows/pg-meta-tests.yml @@ -0,0 +1,50 @@ +name: PG Meta Tests + +on: + push: + branches: ['master'] + paths: + - 'packages/pg-meta/**/*' + pull_request: + branches: ['master'] + paths: + - 'packages/pg-meta/**/*' + +# Cancel old builds on new commit for same workflow + branch/PR +concurrency: + group: ${{ github.workflow }}-${{ github.event.pull_request.number || github.ref }} + cancel-in-progress: true + +jobs: + build: + runs-on: ubuntu-latest + + steps: + - uses: actions/checkout@v4 + with: + sparse-checkout: | + packages/pg-meta + packages/tsconfig + + - uses: pnpm/action-setup@v4 + name: Install pnpm + with: + run_install: false + + - name: Use Node.js + uses: actions/setup-node@v4 + with: + node-version-file: '.nvmrc' + cache: 'pnpm' + + - name: Install deps + run: pnpm i + + - name: Run tests + run: pnpm --filter=@supabase/pg-meta run test + + - name: Upload coverage to Codecov + uses: codecov/codecov-action@v3 + with: + directory: packages/pg-meta/coverage + flags: pg-meta diff --git a/.github/workflows/studio-e2e-tests.yml b/.github/workflows/studio-e2e-tests.yml index 163c42dbe0..8ae25f750f 100644 --- a/.github/workflows/studio-e2e-tests.yml +++ b/.github/workflows/studio-e2e-tests.yml @@ -3,12 +3,14 @@ on: push: branches: [master] paths: + - 'packages/pg-meta/**/*' - 'apps/studio/**' - 'tests/studio-tests/**' - 'pnpm-lock.yaml' pull_request: branches: [master] paths: + - 'packages/pg-meta/**/*' - 'apps/studio/**' - 'tests/studio-tests/**' - 'pnpm-lock.yaml' diff --git a/apps/studio/components/grid/types/base.ts b/apps/studio/components/grid/types/base.ts index 9ac3866680..b66be2b9b7 100644 --- a/apps/studio/components/grid/types/base.ts +++ b/apps/studio/components/grid/types/base.ts @@ -1,32 +1,6 @@ +import { Filter, Sort } from '@supabase/pg-meta/src/query' import { CalculatedColumn, RenderHeaderCellProps } from 'react-data-grid' -export interface Sort { - table: string - column: string - ascending?: boolean - nullsFirst?: boolean -} - -export type FilterOperator = - | '=' - | '<>' - | '>' - | '<' - | '>=' - | '<=' - | '~~' - | '~~*' - | '!~~' - | '!~~*' - | 'in' - | 'is' - -export interface Filter { - column: string - operator: FilterOperator - value: any -} - export interface SavedState { filters: Filter[] sorts: Sort[] diff --git a/apps/studio/components/grid/types/index.ts b/apps/studio/components/grid/types/index.ts index b97605e07b..4d0a436e95 100644 --- a/apps/studio/components/grid/types/index.ts +++ b/apps/studio/components/grid/types/index.ts @@ -1,5 +1,5 @@ +export type * from '@supabase/pg-meta/src/query' export type * from './base' export type * from './grid' -export type * from './query' export type * from './service' export type * from './table' diff --git a/apps/studio/components/grid/types/query.ts b/apps/studio/components/grid/types/query.ts deleted file mode 100644 index 2d688965e4..0000000000 --- a/apps/studio/components/grid/types/query.ts +++ /dev/null @@ -1,9 +0,0 @@ -export interface QueryTable { - name: string - schema: string -} - -export interface QueryPagination { - limit: number - offset: number -} diff --git a/apps/studio/components/interfaces/TableGridEditor/SidePanelEditor/SidePanelEditor.utils.tsx b/apps/studio/components/interfaces/TableGridEditor/SidePanelEditor/SidePanelEditor.utils.tsx index a09f6ca4ce..85642d798a 100644 --- a/apps/studio/components/interfaces/TableGridEditor/SidePanelEditor/SidePanelEditor.utils.tsx +++ b/apps/studio/components/interfaces/TableGridEditor/SidePanelEditor/SidePanelEditor.utils.tsx @@ -3,7 +3,7 @@ import { chunk, find, isEmpty, isEqual } from 'lodash' import Papa from 'papaparse' import { toast } from 'sonner' -import { Query } from 'components/grid/query/Query' +import { Query } from '@supabase/pg-meta/src/query' import SparkBar from 'components/ui/SparkBar' import { createDatabaseColumn } from 'data/database-columns/database-column-create-mutation' import { deleteDatabaseColumn } from 'data/database-columns/database-column-delete-mutation' diff --git a/apps/studio/data/pg-sodium-keys/pg-sodium-key-delete-mutation.ts b/apps/studio/data/pg-sodium-keys/pg-sodium-key-delete-mutation.ts index b88e103814..32d42c08b0 100644 --- a/apps/studio/data/pg-sodium-keys/pg-sodium-key-delete-mutation.ts +++ b/apps/studio/data/pg-sodium-keys/pg-sodium-key-delete-mutation.ts @@ -1,7 +1,7 @@ import { useMutation, UseMutationOptions, useQueryClient } from '@tanstack/react-query' import { toast } from 'sonner' -import { Query } from 'components/grid/query/Query' +import { Query } from '@supabase/pg-meta/src/query' import { executeSql } from 'data/sql/execute-sql-query' import type { ResponseError } from 'types' import { pgSodiumKeys } from './keys' diff --git a/apps/studio/data/pg-sodium-keys/pg-sodium-keys-query.ts b/apps/studio/data/pg-sodium-keys/pg-sodium-keys-query.ts index 517ecac033..c6bfbc5269 100644 --- a/apps/studio/data/pg-sodium-keys/pg-sodium-keys-query.ts +++ b/apps/studio/data/pg-sodium-keys/pg-sodium-keys-query.ts @@ -1,5 +1,5 @@ import { UseQueryOptions, useQuery } from '@tanstack/react-query' -import { Query } from 'components/grid/query/Query' +import { Query } from '@supabase/pg-meta/src/query' import { sortBy } from 'lodash' import { executeSql } from '../sql/execute-sql-query' import { pgSodiumKeys } from './keys' diff --git a/apps/studio/data/table-rows/get-cell-value-mutation.ts b/apps/studio/data/table-rows/get-cell-value-mutation.ts index 7c22ef6855..656325846e 100644 --- a/apps/studio/data/table-rows/get-cell-value-mutation.ts +++ b/apps/studio/data/table-rows/get-cell-value-mutation.ts @@ -1,7 +1,7 @@ import { useMutation, UseMutationOptions } from '@tanstack/react-query' import { toast } from 'sonner' -import { Query } from 'components/grid/query/Query' +import { Query } from '@supabase/pg-meta/src/query' import { executeSql } from 'data/sql/execute-sql-query' import type { ResponseError } from 'types' diff --git a/apps/studio/data/table-rows/table-row-create-mutation.ts b/apps/studio/data/table-rows/table-row-create-mutation.ts index 6dce6c2b5d..aa254dd82b 100644 --- a/apps/studio/data/table-rows/table-row-create-mutation.ts +++ b/apps/studio/data/table-rows/table-row-create-mutation.ts @@ -1,7 +1,7 @@ import { useMutation, UseMutationOptions, useQueryClient } from '@tanstack/react-query' import { toast } from 'sonner' -import { Query } from 'components/grid/query/Query' +import { Query } from '@supabase/pg-meta/src/query' import { executeSql } from 'data/sql/execute-sql-query' import { ImpersonationRole, wrapWithRoleImpersonation } from 'lib/role-impersonation' import { isRoleImpersonationEnabled } from 'state/role-impersonation-state' diff --git a/apps/studio/data/table-rows/table-row-delete-all-mutation.ts b/apps/studio/data/table-rows/table-row-delete-all-mutation.ts index c09c65708a..1d7df3e3e2 100644 --- a/apps/studio/data/table-rows/table-row-delete-all-mutation.ts +++ b/apps/studio/data/table-rows/table-row-delete-all-mutation.ts @@ -1,7 +1,7 @@ import { useMutation, UseMutationOptions, useQueryClient } from '@tanstack/react-query' import { toast } from 'sonner' -import { Query } from 'components/grid/query/Query' +import { Query } from '@supabase/pg-meta/src/query' import type { Filter, SupaTable } from 'components/grid/types' import { executeSql } from 'data/sql/execute-sql-query' import { ImpersonationRole, wrapWithRoleImpersonation } from 'lib/role-impersonation' diff --git a/apps/studio/data/table-rows/table-row-delete-mutation.tsx b/apps/studio/data/table-rows/table-row-delete-mutation.tsx index f79dfc45f3..9e5bbfa4a1 100644 --- a/apps/studio/data/table-rows/table-row-delete-mutation.tsx +++ b/apps/studio/data/table-rows/table-row-delete-mutation.tsx @@ -1,7 +1,7 @@ import { useMutation, UseMutationOptions, useQueryClient } from '@tanstack/react-query' import { toast } from 'sonner' -import { Query } from 'components/grid/query/Query' +import { Query } from '@supabase/pg-meta/src/query' import type { SupaRow } from 'components/grid/types' import { Markdown } from 'components/interfaces/Markdown' import { DocsButton } from 'components/ui/DocsButton' diff --git a/apps/studio/data/table-rows/table-row-truncate-mutation.ts b/apps/studio/data/table-rows/table-row-truncate-mutation.ts index f00ddc1153..b39c2816c9 100644 --- a/apps/studio/data/table-rows/table-row-truncate-mutation.ts +++ b/apps/studio/data/table-rows/table-row-truncate-mutation.ts @@ -1,7 +1,7 @@ import { useMutation, UseMutationOptions, useQueryClient } from '@tanstack/react-query' import { toast } from 'sonner' -import { Query } from 'components/grid/query/Query' +import { Query } from '@supabase/pg-meta/src/query' import { executeSql } from 'data/sql/execute-sql-query' import type { ResponseError } from 'types' import { tableRowKeys } from './keys' diff --git a/apps/studio/data/table-rows/table-row-update-mutation.ts b/apps/studio/data/table-rows/table-row-update-mutation.ts index e5c4470cdd..ec82b06dd0 100644 --- a/apps/studio/data/table-rows/table-row-update-mutation.ts +++ b/apps/studio/data/table-rows/table-row-update-mutation.ts @@ -1,7 +1,7 @@ import { useMutation, UseMutationOptions, useQueryClient } from '@tanstack/react-query' import { toast } from 'sonner' -import { Query } from 'components/grid/query/Query' +import { Query } from '@supabase/pg-meta/src/query' import { executeSql } from 'data/sql/execute-sql-query' import { ImpersonationRole, wrapWithRoleImpersonation } from 'lib/role-impersonation' import { isRoleImpersonationEnabled } from 'state/role-impersonation-state' diff --git a/apps/studio/data/table-rows/table-rows-count-query.ts b/apps/studio/data/table-rows/table-rows-count-query.ts index 39b9de1490..c6b782e864 100644 --- a/apps/studio/data/table-rows/table-rows-count-query.ts +++ b/apps/studio/data/table-rows/table-rows-count-query.ts @@ -1,5 +1,5 @@ import { QueryClient, useQuery, useQueryClient, type UseQueryOptions } from '@tanstack/react-query' -import { Query } from 'components/grid/query/Query' +import { Query } from '@supabase/pg-meta/src/query' import { parseSupaTable } from 'components/grid/SupabaseGrid.utils' import type { Filter, SupaTable } from 'components/grid/types' import { prefetchTableEditor } from 'data/table-editor/table-editor-query' diff --git a/apps/studio/data/table-rows/table-rows-query.ts b/apps/studio/data/table-rows/table-rows-query.ts index 407e9af6a0..48be5a9331 100644 --- a/apps/studio/data/table-rows/table-rows-query.ts +++ b/apps/studio/data/table-rows/table-rows-query.ts @@ -6,7 +6,7 @@ import { } from '@tanstack/react-query' import { IS_PLATFORM } from 'common' -import { Query } from 'components/grid/query/Query' +import { Query } from '@supabase/pg-meta/src/query' import { parseSupaTable } from 'components/grid/SupabaseGrid.utils' import { Filter, Sort, SupaRow, SupaTable } from 'components/grid/types' import { diff --git a/apps/studio/data/vault/vault-secret-decrypted-value-query.ts b/apps/studio/data/vault/vault-secret-decrypted-value-query.ts index 1626084d5c..6f6e251d3f 100644 --- a/apps/studio/data/vault/vault-secret-decrypted-value-query.ts +++ b/apps/studio/data/vault/vault-secret-decrypted-value-query.ts @@ -1,5 +1,5 @@ import { UseQueryOptions, useQuery } from '@tanstack/react-query' -import { Query } from 'components/grid/query/Query' +import { Query } from '@supabase/pg-meta/src/query' import { executeSql } from '../sql/execute-sql-query' import { vaultSecretsKeys } from './keys' diff --git a/apps/studio/data/vault/vault-secret-delete-mutation.ts b/apps/studio/data/vault/vault-secret-delete-mutation.ts index 975add08f3..ffe67f278b 100644 --- a/apps/studio/data/vault/vault-secret-delete-mutation.ts +++ b/apps/studio/data/vault/vault-secret-delete-mutation.ts @@ -1,7 +1,7 @@ import { useMutation, UseMutationOptions, useQueryClient } from '@tanstack/react-query' import { toast } from 'sonner' -import { Query } from 'components/grid/query/Query' +import { Query } from '@supabase/pg-meta/src/query' import { executeSql } from 'data/sql/execute-sql-query' import type { ResponseError } from 'types' import { vaultSecretsKeys } from './keys' diff --git a/apps/studio/data/vault/vault-secrets-query.ts b/apps/studio/data/vault/vault-secrets-query.ts index 2945d21360..52ed122970 100644 --- a/apps/studio/data/vault/vault-secrets-query.ts +++ b/apps/studio/data/vault/vault-secrets-query.ts @@ -1,5 +1,5 @@ import { useQuery, UseQueryOptions } from '@tanstack/react-query' -import { Query } from 'components/grid/query/Query' +import { Query } from '@supabase/pg-meta/src/query' import type { VaultSecret } from 'types' import { executeSql, ExecuteSqlError } from '../sql/execute-sql-query' import { vaultSecretsKeys } from './keys' diff --git a/packages/pg-meta/package.json b/packages/pg-meta/package.json index 9f509e4285..c66713180a 100644 --- a/packages/pg-meta/package.json +++ b/packages/pg-meta/package.json @@ -12,7 +12,8 @@ "db:clean": "cd test/db && docker compose down", "db:run": "cd test/db && docker compose up --detach --wait", "test:run": "vitest run --coverage", - "test:update": "vitest run --update" + "test:update": "vitest run --update", + "lint": "tsc --noEmit" }, "dependencies": { "zod": "^3.22.4" diff --git a/packages/pg-meta/src/index.ts b/packages/pg-meta/src/index.ts index 553ae5ee87..0e59579b8a 100644 --- a/packages/pg-meta/src/index.ts +++ b/packages/pg-meta/src/index.ts @@ -16,6 +16,7 @@ import types from './pg-meta-types' import version from './pg-meta-version' import indexes from './pg-meta-indexes' import columnPrivileges from './pg-meta-column-privileges' +import * as query from './query/index' export default { roles, @@ -36,4 +37,5 @@ export default { version, indexes, columnPrivileges, + query, } diff --git a/apps/studio/components/grid/query/Query.ts b/packages/pg-meta/src/query/Query.ts similarity index 100% rename from apps/studio/components/grid/query/Query.ts rename to packages/pg-meta/src/query/Query.ts diff --git a/apps/studio/components/grid/query/Query.utils.ts b/packages/pg-meta/src/query/Query.utils.ts similarity index 91% rename from apps/studio/components/grid/query/Query.utils.ts rename to packages/pg-meta/src/query/Query.utils.ts index aeb1cb50de..f83a56ba26 100644 --- a/apps/studio/components/grid/query/Query.utils.ts +++ b/packages/pg-meta/src/query/Query.utils.ts @@ -1,6 +1,5 @@ -import { format, ident, literal } from '@supabase/pg-meta/src/pg-format' -import type { Dictionary } from 'types' -import type { Filter, QueryPagination, QueryTable, Sort } from '../types' +import { ident, literal, format } from '../pg-format' +import type { Filter, QueryPagination, QueryTable, Sort, Dictionary } from './types' export function countQuery( table: QueryTable, @@ -51,7 +50,7 @@ export function deleteQuery( query += enumArrayColumns === undefined || enumArrayColumns.length === 0 ? ` returning *` - : ` returning *, ${enumArrayColumns.map((x) => `"${x}"::text[]`).join(',')}` + : ` returning *, ${enumArrayColumns.map((x) => `${ident(x)}::text[]`).join(',')}` } return query + ';' } @@ -90,7 +89,7 @@ export function insertQuery( query += enumArrayColumns === undefined || enumArrayColumns.length === 0 ? ` returning *` - : ` returning *, ${enumArrayColumns.map((x) => `"${x}"::text[]`).join(',')}` + : ` returning *, ${enumArrayColumns.map((x) => `${ident(x)}::text[]`).join(',')}` } return query + ';' } @@ -151,7 +150,7 @@ export function updateQuery( query += enumArrayColumns === undefined || enumArrayColumns.length === 0 ? ` returning *` - : ` returning *, ${enumArrayColumns.map((x) => `"${x}"::text[]`).join(',')}` + : ` returning *, ${enumArrayColumns.map((x) => `${ident(x)}::text[]`).join(',')}` } return query + ';' @@ -218,10 +217,10 @@ function filterLiteral(value: any) { //============================================================ function applySorts(query: string, sorts: Sort[]) { - if (sorts.length === 0) return query - query += ` order by ${sorts + const validSorts = sorts.filter((sort) => sort.column) + if (validSorts.length === 0) return query + query += ` order by ${validSorts .map((x) => { - if (!x.column) return null const order = x.ascending ? 'asc' : 'desc' const nullOrder = x.nullsFirst ? 'nulls first' : 'nulls last' return `${ident(x.table)}.${ident(x.column)} ${order} ${nullOrder}` diff --git a/apps/studio/components/grid/query/QueryAction.ts b/packages/pg-meta/src/query/QueryAction.ts similarity index 96% rename from apps/studio/components/grid/query/QueryAction.ts rename to packages/pg-meta/src/query/QueryAction.ts index cddc6acb0a..82141c3abe 100644 --- a/apps/studio/components/grid/query/QueryAction.ts +++ b/packages/pg-meta/src/query/QueryAction.ts @@ -1,5 +1,4 @@ -import type { QueryTable } from '../types' -import type { Dictionary } from 'types' +import type { QueryTable, Dictionary } from './types' import { IQueryFilter, QueryFilter } from './QueryFilter' export interface IQueryAction { diff --git a/apps/studio/components/grid/query/QueryFilter.ts b/packages/pg-meta/src/query/QueryFilter.ts similarity index 93% rename from apps/studio/components/grid/query/QueryFilter.ts rename to packages/pg-meta/src/query/QueryFilter.ts index f3754b9f27..189e58feab 100644 --- a/apps/studio/components/grid/query/QueryFilter.ts +++ b/packages/pg-meta/src/query/QueryFilter.ts @@ -1,5 +1,4 @@ -import type { Dictionary } from 'types' -import type { Filter, FilterOperator, QueryTable, Sort } from '../types' +import type { Filter, FilterOperator, QueryTable, Sort, Dictionary } from './types' import { IQueryModifier, QueryModifier } from './QueryModifier' export interface IQueryFilter { diff --git a/apps/studio/components/grid/query/QueryModifier.ts b/packages/pg-meta/src/query/QueryModifier.ts similarity index 95% rename from apps/studio/components/grid/query/QueryModifier.ts rename to packages/pg-meta/src/query/QueryModifier.ts index 52eb3b7940..605da26218 100644 --- a/apps/studio/components/grid/query/QueryModifier.ts +++ b/packages/pg-meta/src/query/QueryModifier.ts @@ -1,5 +1,4 @@ -import type { Dictionary } from 'types' -import type { Filter, QueryPagination, QueryTable, Sort } from '../types' +import type { Filter, QueryPagination, QueryTable, Sort, Dictionary } from './types' import { countQuery, deleteQuery, diff --git a/packages/pg-meta/src/query/index.ts b/packages/pg-meta/src/query/index.ts new file mode 100644 index 0000000000..c48eadd865 --- /dev/null +++ b/packages/pg-meta/src/query/index.ts @@ -0,0 +1,6 @@ +export * from './Query' +export * from './Query.utils' +export * from './QueryFilter' +export * from './QueryAction' +export * from './QueryModifier' +export type * from './types' diff --git a/packages/pg-meta/src/query/types.ts b/packages/pg-meta/src/query/types.ts new file mode 100644 index 0000000000..7e0045cdb8 --- /dev/null +++ b/packages/pg-meta/src/query/types.ts @@ -0,0 +1,40 @@ +export interface Sort { + table: string + column: string + ascending?: boolean + nullsFirst?: boolean +} + +export type FilterOperator = + | '=' + | '<>' + | '>' + | '<' + | '>=' + | '<=' + | '~~' + | '~~*' + | '!~~' + | '!~~*' + | 'in' + | 'is' + +export interface Filter { + column: string + operator: FilterOperator + value: any +} + +export interface Dictionary { + [Key: string]: T +} + +export interface QueryTable { + name: string + schema: string +} + +export interface QueryPagination { + limit: number + offset: number +} diff --git a/packages/pg-meta/test/query/advanced-query.test.ts b/packages/pg-meta/test/query/advanced-query.test.ts new file mode 100644 index 0000000000..20537cbbbc --- /dev/null +++ b/packages/pg-meta/test/query/advanced-query.test.ts @@ -0,0 +1,587 @@ +import { expect, test, describe, afterAll } from 'vitest' +import { Query } from '../../src/query/Query' +import { createTestDatabase, cleanupRoot } from '../db/utils' + +type TestDb = Awaited> + +async function validateSql(db: TestDb, sql: string): Promise { + try { + const result = await db.executeQuery(sql) + return result + } catch (error) { + throw new Error(`Invalid SQL generated: ${sql}\nError: ${error}`) + } +} + +const withTestDatabase = (name: string, fn: (db: TestDb) => Promise) => { + test(name, async () => { + const db = await createTestDatabase() + try { + // Setup test tables with special characters, spaces, and quotes + await db.executeQuery(` + CREATE TABLE "public"."normal_table" ( + id SERIAL PRIMARY KEY, + name TEXT + ); + + CREATE TABLE "public"."table with spaces" ( + id SERIAL PRIMARY KEY, + "column with spaces" TEXT, + "quoted""column" TEXT, + "quoted'column" TEXT, + "camelCaseColumn" TEXT, + "special#$%^&Column" TEXT + ); + + CREATE TABLE "public"."quoted""table" ( + id SERIAL PRIMARY KEY, + name TEXT + ); + + CREATE TABLE "public"."quoted'table" ( + id SERIAL PRIMARY KEY, + name TEXT + ); + + CREATE TABLE "public"."camelCaseTable" ( + id SERIAL PRIMARY KEY, + name TEXT + ); + + CREATE TABLE "public"."special#$%^&Table" ( + id SERIAL PRIMARY KEY, + name TEXT + ); + `) + + // Insert test data into each table + await db.executeQuery(` + -- Add data to normal_table + INSERT INTO "public"."normal_table" (name) + VALUES + ('John Doe'), + ('Jane Smith'), + ('O''Reilly Books'), + (NULL); + + -- Add data to table with spaces + INSERT INTO "public"."table with spaces" ( + "column with spaces", + "quoted""column", + "quoted'column", + "camelCaseColumn", + "special#$%^&Column" + ) + VALUES + ('value with spaces', 'value with "quotes"', 'value with ''quotes''', 'camelCaseValue', 'special#$%^&Value'), + ('another value', 'another "quoted" value', 'another ''quoted'' value', 'anotherCamelCase', 'another#$%^&'); + + -- Add data to quoted"table + INSERT INTO "public"."quoted""table" (name) + VALUES + ('quoted table row 1'), + ('quoted table row 2'); + + -- Add data to quoted'table + INSERT INTO "public"."quoted'table" (name) + VALUES + ('single quoted table row 1'), + ('single quoted table row 2'); + + -- Add data to camelCaseTable + INSERT INTO "public"."camelCaseTable" (name) + VALUES + ('camel case table row 1'), + ('camel case table row 2'); + + -- Add data to special#$%^&Table + INSERT INTO "public"."special#$%^&Table" (name) + VALUES + ('special char table row 1'), + ('special char table row 2'); + `) + + await fn(db) + } finally { + await db.cleanup() + } + }) +} + +describe('Advanced Query Tests', () => { + afterAll(async () => { + await cleanupRoot() + }) + + describe('Special Table and Column Names', () => { + withTestDatabase('should handle tables with spaces', async (db) => { + const query = new Query() + const sql = query.from('table with spaces', 'public').select('*').toSql() + + expect(sql).toMatchInlineSnapshot('"select * from public."table with spaces";"') + const result = await validateSql(db, sql) + expect(result.length).toBe(2) + expect(result[0]['column with spaces']).toBe('value with spaces') + expect(result[1]['column with spaces']).toBe('another value') + }) + + withTestDatabase('should handle tables with double quotes', async (db) => { + const query = new Query() + const sql = query.from('quoted"table', 'public').select('*').toSql() + + expect(sql).toMatchInlineSnapshot('"select * from public."quoted""table";"') + const result = await validateSql(db, sql) + expect(result.length).toBe(2) + expect(result[0].name).toBe('quoted table row 1') + expect(result[1].name).toBe('quoted table row 2') + }) + + withTestDatabase('should handle tables with single quotes', async (db) => { + const query = new Query() + const sql = query.from("quoted'table", 'public').select('*').toSql() + + expect(sql).toMatchInlineSnapshot('"select * from public."quoted\'table";"') + const result = await validateSql(db, sql) + expect(result.length).toBe(2) + expect(result[0].name).toBe('single quoted table row 1') + expect(result[1].name).toBe('single quoted table row 2') + }) + + withTestDatabase('should handle camelCase table names', async (db) => { + const query = new Query() + const sql = query.from('camelCaseTable', 'public').select('*').toSql() + + expect(sql).toMatchInlineSnapshot('"select * from public."camelCaseTable";"') + const result = await validateSql(db, sql) + expect(result.length).toBe(2) + expect(result[0].name).toBe('camel case table row 1') + expect(result[1].name).toBe('camel case table row 2') + }) + + withTestDatabase('should handle tables with special characters', async (db) => { + const query = new Query() + const sql = query.from('special#$%^&Table', 'public').select('*').toSql() + + expect(sql).toMatchInlineSnapshot('"select * from public."special#$%^&Table";"') + const result = await validateSql(db, sql) + expect(result.length).toBe(2) + expect(result[0].name).toBe('special char table row 1') + expect(result[1].name).toBe('special char table row 2') + }) + + withTestDatabase('should handle columns with spaces', async (db) => { + const query = new Query() + const sql = query.from('table with spaces', 'public').select('"column with spaces"').toSql() + + expect(sql).toMatchInlineSnapshot( + '"select "column with spaces" from public."table with spaces";"' + ) + const result = await validateSql(db, sql) + expect(result.length).toBe(2) + expect(result[0]['column with spaces']).toBe('value with spaces') + expect(result[1]['column with spaces']).toBe('another value') + }) + + withTestDatabase('should handle columns with double quotes', async (db) => { + const query = new Query() + const sql = query.from('table with spaces', 'public').select('"quoted""column"').toSql() + + expect(sql).toMatchInlineSnapshot( + '"select "quoted""column" from public."table with spaces";"' + ) + const result = await validateSql(db, sql) + expect(result.length).toBe(2) + expect(result[0]['quoted"column']).toBe('value with "quotes"') + expect(result[1]['quoted"column']).toBe('another "quoted" value') + }) + + withTestDatabase('should handle columns with single quotes', async (db) => { + const query = new Query() + const sql = query.from('table with spaces', 'public').select('"quoted\'column"').toSql() + + expect(sql).toMatchInlineSnapshot( + '"select "quoted\'column" from public."table with spaces";"' + ) + const result = await validateSql(db, sql) + expect(result.length).toBe(2) + expect(result[0]["quoted'column"]).toBe("value with 'quotes'") + expect(result[1]["quoted'column"]).toBe("another 'quoted' value") + }) + + withTestDatabase('should handle camelCase column names', async (db) => { + const query = new Query() + const sql = query.from('table with spaces', 'public').select('"camelCaseColumn"').toSql() + + expect(sql).toMatchInlineSnapshot( + '"select "camelCaseColumn" from public."table with spaces";"' + ) + const result = await validateSql(db, sql) + expect(result.length).toBe(2) + expect(result[0].camelCaseColumn).toBe('camelCaseValue') + expect(result[1].camelCaseColumn).toBe('anotherCamelCase') + }) + + withTestDatabase('should handle columns with special characters', async (db) => { + const query = new Query() + const sql = query.from('table with spaces', 'public').select('"special#$%^&Column"').toSql() + + expect(sql).toMatchInlineSnapshot( + '"select "special#$%^&Column" from public."table with spaces";"' + ) + const result = await validateSql(db, sql) + expect(result.length).toBe(2) + expect(result[0]['special#$%^&Column']).toBe('special#$%^&Value') + expect(result[1]['special#$%^&Column']).toBe('another#$%^&') + }) + }) + + describe('Complex Queries with Special Names', () => { + withTestDatabase('should handle filtering on columns with spaces', async (db) => { + // First ensure the table exists with the right column + await db.executeQuery(` + DROP TABLE IF EXISTS "public"."table with spaces"; + CREATE TABLE "public"."table with spaces" ( + id SERIAL PRIMARY KEY, + "column with spaces" TEXT + ); + + -- Insert test data + INSERT INTO "public"."table with spaces" ("column with spaces") + VALUES ('test value'), ('other value'); + `) + + const query = new Query() + + // Specify the column name without extra quotes in the filter + // The Query class handles the proper quoting + const sql = query + .from('table with spaces', 'public') + .select('*') + .filter('column with spaces', '=', 'test value') + .toSql() + + expect(sql).toMatchInlineSnapshot( + '"select * from public."table with spaces" where "column with spaces" = \'test value\';"' + ) + + // Validate the generated SQL directly against the database + const result = await validateSql(db, sql) + expect(result.length).toBe(1) + expect(result[0]['column with spaces']).toBe('test value') + }) + + withTestDatabase('should handle filtering with values containing quotes', async (db) => { + await db.executeQuery(` + INSERT INTO "public"."normal_table" (name) + VALUES ('O''Reilly'); + `) + + const query = new Query() + const sql = query + .from('normal_table', 'public') + .select('*') + .filter('name', '=', "O'Reilly") + .toSql() + + expect(sql).toMatchInlineSnapshot( + "\"select * from public.normal_table where name = 'O''Reilly';\"" + ) + + const result = await validateSql(db, sql) + expect(result.length).toBe(1) + expect(result[0].name).toBe("O'Reilly") + }) + + withTestDatabase('should handle updating with values containing quotes', async (db) => { + const query = new Query() + const sql = query + .from('normal_table', 'public') + .update({ name: "John O'Reilly" }, { returning: true }) + .filter('id', '=', 1) + .toSql() + + expect(sql).toMatchInlineSnapshot( + `"update public.normal_table set (name) = (select name from json_populate_record(null::public.normal_table, '{"name":"John O''Reilly"}')) where id = 1 returning *;"` + ) + await validateSql(db, sql) + }) + + withTestDatabase('should handle inserting with values containing quotes', async (db) => { + const query = new Query() + const sql = query + .from('normal_table', 'public') + .insert([{ name: "John O'Reilly" }], { returning: true }) + .toSql() + + expect(sql).toMatchInlineSnapshot( + `"insert into public.normal_table (name) select name from jsonb_populate_recordset(null::public.normal_table, '[{"name":"John O''Reilly"}]') returning *;"` + ) + await validateSql(db, sql) + }) + }) + + describe('Advanced SQL Generation and Validation', () => { + withTestDatabase( + 'should generate valid select with multiple filters and sorting', + async (db) => { + await db.executeQuery(` + DELETE FROM "public"."normal_table"; + INSERT INTO "public"."normal_table" (id, name) + VALUES + (11, 'John Smith'), + (12, 'John Doe'), + (13, 'Jane Smith'), + (14, 'Someone Else'); + `) + + const query = new Query() + const sql = query + .from('normal_table', 'public') + .select('id, name') + .filter('id', '>', 10) + .filter('name', '~~', '%John%') + .order('normal_table', 'name', true, false) + .range(0, 9) + .toSql() + + expect(sql).toMatchInlineSnapshot( + '"select id, name from public.normal_table where id > 10 and name ~~ \'%John%\' order by normal_table.name asc nulls last limit 10 offset 0;"' + ) + + const result = await validateSql(db, sql) + expect(result.length).toBe(2) + expect(result[0].name).toBe('John Doe') // Alphabetically first + expect(result[1].name).toBe('John Smith') + expect(result.every((row: any) => row.id > 10)).toBe(true) + } + ) + + withTestDatabase('should generate valid insert with returning clause', async (db) => { + const query = new Query() + const sql = query + .from('normal_table', 'public') + .insert([{ name: 'John Doe' }], { returning: true }) + .toSql() + + expect(sql).toMatchInlineSnapshot( + `"insert into public.normal_table (name) select name from jsonb_populate_recordset(null::public.normal_table, '[{"name":"John Doe"}]') returning *;"` + ) + + const result = await validateSql(db, sql) + expect(result.length).toBe(1) + expect(result[0].name).toBe('John Doe') + }) + + withTestDatabase('should generate valid update with filtering', async (db) => { + await db.executeQuery(` + -- Clear and insert test data + DELETE FROM "public"."normal_table"; + INSERT INTO "public"."normal_table" (id, name) + VALUES (1, 'Original Name') ON CONFLICT (id) DO UPDATE SET name = 'Original Name'; + `) + + const query = new Query() + const sql = query + .from('normal_table', 'public') + .update({ name: 'Updated Name' }, { returning: true }) + .filter('id', '=', 1) + .toSql() + + expect(sql).toMatchInlineSnapshot(`"update public.normal_table set (name) = (select name from json_populate_record(null::public.normal_table, '{"name":"Updated Name"}')) where id = 1 returning *;"`) + + const result = await validateSql(db, sql) + expect(result.length).toBe(1) + expect(result[0].id).toBe(1) + expect(result[0].name).toBe('Updated Name') + + // Verify the update was actually persisted + const verifyResult = await db.executeQuery('SELECT * FROM public.normal_table WHERE id = 1') + expect(verifyResult[0].name).toBe('Updated Name') + }) + + withTestDatabase('should generate valid delete with filtering', async (db) => { + await db.executeQuery(` + -- Clear and insert test data + DELETE FROM "public"."normal_table"; + INSERT INTO "public"."normal_table" (id, name) + VALUES (1, 'To Be Deleted') ON CONFLICT (id) DO UPDATE SET name = 'To Be Deleted'; + `) + + const query = new Query() + const sql = query + .from('normal_table', 'public') + .delete({ returning: true }) + .filter('id', '=', 1) + .toSql() + + expect(sql).toMatchInlineSnapshot( + '"delete from public.normal_table where id = 1 returning *;"' + ) + + const result = await validateSql(db, sql) + expect(result.length).toBe(1) + expect(result[0].id).toBe(1) + expect(result[0].name).toBe('To Be Deleted') + + // Verify the row was actually deleted + const verifyResult = await db.executeQuery('SELECT * FROM public.normal_table WHERE id = 1') + expect(verifyResult.length).toBe(0) + }) + + withTestDatabase('should generate valid count with filtering', async (db) => { + await db.executeQuery(` + -- Clear and insert test data + DELETE FROM "public"."normal_table"; + INSERT INTO "public"."normal_table" (name) + VALUES ('John Smith'), ('John Doe'), ('Jane Doe'); + `) + + const query = new Query() + const sql = query + .from('normal_table', 'public') + .count() + .filter('name', '~~', '%John%') + .toSql() + + expect(sql).toMatchInlineSnapshot( + '"select count(*) from public.normal_table where name ~~ \'%John%\';"' + ) + + const result = await validateSql(db, sql) + expect(result[0].count).toBe(2) // PostgreSQL returns count as string + }) + + withTestDatabase('should generate valid truncate query', async (db) => { + await db.executeQuery(` + INSERT INTO "public"."normal_table" (name) + VALUES ('Test Row 1'), ('Test Row 2'); + `) + + // Verify data exists + const beforeCount = await db.executeQuery(`SELECT COUNT(*) FROM "public"."normal_table"`) + expect(parseInt(beforeCount[0].count)).toBeGreaterThan(0) + + const query = new Query() + const sql = query.from('normal_table', 'public').truncate().toSql() + + expect(sql).toMatchInlineSnapshot('"truncate public.normal_table;"') + await validateSql(db, sql) + + // Verify truncate worked + const afterCount = await db.executeQuery(`SELECT COUNT(*) FROM "public"."normal_table"`) + expect(parseInt(afterCount[0].count)).toBe(0) + }) + }) + + describe('Corner Cases and Error Handling', () => { + withTestDatabase('should throw error for delete without filters', async () => { + const query = new Query() + const action = query.from('normal_table', 'public').delete({ returning: true }) + + expect(() => action.toSql()).toThrow(/no filters/) + }) + + withTestDatabase('should throw error for update without filters', async () => { + const query = new Query() + const action = query.from('normal_table', 'public').update({ name: 'Updated Name' }) + + expect(() => action.toSql()).toThrow(/no filters/) + }) + + withTestDatabase('should throw error for insert without values', async () => { + const query = new Query() + // We're passing an empty array to test the runtime error + const action = query.from('normal_table', 'public').insert([] as any, { returning: true }) + + expect(() => action.toSql()).toThrow(/no value to insert/) + }) + + withTestDatabase('should handle special characters in values', async (db) => { + const query = new Query() + const sql = query + .from('normal_table', 'public') + .select('*') + .filter('name', '=', 'Special $ ^ & * ( ) _ + { } | : < > ? characters') + .toSql() + + expect(sql).toMatchInlineSnapshot( + '"select * from public.normal_table where name = \'Special $ ^ & * ( ) _ + { } | : < > ? characters\';"' + ) + await validateSql(db, sql) + }) + }) + + describe('Advanced Filtering', () => { + withTestDatabase('should handle "in" operator with array values', async (db) => { + await db.executeQuery(` + DELETE FROM "public"."normal_table"; + INSERT INTO "public"."normal_table" (id, name) + VALUES + (1, 'Row 1'), + (2, 'Row 2'), + (3, 'Row 3'), + (4, 'Row 4'); + `) + + const query = new Query() + const sql = query + .from('normal_table', 'public') + .select('*') + .filter('id', 'in', [1, 2, 3]) + .toSql() + + expect(sql).toMatchInlineSnapshot('"select * from public.normal_table where id in (1,2,3);"') + const result = await validateSql(db, sql) + expect(result.length).toBe(3) + expect(result.map((row: any) => row.id).sort()).toEqual([1, 2, 3]) + }) + + withTestDatabase('should handle "is" operator with null value', async (db) => { + await db.executeQuery(` + DELETE FROM "public"."normal_table"; + INSERT INTO "public"."normal_table" (id, name) + VALUES + (1, 'Not Null'), + (2, NULL); + `) + + const query = new Query() + const sql = query + .from('normal_table', 'public') + .select('*') + .filter('name', 'is', 'null') + .toSql() + + expect(sql).toMatchInlineSnapshot('"select * from public.normal_table where name is null;"') + const result = await validateSql(db, sql) + expect(result.length).toBe(1) + expect(result[0].id).toBe(2) + expect(result[0].name).toBeNull() + }) + + withTestDatabase('should handle "is" operator with not null value', async (db) => { + await db.executeQuery(` + DELETE FROM "public"."normal_table"; + INSERT INTO "public"."normal_table" (id, name) + VALUES + (1, 'Not Null'), + (2, NULL); + `) + + const query = new Query() + const sql = query + .from('normal_table', 'public') + .select('*') + .filter('name', 'is', 'not null') + .toSql() + + expect(sql).toMatchInlineSnapshot( + '"select * from public.normal_table where name is not null;"' + ) + const result = await validateSql(db, sql) + expect(result.length).toBe(1) + expect(result[0].id).toBe(1) + expect(result[0].name).toBe('Not Null') + }) + }) +}) diff --git a/packages/pg-meta/test/query/query.test.ts b/packages/pg-meta/test/query/query.test.ts new file mode 100644 index 0000000000..57195757a1 --- /dev/null +++ b/packages/pg-meta/test/query/query.test.ts @@ -0,0 +1,615 @@ +import { expect, test, describe } from 'vitest' +import { Query } from '../../src/query/Query' +import { QueryAction } from '../../src/query/QueryAction' +import { QueryFilter } from '../../src/query/QueryFilter' +import { QueryModifier } from '../../src/query/QueryModifier' +import * as QueryUtils from '../../src/query/Query.utils' +import type { QueryTable, Filter, Sort } from '../../src/query/types' + +describe('Query', () => { + test('from() should create a QueryAction with the correct table', () => { + const query = new Query() + const action = query.from('users', 'public') + + expect(action).toBeInstanceOf(QueryAction) + expect(action['table']).toEqual({ name: 'users', schema: 'public' }) + }) + + test('from() should use "public" as the default schema when not provided', () => { + const query = new Query() + const action = query.from('users') + + expect(action['table']).toEqual({ name: 'users', schema: 'public' }) + }) +}) + +describe('QueryAction', () => { + const table: QueryTable = { name: 'users', schema: 'public' } + + test('count() should create a QueryFilter with the correct action', () => { + const action = new QueryAction(table) + const filter = action.count() + + expect(filter).toBeInstanceOf(QueryFilter) + expect(filter['table']).toEqual(table) + expect(filter['action']).toBe('count') + }) + + test('delete() should create a QueryFilter with the correct action and options', () => { + const action = new QueryAction(table) + const filter = action.delete({ returning: true }) + + expect(filter).toBeInstanceOf(QueryFilter) + expect(filter['table']).toEqual(table) + expect(filter['action']).toBe('delete') + expect(filter['actionOptions']).toEqual({ returning: true }) + }) + + test('insert() should create a QueryFilter with the correct action, values and options', () => { + const action = new QueryAction(table) + const values = [{ id: 1, name: 'John' }] + const filter = action.insert(values, { returning: true }) + + expect(filter).toBeInstanceOf(QueryFilter) + expect(filter['table']).toEqual(table) + expect(filter['action']).toBe('insert') + expect(filter['actionValue']).toEqual(values) + expect(filter['actionOptions']).toEqual({ returning: true }) + }) + + test('select() should create a QueryFilter with the correct action and columns', () => { + const action = new QueryAction(table) + const filter = action.select('id, name') + + expect(filter).toBeInstanceOf(QueryFilter) + expect(filter['table']).toEqual(table) + expect(filter['action']).toBe('select') + expect(filter['actionValue']).toBe('id, name') + }) + + test('update() should create a QueryFilter with the correct action, value and options', () => { + const action = new QueryAction(table) + const value = { name: 'John' } + const filter = action.update(value, { returning: true }) + + expect(filter).toBeInstanceOf(QueryFilter) + expect(filter['table']).toEqual(table) + expect(filter['action']).toBe('update') + expect(filter['actionValue']).toEqual(value) + expect(filter['actionOptions']).toEqual({ returning: true }) + }) + + test('truncate() should create a QueryFilter with the correct action and options', () => { + const action = new QueryAction(table) + const filter = action.truncate({ returning: true }) + + expect(filter).toBeInstanceOf(QueryFilter) + expect(filter['table']).toEqual(table) + expect(filter['action']).toBe('truncate') + expect(filter['actionOptions']).toEqual({ returning: true }) + }) +}) + +describe('QueryFilter', () => { + const table: QueryTable = { name: 'users', schema: 'public' } + + test('filter() should add a filter and return the filter instance', () => { + const queryFilter = new QueryFilter(table, 'select', 'id, name') + const result = queryFilter.filter('id', '=', 1) + + expect(result).toBe(queryFilter) + expect(queryFilter['filters']).toEqual([{ column: 'id', operator: '=', value: 1 }]) + }) + + test('match() should add multiple filters and return the filter instance', () => { + const queryFilter = new QueryFilter(table, 'select', 'id, name') + const result = queryFilter.match({ id: 1, name: 'John' }) + + expect(result).toBe(queryFilter) + expect(queryFilter['filters']).toEqual([ + { column: 'id', operator: '=', value: 1 }, + { column: 'name', operator: '=', value: 'John' }, + ]) + }) + + test('order() should add a sort and return the filter instance', () => { + const queryFilter = new QueryFilter(table, 'select', 'id, name') + const result = queryFilter.order('users', 'name', false, true) + + expect(result).toBe(queryFilter) + expect(queryFilter['sorts']).toEqual([ + { table: 'users', column: 'name', ascending: false, nullsFirst: true }, + ]) + }) + + test('range() should delegate to QueryModifier.range() and return the result', () => { + const queryFilter = new QueryFilter(table, 'select', 'id, name') + const result = queryFilter.range(0, 10) + + expect(result).toBeInstanceOf(QueryModifier) + // The pagination gets set in the QueryModifier + expect(result['pagination']).toEqual({ offset: 0, limit: 11 }) + }) + + test('toSql() should delegate to QueryModifier.toSql() and return the SQL string', () => { + const queryFilter = new QueryFilter(table, 'select', 'id, name') + queryFilter.filter('id', '=', 1) + + const result = queryFilter.toSql() + + // Expected SQL should match the pattern from QueryUtils.selectQuery() + expect(result).toBe('select id, name from public.users where id = 1;') + }) +}) + +describe('QueryModifier', () => { + const table: QueryTable = { name: 'users', schema: 'public' } + + test('range() should set the pagination and return the modifier instance', () => { + const queryModifier = new QueryModifier(table, 'select', { + actionValue: 'id, name', + }) + const result = queryModifier.range(0, 10) + + expect(result).toBe(queryModifier) + expect(queryModifier['pagination']).toEqual({ offset: 0, limit: 11 }) + }) + + test('toSql() should generate the correct SQL for a count query', () => { + const queryModifier = new QueryModifier(table, 'count') + const result = queryModifier.toSql() + + expect(result).toBe('select count(*) from public.users;') + }) + + test('toSql() should generate the correct SQL for a delete query with filters', () => { + const queryModifier = new QueryModifier(table, 'delete', { + filters: [{ column: 'id', operator: '=', value: 1 }], + actionOptions: { returning: true }, + }) + const result = queryModifier.toSql() + + expect(result).toBe('delete from public.users where id = 1 returning *;') + }) + + test('toSql() should generate the correct SQL for a select query with filters, sorts and pagination', () => { + const queryModifier = new QueryModifier(table, 'select', { + actionValue: 'id, name', + filters: [{ column: 'id', operator: '>', value: 10 }], + sorts: [{ table: 'users', column: 'name', ascending: true, nullsFirst: false }], + }) + queryModifier.range(0, 5) + const result = queryModifier.toSql() + expect(result).toMatchInlineSnapshot( + `"select id, name from public.users where id > 10 order by users.name asc nulls last limit 6 offset 0;"` + ) + }) + + test('toSql() should generate the correct SQL for a truncate query', () => { + const queryModifier = new QueryModifier(table, 'truncate') + const result = queryModifier.toSql() + + expect(result).toBe('truncate public.users;') + }) + + test('toSql() should generate the correct SQL for a truncate query with cascade', () => { + const queryModifier = new QueryModifier(table, 'truncate', { + actionOptions: { cascade: true }, + }) + const result = queryModifier.toSql() + + expect(result).toBe('truncate public.users cascade;') + }) +}) + +describe('Query.utils', () => { + const table: QueryTable = { name: 'users', schema: 'public' } + + describe('countQuery', () => { + test('should generate a correct count query without filters', () => { + const result = QueryUtils.countQuery(table) + expect(result).toBe('select count(*) from public.users;') + }) + + test('should generate a correct count query with filters', () => { + const filters = [{ column: 'id', operator: '>' as const, value: 1 }] + const result = QueryUtils.countQuery(table, { filters: filters }) + expect(result).toBe('select count(*) from public.users where id > 1;') + }) + }) + + describe('truncateQuery', () => { + test('should generate a correct truncate query without cascade', () => { + const result = QueryUtils.truncateQuery(table) + expect(result).toBe('truncate public.users;') + }) + + test('should generate a correct truncate query with cascade', () => { + const result = QueryUtils.truncateQuery(table, { cascade: true }) + expect(result).toBe('truncate public.users cascade;') + }) + }) + + describe('deleteQuery', () => { + test('should throw an error if no filters are provided', () => { + expect(() => QueryUtils.deleteQuery(table)).toThrow() + }) + + test('should generate a correct delete query with filters', () => { + const filters = [{ column: 'id', operator: '=' as const, value: 1 }] + const result = QueryUtils.deleteQuery(table, filters) + expect(result).toBe('delete from public.users where id = 1;') + }) + + test('should include returning clause when specified', () => { + const filters = [{ column: 'id', operator: '=' as const, value: 1 }] + const result = QueryUtils.deleteQuery(table, filters, { returning: true }) + expect(result).toBe('delete from public.users where id = 1 returning *;') + }) + + test('should include enum array columns in returning clause when specified', () => { + const filters = [{ column: 'id', operator: '=' as const, value: 1 }] + const result = QueryUtils.deleteQuery(table, filters, { + returning: true, + enumArrayColumns: ['tags'], + }) + expect(result).toBe('delete from public.users where id = 1 returning *, tags::text[];') + }) + }) + + describe('insertQuery', () => { + test('should throw an error if no values are provided', () => { + expect(() => QueryUtils.insertQuery(table, [])).toThrow() + }) + + test('should generate a correct insert query with values', () => { + const values = [{ id: 1, name: 'John' }] + const result = QueryUtils.insertQuery(table, values) + expect(result).toMatchInlineSnapshot( + `"insert into public.users (id,name) select id,name from jsonb_populate_recordset(null::public.users, '[{"id":1,"name":"John"}]');"` + ) + }) + + test('should include returning clause when specified', () => { + const values = [{ id: 1, name: 'John' }] + const result = QueryUtils.insertQuery(table, values, { returning: true }) + expect(result).toMatchInlineSnapshot( + `"insert into public.users (id,name) select id,name from jsonb_populate_recordset(null::public.users, '[{"id":1,"name":"John"}]') returning *;"` + ) + }) + + test('should include enum array columns in returning clause when specified', () => { + const values = [{ id: 1, name: 'John' }] + const result = QueryUtils.insertQuery(table, values, { + returning: true, + enumArrayColumns: ['tags'], + }) + expect(result).toMatchInlineSnapshot( + `"insert into public.users (id,name) select id,name from jsonb_populate_recordset(null::public.users, '[{"id":1,"name":"John"}]') returning *, tags::text[];"` + ) + }) + }) + + describe('selectQuery', () => { + test('should generate a correct select query without options', () => { + const result = QueryUtils.selectQuery(table) + expect(result).toBe('select * from public.users;') + }) + + test('should generate a correct select query with custom columns', () => { + const result = QueryUtils.selectQuery(table, 'id, name') + expect(result).toBe('select id, name from public.users;') + }) + + test('should generate a correct select query with filters', () => { + const filters = [{ column: 'id', operator: '>' as const, value: 1 }] + const result = QueryUtils.selectQuery(table, '*', { filters: filters }) + expect(result).toBe('select * from public.users where id > 1;') + }) + + test('should generate a correct select query with sorts', () => { + const sorts = [{ table: 'users', column: 'name', ascending: true, nullsFirst: false }] + const result = QueryUtils.selectQuery(table, '*', { sorts: sorts }) + expect(result).toBe('select * from public.users order by users.name asc nulls last;') + }) + + test('should generate a correct select query with pagination', () => { + const pagination = { limit: 10, offset: 0 } + const result = QueryUtils.selectQuery(table, '*', { pagination: pagination }) + expect(result).toBe('select * from public.users limit 10 offset 0;') + }) + + test('should ignore sorts with undefined column', () => { + const sorts: Sort[] = [{ table: 'users', column: '', ascending: true, nullsFirst: false }] + const result = QueryUtils.selectQuery(table, '*', { sorts: sorts }) + expect(result).toMatchInlineSnapshot(`"select * from public.users;"`) + }) + }) + + describe('updateQuery', () => { + test('should throw an error if no filters are provided', () => { + const value = { name: 'John' } + expect(() => QueryUtils.updateQuery(table, value)).toThrow() + }) + + test('should generate a correct update query with filters', () => { + const value = { name: 'John' } + const filters = [{ column: 'id', operator: '=' as const, value: 1 }] + const result = QueryUtils.updateQuery(table, value, { filters: filters }) + expect(result).toMatchInlineSnapshot( + `"update public.users set (name) = (select name from json_populate_record(null::public.users, '{"name":"John"}')) where id = 1;"` + ) + }) + + test('should include returning clause when specified', () => { + const value = { name: 'John' } + const filters = [{ column: 'id', operator: '=' as const, value: 1 }] + const result = QueryUtils.updateQuery(table, value, { + filters: filters, + returning: true, + }) + expect(result).toMatchInlineSnapshot( + `"update public.users set (name) = (select name from json_populate_record(null::public.users, '{"name":"John"}')) where id = 1 returning *;"` + ) + }) + + test('should include enum array columns in returning clause when specified', () => { + const value = { name: 'John' } + const filters = [{ column: 'id', operator: '=' as const, value: 1 }] + const result = QueryUtils.updateQuery(table, value, { + filters: filters, + returning: true, + enumArrayColumns: ['tags'], + }) + expect(result).toMatchInlineSnapshot( + `"update public.users set (name) = (select name from json_populate_record(null::public.users, '{"name":"John"}')) where id = 1 returning *, tags::text[];"` + ) + }) + }) + + describe('Query.utils internal functions', () => { + describe('applyFilters', () => { + test('should correctly apply equality filters', () => { + const filters: Filter[] = [{ column: 'name', operator: '=', value: 'John' }] + const result = QueryUtils.selectQuery(table, '*', { filters: filters }) + expect(result).toBe("select * from public.users where name = 'John';") + }) + + test('should correctly apply multiple filters with AND logic', () => { + const filters: Filter[] = [ + { column: 'name', operator: '=', value: 'John' }, + { column: 'age', operator: '>', value: 25 }, + ] + const result = QueryUtils.selectQuery(table, '*', { filters: filters }) + expect(result).toBe("select * from public.users where name = 'John' and age > 25;") + }) + + test('should correctly handle "in" operator with array values', () => { + const filters: Filter[] = [{ column: 'id', operator: 'in', value: [1, 2, 3] }] + const result = QueryUtils.selectQuery(table, '*', { filters: filters }) + expect(result).toBe('select * from public.users where id in (1,2,3);') + }) + + test('should correctly handle "in" operator with comma-separated string', () => { + const filters: Filter[] = [{ column: 'id', operator: 'in', value: '1,2,3' }] + const result = QueryUtils.selectQuery(table, '*', { filters: filters }) + expect(result).toBe("select * from public.users where id in ('1','2','3');") + }) + + test('should correctly handle "is" operator with null value', () => { + const filters: Filter[] = [{ column: 'email', operator: 'is', value: 'null' }] + const result = QueryUtils.selectQuery(table, '*', { filters: filters }) + expect(result).toBe('select * from public.users where email is null;') + }) + + test('should correctly handle "is" operator with not null value', () => { + const filters: Filter[] = [{ column: 'email', operator: 'is', value: 'not null' }] + const result = QueryUtils.selectQuery(table, '*', { filters: filters }) + expect(result).toBe('select * from public.users where email is not null;') + }) + + test('should correctly handle "is" operator with boolean values', () => { + const filters: Filter[] = [{ column: 'active', operator: 'is', value: 'true' }] + const result = QueryUtils.selectQuery(table, '*', { filters: filters }) + expect(result).toBe('select * from public.users where active is true;') + }) + + test('should correctly escape string values in filters', () => { + const filters: Filter[] = [{ column: 'name', operator: '=', value: "O'Reilly" }] + const result = QueryUtils.selectQuery(table, '*', { filters: filters }) + expect(result).toContain("where name = 'O''Reilly'") + }) + }) + + describe('applySorts', () => { + test('should correctly apply a single sort with default options', () => { + const sorts: Sort[] = [ + { table: 'users', column: 'name', ascending: true, nullsFirst: false }, + ] + const result = QueryUtils.selectQuery(table, '*', { sorts: sorts }) + expect(result).toBe('select * from public.users order by users.name asc nulls last;') + }) + + test('should correctly apply a descending sort', () => { + const sorts: Sort[] = [ + { table: 'users', column: 'name', ascending: false, nullsFirst: false }, + ] + const result = QueryUtils.selectQuery(table, '*', { sorts: sorts }) + expect(result).toBe('select * from public.users order by users.name desc nulls last;') + }) + + test('should correctly apply nulls first option', () => { + const sorts: Sort[] = [ + { table: 'users', column: 'name', ascending: true, nullsFirst: true }, + ] + const result = QueryUtils.selectQuery(table, '*', { sorts: sorts }) + expect(result).toBe('select * from public.users order by users.name asc nulls first;') + }) + + test('should correctly apply multiple sorts', () => { + const sorts: Sort[] = [ + { table: 'users', column: 'last_name', ascending: true, nullsFirst: false }, + { table: 'users', column: 'first_name', ascending: true, nullsFirst: false }, + ] + const result = QueryUtils.selectQuery(table, '*', { sorts: sorts }) + expect(result).toBe( + 'select * from public.users order by users.last_name asc nulls last, users.first_name asc nulls last;' + ) + }) + + test('should ignore sorts with undefined column', () => { + const sorts: Sort[] = [{ table: 'users', column: '', ascending: true, nullsFirst: false }] + const result = QueryUtils.selectQuery(table, '*', { sorts: sorts }) + expect(result).toMatchInlineSnapshot(`"select * from public.users;"`) + }) + }) + + describe('filterLiteral', () => { + test('should correctly handle array literal syntax', () => { + const filters: Filter[] = [{ column: 'tags', operator: '=', value: "ARRAY['tag1','tag2']" }] + const result = QueryUtils.selectQuery(table, '*', { filters: filters }) + expect(result).toBe("select * from public.users where tags = ARRAY['tag1','tag2'];") + }) + + test('should correctly handle non-string values', () => { + const filters: Filter[] = [{ column: 'active', operator: '=', value: true }] + const result = QueryUtils.selectQuery(table, '*', { filters: filters }) + expect(result).toBe('select * from public.users where active = true;') + }) + }) + + describe('queryTable', () => { + test('should correctly format the table name with schema', () => { + const result = QueryUtils.selectQuery({ name: 'orders', schema: 'shop' }) + expect(result).toBe('select * from shop.orders;') + }) + }) + }) +}) + +describe('End-to-end query chaining', () => { + test('should correctly build a simple select query', () => { + const query = new Query() + const sql = query.from('users', 'public').select('id, name, email').toSql() + + expect(sql).toBe('select id, name, email from public.users;') + }) + + test('should correctly build a filtered select query', () => { + const query = new Query() + const sql = query + .from('users', 'public') + .select('id, name, email') + .filter('id', '>', 10) + .toSql() + + expect(sql).toBe('select id, name, email from public.users where id > 10;') + }) + + test('should correctly build a select query with multiple filters', () => { + const query = new Query() + const sql = query + .from('users', 'public') + .select('id, name, email') + .filter('id', '>', 10) + .filter('name', '~~', '%John%') + .toSql() + + expect(sql).toBe("select id, name, email from public.users where id > 10 and name ~~ '%John%';") + }) + + test('should correctly build a select query with match criteria', () => { + const query = new Query() + const sql = query + .from('users', 'public') + .select('id, name, email') + .match({ active: true, role: 'admin' }) + .toSql() + + expect(sql).toBe( + "select id, name, email from public.users where active = true and role = 'admin';" + ) + }) + + test('should correctly build a select query with sorting', () => { + const query = new Query() + const sql = query + .from('users', 'public') + .select('id, name, email') + .order('users', 'name', true, false) + .toSql() + + expect(sql).toBe('select id, name, email from public.users order by users.name asc nulls last;') + }) + + test('should correctly build a select query with pagination', () => { + const query = new Query() + const sql = query.from('users', 'public').select('id, name, email').range(0, 9).toSql() + + expect(sql).toBe('select id, name, email from public.users limit 10 offset 0;') + }) + + test('should correctly build a complete select query with filters, sorting and pagination', () => { + const query = new Query() + const sql = query + .from('users', 'public') + .select('id, name, email') + .filter('id', '>', 10) + .match({ active: true }) + .order('users', 'name', true, false) + .range(0, 9) + .toSql() + + expect(sql).toBe( + 'select id, name, email from public.users where id > 10 and active = true order by users.name asc nulls last limit 10 offset 0;' + ) + }) + + test('should correctly build an insert query', () => { + const query = new Query() + const sql = query + .from('users', 'public') + .insert([{ name: 'John', email: 'john@example.com' }], { returning: true }) + .toSql() + expect(sql).toMatchInlineSnapshot( + `"insert into public.users (name,email) select name,email from jsonb_populate_recordset(null::public.users, '[{"name":"John","email":"john@example.com"}]') returning *;"` + ) + }) + + test('should correctly build an update query', () => { + const query = new Query() + const sql = query + .from('users', 'public') + .update({ name: 'Updated Name' }, { returning: true }) + .filter('id', '=', 1) + .toSql() + expect(sql).toMatchInlineSnapshot( + `"update public.users set (name) = (select name from json_populate_record(null::public.users, '{"name":"Updated Name"}')) where id = 1 returning *;"` + ) + }) + + test('should correctly build a delete query', () => { + const query = new Query() + const sql = query + .from('users', 'public') + .delete({ returning: true }) + .filter('id', '=', 1) + .toSql() + + expect(sql).toBe('delete from public.users where id = 1 returning *;') + }) + + test('should correctly build a count query', () => { + const query = new Query() + const sql = query.from('users', 'public').count().filter('active', '=', true).toSql() + + expect(sql).toBe('select count(*) from public.users where active = true;') + }) + + test('should correctly build a truncate query', () => { + const query = new Query() + const sql = query.from('users', 'public').truncate().toSql() + + expect(sql).toBe('truncate public.users;') + }) +}) diff --git a/packages/pg-meta/tsconfig.json b/packages/pg-meta/tsconfig.json index 6970ef0a74..989c9d92a9 100644 --- a/packages/pg-meta/tsconfig.json +++ b/packages/pg-meta/tsconfig.json @@ -2,6 +2,7 @@ "extends": "../tsconfig/base.json", "compilerOptions": { "module": "ESNext", + "target": "ES2021", "moduleResolution": "bundler" }, "include": ["."],