From 9aad7f459dbc06512dcc8511d790f5665897bdcc Mon Sep 17 00:00:00 2001 From: Tianzhou Date: Tue, 21 Oct 2025 00:50:16 +0800 Subject: [PATCH] fix: cross schema table reference in view --- ir/formatter.go | 15 ++++++-- ir/normalize.go | 64 ++++--------------------------- ir/parser.go | 16 ++++---- ir/queries/queries.sql | 48 ++++++++++++++++------- ir/queries/queries.sql.go | 48 ++++++++++++++++------- testdata/dump/tenant/pgschema.sql | 39 +++++++++++++++++++ 6 files changed, 136 insertions(+), 94 deletions(-) diff --git a/ir/formatter.go b/ir/formatter.go index 16bf1ad0..88ef4461 100644 --- a/ir/formatter.go +++ b/ir/formatter.go @@ -11,13 +11,15 @@ import ( type postgreSQLFormatter struct { buffer *strings.Builder indentLevel int + viewSchema string // Schema of the view being formatted (for proper schema qualification) } // newPostgreSQLFormatter creates a new PostgreSQL formatter -func newPostgreSQLFormatter() *postgreSQLFormatter { +func newPostgreSQLFormatter(viewSchema string) *postgreSQLFormatter { return &postgreSQLFormatter{ buffer: &strings.Builder{}, indentLevel: 0, + viewSchema: viewSchema, } } @@ -137,8 +139,15 @@ func (f *postgreSQLFormatter) formatFromItem(item *pg_query.Node) { // formatRangeVar formats a table reference func (f *postgreSQLFormatter) formatRangeVar(rangeVar *pg_query.RangeVar) { - if rangeVar.Schemaname != "" { - f.buffer.WriteString(rangeVar.Schemaname) + // Apply schema qualification rules: + // - If table schema == view schema: omit schema qualifier (same schema) + // - If table schema != view schema: include schema qualifier (cross-schema reference) + // - If no schema name in RangeVar: no qualifier (unqualified reference) + tableSchema := rangeVar.Schemaname + + // Only include schema qualifier for cross-schema references + if tableSchema != "" && tableSchema != f.viewSchema { + f.buffer.WriteString(tableSchema) f.buffer.WriteString(".") } f.buffer.WriteString(rangeVar.Relname) diff --git a/ir/normalize.go b/ir/normalize.go index 5cdbd61f..a6b723d5 100644 --- a/ir/normalize.go +++ b/ir/normalize.go @@ -215,7 +215,7 @@ func normalizeView(view *View) { return } - view.Definition = normalizeViewDefinition(view.Definition) + view.Definition = normalizeViewDefinition(view.Definition, view.Schema) } // normalizeViewDefinition normalizes view SQL definition for consistent comparison @@ -227,7 +227,7 @@ func normalizeView(view *View) { // // This function removes unnecessary table qualifiers from column references when unambiguous // to ensure consistent comparison between Inspector (database) and Parser (SQL files). -func normalizeViewDefinition(definition string) string { +func normalizeViewDefinition(definition string, viewSchema string) string { if definition == "" { return definition } @@ -243,7 +243,8 @@ func normalizeViewDefinition(definition string) string { // This includes: // 1. Converting PostgreSQL's "= ANY (ARRAY[...])" to "IN (...)" // 2. Normalizing ORDER BY clauses to use aliases - normalized = normalizeViewWithAST(normalized) + // 3. Applying proper schema qualification rules for table references + normalized = normalizeViewWithAST(normalized, viewSchema) return normalized } @@ -1030,7 +1031,7 @@ func convertAnyArrayToIn(expr string) string { // normalizeViewWithAST applies all AST-based normalizations in a single pass // This includes converting "= ANY (ARRAY[...])" to "IN (...)" and normalizing ORDER BY -func normalizeViewWithAST(definition string) string { +func normalizeViewWithAST(definition string, viewSchema string) string { if definition == "" { return definition } @@ -1078,59 +1079,8 @@ func normalizeViewWithAST(definition string) string { // The formatter will handle: // - Converting "= ANY (ARRAY[...])" to "IN (...)" // - Proper formatting of all expressions - formatter := newPostgreSQLFormatter() - formatted := formatter.formatQueryNode(stmt.Stmt) - if formatted != "" { - return formatted - } - } - - return definition -} - -// normalizeOrderByInView normalizes ORDER BY clauses in view definitions -// This converts PostgreSQL's pg_get_viewdef format (with parentheses and expressions) -// back to parser format (using column aliases) for consistent comparison -// Uses AST manipulation for robustness -func normalizeOrderByInView(definition string) string { - if definition == "" { - return definition - } - - // Parse the view definition - parseResult, err := pg_query.Parse(definition) - if err != nil { - return definition - } - - if len(parseResult.Stmts) == 0 { - return definition - } - - stmt := parseResult.Stmts[0] - selectStmt := stmt.Stmt.GetSelectStmt() - if selectStmt == nil || len(selectStmt.SortClause) == 0 { - return definition - } - - // Build reverse alias map (expression -> alias) from target list - // This helps us convert ORDER BY expressions back to aliases - exprToAliasMap := buildExpressionToAliasMap(selectStmt.TargetList) - - // Transform ORDER BY clauses: replace complex expressions with aliases when possible - modified := false - for _, sortItem := range selectStmt.SortClause { - if sortBy := sortItem.GetSortBy(); sortBy != nil { - if wasModified := normalizeOrderByExpressionToAlias(sortBy, exprToAliasMap); wasModified { - modified = true - } - } - } - - // If we made modifications, use PostgreSQL formatter to maintain formatting - // IMPORTANT: Use the custom formatter to preserve ANY->IN conversions done earlier - if modified { - formatter := newPostgreSQLFormatter() + // - Applying proper schema qualification rules + formatter := newPostgreSQLFormatter(viewSchema) formatted := formatter.formatQueryNode(stmt.Stmt) if formatted != "" { return formatted diff --git a/ir/parser.go b/ir/parser.go index b6dc660e..2432eb35 100644 --- a/ir/parser.go +++ b/ir/parser.go @@ -1659,7 +1659,7 @@ func (p *Parser) parseCreateView(viewStmt *pg_query.ViewStmt) error { dbSchema := p.schema.getOrCreateSchema(schemaName) // Extract the view definition from the parsed AST - definition := p.extractViewDefinitionFromAST(viewStmt) + definition := p.extractViewDefinitionFromAST(viewStmt, schemaName) // Create view (regular view, not materialized) view := &View{ @@ -1688,7 +1688,7 @@ func (p *Parser) parseCreateTableAs(stmt *pg_query.CreateTableAsStmt) error { dbSchema := p.schema.getOrCreateSchema(schemaName) // Extract the view definition from the parsed AST - definition := p.extractQueryDefinitionFromAST(stmt.Query) + definition := p.extractQueryDefinitionFromAST(stmt.Query, schemaName) // Create materialized view view := &View{ @@ -1705,28 +1705,28 @@ func (p *Parser) parseCreateTableAs(stmt *pg_query.CreateTableAsStmt) error { } // extractQueryDefinitionFromAST extracts the SELECT statement from a query node -func (p *Parser) extractQueryDefinitionFromAST(query *pg_query.Node) string { +func (p *Parser) extractQueryDefinitionFromAST(query *pg_query.Node, viewSchema string) string { if query == nil { return "" } // Use AST-based formatting to match PostgreSQL's pg_get_viewdef(c.oid, true) output - return p.formatViewDefinitionFromAST(query) + return p.formatViewDefinitionFromAST(query, viewSchema) } // extractViewDefinitionFromAST extracts the SELECT statement from parsed ViewStmt AST -func (p *Parser) extractViewDefinitionFromAST(viewStmt *pg_query.ViewStmt) string { +func (p *Parser) extractViewDefinitionFromAST(viewStmt *pg_query.ViewStmt, viewSchema string) string { if viewStmt.Query == nil { return "" } // Use AST-based formatting to match PostgreSQL's pg_get_viewdef(c.oid, true) output - return p.formatViewDefinitionFromAST(viewStmt.Query) + return p.formatViewDefinitionFromAST(viewStmt.Query, viewSchema) } // formatViewDefinitionFromAST formats a query AST using PostgreSQL's formatting rules -func (p *Parser) formatViewDefinitionFromAST(queryNode *pg_query.Node) string { - formatter := newPostgreSQLFormatter() +func (p *Parser) formatViewDefinitionFromAST(queryNode *pg_query.Node, viewSchema string) string { + formatter := newPostgreSQLFormatter(viewSchema) return formatter.formatQueryNode(queryNode) } diff --git a/ir/queries/queries.sql b/ir/queries/queries.sql index 5c279fa6..7a6370b0 100644 --- a/ir/queries/queries.sql +++ b/ir/queries/queries.sql @@ -827,20 +827,42 @@ WHERE p.prokind = 'a' -- Only aggregates ORDER BY n.nspname, p.proname; -- GetViewsForSchema retrieves all views and materialized views for a specific schema +-- IMPORTANT: Uses LATERAL join with set_config to temporarily set search_path to only the view's schema +-- This ensures pg_get_viewdef() includes schema qualifiers for cross-schema references +-- The LATERAL join guarantees set_config executes before pg_get_viewdef in the same row context -- name: GetViewsForSchema :many -SELECT - n.nspname AS table_schema, - c.relname AS table_name, - pg_get_viewdef(c.oid, true) AS view_definition, - COALESCE(d.description, '') AS view_comment, - (c.relkind = 'm') AS is_materialized -FROM pg_class c -JOIN pg_namespace n ON c.relnamespace = n.oid -LEFT JOIN pg_description d ON d.objoid = c.oid AND d.classoid = 'pg_class'::regclass AND d.objsubid = 0 -WHERE - c.relkind IN ('v', 'm') -- views and materialized views - AND n.nspname = $1 -ORDER BY n.nspname, c.relname; +WITH view_definitions AS ( + SELECT + n.nspname AS table_schema, + c.relname AS table_name, + c.oid AS view_oid, + COALESCE(d.description, '') AS view_comment, + (c.relkind = 'm') AS is_materialized, + n.nspname AS view_schema + FROM pg_class c + JOIN pg_namespace n ON c.relnamespace = n.oid + LEFT JOIN pg_description d ON d.objoid = c.oid AND d.classoid = 'pg_class'::regclass AND d.objsubid = 0 + WHERE + c.relkind IN ('v', 'm') -- views and materialized views + AND n.nspname = $1 +) +SELECT + vd.table_schema, + vd.table_name, + -- Use LATERAL join to guarantee execution order: + -- 1. set_config sets search_path to only the view's schema + -- 2. pg_get_viewdef then uses that search_path + -- This ensures cross-schema table references are qualified with schema names + sp.view_def AS view_definition, + vd.view_comment, + vd.is_materialized +FROM view_definitions vd +CROSS JOIN LATERAL ( + SELECT + set_config('search_path', vd.view_schema || ', pg_catalog', true) as dummy, + pg_get_viewdef(vd.view_oid, true) as view_def +) sp +ORDER BY vd.table_schema, vd.table_name; -- GetTriggersForSchema retrieves all triggers for a specific schema -- Uses pg_trigger catalog to include all trigger types (including TRUNCATE) diff --git a/ir/queries/queries.sql.go b/ir/queries/queries.sql.go index 0c5ffddf..1e186040 100644 --- a/ir/queries/queries.sql.go +++ b/ir/queries/queries.sql.go @@ -2551,19 +2551,38 @@ func (q *Queries) GetViews(ctx context.Context) ([]GetViewsRow, error) { } const getViewsForSchema = `-- name: GetViewsForSchema :many -SELECT - n.nspname AS table_schema, - c.relname AS table_name, - pg_get_viewdef(c.oid, true) AS view_definition, - COALESCE(d.description, '') AS view_comment, - (c.relkind = 'm') AS is_materialized -FROM pg_class c -JOIN pg_namespace n ON c.relnamespace = n.oid -LEFT JOIN pg_description d ON d.objoid = c.oid AND d.classoid = 'pg_class'::regclass AND d.objsubid = 0 -WHERE - c.relkind IN ('v', 'm') -- views and materialized views - AND n.nspname = $1 -ORDER BY n.nspname, c.relname +WITH view_definitions AS ( + SELECT + n.nspname AS table_schema, + c.relname AS table_name, + c.oid AS view_oid, + COALESCE(d.description, '') AS view_comment, + (c.relkind = 'm') AS is_materialized, + n.nspname AS view_schema + FROM pg_class c + JOIN pg_namespace n ON c.relnamespace = n.oid + LEFT JOIN pg_description d ON d.objoid = c.oid AND d.classoid = 'pg_class'::regclass AND d.objsubid = 0 + WHERE + c.relkind IN ('v', 'm') -- views and materialized views + AND n.nspname = $1 +) +SELECT + vd.table_schema, + vd.table_name, + -- Use LATERAL join to guarantee execution order: + -- 1. set_config sets search_path to only the view's schema + -- 2. pg_get_viewdef then uses that search_path + -- This ensures cross-schema table references are qualified with schema names + sp.view_def AS view_definition, + vd.view_comment, + vd.is_materialized +FROM view_definitions vd +CROSS JOIN LATERAL ( + SELECT + set_config('search_path', vd.view_schema || ', pg_catalog', true) as dummy, + pg_get_viewdef(vd.view_oid, true) as view_def +) sp +ORDER BY vd.table_schema, vd.table_name ` type GetViewsForSchemaRow struct { @@ -2575,6 +2594,9 @@ type GetViewsForSchemaRow struct { } // GetViewsForSchema retrieves all views and materialized views for a specific schema +// IMPORTANT: Uses LATERAL join with set_config to temporarily set search_path to only the view's schema +// This ensures pg_get_viewdef() includes schema qualifiers for cross-schema references +// The LATERAL join guarantees set_config executes before pg_get_viewdef in the same row context func (q *Queries) GetViewsForSchema(ctx context.Context, dollar_1 sql.NullString) ([]GetViewsForSchemaRow, error) { rows, err := q.db.QueryContext(ctx, getViewsForSchema, dollar_1) if err != nil { diff --git a/testdata/dump/tenant/pgschema.sql b/testdata/dump/tenant/pgschema.sql index df235535..0239bddf 100644 --- a/testdata/dump/tenant/pgschema.sql +++ b/testdata/dump/tenant/pgschema.sql @@ -43,3 +43,42 @@ CREATE TABLE IF NOT EXISTS posts ( CONSTRAINT posts_category_id_fkey FOREIGN KEY (category_id) REFERENCES public.categories (id) ); +-- +-- Name: active_posts_mv; Type: MATERIALIZED VIEW; Schema: -; Owner: - +-- + +CREATE MATERIALIZED VIEW IF NOT EXISTS active_posts_mv AS + SELECT p.id, + p.title, + p.content, + u.username AS author_name, + c.name AS category_name, + c.description AS category_description, + p.created_at + FROM posts p + JOIN users u ON p.author_id = u.id + JOIN public.categories c ON p.category_id = c.id + WHERE p.status = 'active'::public.status; + +-- +-- Name: idx_active_posts_category; Type: INDEX; Schema: -; Owner: - +-- + +CREATE INDEX IF NOT EXISTS idx_active_posts_category ON active_posts_mv (category_name); + +-- +-- Name: user_posts_summary; Type: VIEW; Schema: -; Owner: - +-- + +CREATE OR REPLACE VIEW user_posts_summary AS + SELECT u.id, + u.username, + u.email, + p.title AS post_title, + c.name AS category_name, + p.created_at + FROM users u + JOIN posts p ON u.id = p.author_id + JOIN public.categories c ON p.category_id = c.id + WHERE u.status = 'active'::public.status; +