From 31c32d1d7dfa65b5477d5ca3d6806d6ea0e1c5f2 Mon Sep 17 00:00:00 2001 From: Paul Copplestone Date: Sun, 5 Jul 2020 17:36:33 +0800 Subject: [PATCH 1/3] refactor: Simplifies the /table interface - column changes can exist in their own file --- src/api/columns.ts | 67 +++++++++++++++++++++++++++++++- src/api/schemas.ts | 7 ++-- src/api/tables.ts | 70 +++++++++++++++++++++++++++------- src/lib/helpers.ts | 34 ----------------- test/integration/index.spec.js | 68 ++++++++++++++++++++++----------- 5 files changed, 170 insertions(+), 76 deletions(-) diff --git a/src/api/columns.ts b/src/api/columns.ts index 68150a2a..f96e1e3f 100644 --- a/src/api/columns.ts +++ b/src/api/columns.ts @@ -1,14 +1,39 @@ import { Router } from 'express' - import { RunQuery } from '../lib/connectionPool' import sql = require('../lib/sql') const { columns } = sql +import { DEFAULT_SYSTEM_SCHEMAS } from '../lib/constants' +import { Tables } from '../lib/interfaces' const router = Router() router.get('/', async (req, res) => { try { const { data } = await RunQuery(req.headers.pg, columns) - return res.status(200).json(data) + const query: Fetch.QueryParams = req.query + let payload: Tables.Column[] = data + if (!query?.includeSystemSchemas) payload = removeSystemSchemas(data) + return res.status(200).json(payload) + } catch (error) { + console.log('throwing error') + res.status(500).send('Database error.') + } +}) +router.post('/', async (req, res) => { + try { + } catch (error) { + console.log('throwing error') + res.status(500).send('Database error.') + } +}) +router.patch('/:id', async (req, res) => { + try { + } catch (error) { + console.log('throwing error') + res.status(500).send('Database error.') + } +}) +router.delete('/:id', async (req, res) => { + try { } catch (error) { console.log('throwing error') res.status(500).send('Database error.') @@ -16,3 +41,41 @@ router.get('/', async (req, res) => { }) export = router + +const removeSystemSchemas = (data: Tables.Column[]) => { + return data.filter((x) => !DEFAULT_SYSTEM_SCHEMAS.includes(x.schema)) +} +const newColumnSql = ({ + name, + default_value, + is_identity = false, + is_nullable = true, + is_primary_key = false, + data_type, +}: { + name: string + default_value?: string + is_identity?: boolean + is_nullable?: boolean + is_primary_key?: boolean + data_type: string +}) => { + return ` +${name} ${data_type} +${default_value === undefined ? '' : `DEFAULT ${default_value}`} +${is_identity ? 'GENERATED BY DEFAULT AS IDENTITY' : ''} +${is_nullable ? '' : 'NOT NULL'} +${is_primary_key ? 'PRIMARY KEY' : ''}` +} + +/** + * Types + */ +namespace Fetch { + /** + * @param {boolean} [includeSystemSchemas=false] - Return system schemas as well as user schemas + */ + export interface QueryParams { + includeSystemSchemas?: boolean + } +} diff --git a/src/api/schemas.ts b/src/api/schemas.ts index bc2c7d85..249230d2 100644 --- a/src/api/schemas.ts +++ b/src/api/schemas.ts @@ -64,15 +64,16 @@ router.patch('/:id', async (req, res) => { const updateOwner = alterSchemaOwner(previousSchema.name, owner) await RunQuery(req.headers.pg, updateOwner) } + // NB: Run name updates last if (name) { const updateName = alterSchemaName(previousSchema.name, name) await RunQuery(req.headers.pg, updateName) } // Return fresh details - const { data: updatedSchemaResults } = await RunQuery(req.headers.pg, getSchema) - let updatedSchema: Schemas.Schema = updatedSchemaResults[0] - return res.status(200).json(updatedSchema) + const { data: updatedResults } = await RunQuery(req.headers.pg, getSchema) + let updated: Schemas.Schema = updatedResults[0] + return res.status(200).json(updated) } catch (error) { console.log('throwing error', error) res.status(500).json({ error: 'Database error', status: 500 }) diff --git a/src/api/tables.ts b/src/api/tables.ts index 4dfefd26..5f416f31 100644 --- a/src/api/tables.ts +++ b/src/api/tables.ts @@ -1,8 +1,8 @@ import { Router } from 'express' - -import sql = require('../lib/sql') -const { columns, grants, primary_keys, relationships, tables } = sql -import { coalesceRowsToArray, formatColumns } from '../lib/helpers' +import SQL from 'sql-template-strings' +import sqlTemplates = require('../lib/sql') +const { columns, grants, primary_keys, relationships, tables } = sqlTemplates +import { coalesceRowsToArray } from '../lib/helpers' import { RunQuery } from '../lib/connectionPool' import { DEFAULT_SYSTEM_SCHEMAS } from '../lib/constants' import { Tables } from '../lib/interfaces' @@ -48,18 +48,47 @@ FROM }) router.post('/', async (req, res) => { try { - const { schema = 'public', name, columns, primary_keys = [] } = req.body as { + const { schema = 'public', name } = req.body as { schema?: string name: string - columns: Tables.Column[] - primary_keys?: Tables.PrimaryKey[] } - const sql = ` -CREATE TABLE ${schema}.${name} ( - ${formatColumns({ columns, primary_keys })} -)` - const { data } = await RunQuery(req.headers.pg, sql) - return res.status(200).json(data) + + // Create the table + const createTableSql = createTable(name, schema) + await RunQuery(req.headers.pg, createTableSql) + + // Return fresh details + const getTable = selectSingleByName(schema, name) + const { data: newTableResults } = await RunQuery(req.headers.pg, getTable) + let newTable: Tables.Table = newTableResults[0] + return res.status(200).json(newTable) + } catch (error) { + // For this one, we always want to give back the error to the customer + console.log('Soft error!', error) + res.status(200).json([{ error: error.toString() }]) + } +}) +router.patch('/:id', async (req, res) => { + try { + const id: number = parseInt(req.params.id) + const name: string = req.body.name + + // Get table + const getTableSql = selectSingleSql(id) + const { data: getTableResults } = await RunQuery(req.headers.pg, getTableSql) + let previousTable: Tables.Table = getTableResults[0] + + // Update fields + // NB: Run name updates last + if (name) { + const updateName = alterTableName(previousTable.name, name, previousTable.schema) + await RunQuery(req.headers.pg, updateName) + } + + // Return fresh details + const { data: updatedResults } = await RunQuery(req.headers.pg, getTableSql) + let updated: Tables.Table = updatedResults[0] + return res.status(200).json(updated) } catch (error) { // For this one, we always want to give back the error to the customer console.log('Soft error!', error) @@ -69,6 +98,20 @@ CREATE TABLE ${schema}.${name} ( export = router +const selectSingleSql = (id: number) => { + return SQL``.append(tables).append(SQL` and c.oid = ${id}`) +} +const selectSingleByName = (schema: string, name: string) => { + return SQL``.append(tables).append(SQL` and table_schema = ${schema} and table_name = ${name}`) +} +const createTable = (name: string, schema: string = 'postgres') => { + const query = SQL``.append(`CREATE TABLE ${schema}.${name} ()`) + return query +} +const alterTableName = (previousName: string, newName: string, schema: string) => { + const query = SQL``.append(`ALTER SCHEMA ${previousName} RENAME TO ${newName}`) + return query +} const removeSystemSchemas = (data: Tables.Table[]) => { return data.filter((x) => !DEFAULT_SYSTEM_SCHEMAS.includes(x.schema)) } @@ -76,7 +119,6 @@ const removeSystemSchemas = (data: Tables.Table[]) => { /** * Types */ - namespace Fetch { /** * @param {boolean} [includeSystemSchemas=false] - Return system schemas as well as user schemas diff --git a/src/lib/helpers.ts b/src/lib/helpers.ts index 548cdf3f..28ff9975 100644 --- a/src/lib/helpers.ts +++ b/src/lib/helpers.ts @@ -1,4 +1,3 @@ -import { Tables } from '../lib/interfaces' export const coalesceRowsToArray = (source: string, joinQuery: string) => { return ` @@ -12,36 +11,3 @@ COALESCE( '[]' ) AS ${source}` } - -export const formatColumns = ({ - columns, - primary_keys, -}: { - columns: Tables.Column[] - primary_keys: Tables.PrimaryKey[] -}) => { - const pkey_columns = primary_keys.map((primary_key) => primary_key.name) - return columns - .map((column) => { - const { - name, - default_value, - is_identity = false, - is_nullable = true, - data_type, - } = column as { - name: string - default_value?: string - is_identity?: boolean - is_nullable?: boolean - data_type: string - } - return ` -${name} ${data_type} -${default_value === undefined ? '' : `DEFAULT ${default_value}`} -${is_identity ? 'GENERATED BY DEFAULT AS IDENTITY' : ''} -${is_nullable ? '' : 'NOT NULL'} -${pkey_columns.includes(name) ? 'PRIMARY KEY' : ''}` - }) - .join(',') -} diff --git a/test/integration/index.spec.js b/test/integration/index.spec.js index 381d3c5e..7dd07054 100644 --- a/test/integration/index.spec.js +++ b/test/integration/index.spec.js @@ -132,8 +132,8 @@ describe('/types', () => { assert.equal(true, !!included) }) }) -describe('/tables', async () => { - it('GET', async () => { +describe('/tables & /columns', async () => { + it('GET /tables', async () => { const tables = await axios.get(`${URL}/tables`) const datum = tables.data.find((x) => `${x.schema}.${x.name}` === 'public.users') const notIncluded = tables.data.find((x) => `${x.schema}.${x.name}` === 'pg_catalog.pg_type') @@ -141,7 +141,7 @@ describe('/tables', async () => { assert.equal(true, !!datum) assert.equal(true, !notIncluded) }) - it('should return the columns', async () => { + it('/tables should return the columns', async () => { const tables = await axios.get(`${URL}/tables`) const datum = tables.data.find((x) => `${x.schema}.${x.name}` === 'public.users') const idColumn = datum.columns.find((x) => x.name === 'id') @@ -153,12 +153,12 @@ describe('/tables', async () => { assert.equal(idColumn.is_identity, true) assert.equal(nameColumn.is_identity, false) }) - it('should return the grants', async () => { + it('/tables should return the grants', async () => { const tables = await axios.get(`${URL}/tables`) const datum = tables.data.find((x) => `${x.schema}.${x.name}` === 'public.users') assert.equal(datum.grants.length > 0, true) }) - it('should return the relationships', async () => { + it('/tables should return the relationships', async () => { const tables = await axios.get(`${URL}/tables`) const datum = tables.data.find((x) => `${x.schema}.${x.name}` === 'public.users') const relationships = datum.relationships @@ -169,32 +169,54 @@ describe('/tables', async () => { assert.equal(true, relationship.target_table_schema === 'public') assert.equal(true, relationship.target_table_name === 'users') }) - it('GET with system tables', async () => { + it('GET /tabls with system tables', async () => { const res = await axios.get(`${URL}/tables?includeSystemSchemas=true`) const included = res.data.find((x) => `${x.schema}.${x.name}` === 'pg_catalog.pg_type') assert.equal(res.status, STATUS.SUCCESS) assert.equal(true, !!included) }) - it('POST', async () => { - await axios.post(`${URL}/tables`, { + it('GET /columns', async () => { + const res = await axios.get(`${URL}/columns`) + // console.log('res.data', res.data) + const datum = res.data.find((x) => x.schema == 'public') + const notIncluded = res.data.find((x) => x.schema == 'pg_catalog') + assert.equal(res.status, STATUS.SUCCESS) + assert.equal(true, !!datum) + assert.equal(true, !notIncluded) + }) + it('GET /columns with system types', async () => { + const res = await axios.get(`${URL}/columns?includeSystemSchemas=true`) + // console.log('res.data', res.data) + const datum = res.data.find((x) => x.schema == 'public') + const included = res.data.find((x) => x.schema == 'pg_catalog') + assert.equal(res.status, STATUS.SUCCESS) + assert.equal(true, !!datum) + assert.equal(true, !!included) + }) + it('POST /tables should create a table', async () => { + await axios.post(`${URL}/query`, { query: 'DROP TABLE IF EXISTS public.test' }) + let {data: newTable} = await axios.post(`${URL}/tables`, { schema: 'public', name: 'test', - columns: [ - { name: 'id', is_identity: true, is_nullable: false, data_type: 'bigint' }, - { name: 'data', data_type: 'text' }, - ], - primary_keys: ['id'], + // columns: [ + // { name: 'id', is_identity: true, is_nullable: false, data_type: 'bigint' }, + // { name: 'data', data_type: 'text' }, + // ], + // primary_keys: ['id'], }) - const { data: tables } = await axios.get(`${URL}/tables`) - const test = tables.find((table) => `${table.schema}.${table.name}` === 'public.test') - const id = test.columns.find((column) => column.name === 'id') - const data = test.columns.find((column) => column.name === 'data') - assert.equal(id.is_identity, true) - assert.equal(id.is_nullable, false) - assert.equal(id.data_type, 'bigint') - assert.equal(data.is_identity, false) - assert.equal(data.is_nullable, true) - assert.equal(data.data_type, 'text') + // console.log('newTable', newTable) + const newTableId = newTable.id + assert.equal(newTableId > 0, true) + // const { data: tables } = await axios.get(`${URL}/tables`) + // const test = tables.find((table) => `${table.schema}.${table.name}` === 'public.test') + // const id = test.columns.find((column) => column.name === 'id') + // const data = test.columns.find((column) => column.name === 'data') + // assert.equal(id.is_identity, true) + // assert.equal(id.is_nullable, false) + // assert.equal(id.data_type, 'bigint') + // assert.equal(data.is_identity, false) + // assert.equal(data.is_nullable, true) + // assert.equal(data.data_type, 'text') await axios.post(`${URL}/query`, { query: 'DROP TABLE public.test' }) }) }) From f1de03151879794ba9f73ddbe85ea5fb00ddc844 Mon Sep 17 00:00:00 2001 From: Bobbie Soedirgo Date: Mon, 6 Jul 2020 02:16:07 +0800 Subject: [PATCH 2/3] fix: conversion error on identifiers Things break when using indentifiers for tables/columns/etc. with spaces in the name--need to quote it. --- src/lib/sql/columns.sql | 5 ++--- src/lib/sql/grants.sql | 4 ++-- src/lib/sql/schemas.sql | 2 +- src/lib/sql/tables.sql | 8 ++++---- src/lib/sql/views.sql | 4 ++-- 5 files changed, 11 insertions(+), 12 deletions(-) diff --git a/src/lib/sql/columns.sql b/src/lib/sql/columns.sql index 2042b03d..49ea7f3d 100644 --- a/src/lib/sql/columns.sql +++ b/src/lib/sql/columns.sql @@ -1,4 +1,3 @@ --- We can uniquely point to a specific column using table_id + ordinal_position. SELECT c.oid AS table_id, table_schema AS schema, @@ -19,5 +18,5 @@ SELECT is_updatable::boolean FROM information_schema.columns - JOIN pg_class c ON c.relnamespace = table_schema::text::regnamespace - AND c.relname = table_name::text + JOIN pg_class c ON quote_ident(table_schema)::regnamespace = c.relnamespace + AND c.relname = table_name diff --git a/src/lib/sql/grants.sql b/src/lib/sql/grants.sql index 8a6955ff..015fa4a6 100644 --- a/src/lib/sql/grants.sql +++ b/src/lib/sql/grants.sql @@ -10,5 +10,5 @@ SELECT with_hierarchy :: boolean FROM information_schema.role_table_grants - INNER JOIN pg_class c ON table_schema::text::regnamespace = c.relnamespace - AND table_name::text = c.relname + JOIN pg_class c ON quote_ident(table_schema)::regnamespace = c.relnamespace + AND table_name = c.relname diff --git a/src/lib/sql/schemas.sql b/src/lib/sql/schemas.sql index 13cb7838..b0a17dc3 100644 --- a/src/lib/sql/schemas.sql +++ b/src/lib/sql/schemas.sql @@ -9,4 +9,4 @@ SELECT sql_path FROM information_schema.schemata - JOIN pg_namespace nsp ON schema_name::text::regnamespace = nsp.oid + JOIN pg_namespace nsp ON schema_name = nsp.nspname diff --git a/src/lib/sql/tables.sql b/src/lib/sql/tables.sql index 25ea9705..d4be5c31 100644 --- a/src/lib/sql/tables.sql +++ b/src/lib/sql/tables.sql @@ -5,9 +5,9 @@ SELECT table_name AS name, is_insertable_into, is_typed, - pg_total_relation_size(table_schema || '.' || table_name) :: bigint AS bytes, + pg_total_relation_size(format('%I.%I', table_schema, table_name))::bigint AS bytes, pg_size_pretty( - pg_total_relation_size(table_schema || '.' || table_name) + pg_total_relation_size(format('%I.%I', table_schema, table_name)) ) AS size, seq_scan :: bigint AS seq_scan_count, seq_tup_read :: bigint AS seq_row_read_count, @@ -30,8 +30,8 @@ SELECT autoanalyze_count :: bigint FROM information_schema.tables - JOIN pg_class c ON c.relnamespace = table_schema::text::regnamespace - AND c.relname = table_name::text + JOIN pg_class c ON quote_ident(table_schema)::regnamespace = c.relnamespace + AND c.relname = table_name LEFT JOIN pg_stat_user_tables ON pg_stat_user_tables.schemaname = tables.table_schema AND pg_stat_user_tables.relname = tables.table_name WHERE diff --git a/src/lib/sql/views.sql b/src/lib/sql/views.sql index fd821834..345e1cb3 100644 --- a/src/lib/sql/views.sql +++ b/src/lib/sql/views.sql @@ -10,5 +10,5 @@ SELECT is_trigger_insertable_into FROM information_schema.views - INNER JOIN pg_class c ON table_schema::text::regnamespace = c.relnamespace - AND table_name::text = c.relname + JOIN pg_class c ON quote_ident(table_schema)::regnamespace = c.relnamespace + AND table_name = c.relname From 5de590128a616174d0e1494ec7d13a97c266ee8e Mon Sep 17 00:00:00 2001 From: Bobbie Soedirgo Date: Mon, 6 Jul 2020 19:06:27 +0800 Subject: [PATCH 3/3] feat: support CRUD on /schemas, /tables, /columns --- src/api/columns.ts | 78 +++++++++++++++++++-- src/api/schemas.ts | 23 ++++++- src/api/tables.ts | 33 +++++++-- test/integration/index.spec.js | 122 ++++++++++++++++++++++++++------- 4 files changed, 215 insertions(+), 41 deletions(-) diff --git a/src/api/columns.ts b/src/api/columns.ts index f96e1e3f..27dece19 100644 --- a/src/api/columns.ts +++ b/src/api/columns.ts @@ -1,11 +1,13 @@ import { Router } from 'express' +import SQL from 'sql-template-strings' import { RunQuery } from '../lib/connectionPool' import sql = require('../lib/sql') -const { columns } = sql import { DEFAULT_SYSTEM_SCHEMAS } from '../lib/constants' import { Tables } from '../lib/interfaces' const router = Router() +const { columns, tables } = sql + router.get('/', async (req, res) => { try { const { data } = await RunQuery(req.headers.pg, columns) @@ -18,25 +20,87 @@ router.get('/', async (req, res) => { res.status(500).send('Database error.') } }) + router.post('/', async (req, res) => { try { + const { tableId, name, type } = req.body as { + tableId: number + name: string + type: string + } + const getTableQuery = SQL``.append(tables).append(SQL` AND c.oid = ${tableId}`) + const { name: table, schema } = (await RunQuery(req.headers.pg, getTableQuery)).data[0] + + const query = `ALTER TABLE "${schema}"."${table}" ADD COLUMN "${name}" "${type}"` + await RunQuery(req.headers.pg, query) + + const getColumnQuery = SQL`` + .append(columns) + .append(SQL` WHERE c.oid = ${tableId} AND column_name = ${name}`) + const column = (await RunQuery(req.headers.pg, getColumnQuery)).data[0] + + return res.status(200).json(column) } catch (error) { - console.log('throwing error') - res.status(500).send('Database error.') + console.log('throwing error', error) + res.status(500).json({ error: 'Database error', status: 500 }) } }) + router.patch('/:id', async (req, res) => { try { + const [tableId, ordinalPos] = req.params.id.split('.') + const getColumnQuery = SQL`` + .append(columns) + .append(SQL` WHERE c.oid = ${tableId} AND ordinal_position = ${ordinalPos}`) + const { schema, table, name: oldName } = ( + await RunQuery(req.headers.pg, getColumnQuery) + ).data[0] + + const { name, type } = req.body as { + name?: string + type?: string + } + + const query = ` +BEGIN; + ${ + type === undefined + ? '' + : `ALTER TABLE "${schema}"."${table}" ALTER COLUMN "${oldName}" SET DATA TYPE "${type}";` + } + ${ + name === undefined + ? '' + : `ALTER TABLE "${schema}"."${table}" RENAME COLUMN "${oldName}" TO "${name}";` + } +COMMIT;` + await RunQuery(req.headers.pg, query) + + const updated = (await RunQuery(req.headers.pg, getColumnQuery)).data[0] + return res.status(200).json(updated) } catch (error) { - console.log('throwing error') - res.status(500).send('Database error.') + console.log('throwing error', error) + res.status(500).json({ error: 'Database error', status: 500 }) } }) + router.delete('/:id', async (req, res) => { try { + const [tableId, ordinalPos] = req.params.id.split('.') + + const getColumnQuery = SQL`` + .append(columns) + .append(SQL` WHERE c.oid = ${tableId} AND ordinal_position = ${ordinalPos} `) + const column = (await RunQuery(req.headers.pg, getColumnQuery)).data[0] + const { schema, table, name } = column + + const query = `ALTER TABLE "${schema}"."${table}" DROP COLUMN "${name}"` + await RunQuery(req.headers.pg, query) + + return res.status(200).json(column) } catch (error) { - console.log('throwing error') - res.status(500).send('Database error.') + console.log('throwing error', error) + res.status(500).json({ error: 'Database error', status: 500 }) } }) diff --git a/src/api/schemas.ts b/src/api/schemas.ts index 249230d2..2f035f64 100644 --- a/src/api/schemas.ts +++ b/src/api/schemas.ts @@ -29,6 +29,7 @@ router.get('/', async (req, res) => { res.status(500).json({ error: 'Database error', status: 500 }) } }) + router.post('/', async (req, res) => { try { const name: string = req.body.name @@ -37,7 +38,7 @@ router.post('/', async (req, res) => { // Create the schema const schemqQuery = createSchema(name, owner) await RunQuery(req.headers.pg, schemqQuery) - + // Return fresh details const getSchema = selectSingleByName(name) const { data } = await RunQuery(req.headers.pg, getSchema) @@ -48,6 +49,7 @@ router.post('/', async (req, res) => { res.status(500).json({ error: 'Database error', status: 500 }) } }) + router.patch('/:id', async (req, res) => { try { const id: number = parseInt(req.params.id) @@ -80,6 +82,23 @@ router.patch('/:id', async (req, res) => { } }) +router.delete('/:id', async (req, res) => { + try { + const id = req.params.id + const getNameQuery = SQL``.append(schemas).append(SQL` WHERE nsp.oid = ${id}`) + const schema = (await RunQuery(req.headers.pg, getNameQuery)).data[0] + + const cascade = req.query.cascade + const query = `DROP SCHEMA "${schema.name}" ${cascade === 'true' ? 'CASCADE' : 'RESTRICT'}` + await RunQuery(req.headers.pg, query) + + return res.status(200).json(schema) + } catch (error) { + console.log('throwing error', error) + res.status(500).json({ error: 'Database error', status: 500 }) + } +}) + // Helpers const selectSingleSql = (id: number) => { const query = SQL``.append(schemas).append(SQL` where nsp.oid = ${id}`) @@ -90,7 +109,7 @@ const selectSingleByName = (name: string) => { return query } const createSchema = (name: string, owner: string = 'postgres') => { - const query = SQL``.append(`CREATE SCHEMA IF NOT EXISTS ${name} AUTHORIZATION ${owner}`) + const query = SQL``.append(`CREATE SCHEMA IF NOT EXISTS "${name}" AUTHORIZATION ${owner}`) return query } const alterSchemaName = (previousName: string, newName: string) => { diff --git a/src/api/tables.ts b/src/api/tables.ts index 5f416f31..f2989749 100644 --- a/src/api/tables.ts +++ b/src/api/tables.ts @@ -8,14 +8,15 @@ import { DEFAULT_SYSTEM_SCHEMAS } from '../lib/constants' import { Tables } from '../lib/interfaces' const router = Router() + router.get('/', async (req, res) => { try { const sql = ` WITH tables AS ( ${tables} ), -columns AS ( ${columns} ), -grants AS ( ${grants} ), -primary_keys AS ( ${primary_keys} ), -relationships AS ( ${relationships} ) + columns AS ( ${columns} ), + grants AS ( ${grants} ), + primary_keys AS ( ${primary_keys} ), + relationships AS ( ${relationships} ) SELECT *, ${coalesceRowsToArray('columns', 'SELECT * FROM columns WHERE columns.table_id = tables.id')}, @@ -46,6 +47,7 @@ FROM res.status(500).json({ error: 'Database error', status: 500 }) } }) + router.post('/', async (req, res) => { try { const { schema = 'public', name } = req.body as { @@ -68,6 +70,7 @@ router.post('/', async (req, res) => { res.status(200).json([{ error: error.toString() }]) } }) + router.patch('/:id', async (req, res) => { try { const id: number = parseInt(req.params.id) @@ -96,6 +99,24 @@ router.patch('/:id', async (req, res) => { } }) +router.delete('/:id', async (req, res) => { + try { + const id = req.params.id + const getTableQuery = SQL``.append(tables).append(SQL` AND c.oid = ${id}`) + const table = (await RunQuery(req.headers.pg, getTableQuery)).data[0] + const { name, schema } = table + + const cascade = req.query.cascade + const query = `DROP TABLE "${schema}"."${name}" ${cascade === 'true' ? 'CASCADE' : 'RESTRICT'}` + await RunQuery(req.headers.pg, query) + + return res.status(200).json(table) + } catch (error) { + console.log('throwing error', error) + res.status(500).json({ error: 'Database error', status: 500 }) + } +}) + export = router const selectSingleSql = (id: number) => { @@ -105,11 +126,11 @@ const selectSingleByName = (schema: string, name: string) => { return SQL``.append(tables).append(SQL` and table_schema = ${schema} and table_name = ${name}`) } const createTable = (name: string, schema: string = 'postgres') => { - const query = SQL``.append(`CREATE TABLE ${schema}.${name} ()`) + const query = SQL``.append(`CREATE TABLE "${schema}"."${name}" ()`) return query } const alterTableName = (previousName: string, newName: string, schema: string) => { - const query = SQL``.append(`ALTER SCHEMA ${previousName} RENAME TO ${newName}`) + const query = SQL``.append(`ALTER TABLE "${schema}"."${previousName}" RENAME TO "${newName}"`) return query } const removeSystemSchemas = (data: Tables.Table[]) => { diff --git a/test/integration/index.spec.js b/test/integration/index.spec.js index 7dd07054..4f54e95c 100644 --- a/test/integration/index.spec.js +++ b/test/integration/index.spec.js @@ -99,7 +99,7 @@ describe('/schemas', () => { assert.equal(true, !!datum) assert.equal(true, !!included) }) - it('POST & PATCH', async () => { + it('POST & PATCH & DELETE', async () => { const res = await axios.post(`${URL}/schemas`, { name: 'api' }) assert.equal('api', res.data.name) const newSchemaId = res.data.id @@ -110,6 +110,15 @@ describe('/schemas', () => { owner: 'postgres', }) assert.equal('api', res3.data.name) + + const res4 = await axios.delete(`${URL}/schemas/${newSchemaId}`) + assert.equal(res4.data.name, 'api') + + const res5 = await axios.get(`${URL}/schemas`) + assert.equal( + res5.data.some((x) => x.id === newSchemaId), + false + ) }) }) describe('/types', () => { @@ -169,12 +178,19 @@ describe('/tables & /columns', async () => { assert.equal(true, relationship.target_table_schema === 'public') assert.equal(true, relationship.target_table_name === 'users') }) - it('GET /tabls with system tables', async () => { + it('GET /tables with system tables', async () => { const res = await axios.get(`${URL}/tables?includeSystemSchemas=true`) const included = res.data.find((x) => `${x.schema}.${x.name}` === 'pg_catalog.pg_type') assert.equal(res.status, STATUS.SUCCESS) assert.equal(true, !!included) }) + // FIXME: Bad handling of query param in /tables & /columns & /schemas & /types + // it('GET /tables without system tables (explicit)', async () => { + // const res = await axios.get(`${URL}/tables?includeSystemSchemas=false`) + // const isIncluded = res.data.some((x) => `${x.schema}.${x.name}` === 'pg_catalog.pg_type') + // assert.equal(res.status, STATUS.SUCCESS) + // assert.equal(isIncluded, false) + // }) it('GET /columns', async () => { const res = await axios.get(`${URL}/columns`) // console.log('res.data', res.data) @@ -194,30 +210,84 @@ describe('/tables & /columns', async () => { assert.equal(true, !!included) }) it('POST /tables should create a table', async () => { - await axios.post(`${URL}/query`, { query: 'DROP TABLE IF EXISTS public.test' }) - let {data: newTable} = await axios.post(`${URL}/tables`, { - schema: 'public', - name: 'test', - // columns: [ - // { name: 'id', is_identity: true, is_nullable: false, data_type: 'bigint' }, - // { name: 'data', data_type: 'text' }, - // ], - // primary_keys: ['id'], - }) - // console.log('newTable', newTable) - const newTableId = newTable.id - assert.equal(newTableId > 0, true) - // const { data: tables } = await axios.get(`${URL}/tables`) - // const test = tables.find((table) => `${table.schema}.${table.name}` === 'public.test') - // const id = test.columns.find((column) => column.name === 'id') - // const data = test.columns.find((column) => column.name === 'data') - // assert.equal(id.is_identity, true) - // assert.equal(id.is_nullable, false) - // assert.equal(id.data_type, 'bigint') - // assert.equal(data.is_identity, false) - // assert.equal(data.is_nullable, true) - // assert.equal(data.data_type, 'text') - await axios.post(`${URL}/query`, { query: 'DROP TABLE public.test' }) + const { data: newTable } = await axios.post(`${URL}/tables`, { name: 'test' }) + assert.equal(`${newTable.schema}.${newTable.name}`, 'public.test') + + const { data: tables } = await axios.get(`${URL}/tables`) + assert.equal( + tables.some((table) => table.id === newTable.id), + true + ) + + await axios.delete(`${URL}/tables/${newTable.id}`) + }) + it('PATCH /tables', async () => { + const { data: newTable } = await axios.post(`${URL}/tables`, { name: 'test' }) + await axios.patch(`${URL}/tables/${newTable.id}`, { name: 'test a' }) + const { data: tables } = await axios.get(`${URL}/tables`) + assert.equal( + tables.some((table) => `${table.schema}.${table.name}` === `public.test a`), + true + ) + + await axios.delete(`${URL}/tables/${newTable.id}`) + }) + it('DELETE /tables', async () => { + const { data: newTable } = await axios.post(`${URL}/tables`, { name: 'test' }) + + await axios.delete(`${URL}/tables/${newTable.id}`) + const { data: tables } = await axios.get(`${URL}/tables`) + assert.equal( + tables.some((table) => `${table.schema}.${table.name}` === `public.test`), + false + ) + }) + it('POST /column', async () => { + const { data: newTable } = await axios.post(`${URL}/tables`, { name: 'foo bar' }) + await axios.post(`${URL}/columns`, { tableId: newTable.id, name: 'foo bar', type: 'int2' }) + + const { data: columns } = await axios.get(`${URL}/columns`) + assert.equal( + columns.some( + (column) => + column.id === `${newTable.id}.1` && column.name === 'foo bar' && column.format === 'int2' + ), + true + ) + + await axios.delete(`${URL}/columns/${newTable.id}.1`) + await axios.delete(`${URL}/tables/${newTable.id}`) + }) + it('PATCH /columns', async () => { + const { data: newTable } = await axios.post(`${URL}/tables`, { name: 'foo bar' }) + await axios.post(`${URL}/columns`, { tableId: newTable.id, name: 'foo', type: 'int2' }) + + await axios.patch(`${URL}/columns/${newTable.id}.1`, { name: 'foo bar', type: 'int4' }) + + const { data: columns } = await axios.get(`${URL}/columns`) + assert.equal( + columns.some( + (column) => + column.id === `${newTable.id}.1` && column.name === 'foo bar' && column.format === 'int4' + ), + true + ) + + await axios.delete(`${URL}/columns/${newTable.id}.1`) + await axios.delete(`${URL}/tables/${newTable.id}`) + }) + it('DELETE /columns', async () => { + const { data: newTable } = await axios.post(`${URL}/tables`, { name: 'foo bar' }) + await axios.post(`${URL}/columns`, { tableId: newTable.id, name: 'foo bar', type: 'int2' }) + + await axios.delete(`${URL}/columns/${newTable.id}.1`) + const { data: columns } = await axios.get(`${URL}/columns`) + assert.equal( + columns.some((column) => column.id === `${newTable.id}.1`), + false + ) + + await axios.delete(`${URL}/tables/${newTable.id}`) }) }) describe('/extensions', () => {