Skip to content

Commit 803868a

Browse files
Use jsonb_strip_nulls in read_schema function (#925)
Stop creating empty objects and lists in the JSON returned by the `read_schema` function for each table. Empty fields are now now omitted from the returned JSON object, rather than being present with empty/lists maps. Example: * Create a simple table: ```sql CREATE TABLE items(id int) ``` * Run: ```sql SELECT jsonb_pretty(pgroll.read_schema('public')) ``` **Before this change**: ``` +--------------------------------------------+ | jsonb_pretty | |--------------------------------------------| | { | | "name": "public", | | "tables": { | | "items": { | | "oid": "16437", | | "name": "items", | | "columns": { | | "id": { | | "name": "id", | | "type": "integer", | | "unique": false, | | "comment": null, | | "default": null, | | "nullable": true, | | "enumvalues": null, | | "postgrestype": "base" | | } | | }, | | "comment": null, | | "indexes": { | | }, | | "primaryKey": [ | | ], | | "foreignKeys": { | | }, | | "checkConstraints": { | | }, | | "uniqueConstraints": { | | }, | | "excludeConstraints": { | | } | | } | | } | | } | +--------------------------------------------+ ``` **After this change** ``` +--------------------------------------------+ | jsonb_pretty | |--------------------------------------------| | { | | "name": "public", | | "tables": { | | "items": { | | "oid": "16437", | | "name": "items", | | "columns": { | | "id": { | | "name": "id", | | "type": "integer", | | "unique": false, | | "nullable": true, | | "postgrestype": "base" | | } | | } | | } | | } | | } | +--------------------------------------------+ ``` `null` and empty fields are removed from the resulting JSON, reducing bloat in the `pgroll.migrations` table for large schema.
1 parent b6c7a94 commit 803868a

File tree

3 files changed

+23
-146
lines changed

3 files changed

+23
-146
lines changed

pkg/roll/baseline_test.go

Lines changed: 0 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -47,12 +47,6 @@ func TestBaseline(t *testing.T) {
4747
PostgresType: "base",
4848
},
4949
},
50-
PrimaryKey: []string{},
51-
Indexes: map[string]*schema.Index{},
52-
ForeignKeys: map[string]*schema.ForeignKey{},
53-
CheckConstraints: map[string]*schema.CheckConstraint{},
54-
UniqueConstraints: map[string]*schema.UniqueConstraint{},
55-
ExcludeConstraints: map[string]*schema.ExcludeConstraint{},
5650
},
5751
},
5852
}

pkg/state/init.sql

