From 66b75de87a6e061b380360418efaa7b9f711f052 Mon Sep 17 00:00:00 2001 From: Tran Minh Luan Date: Thu, 11 Jul 2024 16:44:20 +0700 Subject: [PATCH] gormschema: supports trigger (#50) * refactor: re-order code blocks: public first * feat: allow defining Triggers() for a model * fix: use Triggers return type as an array of Options * tests: update test cases for trigger * docs: update usage for trigger * refactor: change creating trigger API * chore: re-hash atlas.sum * fix: remove unicode character * fix: correct sqlite migration files * chore: add comments * docs: change trigger usage --- README.md | 32 +++ gormschema/gorm.go | 183 +++++++++++------- gormschema/gorm_test.go | 41 +++- gormschema/testdata/mysql_default | 14 ++ .../testdata/mysql_deterministic_output | 14 ++ gormschema/testdata/postgresql_default | 26 +++ gormschema/testdata/sqlite_default | 12 ++ gormschema/testdata/sqlite_no_fk | 12 ++ gormschema/testdata/sqlserver_default | 28 +++ .../migrations/mysql/20240528162003.sql | 16 ++ internal/testdata/migrations/mysql/atlas.sum | 5 +- .../migrations/postgres/20240528162135.sql | 26 +++ .../testdata/migrations/postgres/atlas.sum | 5 +- .../migrations/sqlite/20240528162330.sql | 16 ++ internal/testdata/migrations/sqlite/atlas.sum | 5 +- .../migrations/sqlserver/20240528162241.sql | 28 +++ .../testdata/migrations/sqlserver/atlas.sum | 5 +- internal/testdata/models/pet.go | 99 ++++++++++ 18 files changed, 487 insertions(+), 80 deletions(-) create mode 100644 internal/testdata/migrations/mysql/20240528162003.sql create mode 100644 internal/testdata/migrations/postgres/20240528162135.sql create mode 100644 internal/testdata/migrations/sqlite/20240528162330.sql create mode 100644 internal/testdata/migrations/sqlserver/20240528162241.sql diff --git a/README.md b/README.md index dd74875..bbd1815 100644 --- a/README.md +++ b/README.md @@ -136,6 +136,7 @@ env "gorm" { > Note: Views are available for logged-in users, run `atlas login` if you haven't already. To learn more about logged-in features for Atlas, visit [Feature Availability](https://atlasgo.io/features#database-features). To define a Go struct as a database `VIEW`, implement the `ViewDef` method as follow: + ```go // User is a regular gorm.Model stored in the "users" table. type User struct { @@ -158,7 +159,9 @@ func (WorkingAgedUsers) ViewDef(dialect string) []gormschema.ViewOption { } } ``` + In order to pass a plain `CREATE VIEW` statement, use the `CreateStmt` as follows: + ```go type BotlTracker struct { ID uint @@ -176,19 +179,48 @@ func (BotlTracker) ViewDef(dialect string) []gormschema.ViewOption { } } ``` + To include both VIEWs and TABLEs in the migration generation, pass all models to the `Load` function: + ```go stmts, err := gormschema.New("mysql").Load( &models.User{}, // Table-based model. &models.WorkingAgedUsers{}, // View-based model. ) ``` + The view-based model works just like a regular models in GORM queries. However, make sure the view name is identical to the struct name, and in case they are differ, configure the name using the `TableName` method: + ```go func (WorkingAgedUsers) TableName() string { return "working_aged_users_custom_name" // View name is different than pluralized struct name. } ``` + +#### Trigger + +> Note: Trigger feature is only available for logged-in users, run `atlas login` if you haven't already. To learn more about logged-in features for Atlas, visit [Feature Availability](https://atlasgo.io/features#database-features). + +To attach triggers to a table, use the `Triggers` method as follows: + +```go +type Pet struct { + gorm.Model + Name string +} + +func (Pet) Triggers(dialect string) []gormschema.Trigger { + var stmt string + switch dialect { + case "mysql": + stmt = "CREATE TRIGGER pet_insert BEFORE INSERT ON pets FOR EACH ROW SET NEW.name = UPPER(NEW.name)" + } + return []gormschema.Trigger{ + gormschema.NewTrigger(gormschema.CreateStmt(stmt)), + } +} +``` + ### Additional Configuration To supply custom `gorm.Config{}` object to the provider use the [Go Program Mode](#as-go-file) with diff --git a/gormschema/gorm.go b/gormschema/gorm.go index 6cfd393..01dda5c 100644 --- a/gormschema/gorm.go +++ b/gormschema/gorm.go @@ -17,15 +17,6 @@ import ( gormig "gorm.io/gorm/migrator" ) -// New returns a new Loader. -func New(dialect string, opts ...Option) *Loader { - l := &Loader{dialect: dialect, config: &gorm.Config{}} - for _, opt := range opts { - opt(l) - } - return l -} - type ( // Loader is a Loader for gorm schema. Loader struct { @@ -35,6 +26,33 @@ type ( } // Option configures the Loader. Option func(*Loader) + // ViewOption implemented by VIEW's related options + ViewOption interface { + isViewOption() + apply(*schemaBuilder) + } + // TriggerOption implemented by TRIGGER's related options + TriggerOption interface { + isTriggerOption() + apply(*schemaBuilder) + } + // Trigger defines a trigger. + Trigger struct { + opts []TriggerOption + } + // ViewDefiner defines a view. + ViewDefiner interface { + ViewDef(dialect string) []ViewOption + } + // schemaOption configures the schemaBuilder. + schemaOption func(*schemaBuilder) + schemaBuilder struct { + db *gorm.DB + createStmt string + // viewName is only used for the BuildStmt option. + // BuildStmt returns only a subquery; viewName helps to create a full CREATE VIEW statement. + viewName string + } ) // WithConfig sets the gorm config. @@ -44,6 +62,60 @@ func WithConfig(cfg *gorm.Config) Option { } } +// WithJoinTable sets up a join table for the given model and field. +// Deprecated: put the join tables alongside the models in the Load call. +func WithJoinTable(model any, field string, jointable any) Option { + return func(l *Loader) { + l.beforeAutoMigrate = append(l.beforeAutoMigrate, func(db *gorm.DB) error { + return db.SetupJoinTable(model, field, jointable) + }) + } +} + +// New returns a new Loader. +func New(dialect string, opts ...Option) *Loader { + l := &Loader{dialect: dialect, config: &gorm.Config{}} + for _, opt := range opts { + opt(l) + } + return l +} + +// NewTrigger receives a list of TriggerOption to build a Trigger. +func NewTrigger(opts ...TriggerOption) Trigger { + return Trigger{opts: opts} +} + +func (s schemaOption) apply(b *schemaBuilder) { + s(b) +} + +func (schemaOption) isViewOption() {} +func (schemaOption) isTriggerOption() {} + +// CreateStmt accepts raw SQL to create a view or trigger +func CreateStmt(stmt string) interface { + ViewOption + TriggerOption +} { + return schemaOption(func(b *schemaBuilder) { + b.createStmt = stmt + }) +} + +// BuildStmt accepts a function with gorm query builder to create a CREATE VIEW statement. +// With this option, the view's name will be the same as the model's table name +func BuildStmt(fn func(db *gorm.DB) *gorm.DB) ViewOption { + return schemaOption(func(b *schemaBuilder) { + vd := b.db.ToSQL(func(tx *gorm.DB) *gorm.DB { + return fn(tx). + Unscoped(). // Skip gorm deleted_at filtering. + Find(nil) // Execute the query and convert it to SQL. + }) + b.createStmt = fmt.Sprintf("CREATE VIEW %s AS %s", b.viewName, vd) + }) +} + // Load loads the models and returns the DDL statements representing the schema. func (l *Loader) Load(models ...any) (string, error) { var ( @@ -125,6 +197,9 @@ func (l *Loader) Load(models ...any) (string, error) { if err = cm.CreateViews(views); err != nil { return "", err } + if err = cm.CreateTriggers(models); err != nil { + return "", err + } if !l.config.DisableForeignKeyConstraintWhenMigrating && l.dialect != "sqlite" { if err = cm.CreateConstraints(tables); err != nil { return "", err @@ -242,75 +317,20 @@ func (m *migrator) CreateViews(views []ViewDefiner) error { }); ok { viewName = namer.TableName() } - viewBuilder := &viewBuilder{ + schemaBuilder := &schemaBuilder{ db: m.DB, viewName: viewName, } for _, opt := range view.ViewDef(m.Dialector.Name()) { - opt(viewBuilder) + opt.apply(schemaBuilder) } - if err := m.DB.Exec(viewBuilder.createStmt).Error; err != nil { + if err := m.DB.Exec(schemaBuilder.createStmt).Error; err != nil { return err } } return nil } -// WithJoinTable sets up a join table for the given model and field. -// Deprecated: put the join tables alongside the models in the Load call. -func WithJoinTable(model any, field string, jointable any) Option { - return func(l *Loader) { - l.beforeAutoMigrate = append(l.beforeAutoMigrate, func(db *gorm.DB) error { - return db.SetupJoinTable(model, field, jointable) - }) - } -} - -func indirect(t reflect.Type) reflect.Type { - for t.Kind() == reflect.Ptr { - t = t.Elem() - } - return t -} - -type ( - // ViewOption configures a viewBuilder. - ViewOption func(*viewBuilder) - // ViewDefiner defines a view. - ViewDefiner interface { - ViewDef(dialect string) []ViewOption - } - viewBuilder struct { - db *gorm.DB - createStmt string - // viewName is only used for the BuildStmt option. - // BuildStmt returns only a subquery; viewName helps to create a full CREATE VIEW statement. - viewName string - } -) - -// CreateStmt accepts raw SQL to create a CREATE VIEW statement. -func CreateStmt(stmt string) ViewOption { - return func(b *viewBuilder) { - b.createStmt = b.db.ToSQL(func(tx *gorm.DB) *gorm.DB { - return tx.Exec(stmt) - }) - } -} - -// BuildStmt accepts a function with gorm query builder to create a CREATE VIEW statement. -// With this option, the view's name will be the same as the model's table name -func BuildStmt(fn func(db *gorm.DB) *gorm.DB) ViewOption { - return func(b *viewBuilder) { - vd := b.db.ToSQL(func(tx *gorm.DB) *gorm.DB { - return fn(tx). - Unscoped(). // Skip gorm deleted_at filtering. - Find(nil) // Execute the query and convert it to SQL. - }) - b.createStmt = fmt.Sprintf("CREATE VIEW %s AS %s", b.viewName, vd) - } -} - // orderModels places join tables at the end of the list of models (if any), // which helps GORM resolve m2m relationships correctly. func (m *migrator) orderModels(models ...any) ([]any, error) { @@ -348,3 +368,32 @@ func (m *migrator) orderModels(models ...any) ([]any, error) { } return append(otherTables, joinTables...), nil } + +// CreateTriggers creates the triggers for the given models. +func (m *migrator) CreateTriggers(models []any) error { + for _, model := range models { + if md, ok := model.(interface { + Triggers(string) []Trigger + }); ok { + for _, trigger := range md.Triggers(m.Dialector.Name()) { + schemaBuilder := &schemaBuilder{ + db: m.DB, + } + for _, opt := range trigger.opts { + opt.apply(schemaBuilder) + if err := m.DB.Exec(schemaBuilder.createStmt).Error; err != nil { + return err + } + } + } + } + } + return nil +} + +func indirect(t reflect.Type) reflect.Type { + for t.Kind() == reflect.Ptr { + t = t.Elem() + } + return t +} diff --git a/gormschema/gorm_test.go b/gormschema/gorm_test.go index f2d6e36..93fdae8 100644 --- a/gormschema/gorm_test.go +++ b/gormschema/gorm_test.go @@ -16,14 +16,21 @@ import ( func TestSQLiteConfig(t *testing.T) { resetSession() l := gormschema.New("sqlite") - sql, err := l.Load(models.WorkingAgedUsers{}, models.Pet{}, ckmodels.Event{}, ckmodels.Location{}, models.TopPetOwner{}) + sql, err := l.Load( + models.WorkingAgedUsers{}, + models.Pet{}, + models.UserPetHistory{}, + ckmodels.Event{}, + ckmodels.Location{}, + models.TopPetOwner{}, + ) require.NoError(t, err) requireEqualContent(t, sql, "testdata/sqlite_default") resetSession() l = gormschema.New("sqlite", gormschema.WithConfig(&gorm.Config{ DisableForeignKeyConstraintWhenMigrating: true, })) - sql, err = l.Load(models.Pet{}, models.User{}) + sql, err = l.Load(models.UserPetHistory{}, models.Pet{}, models.User{}) require.NoError(t, err) requireEqualContent(t, sql, "testdata/sqlite_no_fk") resetSession() @@ -32,7 +39,15 @@ func TestSQLiteConfig(t *testing.T) { func TestPostgreSQLConfig(t *testing.T) { resetSession() l := gormschema.New("postgres") - sql, err := l.Load(models.WorkingAgedUsers{}, ckmodels.Location{}, ckmodels.Event{}, models.User{}, models.Pet{}, models.TopPetOwner{}) + sql, err := l.Load( + models.WorkingAgedUsers{}, + ckmodels.Location{}, + ckmodels.Event{}, + models.UserPetHistory{}, + models.User{}, + models.Pet{}, + models.TopPetOwner{}, + ) require.NoError(t, err) requireEqualContent(t, sql, "testdata/postgresql_default") resetSession() @@ -48,7 +63,15 @@ func TestPostgreSQLConfig(t *testing.T) { func TestMySQLConfig(t *testing.T) { resetSession() l := gormschema.New("mysql") - sql, err := l.Load(models.WorkingAgedUsers{}, ckmodels.Location{}, ckmodels.Event{}, models.User{}, models.Pet{}, models.TopPetOwner{}) + sql, err := l.Load( + models.WorkingAgedUsers{}, + ckmodels.Location{}, + ckmodels.Event{}, + models.UserPetHistory{}, + models.User{}, + models.Pet{}, + models.TopPetOwner{}, + ) require.NoError(t, err) requireEqualContent(t, sql, "testdata/mysql_default") resetSession() @@ -80,7 +103,15 @@ func TestMySQLConfig(t *testing.T) { func TestSQLServerConfig(t *testing.T) { resetSession() l := gormschema.New("sqlserver") - sql, err := l.Load(models.WorkingAgedUsers{}, ckmodels.Location{}, ckmodels.Event{}, models.User{}, models.Pet{}, models.TopPetOwner{}) + sql, err := l.Load( + models.WorkingAgedUsers{}, + ckmodels.Location{}, + ckmodels.Event{}, + models.UserPetHistory{}, + models.User{}, + models.Pet{}, + models.TopPetOwner{}, + ) require.NoError(t, err) requireEqualContent(t, sql, "testdata/sqlserver_default") resetSession() diff --git a/gormschema/testdata/mysql_default b/gormschema/testdata/mysql_default index 2e42336..87f336f 100644 --- a/gormschema/testdata/mysql_default +++ b/gormschema/testdata/mysql_default @@ -1,11 +1,25 @@ CREATE TABLE `events` (`eventId` varchar(191),`locationId` varchar(191),PRIMARY KEY (`eventId`),UNIQUE INDEX `idx_events_location_id` (`locationId`)); CREATE TABLE `locations` (`locationId` varchar(191),`eventId` varchar(191),PRIMARY KEY (`locationId`),UNIQUE INDEX `idx_locations_event_id` (`eventId`)); +CREATE TABLE `user_pet_histories` (`user_id` bigint unsigned,`pet_id` bigint unsigned,`created_at` datetime(3) NULL,PRIMARY KEY (`user_id`,`pet_id`)); CREATE TABLE `users` (`id` bigint unsigned AUTO_INCREMENT,`created_at` datetime(3) NULL,`updated_at` datetime(3) NULL,`deleted_at` datetime(3) NULL,`name` longtext,`age` bigint,PRIMARY KEY (`id`),INDEX `idx_users_deleted_at` (`deleted_at`)); CREATE TABLE `hobbies` (`id` bigint unsigned AUTO_INCREMENT,`name` longtext,PRIMARY KEY (`id`)); CREATE TABLE `user_hobbies` (`hobby_id` bigint unsigned,`user_id` bigint unsigned,PRIMARY KEY (`hobby_id`,`user_id`)); CREATE TABLE `pets` (`id` bigint unsigned AUTO_INCREMENT,`created_at` datetime(3) NULL,`updated_at` datetime(3) NULL,`deleted_at` datetime(3) NULL,`name` longtext,`user_id` bigint unsigned,PRIMARY KEY (`id`),INDEX `idx_pets_deleted_at` (`deleted_at`)); CREATE VIEW working_aged_users AS SELECT name, age FROM `users` WHERE age BETWEEN 18 AND 65; CREATE VIEW top_pet_owners AS SELECT user_id, COUNT(id) AS pet_count FROM pets GROUP BY user_id ORDER BY pet_count DESC LIMIT 10; +CREATE TRIGGER trg_insert_user_pet_history +AFTER INSERT ON pets +FOR EACH ROW +BEGIN + INSERT INTO user_pet_histories (user_id, pet_id, created_at) + VALUES (NEW.user_id, NEW.id, NOW(3)); +END; +CREATE TRIGGER trg_adding_heart_on_pet +BEFORE INSERT ON pets +FOR EACH ROW +BEGIN + SET NEW.name = CONCAT(NEW.name, ' <3'); +END; ALTER TABLE `events` ADD CONSTRAINT `fk_locations_event` FOREIGN KEY (`locationId`) REFERENCES `locations`(`locationId`); ALTER TABLE `locations` ADD CONSTRAINT `fk_events_location` FOREIGN KEY (`eventId`) REFERENCES `events`(`eventId`); ALTER TABLE `user_hobbies` ADD CONSTRAINT `fk_user_hobbies_hobby` FOREIGN KEY (`hobby_id`) REFERENCES `hobbies`(`id`); diff --git a/gormschema/testdata/mysql_deterministic_output b/gormschema/testdata/mysql_deterministic_output index 9feb1df..c41114f 100644 --- a/gormschema/testdata/mysql_deterministic_output +++ b/gormschema/testdata/mysql_deterministic_output @@ -2,8 +2,22 @@ CREATE TABLE `hobbies` (`id` bigint unsigned AUTO_INCREMENT,`name` longtext,PRIM CREATE TABLE `users` (`id` bigint unsigned AUTO_INCREMENT,`created_at` datetime(3) NULL,`updated_at` datetime(3) NULL,`deleted_at` datetime(3) NULL,`name` longtext,`age` bigint,PRIMARY KEY (`id`),INDEX `idx_users_deleted_at` (`deleted_at`)); CREATE TABLE `user_hobbies` (`user_id` bigint unsigned,`hobby_id` bigint unsigned,PRIMARY KEY (`user_id`,`hobby_id`)); CREATE TABLE `pets` (`id` bigint unsigned AUTO_INCREMENT,`created_at` datetime(3) NULL,`updated_at` datetime(3) NULL,`deleted_at` datetime(3) NULL,`name` longtext,`user_id` bigint unsigned,PRIMARY KEY (`id`),INDEX `idx_pets_deleted_at` (`deleted_at`)); +CREATE TABLE `user_pet_histories` (`user_id` bigint unsigned,`pet_id` bigint unsigned,`created_at` datetime(3) NULL,PRIMARY KEY (`user_id`,`pet_id`)); CREATE VIEW top_pet_owners AS SELECT user_id, COUNT(id) AS pet_count FROM pets GROUP BY user_id ORDER BY pet_count DESC LIMIT 10; CREATE VIEW working_aged_users AS SELECT name, age FROM `users` WHERE age BETWEEN 18 AND 65; +CREATE TRIGGER trg_insert_user_pet_history +AFTER INSERT ON pets +FOR EACH ROW +BEGIN + INSERT INTO user_pet_histories (user_id, pet_id, created_at) + VALUES (NEW.user_id, NEW.id, NOW(3)); +END; +CREATE TRIGGER trg_adding_heart_on_pet +BEFORE INSERT ON pets +FOR EACH ROW +BEGIN + SET NEW.name = CONCAT(NEW.name, ' <3'); +END; ALTER TABLE `user_hobbies` ADD CONSTRAINT `fk_user_hobbies_hobby` FOREIGN KEY (`hobby_id`) REFERENCES `hobbies`(`id`); ALTER TABLE `user_hobbies` ADD CONSTRAINT `fk_user_hobbies_user` FOREIGN KEY (`user_id`) REFERENCES `users`(`id`); ALTER TABLE `pets` ADD CONSTRAINT `fk_users_pets` FOREIGN KEY (`user_id`) REFERENCES `users`(`id`); diff --git a/gormschema/testdata/postgresql_default b/gormschema/testdata/postgresql_default index d0c022d..60fd2d6 100644 --- a/gormschema/testdata/postgresql_default +++ b/gormschema/testdata/postgresql_default @@ -2,6 +2,7 @@ CREATE TABLE "events" ("eventId" varchar(191),"locationId" varchar(191),PRIMARY CREATE UNIQUE INDEX IF NOT EXISTS "idx_events_location_id" ON "events" ("locationId"); CREATE TABLE "locations" ("locationId" varchar(191),"eventId" varchar(191),PRIMARY KEY ("locationId")); CREATE UNIQUE INDEX IF NOT EXISTS "idx_locations_event_id" ON "locations" ("eventId"); +CREATE TABLE "user_pet_histories" ("user_id" bigint,"pet_id" bigint,"created_at" timestamptz,PRIMARY KEY ("user_id","pet_id")); CREATE TABLE "users" ("id" bigserial,"created_at" timestamptz,"updated_at" timestamptz,"deleted_at" timestamptz,"name" text,"age" bigint,PRIMARY KEY ("id")); CREATE INDEX IF NOT EXISTS "idx_users_deleted_at" ON "users" ("deleted_at"); CREATE TABLE "hobbies" ("id" bigserial,"name" text,PRIMARY KEY ("id")); @@ -10,6 +11,31 @@ CREATE TABLE "pets" ("id" bigserial,"created_at" timestamptz,"updated_at" timest CREATE INDEX IF NOT EXISTS "idx_pets_deleted_at" ON "pets" ("deleted_at"); CREATE VIEW working_aged_users AS SELECT name, age FROM "users" WHERE age BETWEEN 18 AND 65; CREATE VIEW top_pet_owners AS SELECT user_id, COUNT(id) AS pet_count FROM pets GROUP BY user_id ORDER BY pet_count DESC LIMIT 10; +CREATE OR REPLACE FUNCTION log_user_pet_histories() +RETURNS TRIGGER AS $$ +BEGIN + INSERT INTO user_pet_histories (user_id, pet_id, created_at) + VALUES (NEW.user_id, NEW.id, NEW.created_at); + RETURN NEW; +END; +$$ LANGUAGE plpgsql; + +CREATE TRIGGER trg_insert_user_pet_history +AFTER INSERT ON pets +FOR EACH ROW +EXECUTE FUNCTION log_user_pet_histories();; +CREATE OR REPLACE FUNCTION add_heart_on_pet() +RETURNS TRIGGER AS $$ +BEGIN + NEW.name := NEW.name || ' <3'; + RETURN NEW; +END; +$$ LANGUAGE plpgsql; + +CREATE TRIGGER trg_adding_heart_on_pet +BEFORE INSERT ON pets +FOR EACH ROW +EXECUTE FUNCTION add_heart_on_pet();; ALTER TABLE "events" ADD CONSTRAINT "fk_locations_event" FOREIGN KEY ("locationId") REFERENCES "locations"("locationId"); ALTER TABLE "locations" ADD CONSTRAINT "fk_events_location" FOREIGN KEY ("eventId") REFERENCES "events"("eventId"); ALTER TABLE "user_hobbies" ADD CONSTRAINT "fk_user_hobbies_hobby" FOREIGN KEY ("hobby_id") REFERENCES "hobbies"("id"); diff --git a/gormschema/testdata/sqlite_default b/gormschema/testdata/sqlite_default index ba84c95..5600293 100644 --- a/gormschema/testdata/sqlite_default +++ b/gormschema/testdata/sqlite_default @@ -2,9 +2,21 @@ CREATE TABLE `users` (`id` integer,`created_at` datetime,`updated_at` datetime,` CREATE INDEX `idx_users_deleted_at` ON `users`(`deleted_at`); CREATE TABLE `pets` (`id` integer,`created_at` datetime,`updated_at` datetime,`deleted_at` datetime,`name` text,`user_id` integer,PRIMARY KEY (`id`),CONSTRAINT `fk_users_pets` FOREIGN KEY (`user_id`) REFERENCES `users`(`id`)); CREATE INDEX `idx_pets_deleted_at` ON `pets`(`deleted_at`); +CREATE TABLE `user_pet_histories` (`user_id` integer,`pet_id` integer,`created_at` datetime,PRIMARY KEY (`user_id`,`pet_id`)); CREATE TABLE `locations` (`locationId` text,`eventId` text,PRIMARY KEY (`locationId`),CONSTRAINT `fk_events_location` FOREIGN KEY (`eventId`) REFERENCES `events`(`eventId`)); CREATE UNIQUE INDEX `idx_locations_event_id` ON `locations`(`eventId`); CREATE TABLE `events` (`eventId` text,`locationId` text,PRIMARY KEY (`eventId`),CONSTRAINT `fk_locations_event` FOREIGN KEY (`locationId`) REFERENCES `locations`(`locationId`)); CREATE UNIQUE INDEX `idx_events_location_id` ON `events`(`locationId`); CREATE VIEW working_aged_users AS SELECT name, age FROM `users` WHERE age BETWEEN 18 AND 65; CREATE VIEW top_pet_owners AS SELECT user_id, COUNT(id) AS pet_count FROM pets GROUP BY user_id ORDER BY pet_count DESC LIMIT 10; +CREATE TRIGGER trg_insert_user_pet_history +AFTER INSERT ON pets +BEGIN + INSERT INTO user_pet_histories (user_id, pet_id, created_at) + VALUES (NEW.user_id, NEW.id, datetime('now')); +END; +CREATE TRIGGER trg_adding_heart_on_pet +BEFORE INSERT ON pets +BEGIN + UPDATE pets SET name = name || ' <3' WHERE id = NEW.id; +END; diff --git a/gormschema/testdata/sqlite_no_fk b/gormschema/testdata/sqlite_no_fk index 0405a77..fb62820 100644 --- a/gormschema/testdata/sqlite_no_fk +++ b/gormschema/testdata/sqlite_no_fk @@ -1,6 +1,18 @@ +CREATE TABLE `user_pet_histories` (`user_id` integer,`pet_id` integer,`created_at` datetime,PRIMARY KEY (`user_id`,`pet_id`)); CREATE TABLE `users` (`id` integer,`created_at` datetime,`updated_at` datetime,`deleted_at` datetime,`name` text,`age` integer,PRIMARY KEY (`id`)); CREATE INDEX `idx_users_deleted_at` ON `users`(`deleted_at`); CREATE TABLE `pets` (`id` integer,`created_at` datetime,`updated_at` datetime,`deleted_at` datetime,`name` text,`user_id` integer,PRIMARY KEY (`id`)); CREATE INDEX `idx_pets_deleted_at` ON `pets`(`deleted_at`); CREATE TABLE `hobbies` (`id` integer,`name` text,PRIMARY KEY (`id`)); CREATE TABLE `user_hobbies` (`hobby_id` integer,`user_id` integer,PRIMARY KEY (`hobby_id`,`user_id`)); +CREATE TRIGGER trg_insert_user_pet_history +AFTER INSERT ON pets +BEGIN + INSERT INTO user_pet_histories (user_id, pet_id, created_at) + VALUES (NEW.user_id, NEW.id, datetime('now')); +END; +CREATE TRIGGER trg_adding_heart_on_pet +BEFORE INSERT ON pets +BEGIN + UPDATE pets SET name = name || ' <3' WHERE id = NEW.id; +END; diff --git a/gormschema/testdata/sqlserver_default b/gormschema/testdata/sqlserver_default index 1f4c36e..7fc5138 100644 --- a/gormschema/testdata/sqlserver_default +++ b/gormschema/testdata/sqlserver_default @@ -2,6 +2,7 @@ CREATE TABLE "events" ("eventId" nvarchar(191),"locationId" nvarchar(191),PRIMAR CREATE UNIQUE INDEX "idx_events_location_id" ON "events"("locationId"); CREATE TABLE "locations" ("locationId" nvarchar(191),"eventId" nvarchar(191),PRIMARY KEY ("locationId")); CREATE UNIQUE INDEX "idx_locations_event_id" ON "locations"("eventId"); +CREATE TABLE "user_pet_histories" ("user_id" bigint,"pet_id" bigint,"created_at" datetimeoffset,PRIMARY KEY ("user_id","pet_id")); CREATE TABLE "users" ("id" bigint IDENTITY(1,1),"created_at" datetimeoffset,"updated_at" datetimeoffset,"deleted_at" datetimeoffset,"name" nvarchar(MAX),"age" bigint,PRIMARY KEY ("id")); CREATE INDEX "idx_users_deleted_at" ON "users"("deleted_at"); CREATE TABLE "hobbies" ("id" bigint IDENTITY(1,1),"name" nvarchar(MAX),PRIMARY KEY ("id")); @@ -10,6 +11,33 @@ CREATE TABLE "pets" ("id" bigint IDENTITY(1,1),"created_at" datetimeoffset,"upda CREATE INDEX "idx_pets_deleted_at" ON "pets"("deleted_at"); CREATE VIEW working_aged_users AS SELECT name, age FROM "users" WHERE age BETWEEN 18 AND 65; CREATE VIEW top_pet_owners AS SELECT user_id, COUNT(id) AS pet_count FROM pets GROUP BY user_id ORDER BY pet_count DESC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY; +CREATE TRIGGER trg_insert_user_pet_history +ON pets +AFTER INSERT +AS +BEGIN + INSERT INTO user_pet_histories (user_id, pet_id, created_at) + SELECT + inserted.user_id, + inserted.id, + GETDATE() + FROM + inserted + WHERE + inserted.user_id IS NOT NULL; +END; +CREATE TRIGGER trg_adding_heart_on_pet +ON pets +INSTEAD OF INSERT +AS +BEGIN + INSERT INTO pets (name, user_id) + SELECT + CONCAT(inserted.name, ' <3'), + inserted.user_id + FROM + inserted; +END; ALTER TABLE "events" ADD CONSTRAINT "fk_locations_event" FOREIGN KEY ("locationId") REFERENCES "locations"("locationId"); ALTER TABLE "locations" ADD CONSTRAINT "fk_events_location" FOREIGN KEY ("eventId") REFERENCES "events"("eventId"); ALTER TABLE "user_hobbies" ADD CONSTRAINT "fk_user_hobbies_hobby" FOREIGN KEY ("hobby_id") REFERENCES "hobbies"("id"); diff --git a/internal/testdata/migrations/mysql/20240528162003.sql b/internal/testdata/migrations/mysql/20240528162003.sql new file mode 100644 index 0000000..283851c --- /dev/null +++ b/internal/testdata/migrations/mysql/20240528162003.sql @@ -0,0 +1,16 @@ +-- Create trigger "trg_adding_heart_on_pet" +CREATE TRIGGER `trg_adding_heart_on_pet` BEFORE INSERT ON `pets` FOR EACH ROW BEGIN + SET NEW.name = CONCAT(NEW.name, ' <3'); +END; +-- Create trigger "trg_insert_user_pet_history" +CREATE TRIGGER `trg_insert_user_pet_history` AFTER INSERT ON `pets` FOR EACH ROW BEGIN + INSERT INTO user_pet_histories (user_id, pet_id, created_at) + VALUES (NEW.user_id, NEW.id, NOW(3)); +END; +-- Create "user_pet_histories" table +CREATE TABLE `user_pet_histories` ( + `user_id` bigint unsigned NOT NULL, + `pet_id` bigint unsigned NOT NULL, + `created_at` datetime(3) NULL, + PRIMARY KEY (`user_id`, `pet_id`) +) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci; diff --git a/internal/testdata/migrations/mysql/atlas.sum b/internal/testdata/migrations/mysql/atlas.sum index 925ebbd..372aa8e 100644 --- a/internal/testdata/migrations/mysql/atlas.sum +++ b/internal/testdata/migrations/mysql/atlas.sum @@ -1,5 +1,6 @@ -h1:4neLwABljo1WE/2TflQvcvZCa4xR025viAzNEa4Cp6s= +h1:SewVf3c3uzZ3RukSbEFfrhVO7qP3fXNNZQPNSbyVm8Y= 20230627123246.sql h1:+bgzC3WJyyIR6Rv/FUvaNXJ1gkbKJlYcEMgp69yORIY= 20240512024238.sql h1:2kQL4tE/tAhvXuozmRAJ3oXTo1KRz11QosVDw+0va14= 20240518091603.sql h1:xNClqqRaOjXwg0julpsiPYsmqUcEL/hJel1iqYzi3DM= -20240601122756.sql h1:5+N9UzKTw6qQvJLf8nGw4BdFuHG0fa2JHdHn++G8MuE= +20240528162003.sql h1:t0jcB27MMyDFHC454jyy/ODE4K1H/Ekwg+7stba0TEQ= +20240601122756.sql h1:9NVhx5ubGsIZYOiXY2GSV1PcZQxrxL2F12TM/T4jRBA= diff --git a/internal/testdata/migrations/postgres/20240528162135.sql b/internal/testdata/migrations/postgres/20240528162135.sql new file mode 100644 index 0000000..a215579 --- /dev/null +++ b/internal/testdata/migrations/postgres/20240528162135.sql @@ -0,0 +1,26 @@ +-- Create "log_user_pet_histories" function +CREATE FUNCTION "public"."log_user_pet_histories" () RETURNS trigger LANGUAGE plpgsql AS $$ +BEGIN + INSERT INTO user_pet_histories (user_id, pet_id, created_at) + VALUES (NEW.user_id, NEW.id, NEW.created_at); + RETURN NEW; +END; +$$; +-- Create trigger "trg_insert_user_pet_history" +CREATE TRIGGER "trg_insert_user_pet_history" AFTER INSERT ON "public"."pets" FOR EACH ROW EXECUTE FUNCTION "public"."log_user_pet_histories"(); +-- Create "add_heart_on_pet" function +CREATE FUNCTION "public"."add_heart_on_pet" () RETURNS trigger LANGUAGE plpgsql AS $$ +BEGIN + NEW.name := NEW.name || ' <3'; + RETURN NEW; +END; +$$; +-- Create trigger "trg_adding_heart_on_pet" +CREATE TRIGGER "trg_adding_heart_on_pet" BEFORE INSERT ON "public"."pets" FOR EACH ROW EXECUTE FUNCTION "public"."add_heart_on_pet"(); +-- Create "user_pet_histories" table +CREATE TABLE "public"."user_pet_histories" ( + "user_id" bigint NOT NULL, + "pet_id" bigint NOT NULL, + "created_at" timestamptz NULL, + PRIMARY KEY ("user_id", "pet_id") +); diff --git a/internal/testdata/migrations/postgres/atlas.sum b/internal/testdata/migrations/postgres/atlas.sum index fa401b8..fb6d4b1 100644 --- a/internal/testdata/migrations/postgres/atlas.sum +++ b/internal/testdata/migrations/postgres/atlas.sum @@ -1,5 +1,6 @@ -h1:a/bAYykD/mWdu/8WM16vbYqnwg5NsdX2iM3urGrBFUc= +h1:004to5XhdkOrbE16ahrCO3rJoNEsUFkBtP6jtchr6Jo= 20230627123049.sql h1:1jYJM2+VCr9152vg6gayCrcEvuT/FE7ufOyZ86VLaOE= 20240512024223.sql h1:RY4w148OJBBr5sXpfBq6B48p/1cFrTEpH4TlwD7mUps= 20240518091611.sql h1:3Kv6mYS8ML72H6HE5qr/a2gdVUrfWuHVufP/1wl70vE= -20240601122813.sql h1:ALbhVYVMyOvZSy5jmBVrsk4xjdkx6ro8OxKJcmW0n1U= +20240528162135.sql h1:b8wlzdKR7j6se8BCHEYxQ+fOU1weAZ18rhnH6vvWzFw= +20240601122813.sql h1:y8B6XrUIXYWNxUCtxP6Tx/SZ+WHH3WsFD6BnfLaCwJc= diff --git a/internal/testdata/migrations/sqlite/20240528162330.sql b/internal/testdata/migrations/sqlite/20240528162330.sql new file mode 100644 index 0000000..f334771 --- /dev/null +++ b/internal/testdata/migrations/sqlite/20240528162330.sql @@ -0,0 +1,16 @@ +-- Create trigger "trg_insert_user_pet_history" +CREATE TRIGGER `trg_insert_user_pet_history` AFTER INSERT ON `pets` FOR EACH ROW BEGIN + INSERT INTO user_pet_histories (user_id, pet_id, created_at) + VALUES (NEW.user_id, NEW.id, datetime('now')); +END; +-- Create trigger "trg_adding_heart_on_pet" +CREATE TRIGGER `trg_adding_heart_on_pet` BEFORE INSERT ON `pets` FOR EACH ROW BEGIN + UPDATE pets SET name = name || ' <3' WHERE id = NEW.id; +END; +-- Create "user_pet_histories" table +CREATE TABLE `user_pet_histories` ( + `user_id` integer NULL, + `pet_id` integer NULL, + `created_at` datetime NULL, + PRIMARY KEY (`user_id`, `pet_id`) +); diff --git a/internal/testdata/migrations/sqlite/atlas.sum b/internal/testdata/migrations/sqlite/atlas.sum index 4bbb8ac..3f80136 100644 --- a/internal/testdata/migrations/sqlite/atlas.sum +++ b/internal/testdata/migrations/sqlite/atlas.sum @@ -1,5 +1,6 @@ -h1:n3NYZrFWODZNTYXEomQ/EtMuxc7EsQDZ7jaIgd9olYY= +h1:ZcgtDL3lj/vDZHQaciSLUG78ptrqYeZyvavU5VKXdew= 20230627123228.sql h1:YfwJdN73sWz1G5/0tU2BtGLyzJCfRQr8blTSquUZ+qo= 20240511123637.sql h1:Kbk3wUzTfBbq8mDdTT08hP93ecNU0y5oTL+O8idEcdQ= 20240518091437.sql h1:svMANRZuZDvgzqO3iyNLUjrUrK8BTMEB2f0NV3d5sJo= -20240601122746.sql h1:Jpzp4UdG5EjO8uNtRWU8sZ9fKuP4mRod5ofyFVQwH1A= +20240528162330.sql h1:UHg9lcwzLRovMOUscLmG/Pe+0UYnTc/JcA2GgGawGNM= +20240601122746.sql h1:V2pXzBKor6b4HNxdYevk2QfFhDOSnVfTmoftPFp/x58= diff --git a/internal/testdata/migrations/sqlserver/20240528162241.sql b/internal/testdata/migrations/sqlserver/20240528162241.sql new file mode 100644 index 0000000..0bd6f51 --- /dev/null +++ b/internal/testdata/migrations/sqlserver/20240528162241.sql @@ -0,0 +1,28 @@ +-- Create trigger "trg_insert_user_pet_history" +CREATE TRIGGER [trg_insert_user_pet_history] ON [pets] AFTER INSERT AS BEGIN + INSERT INTO user_pet_histories (user_id, pet_id, created_at) + SELECT + inserted.user_id, + inserted.id, + GETDATE() + FROM + inserted + WHERE + inserted.user_id IS NOT NULL; +END;; +-- Create trigger "trg_adding_heart_on_pet" +CREATE TRIGGER [trg_adding_heart_on_pet] ON [pets] INSTEAD OF INSERT AS BEGIN + INSERT INTO pets (name, user_id) + SELECT + CONCAT(inserted.name, ' <3'), + inserted.user_id + FROM + inserted; +END;; +-- Create "user_pet_histories" table +CREATE TABLE [user_pet_histories] ( + [user_id] bigint NOT NULL, + [pet_id] bigint NOT NULL, + [created_at] datetimeoffset(7) NULL, + CONSTRAINT [PK_user_pet_histories] PRIMARY KEY CLUSTERED ([user_id] ASC, [pet_id] ASC) +); diff --git a/internal/testdata/migrations/sqlserver/atlas.sum b/internal/testdata/migrations/sqlserver/atlas.sum index 6ec041b..d1a799c 100644 --- a/internal/testdata/migrations/sqlserver/atlas.sum +++ b/internal/testdata/migrations/sqlserver/atlas.sum @@ -1,5 +1,6 @@ -h1:chvbQ1yysFYmq1K82/VfQeLxzMYrhjQ+8xv+2uoXdZw= +h1:pbVtWu6feRtoRq90DbpxEC3hUK6MdCaZvh8F5kWibAs= 20240124151658.sql h1:KaWALlql7BBV3oPVRT4rn+dvZaolhDmgbTgUPxIhauU= 20240512024328.sql h1:IBON1V3jlts+AqxRhejN82SE7/BIXSUWM0SQ0pvw4wc= 20240518091510.sql h1:CCFQHjVI+5dLXCgoPSERCHhyGBZl7QistZlrs1I5170= -20240601122612.sql h1:sCf/0g9oPsaj0Z3l7WO2BjthUwsK9OfPWv80J/L1WCA= +20240528162241.sql h1:/HGF+9kwa+4jGCT4gidpNxdRAB02wn//GtMqZ7j1DOg= +20240601122612.sql h1:ff7/8377CAqwdWAoceY/A4tYlLR1mqJxTUpLdCagDnM= diff --git a/internal/testdata/models/pet.go b/internal/testdata/models/pet.go index bff753c..3685be2 100644 --- a/internal/testdata/models/pet.go +++ b/internal/testdata/models/pet.go @@ -1,6 +1,8 @@ package models import ( + "time" + "gorm.io/gorm" "ariga.io/atlas-provider-gorm/gormschema" @@ -32,3 +34,100 @@ func (TopPetOwner) ViewDef(dialect string) []gormschema.ViewOption { } return []gormschema.ViewOption{gormschema.CreateStmt(stmt)} } + +type UserPetHistory struct { + UserID uint `gorm:"primaryKey"` + PetID uint `gorm:"primaryKey"` + CreatedAt time.Time +} + +func (Pet) Triggers(dialect string) []gormschema.Trigger { + var stmt1, stmt2 string + switch dialect { + case "mysql": + stmt1 = `CREATE TRIGGER trg_insert_user_pet_history +AFTER INSERT ON pets +FOR EACH ROW +BEGIN + INSERT INTO user_pet_histories (user_id, pet_id, created_at) + VALUES (NEW.user_id, NEW.id, NOW(3)); +END` + stmt2 = `CREATE TRIGGER trg_adding_heart_on_pet +BEFORE INSERT ON pets +FOR EACH ROW +BEGIN + SET NEW.name = CONCAT(NEW.name, ' <3'); +END` + case "sqlite": + stmt1 = `CREATE TRIGGER trg_insert_user_pet_history +AFTER INSERT ON pets +BEGIN + INSERT INTO user_pet_histories (user_id, pet_id, created_at) + VALUES (NEW.user_id, NEW.id, datetime('now')); +END` + stmt2 = `CREATE TRIGGER trg_adding_heart_on_pet +BEFORE INSERT ON pets +BEGIN + UPDATE pets SET name = name || ' <3' WHERE id = NEW.id; +END` + case "postgres": + stmt1 = `CREATE OR REPLACE FUNCTION log_user_pet_histories() +RETURNS TRIGGER AS $$ +BEGIN + INSERT INTO user_pet_histories (user_id, pet_id, created_at) + VALUES (NEW.user_id, NEW.id, NEW.created_at); + RETURN NEW; +END; +$$ LANGUAGE plpgsql; + +CREATE TRIGGER trg_insert_user_pet_history +AFTER INSERT ON pets +FOR EACH ROW +EXECUTE FUNCTION log_user_pet_histories();` + stmt2 = `CREATE OR REPLACE FUNCTION add_heart_on_pet() +RETURNS TRIGGER AS $$ +BEGIN + NEW.name := NEW.name || ' <3'; + RETURN NEW; +END; +$$ LANGUAGE plpgsql; + +CREATE TRIGGER trg_adding_heart_on_pet +BEFORE INSERT ON pets +FOR EACH ROW +EXECUTE FUNCTION add_heart_on_pet();` + case "sqlserver": + stmt1 = `CREATE TRIGGER trg_insert_user_pet_history +ON pets +AFTER INSERT +AS +BEGIN + INSERT INTO user_pet_histories (user_id, pet_id, created_at) + SELECT + inserted.user_id, + inserted.id, + GETDATE() + FROM + inserted + WHERE + inserted.user_id IS NOT NULL; +END` + stmt2 = `CREATE TRIGGER trg_adding_heart_on_pet +ON pets +INSTEAD OF INSERT +AS +BEGIN + INSERT INTO pets (name, user_id) + SELECT + CONCAT(inserted.name, ' <3'), + inserted.user_id + FROM + inserted; +END` + } + + return []gormschema.Trigger{ + gormschema.NewTrigger(gormschema.CreateStmt(stmt1)), + gormschema.NewTrigger(gormschema.CreateStmt(stmt2)), + } +}