# PostgreSQL Migration Writer ## Overview The PostgreSQL Migration Writer implements database schema inspection and differential migration generation, following the same approach as the `pgsql_meta_upgrade` migration system. It compares a desired model (target schema) against the current database state and generates the necessary SQL migration scripts. ## Migration Phases The migration writer follows a phased approach with specific priorities to ensure proper execution order: ### Phase 1: Drops (Priority 11-50) - Drop changed constraints (Priority 11) - Drop changed indexes (Priority 20) - Drop changed foreign keys (Priority 50) ### Phase 2: Renames (Priority 60-90) - Rename tables (Priority 60) - Rename columns (Priority 90) - *Note: Currently requires manual handling or metadata for rename detection* ### Phase 3: Tables & Columns (Priority 100-145) - Create new tables (Priority 100) - Add new columns (Priority 120) - Alter column types (Priority 120) - Alter column defaults (Priority 145) ### Phase 4: Indexes (Priority 160-180) - Create primary keys (Priority 160) - Create indexes (Priority 180) ### Phase 5: Foreign Keys (Priority 195) - Create foreign key constraints ### Phase 6: Comments (Priority 200+) - Add table and column comments ## Usage ### 1. Inspect Current Database ```go import ( "git.warky.dev/wdevs/relspecgo/pkg/readers" "git.warky.dev/wdevs/relspecgo/pkg/readers/pgsql" ) // Create reader with connection string options := &readers.ReaderOptions{ ConnectionString: "host=localhost port=5432 dbname=mydb user=postgres password=secret", } reader := pgsql.NewReader(options) // Read current database state currentDB, err := reader.ReadDatabase() if err != nil { log.Fatal(err) } ``` ### 2. Define Desired Model ```go import "git.warky.dev/wdevs/relspecgo/pkg/models" // Create desired model (could be loaded from DBML, JSON, etc.) modelDB := models.InitDatabase("mydb") schema := models.InitSchema("public") // Define table table := models.InitTable("users", "public") table.Description = "User accounts" // Add columns idCol := models.InitColumn("id", "users", "public") idCol.Type = "integer" idCol.NotNull = true idCol.IsPrimaryKey = true table.Columns["id"] = idCol nameCol := models.InitColumn("name", "users", "public") nameCol.Type = "text" nameCol.NotNull = true table.Columns["name"] = nameCol emailCol := models.InitColumn("email", "users", "public") emailCol.Type = "text" table.Columns["email"] = emailCol // Add primary key constraint pkConstraint := &models.Constraint{ Name: "pk_users", Type: models.PrimaryKeyConstraint, Columns: []string{"id"}, } table.Constraints["pk_users"] = pkConstraint // Add unique index emailIndex := &models.Index{ Name: "uk_users_email", Unique: true, Columns: []string{"email"}, } table.Indexes["uk_users_email"] = emailIndex schema.Tables = append(schema.Tables, table) modelDB.Schemas = append(modelDB.Schemas, schema) ``` ### 3. Generate Migration ```go import ( "git.warky.dev/wdevs/relspecgo/pkg/writers" "git.warky.dev/wdevs/relspecgo/pkg/writers/pgsql" ) // Create migration writer writerOptions := &writers.WriterOptions{ OutputPath: "migration_001.sql", } migrationWriter := pgsql.NewMigrationWriter(writerOptions) // Generate migration comparing model vs current err = migrationWriter.WriteMigration(modelDB, currentDB) if err != nil { log.Fatal(err) } ``` ## Example Migration Output ```sql -- PostgreSQL Migration Script -- Generated by RelSpec -- Source: mydb -> mydb -- Priority: 11 | Type: drop constraint | Object: public.users.old_constraint ALTER TABLE public.users DROP CONSTRAINT IF EXISTS old_constraint; -- Priority: 100 | Type: create table | Object: public.orders CREATE TABLE IF NOT EXISTS public.orders ( id integer NOT NULL, user_id integer, total numeric(10,2) DEFAULT 0.00, created_at timestamp DEFAULT CURRENT_TIMESTAMP ); -- Priority: 120 | Type: create column | Object: public.users.phone ALTER TABLE public.users ADD COLUMN IF NOT EXISTS phone text; -- Priority: 120 | Type: alter column type | Object: public.users.age ALTER TABLE public.users ALTER COLUMN age TYPE integer; -- Priority: 160 | Type: create primary key | Object: public.orders.pk_orders DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.table_constraints WHERE table_schema = 'public' AND table_name = 'orders' AND constraint_name = 'pk_orders' ) THEN ALTER TABLE public.orders ADD CONSTRAINT pk_orders PRIMARY KEY (id); END IF; END; $$; -- Priority: 180 | Type: create index | Object: public.users.idx_users_email CREATE INDEX IF NOT EXISTS idx_users_email ON public.users USING btree (email); -- Priority: 195 | Type: create foreign key | Object: public.orders.fk_orders_users ALTER TABLE public.orders DROP CONSTRAINT IF EXISTS fk_orders_users; ALTER TABLE public.orders ADD CONSTRAINT fk_orders_users FOREIGN KEY (user_id) REFERENCES public.users (id) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE; -- Priority: 200 | Type: comment on table | Object: public.users COMMENT ON TABLE public.users IS 'User accounts'; -- Priority: 200 | Type: comment on column | Object: public.users.email COMMENT ON COLUMN public.users.email IS 'User email address'; ``` ## Migration Script Structure Each migration script includes: - **ObjectName**: Fully qualified name of the object being modified - **ObjectType**: Type of operation (create table, alter column, etc.) - **Schema**: Schema name - **Priority**: Execution order priority (lower runs first) - **Sequence**: Sub-ordering within same priority - **Body**: The actual SQL statement ## Comparison Logic The migration writer compares objects using: ### Tables - Existence check by name (case-insensitive) - New tables generate CREATE TABLE statements ### Columns - Existence check within tables - Type changes generate ALTER COLUMN TYPE - Default value changes generate SET/DROP DEFAULT - New columns generate ADD COLUMN ### Constraints - Compared by type, columns, and referenced objects - Changed constraints are dropped and recreated ### Indexes - Compared by uniqueness and column list - Changed indexes are dropped and recreated ### Foreign Keys - Compared by columns, referenced table/columns, and actions - Changed foreign keys are dropped and recreated ## Best Practices 1. **Always Review Generated Migrations**: Manually review SQL before execution 2. **Test on Non-Production First**: Apply migrations to development/staging environments first 3. **Backup Before Migration**: Create database backup before running migrations 4. **Use Transactions**: Wrap migrations in transactions when possible 5. **Handle Renames Carefully**: Column/table renames may appear as DROP + CREATE without metadata 6. **Consider Data Migration**: Generated SQL handles structure only; data migration may be needed ## Limitations 1. **Rename Detection**: Automatic rename detection not implemented; requires GUID or metadata matching 2. **Data Type Conversions**: Some type changes may require custom USING clauses 3. **Complex Constraints**: CHECK constraints with complex expressions may need manual handling 4. **Sequence Values**: Current sequence values not automatically synced 5. **Permissions**: Schema and object permissions not included in migrations ## Integration with Migration System This implementation follows the same logic as the SQL migration system in `examples/pgsql_meta_upgrade`: - `migration_inspect.sql` → Reader (pkg/readers/pgsql) - `migration_build.sql` → MigrationWriter (pkg/writers/pgsql) - `migration_run.sql` → External execution (psql, application code) The phases, priorities, and script generation logic match the original migration system to ensure compatibility and consistency.