Lines changed: 22 additions & 22 deletions
Original file line numberDiff line numberDiff line change
@@ -193,14 +193,14 @@ BEGIN
193193
SELECT
194194
json_build_object('name', schemaname, 'tables', (
195195
SELECT
196-
COALESCE(json_object_agg(t.relname, jsonb_build_object('name', t.relname, 'oid', t.oid, 'comment', descr.description, 'columns', (
197-
SELECT
198-
COALESCE(json_object_agg(name, c), '{}'::json)
199-
FROM (
200-
SELECT
201-
attr.attname AS name, pg_get_expr(def.adbin, def.adrelid) AS default, NOT (attr.attnotnull
202-
OR tp.typtype = 'd'
203-
AND tp.typnotnull) AS nullable, CASE WHEN 'character varying'::regtype = ANY (ARRAY[attr.atttypid, tp.typelem]) THEN
196+
COALESCE(json_object_agg(t.relname, jsonb_strip_nulls (jsonb_build_object('name', t.relname, 'oid', t.oid, 'comment', descr.description, 'columns', (
197+
SELECT
198+
json_object_agg(name, c)
199+
FROM (
200+
SELECT
201+
attr.attname AS name, pg_get_expr(def.adbin, def.adrelid) AS default, NOT (attr.attnotnull
202+
OR tp.typtype = 'd'
203+
AND tp.typnotnull) AS nullable, CASE WHEN 'character varying'::regtype = ANY (ARRAY[attr.atttypid, tp.typelem]) THEN
204204
REPLACE(format_type(attr.atttypid, attr.atttypmod), 'character varying', 'varchar')
205205
WHEN 'timestamp with time zone'::regtype = ANY (ARRAY[attr.atttypid, tp.typelem]) THEN
206206
REPLACE(format_type(attr.atttypid, attr.atttypmod), 'timestamp with time zone', 'timestamptz')
@@ -252,7 +252,7 @@ BEGIN
252252
AND NOT attr.attisdropped
253253
AND attr.attrelid = t.oid ORDER BY attr.attnum) c), 'primaryKey', (
254254
SELECT
255-
COALESCE(json_agg(pg_attribute.attname), '[]'::json) AS primary_key_columns
255+
json_agg(pg_attribute.attname) AS primary_key_columns
256256
FROM pg_index, pg_attribute
257257
WHERE
258258
indrelid = t.oid
@@ -261,7 +261,7 @@ BEGIN
261261
AND pg_attribute.attnum = ANY (pg_index.indkey)
262262
AND indisprimary), 'indexes', (
263263
SELECT
264-
COALESCE(json_object_agg(ix_details.name, json_build_object('name', ix_details.name, 'unique', ix_details.indisunique, 'exclusion', ix_details.indisexclusion, 'columns', ix_details.columns, 'predicate', ix_details.predicate, 'method', ix_details.method, 'definition', ix_details.definition)), '{}'::json)
264+
json_object_agg(ix_details.name, json_build_object('name', ix_details.name, 'unique', ix_details.indisunique, 'exclusion', ix_details.indisexclusion, 'columns', ix_details.columns, 'predicate', ix_details.predicate, 'method', ix_details.method, 'definition', ix_details.definition))
265265
FROM (
266266
SELECT
267267
replace(reverse(split_part(reverse(pi.indexrelid::regclass::text), '.', 1)), '"', '') AS name, pi.indisunique, pi.indisexclusion, array_agg(a.attname) AS columns, pg_get_expr(pi.indpred, t.oid) AS predicate, am.amname AS method, pg_get_indexdef(pi.indexrelid) AS definition
@@ -273,7 +273,7 @@ BEGIN
273273
WHERE
274274
indrelid = t.oid::regclass GROUP BY pi.indexrelid, pi.indisunique, pi.indpred, am.amname) AS ix_details), 'checkConstraints', (
275275
SELECT
276-
COALESCE(json_object_agg(cc_details.conname, json_build_object('name', cc_details.conname, 'columns', cc_details.columns, 'definition', cc_details.definition, 'noInherit', cc_details.connoinherit)), '{}'::json)
276+
json_object_agg(cc_details.conname, json_build_object('name', cc_details.conname, 'columns', cc_details.columns, 'definition', cc_details.definition, 'noInherit', cc_details.connoinherit))
277277
FROM (
278278
SELECT
279279
cc_constraint.conname, array_agg(cc_attr.attname ORDER BY cc_constraint.conkey::int[]) AS columns, pg_get_constraintdef(cc_constraint.oid) AS definition, cc_constraint.connoinherit FROM pg_constraint AS cc_constraint
@@ -283,7 +283,7 @@ BEGIN
283283
cc_constraint.conrelid = t.oid
284284
AND cc_constraint.contype = 'c' GROUP BY cc_constraint.oid, cc_constraint.conname) AS cc_details), 'uniqueConstraints', (
285285
SELECT
286-
COALESCE(json_object_agg(uc_details.conname, json_build_object('name', uc_details.conname, 'columns', uc_details.columns)), '{}'::json)
286+
json_object_agg(uc_details.conname, json_build_object('name', uc_details.conname, 'columns', uc_details.columns))
287287
FROM (
288288
SELECT
289289
uc_constraint.conname, array_agg(uc_attr.attname ORDER BY uc_constraint.conkey::int[]) AS columns, pg_get_constraintdef(uc_constraint.oid) AS definition FROM pg_constraint AS uc_constraint
@@ -293,7 +293,7 @@ BEGIN
293293
uc_constraint.conrelid = t.oid
294294
AND uc_constraint.contype = 'u' GROUP BY uc_constraint.oid, uc_constraint.conname) AS uc_details), 'excludeConstraints', (
295295
SELECT
296-
COALESCE(json_object_agg(xc_details.conname, json_build_object('name', xc_details.conname, 'columns', xc_details.columns, 'definition', xc_details.definition, 'predicate', xc_details.predicate, 'method', xc_details.method)), '{}'::json)
296+
json_object_agg(xc_details.conname, json_build_object('name', xc_details.conname, 'columns', xc_details.columns, 'definition', xc_details.definition, 'predicate', xc_details.predicate, 'method', xc_details.method))
297297
FROM (
298298
SELECT
299299
xc_constraint.conname, array_agg(xc_attr.attname ORDER BY xc_constraint.conkey::int[]) AS columns, pg_get_expr(pi.indpred, t.oid) AS predicate, am.amname AS method, pg_get_constraintdef(xc_constraint.oid) AS definition FROM pg_constraint AS xc_constraint
@@ -306,7 +306,7 @@ BEGIN
306306
xc_constraint.conrelid = t.oid
307307
AND xc_constraint.contype = 'x' GROUP BY xc_constraint.oid, xc_constraint.conname, pi.indpred, pi.indexrelid, am.amname) AS xc_details), 'foreignKeys', (
308308
SELECT
309-
COALESCE(json_object_agg(fk_details.conname, json_build_object('name', fk_details.conname, 'columns', fk_details.columns, 'referencedTable', fk_details.referencedTable, 'referencedColumns', fk_details.referencedColumns, 'matchType', fk_details.matchType, 'onDelete', fk_details.onDelete, 'onUpdate', fk_details.onUpdate)), '{}'::json)
309+
json_object_agg(fk_details.conname, json_build_object('name', fk_details.conname, 'columns', fk_details.columns, 'referencedTable', fk_details.referencedTable, 'referencedColumns', fk_details.referencedColumns, 'matchType', fk_details.matchType, 'onDelete', fk_details.onDelete, 'onUpdate', fk_details.onUpdate))
310310
FROM (
311311
SELECT
312312
fk_info.conname AS conname, fk_info.columns AS columns, fk_info.relname AS referencedTable, array_agg(ref_attr.attname ORDER BY ref_attr.attname) AS referencedColumns, CASE WHEN fk_info.confmatchtype = 'f' THEN
@@ -346,14 +346,14 @@ BEGIN
346346
AND fk_constraint.contype = 'f' GROUP BY fk_constraint.conrelid, fk_constraint.conname, fk_constraint.confrelid, fk_cl.relname, fk_constraint.confkey, fk_constraint.confmatchtype, fk_constraint.confdeltype, fk_constraint.confupdtype) AS fk_info
347347
INNER JOIN pg_attribute ref_attr ON ref_attr.attrelid = fk_info.confrelid
348348
AND ref_attr.attnum = ANY (fk_info.confkey) -- join the columns of the referenced table
349-
GROUP BY fk_info.conname, fk_info.conrelid, fk_info.columns, fk_info.confrelid, fk_info.confmatchtype, fk_info.confdeltype, fk_info.confupdtype, fk_info.relname) AS fk_details))), '{}'::json)
350-
FROM pg_class AS t
351-
INNER JOIN pg_namespace AS ns ON t.relnamespace = ns.oid
352-
LEFT JOIN pg_description AS descr ON t.oid = descr.objoid
353-
AND descr.objsubid = 0
354-
WHERE
355-
ns.nspname = schemaname
356-
AND t.relkind IN ('r', 'p') -- tables only (ignores views, materialized views & foreign tables)
349+
GROUP BY fk_info.conname, fk_info.conrelid, fk_info.columns, fk_info.confrelid, fk_info.confmatchtype, fk_info.confdeltype, fk_info.confupdtype, fk_info.relname) AS fk_details)))), '{}'::json)
350+
FROM pg_class AS t
351+
INNER JOIN pg_namespace AS ns ON t.relnamespace = ns.oid
352+
LEFT JOIN pg_description AS descr ON t.oid = descr.objoid
353+
AND descr.objsubid = 0
354+
WHERE
355+
ns.nspname = schemaname
356+
AND t.relkind IN ('r', 'p') -- tables only (ignores views, materialized views & foreign tables)
357357
)) INTO tables;
358358
RETURN tables;
359359
END;

0 commit comments

Comments
 (0)