From 798068180cb3eda5a23b3fdcaee7d7bda8796dc7 Mon Sep 17 00:00:00 2001 From: Tianzhou Date: Wed, 17 Dec 2025 08:33:29 -0800 Subject: [PATCH 1/2] fix: partial index --- ir/normalize.go | 19 +- ir/queries/queries.sql | 231 ++++++++++------- ir/queries/queries.sql.go | 237 +++++++++++------- testdata/diff/migrate/v2/diff.sql | 2 +- .../diff/online/add_partial_index/diff.sql | 2 +- .../diff/online/add_partial_index/new.sql | 6 +- .../diff/online/add_partial_index/old.sql | 4 +- .../diff/online/add_partial_index/plan.json | 4 +- .../diff/online/add_partial_index/plan.sql | 2 +- .../diff/online/add_partial_index/plan.txt | 2 +- testdata/dump/employee/pgschema.sql | 2 +- 11 files changed, 322 insertions(+), 189 deletions(-) diff --git a/ir/normalize.go b/ir/normalize.go index df1e8590..1fdf97d8 100644 --- a/ir/normalize.go +++ b/ir/normalize.go @@ -896,7 +896,16 @@ func applyLegacyCheckNormalizations(clause string) string { } // convertAnyArrayToIn converts PostgreSQL's "column = ANY (ARRAY[...])" format -// to the more readable "column IN (...)" format +// to the more readable "column IN (...)" format. +// +// Type casts are always preserved to ensure: +// - Custom types (enums, domains) are properly qualified (e.g., 'value'::public.my_enum) +// - Output matches pg_dump's format exactly +// - Comparison between desired and current states is accurate +// +// Example transformations: +// - "status = ANY (ARRAY['active'::public.status_type])" → "status IN ('active'::public.status_type)" +// - "gender = ANY (ARRAY['M'::text, 'F'::text])" → "gender IN ('M'::text, 'F'::text)" func convertAnyArrayToIn(expr string) string { if !strings.Contains(expr, "= ANY (ARRAY[") { return expr @@ -917,19 +926,15 @@ func convertAnyArrayToIn(expr string) string { valuesPart = strings.TrimSuffix(valuesPart, "]))") valuesPart = strings.TrimSuffix(valuesPart, "])") - // Split the values and clean them up + // Split values and preserve them as-is, including all type casts values := strings.Split(valuesPart, ", ") var cleanValues []string for _, val := range values { val = strings.TrimSpace(val) - // Remove type casts like ::text, ::varchar, etc. - if idx := strings.Index(val, "::"); idx != -1 { - val = val[:idx] - } cleanValues = append(cleanValues, val) } - // Return converted format: "column IN ('val1', 'val2')" + // Return converted format: "column IN ('val1'::type, 'val2'::type)" return fmt.Sprintf("%s IN (%s)", columnName, strings.Join(cleanValues, ", ")) } diff --git a/ir/queries/queries.sql b/ir/queries/queries.sql index 7ad9c7f7..cf1fb4c9 100644 --- a/ir/queries/queries.sql +++ b/ir/queries/queries.sql @@ -296,97 +296,156 @@ WHERE n.nspname NOT IN ('information_schema', 'pg_catalog', 'pg_toast') ORDER BY n.nspname, cl.relname, c.contype, c.conname, a.attnum; -- GetIndexes retrieves all indexes including regular and unique indexes created with CREATE INDEX +-- IMPORTANT: Uses LATERAL join with set_config to temporarily set search_path to empty +-- This ensures pg_get_expr() includes schema qualifiers for types in partial index predicates, +-- matching pg_dump's behavior and preventing false positives when comparing schemas -- name: GetIndexes :many -SELECT - n.nspname as schemaname, - t.relname as tablename, - i.relname as indexname, - idx.indisunique as is_unique, - idx.indisprimary as is_primary, - (idx.indpred IS NOT NULL) as is_partial, - am.amname as method, - pg_get_indexdef(idx.indexrelid) as indexdef, - CASE - WHEN idx.indpred IS NOT NULL THEN pg_get_expr(idx.indpred, idx.indrelid) - ELSE NULL - END as partial_predicate, - CASE - WHEN idx.indexprs IS NOT NULL THEN true - ELSE false - END as has_expressions -FROM pg_index idx -JOIN pg_class i ON i.oid = idx.indexrelid -JOIN pg_class t ON t.oid = idx.indrelid -JOIN pg_namespace n ON n.oid = t.relnamespace -JOIN pg_am am ON am.oid = i.relam -WHERE - NOT idx.indisprimary - AND NOT EXISTS ( - SELECT 1 FROM pg_constraint c - WHERE c.conindid = idx.indexrelid - AND c.contype IN ('u', 'p') - ) - AND n.nspname NOT IN ('information_schema', 'pg_catalog', 'pg_toast') - AND n.nspname NOT LIKE 'pg_temp_%' - AND n.nspname NOT LIKE 'pg_toast_temp_%' -ORDER BY n.nspname, t.relname, i.relname; +WITH index_base AS ( + SELECT + n.nspname as schemaname, + t.relname as tablename, + i.relname as indexname, + idx.indisunique as is_unique, + idx.indisprimary as is_primary, + (idx.indpred IS NOT NULL) as is_partial, + am.amname as method, + pg_get_indexdef(idx.indexrelid) as indexdef, + idx.indpred, + idx.indrelid, + CASE + WHEN idx.indexprs IS NOT NULL THEN true + ELSE false + END as has_expressions + FROM pg_index idx + JOIN pg_class i ON i.oid = idx.indexrelid + JOIN pg_class t ON t.oid = idx.indrelid + JOIN pg_namespace n ON n.oid = t.relnamespace + JOIN pg_am am ON am.oid = i.relam + WHERE + NOT idx.indisprimary + AND NOT EXISTS ( + SELECT 1 FROM pg_constraint c + WHERE c.conindid = idx.indexrelid + AND c.contype IN ('u', 'p') + ) + AND n.nspname NOT IN ('information_schema', 'pg_catalog', 'pg_toast') + AND n.nspname NOT LIKE 'pg_temp_%' + AND n.nspname NOT LIKE 'pg_toast_temp_%' +) +SELECT + ib.schemaname, + ib.tablename, + ib.indexname, + ib.is_unique, + ib.is_primary, + ib.is_partial, + ib.method, + ib.indexdef, + -- Use LATERAL join to guarantee execution order: + -- 1. set_config sets search_path to empty (like pg_dump does) + -- 2. pg_get_expr then uses that search_path + -- This ensures type references are schema-qualified (e.g., 'value'::public.my_enum) + sp.partial_predicate, + ib.has_expressions +FROM index_base ib +CROSS JOIN LATERAL ( + SELECT + set_config('search_path', '', true) as dummy, + CASE + WHEN ib.indpred IS NOT NULL THEN pg_get_expr(ib.indpred, ib.indrelid) + ELSE NULL + END as partial_predicate +) sp +ORDER BY ib.schemaname, ib.tablename, ib.indexname; -- GetIndexesForSchema retrieves all indexes for a specific schema +-- IMPORTANT: Uses LATERAL join with set_config to temporarily set search_path to empty +-- This ensures pg_get_expr() includes schema qualifiers for types in partial index predicates, +-- matching pg_dump's behavior and preventing false positives when comparing schemas -- name: GetIndexesForSchema :many -SELECT - n.nspname as schemaname, - t.relname as tablename, - i.relname as indexname, - idx.indisunique as is_unique, - idx.indisprimary as is_primary, - (idx.indpred IS NOT NULL) as is_partial, - am.amname as method, - pg_get_indexdef(idx.indexrelid) as indexdef, - CASE - WHEN idx.indpred IS NOT NULL THEN pg_get_expr(idx.indpred, idx.indrelid) - ELSE NULL - END as partial_predicate, - CASE - WHEN idx.indexprs IS NOT NULL THEN true - ELSE false - END as has_expressions, - COALESCE(d.description, '') AS index_comment, - idx.indnatts as num_columns, - ARRAY( - SELECT pg_get_indexdef(idx.indexrelid, k::int, true) - FROM generate_series(1, idx.indnatts) k - ) as column_definitions, - ARRAY( - SELECT - CASE - WHEN (idx.indoption[k-1] & 1) = 1 THEN 'DESC' - ELSE 'ASC' +WITH index_base AS ( + SELECT + n.nspname as schemaname, + t.relname as tablename, + i.relname as indexname, + idx.indisunique as is_unique, + idx.indisprimary as is_primary, + (idx.indpred IS NOT NULL) as is_partial, + am.amname as method, + pg_get_indexdef(idx.indexrelid) as indexdef, + idx.indpred, + idx.indrelid, + CASE + WHEN idx.indexprs IS NOT NULL THEN true + ELSE false + END as has_expressions, + COALESCE(d.description, '') AS index_comment, + idx.indnatts as num_columns, + ARRAY( + SELECT pg_get_indexdef(idx.indexrelid, k::int, true) + FROM generate_series(1, idx.indnatts) k + ) as column_definitions, + ARRAY( + SELECT + CASE + WHEN (idx.indoption[k-1] & 1) = 1 THEN 'DESC' + ELSE 'ASC' + END + FROM generate_series(1, idx.indnatts) k + ) as column_directions, + ARRAY( + SELECT CASE + WHEN opc.opcdefault THEN '' -- Omit default operator classes + ELSE COALESCE(opc.opcname, '') END - FROM generate_series(1, idx.indnatts) k - ) as column_directions, - ARRAY( - SELECT CASE - WHEN opc.opcdefault THEN '' -- Omit default operator classes - ELSE COALESCE(opc.opcname, '') - END - FROM generate_series(1, idx.indnatts) k - LEFT JOIN pg_opclass opc ON opc.oid = idx.indclass[k-1] - ) as column_opclasses -FROM pg_index idx -JOIN pg_class i ON i.oid = idx.indexrelid -JOIN pg_class t ON t.oid = idx.indrelid -JOIN pg_namespace n ON n.oid = t.relnamespace -JOIN pg_am am ON am.oid = i.relam -LEFT JOIN pg_description d ON d.objoid = i.oid AND d.objsubid = 0 -WHERE - NOT idx.indisprimary - AND NOT EXISTS ( - SELECT 1 FROM pg_constraint c - WHERE c.conindid = idx.indexrelid - AND c.contype IN ('u', 'p') - ) - AND n.nspname = $1 -ORDER BY n.nspname, t.relname, i.relname; + FROM generate_series(1, idx.indnatts) k + LEFT JOIN pg_opclass opc ON opc.oid = idx.indclass[k-1] + ) as column_opclasses + FROM pg_index idx + JOIN pg_class i ON i.oid = idx.indexrelid + JOIN pg_class t ON t.oid = idx.indrelid + JOIN pg_namespace n ON n.oid = t.relnamespace + JOIN pg_am am ON am.oid = i.relam + LEFT JOIN pg_description d ON d.objoid = i.oid AND d.objsubid = 0 + WHERE + NOT idx.indisprimary + AND NOT EXISTS ( + SELECT 1 FROM pg_constraint c + WHERE c.conindid = idx.indexrelid + AND c.contype IN ('u', 'p') + ) + AND n.nspname = $1 +) +SELECT + ib.schemaname, + ib.tablename, + ib.indexname, + ib.is_unique, + ib.is_primary, + ib.is_partial, + ib.method, + ib.indexdef, + -- Use LATERAL join to guarantee execution order: + -- 1. set_config sets search_path to empty (like pg_dump does) + -- 2. pg_get_expr then uses that search_path + -- This ensures type references are schema-qualified (e.g., 'value'::public.my_enum) + sp.partial_predicate, + ib.has_expressions, + ib.index_comment, + ib.num_columns, + ib.column_definitions, + ib.column_directions, + ib.column_opclasses +FROM index_base ib +CROSS JOIN LATERAL ( + SELECT + set_config('search_path', '', true) as dummy, + CASE + WHEN ib.indpred IS NOT NULL THEN pg_get_expr(ib.indpred, ib.indrelid) + ELSE NULL + END as partial_predicate +) sp +ORDER BY ib.schemaname, ib.tablename, ib.indexname; -- GetSequences retrieves all sequences -- name: GetSequences :many diff --git a/ir/queries/queries.sql.go b/ir/queries/queries.sql.go index 0316c340..f8bfd276 100644 --- a/ir/queries/queries.sql.go +++ b/ir/queries/queries.sql.go @@ -432,6 +432,12 @@ SELECT -- a single query level. The LATERAL join guarantees this happens row-by-row, -- and 'true' in the WHERE clause ensures set_config is called for every row. -- This pattern mirrors GetViewsForSchema (line 959-963) for consistency. + -- + -- Alternative considered: Create a custom PostgreSQL function wrapping pg_get_expr + -- with search_path control. Rejected because: + -- 1. Requires creating database objects (function) on target database + -- 2. pgschema operates in read-only inspection mode + -- 3. LATERAL join pattern is PostgreSQL-native and well-documented ge.generated_expr FROM column_base cb LEFT JOIN LATERAL ( @@ -1350,39 +1356,63 @@ func (q *Queries) GetFunctionsForSchema(ctx context.Context, dollar_1 sql.NullSt } const getIndexes = `-- name: GetIndexes :many -SELECT - n.nspname as schemaname, - t.relname as tablename, - i.relname as indexname, - idx.indisunique as is_unique, - idx.indisprimary as is_primary, - (idx.indpred IS NOT NULL) as is_partial, - am.amname as method, - pg_get_indexdef(idx.indexrelid) as indexdef, - CASE - WHEN idx.indpred IS NOT NULL THEN pg_get_expr(idx.indpred, idx.indrelid) - ELSE NULL - END as partial_predicate, - CASE - WHEN idx.indexprs IS NOT NULL THEN true - ELSE false - END as has_expressions -FROM pg_index idx -JOIN pg_class i ON i.oid = idx.indexrelid -JOIN pg_class t ON t.oid = idx.indrelid -JOIN pg_namespace n ON n.oid = t.relnamespace -JOIN pg_am am ON am.oid = i.relam -WHERE - NOT idx.indisprimary - AND NOT EXISTS ( - SELECT 1 FROM pg_constraint c - WHERE c.conindid = idx.indexrelid - AND c.contype IN ('u', 'p') - ) - AND n.nspname NOT IN ('information_schema', 'pg_catalog', 'pg_toast') - AND n.nspname NOT LIKE 'pg_temp_%' - AND n.nspname NOT LIKE 'pg_toast_temp_%' -ORDER BY n.nspname, t.relname, i.relname +WITH index_base AS ( + SELECT + n.nspname as schemaname, + t.relname as tablename, + i.relname as indexname, + idx.indisunique as is_unique, + idx.indisprimary as is_primary, + (idx.indpred IS NOT NULL) as is_partial, + am.amname as method, + pg_get_indexdef(idx.indexrelid) as indexdef, + idx.indpred, + idx.indrelid, + CASE + WHEN idx.indexprs IS NOT NULL THEN true + ELSE false + END as has_expressions + FROM pg_index idx + JOIN pg_class i ON i.oid = idx.indexrelid + JOIN pg_class t ON t.oid = idx.indrelid + JOIN pg_namespace n ON n.oid = t.relnamespace + JOIN pg_am am ON am.oid = i.relam + WHERE + NOT idx.indisprimary + AND NOT EXISTS ( + SELECT 1 FROM pg_constraint c + WHERE c.conindid = idx.indexrelid + AND c.contype IN ('u', 'p') + ) + AND n.nspname NOT IN ('information_schema', 'pg_catalog', 'pg_toast') + AND n.nspname NOT LIKE 'pg_temp_%' + AND n.nspname NOT LIKE 'pg_toast_temp_%' +) +SELECT + ib.schemaname, + ib.tablename, + ib.indexname, + ib.is_unique, + ib.is_primary, + ib.is_partial, + ib.method, + ib.indexdef, + -- Use LATERAL join to guarantee execution order: + -- 1. set_config sets search_path to empty (like pg_dump does) + -- 2. pg_get_expr then uses that search_path + -- This ensures type references are schema-qualified (e.g., 'value'::public.my_enum) + sp.partial_predicate, + ib.has_expressions +FROM index_base ib +CROSS JOIN LATERAL ( + SELECT + set_config('search_path', '', true) as dummy, + CASE + WHEN ib.indpred IS NOT NULL THEN pg_get_expr(ib.indpred, ib.indrelid) + ELSE NULL + END as partial_predicate +) sp +ORDER BY ib.schemaname, ib.tablename, ib.indexname ` type GetIndexesRow struct { @@ -1399,6 +1429,9 @@ type GetIndexesRow struct { } // GetIndexes retrieves all indexes including regular and unique indexes created with CREATE INDEX +// IMPORTANT: Uses LATERAL join with set_config to temporarily set search_path to empty +// This ensures pg_get_expr() includes schema qualifiers for types in partial index predicates, +// matching pg_dump's behavior and preventing false positives when comparing schemas func (q *Queries) GetIndexes(ctx context.Context) ([]GetIndexesRow, error) { rows, err := q.db.QueryContext(ctx, getIndexes) if err != nil { @@ -1434,60 +1467,89 @@ func (q *Queries) GetIndexes(ctx context.Context) ([]GetIndexesRow, error) { } const getIndexesForSchema = `-- name: GetIndexesForSchema :many -SELECT - n.nspname as schemaname, - t.relname as tablename, - i.relname as indexname, - idx.indisunique as is_unique, - idx.indisprimary as is_primary, - (idx.indpred IS NOT NULL) as is_partial, - am.amname as method, - pg_get_indexdef(idx.indexrelid) as indexdef, - CASE - WHEN idx.indpred IS NOT NULL THEN pg_get_expr(idx.indpred, idx.indrelid) - ELSE NULL - END as partial_predicate, - CASE - WHEN idx.indexprs IS NOT NULL THEN true - ELSE false - END as has_expressions, - COALESCE(d.description, '') AS index_comment, - idx.indnatts as num_columns, - ARRAY( - SELECT pg_get_indexdef(idx.indexrelid, k::int, true) - FROM generate_series(1, idx.indnatts) k - ) as column_definitions, - ARRAY( - SELECT - CASE - WHEN (idx.indoption[k-1] & 1) = 1 THEN 'DESC' - ELSE 'ASC' +WITH index_base AS ( + SELECT + n.nspname as schemaname, + t.relname as tablename, + i.relname as indexname, + idx.indisunique as is_unique, + idx.indisprimary as is_primary, + (idx.indpred IS NOT NULL) as is_partial, + am.amname as method, + pg_get_indexdef(idx.indexrelid) as indexdef, + idx.indpred, + idx.indrelid, + CASE + WHEN idx.indexprs IS NOT NULL THEN true + ELSE false + END as has_expressions, + COALESCE(d.description, '') AS index_comment, + idx.indnatts as num_columns, + ARRAY( + SELECT pg_get_indexdef(idx.indexrelid, k::int, true) + FROM generate_series(1, idx.indnatts) k + ) as column_definitions, + ARRAY( + SELECT + CASE + WHEN (idx.indoption[k-1] & 1) = 1 THEN 'DESC' + ELSE 'ASC' + END + FROM generate_series(1, idx.indnatts) k + ) as column_directions, + ARRAY( + SELECT CASE + WHEN opc.opcdefault THEN '' -- Omit default operator classes + ELSE COALESCE(opc.opcname, '') END - FROM generate_series(1, idx.indnatts) k - ) as column_directions, - ARRAY( - SELECT CASE - WHEN opc.opcdefault THEN '' -- Omit default operator classes - ELSE COALESCE(opc.opcname, '') - END - FROM generate_series(1, idx.indnatts) k - LEFT JOIN pg_opclass opc ON opc.oid = idx.indclass[k-1] - ) as column_opclasses -FROM pg_index idx -JOIN pg_class i ON i.oid = idx.indexrelid -JOIN pg_class t ON t.oid = idx.indrelid -JOIN pg_namespace n ON n.oid = t.relnamespace -JOIN pg_am am ON am.oid = i.relam -LEFT JOIN pg_description d ON d.objoid = i.oid AND d.objsubid = 0 -WHERE - NOT idx.indisprimary - AND NOT EXISTS ( - SELECT 1 FROM pg_constraint c - WHERE c.conindid = idx.indexrelid - AND c.contype IN ('u', 'p') - ) - AND n.nspname = $1 -ORDER BY n.nspname, t.relname, i.relname + FROM generate_series(1, idx.indnatts) k + LEFT JOIN pg_opclass opc ON opc.oid = idx.indclass[k-1] + ) as column_opclasses + FROM pg_index idx + JOIN pg_class i ON i.oid = idx.indexrelid + JOIN pg_class t ON t.oid = idx.indrelid + JOIN pg_namespace n ON n.oid = t.relnamespace + JOIN pg_am am ON am.oid = i.relam + LEFT JOIN pg_description d ON d.objoid = i.oid AND d.objsubid = 0 + WHERE + NOT idx.indisprimary + AND NOT EXISTS ( + SELECT 1 FROM pg_constraint c + WHERE c.conindid = idx.indexrelid + AND c.contype IN ('u', 'p') + ) + AND n.nspname = $1 +) +SELECT + ib.schemaname, + ib.tablename, + ib.indexname, + ib.is_unique, + ib.is_primary, + ib.is_partial, + ib.method, + ib.indexdef, + -- Use LATERAL join to guarantee execution order: + -- 1. set_config sets search_path to empty (like pg_dump does) + -- 2. pg_get_expr then uses that search_path + -- This ensures type references are schema-qualified (e.g., 'value'::public.my_enum) + sp.partial_predicate, + ib.has_expressions, + ib.index_comment, + ib.num_columns, + ib.column_definitions, + ib.column_directions, + ib.column_opclasses +FROM index_base ib +CROSS JOIN LATERAL ( + SELECT + set_config('search_path', '', true) as dummy, + CASE + WHEN ib.indpred IS NOT NULL THEN pg_get_expr(ib.indpred, ib.indrelid) + ELSE NULL + END as partial_predicate +) sp +ORDER BY ib.schemaname, ib.tablename, ib.indexname ` type GetIndexesForSchemaRow struct { @@ -1509,6 +1571,9 @@ type GetIndexesForSchemaRow struct { } // GetIndexesForSchema retrieves all indexes for a specific schema +// IMPORTANT: Uses LATERAL join with set_config to temporarily set search_path to empty +// This ensures pg_get_expr() includes schema qualifiers for types in partial index predicates, +// matching pg_dump's behavior and preventing false positives when comparing schemas func (q *Queries) GetIndexesForSchema(ctx context.Context, dollar_1 sql.NullString) ([]GetIndexesForSchemaRow, error) { rows, err := q.db.QueryContext(ctx, getIndexesForSchema, dollar_1) if err != nil { diff --git a/testdata/diff/migrate/v2/diff.sql b/testdata/diff/migrate/v2/diff.sql index b8bdd7de..3f798956 100644 --- a/testdata/diff/migrate/v2/diff.sql +++ b/testdata/diff/migrate/v2/diff.sql @@ -22,7 +22,7 @@ ALTER TABLE dept_manager ADD CONSTRAINT dept_manager_emp_no_fkey FOREIGN KEY (emp_no) REFERENCES employee (emp_no) ON DELETE CASCADE; ALTER TABLE employee -ADD CONSTRAINT employee_gender_check CHECK (gender IN ('M', 'F')); +ADD CONSTRAINT employee_gender_check CHECK (gender IN ('M'::text, 'F'::text)); CREATE INDEX IF NOT EXISTS idx_employee_hire_date ON employee (hire_date); diff --git a/testdata/diff/online/add_partial_index/diff.sql b/testdata/diff/online/add_partial_index/diff.sql index 6c154bbb..6cf158fb 100644 --- a/testdata/diff/online/add_partial_index/diff.sql +++ b/testdata/diff/online/add_partial_index/diff.sql @@ -1 +1 @@ -CREATE INDEX IF NOT EXISTS idx_active_orders_customer_date ON orders (customer_id, order_date DESC, total_amount) WHERE status IN ('pending', 'processing', 'confirmed'); +CREATE INDEX IF NOT EXISTS idx_active_orders_customer_date ON orders (customer_id, order_date DESC, total_amount) WHERE status IN ('pending'::public.order_status, 'processing'::public.order_status, 'confirmed'::public.order_status); diff --git a/testdata/diff/online/add_partial_index/new.sql b/testdata/diff/online/add_partial_index/new.sql index 262530b2..8f9a0f30 100644 --- a/testdata/diff/online/add_partial_index/new.sql +++ b/testdata/diff/online/add_partial_index/new.sql @@ -1,7 +1,9 @@ +CREATE TYPE public.order_status AS ENUM ('pending', 'processing', 'confirmed', 'shipped', 'delivered', 'cancelled'); + CREATE TABLE public.orders ( id integer NOT NULL, customer_id integer, - status text, + status order_status, order_date date, total_amount numeric(10,2), payment_status text, @@ -9,4 +11,4 @@ CREATE TABLE public.orders ( updated_at timestamp with time zone ); -CREATE INDEX idx_active_orders_customer_date ON public.orders USING btree (customer_id, order_date DESC, total_amount) WHERE status IN ('pending', 'processing', 'confirmed'); \ No newline at end of file +CREATE INDEX idx_active_orders_customer_date ON public.orders USING btree (customer_id, order_date DESC, total_amount) WHERE status IN ('pending'::order_status, 'processing'::order_status, 'confirmed'::order_status); \ No newline at end of file diff --git a/testdata/diff/online/add_partial_index/old.sql b/testdata/diff/online/add_partial_index/old.sql index dc6a28ab..4928b62c 100644 --- a/testdata/diff/online/add_partial_index/old.sql +++ b/testdata/diff/online/add_partial_index/old.sql @@ -1,7 +1,9 @@ +CREATE TYPE public.order_status AS ENUM ('pending', 'processing', 'confirmed', 'shipped', 'delivered', 'cancelled'); + CREATE TABLE public.orders ( id integer NOT NULL, customer_id integer, - status text, + status order_status, order_date date, total_amount numeric(10,2), payment_status text, diff --git a/testdata/diff/online/add_partial_index/plan.json b/testdata/diff/online/add_partial_index/plan.json index 562222f1..75784978 100644 --- a/testdata/diff/online/add_partial_index/plan.json +++ b/testdata/diff/online/add_partial_index/plan.json @@ -3,13 +3,13 @@ "pgschema_version": "1.5.0", "created_at": "1970-01-01T00:00:00Z", "source_fingerprint": { - "hash": "9414dcd6f114495bf21d3cce73629e2ab5a8ee6f7db38dc848bca4c80206bd3a" + "hash": "027caac0137fe70d301cf88a60838a17a20662da10176ce34adab03d7ab985dd" }, "groups": [ { "steps": [ { - "sql": "CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_active_orders_customer_date ON orders (customer_id, order_date DESC, total_amount) WHERE status IN ('pending', 'processing', 'confirmed');", + "sql": "CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_active_orders_customer_date ON orders (customer_id, order_date DESC, total_amount) WHERE status IN ('pending'::public.order_status, 'processing'::public.order_status, 'confirmed'::public.order_status);", "type": "table.index", "operation": "create", "path": "public.orders.idx_active_orders_customer_date" diff --git a/testdata/diff/online/add_partial_index/plan.sql b/testdata/diff/online/add_partial_index/plan.sql index b700201a..99e4ca03 100644 --- a/testdata/diff/online/add_partial_index/plan.sql +++ b/testdata/diff/online/add_partial_index/plan.sql @@ -1,4 +1,4 @@ -CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_active_orders_customer_date ON orders (customer_id, order_date DESC, total_amount) WHERE status IN ('pending', 'processing', 'confirmed'); +CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_active_orders_customer_date ON orders (customer_id, order_date DESC, total_amount) WHERE status IN ('pending'::public.order_status, 'processing'::public.order_status, 'confirmed'::public.order_status); -- pgschema:wait SELECT diff --git a/testdata/diff/online/add_partial_index/plan.txt b/testdata/diff/online/add_partial_index/plan.txt index fb584ad7..f29ad623 100644 --- a/testdata/diff/online/add_partial_index/plan.txt +++ b/testdata/diff/online/add_partial_index/plan.txt @@ -11,7 +11,7 @@ DDL to be executed: -------------------------------------------------- -- Transaction Group #1 -CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_active_orders_customer_date ON orders (customer_id, order_date DESC, total_amount) WHERE status IN ('pending', 'processing', 'confirmed'); +CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_active_orders_customer_date ON orders (customer_id, order_date DESC, total_amount) WHERE status IN ('pending'::public.order_status, 'processing'::public.order_status, 'confirmed'::public.order_status); -- Transaction Group #2 -- pgschema:wait diff --git a/testdata/dump/employee/pgschema.sql b/testdata/dump/employee/pgschema.sql index da1b3fa3..ef1b4d21 100644 --- a/testdata/dump/employee/pgschema.sql +++ b/testdata/dump/employee/pgschema.sql @@ -78,7 +78,7 @@ CREATE TABLE IF NOT EXISTS employee ( gender text NOT NULL, hire_date date NOT NULL, CONSTRAINT employee_pkey PRIMARY KEY (emp_no), - CONSTRAINT employee_gender_check CHECK (gender IN ('M', 'F')) + CONSTRAINT employee_gender_check CHECK (gender IN ('M'::text, 'F'::text)) ); -- From fa31fab093f3076da70a7c93acf37c344a73dcaf Mon Sep 17 00:00:00 2001 From: tianzhou Date: Wed, 17 Dec 2025 20:45:57 -0800 Subject: [PATCH 2/2] chore: fix test case --- testdata/diff/migrate/v2/plan.json | 2 +- testdata/diff/migrate/v2/plan.sql | 2 +- testdata/diff/migrate/v2/plan.txt | 2 +- testdata/diff/migrate/v3/plan.json | 2 +- testdata/diff/migrate/v4/plan.json | 2 +- testdata/diff/migrate/v5/plan.json | 2 +- testdata/dump/bytebase/pgschema.sql | 12 ++++++------ testdata/include/expected_full_schema.sql | 2 +- testdata/include/tables/orders.sql | 2 +- 9 files changed, 14 insertions(+), 14 deletions(-) diff --git a/testdata/diff/migrate/v2/plan.json b/testdata/diff/migrate/v2/plan.json index 64016d26..0c2b5515 100644 --- a/testdata/diff/migrate/v2/plan.json +++ b/testdata/diff/migrate/v2/plan.json @@ -87,7 +87,7 @@ "path": "public.dept_manager.dept_manager_emp_no_fkey" }, { - "sql": "ALTER TABLE employee\nADD CONSTRAINT employee_gender_check CHECK (gender IN ('M', 'F')) NOT VALID;", + "sql": "ALTER TABLE employee\nADD CONSTRAINT employee_gender_check CHECK (gender IN ('M'::text, 'F'::text)) NOT VALID;", "type": "table.constraint", "operation": "create", "path": "public.employee.employee_gender_check" diff --git a/testdata/diff/migrate/v2/plan.sql b/testdata/diff/migrate/v2/plan.sql index 7cffa08c..1cfa6c83 100644 --- a/testdata/diff/migrate/v2/plan.sql +++ b/testdata/diff/migrate/v2/plan.sql @@ -30,7 +30,7 @@ ADD CONSTRAINT dept_manager_emp_no_fkey FOREIGN KEY (emp_no) REFERENCES employee ALTER TABLE dept_manager VALIDATE CONSTRAINT dept_manager_emp_no_fkey; ALTER TABLE employee -ADD CONSTRAINT employee_gender_check CHECK (gender IN ('M', 'F')) NOT VALID; +ADD CONSTRAINT employee_gender_check CHECK (gender IN ('M'::text, 'F'::text)) NOT VALID; ALTER TABLE employee VALIDATE CONSTRAINT employee_gender_check; diff --git a/testdata/diff/migrate/v2/plan.txt b/testdata/diff/migrate/v2/plan.txt index dbfe57fb..fa006f05 100644 --- a/testdata/diff/migrate/v2/plan.txt +++ b/testdata/diff/migrate/v2/plan.txt @@ -63,7 +63,7 @@ ADD CONSTRAINT dept_manager_emp_no_fkey FOREIGN KEY (emp_no) REFERENCES employee ALTER TABLE dept_manager VALIDATE CONSTRAINT dept_manager_emp_no_fkey; ALTER TABLE employee -ADD CONSTRAINT employee_gender_check CHECK (gender IN ('M', 'F')) NOT VALID; +ADD CONSTRAINT employee_gender_check CHECK (gender IN ('M'::text, 'F'::text)) NOT VALID; ALTER TABLE employee VALIDATE CONSTRAINT employee_gender_check; diff --git a/testdata/diff/migrate/v3/plan.json b/testdata/diff/migrate/v3/plan.json index 7186f361..0c5a2b64 100644 --- a/testdata/diff/migrate/v3/plan.json +++ b/testdata/diff/migrate/v3/plan.json @@ -3,7 +3,7 @@ "pgschema_version": "1.5.0", "created_at": "1970-01-01T00:00:00Z", "source_fingerprint": { - "hash": "b07ab6318b6ff348aa5554a1f6e1a1ec9ad6b987a6d47e455fbdf97f1b0b96fb" + "hash": "9329b8621db3e793651fd617ad5e8a6301c168562d9db784ae5a6f89b6a47544" }, "groups": [ { diff --git a/testdata/diff/migrate/v4/plan.json b/testdata/diff/migrate/v4/plan.json index c8043513..22cb9d3f 100644 --- a/testdata/diff/migrate/v4/plan.json +++ b/testdata/diff/migrate/v4/plan.json @@ -3,7 +3,7 @@ "pgschema_version": "1.5.0", "created_at": "1970-01-01T00:00:00Z", "source_fingerprint": { - "hash": "a51544f8a42466271edf94486458c736751f3e18db92371137fafad144e95bfc" + "hash": "73cb3763bd04c0c4065b4af796613ff72b7eeb1b9f9639f5adbbdf2c8654f019" }, "groups": [ { diff --git a/testdata/diff/migrate/v5/plan.json b/testdata/diff/migrate/v5/plan.json index e5d6df84..e68ee7b4 100644 --- a/testdata/diff/migrate/v5/plan.json +++ b/testdata/diff/migrate/v5/plan.json @@ -3,7 +3,7 @@ "pgschema_version": "1.5.0", "created_at": "1970-01-01T00:00:00Z", "source_fingerprint": { - "hash": "79ba873c42fd02b3faebc027cefce1ad32bfa45985caa85ae35ed39762424cf5" + "hash": "8251b49db73f8777c28fc88ee639cf97964e218d34258d24d77e417e8e079b0d" }, "groups": [ { diff --git a/testdata/dump/bytebase/pgschema.sql b/testdata/dump/bytebase/pgschema.sql index 99b2a2de..027af93c 100644 --- a/testdata/dump/bytebase/pgschema.sql +++ b/testdata/dump/bytebase/pgschema.sql @@ -71,7 +71,7 @@ CREATE TABLE IF NOT EXISTS idp ( type text NOT NULL, config jsonb DEFAULT '{}' NOT NULL, CONSTRAINT idp_pkey PRIMARY KEY (id), - CONSTRAINT idp_type_check CHECK (type IN ('OAUTH2', 'OIDC', 'LDAP')) + CONSTRAINT idp_type_check CHECK (type IN ('OAUTH2'::text, 'OIDC'::text, 'LDAP'::text)) ); -- @@ -165,7 +165,7 @@ CREATE TABLE IF NOT EXISTS principal ( mfa_config jsonb DEFAULT '{}' NOT NULL, profile jsonb DEFAULT '{}' NOT NULL, CONSTRAINT principal_pkey PRIMARY KEY (id), - CONSTRAINT principal_type_check CHECK (type IN ('END_USER', 'SYSTEM_BOT', 'SERVICE_ACCOUNT')) + CONSTRAINT principal_type_check CHECK (type IN ('END_USER'::text, 'SYSTEM_BOT'::text, 'SERVICE_ACCOUNT'::text)) ); -- @@ -357,7 +357,7 @@ CREATE TABLE IF NOT EXISTS issue ( CONSTRAINT issue_pipeline_id_fkey FOREIGN KEY (pipeline_id) REFERENCES pipeline (id), CONSTRAINT issue_plan_id_fkey FOREIGN KEY (plan_id) REFERENCES plan (id), CONSTRAINT issue_project_fkey FOREIGN KEY (project) REFERENCES project (resource_id), - CONSTRAINT issue_status_check CHECK (status IN ('OPEN', 'DONE', 'CANCELED')) + CONSTRAINT issue_status_check CHECK (status IN ('OPEN'::text, 'DONE'::text, 'CANCELED'::text)) ); -- @@ -446,7 +446,7 @@ CREATE TABLE IF NOT EXISTS plan_check_run ( payload jsonb DEFAULT '{}' NOT NULL, CONSTRAINT plan_check_run_pkey PRIMARY KEY (id), CONSTRAINT plan_check_run_plan_id_fkey FOREIGN KEY (plan_id) REFERENCES plan (id), - CONSTRAINT plan_check_run_status_check CHECK (status IN ('RUNNING', 'DONE', 'FAILED', 'CANCELED')), + CONSTRAINT plan_check_run_status_check CHECK (status IN ('RUNNING'::text, 'DONE'::text, 'FAILED'::text, 'CANCELED'::text)), CONSTRAINT plan_check_run_type_check CHECK (type LIKE 'bb.plan-check.%') ); @@ -689,7 +689,7 @@ CREATE TABLE IF NOT EXISTS changelog ( CONSTRAINT changelog_instance_db_name_fkey FOREIGN KEY (instance, db_name) REFERENCES db (instance, name), CONSTRAINT changelog_prev_sync_history_id_fkey FOREIGN KEY (prev_sync_history_id) REFERENCES sync_history (id), CONSTRAINT changelog_sync_history_id_fkey FOREIGN KEY (sync_history_id) REFERENCES sync_history (id), - CONSTRAINT changelog_status_check CHECK (status IN ('PENDING', 'DONE', 'FAILED')) + CONSTRAINT changelog_status_check CHECK (status IN ('PENDING'::text, 'DONE'::text, 'FAILED'::text)) ); -- @@ -742,7 +742,7 @@ CREATE TABLE IF NOT EXISTS task_run ( CONSTRAINT task_run_creator_id_fkey FOREIGN KEY (creator_id) REFERENCES principal (id), CONSTRAINT task_run_sheet_id_fkey FOREIGN KEY (sheet_id) REFERENCES sheet (id), CONSTRAINT task_run_task_id_fkey FOREIGN KEY (task_id) REFERENCES task (id), - CONSTRAINT task_run_status_check CHECK (status IN ('PENDING', 'RUNNING', 'DONE', 'FAILED', 'CANCELED')) + CONSTRAINT task_run_status_check CHECK (status IN ('PENDING'::text, 'RUNNING'::text, 'DONE'::text, 'FAILED'::text, 'CANCELED'::text)) ); -- diff --git a/testdata/include/expected_full_schema.sql b/testdata/include/expected_full_schema.sql index edb3b073..01d9364f 100644 --- a/testdata/include/expected_full_schema.sql +++ b/testdata/include/expected_full_schema.sql @@ -127,7 +127,7 @@ CREATE TABLE IF NOT EXISTS orders ( amount numeric(10,2) DEFAULT 0.00, CONSTRAINT orders_pkey PRIMARY KEY (id), CONSTRAINT orders_user_id_fkey FOREIGN KEY (user_id) REFERENCES users (id), - CONSTRAINT orders_status_check CHECK (status IN ('pending', 'completed')) + CONSTRAINT orders_status_check CHECK (status IN ('pending'::text, 'completed'::text)) ); COMMENT ON TABLE orders IS 'Customer orders'; diff --git a/testdata/include/tables/orders.sql b/testdata/include/tables/orders.sql index d64bdd44..2fbb65d9 100644 --- a/testdata/include/tables/orders.sql +++ b/testdata/include/tables/orders.sql @@ -9,7 +9,7 @@ CREATE TABLE IF NOT EXISTS orders ( amount numeric(10,2) DEFAULT 0.00, CONSTRAINT orders_pkey PRIMARY KEY (id), CONSTRAINT orders_user_id_fkey FOREIGN KEY (user_id) REFERENCES users (id), - CONSTRAINT orders_status_check CHECK (status IN ('pending', 'completed')) + CONSTRAINT orders_status_check CHECK (status IN ('pending'::text, 'completed'::text)) ); COMMENT ON TABLE orders IS 'Customer orders';