diff --git a/cmd/dump/dump_integration_test.go b/cmd/dump/dump_integration_test.go index b1b6731d..fb040ee9 100644 --- a/cmd/dump/dump_integration_test.go +++ b/cmd/dump/dump_integration_test.go @@ -256,7 +256,8 @@ func runTenantSchemaTest(t *testing.T, testDataDir string) { } } -// normalizeSchemaOutput removes version-specific lines for comparison +// normalizeSchemaOutput removes version-specific lines for comparison. +// This allows comparing dumps across different PostgreSQL versions. func normalizeSchemaOutput(output string) string { lines := strings.Split(output, "\n") var normalizedLines []string diff --git a/ir/normalize.go b/ir/normalize.go index 0d585293..52dec79d 100644 --- a/ir/normalize.go +++ b/ir/normalize.go @@ -141,6 +141,14 @@ func normalizeDefaultValue(value string, tableSchema string) string { re := regexp.MustCompile(`::pgschema_tmp_[^.]+\.`) value = re.ReplaceAllString(value, "::") } + // Also strip same-schema type qualifiers for consistent comparison during plan/diff + // This ensures that '::public.typename' from current state matches '::typename' from + // desired state (after pgschema_tmp_* is stripped). Both are semantically equivalent + // within the same schema context. (Issue #218) + if tableSchema != "" && strings.Contains(value, "::"+tableSchema+".") { + re := regexp.MustCompile(`::\Q` + tableSchema + `\E\.`) + value = re.ReplaceAllString(value, "::") + } // Handle NULL::type -> NULL // Example: NULL::text -> NULL diff --git a/ir/queries/queries.sql b/ir/queries/queries.sql index bc65c84d..fe2164ab 100644 --- a/ir/queries/queries.sql +++ b/ir/queries/queries.sql @@ -56,74 +56,116 @@ ORDER BY t.table_name; -- GetColumns retrieves all columns for all tables -- name: GetColumns :many +WITH column_base AS ( + SELECT + c.table_schema, + c.table_name, + c.column_name, + c.ordinal_position, + c.column_default, + c.is_nullable, + c.data_type, + c.character_maximum_length, + c.numeric_precision, + c.numeric_scale, + c.udt_name, + COALESCE(d.description, '') AS column_comment, + CASE + WHEN dt.typtype = 'd' THEN + CASE WHEN dn.nspname = c.table_schema THEN dt.typname + ELSE dn.nspname || '.' || dt.typname + END + WHEN dt.typtype = 'e' OR dt.typtype = 'c' THEN + CASE WHEN dn.nspname = c.table_schema THEN dt.typname + ELSE dn.nspname || '.' || dt.typname + END + WHEN dt.typtype = 'b' AND dt.typelem <> 0 THEN + -- Array types: apply same schema qualification logic to element type + CASE + WHEN en.nspname = 'pg_catalog' THEN et.typname || '[]' + WHEN en.nspname = c.table_schema THEN et.typname || '[]' + ELSE en.nspname || '.' || et.typname || '[]' + END + WHEN dt.typtype = 'b' THEN + -- Non-array base types: qualify if not in pg_catalog or table's schema + CASE + WHEN dn.nspname = 'pg_catalog' THEN c.udt_name + WHEN dn.nspname = c.table_schema THEN dt.typname + ELSE dn.nspname || '.' || dt.typname + END + ELSE c.udt_name + END AS resolved_type, + c.is_identity, + c.identity_generation, + c.identity_start, + c.identity_increment, + c.identity_maximum, + c.identity_minimum, + c.identity_cycle, + a.attgenerated, + ad.adbin, + ad.adrelid + FROM information_schema.columns c + LEFT JOIN pg_class cl ON cl.relname = c.table_name + LEFT JOIN pg_namespace n ON cl.relnamespace = n.oid AND n.nspname = c.table_schema + LEFT JOIN pg_description d ON d.objoid = cl.oid AND d.classoid = 'pg_class'::regclass AND d.objsubid = c.ordinal_position + LEFT JOIN pg_attribute a ON a.attrelid = cl.oid AND a.attname = c.column_name + LEFT JOIN pg_attrdef ad ON ad.adrelid = a.attrelid AND ad.adnum = a.attnum + LEFT JOIN pg_type dt ON dt.oid = a.atttypid + LEFT JOIN pg_namespace dn ON dt.typnamespace = dn.oid + LEFT JOIN pg_type et ON dt.typelem = et.oid + LEFT JOIN pg_namespace en ON et.typnamespace = en.oid + WHERE + c.table_schema NOT IN ('information_schema', 'pg_catalog', 'pg_toast') + AND c.table_schema NOT LIKE 'pg_temp_%' + AND c.table_schema NOT LIKE 'pg_toast_temp_%' +) SELECT - c.table_schema, - c.table_name, - c.column_name, - c.ordinal_position, - CASE - WHEN a.attgenerated = 's' THEN NULL -- Generated columns don't have defaults - ELSE COALESCE(pg_get_expr(ad.adbin, ad.adrelid), c.column_default) - END AS column_default, - c.is_nullable, - c.data_type, - c.character_maximum_length, - c.numeric_precision, - c.numeric_scale, - c.udt_name, - COALESCE(d.description, '') AS column_comment, - CASE - WHEN dt.typtype = 'd' THEN - CASE WHEN dn.nspname = c.table_schema THEN dt.typname - ELSE dn.nspname || '.' || dt.typname - END - WHEN dt.typtype = 'e' OR dt.typtype = 'c' THEN - CASE WHEN dn.nspname = c.table_schema THEN dt.typname - ELSE dn.nspname || '.' || dt.typname - END - WHEN dt.typtype = 'b' AND dt.typelem <> 0 THEN - -- Array types: apply same schema qualification logic to element type - CASE - WHEN en.nspname = 'pg_catalog' THEN et.typname || '[]' - WHEN en.nspname = c.table_schema THEN et.typname || '[]' - ELSE en.nspname || '.' || et.typname || '[]' - END - WHEN dt.typtype = 'b' THEN - -- Non-array base types: qualify if not in pg_catalog or table's schema - CASE - WHEN dn.nspname = 'pg_catalog' THEN c.udt_name - WHEN dn.nspname = c.table_schema THEN dt.typname - ELSE dn.nspname || '.' || dt.typname - END - ELSE c.udt_name - END AS resolved_type, - c.is_identity, - c.identity_generation, - c.identity_start, - c.identity_increment, - c.identity_maximum, - c.identity_minimum, - c.identity_cycle, - a.attgenerated, - CASE - WHEN a.attgenerated = 's' THEN pg_get_expr(ad.adbin, ad.adrelid) - ELSE NULL - END AS generated_expr -FROM information_schema.columns c -LEFT JOIN pg_class cl ON cl.relname = c.table_name -LEFT JOIN pg_namespace n ON cl.relnamespace = n.oid AND n.nspname = c.table_schema -LEFT JOIN pg_description d ON d.objoid = cl.oid AND d.classoid = 'pg_class'::regclass AND d.objsubid = c.ordinal_position -LEFT JOIN pg_attribute a ON a.attrelid = cl.oid AND a.attname = c.column_name -LEFT JOIN pg_attrdef ad ON ad.adrelid = a.attrelid AND ad.adnum = a.attnum -LEFT JOIN pg_type dt ON dt.oid = a.atttypid -LEFT JOIN pg_namespace dn ON dt.typnamespace = dn.oid -LEFT JOIN pg_type et ON dt.typelem = et.oid -LEFT JOIN pg_namespace en ON et.typnamespace = en.oid -WHERE - c.table_schema NOT IN ('information_schema', 'pg_catalog', 'pg_toast') - AND c.table_schema NOT LIKE 'pg_temp_%' - AND c.table_schema NOT LIKE 'pg_toast_temp_%' -ORDER BY c.table_schema, c.table_name, c.ordinal_position; + cb.table_schema, + cb.table_name, + cb.column_name, + cb.ordinal_position, + -- Use the column_default from LATERAL join which has proper search_path set + ge.column_default, + cb.is_nullable, + cb.data_type, + cb.character_maximum_length, + cb.numeric_precision, + cb.numeric_scale, + cb.udt_name, + cb.column_comment, + cb.resolved_type, + cb.is_identity, + cb.identity_generation, + cb.identity_start, + cb.identity_increment, + cb.identity_maximum, + cb.identity_minimum, + cb.identity_cycle, + cb.attgenerated, + -- Use LATERAL join to guarantee execution order: + -- 1. set_config sets search_path to only the table's schema + -- 2. pg_get_expr then uses that search_path + -- This ensures cross-schema type references in column defaults and generated columns + -- are properly qualified (Issue #218) + ge.generated_expr +FROM column_base cb +LEFT JOIN LATERAL ( + SELECT + -- Set search_path to only pg_catalog to force pg_get_expr to include schema qualifiers + -- for all user-defined types and functions. The normalization code will then strip + -- same-schema function qualifiers while preserving type qualifiers (Issue #218) + set_config('search_path', 'pg_catalog', true) as dummy, + CASE + WHEN cb.attgenerated = 's' THEN NULL -- Generated columns don't have defaults + ELSE COALESCE(pg_get_expr(cb.adbin, cb.adrelid), cb.column_default) + END as column_default, + CASE + WHEN cb.attgenerated = 's' THEN pg_get_expr(cb.adbin, cb.adrelid) + ELSE NULL + END as generated_expr +) ge ON true +ORDER BY cb.table_schema, cb.table_name, cb.ordinal_position; -- GetColumnsForSchema retrieves all columns for tables in a specific schema -- name: GetColumnsForSchema :many @@ -195,10 +237,8 @@ SELECT cb.table_name, cb.column_name, cb.ordinal_position, - CASE - WHEN cb.attgenerated = 's' THEN NULL -- Generated columns don't have defaults - ELSE COALESCE(pg_get_expr(cb.adbin, cb.adrelid), cb.column_default) - END AS column_default, + -- Use the column_default from LATERAL join which has proper search_path set + ge.column_default, cb.is_nullable, cb.data_type, cb.character_maximum_length, @@ -216,14 +256,15 @@ SELECT cb.identity_cycle, cb.attgenerated, -- Use LATERAL join to guarantee execution order: - -- 1. set_config sets search_path to only the table's schema - -- 2. pg_get_expr then uses that search_path - -- This ensures cross-schema function references in generated columns are qualified + -- 1. set_config sets search_path to only pg_catalog + -- 2. pg_get_expr then uses that search_path and includes schema qualifiers for user types + -- This ensures type references in column defaults and generated columns are properly + -- qualified (Issue #218). The normalization code strips same-schema function qualifiers. -- -- NOTE: The 'dummy' column in the LATERAL subquery forces set_config to execute -- before pg_get_expr. PostgreSQL evaluates SELECT columns left-to-right within -- 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. + -- and 'ON true' in the join condition ensures the LATERAL subquery executes for every row. -- This pattern mirrors GetViewsForSchema (line 959-963) for consistency. -- -- Alternative considered: Create a custom PostgreSQL function wrapping pg_get_expr @@ -235,7 +276,14 @@ SELECT FROM column_base cb LEFT JOIN LATERAL ( SELECT - set_config('search_path', cb.table_schema || ', pg_catalog', true) as dummy, + -- Set search_path to only pg_catalog to force pg_get_expr to include schema qualifiers + -- for all user-defined types and functions. The normalization code will then strip + -- same-schema function qualifiers while preserving type qualifiers (Issue #218) + set_config('search_path', 'pg_catalog', true) as dummy, + CASE + WHEN cb.attgenerated = 's' THEN NULL -- Generated columns don't have defaults + ELSE COALESCE(pg_get_expr(cb.adbin, cb.adrelid), cb.column_default) + END as column_default, CASE WHEN cb.attgenerated = 's' THEN pg_get_expr(cb.adbin, cb.adrelid) ELSE NULL diff --git a/ir/queries/queries.sql.go b/ir/queries/queries.sql.go index cc64fb71..8fe65638 100644 --- a/ir/queries/queries.sql.go +++ b/ir/queries/queries.sql.go @@ -191,74 +191,116 @@ func (q *Queries) GetAggregatesForSchema(ctx context.Context, dollar_1 sql.NullS } const getColumns = `-- name: GetColumns :many +WITH column_base AS ( + SELECT + c.table_schema, + c.table_name, + c.column_name, + c.ordinal_position, + c.column_default, + c.is_nullable, + c.data_type, + c.character_maximum_length, + c.numeric_precision, + c.numeric_scale, + c.udt_name, + COALESCE(d.description, '') AS column_comment, + CASE + WHEN dt.typtype = 'd' THEN + CASE WHEN dn.nspname = c.table_schema THEN dt.typname + ELSE dn.nspname || '.' || dt.typname + END + WHEN dt.typtype = 'e' OR dt.typtype = 'c' THEN + CASE WHEN dn.nspname = c.table_schema THEN dt.typname + ELSE dn.nspname || '.' || dt.typname + END + WHEN dt.typtype = 'b' AND dt.typelem <> 0 THEN + -- Array types: apply same schema qualification logic to element type + CASE + WHEN en.nspname = 'pg_catalog' THEN et.typname || '[]' + WHEN en.nspname = c.table_schema THEN et.typname || '[]' + ELSE en.nspname || '.' || et.typname || '[]' + END + WHEN dt.typtype = 'b' THEN + -- Non-array base types: qualify if not in pg_catalog or table's schema + CASE + WHEN dn.nspname = 'pg_catalog' THEN c.udt_name + WHEN dn.nspname = c.table_schema THEN dt.typname + ELSE dn.nspname || '.' || dt.typname + END + ELSE c.udt_name + END AS resolved_type, + c.is_identity, + c.identity_generation, + c.identity_start, + c.identity_increment, + c.identity_maximum, + c.identity_minimum, + c.identity_cycle, + a.attgenerated, + ad.adbin, + ad.adrelid + FROM information_schema.columns c + LEFT JOIN pg_class cl ON cl.relname = c.table_name + LEFT JOIN pg_namespace n ON cl.relnamespace = n.oid AND n.nspname = c.table_schema + LEFT JOIN pg_description d ON d.objoid = cl.oid AND d.classoid = 'pg_class'::regclass AND d.objsubid = c.ordinal_position + LEFT JOIN pg_attribute a ON a.attrelid = cl.oid AND a.attname = c.column_name + LEFT JOIN pg_attrdef ad ON ad.adrelid = a.attrelid AND ad.adnum = a.attnum + LEFT JOIN pg_type dt ON dt.oid = a.atttypid + LEFT JOIN pg_namespace dn ON dt.typnamespace = dn.oid + LEFT JOIN pg_type et ON dt.typelem = et.oid + LEFT JOIN pg_namespace en ON et.typnamespace = en.oid + WHERE + c.table_schema NOT IN ('information_schema', 'pg_catalog', 'pg_toast') + AND c.table_schema NOT LIKE 'pg_temp_%' + AND c.table_schema NOT LIKE 'pg_toast_temp_%' +) SELECT - c.table_schema, - c.table_name, - c.column_name, - c.ordinal_position, - CASE - WHEN a.attgenerated = 's' THEN NULL -- Generated columns don't have defaults - ELSE COALESCE(pg_get_expr(ad.adbin, ad.adrelid), c.column_default) - END AS column_default, - c.is_nullable, - c.data_type, - c.character_maximum_length, - c.numeric_precision, - c.numeric_scale, - c.udt_name, - COALESCE(d.description, '') AS column_comment, - CASE - WHEN dt.typtype = 'd' THEN - CASE WHEN dn.nspname = c.table_schema THEN dt.typname - ELSE dn.nspname || '.' || dt.typname - END - WHEN dt.typtype = 'e' OR dt.typtype = 'c' THEN - CASE WHEN dn.nspname = c.table_schema THEN dt.typname - ELSE dn.nspname || '.' || dt.typname - END - WHEN dt.typtype = 'b' AND dt.typelem <> 0 THEN - -- Array types: apply same schema qualification logic to element type - CASE - WHEN en.nspname = 'pg_catalog' THEN et.typname || '[]' - WHEN en.nspname = c.table_schema THEN et.typname || '[]' - ELSE en.nspname || '.' || et.typname || '[]' - END - WHEN dt.typtype = 'b' THEN - -- Non-array base types: qualify if not in pg_catalog or table's schema - CASE - WHEN dn.nspname = 'pg_catalog' THEN c.udt_name - WHEN dn.nspname = c.table_schema THEN dt.typname - ELSE dn.nspname || '.' || dt.typname - END - ELSE c.udt_name - END AS resolved_type, - c.is_identity, - c.identity_generation, - c.identity_start, - c.identity_increment, - c.identity_maximum, - c.identity_minimum, - c.identity_cycle, - a.attgenerated, - CASE - WHEN a.attgenerated = 's' THEN pg_get_expr(ad.adbin, ad.adrelid) - ELSE NULL - END AS generated_expr -FROM information_schema.columns c -LEFT JOIN pg_class cl ON cl.relname = c.table_name -LEFT JOIN pg_namespace n ON cl.relnamespace = n.oid AND n.nspname = c.table_schema -LEFT JOIN pg_description d ON d.objoid = cl.oid AND d.classoid = 'pg_class'::regclass AND d.objsubid = c.ordinal_position -LEFT JOIN pg_attribute a ON a.attrelid = cl.oid AND a.attname = c.column_name -LEFT JOIN pg_attrdef ad ON ad.adrelid = a.attrelid AND ad.adnum = a.attnum -LEFT JOIN pg_type dt ON dt.oid = a.atttypid -LEFT JOIN pg_namespace dn ON dt.typnamespace = dn.oid -LEFT JOIN pg_type et ON dt.typelem = et.oid -LEFT JOIN pg_namespace en ON et.typnamespace = en.oid -WHERE - c.table_schema NOT IN ('information_schema', 'pg_catalog', 'pg_toast') - AND c.table_schema NOT LIKE 'pg_temp_%' - AND c.table_schema NOT LIKE 'pg_toast_temp_%' -ORDER BY c.table_schema, c.table_name, c.ordinal_position + cb.table_schema, + cb.table_name, + cb.column_name, + cb.ordinal_position, + -- Use the column_default from LATERAL join which has proper search_path set + ge.column_default, + cb.is_nullable, + cb.data_type, + cb.character_maximum_length, + cb.numeric_precision, + cb.numeric_scale, + cb.udt_name, + cb.column_comment, + cb.resolved_type, + cb.is_identity, + cb.identity_generation, + cb.identity_start, + cb.identity_increment, + cb.identity_maximum, + cb.identity_minimum, + cb.identity_cycle, + cb.attgenerated, + -- Use LATERAL join to guarantee execution order: + -- 1. set_config sets search_path to only the table's schema + -- 2. pg_get_expr then uses that search_path + -- This ensures cross-schema type references in column defaults and generated columns + -- are properly qualified (Issue #218) + ge.generated_expr +FROM column_base cb +LEFT JOIN LATERAL ( + SELECT + -- Set search_path to only pg_catalog to force pg_get_expr to include schema qualifiers + -- for all user-defined types and functions. The normalization code will then strip + -- same-schema function qualifiers while preserving type qualifiers (Issue #218) + set_config('search_path', 'pg_catalog', true) as dummy, + CASE + WHEN cb.attgenerated = 's' THEN NULL -- Generated columns don't have defaults + ELSE COALESCE(pg_get_expr(cb.adbin, cb.adrelid), cb.column_default) + END as column_default, + CASE + WHEN cb.attgenerated = 's' THEN pg_get_expr(cb.adbin, cb.adrelid) + ELSE NULL + END as generated_expr +) ge ON true +ORDER BY cb.table_schema, cb.table_name, cb.ordinal_position ` type GetColumnsRow struct { @@ -402,10 +444,8 @@ SELECT cb.table_name, cb.column_name, cb.ordinal_position, - CASE - WHEN cb.attgenerated = 's' THEN NULL -- Generated columns don't have defaults - ELSE COALESCE(pg_get_expr(cb.adbin, cb.adrelid), cb.column_default) - END AS column_default, + -- Use the column_default from LATERAL join which has proper search_path set + ge.column_default, cb.is_nullable, cb.data_type, cb.character_maximum_length, @@ -423,14 +463,15 @@ SELECT cb.identity_cycle, cb.attgenerated, -- Use LATERAL join to guarantee execution order: - -- 1. set_config sets search_path to only the table's schema - -- 2. pg_get_expr then uses that search_path - -- This ensures cross-schema function references in generated columns are qualified + -- 1. set_config sets search_path to only pg_catalog + -- 2. pg_get_expr then uses that search_path and includes schema qualifiers for user types + -- This ensures type references in column defaults and generated columns are properly + -- qualified (Issue #218). The normalization code strips same-schema function qualifiers. -- -- NOTE: The 'dummy' column in the LATERAL subquery forces set_config to execute -- before pg_get_expr. PostgreSQL evaluates SELECT columns left-to-right within -- 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. + -- and 'ON true' in the join condition ensures the LATERAL subquery executes for every row. -- This pattern mirrors GetViewsForSchema (line 959-963) for consistency. -- -- Alternative considered: Create a custom PostgreSQL function wrapping pg_get_expr @@ -442,7 +483,14 @@ SELECT FROM column_base cb LEFT JOIN LATERAL ( SELECT - set_config('search_path', cb.table_schema || ', pg_catalog', true) as dummy, + -- Set search_path to only pg_catalog to force pg_get_expr to include schema qualifiers + -- for all user-defined types and functions. The normalization code will then strip + -- same-schema function qualifiers while preserving type qualifiers (Issue #218) + set_config('search_path', 'pg_catalog', true) as dummy, + CASE + WHEN cb.attgenerated = 's' THEN NULL -- Generated columns don't have defaults + ELSE COALESCE(pg_get_expr(cb.adbin, cb.adrelid), cb.column_default) + END as column_default, CASE WHEN cb.attgenerated = 's' THEN pg_get_expr(cb.adbin, cb.adrelid) ELSE NULL diff --git a/testdata/dump/tenant/pgschema.sql b/testdata/dump/tenant/pgschema.sql index 149fd428..6a41eebe 100644 --- a/testdata/dump/tenant/pgschema.sql +++ b/testdata/dump/tenant/pgschema.sql @@ -2,7 +2,7 @@ -- pgschema database dump -- --- Dumped from database version PostgreSQL 17.5 +-- Dumped from database version PostgreSQL 18.0 -- Dumped by pgschema version 1.5.1 @@ -53,29 +53,6 @@ CREATE TABLE IF NOT EXISTS categories ( CONSTRAINT categories_name_key UNIQUE (name) ); --- --- Name: users; Type: TABLE; Schema: -; Owner: - --- - -CREATE TABLE IF NOT EXISTS users ( - id SERIAL, - username varchar(100) NOT NULL, - email varchar(100) NOT NULL, - website varchar(255), - user_code text DEFAULT util.generate_id(), - domain text GENERATED ALWAYS AS (util.extract_domain((website)::text)) STORED, - role user_role DEFAULT 'user'::user_role, - status status DEFAULT 'active'::status, - created_at timestamp DEFAULT now(), - CONSTRAINT users_pkey PRIMARY KEY (id) -); - --- --- Name: idx_users_email; Type: INDEX; Schema: -; Owner: - --- - -CREATE INDEX IF NOT EXISTS idx_users_email ON users (email); - -- -- Name: posts; Type: TABLE; Schema: -; Owner: - -- @@ -87,10 +64,16 @@ CREATE TABLE IF NOT EXISTS posts ( author_id integer, status status DEFAULT 'active'::status, created_at timestamp DEFAULT now(), - CONSTRAINT posts_pkey PRIMARY KEY (id), - CONSTRAINT posts_author_id_fkey FOREIGN KEY (author_id) REFERENCES users (id) + CONSTRAINT posts_pkey PRIMARY KEY (id) ); +-- +-- Name: posts_author_id_fkey; Type: CONSTRAINT; Schema: -; Owner: - +-- + +ALTER TABLE posts +ADD CONSTRAINT posts_author_id_fkey FOREIGN KEY (author_id) REFERENCES users (id); + -- -- Name: create_task_assignment(text, priority_level, integer); Type: FUNCTION; Schema: -; Owner: - -- @@ -128,6 +111,18 @@ BEGIN END; $$; +-- +-- Name: get_default_status_text(); Type: FUNCTION; Schema: -; Owner: - +-- + +CREATE OR REPLACE FUNCTION get_default_status_text() +RETURNS text +LANGUAGE sql +IMMUTABLE +AS $$ + SELECT 'active'::text +$$; + -- -- Name: set_task_priority(priority_level); Type: FUNCTION; Schema: -; Owner: - -- @@ -161,3 +156,27 @@ BEGIN END; $$; +-- +-- Name: users; Type: TABLE; Schema: -; Owner: - +-- + +CREATE TABLE IF NOT EXISTS users ( + id SERIAL, + username varchar(100) NOT NULL, + email varchar(100) NOT NULL, + website varchar(255), + user_code text DEFAULT util.generate_id(), + domain text GENERATED ALWAYS AS (util.extract_domain((website)::text)) STORED, + role user_role DEFAULT 'user'::user_role, + account_status status DEFAULT (util.get_default_status())::status, + secondary_status status DEFAULT (get_default_status_text())::status, + created_at timestamp DEFAULT now(), + CONSTRAINT users_pkey PRIMARY KEY (id) +); + +-- +-- Name: idx_users_email; Type: INDEX; Schema: -; Owner: - +-- + +CREATE INDEX IF NOT EXISTS idx_users_email ON users (email); + diff --git a/testdata/dump/tenant/tenant.sql b/testdata/dump/tenant/tenant.sql index 63a65fa4..319c835b 100644 --- a/testdata/dump/tenant/tenant.sql +++ b/testdata/dump/tenant/tenant.sql @@ -16,6 +16,18 @@ CREATE TYPE task_assignment AS ( estimated_hours integer ); +-- Function to get default status as text (in same schema as table) +-- Issue #218: This tests when function and type are in the same schema as the column +-- Returns TEXT so that explicit cast to status is needed +-- Must be defined before table that uses it +CREATE FUNCTION get_default_status_text() +RETURNS text +LANGUAGE sql +IMMUTABLE +AS $$ + SELECT 'active'::text +$$; + -- Shared categories table CREATE TABLE categories ( id SERIAL PRIMARY KEY, @@ -24,6 +36,7 @@ CREATE TABLE categories ( ); -- Users table (uses util.generate_id() for default user codes and util.extract_domain() for generated column) +-- Also tests schema-qualified type casts in default expressions (Issue #218) CREATE TABLE users ( id SERIAL, username varchar(100) NOT NULL, @@ -32,7 +45,13 @@ CREATE TABLE users ( user_code text DEFAULT util.generate_id(), domain text GENERATED ALWAYS AS (util.extract_domain(website)) STORED, role user_role DEFAULT 'user', - status status DEFAULT 'active', + -- Bug reproduction case 1: cross-schema function with type cast to local enum + account_status status DEFAULT (util.get_default_status())::status, + -- Bug reproduction case 2 (Issue #218): same-schema function returning TEXT with explicit cast to status + -- When dumping from tenant1 schema, PostgreSQL stores this with qualified type cast + -- Expected: (get_default_status_text())::tenant1.status (type qualifier preserved) + -- Bug in v1.5.1: (get_default_status_text())::status (type qualifier stripped) + secondary_status status DEFAULT (get_default_status_text())::status, created_at timestamp DEFAULT now(), CONSTRAINT users_pkey PRIMARY KEY (id) ); diff --git a/testdata/dump/tenant/util.sql b/testdata/dump/tenant/util.sql index 459aa13e..7446d555 100644 --- a/testdata/dump/tenant/util.sql +++ b/testdata/dump/tenant/util.sql @@ -19,6 +19,20 @@ BEGIN END; $$; +-- +-- Name: get_default_status(); Type: FUNCTION; Schema: util; Owner: - +-- Returns a text that can be cast to status type +-- + +CREATE FUNCTION util.get_default_status() + RETURNS text + LANGUAGE sql + IMMUTABLE + PARALLEL SAFE +AS $$ + SELECT 'active'::text +$$; + -- -- Name: extract_domain(text); Type: FUNCTION; Schema: util; Owner: - --