forked from akka/akka-persistence-jdbc
-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Browse files
Browse the repository at this point in the history
* Replace event_tag FK to get rid of insert and return akka#710 * support rolling updates akka#710 * remove CRLF akka#710 * optimized migrator akka#710 * fixes oracle test akka#710 * unitTest,SQL for migration akka#710 * fix MigratorSpec akka#710 * chore: typo fix akka#710 * fix: IntegrationTest and clean code akka#710 * fix: compatible legacy tag read akka#673 * chore: mi-ma filter for PR * fix: optimized migrate step * fix: dialect for column fill * fix: update migration sql * fix: mysql dialect * fix: dialect syntax * fix: dialect syntax * fix: avoid use system table of mysql * fix: batch insert caused flaky test * fix: insert less event of large batch * fix: script fix and strongly express two-step update
- Loading branch information
Showing
30 changed files
with
678 additions
and
79 deletions.
There are no files selected for viewing
82 changes: 82 additions & 0 deletions
82
core/src/it/scala/akka/persistence/jdbc/integration/EventsByTagMigrationTest.scala
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,82 @@ | ||
/* | ||
* Copyright (C) 2014 - 2019 Dennis Vriend <https://github.com/dnvriend> | ||
* Copyright (C) 2019 - 2023 Lightbend Inc. <https://www.lightbend.com> | ||
*/ | ||
|
||
package akka.persistence.jdbc.integration | ||
|
||
import akka.persistence.jdbc.query.{ | ||
EventsByTagMigrationTest, | ||
MysqlCleaner, | ||
OracleCleaner, | ||
PostgresCleaner, | ||
SqlServerCleaner | ||
} | ||
|
||
class PostgresScalaEventsByTagMigrationTest | ||
extends EventsByTagMigrationTest("postgres-application.conf") | ||
with PostgresCleaner {} | ||
|
||
class MySQLScalaEventByTagMigrationTest extends EventsByTagMigrationTest("mysql-application.conf") with MysqlCleaner { | ||
|
||
override def dropLegacyFKConstraint(): Unit = | ||
dropConstraint(constraintType = "FOREIGN KEY", constraintDialect = "FOREIGN KEY") | ||
|
||
override def dropLegacyPKConstraint(): Unit = | ||
dropConstraint(constraintType = "PRIMARY KEY", constraintDialect = "", constraintNameDialect = "KEY") | ||
|
||
override def addNewPKConstraint(): Unit = | ||
addPKConstraint(constraintNameDialect = "") | ||
|
||
override def addNewFKConstraint(): Unit = | ||
addFKConstraint() | ||
|
||
override def migrateLegacyRows(): Unit = | ||
fillNewColumn( | ||
joinDialect = joinSQL, | ||
pidSetDialect = | ||
s"${tagTableCfg.tableName}.${tagTableCfg.columnNames.persistenceId} = ${journalTableName}.${journalTableCfg.columnNames.persistenceId}", | ||
seqNrSetDialect = | ||
s"${tagTableCfg.tableName}.${tagTableCfg.columnNames.sequenceNumber} = ${journalTableName}.${journalTableCfg.columnNames.sequenceNumber}") | ||
} | ||
|
||
class OracleScalaEventByTagMigrationTest | ||
extends EventsByTagMigrationTest("oracle-application.conf") | ||
with OracleCleaner { | ||
|
||
override def addNewColumn(): Unit = { | ||
// mock event_id not null, in order to change it to null later | ||
alterColumn(alterDialect = "MODIFY", changeToDialect = "NOT NULL") | ||
} | ||
|
||
override def dropLegacyFKConstraint(): Unit = | ||
dropConstraint(constraintTableName = "USER_CONSTRAINTS", constraintType = "R") | ||
|
||
override def dropLegacyPKConstraint(): Unit = | ||
dropConstraint(constraintTableName = "USER_CONSTRAINTS", constraintType = "P") | ||
|
||
override def migrateLegacyRows(): Unit = | ||
withStatement { stmt => | ||
stmt.execute(s"""UPDATE ${tagTableCfg.tableName} | ||
|SET (${tagTableCfg.columnNames.persistenceId}, ${tagTableCfg.columnNames.sequenceNumber}) = ( | ||
| SELECT ${journalTableCfg.columnNames.persistenceId}, ${journalTableCfg.columnNames.sequenceNumber} | ||
| ${fromSQL} | ||
|) | ||
|WHERE EXISTS ( | ||
| SELECT 1 | ||
| ${fromSQL} | ||
|)""".stripMargin) | ||
} | ||
} | ||
|
||
class SqlServerScalaEventByTagMigrationTest | ||
extends EventsByTagMigrationTest("sqlserver-application.conf") | ||
with SqlServerCleaner { | ||
|
||
override def addNewPKConstraint(): Unit = { | ||
// Change new column not null | ||
alterColumn(columnName = tagTableCfg.columnNames.persistenceId, changeToDialect = "NVARCHAR(255) NOT NULL") | ||
alterColumn(columnName = tagTableCfg.columnNames.sequenceNumber, changeToDialect = "NUMERIC(10,0) NOT NULL") | ||
super.addNewPKConstraint() | ||
} | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
9 changes: 9 additions & 0 deletions
9
core/src/main/mima-filters/5.4.0.backwards.excludes/issue-710-tag-fk.excludes
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,9 @@ | ||
ProblemFilters.exclude[IncompatibleSignatureProblem]("akka.persistence.jdbc.journal.dao.JournalTables#EventTags.eventId") | ||
ProblemFilters.exclude[IncompatibleResultTypeProblem]("akka.persistence.jdbc.journal.dao.JournalTables#TagRow.eventId") | ||
ProblemFilters.exclude[DirectMissingMethodProblem]("akka.persistence.jdbc.journal.dao.JournalTables#TagRow.copy") | ||
ProblemFilters.exclude[IncompatibleResultTypeProblem]("akka.persistence.jdbc.journal.dao.JournalTables#TagRow.copy$default$1") | ||
ProblemFilters.exclude[IncompatibleResultTypeProblem]("akka.persistence.jdbc.journal.dao.JournalTables#TagRow.copy$default$2") | ||
ProblemFilters.exclude[DirectMissingMethodProblem]("akka.persistence.jdbc.journal.dao.JournalTables#TagRow.this") | ||
ProblemFilters.exclude[MissingTypesProblem]("akka.persistence.jdbc.journal.dao.JournalTables$TagRow$") | ||
ProblemFilters.exclude[DirectMissingMethodProblem]("akka.persistence.jdbc.journal.dao.JournalTables#TagRow.apply") | ||
ProblemFilters.exclude[IncompatibleSignatureProblem]("akka.persistence.jdbc.journal.dao.JournalTables#TagRow.unapply") |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
36 changes: 36 additions & 0 deletions
36
core/src/main/resources/schema/mysql/mysql-event-tag-migration.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,36 @@ | ||
-- **************** first step **************** | ||
-- add new column | ||
ALTER TABLE event_tag | ||
ADD persistence_id VARCHAR(255), | ||
ADD sequence_number BIGINT; | ||
-- **************** second step **************** | ||
-- migrate rows | ||
UPDATE event_tag | ||
INNER JOIN event_journal ON event_tag.event_id = event_journal.ordering | ||
SET event_tag.persistence_id = event_journal.persistence_id, | ||
event_tag.sequence_number = event_journal.sequence_number; | ||
-- drop old FK constraint | ||
SELECT CONSTRAINT_NAME | ||
INTO @fk_constraint_name | ||
FROM INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS | ||
WHERE TABLE_NAME = 'event_tag'; | ||
SET @alter_query = CONCAT('ALTER TABLE event_tag DROP FOREIGN KEY ', @fk_constraint_name); | ||
PREPARE stmt FROM @alter_query; | ||
EXECUTE stmt; | ||
DEALLOCATE PREPARE stmt; | ||
-- drop old PK constraint | ||
ALTER TABLE event_tag | ||
DROP PRIMARY KEY; | ||
-- create new PK constraint for PK column. | ||
ALTER TABLE event_tag | ||
ADD CONSTRAINT | ||
PRIMARY KEY (persistence_id, sequence_number, tag); | ||
-- create new FK constraint for PK column. | ||
ALTER TABLE event_tag | ||
ADD CONSTRAINT fk_event_journal_on_pk | ||
FOREIGN KEY (persistence_id, sequence_number) | ||
REFERENCES event_journal (persistence_id, sequence_number) | ||
ON DELETE CASCADE; | ||
-- alter the event_id to nullable, so we can skip the InsertAndReturn. | ||
ALTER TABLE event_tag | ||
MODIFY COLUMN event_id BIGINT UNSIGNED NULL; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
52 changes: 52 additions & 0 deletions
52
core/src/main/resources/schema/oracle/oracle-event-tag-migration.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,52 @@ | ||
-- **************** first step **************** | ||
-- add new column | ||
ALTER TABLE EVENT_TAG | ||
ADD (PERSISTENCE_ID VARCHAR2(255), | ||
SEQUENCE_NUMBER NUMERIC); | ||
-- **************** second step **************** | ||
-- migrate rows | ||
UPDATE EVENT_TAG | ||
SET PERSISTENCE_ID = (SELECT PERSISTENCE_ID | ||
FROM EVENT_JOURNAL | ||
WHERE EVENT_TAG.EVENT_ID = EVENT_JOURNAL.ORDERING), | ||
SEQUENCE_NUMBER = (SELECT SEQUENCE_NUMBER | ||
FROM EVENT_JOURNAL | ||
WHERE EVENT_TAG.EVENT_ID = EVENT_JOURNAL.ORDERING) | ||
-- drop old FK constraint | ||
DECLARE | ||
v_constraint_name VARCHAR2(255); | ||
BEGIN | ||
SELECT CONSTRAINT_NAME | ||
INTO v_constraint_name | ||
FROM USER_CONSTRAINTS | ||
WHERE TABLE_NAME = 'EVENT_TAG' | ||
AND CONSTRAINT_TYPE = 'R'; | ||
|
||
IF v_constraint_name IS NOT NULL THEN | ||
EXECUTE IMMEDIATE 'ALTER TABLE EVENT_TAG DROP CONSTRAINT ' || v_constraint_name; | ||
END IF; | ||
|
||
COMMIT; | ||
EXCEPTION | ||
WHEN OTHERS THEN | ||
ROLLBACK; | ||
RAISE; | ||
END; | ||
/ | ||
|
||
-- drop old PK constraint | ||
ALTER TABLE EVENT_TAG | ||
DROP PRIMARY KEY; | ||
-- create new PK constraint for PK column. | ||
ALTER TABLE EVENT_TAG | ||
ADD CONSTRAINT "pk_event_tag" | ||
PRIMARY KEY (PERSISTENCE_ID, SEQUENCE_NUMBER, TAG); | ||
-- create new FK constraint for PK column. | ||
ALTER TABLE EVENT_TAG | ||
ADD CONSTRAINT fk_EVENT_JOURNAL_on_pk | ||
FOREIGN KEY (PERSISTENCE_ID, SEQUENCE_NUMBER) | ||
REFERENCES EVENT_JOURNAL (PERSISTENCE_ID, SEQUENCE_NUMBER) | ||
ON DELETE CASCADE; | ||
-- alter the EVENT_ID to nullable, so we can skip the InsertAndReturn. | ||
ALTER TABLE EVENT_TAG | ||
MODIFY EVENT_ID NULL; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
31 changes: 31 additions & 0 deletions
31
core/src/main/resources/schema/postgres/postgres-event-tag-migration.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,31 @@ | ||
-- **************** first step **************** | ||
-- add new column | ||
ALTER TABLE public.event_tag | ||
ADD persistence_id VARCHAR(255), | ||
ADD sequence_number BIGINT; | ||
-- **************** second step **************** | ||
-- migrate rows | ||
UPDATE public.event_tag | ||
SET persistence_id = public.event_journal.persistence_id, | ||
sequence_number = public.event_journal.sequence_number | ||
FROM event_journal | ||
WHERE public.event_tag.event_id = public.event_journal.ordering; | ||
-- drop old FK constraint | ||
ALTER TABLE public.event_tag | ||
DROP CONSTRAINT "fk_event_journal"; | ||
-- drop old PK constraint | ||
ALTER TABLE public.event_tag | ||
DROP CONSTRAINT "event_tag_pkey"; | ||
-- create new PK constraint for PK column. | ||
ALTER TABLE public.event_tag | ||
ADD CONSTRAINT "pk_event_tag" | ||
PRIMARY KEY (persistence_id, sequence_number, tag); | ||
-- create new FK constraint for PK column. | ||
ALTER TABLE public.event_tag | ||
ADD CONSTRAINT "fk_event_journal_on_pk" | ||
FOREIGN KEY (persistence_id, sequence_number) | ||
REFERENCES public.event_journal (persistence_id, sequence_number) | ||
ON DELETE CASCADE; | ||
-- alter the event_id to nullable, so we can skip the InsertAndReturn. | ||
ALTER TABLE public.event_tag | ||
ALTER COLUMN event_id DROP NOT NULL; |
Oops, something went wrong.