Skip to content

fix: remove pg-meta dep by embedding required logic #43

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 1 commit into from
Apr 9, 2025
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
2,091 changes: 34 additions & 2,057 deletions package-lock.json

Large diffs are not rendered by default.

5 changes: 1 addition & 4 deletions packages/mcp-server-supabase/package.json
Original file line number Diff line number Diff line change
Expand Up @@ -27,14 +27,11 @@
}
},
"dependencies": {
"@gregnr/postgres-meta": "^0.82.0-dev.2",
"@modelcontextprotocol/sdk": "^1.4.1",
"@supabase/mcp-utils": "0.1.2",
"common-tags": "^1.8.2",
"openapi-fetch": "^0.13.4",
"postgres": "^3.4.5",
"zod": "^3.24.1",
"zod-to-json-schema": "^3.24.1"
"zod": "^3.24.1"
},
"devDependencies": {
"@electric-sql/pglite": "^0.2.17",
Expand Down
111 changes: 111 additions & 0 deletions packages/mcp-server-supabase/src/pg-meta/columns.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,111 @@
-- Adapted from information_schema.columns

SELECT
c.oid :: int8 AS table_id,
nc.nspname AS schema,
c.relname AS table,
(c.oid || '.' || a.attnum) AS id,
a.attnum AS ordinal_position,
a.attname AS name,
CASE
WHEN a.atthasdef THEN pg_get_expr(ad.adbin, ad.adrelid)
ELSE NULL
END AS default_value,
CASE
WHEN t.typtype = 'd' THEN CASE
WHEN bt.typelem <> 0 :: oid
AND bt.typlen = -1 THEN 'ARRAY'
WHEN nbt.nspname = 'pg_catalog' THEN format_type(t.typbasetype, NULL)
ELSE 'USER-DEFINED'
END
ELSE CASE
WHEN t.typelem <> 0 :: oid
AND t.typlen = -1 THEN 'ARRAY'
WHEN nt.nspname = 'pg_catalog' THEN format_type(a.atttypid, NULL)
ELSE 'USER-DEFINED'
END
END AS data_type,
COALESCE(bt.typname, t.typname) AS format,
a.attidentity IN ('a', 'd') AS is_identity,
CASE
a.attidentity
WHEN 'a' THEN 'ALWAYS'
WHEN 'd' THEN 'BY DEFAULT'
ELSE NULL
END AS identity_generation,
a.attgenerated IN ('s') AS is_generated,
NOT (
a.attnotnull
OR t.typtype = 'd' AND t.typnotnull
) AS is_nullable,
(
c.relkind IN ('r', 'p')
OR c.relkind IN ('v', 'f') AND pg_column_is_updatable(c.oid, a.attnum, FALSE)
) AS is_updatable,
uniques.table_id IS NOT NULL AS is_unique,
check_constraints.definition AS "check",
array_to_json(
array(
SELECT
enumlabel
FROM
pg_catalog.pg_enum enums
WHERE
enums.enumtypid = coalesce(bt.oid, t.oid)
OR enums.enumtypid = coalesce(bt.typelem, t.typelem)
ORDER BY
enums.enumsortorder
)
) AS enums,
col_description(c.oid, a.attnum) AS comment
FROM
pg_attribute a
LEFT JOIN pg_attrdef ad ON a.attrelid = ad.adrelid
AND a.attnum = ad.adnum
JOIN (
pg_class c
JOIN pg_namespace nc ON c.relnamespace = nc.oid
) ON a.attrelid = c.oid
JOIN (
pg_type t
JOIN pg_namespace nt ON t.typnamespace = nt.oid
) ON a.atttypid = t.oid
LEFT JOIN (
pg_type bt
JOIN pg_namespace nbt ON bt.typnamespace = nbt.oid
) ON t.typtype = 'd'
AND t.typbasetype = bt.oid
LEFT JOIN (
SELECT DISTINCT ON (table_id, ordinal_position)
conrelid AS table_id,
conkey[1] AS ordinal_position
FROM pg_catalog.pg_constraint
WHERE contype = 'u' AND cardinality(conkey) = 1
) AS uniques ON uniques.table_id = c.oid AND uniques.ordinal_position = a.attnum
LEFT JOIN (
-- We only select the first column check
SELECT DISTINCT ON (table_id, ordinal_position)
conrelid AS table_id,
conkey[1] AS ordinal_position,
substring(
pg_get_constraintdef(pg_constraint.oid, true),
8,
length(pg_get_constraintdef(pg_constraint.oid, true)) - 8
) AS "definition"
FROM pg_constraint
WHERE contype = 'c' AND cardinality(conkey) = 1
ORDER BY table_id, ordinal_position, oid asc
) AS check_constraints ON check_constraints.table_id = c.oid AND check_constraints.ordinal_position = a.attnum
WHERE
NOT pg_is_other_temp_schema(nc.oid)
AND a.attnum > 0
AND NOT a.attisdropped
AND (c.relkind IN ('r', 'v', 'm', 'f', 'p'))
AND (
pg_has_role(c.relowner, 'USAGE')
OR has_column_privilege(
c.oid,
a.attnum,
'SELECT, INSERT, UPDATE, REFERENCES'
)
)
10 changes: 10 additions & 0 deletions packages/mcp-server-supabase/src/pg-meta/extensions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
SELECT
e.name,
n.nspname AS schema,
e.default_version,
x.extversion AS installed_version,
e.comment
FROM
pg_available_extensions() e(name, default_version, comment)
LEFT JOIN pg_extension x ON e.name = x.extname
LEFT JOIN pg_namespace n ON x.extnamespace = n.oid
49 changes: 49 additions & 0 deletions packages/mcp-server-supabase/src/pg-meta/index.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,49 @@
import { stripIndent } from 'common-tags';
import columnsSql from './columns.sql';
import extensionsSql from './extensions.sql';
import tablesSql from './tables.sql';

/**
* Generates the SQL query to list tables in the database.
*/
export function listTablesSql(schemas: string[] = []) {
let sql = stripIndent`
with
tables as (${tablesSql}),
columns as (${columnsSql})
select
*,
${coalesceRowsToArray('columns', 'columns.table_id = tables.id')}
from tables
`;

if (schemas.length > 0) {
sql += ` where schema in (${schemas.map((s) => `'${s}'`).join(',')})`;
}

return sql;
}

/**
* Generates the SQL query to list all extensions in the database.
*/
export function listExtensionsSql() {
return extensionsSql;
}

/**
* Generates a SQL segment that coalesces rows into an array of JSON objects.
*/
export const coalesceRowsToArray = (source: string, filter: string) => {
return stripIndent`
COALESCE(
(
SELECT
array_agg(row_to_json(${source})) FILTER (WHERE ${filter})
FROM
${source}
),
'{}'
) AS ${source}
`;
};
98 changes: 98 additions & 0 deletions packages/mcp-server-supabase/src/pg-meta/tables.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,98 @@
SELECT
c.oid :: int8 AS id,
nc.nspname AS schema,
c.relname AS name,
c.relrowsecurity AS rls_enabled,
c.relforcerowsecurity AS rls_forced,
CASE
WHEN c.relreplident = 'd' THEN 'DEFAULT'
WHEN c.relreplident = 'i' THEN 'INDEX'
WHEN c.relreplident = 'f' THEN 'FULL'
ELSE 'NOTHING'
END AS replica_identity,
pg_total_relation_size(format('%I.%I', nc.nspname, c.relname)) :: int8 AS bytes,
pg_size_pretty(
pg_total_relation_size(format('%I.%I', nc.nspname, c.relname))
) AS size,
pg_stat_get_live_tuples(c.oid) AS live_rows_estimate,
pg_stat_get_dead_tuples(c.oid) AS dead_rows_estimate,
obj_description(c.oid) AS comment,
coalesce(pk.primary_keys, '[]') as primary_keys,
coalesce(
jsonb_agg(relationships) filter (where relationships is not null),
'[]'
) as relationships
FROM
pg_namespace nc
JOIN pg_class c ON nc.oid = c.relnamespace
left join (
select
table_id,
jsonb_agg(_pk.*) as primary_keys
from (
select
n.nspname as schema,
c.relname as table_name,
a.attname as name,
c.oid :: int8 as table_id
from
pg_index i,
pg_class c,
pg_attribute a,
pg_namespace n
where
i.indrelid = c.oid
and c.relnamespace = n.oid
and a.attrelid = c.oid
and a.attnum = any (i.indkey)
and i.indisprimary
) as _pk
group by table_id
) as pk
on pk.table_id = c.oid
left join (
select
c.oid :: int8 as id,
c.conname as constraint_name,
nsa.nspname as source_schema,
csa.relname as source_table_name,
sa.attname as source_column_name,
nta.nspname as target_table_schema,
cta.relname as target_table_name,
ta.attname as target_column_name
from
pg_constraint c
join (
pg_attribute sa
join pg_class csa on sa.attrelid = csa.oid
join pg_namespace nsa on csa.relnamespace = nsa.oid
) on sa.attrelid = c.conrelid and sa.attnum = any (c.conkey)
join (
pg_attribute ta
join pg_class cta on ta.attrelid = cta.oid
join pg_namespace nta on cta.relnamespace = nta.oid
) on ta.attrelid = c.confrelid and ta.attnum = any (c.confkey)
where
c.contype = 'f'
) as relationships
on (relationships.source_schema = nc.nspname and relationships.source_table_name = c.relname)
or (relationships.target_table_schema = nc.nspname and relationships.target_table_name = c.relname)
WHERE
c.relkind IN ('r', 'p')
AND NOT pg_is_other_temp_schema(nc.oid)
AND (
pg_has_role(c.relowner, 'USAGE')
OR has_table_privilege(
c.oid,
'SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER'
)
OR has_any_column_privilege(c.oid, 'SELECT, INSERT, UPDATE, REFERENCES')
)
group by
c.oid,
c.relname,
c.relrowsecurity,
c.relforcerowsecurity,
c.relreplident,
nc.nspname,
pk.primary_keys
80 changes: 80 additions & 0 deletions packages/mcp-server-supabase/src/pg-meta/types.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,80 @@
import { z } from 'zod';

export const postgresPrimaryKeySchema = z.object({
schema: z.string(),
table_name: z.string(),
name: z.string(),
table_id: z.number().int(),
});

export const postgresRelationshipSchema = z.object({
id: z.number().int(),
constraint_name: z.string(),
source_schema: z.string(),
source_table_name: z.string(),
source_column_name: z.string(),
target_table_schema: z.string(),
target_table_name: z.string(),
target_column_name: z.string(),
});

export const postgresColumnSchema = z.object({
table_id: z.number().int(),
schema: z.string(),
table: z.string(),
id: z.string().regex(/^(\d+)\.(\d+)$/),
ordinal_position: z.number().int(),
name: z.string(),
default_value: z.any(),
data_type: z.string(),
format: z.string(),
is_identity: z.boolean(),
identity_generation: z.union([
z.literal('ALWAYS'),
z.literal('BY DEFAULT'),
z.null(),
]),
is_generated: z.boolean(),
is_nullable: z.boolean(),
is_updatable: z.boolean(),
is_unique: z.boolean(),
enums: z.array(z.string()),
check: z.union([z.string(), z.null()]),
comment: z.union([z.string(), z.null()]),
});

export const postgresTableSchema = z.object({
id: z.number().int(),
schema: z.string(),
name: z.string(),
rls_enabled: z.boolean(),
rls_forced: z.boolean(),
replica_identity: z.union([
z.literal('DEFAULT'),
z.literal('INDEX'),
z.literal('FULL'),
z.literal('NOTHING'),
]),
bytes: z.number().int(),
size: z.string(),
live_rows_estimate: z.number().int(),
dead_rows_estimate: z.number().int(),
comment: z.string().nullable(),
columns: z.array(postgresColumnSchema).optional(),
primary_keys: z.array(postgresPrimaryKeySchema),
relationships: z.array(postgresRelationshipSchema),
});

export const postgresExtensionSchema = z.object({
name: z.string(),
schema: z.union([z.string(), z.null()]),
default_version: z.string(),
installed_version: z.union([z.string(), z.null()]),
comment: z.union([z.string(), z.null()]),
});

export type PostgresPrimaryKey = z.infer<typeof postgresPrimaryKeySchema>;
export type PostgresRelationship = z.infer<typeof postgresRelationshipSchema>;
export type PostgresColumn = z.infer<typeof postgresColumnSchema>;
export type PostgresTable = z.infer<typeof postgresTableSchema>;
export type PostgresExtension = z.infer<typeof postgresExtensionSchema>;
Loading