-
Notifications
You must be signed in to change notification settings - Fork 30
fix: preserve schema qualifiers in column default type casts #219
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
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
There are no files selected for viewing
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
| Original file line number | Diff line number | Diff line change |
|---|---|---|
|
|
@@ -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 | ||
|
Comment on lines
264
to
265
|
||
| -- 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 | ||
|
|
||
Oops, something went wrong.
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
The comment states "set_config sets search_path to only the table's schema" but the actual code on line 158 sets the search_path to 'pg_catalog', not the table's schema. This comment should be updated to match the implementation, similar to the comment on lines 259-262.