From 591748be374fd520f265ec174cc02cd6beaae5be Mon Sep 17 00:00:00 2001 From: tianzhou Date: Thu, 11 Sep 2025 15:07:12 +0800 Subject: [PATCH] feat: CREATE TABLE LIKE source_table --- internal/diff/table.go | 10 + internal/ir/ir.go | 8 + internal/ir/parser.go | 406 ++++++++++++++++-- .../diff/create_table/add_table_like/diff.sql | 18 + .../diff/create_table/add_table_like/new.sql | 24 ++ .../diff/create_table/add_table_like/old.sql | 12 + .../create_table/add_table_like/plan.json | 66 +++ .../diff/create_table/add_table_like/plan.sql | 32 ++ .../diff/create_table/add_table_like/plan.txt | 52 +++ .../add_table_like/plan_actual.sql | 32 ++ .../add_table_like/plan_actual.txt | 52 +++ .../add_table_like_forward_ref/diff.sql | 17 + .../add_table_like_forward_ref/error_case.sql | 6 + .../add_table_like_forward_ref/new.sql | 16 + .../add_table_like_forward_ref/old.sql | 1 + .../add_table_like_forward_ref/plan.json | 26 ++ .../add_table_like_forward_ref/plan.sql | 17 + .../add_table_like_forward_ref/plan.txt | 29 ++ 18 files changed, 785 insertions(+), 39 deletions(-) create mode 100644 testdata/diff/create_table/add_table_like/diff.sql create mode 100644 testdata/diff/create_table/add_table_like/new.sql create mode 100644 testdata/diff/create_table/add_table_like/old.sql create mode 100644 testdata/diff/create_table/add_table_like/plan.json create mode 100644 testdata/diff/create_table/add_table_like/plan.sql create mode 100644 testdata/diff/create_table/add_table_like/plan.txt create mode 100644 testdata/diff/create_table/add_table_like/plan_actual.sql create mode 100644 testdata/diff/create_table/add_table_like/plan_actual.txt create mode 100644 testdata/diff/create_table/add_table_like_forward_ref/diff.sql create mode 100644 testdata/diff/create_table/add_table_like_forward_ref/error_case.sql create mode 100644 testdata/diff/create_table/add_table_like_forward_ref/new.sql create mode 100644 testdata/diff/create_table/add_table_like_forward_ref/old.sql create mode 100644 testdata/diff/create_table/add_table_like_forward_ref/plan.json create mode 100644 testdata/diff/create_table/add_table_like_forward_ref/plan.sql create mode 100644 testdata/diff/create_table/add_table_like_forward_ref/plan.txt diff --git a/internal/diff/table.go b/internal/diff/table.go index da2ea70e..4651c234 100644 --- a/internal/diff/table.go +++ b/internal/diff/table.go @@ -422,6 +422,16 @@ func generateTableSQL(table *ir.Table, targetSchema string) string { columnParts = append(columnParts, fmt.Sprintf(" %s", builder.String())) } + // Add LIKE clauses + for _, likeClause := range table.LikeClauses { + likeTableName := util.QualifyEntityNameWithQuotes(likeClause.SourceSchema, likeClause.SourceTable, targetSchema) + likeSQL := fmt.Sprintf("LIKE %s", likeTableName) + if likeClause.Options != "" { + likeSQL += " " + likeClause.Options + } + columnParts = append(columnParts, fmt.Sprintf(" %s", likeSQL)) + } + // Add constraints inline in the correct order (PRIMARY KEY, UNIQUE, FOREIGN KEY) inlineConstraints := getInlineConstraintsForTable(table) for _, constraint := range inlineConstraints { diff --git a/internal/ir/ir.go b/internal/ir/ir.go index 6c7e3247..9a732658 100644 --- a/internal/ir/ir.go +++ b/internal/ir/ir.go @@ -29,6 +29,13 @@ type Schema struct { mu sync.RWMutex // Protects concurrent access to all maps } +// LikeClause represents a LIKE clause in CREATE TABLE statement +type LikeClause struct { + SourceSchema string `json:"source_schema"` + SourceTable string `json:"source_table"` + Options string `json:"options"` // e.g., "INCLUDING ALL" or "INCLUDING DEFAULTS EXCLUDING INDEXES" +} + // Table represents a database table type Table struct { Schema string `json:"schema"` @@ -45,6 +52,7 @@ type Table struct { IsPartitioned bool `json:"is_partitioned"` PartitionStrategy string `json:"partition_strategy,omitempty"` // RANGE, LIST, HASH PartitionKey string `json:"partition_key,omitempty"` // Column(s) used for partitioning + LikeClauses []LikeClause `json:"like_clauses,omitempty"` // LIKE clauses in CREATE TABLE } // Column represents a table column diff --git a/internal/ir/parser.go b/internal/ir/parser.go index abe6e41b..ae95b73d 100644 --- a/internal/ir/parser.go +++ b/internal/ir/parser.go @@ -11,6 +11,78 @@ import ( "github.com/pgschema/pgschema/internal/util" ) +// Constants for LIKE clause options matching pg_query constants +const ( + CREATE_TABLE_LIKE_COMMENTS = 1 << 0 // 1 + CREATE_TABLE_LIKE_COMPRESSION = 1 << 1 // 2 + CREATE_TABLE_LIKE_CONSTRAINTS = 1 << 2 // 4 + CREATE_TABLE_LIKE_DEFAULTS = 1 << 3 // 8 + CREATE_TABLE_LIKE_GENERATED = 1 << 4 // 16 + CREATE_TABLE_LIKE_IDENTITY = 1 << 5 // 32 + CREATE_TABLE_LIKE_INDEXES = 1 << 6 // 64 + CREATE_TABLE_LIKE_STATISTICS = 1 << 7 // 128 + CREATE_TABLE_LIKE_STORAGE = 1 << 8 // 256 + CREATE_TABLE_LIKE_ALL = 1 << 9 // 512 +) + +// convertLikeOptions converts a bitmask to SQL LIKE clause options string +func convertLikeOptions(options uint32) string { + if options == 0 { + return "" + } + + // Handle INCLUDING ALL case + if options&CREATE_TABLE_LIKE_ALL != 0 { + return "INCLUDING ALL" + } + + var including []string + var excluding []string + + // Check each option + if options&CREATE_TABLE_LIKE_COMMENTS != 0 { + including = append(including, "COMMENTS") + } + if options&CREATE_TABLE_LIKE_COMPRESSION != 0 { + including = append(including, "COMPRESSION") + } + if options&CREATE_TABLE_LIKE_CONSTRAINTS != 0 { + including = append(including, "CONSTRAINTS") + } + if options&CREATE_TABLE_LIKE_DEFAULTS != 0 { + including = append(including, "DEFAULTS") + } + if options&CREATE_TABLE_LIKE_GENERATED != 0 { + including = append(including, "GENERATED") + } + if options&CREATE_TABLE_LIKE_IDENTITY != 0 { + including = append(including, "IDENTITY") + } + if options&CREATE_TABLE_LIKE_INDEXES != 0 { + including = append(including, "INDEXES") + } + if options&CREATE_TABLE_LIKE_STATISTICS != 0 { + including = append(including, "STATISTICS") + } + if options&CREATE_TABLE_LIKE_STORAGE != 0 { + including = append(including, "STORAGE") + } + + var result []string + + // Add INCLUDING clauses + for _, option := range including { + result = append(result, "INCLUDING "+option) + } + + // Add EXCLUDING clauses (for now we don't have excluding info in the bitmask) + for _, option := range excluding { + result = append(result, "EXCLUDING "+option) + } + + return strings.Join(result, " ") +} + // ParsingPhase represents the current phase of SQL parsing type ParsingPhase int @@ -23,7 +95,16 @@ const ( // DeferredStatements holds statements that need to be processed in a later phase type DeferredStatements struct { - Triggers []string // Trigger statements to be processed after tables exist + Triggers []string // Trigger statements to be processed after tables exist + LikeClauses map[string][]*TableLikeRef // Tables with unresolved LIKE clauses: "schema.table" -> []LikeClauseRef +} + +// TableLikeRef represents a table that has unresolved LIKE clauses +type TableLikeRef struct { + Schema string + Table string + LikeClause *LikeClause + TargetTable *Table } // Parser handles parsing SQL statements into IR representation @@ -61,7 +142,8 @@ func (p *Parser) ParseSQL(sqlContent string) (*IR, error) { // Initialize deferred statements structure deferred := &DeferredStatements{ - Triggers: make([]string, 0), + Triggers: make([]string, 0), + LikeClauses: make(map[string][]*TableLikeRef), } // First pass: Parse all statements except triggers @@ -71,6 +153,10 @@ func (p *Parser) ParseSQL(sqlContent string) (*IR, error) { } } + if err := p.resolveDeferredLikeClauses(deferred); err != nil { + return nil, fmt.Errorf("failed to resolve deferred LIKE clauses: %w", err) + } + // Second pass: Parse deferred triggers now that all tables exist for _, triggerStmt := range deferred.Triggers { if err := p.parseStatement(triggerStmt, ParsingPhaseDeferred, deferred); err != nil { @@ -119,7 +205,7 @@ func (p *Parser) parseStatement(stmt string, phase ParsingPhase, deferred *Defer // Process each parsed statement for _, parsedStmt := range result.Stmts { if parsedStmt.Stmt != nil { - if err := p.processStatement(parsedStmt.Stmt); err != nil { + if err := p.processStatement(parsedStmt.Stmt, deferred); err != nil { return err } } @@ -129,10 +215,10 @@ func (p *Parser) parseStatement(stmt string, phase ParsingPhase, deferred *Defer } // processStatement processes a single parsed statement node -func (p *Parser) processStatement(stmt *pg_query.Node) error { +func (p *Parser) processStatement(stmt *pg_query.Node, deferred *DeferredStatements) error { switch node := stmt.Node.(type) { case *pg_query.Node_CreateStmt: - return p.parseCreateTable(node.CreateStmt) + return p.parseCreateTable(node.CreateStmt, deferred) case *pg_query.Node_ViewStmt: return p.parseCreateView(node.ViewStmt) case *pg_query.Node_CreateTableAsStmt: @@ -253,7 +339,7 @@ func (p *Parser) extractIntValue(node *pg_query.Node) int { } // parseCreateTable parses CREATE TABLE statements -func (p *Parser) parseCreateTable(createStmt *pg_query.CreateStmt) error { +func (p *Parser) parseCreateTable(createStmt *pg_query.CreateStmt, deferred *DeferredStatements) error { schemaName, tableName := p.extractTableName(createStmt.Relation) // Get or create schema @@ -287,6 +373,7 @@ func (p *Parser) parseCreateTable(createStmt *pg_query.CreateStmt) error { // Parse columns position := 1 + var allInlineConstraints []*Constraint for _, element := range createStmt.TableElts { switch elt := element.Node.(type) { case *pg_query.Node_ColumnDef: @@ -317,15 +404,256 @@ func (p *Parser) parseCreateTable(createStmt *pg_query.CreateStmt) error { } } } + + case *pg_query.Node_TableLikeClause: + // Expand LIKE clause instead of storing it + err := p.expandTableLikeClause(elt.TableLikeClause, table, schemaName, &allInlineConstraints, deferred) + if err != nil { + return err + } } } + // Add any inline constraints from LIKE clauses to the table + for _, constraint := range allInlineConstraints { + table.Constraints[constraint.Name] = constraint + } + // Add table to schema dbSchema.Tables[tableName] = table return nil } +// parseTableLikeClause parses a LIKE clause in CREATE TABLE statement +func (p *Parser) parseTableLikeClause(likeClause *pg_query.TableLikeClause, currentSchema string) *LikeClause { + // Extract source table name + sourceSchema, sourceTable := p.extractTableName(likeClause.Relation) + + // Convert options bitmask to SQL string + options := convertLikeOptions(likeClause.Options) + + return &LikeClause{ + SourceSchema: sourceSchema, + SourceTable: sourceTable, + Options: options, + } +} + +// expandTableLikeClause expands a LIKE clause by copying elements from the source table +func (p *Parser) expandTableLikeClause(likeClause *pg_query.TableLikeClause, targetTable *Table, currentSchema string, inlineConstraints *[]*Constraint, deferred *DeferredStatements) error { + // Extract source table name + sourceSchema, sourceTable := p.extractTableName(likeClause.Relation) + if sourceSchema == "" { + sourceSchema = currentSchema + } + + // Find the source table in our parsed schemas + sourceTableObj := p.findTable(sourceSchema, sourceTable) + if sourceTableObj == nil { + // If we can't find the source table, defer the LIKE clause for later processing + // This handles cases where the source table is defined after the target table + likeClauseObj := p.parseTableLikeClause(likeClause, currentSchema) + + // Create a reference for deferred processing + tableKey := fmt.Sprintf("%s.%s", targetTable.Schema, targetTable.Name) + likeRef := &TableLikeRef{ + Schema: targetTable.Schema, + Table: targetTable.Name, + LikeClause: likeClauseObj, + TargetTable: targetTable, + } + + // Store in deferred map + deferred.LikeClauses[tableKey] = append(deferred.LikeClauses[tableKey], likeRef) + return nil + } + + // Determine what to include based on options + options := likeClause.Options + includeAll := options&CREATE_TABLE_LIKE_ALL != 0 + + // Copy columns (always included with LIKE) + for _, column := range sourceTableObj.Columns { + newColumn := *column // Copy the column + newColumn.Position = len(targetTable.Columns) + 1 + targetTable.Columns = append(targetTable.Columns, &newColumn) + } + + // Copy defaults if requested + if includeAll || options&CREATE_TABLE_LIKE_DEFAULTS != 0 { + // Defaults are included as part of column definitions, already handled above + } + + // Copy constraints if requested + if includeAll || options&CREATE_TABLE_LIKE_CONSTRAINTS != 0 { + for _, constraint := range sourceTableObj.Constraints { + // Create a new constraint for the target table + newConstraint := *constraint // Copy the constraint + newConstraint.Schema = targetTable.Schema + newConstraint.Table = targetTable.Name + + // Update constraint name to match PostgreSQL's LIKE behavior + // PostgreSQL replaces the table name part of the constraint name + if strings.HasPrefix(newConstraint.Name, sourceTableObj.Name+"_") { + suffix := strings.TrimPrefix(newConstraint.Name, sourceTableObj.Name+"_") + newConstraint.Name = targetTable.Name + "_" + suffix + } + + *inlineConstraints = append(*inlineConstraints, &newConstraint) + } + } + + // Copy indexes if requested + if includeAll || options&CREATE_TABLE_LIKE_INDEXES != 0 { + for _, index := range sourceTableObj.Indexes { + // Create a new index for the target table + newIndex := *index // Copy the index + newIndex.Schema = targetTable.Schema + newIndex.Table = targetTable.Name + + // Update index name to match PostgreSQL's LIKE behavior + // PostgreSQL generates new index names to avoid conflicts + newIndexName := p.generateIndexNameForLike(sourceTableObj.Name, targetTable.Name, index.Name) + newIndex.Name = newIndexName + + // Add the copied index to the target table + if targetTable.Indexes == nil { + targetTable.Indexes = make(map[string]*Index) + } + targetTable.Indexes[newIndex.Name] = &newIndex + } + } + + // Copy comments if requested + if includeAll || options&CREATE_TABLE_LIKE_COMMENTS != 0 { + // Table comment + if sourceTableObj.Comment != "" { + targetTable.Comment = sourceTableObj.Comment + } + + // Column comments are already copied with the columns + } + + return nil +} + +// generateIndexNameForLike generates a new index name when copying via LIKE clause +// following PostgreSQL's naming convention +func (p *Parser) generateIndexNameForLike(sourceTableName, targetTableName, originalIndexName string) string { + // PostgreSQL automatically generates new index names when using LIKE + // We need to extract the meaningful part (usually column names) from the original + // index name and create a new name with the target table + + // Pattern 1: idx__ -> __idx + if strings.HasPrefix(originalIndexName, "idx_") { + remainder := strings.TrimPrefix(originalIndexName, "idx_") + + // Try to extract column name by removing table name components + sourceTableClean := strings.Trim(sourceTableName, "_") + tableComponents := strings.Split(sourceTableClean, "_") + + // Remove table components from the beginning of remainder + indexComponents := strings.Split(remainder, "_") + + // Find where table components end and column components begin + columnStart := 0 + for i, tableComp := range tableComponents { + if i < len(indexComponents) && indexComponents[i] == tableComp { + columnStart = i + 1 + } else { + break + } + } + + // Extract column components + if columnStart < len(indexComponents) { + columnPart := strings.Join(indexComponents[columnStart:], "_") + return targetTableName + "_" + columnPart + "_idx" + } + + // Fallback: use remainder as-is + return targetTableName + "_" + remainder + "_idx" + } + + // Pattern 2: __idx -> __idx + if strings.HasPrefix(originalIndexName, sourceTableName+"_") && strings.HasSuffix(originalIndexName, "_idx") { + middle := strings.TrimPrefix(originalIndexName, sourceTableName+"_") + middle = strings.TrimSuffix(middle, "_idx") + return targetTableName + "_" + middle + "_idx" + } + + // Pattern 3: Fallback - generate a unique name + return targetTableName + "_" + originalIndexName + "_idx" +} + +// resolveDeferredLikeClauses processes all deferred LIKE clauses after all tables are parsed +func (p *Parser) resolveDeferredLikeClauses(deferred *DeferredStatements) error { + // Process all deferred LIKE clauses + for tableKey, likeRefs := range deferred.LikeClauses { + for _, likeRef := range likeRefs { + // Try to find the source table now + sourceTableObj := p.findTable(likeRef.LikeClause.SourceSchema, likeRef.LikeClause.SourceTable) + if sourceTableObj == nil { + return fmt.Errorf("LIKE clause references non-existent table: %s.%s", + likeRef.LikeClause.SourceSchema, likeRef.LikeClause.SourceTable) + } + + // Parse LIKE options + options := likeRef.LikeClause.Options + likeClause := &pg_query.TableLikeClause{ + Relation: &pg_query.RangeVar{ + Schemaname: likeRef.LikeClause.SourceSchema, + Relname: likeRef.LikeClause.SourceTable, + }, + Options: 0, // We'll set this properly + } + + // Convert options back to bitmask for processing + // This is a simplification - in a full implementation you'd need to properly parse the options string + if strings.Contains(options, "INCLUDING ALL") { + likeClause.Options = CREATE_TABLE_LIKE_ALL + } else { + if strings.Contains(options, "INCLUDING DEFAULTS") { + likeClause.Options |= CREATE_TABLE_LIKE_DEFAULTS + } + if strings.Contains(options, "INCLUDING CONSTRAINTS") { + likeClause.Options |= CREATE_TABLE_LIKE_CONSTRAINTS + } + if strings.Contains(options, "INCLUDING INDEXES") { + likeClause.Options |= CREATE_TABLE_LIKE_INDEXES + } + if strings.Contains(options, "INCLUDING COMMENTS") { + likeClause.Options |= CREATE_TABLE_LIKE_COMMENTS + } + } + + // Now expand the LIKE clause with empty inline constraints (we'll handle them separately) + var inlineConstraints []*Constraint + if err := p.expandTableLikeClause(likeClause, likeRef.TargetTable, likeRef.Schema, &inlineConstraints, deferred); err != nil { + return fmt.Errorf("failed to expand deferred LIKE clause for table %s: %w", tableKey, err) + } + + // Add any inline constraints to the target table + for _, constraint := range inlineConstraints { + likeRef.TargetTable.Constraints[constraint.Name] = constraint + } + } + } + + return nil +} + +// findTable searches for a table in all parsed schemas +func (p *Parser) findTable(schemaName, tableName string) *Table { + if schema, exists := p.schema.Schemas[schemaName]; exists { + if table, exists := schema.Tables[tableName]; exists { + return table + } + } + return nil +} + // parseColumnDef parses a column definition and returns the column plus any inline constraints func (p *Parser) parseColumnDef(colDef *pg_query.ColumnDef, position int, schemaName, tableName string) (*Column, []*Constraint) { column := &Column{ @@ -388,7 +716,7 @@ func (p *Parser) parseColumnDef(colDef *pg_query.ColumnDef, position int, schema case "d": identity.Generation = "BY DEFAULT" } - + // Set PostgreSQL defaults for identity columns to match inspector behavior start := int64(1) identity.Start = &start @@ -399,7 +727,7 @@ func (p *Parser) parseColumnDef(colDef *pg_query.ColumnDef, position int, schema minimum := int64(1) identity.Minimum = &minimum // Cycle defaults to false, so we don't set it - + column.Identity = identity // Identity columns are implicitly NOT NULL column.IsNullable = false @@ -941,31 +1269,31 @@ func (p *Parser) parseAExpr(expr *pg_query.A_Expr) string { return fmt.Sprintf("%s IN %s", left, right) } - // Simplified implementation for basic expressions - if len(expr.Name) > 0 { - if str := expr.Name[0].GetString_(); str != nil { - op := str.Sval - left := p.extractExpressionText(expr.Lexpr) - // Special-case BETWEEN: right side comes as a 2-item list - if strings.EqualFold(op, "between") { - if listNode, ok := expr.Rexpr.Node.(*pg_query.Node_List); ok { - if len(listNode.List.Items) == 2 { - low := p.extractExpressionText(listNode.List.Items[0]) - high := p.extractExpressionText(listNode.List.Items[1]) - return fmt.Sprintf("%s BETWEEN %s AND %s", left, low, high) - } - } - } - right := p.extractExpressionText(expr.Rexpr) - // Add parentheses for comparison operators (matching PostgreSQL's internal format) - switch op { - case ">=", "<=", ">", "<", "=", "<>", "!=", "~", "~*", "!~", "!~*": - return fmt.Sprintf("(%s %s %s)", left, op, right) - default: - return fmt.Sprintf("%s %s %s", left, op, right) - } - } - } + // Simplified implementation for basic expressions + if len(expr.Name) > 0 { + if str := expr.Name[0].GetString_(); str != nil { + op := str.Sval + left := p.extractExpressionText(expr.Lexpr) + // Special-case BETWEEN: right side comes as a 2-item list + if strings.EqualFold(op, "between") { + if listNode, ok := expr.Rexpr.Node.(*pg_query.Node_List); ok { + if len(listNode.List.Items) == 2 { + low := p.extractExpressionText(listNode.List.Items[0]) + high := p.extractExpressionText(listNode.List.Items[1]) + return fmt.Sprintf("%s BETWEEN %s AND %s", left, low, high) + } + } + } + right := p.extractExpressionText(expr.Rexpr) + // Add parentheses for comparison operators (matching PostgreSQL's internal format) + switch op { + case ">=", "<=", ">", "<", "=", "<>", "!=", "~", "~*", "!~", "!~*": + return fmt.Sprintf("(%s %s %s)", left, op, right) + default: + return fmt.Sprintf("%s %s %s", left, op, right) + } + } + } return "" } @@ -1484,10 +1812,10 @@ func (p *Parser) parseCreateSequence(seqStmt *pg_query.CreateSeqStmt) error { sequence := &Sequence{ Schema: schemaName, Name: seqName, - DataType: "", // Empty means no explicit data type specified - StartValue: 1, // Default - Increment: 1, // Default - CycleOption: false, // Default + DataType: "", // Empty means no explicit data type specified + StartValue: 1, // Default + Increment: 1, // Default + CycleOption: false, // Default } // Parse all sequence options from the AST @@ -1676,7 +2004,7 @@ func (p *Parser) handleAddColumn(cmd *pg_query.AlterTableCmd, table *Table) erro maxPosition = col.Position } } - + // New column gets the next position position := maxPosition + 1 @@ -1684,7 +2012,7 @@ func (p *Parser) handleAddColumn(cmd *pg_query.AlterTableCmd, table *Table) erro // Add the column to the table table.Columns = append(table.Columns, column) - + return nil } diff --git a/testdata/diff/create_table/add_table_like/diff.sql b/testdata/diff/create_table/add_table_like/diff.sql new file mode 100644 index 00000000..c463ce1c --- /dev/null +++ b/testdata/diff/create_table/add_table_like/diff.sql @@ -0,0 +1,18 @@ +CREATE TABLE IF NOT EXISTS products ( + id SERIAL PRIMARY KEY, + created_at timestamptz DEFAULT now() NOT NULL, + updated_at timestamptz DEFAULT now() NOT NULL, + deleted_at timestamptz +); + +CREATE TABLE IF NOT EXISTS users ( + id SERIAL PRIMARY KEY, + created_at timestamptz DEFAULT now() NOT NULL, + updated_at timestamptz DEFAULT now() NOT NULL, + deleted_at timestamptz, + CHECK (created_at <= updated_at) +); + +COMMENT ON TABLE users IS 'Template for timestamp fields'; + +CREATE INDEX IF NOT EXISTS users_created_at_idx ON users (created_at); \ No newline at end of file diff --git a/testdata/diff/create_table/add_table_like/new.sql b/testdata/diff/create_table/add_table_like/new.sql new file mode 100644 index 00000000..6e920b7c --- /dev/null +++ b/testdata/diff/create_table/add_table_like/new.sql @@ -0,0 +1,24 @@ +-- Template table for common timestamp fields +CREATE TABLE public._template_timestamps ( + created_at timestamptz NOT NULL DEFAULT now(), + updated_at timestamptz NOT NULL DEFAULT now(), + deleted_at timestamptz, + CHECK (created_at <= updated_at) +); + +CREATE INDEX idx_template_created_at ON public._template_timestamps (created_at); + +COMMENT ON TABLE public._template_timestamps IS 'Template for timestamp fields'; +COMMENT ON COLUMN public._template_timestamps.created_at IS 'Record creation time'; + +-- Products table using LIKE with specific options +CREATE TABLE public.products ( + id serial PRIMARY KEY, + LIKE public._template_timestamps INCLUDING DEFAULTS +); + +-- Users table using LIKE with INCLUDING ALL +CREATE TABLE public.users ( + id serial PRIMARY KEY, + LIKE public._template_timestamps INCLUDING ALL +); \ No newline at end of file diff --git a/testdata/diff/create_table/add_table_like/old.sql b/testdata/diff/create_table/add_table_like/old.sql new file mode 100644 index 00000000..53e919f9 --- /dev/null +++ b/testdata/diff/create_table/add_table_like/old.sql @@ -0,0 +1,12 @@ +-- Template table for common timestamp fields +CREATE TABLE public._template_timestamps ( + created_at timestamptz NOT NULL DEFAULT now(), + updated_at timestamptz NOT NULL DEFAULT now(), + deleted_at timestamptz, + CHECK (created_at <= updated_at) +); + +CREATE INDEX idx_template_created_at ON public._template_timestamps (created_at); + +COMMENT ON TABLE public._template_timestamps IS 'Template for timestamp fields'; +COMMENT ON COLUMN public._template_timestamps.created_at IS 'Record creation time'; \ No newline at end of file diff --git a/testdata/diff/create_table/add_table_like/plan.json b/testdata/diff/create_table/add_table_like/plan.json new file mode 100644 index 00000000..94ab782b --- /dev/null +++ b/testdata/diff/create_table/add_table_like/plan.json @@ -0,0 +1,66 @@ +{ + "version": "1.0.0", + "pgschema_version": "1.0.2", + "created_at": "1970-01-01T00:00:00Z", + "source_fingerprint": { + "hash": "bcda23084995439e43e6387779062084fe7c9fab8123ca140161baf8ec4d2be6" + }, + "groups": [ + { + "steps": [ + { + "sql": "CREATE TABLE IF NOT EXISTS products (\n id SERIAL PRIMARY KEY,\n created_at timestamptz DEFAULT now() NOT NULL,\n updated_at timestamptz DEFAULT now() NOT NULL,\n deleted_at timestamptz\n);", + "type": "table", + "operation": "create", + "path": "public.products" + }, + { + "sql": "CREATE TABLE IF NOT EXISTS users (\n id SERIAL PRIMARY KEY,\n created_at timestamptz DEFAULT now() NOT NULL,\n updated_at timestamptz DEFAULT now() NOT NULL,\n deleted_at timestamptz,\n CHECK (created_at <= updated_at)\n);", + "type": "table", + "operation": "create", + "path": "public.users" + }, + { + "sql": "COMMENT ON TABLE users IS 'Template for timestamp fields';", + "type": "table.comment", + "operation": "create", + "path": "public.users" + } + ] + }, + { + "steps": [ + { + "sql": "CREATE INDEX CONCURRENTLY IF NOT EXISTS users_created_at_idx ON users (created_at);", + "type": "table.index", + "operation": "create", + "path": "public.users.users_created_at_idx" + } + ] + }, + { + "steps": [ + { + "sql": "SELECT \n COALESCE(i.indisvalid, false) as done,\n CASE \n WHEN p.blocks_total > 0 THEN p.blocks_done * 100 / p.blocks_total\n ELSE 0\n END as progress\nFROM pg_class c\nLEFT JOIN pg_index i ON c.oid = i.indexrelid\nLEFT JOIN pg_stat_progress_create_index p ON c.oid = p.index_relid\nWHERE c.relname = 'users_created_at_idx';", + "directive": { + "type": "wait", + "message": "Creating index users_created_at_idx" + }, + "type": "table.index", + "operation": "create", + "path": "public.users.users_created_at_idx" + } + ] + }, + { + "steps": [ + { + "sql": "COMMENT ON COLUMN _template_timestamps.created_at IS NULL;", + "type": "table.column.comment", + "operation": "alter", + "path": "public._template_timestamps.created_at" + } + ] + } + ] +} diff --git a/testdata/diff/create_table/add_table_like/plan.sql b/testdata/diff/create_table/add_table_like/plan.sql new file mode 100644 index 00000000..dbb817e6 --- /dev/null +++ b/testdata/diff/create_table/add_table_like/plan.sql @@ -0,0 +1,32 @@ +CREATE TABLE IF NOT EXISTS products ( + id SERIAL PRIMARY KEY, + created_at timestamptz DEFAULT now() NOT NULL, + updated_at timestamptz DEFAULT now() NOT NULL, + deleted_at timestamptz +); + +CREATE TABLE IF NOT EXISTS users ( + id SERIAL PRIMARY KEY, + created_at timestamptz DEFAULT now() NOT NULL, + updated_at timestamptz DEFAULT now() NOT NULL, + deleted_at timestamptz, + CHECK (created_at <= updated_at) +); + +COMMENT ON TABLE users IS 'Template for timestamp fields'; + +CREATE INDEX CONCURRENTLY IF NOT EXISTS users_created_at_idx ON users (created_at); + +-- pgschema:wait +SELECT + COALESCE(i.indisvalid, false) as done, + CASE + WHEN p.blocks_total > 0 THEN p.blocks_done * 100 / p.blocks_total + ELSE 0 + END as progress +FROM pg_class c +LEFT JOIN pg_index i ON c.oid = i.indexrelid +LEFT JOIN pg_stat_progress_create_index p ON c.oid = p.index_relid +WHERE c.relname = 'users_created_at_idx'; + +COMMENT ON COLUMN _template_timestamps.created_at IS NULL; diff --git a/testdata/diff/create_table/add_table_like/plan.txt b/testdata/diff/create_table/add_table_like/plan.txt new file mode 100644 index 00000000..6b24bed2 --- /dev/null +++ b/testdata/diff/create_table/add_table_like/plan.txt @@ -0,0 +1,52 @@ +Plan: 2 to add, 1 to modify. + +Summary by type: + tables: 2 to add, 1 to modify + +Tables: + ~ _template_timestamps + ~ created_at (column.comment) + + products + + users + + users (comment) + + users_created_at_idx (index) + +DDL to be executed: +-------------------------------------------------- + +-- Transaction Group #1 +CREATE TABLE IF NOT EXISTS products ( + id SERIAL PRIMARY KEY, + created_at timestamptz DEFAULT now() NOT NULL, + updated_at timestamptz DEFAULT now() NOT NULL, + deleted_at timestamptz +); + +CREATE TABLE IF NOT EXISTS users ( + id SERIAL PRIMARY KEY, + created_at timestamptz DEFAULT now() NOT NULL, + updated_at timestamptz DEFAULT now() NOT NULL, + deleted_at timestamptz, + CHECK (created_at <= updated_at) +); + +COMMENT ON TABLE users IS 'Template for timestamp fields'; + +-- Transaction Group #2 +CREATE INDEX CONCURRENTLY IF NOT EXISTS users_created_at_idx ON users (created_at); + +-- Transaction Group #3 +-- pgschema:wait +SELECT + COALESCE(i.indisvalid, false) as done, + CASE + WHEN p.blocks_total > 0 THEN p.blocks_done * 100 / p.blocks_total + ELSE 0 + END as progress +FROM pg_class c +LEFT JOIN pg_index i ON c.oid = i.indexrelid +LEFT JOIN pg_stat_progress_create_index p ON c.oid = p.index_relid +WHERE c.relname = 'users_created_at_idx'; + +-- Transaction Group #4 +COMMENT ON COLUMN _template_timestamps.created_at IS NULL; diff --git a/testdata/diff/create_table/add_table_like/plan_actual.sql b/testdata/diff/create_table/add_table_like/plan_actual.sql new file mode 100644 index 00000000..dbb817e6 --- /dev/null +++ b/testdata/diff/create_table/add_table_like/plan_actual.sql @@ -0,0 +1,32 @@ +CREATE TABLE IF NOT EXISTS products ( + id SERIAL PRIMARY KEY, + created_at timestamptz DEFAULT now() NOT NULL, + updated_at timestamptz DEFAULT now() NOT NULL, + deleted_at timestamptz +); + +CREATE TABLE IF NOT EXISTS users ( + id SERIAL PRIMARY KEY, + created_at timestamptz DEFAULT now() NOT NULL, + updated_at timestamptz DEFAULT now() NOT NULL, + deleted_at timestamptz, + CHECK (created_at <= updated_at) +); + +COMMENT ON TABLE users IS 'Template for timestamp fields'; + +CREATE INDEX CONCURRENTLY IF NOT EXISTS users_created_at_idx ON users (created_at); + +-- pgschema:wait +SELECT + COALESCE(i.indisvalid, false) as done, + CASE + WHEN p.blocks_total > 0 THEN p.blocks_done * 100 / p.blocks_total + ELSE 0 + END as progress +FROM pg_class c +LEFT JOIN pg_index i ON c.oid = i.indexrelid +LEFT JOIN pg_stat_progress_create_index p ON c.oid = p.index_relid +WHERE c.relname = 'users_created_at_idx'; + +COMMENT ON COLUMN _template_timestamps.created_at IS NULL; diff --git a/testdata/diff/create_table/add_table_like/plan_actual.txt b/testdata/diff/create_table/add_table_like/plan_actual.txt new file mode 100644 index 00000000..04378659 --- /dev/null +++ b/testdata/diff/create_table/add_table_like/plan_actual.txt @@ -0,0 +1,52 @@ +Plan: 2 to add, 1 to modify. + +Summary by type: + tables: 2 to add, 1 to modify + +Tables: + ~ _template_timestamps + ~ created_at (column.comment) + + products + + users + + users (comment) + + users_created_at_idx (index) + +DDL to be executed: +-------------------------------------------------- + +-- Transaction Group #1 +CREATE TABLE IF NOT EXISTS products ( + id SERIAL PRIMARY KEY, + created_at timestamptz DEFAULT now() NOT NULL, + updated_at timestamptz DEFAULT now() NOT NULL, + deleted_at timestamptz +); + +CREATE TABLE IF NOT EXISTS users ( + id SERIAL PRIMARY KEY, + created_at timestamptz DEFAULT now() NOT NULL, + updated_at timestamptz DEFAULT now() NOT NULL, + deleted_at timestamptz, + CHECK (created_at <= updated_at) +); + +COMMENT ON TABLE users IS 'Template for timestamp fields'; + +-- Transaction Group #2 +CREATE INDEX CONCURRENTLY IF NOT EXISTS users_created_at_idx ON users (created_at); + +-- Transaction Group #3 +-- pgschema:wait +SELECT + COALESCE(i.indisvalid, false) as done, + CASE + WHEN p.blocks_total > 0 THEN p.blocks_done * 100 / p.blocks_total + ELSE 0 + END as progress +FROM pg_class c +LEFT JOIN pg_index i ON c.oid = i.indexrelid +LEFT JOIN pg_stat_progress_create_index p ON c.oid = p.index_relid +WHERE c.relname = 'users_created_at_idx'; + +-- Transaction Group #4 +COMMENT ON COLUMN _template_timestamps.created_at IS NULL; \ No newline at end of file diff --git a/testdata/diff/create_table/add_table_like_forward_ref/diff.sql b/testdata/diff/create_table/add_table_like_forward_ref/diff.sql new file mode 100644 index 00000000..1f350642 --- /dev/null +++ b/testdata/diff/create_table/add_table_like_forward_ref/diff.sql @@ -0,0 +1,17 @@ +CREATE TABLE IF NOT EXISTS customers ( + customer_id integer NOT NULL, + name varchar(100) NOT NULL, + email varchar(255) UNIQUE, + created_at timestamp DEFAULT now(), + updated_at timestamp DEFAULT now() +); + +CREATE TABLE IF NOT EXISTS orders ( + id SERIAL PRIMARY KEY, + order_date date NOT NULL, + customer_id integer NOT NULL, + name varchar(100) NOT NULL, + email varchar(255), + created_at timestamp DEFAULT now(), + updated_at timestamp DEFAULT now() +); \ No newline at end of file diff --git a/testdata/diff/create_table/add_table_like_forward_ref/error_case.sql b/testdata/diff/create_table/add_table_like_forward_ref/error_case.sql new file mode 100644 index 00000000..6e14d42a --- /dev/null +++ b/testdata/diff/create_table/add_table_like_forward_ref/error_case.sql @@ -0,0 +1,6 @@ +-- Test error case: LIKE references non-existent table +CREATE TABLE public.orders ( + id SERIAL PRIMARY KEY, + order_date DATE NOT NULL, + LIKE public.nonexistent_table INCLUDING DEFAULTS +); \ No newline at end of file diff --git a/testdata/diff/create_table/add_table_like_forward_ref/new.sql b/testdata/diff/create_table/add_table_like_forward_ref/new.sql new file mode 100644 index 00000000..fac56b1c --- /dev/null +++ b/testdata/diff/create_table/add_table_like_forward_ref/new.sql @@ -0,0 +1,16 @@ +-- Test forward referencing: orders table references customers table that is defined later + +CREATE TABLE public.orders ( + id SERIAL PRIMARY KEY, + order_date DATE NOT NULL, + LIKE public.customers INCLUDING DEFAULTS +); + +-- This is the template table that orders references (defined AFTER orders) +CREATE TABLE public.customers ( + customer_id INTEGER NOT NULL, + name VARCHAR(100) NOT NULL, + email VARCHAR(255) UNIQUE, + created_at TIMESTAMP DEFAULT now(), + updated_at TIMESTAMP DEFAULT now() +); \ No newline at end of file diff --git a/testdata/diff/create_table/add_table_like_forward_ref/old.sql b/testdata/diff/create_table/add_table_like_forward_ref/old.sql new file mode 100644 index 00000000..07ac202e --- /dev/null +++ b/testdata/diff/create_table/add_table_like_forward_ref/old.sql @@ -0,0 +1 @@ +-- Empty starting state \ No newline at end of file diff --git a/testdata/diff/create_table/add_table_like_forward_ref/plan.json b/testdata/diff/create_table/add_table_like_forward_ref/plan.json new file mode 100644 index 00000000..ff970c4f --- /dev/null +++ b/testdata/diff/create_table/add_table_like_forward_ref/plan.json @@ -0,0 +1,26 @@ +{ + "version": "1.0.0", + "pgschema_version": "1.0.2", + "created_at": "1970-01-01T00:00:00Z", + "source_fingerprint": { + "hash": "965b1131737c955e24c7f827c55bd78e4cb49a75adfd04229e0ba297376f5085" + }, + "groups": [ + { + "steps": [ + { + "sql": "CREATE TABLE IF NOT EXISTS customers (\n customer_id integer NOT NULL,\n name varchar(100) NOT NULL,\n email varchar(255) UNIQUE,\n created_at timestamp DEFAULT now(),\n updated_at timestamp DEFAULT now()\n);", + "type": "table", + "operation": "create", + "path": "public.customers" + }, + { + "sql": "CREATE TABLE IF NOT EXISTS orders (\n id SERIAL PRIMARY KEY,\n order_date date NOT NULL,\n customer_id integer NOT NULL,\n name varchar(100) NOT NULL,\n email varchar(255),\n created_at timestamp DEFAULT now(),\n updated_at timestamp DEFAULT now()\n);", + "type": "table", + "operation": "create", + "path": "public.orders" + } + ] + } + ] +} diff --git a/testdata/diff/create_table/add_table_like_forward_ref/plan.sql b/testdata/diff/create_table/add_table_like_forward_ref/plan.sql new file mode 100644 index 00000000..afdaa507 --- /dev/null +++ b/testdata/diff/create_table/add_table_like_forward_ref/plan.sql @@ -0,0 +1,17 @@ +CREATE TABLE IF NOT EXISTS customers ( + customer_id integer NOT NULL, + name varchar(100) NOT NULL, + email varchar(255) UNIQUE, + created_at timestamp DEFAULT now(), + updated_at timestamp DEFAULT now() +); + +CREATE TABLE IF NOT EXISTS orders ( + id SERIAL PRIMARY KEY, + order_date date NOT NULL, + customer_id integer NOT NULL, + name varchar(100) NOT NULL, + email varchar(255), + created_at timestamp DEFAULT now(), + updated_at timestamp DEFAULT now() +); diff --git a/testdata/diff/create_table/add_table_like_forward_ref/plan.txt b/testdata/diff/create_table/add_table_like_forward_ref/plan.txt new file mode 100644 index 00000000..1ca58df0 --- /dev/null +++ b/testdata/diff/create_table/add_table_like_forward_ref/plan.txt @@ -0,0 +1,29 @@ +Plan: 2 to add. + +Summary by type: + tables: 2 to add + +Tables: + + customers + + orders + +DDL to be executed: +-------------------------------------------------- + +CREATE TABLE IF NOT EXISTS customers ( + customer_id integer NOT NULL, + name varchar(100) NOT NULL, + email varchar(255) UNIQUE, + created_at timestamp DEFAULT now(), + updated_at timestamp DEFAULT now() +); + +CREATE TABLE IF NOT EXISTS orders ( + id SERIAL PRIMARY KEY, + order_date date NOT NULL, + customer_id integer NOT NULL, + name varchar(100) NOT NULL, + email varchar(255), + created_at timestamp DEFAULT now(), + updated_at timestamp DEFAULT now() +);