From 2a5c033fa57a13b78dcaf83c7dd93c9c61fa0679 Mon Sep 17 00:00:00 2001 From: Doug Lauder Date: Fri, 16 Dec 2022 11:15:38 -0500 Subject: [PATCH] Idempotent schema and data migrations (#4253) * modify all migration scripts for idempotency * Add readme --- Makefile | 4 +- docker-testing/docker-compose-mysql.yml | 2 +- docker-testing/docker-compose-postgres.yml | 2 +- .../mmpermissions/mocks/mockpluginapi.go | 59 +++ server/services/store/sqlstore/migrate.go | 375 +++++++++++++++++- .../migrations/000003_blocks_rootid.up.sql | 4 +- .../000005_blocks_modifiedby.up.sql | 4 +- .../sqlstore/migrations/000008_teams.up.sql | 10 +- .../migrations/000009_blocks_history.up.sql | 49 ++- .../000010_blocks_created_by.up.sql | 9 +- .../migrations/000011_match_collation.up.sql | 50 +-- .../000018_add_teams_and_boards.up.sql | 70 ++-- .../000019_populate_categories.up.sql | 4 +- .../000020_populate_category_blocks.up.sql | 3 +- ...00021_create_boards_members_history.up.sql | 16 +- .../000022_create_default_board_role.up.sql | 10 +- ...23_persist_category_collapsed_state.up.sql | 3 +- ...rk_existing_categories_collapsed.down.sql} | 0 ...mark_existing_categories_collapsed.up.sql} | 0 .../migrations/000025_indexes_update.up.sql | 6 +- .../000026_create_preferences_table.up.sql | 10 +- ...7_migrate_user_props_to_preferences.up.sql | 2 +- .../000029_add_category_type_field.up.sql | 4 +- .../000030_add_category_sort_order.up.sql | 3 +- ...0031_add_category_boards_sort_order.up.sql | 4 +- .../000032_move_boards_category_to_end.up.sql | 6 +- .../store/sqlstore/migrations/README.md | 68 ++++ .../migrationstests/boards_migrator_test.go | 2 +- server/services/store/sqlstore/sqlstore.go | 7 + server/services/store/sqlstore/util.go | 25 ++ server/ws/mocks/mockpluginapi.go | 59 +++ 31 files changed, 731 insertions(+), 139 deletions(-) rename server/services/store/sqlstore/migrations/{000024_mark_existsing_categories_collapsed.down.sql => 000024_mark_existing_categories_collapsed.down.sql} (100%) rename server/services/store/sqlstore/migrations/{000024_mark_existsing_categories_collapsed.up.sql => 000024_mark_existing_categories_collapsed.up.sql} (100%) create mode 100644 server/services/store/sqlstore/migrations/README.md diff --git a/Makefile b/Makefile index 7cab81b8b..b6e13291c 100644 --- a/Makefile +++ b/Makefile @@ -146,7 +146,7 @@ server-test-mini-sqlite: setup-go-work ## Run server tests using sqlite server-test-mysql: export FOCALBOARD_UNIT_TESTING=1 server-test-mysql: export FOCALBOARD_STORE_TEST_DB_TYPE=mysql -server-test-mysql: export FOCALBOARD_STORE_TEST_DOCKER_PORT=44445 +server-test-mysql: export FOCALBOARD_STORE_TEST_DOCKER_PORT=44446 server-test-mysql: setup-go-work ## Run server tests using mysql @echo Starting docker container for mysql @@ -174,7 +174,7 @@ server-test-mariadb: templates-archive ## Run server tests using mysql server-test-postgres: export FOCALBOARD_UNIT_TESTING=1 server-test-postgres: export FOCALBOARD_STORE_TEST_DB_TYPE=postgres -server-test-postgres: export FOCALBOARD_STORE_TEST_DOCKER_PORT=44446 +server-test-postgres: export FOCALBOARD_STORE_TEST_DOCKER_PORT=44447 server-test-postgres: setup-go-work ## Run server tests using postgres @echo Starting docker container for postgres diff --git a/docker-testing/docker-compose-mysql.yml b/docker-testing/docker-compose-mysql.yml index f4aad8400..60ea44aca 100644 --- a/docker-testing/docker-compose-mysql.yml +++ b/docker-testing/docker-compose-mysql.yml @@ -15,7 +15,7 @@ services: retries: 3 tmpfs: /var/lib/mysql ports: - - 44445:3306 + - 44446:3306 start_dependencies: image: mattermost/mattermost-wait-for-dep:latest diff --git a/docker-testing/docker-compose-postgres.yml b/docker-testing/docker-compose-postgres.yml index 463416581..529f3bb6b 100644 --- a/docker-testing/docker-compose-postgres.yml +++ b/docker-testing/docker-compose-postgres.yml @@ -13,7 +13,7 @@ services: retries: 3 tmpfs: /var/lib/postgresql/data ports: - - 44446:5432 + - 44447:5432 start_dependencies: image: mattermost/mattermost-wait-for-dep:latest diff --git a/server/services/permissions/mmpermissions/mocks/mockpluginapi.go b/server/services/permissions/mmpermissions/mocks/mockpluginapi.go index 1a2c131e1..c9ad2518e 100644 --- a/server/services/permissions/mmpermissions/mocks/mockpluginapi.go +++ b/server/services/permissions/mmpermissions/mocks/mockpluginapi.go @@ -261,6 +261,21 @@ func (mr *MockAPIMockRecorder) CreateTeamMembersGracefully(arg0, arg1, arg2 inte return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "CreateTeamMembersGracefully", reflect.TypeOf((*MockAPI)(nil).CreateTeamMembersGracefully), arg0, arg1, arg2) } +// CreateUploadSession mocks base method. +func (m *MockAPI) CreateUploadSession(arg0 *model.UploadSession) (*model.UploadSession, error) { + m.ctrl.T.Helper() + ret := m.ctrl.Call(m, "CreateUploadSession", arg0) + ret0, _ := ret[0].(*model.UploadSession) + ret1, _ := ret[1].(error) + return ret0, ret1 +} + +// CreateUploadSession indicates an expected call of CreateUploadSession. +func (mr *MockAPIMockRecorder) CreateUploadSession(arg0 interface{}) *gomock.Call { + mr.mock.ctrl.T.Helper() + return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "CreateUploadSession", reflect.TypeOf((*MockAPI)(nil).CreateUploadSession), arg0) +} + // CreateUser mocks base method. func (m *MockAPI) CreateUser(arg0 *model.User) (*model.User, *model.AppError) { m.ctrl.T.Helper() @@ -1440,6 +1455,21 @@ func (mr *MockAPIMockRecorder) GetUnsanitizedConfig() *gomock.Call { return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "GetUnsanitizedConfig", reflect.TypeOf((*MockAPI)(nil).GetUnsanitizedConfig)) } +// GetUploadSession mocks base method. +func (m *MockAPI) GetUploadSession(arg0 string) (*model.UploadSession, error) { + m.ctrl.T.Helper() + ret := m.ctrl.Call(m, "GetUploadSession", arg0) + ret0, _ := ret[0].(*model.UploadSession) + ret1, _ := ret[1].(error) + return ret0, ret1 +} + +// GetUploadSession indicates an expected call of GetUploadSession. +func (mr *MockAPIMockRecorder) GetUploadSession(arg0 interface{}) *gomock.Call { + mr.mock.ctrl.T.Helper() + return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "GetUploadSession", reflect.TypeOf((*MockAPI)(nil).GetUploadSession), arg0) +} + // GetUser mocks base method. func (m *MockAPI) GetUser(arg0 string) (*model.User, *model.AppError) { m.ctrl.T.Helper() @@ -2031,6 +2061,20 @@ func (mr *MockAPIMockRecorder) ReadFile(arg0 interface{}) *gomock.Call { return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "ReadFile", reflect.TypeOf((*MockAPI)(nil).ReadFile), arg0) } +// RegisterCollectionAndTopic mocks base method. +func (m *MockAPI) RegisterCollectionAndTopic(arg0, arg1 string) error { + m.ctrl.T.Helper() + ret := m.ctrl.Call(m, "RegisterCollectionAndTopic", arg0, arg1) + ret0, _ := ret[0].(error) + return ret0 +} + +// RegisterCollectionAndTopic indicates an expected call of RegisterCollectionAndTopic. +func (mr *MockAPIMockRecorder) RegisterCollectionAndTopic(arg0, arg1 interface{}) *gomock.Call { + mr.mock.ctrl.T.Helper() + return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "RegisterCollectionAndTopic", reflect.TypeOf((*MockAPI)(nil).RegisterCollectionAndTopic), arg0, arg1) +} + // RegisterCommand mocks base method. func (m *MockAPI) RegisterCommand(arg0 *model.Command) error { m.ctrl.T.Helper() @@ -2581,6 +2625,21 @@ func (mr *MockAPIMockRecorder) UpdateUserStatus(arg0, arg1 interface{}) *gomock. return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "UpdateUserStatus", reflect.TypeOf((*MockAPI)(nil).UpdateUserStatus), arg0, arg1) } +// UploadData mocks base method. +func (m *MockAPI) UploadData(arg0 *model.UploadSession, arg1 io.Reader) (*model.FileInfo, error) { + m.ctrl.T.Helper() + ret := m.ctrl.Call(m, "UploadData", arg0, arg1) + ret0, _ := ret[0].(*model.FileInfo) + ret1, _ := ret[1].(error) + return ret0, ret1 +} + +// UploadData indicates an expected call of UploadData. +func (mr *MockAPIMockRecorder) UploadData(arg0, arg1 interface{}) *gomock.Call { + mr.mock.ctrl.T.Helper() + return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "UploadData", reflect.TypeOf((*MockAPI)(nil).UploadData), arg0, arg1) +} + // UploadFile mocks base method. func (m *MockAPI) UploadFile(arg0 []byte, arg1, arg2 string) (*model.FileInfo, *model.AppError) { m.ctrl.T.Helper() diff --git a/server/services/store/sqlstore/migrate.go b/server/services/store/sqlstore/migrate.go index 46f9e268f..d9cd11c3b 100644 --- a/server/services/store/sqlstore/migrate.go +++ b/server/services/store/sqlstore/migrate.go @@ -7,9 +7,12 @@ import ( "embed" "errors" "fmt" + "strings" "text/template" + sq "github.com/Masterminds/squirrel" + "github.com/mattermost/mattermost-server/v6/shared/mlog" "github.com/mattermost/mattermost-server/v6/store/sqlstore" @@ -25,7 +28,7 @@ import ( "github.com/mattermost/focalboard/server/model" ) -//go:embed migrations +//go:embed migrations/*.sql var Assets embed.FS const ( @@ -159,10 +162,11 @@ func (s *SQLStore) Migrate() error { return nil, mErr } - tmpl, pErr := template.New("sql").Parse(string(asset)) + tmpl, pErr := template.New("sql").Funcs(s.GetTemplateHelperFuncs()).Parse(string(asset)) if pErr != nil { return nil, pErr } + buffer := bytes.NewBufferString("") err = tmpl.Execute(buffer, params) @@ -170,6 +174,11 @@ func (s *SQLStore) Migrate() error { return nil, err } + s.logger.Trace("migration template", + mlog.String("name", name), + mlog.String("sql", buffer.String()), + ) + return buffer.Bytes(), nil }, } @@ -282,3 +291,365 @@ func (s *SQLStore) ensureMigrationsAppliedUpToVersion(engine *morph.Morph, drive return nil } + +func (s *SQLStore) GetTemplateHelperFuncs() template.FuncMap { + funcs := template.FuncMap{ + "addColumnIfNeeded": s.genAddColumnIfNeeded, + "dropColumnIfNeeded": s.genDropColumnIfNeeded, + "createIndexIfNeeded": s.genCreateIndexIfNeeded, + "renameTableIfNeeded": s.genRenameTableIfNeeded, + "renameColumnIfNeeded": s.genRenameColumnIfNeeded, + "doesTableExist": s.doesTableExist, + "doesColumnExist": s.doesColumnExist, + } + return funcs +} + +func (s *SQLStore) genAddColumnIfNeeded(tableName, columnName, datatype, constraint string) (string, error) { + tableName = addPrefixIfNeeded(tableName, s.tablePrefix) + normTableName := normalizeTablename(s.schemaName, tableName) + + switch s.dbType { + case model.SqliteDBType: + // Sqlite does not support any conditionals that can contain DDL commands. No idempotent migrations for Sqlite :-( + return fmt.Sprintf("\nALTER TABLE %s ADD COLUMN %s %s %s;\n", normTableName, columnName, datatype, constraint), nil + case model.MysqlDBType: + vars := map[string]string{ + "schema": s.schemaName, + "table_name": tableName, + "norm_table_name": normTableName, + "column_name": columnName, + "data_type": datatype, + "constraint": constraint, + } + return replaceVars(` + SET @stmt = (SELECT IF( + ( + SELECT COUNT(column_name) FROM INFORMATION_SCHEMA.COLUMNS + WHERE table_name = '[[table_name]]' + AND table_schema = '[[schema]]' + AND column_name = '[[column_name]]' + ) > 0, + 'SELECT 1;', + 'ALTER TABLE [[norm_table_name]] ADD COLUMN [[column_name]] [[data_type]] [[constraint]];' + )); + PREPARE addColumnIfNeeded FROM @stmt; + EXECUTE addColumnIfNeeded; + DEALLOCATE PREPARE addColumnIfNeeded; + `, vars), nil + case model.PostgresDBType: + return fmt.Sprintf("\nALTER TABLE %s ADD COLUMN IF NOT EXISTS %s %s %s;\n", normTableName, columnName, datatype, constraint), nil + default: + return "", ErrUnsupportedDatabaseType + } +} + +func (s *SQLStore) genDropColumnIfNeeded(tableName, columnName string) (string, error) { + tableName = addPrefixIfNeeded(tableName, s.tablePrefix) + normTableName := normalizeTablename(s.schemaName, tableName) + + switch s.dbType { + case model.SqliteDBType: + return fmt.Sprintf("\n-- Sqlite3 cannot drop columns for versions less than 3.35.0; drop column '%s' in table '%s' skipped\n", columnName, tableName), nil + case model.MysqlDBType: + vars := map[string]string{ + "schema": s.schemaName, + "table_name": tableName, + "norm_table_name": normTableName, + "column_name": columnName, + } + return replaceVars(` + SET @stmt = (SELECT IF( + ( + SELECT COUNT(column_name) FROM INFORMATION_SCHEMA.COLUMNS + WHERE table_name = '[[table_name]]' + AND table_schema = '[[schema]]' + AND column_name = '[[column_name]]' + ) > 0, + 'ALTER TABLE [[norm_table_name]] DROP COLUMN [[column_name]];', + 'SELECT 1;' + )); + PREPARE dropColumnIfNeeded FROM @stmt; + EXECUTE dropColumnIfNeeded; + DEALLOCATE PREPARE dropColumnIfNeeded; + `, vars), nil + case model.PostgresDBType: + return fmt.Sprintf("\nALTER TABLE %s DROP COLUMN IF EXISTS %s;\n", normTableName, columnName), nil + default: + return "", ErrUnsupportedDatabaseType + } +} + +func (s *SQLStore) genCreateIndexIfNeeded(tableName, columns string) (string, error) { + indexName := getIndexName(tableName, columns) + tableName = addPrefixIfNeeded(tableName, s.tablePrefix) + normTableName := normalizeTablename(s.schemaName, tableName) + + switch s.dbType { + case model.SqliteDBType: + // No support for idempotent index creation in Sqlite. + return fmt.Sprintf("\nCREATE INDEX %s ON %s (%s);\n", indexName, normTableName, columns), nil + case model.MysqlDBType: + vars := map[string]string{ + "schema": s.schemaName, + "table_name": tableName, + "norm_table_name": normTableName, + "index_name": indexName, + "columns": columns, + } + return replaceVars(` + SET @stmt = (SELECT IF( + ( + SELECT COUNT(index_name) FROM INFORMATION_SCHEMA.STATISTICS + WHERE table_name = '[[table_name]]' + AND table_schema = '[[schema]]' + AND index_name = '[[index_name]]' + ) > 0, + 'SELECT 1;', + 'CREATE INDEX [[index_name]] ON [[norm_table_name]] ([[columns]]);' + )); + PREPARE createIndexIfNeeded FROM @stmt; + EXECUTE createIndexIfNeeded; + DEALLOCATE PREPARE createIndexIfNeeded; + `, vars), nil + case model.PostgresDBType: + return fmt.Sprintf("\nCREATE INDEX IF NOT EXISTS %s ON %s (%s);\n", indexName, normTableName, columns), nil + default: + return "", ErrUnsupportedDatabaseType + } +} + +func (s *SQLStore) genRenameTableIfNeeded(oldTableName, newTableName string) (string, error) { + oldTableName = addPrefixIfNeeded(oldTableName, s.tablePrefix) + newTableName = addPrefixIfNeeded(newTableName, s.tablePrefix) + + normOldTableName := normalizeTablename(s.schemaName, oldTableName) + + vars := map[string]string{ + "schema": s.schemaName, + "table_name": newTableName, + "norm_old_table_name": normOldTableName, + "new_table_name": newTableName, + } + + switch s.dbType { + case model.SqliteDBType: + // No support for idempotent table renaming in Sqlite. + return fmt.Sprintf("\nALTER TABLE %s RENAME TO %s;\n", normOldTableName, newTableName), nil + case model.MysqlDBType: + return replaceVars(` + SET @stmt = (SELECT IF( + ( + SELECT COUNT(table_name) FROM INFORMATION_SCHEMA.TABLES + WHERE table_name = '[[table_name]]' + AND table_schema = '[[schema]]' + ) > 0, + 'SELECT 1;', + 'RENAME TABLE [[norm_old_table_name]] TO [[new_table_name]];' + )); + PREPARE renameTableIfNeeded FROM @stmt; + EXECUTE renameTableIfNeeded; + DEALLOCATE PREPARE renameTableIfNeeded; + `, vars), nil + case model.PostgresDBType: + return replaceVars(` + do $$ + begin + if (SELECT COUNT(table_name) FROM INFORMATION_SCHEMA.TABLES + WHERE table_name = '[[new_table_name]]' + AND table_schema = '[[schema]]' + ) = 0 then + ALTER TABLE [[norm_old_table_name]] RENAME TO [[new_table_name]]; + end if; + end$$; + `, vars), nil + default: + return "", ErrUnsupportedDatabaseType + } +} + +func (s *SQLStore) genRenameColumnIfNeeded(tableName, oldColumnName, newColumnName, dataType string) (string, error) { + tableName = addPrefixIfNeeded(tableName, s.tablePrefix) + normTableName := normalizeTablename(s.schemaName, tableName) + + vars := map[string]string{ + "schema": s.schemaName, + "table_name": tableName, + "norm_table_name": normTableName, + "old_column_name": oldColumnName, + "new_column_name": newColumnName, + "data_type": dataType, + } + + switch s.dbType { + case model.SqliteDBType: + // No support for idempotent column renaming in Sqlite. + return fmt.Sprintf("\nALTER TABLE %s RENAME COLUMN %s TO %s;\n", normTableName, oldColumnName, newColumnName), nil + case model.MysqlDBType: + return replaceVars(` + SET @stmt = (SELECT IF( + ( + SELECT COUNT(column_name) FROM INFORMATION_SCHEMA.COLUMNS + WHERE table_name = '[[table_name]]' + AND table_schema = '[[schema]]' + AND column_name = '[[new_column_name]]' + ) > 0, + 'SELECT 1;', + 'ALTER TABLE [[norm_table_name]] CHANGE [[old_column_name]] [[new_column_name]] [[data_type]];' + )); + PREPARE renameColumnIfNeeded FROM @stmt; + EXECUTE renameColumnIfNeeded; + DEALLOCATE PREPARE renameColumnIfNeeded; + `, vars), nil + case model.PostgresDBType: + return replaceVars(` + do $$ + begin + if (SELECT COUNT(table_name) FROM INFORMATION_SCHEMA.COLUMNS + WHERE table_name = '[[table_name]]' + AND table_schema = '[[schema]]' + AND column_name = '[[new_column_name]]' + ) = 0 then + ALTER TABLE [[norm_table_name]] RENAME COLUMN [[old_column_name]] TO [[new_column_name]]; + end if; + end$$; + `, vars), nil + default: + return "", ErrUnsupportedDatabaseType + } +} + +func (s *SQLStore) doesTableExist(tableName string) (bool, error) { + tableName = addPrefixIfNeeded(tableName, s.tablePrefix) + var query sq.SelectBuilder + + switch s.dbType { + case model.MysqlDBType, model.PostgresDBType: + query = s.getQueryBuilder(s.db). + Select("table_name"). + From("INFORMATION_SCHEMA.TABLES"). + Where(sq.Eq{ + "table_name": tableName, + "table_schema": s.schemaName, + }) + case model.SqliteDBType: + query = s.getQueryBuilder(s.db). + Select("name"). + From("sqlite_master"). + Where(sq.Eq{ + "name": tableName, + "type": "table", + }) + default: + return false, ErrUnsupportedDatabaseType + } + + rows, err := query.Query() + if err != nil { + s.logger.Error(`doesTableExist ERROR`, mlog.Err(err)) + return false, err + } + defer s.CloseRows(rows) + + exists := rows.Next() + sql, _, _ := query.ToSql() + + s.logger.Trace("doesTableExist", + mlog.String("table", tableName), + mlog.Bool("exists", exists), + mlog.String("sql", sql), + ) + return exists, nil +} + +func (s *SQLStore) doesColumnExist(tableName, columnName string) (bool, error) { + tableName = addPrefixIfNeeded(tableName, s.tablePrefix) + var query sq.SelectBuilder + + switch s.dbType { + case model.MysqlDBType, model.PostgresDBType: + query = s.getQueryBuilder(s.db). + Select("table_name"). + From("INFORMATION_SCHEMA.COLUMNS"). + Where(sq.Eq{ + "table_name": tableName, + "table_schema": s.schemaName, + "column_name": columnName, + }) + case model.SqliteDBType: + query = s.getQueryBuilder(s.db). + Select("name"). + From(fmt.Sprintf("pragma_table_info('%s')", tableName)). + Where(sq.Eq{ + "name": columnName, + }) + default: + return false, ErrUnsupportedDatabaseType + } + + rows, err := query.Query() + if err != nil { + s.logger.Error(`doesColumnExist ERROR`, mlog.Err(err)) + return false, err + } + defer s.CloseRows(rows) + + exists := rows.Next() + sql, _, _ := query.ToSql() + + s.logger.Trace("doesColumnExist", + mlog.String("table", tableName), + mlog.String("column", columnName), + mlog.Bool("exists", exists), + mlog.String("sql", sql), + ) + return exists, nil +} + +func addPrefixIfNeeded(s, prefix string) string { + if !strings.HasPrefix(s, prefix) { + return prefix + s + } + return s +} + +func normalizeTablename(schemaName, tableName string) string { + if schemaName != "" && !strings.HasPrefix(tableName, schemaName+".") { + tableName = schemaName + "." + tableName + } + return tableName +} + +func getIndexName(tableName string, columns string) string { + var sb strings.Builder + + _, _ = sb.WriteString("idx_") + _, _ = sb.WriteString(tableName) + + // allow developers to separate column names with spaces and/or commas + columns = strings.ReplaceAll(columns, ",", " ") + cols := strings.Split(columns, " ") + + for _, s := range cols { + sub := strings.TrimSpace(s) + if sub == "" { + continue + } + + _, _ = sb.WriteString("_") + _, _ = sb.WriteString(s) + } + return sb.String() +} + +// replaceVars replaces instances of variable placeholders with the +// values provided via a map. Variable placeholders are of the form +// `[[var_name]]`. +func replaceVars(s string, vars map[string]string) string { + for key, val := range vars { + placeholder := "[[" + key + "]]" + val = strings.ReplaceAll(val, "'", "\\'") + s = strings.ReplaceAll(s, placeholder, val) + } + return s +} diff --git a/server/services/store/sqlstore/migrations/000003_blocks_rootid.up.sql b/server/services/store/sqlstore/migrations/000003_blocks_rootid.up.sql index 98ac52f8d..500ce1626 100644 --- a/server/services/store/sqlstore/migrations/000003_blocks_rootid.up.sql +++ b/server/services/store/sqlstore/migrations/000003_blocks_rootid.up.sql @@ -1,2 +1,2 @@ -ALTER TABLE {{.prefix}}blocks -ADD COLUMN root_id VARCHAR(36); +{{- /* addColumnIfNeeded tableName columnName datatype constraint */ -}} +{{ addColumnIfNeeded "blocks" "root_id" "varchar(36)" ""}} \ No newline at end of file diff --git a/server/services/store/sqlstore/migrations/000005_blocks_modifiedby.up.sql b/server/services/store/sqlstore/migrations/000005_blocks_modifiedby.up.sql index 6a532f1b0..411f7968d 100644 --- a/server/services/store/sqlstore/migrations/000005_blocks_modifiedby.up.sql +++ b/server/services/store/sqlstore/migrations/000005_blocks_modifiedby.up.sql @@ -1,2 +1,2 @@ -ALTER TABLE {{.prefix}}blocks -ADD COLUMN modified_by VARCHAR(36); +{{- /* addColumnIfNeeded tableName columnName datatype constraint */ -}} +{{ addColumnIfNeeded "blocks" "modified_by" "varchar(36)" ""}} \ No newline at end of file diff --git a/server/services/store/sqlstore/migrations/000008_teams.up.sql b/server/services/store/sqlstore/migrations/000008_teams.up.sql index dc46f7188..133f56bf1 100644 --- a/server/services/store/sqlstore/migrations/000008_teams.up.sql +++ b/server/services/store/sqlstore/migrations/000008_teams.up.sql @@ -1,10 +1,8 @@ -ALTER TABLE {{.prefix}}blocks -ADD COLUMN workspace_id VARCHAR(36); +{{- /* addColumnIfNeeded tableName columnName datatype constraint */ -}} +{{ addColumnIfNeeded "blocks" "workspace_id" "varchar(36)" ""}} -ALTER TABLE {{.prefix}}sharing -ADD COLUMN workspace_id VARCHAR(36); +{{ addColumnIfNeeded "sharing" "workspace_id" "varchar(36)" ""}} -ALTER TABLE {{.prefix}}sessions -ADD COLUMN auth_service VARCHAR(20); +{{ addColumnIfNeeded "sessions" "auth_service" "varchar(20)" ""}} UPDATE {{.prefix}}blocks SET workspace_id = '0' WHERE workspace_id = '' OR workspace_id IS NULL; diff --git a/server/services/store/sqlstore/migrations/000009_blocks_history.up.sql b/server/services/store/sqlstore/migrations/000009_blocks_history.up.sql index 7bbd4f2fb..e1a18babd 100644 --- a/server/services/store/sqlstore/migrations/000009_blocks_history.up.sql +++ b/server/services/store/sqlstore/migrations/000009_blocks_history.up.sql @@ -1,21 +1,32 @@ -ALTER TABLE {{.prefix}}blocks RENAME TO {{.prefix}}blocks_history; +{{- /* Only perform this migration if the blocks_history table does not already exist */ -}} + +{{- /* doesTableExist tableName */ -}} +{{if doesTableExist "blocks_history" }} + + SELECT 1; + +{{else}} + +{{- /* renameTableIfNeeded oldTableName newTableName */ -}} +{{ renameTableIfNeeded "blocks" "blocks_history" }} + CREATE TABLE IF NOT EXISTS {{.prefix}}blocks ( - id VARCHAR(36), - {{if .postgres}}insert_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),{{end}} - {{if .sqlite}}insert_at DATETIME NOT NULL DEFAULT(STRFTIME('%Y-%m-%d %H:%M:%f', 'NOW')),{{end}} - {{if .mysql}}insert_at DATETIME(6) NOT NULL DEFAULT NOW(6),{{end}} - parent_id VARCHAR(36), - {{if .mysql}}`schema`{{else}}schema{{end}} BIGINT, - type TEXT, - title TEXT, - fields {{if .postgres}}JSON{{else}}TEXT{{end}}, - create_at BIGINT, - update_at BIGINT, - delete_at BIGINT, - root_id VARCHAR(36), - modified_by VARCHAR(36), - workspace_id VARCHAR(36), - PRIMARY KEY (workspace_id,id) + id VARCHAR(36), + {{if .postgres}}insert_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),{{end}} + {{if .sqlite}}insert_at DATETIME NOT NULL DEFAULT(STRFTIME('%Y-%m-%d %H:%M:%f', 'NOW')),{{end}} + {{if .mysql}}insert_at DATETIME(6) NOT NULL DEFAULT NOW(6),{{end}} + parent_id VARCHAR(36), + {{if .mysql}}`schema`{{else}}schema{{end}} BIGINT, + type TEXT, + title TEXT, + fields {{if .postgres}}JSON{{else}}TEXT{{end}}, + create_at BIGINT, + update_at BIGINT, + delete_at BIGINT, + root_id VARCHAR(36), + modified_by VARCHAR(36), + workspace_id VARCHAR(36), + PRIMARY KEY (workspace_id,id) ) {{if .mysql}}DEFAULT CHARACTER SET utf8mb4{{end}}; {{if .mysql}} @@ -27,4 +38,8 @@ INSERT INTO {{.prefix}}blocks (SELECT * FROM {{.prefix}}blocks_history ORDER BY {{if .sqlite}} INSERT OR IGNORE INTO {{.prefix}}blocks SELECT * FROM {{.prefix}}blocks_history ORDER BY insert_at DESC; {{end}} + +{{end}} + DELETE FROM {{.prefix}}blocks where delete_at > 0; + diff --git a/server/services/store/sqlstore/migrations/000010_blocks_created_by.up.sql b/server/services/store/sqlstore/migrations/000010_blocks_created_by.up.sql index 7c8e59ade..ba5143127 100644 --- a/server/services/store/sqlstore/migrations/000010_blocks_created_by.up.sql +++ b/server/services/store/sqlstore/migrations/000010_blocks_created_by.up.sql @@ -1,4 +1,7 @@ -ALTER TABLE {{.prefix}}blocks ADD COLUMN created_by VARCHAR(36); -ALTER TABLE {{.prefix}}blocks_history ADD COLUMN created_by VARCHAR(36); +{{- /* addColumnIfNeeded tableName columnName datatype constraint) */ -}} +{{ addColumnIfNeeded "blocks" "created_by" "varchar(36)" ""}} +{{ addColumnIfNeeded "blocks_history" "created_by" "varchar(36)" ""}} -UPDATE {{.prefix}}blocks SET created_by = COALESCE(NULLIF((select modified_by from {{.prefix}}blocks_history where {{.prefix}}blocks_history.id = {{.prefix}}blocks.id ORDER BY {{.prefix}}blocks_history.insert_at ASC limit 1), ''), 'system'); +UPDATE {{.prefix}}blocks SET created_by = + COALESCE(NULLIF((select modified_by from {{.prefix}}blocks_history where {{.prefix}}blocks_history.id = {{.prefix}}blocks.id ORDER BY {{.prefix}}blocks_history.insert_at ASC limit 1), ''), 'system') +WHERE created_by IS NULL; diff --git a/server/services/store/sqlstore/migrations/000011_match_collation.up.sql b/server/services/store/sqlstore/migrations/000011_match_collation.up.sql index fd84d3f95..c593b6353 100644 --- a/server/services/store/sqlstore/migrations/000011_match_collation.up.sql +++ b/server/services/store/sqlstore/migrations/000011_match_collation.up.sql @@ -1,51 +1,7 @@ -{{if and .mysql .plugin}} - -- collation of mattermost's Channels table - SET @mattermostCollation = (SELECT table_collation from information_schema.tables WHERE table_name = 'Channels' AND table_schema = (SELECT DATABASE())); +{{- /* All tables have collation fixed via code at startup so this migration is no longer needed. */ -}} +{{- /* See https://github.com/mattermost/focalboard/pull/4002 */ -}} - -- blocks - SET @updateCollationQuery = CONCAT('ALTER TABLE {{.prefix}}blocks COLLATE ', @mattermostCollation); - PREPARE stmt FROM @updateCollationQuery; - EXECUTE stmt; - DEALLOCATE PREPARE stmt; +SELECT 1; - -- blocks history - SET @updateCollationQuery = CONCAT('ALTER TABLE {{.prefix}}blocks_history COLLATE ', @mattermostCollation); - PREPARE stmt FROM @updateCollationQuery; - EXECUTE stmt; - DEALLOCATE PREPARE stmt; - -- sessions - SET @updateCollationQuery = CONCAT('ALTER TABLE {{.prefix}}sessions COLLATE ', @mattermostCollation); - PREPARE stmt FROM @updateCollationQuery; - EXECUTE stmt; - DEALLOCATE PREPARE stmt; - -- sharing - SET @updateCollationQuery = CONCAT('ALTER TABLE {{.prefix}}sharing COLLATE ', @mattermostCollation); - PREPARE stmt FROM @updateCollationQuery; - EXECUTE stmt; - DEALLOCATE PREPARE stmt; - - -- system settings - SET @updateCollationQuery = CONCAT('ALTER TABLE {{.prefix}}system_settings COLLATE ', @mattermostCollation); - PREPARE stmt FROM @updateCollationQuery; - EXECUTE stmt; - DEALLOCATE PREPARE stmt; - - -- users - SET @updateCollationQuery = CONCAT('ALTER TABLE {{.prefix}}users COLLATE ', @mattermostCollation); - PREPARE stmt FROM @updateCollationQuery; - EXECUTE stmt; - DEALLOCATE PREPARE stmt; - - -- workspaces - SET @updateCollationQuery = CONCAT('ALTER TABLE {{.prefix}}workspaces COLLATE ', @mattermostCollation); - PREPARE stmt FROM @updateCollationQuery; - EXECUTE stmt; - DEALLOCATE PREPARE stmt; -{{else}} - -- We need a query here otherwise the migration will result - -- in an empty query when the if condition is false. - -- Empty query causes a "Query was empty" error. - SELECT 1; -{{end}} diff --git a/server/services/store/sqlstore/migrations/000018_add_teams_and_boards.up.sql b/server/services/store/sqlstore/migrations/000018_add_teams_and_boards.up.sql index 9f37b284c..ef57317ab 100644 --- a/server/services/store/sqlstore/migrations/000018_add_teams_and_boards.up.sql +++ b/server/services/store/sqlstore/migrations/000018_add_teams_and_boards.up.sql @@ -1,14 +1,17 @@ -{{if .mysql}} -RENAME TABLE {{.prefix}}workspaces TO {{.prefix}}teams; -ALTER TABLE {{.prefix}}blocks CHANGE workspace_id channel_id VARCHAR(36); -ALTER TABLE {{.prefix}}blocks_history CHANGE workspace_id channel_id VARCHAR(36); -{{else}} -ALTER TABLE {{.prefix}}workspaces RENAME TO {{.prefix}}teams; -ALTER TABLE {{.prefix}}blocks RENAME COLUMN workspace_id TO channel_id; -ALTER TABLE {{.prefix}}blocks_history RENAME COLUMN workspace_id TO channel_id; -{{end}} -ALTER TABLE {{.prefix}}blocks ADD COLUMN board_id VARCHAR(36); -ALTER TABLE {{.prefix}}blocks_history ADD COLUMN board_id VARCHAR(36); +{{- /* renameTableIfNeeded oldTableName newTableName string */ -}} +{{ renameTableIfNeeded "workspaces" "teams" }} + +{{- /* renameColumnIfNeeded tableName oldColumnName newColumnName dataType */ -}} +{{ renameColumnIfNeeded "blocks" "workspace_id" "channel_id" "varchar(36)" }} +{{ renameColumnIfNeeded "blocks_history" "workspace_id" "channel_id" "varchar(36)" }} + +{{- /* dropColumnIfNeeded tableName columnName */ -}} +{{ dropColumnIfNeeded "blocks" "workspace_id" }} +{{ dropColumnIfNeeded "blocks_history" "workspace_id" }} + +{{- /* addColumnIfNeeded tableName columnName datatype constraint */ -}} +{{ addColumnIfNeeded "blocks" "board_id" "varchar(36)" ""}} +{{ addColumnIfNeeded "blocks_history" "board_id" "varchar(36)" ""}} {{- /* cleanup incorrect data format in column calculations */ -}} {{- /* then move from 'board' type to 'view' type*/ -}} @@ -24,6 +27,7 @@ UPDATE {{.prefix}}blocks b WHERE JSON_EXTRACT(b.fields, '$.viewType') = 'table' AND b.type = 'view'; {{end}} + {{if .postgres}} UPDATE {{.prefix}}blocks SET fields = fields::jsonb - 'columnCalculations' || '{"columnCalculations": {}}' WHERE fields->>'columnCalculations' = '[]'; @@ -37,6 +41,7 @@ UPDATE {{.prefix}}blocks b AND b.fields ->> 'viewType' = 'table' AND b.type = 'view'; {{end}} + {{if .sqlite}} UPDATE {{.prefix}}blocks SET fields = replace(fields, '"columnCalculations":[]', '"columnCalculations":{}'); @@ -49,7 +54,8 @@ UPDATE {{.prefix}}blocks AS b AND b.type = 'view'; {{end}} -/* TODO: Migrate the columnCalculations at app level and remove it from the boards and boards_history tables */ +{{- /* TODO: Migrate the columnCalculations at app level and remove it from the boards and boards_history tables */ -}} + {{- /* add boards tables */ -}} CREATE TABLE IF NOT EXISTS {{.prefix}}boards ( @@ -87,8 +93,9 @@ CREATE TABLE IF NOT EXISTS {{.prefix}}boards ( delete_at BIGINT ) {{if .mysql}}DEFAULT CHARACTER SET utf8mb4{{end}}; -CREATE INDEX idx_board_team_id ON {{.prefix}}boards(team_id, is_template); -CREATE INDEX idx_board_channel_id ON {{.prefix}}boards(channel_id); +{{- /* createIndexIfNeeded tableName columns */ -}} +{{ createIndexIfNeeded "boards" "team_id, is_template" }} +{{ createIndexIfNeeded "boards" "channel_id" }} CREATE TABLE IF NOT EXISTS {{.prefix}}boards_history ( id VARCHAR(36) NOT NULL, @@ -140,7 +147,7 @@ CREATE TABLE IF NOT EXISTS {{.prefix}}boards_history ( COALESCE((fields->'isTemplate')::text::boolean, false), COALESCE((B.fields->'templateVer')::text::int, 0), '{}', B.fields->'cardProperties', B.create_at, - B.update_at, B.delete_at + B.update_at, B.delete_at {{if doesColumnExist "boards" "minimum_role"}} ,'' {{end}} FROM {{.prefix}}blocks AS B INNER JOIN channels AS C ON C.Id=B.channel_id WHERE B.type='board' @@ -154,7 +161,7 @@ CREATE TABLE IF NOT EXISTS {{.prefix}}boards_history ( COALESCE((fields->'isTemplate')::text::boolean, false), COALESCE((B.fields->'templateVer')::text::int, 0), '{}', B.fields->'cardProperties', B.create_at, - B.update_at, B.delete_at + B.update_at, B.delete_at {{if doesColumnExist "boards_history" "minimum_role"}} ,'' {{end}} FROM {{.prefix}}blocks_history AS B INNER JOIN channels AS C ON C.Id=B.channel_id WHERE B.type='board' @@ -170,7 +177,7 @@ CREATE TABLE IF NOT EXISTS {{.prefix}}boards_history ( COALESCE(JSON_EXTRACT(B.fields, '$.isTemplate'), 'false') = 'true', COALESCE(JSON_EXTRACT(B.fields, '$.templateVer'), 0), '{}', JSON_EXTRACT(B.fields, '$.cardProperties'), B.create_at, - B.update_at, B.delete_at + B.update_at, B.delete_at {{if doesColumnExist "boards" "minimum_role"}} ,'' {{end}} FROM {{.prefix}}blocks AS B INNER JOIN Channels AS C ON C.Id=B.channel_id WHERE B.type='board' @@ -184,7 +191,7 @@ CREATE TABLE IF NOT EXISTS {{.prefix}}boards_history ( COALESCE(JSON_EXTRACT(B.fields, '$.isTemplate'), 'false') = 'true', COALESCE(JSON_EXTRACT(B.fields, '$.templateVer'), 0), '{}', JSON_EXTRACT(B.fields, '$.cardProperties'), B.create_at, - B.update_at, B.delete_at + B.update_at, B.delete_at {{if doesColumnExist "boards_history" "minimum_role"}} ,'' {{end}} FROM {{.prefix}}blocks_history AS B INNER JOIN Channels AS C ON C.Id=B.channel_id WHERE B.type='board' @@ -201,7 +208,7 @@ CREATE TABLE IF NOT EXISTS {{.prefix}}boards_history ( COALESCE((fields->'isTemplate')::text::boolean, false), COALESCE((B.fields->'templateVer')::text::int, 0), '{}', fields->'cardProperties', create_at, - update_at, delete_at + update_at, delete_at {{if doesColumnExist "boards" "minimum_role"}} ,'editor' {{end}} FROM {{.prefix}}blocks AS B WHERE type='board' ); @@ -214,11 +221,12 @@ CREATE TABLE IF NOT EXISTS {{.prefix}}boards_history ( COALESCE((fields->'isTemplate')::text::boolean, false), COALESCE((B.fields->'templateVer')::text::int, 0), '{}', fields->'cardProperties', create_at, - update_at, delete_at + update_at, delete_at {{if doesColumnExist "boards_history" "minimum_role"}} ,'editor' {{end}} FROM {{.prefix}}blocks_history AS B WHERE type='board' ); {{end}} + {{if .mysql}} INSERT INTO {{.prefix}}boards ( SELECT id, insert_at, '0', channel_id, created_by, modified_by, 'O', @@ -229,7 +237,7 @@ CREATE TABLE IF NOT EXISTS {{.prefix}}boards_history ( COALESCE(JSON_EXTRACT(B.fields, '$.isTemplate'), 'false') = 'true', COALESCE(JSON_EXTRACT(B.fields, '$.templateVer'), 0), '{}', JSON_EXTRACT(fields, '$.cardProperties'), create_at, - update_at, delete_at + update_at, delete_at {{if doesColumnExist "boards" "minimum_role"}} ,'editor' {{end}} FROM {{.prefix}}blocks AS B WHERE type='board' ); @@ -242,11 +250,12 @@ CREATE TABLE IF NOT EXISTS {{.prefix}}boards_history ( COALESCE(JSON_EXTRACT(B.fields, '$.isTemplate'), 'false') = 'true', COALESCE(JSON_EXTRACT(B.fields, '$.templateVer'), 0), '{}', JSON_EXTRACT(fields, '$.cardProperties'), create_at, - update_at, delete_at + update_at, delete_at {{if doesColumnExist "boards_history" "minimum_role"}} ,'editor' {{end}} FROM {{.prefix}}blocks_history AS B WHERE type='board' ); {{end}} + {{if .sqlite}} INSERT INTO {{.prefix}}boards SELECT id, insert_at, '0', channel_id, created_by, modified_by, 'O', @@ -255,7 +264,7 @@ CREATE TABLE IF NOT EXISTS {{.prefix}}boards_history ( json_extract(fields, '$.icon'), json_extract(fields, '$.showDescription'), json_extract(fields, '$.isTemplate'), COALESCE(json_extract(fields, '$.templateVer'), 0), '{}', json_extract(fields, '$.cardProperties'), create_at, - update_at, delete_at + update_at, delete_at {{if doesColumnExist "boards" "minimum_role"}} ,'editor' {{end}} FROM {{.prefix}}blocks WHERE type='board' ; @@ -266,7 +275,7 @@ CREATE TABLE IF NOT EXISTS {{.prefix}}boards_history ( json_extract(fields, '$.icon'), json_extract(fields, '$.showDescription'), json_extract(fields, '$.isTemplate'), COALESCE(json_extract(fields, '$.templateVer'), 0), '{}', json_extract(fields, '$.cardProperties'), create_at, - update_at, delete_at + update_at, delete_at {{if doesColumnExist "boards_history" "minimum_role"}} ,'editor' {{end}} FROM {{.prefix}}blocks_history WHERE type='board' ; @@ -275,14 +284,15 @@ CREATE TABLE IF NOT EXISTS {{.prefix}}boards_history ( {{- /* Update block references to boards*/ -}} -UPDATE {{.prefix}}blocks SET board_id=root_id; -UPDATE {{.prefix}}blocks_history SET board_id=root_id; +UPDATE {{.prefix}}blocks SET board_id=root_id WHERE board_id IS NULL OR board_id=''; +UPDATE {{.prefix}}blocks_history SET board_id=root_id WHERE board_id IS NULL OR board_id=''; {{- /* Remove boards, including templates */ -}} DELETE FROM {{.prefix}}blocks WHERE type = 'board'; DELETE FROM {{.prefix}}blocks_history WHERE type = 'board'; -{{- /* add board_members */ -}} +{{- /* add board_members (only if boards_members doesn't already exist) */ -}} +{{if not (doesTableExist "board_members") }} CREATE TABLE IF NOT EXISTS {{.prefix}}board_members ( board_id VARCHAR(36) NOT NULL, user_id VARCHAR(36) NOT NULL, @@ -294,8 +304,6 @@ CREATE TABLE IF NOT EXISTS {{.prefix}}board_members ( PRIMARY KEY (board_id, user_id) ) {{if .mysql}}DEFAULT CHARACTER SET utf8mb4{{end}}; -CREATE INDEX idx_boardmembers_user_id ON {{.prefix}}board_members(user_id); - {{- /* if we're in plugin, migrate channel memberships to the board */ -}} {{if .plugin}} INSERT INTO {{.prefix}}board_members ( @@ -321,3 +329,7 @@ INSERT INTO {{.prefix}}board_members SELECT B.id, 'single-user', '', TRUE, TRUE, FALSE, FALSE FROM {{.prefix}}boards AS B; {{end}} +{{end}} + +{{- /* createIndexIfNeeded tableName columns */ -}} +{{ createIndexIfNeeded "board_members" "user_id" }} diff --git a/server/services/store/sqlstore/migrations/000019_populate_categories.up.sql b/server/services/store/sqlstore/migrations/000019_populate_categories.up.sql index d551eeb39..6b59957c6 100644 --- a/server/services/store/sqlstore/migrations/000019_populate_categories.up.sql +++ b/server/services/store/sqlstore/migrations/000019_populate_categories.up.sql @@ -10,4 +10,6 @@ CREATE TABLE IF NOT EXISTS {{.prefix}}categories ( PRIMARY KEY (id) ) {{if .mysql}}DEFAULT CHARACTER SET utf8mb4{{end}}; -CREATE INDEX idx_categories_user_id_team_id ON {{.prefix}}categories(user_id, team_id); +{{- /* createIndexIfNeeded tableName columns */ -}} +{{ createIndexIfNeeded "categories" "user_id, team_id" }} + diff --git a/server/services/store/sqlstore/migrations/000020_populate_category_blocks.up.sql b/server/services/store/sqlstore/migrations/000020_populate_category_blocks.up.sql index c5dd300c7..39a0d4cdc 100644 --- a/server/services/store/sqlstore/migrations/000020_populate_category_blocks.up.sql +++ b/server/services/store/sqlstore/migrations/000020_populate_category_blocks.up.sql @@ -9,4 +9,5 @@ CREATE TABLE IF NOT EXISTS {{.prefix}}category_boards ( PRIMARY KEY (id) ) {{if .mysql}}DEFAULT CHARACTER SET utf8mb4{{end}}; -CREATE INDEX idx_categoryboards_category_id ON {{.prefix}}category_boards(category_id); +{{- /* createIndexIfNeeded tableName columns */ -}} +{{ createIndexIfNeeded "category_boards" "category_id" }} diff --git a/server/services/store/sqlstore/migrations/000021_create_boards_members_history.up.sql b/server/services/store/sqlstore/migrations/000021_create_boards_members_history.up.sql index 7bc327568..b2a2b819e 100644 --- a/server/services/store/sqlstore/migrations/000021_create_boards_members_history.up.sql +++ b/server/services/store/sqlstore/migrations/000021_create_boards_members_history.up.sql @@ -1,3 +1,10 @@ +{{- /* Only perform this migration if the board_members_history table does not already exist */ -}} +{{if doesTableExist "board_members_history" }} + +SELECT 1; + +{{else}} + CREATE TABLE IF NOT EXISTS {{.prefix}}board_members_history ( board_id VARCHAR(36) NOT NULL, user_id VARCHAR(36) NOT NULL, @@ -8,7 +15,10 @@ CREATE TABLE IF NOT EXISTS {{.prefix}}board_members_history ( PRIMARY KEY (board_id, user_id, insert_at) ) {{if .mysql}}DEFAULT CHARACTER SET utf8mb4{{end}}; -CREATE INDEX idx_boardmembershistory_user_id ON {{.prefix}}board_members_history(user_id); -CREATE INDEX idx_boardmembershistory_board_id_user_id ON {{.prefix}}board_members_history(board_id, user_id); - INSERT INTO {{.prefix}}board_members_history (board_id, user_id, action) SELECT board_id, user_id, 'created' from {{.prefix}}board_members; + +{{end}} + +{{- /* createIndexIfNeeded tableName columns */ -}} +{{ createIndexIfNeeded "board_members_history" "user_id" }} +{{ createIndexIfNeeded "board_members_history" "board_id, user_id" }} diff --git a/server/services/store/sqlstore/migrations/000022_create_default_board_role.up.sql b/server/services/store/sqlstore/migrations/000022_create_default_board_role.up.sql index 55526109a..f91f0c2e3 100644 --- a/server/services/store/sqlstore/migrations/000022_create_default_board_role.up.sql +++ b/server/services/store/sqlstore/migrations/000022_create_default_board_role.up.sql @@ -1,4 +1,6 @@ -ALTER TABLE {{.prefix}}boards ADD COLUMN minimum_role VARCHAR(36) NOT NULL DEFAULT ''; -ALTER TABLE {{.prefix}}boards_history ADD COLUMN minimum_role VARCHAR(36) NOT NULL DEFAULT ''; -UPDATE {{.prefix}}boards SET minimum_role = 'editor'; -UPDATE {{.prefix}}boards_history SET minimum_role = 'editor'; +{{- /* addColumnIfNeeded tableName columnName datatype constraint */ -}} +{{ addColumnIfNeeded "boards" "minimum_role" "varchar(36)" "NOT NULL DEFAULT ''"}} +{{ addColumnIfNeeded "boards_history" "minimum_role" "varchar(36)" "NOT NULL DEFAULT ''"}} + +UPDATE {{.prefix}}boards SET minimum_role = 'editor' WHERE minimum_role IS NULL OR minimum_role=''; +UPDATE {{.prefix}}boards_history SET minimum_role = 'editor' WHERE minimum_role IS NULL OR minimum_role=''; diff --git a/server/services/store/sqlstore/migrations/000023_persist_category_collapsed_state.up.sql b/server/services/store/sqlstore/migrations/000023_persist_category_collapsed_state.up.sql index 2fd8eefb0..a85da0e5b 100644 --- a/server/services/store/sqlstore/migrations/000023_persist_category_collapsed_state.up.sql +++ b/server/services/store/sqlstore/migrations/000023_persist_category_collapsed_state.up.sql @@ -1 +1,2 @@ -ALTER TABLE {{.prefix}}categories ADD collapsed boolean default false; +{{- /* addColumnIfNeeded tableName columnName datatype constraint */ -}} +{{ addColumnIfNeeded "categories" "collapsed" "boolean" "default false"}} diff --git a/server/services/store/sqlstore/migrations/000024_mark_existsing_categories_collapsed.down.sql b/server/services/store/sqlstore/migrations/000024_mark_existing_categories_collapsed.down.sql similarity index 100% rename from server/services/store/sqlstore/migrations/000024_mark_existsing_categories_collapsed.down.sql rename to server/services/store/sqlstore/migrations/000024_mark_existing_categories_collapsed.down.sql diff --git a/server/services/store/sqlstore/migrations/000024_mark_existsing_categories_collapsed.up.sql b/server/services/store/sqlstore/migrations/000024_mark_existing_categories_collapsed.up.sql similarity index 100% rename from server/services/store/sqlstore/migrations/000024_mark_existsing_categories_collapsed.up.sql rename to server/services/store/sqlstore/migrations/000024_mark_existing_categories_collapsed.up.sql diff --git a/server/services/store/sqlstore/migrations/000025_indexes_update.up.sql b/server/services/store/sqlstore/migrations/000025_indexes_update.up.sql index d58b4a144..1dd031c97 100644 --- a/server/services/store/sqlstore/migrations/000025_indexes_update.up.sql +++ b/server/services/store/sqlstore/migrations/000025_indexes_update.up.sql @@ -13,7 +13,7 @@ ALTER TABLE {{.prefix}}blocks ADD PRIMARY KEY (id); {{if .sqlite}} ALTER TABLE {{.prefix}}blocks RENAME TO {{.prefix}}blocks_tmp; -CREATE TABLE {{.prefix}}blocks ( +CREATE TABLE IF NOT EXISTS {{.prefix}}blocks ( id VARCHAR(36), insert_at DATETIME NOT NULL DEFAULT(STRFTIME('%Y-%m-%d %H:%M:%f', 'NOW')), parent_id VARCHAR(36), @@ -38,7 +38,7 @@ DROP TABLE {{.prefix}}blocks_tmp; {{end}} {{- /* most block searches use board_id or a combination of board and parent ids */ -}} -CREATE INDEX idx_blocks_board_id_parent_id ON {{.prefix}}blocks (board_id, parent_id); +{{ createIndexIfNeeded "blocks" "board_id, parent_id" }} {{- /* get subscriptions is used once per board page load */ -}} -CREATE INDEX idx_subscriptions_subscriber_id ON {{.prefix}}subscriptions (subscriber_id); +{{ createIndexIfNeeded "subscriptions" "subscriber_id" }} \ No newline at end of file diff --git a/server/services/store/sqlstore/migrations/000026_create_preferences_table.up.sql b/server/services/store/sqlstore/migrations/000026_create_preferences_table.up.sql index 6340835eb..43e694c5b 100644 --- a/server/services/store/sqlstore/migrations/000026_create_preferences_table.up.sql +++ b/server/services/store/sqlstore/migrations/000026_create_preferences_table.up.sql @@ -1,4 +1,4 @@ -CREATE TABLE {{.prefix}}preferences +CREATE TABLE IF NOT EXISTS {{.prefix}}preferences ( userid VARCHAR(36) NOT NULL, category VARCHAR(32) NOT NULL, @@ -7,8 +7,6 @@ CREATE TABLE {{.prefix}}preferences PRIMARY KEY (userid, category, name) ) {{if .mysql}}DEFAULT CHARACTER SET utf8mb4{{end}}; -CREATE index idx_{{.prefix}}preferences_category - ON {{.prefix}}preferences (category); - -CREATE index idx_{{.prefix}}preferences_name - ON {{.prefix}}preferences (name); +{{- /* createIndexIfNeeded tableName columns */ -}} +{{ createIndexIfNeeded "preferences" "category" }} +{{ createIndexIfNeeded "preferences" "name" }} diff --git a/server/services/store/sqlstore/migrations/000027_migrate_user_props_to_preferences.up.sql b/server/services/store/sqlstore/migrations/000027_migrate_user_props_to_preferences.up.sql index e95abe47a..d9be852c4 100644 --- a/server/services/store/sqlstore/migrations/000027_migrate_user_props_to_preferences.up.sql +++ b/server/services/store/sqlstore/migrations/000027_migrate_user_props_to_preferences.up.sql @@ -48,7 +48,7 @@ INSERT INTO {{.prefix}}preferences (UserId, Category, Name, Value) SELECT Id, 'focalboard', 'version72MessageCanceled', replace((Props->'focalboard_version72MessageCanceled')::varchar, '"', '') from {{.prefix}}users WHERE Props->'focalboard_version72MessageCanceled' IS NOT NULL ON CONFLICT DO NOTHING; INSERT INTO {{.prefix}}preferences (UserId, Category, Name, Value) SELECT Id, 'focalboard', 'lastWelcomeVersion', replace((Props->'focalboard_lastWelcomeVersion')::varchar, '"', '') from {{.prefix}}users WHERE Props->'focalboard_lastWelcomeVersion' IS NOT NULL ON CONFLICT DO NOTHING; -UPDATE {{.prefix}}users SET props = (props::jsonb - 'focalboard_welcomePageViewed' - 'hiddenBoardIDs' - 'focalboard_tourCategory' - 'focalboard_onboardingTourStep' - 'focalboard_onboardingTourStarted' - 'focalboard_version72MessageCanceled' - 'focalboard_lastWelcomeVersion')::json WHERE jsonb_typeof(props::jsonb) = 'object'; + UPDATE {{.prefix}}users SET props = (props::jsonb - 'focalboard_welcomePageViewed' - 'hiddenBoardIDs' - 'focalboard_tourCategory' - 'focalboard_onboardingTourStep' - 'focalboard_onboardingTourStarted' - 'focalboard_version72MessageCanceled' - 'focalboard_lastWelcomeVersion')::json WHERE jsonb_typeof(props::jsonb) = 'object'; {{end}} {{if .mysql}} diff --git a/server/services/store/sqlstore/migrations/000029_add_category_type_field.up.sql b/server/services/store/sqlstore/migrations/000029_add_category_type_field.up.sql index 676ceea01..36471b36f 100644 --- a/server/services/store/sqlstore/migrations/000029_add_category_type_field.up.sql +++ b/server/services/store/sqlstore/migrations/000029_add_category_type_field.up.sql @@ -1,2 +1,4 @@ -ALTER TABLE {{.prefix}}categories ADD COLUMN type varchar(64); +{{- /* addColumnIfNeeded tableName columnName datatype constraint */ -}} +{{ addColumnIfNeeded "categories" "type" "varchar(64)" ""}} + UPDATE {{.prefix}}categories SET type = 'custom' WHERE type IS NULL; diff --git a/server/services/store/sqlstore/migrations/000030_add_category_sort_order.up.sql b/server/services/store/sqlstore/migrations/000030_add_category_sort_order.up.sql index f8a1bf0cd..c5be380d7 100644 --- a/server/services/store/sqlstore/migrations/000030_add_category_sort_order.up.sql +++ b/server/services/store/sqlstore/migrations/000030_add_category_sort_order.up.sql @@ -1 +1,2 @@ -ALTER TABLE {{.prefix}}categories ADD COLUMN sort_order BIGINT DEFAULT 0; +{{- /* addColumnIfNeeded tableName columnName datatype constraint */ -}} +{{ addColumnIfNeeded "categories" "sort_order" "BIGINT" "DEFAULT 0"}} diff --git a/server/services/store/sqlstore/migrations/000031_add_category_boards_sort_order.up.sql b/server/services/store/sqlstore/migrations/000031_add_category_boards_sort_order.up.sql index fc023e724..fb42d35e3 100644 --- a/server/services/store/sqlstore/migrations/000031_add_category_boards_sort_order.up.sql +++ b/server/services/store/sqlstore/migrations/000031_add_category_boards_sort_order.up.sql @@ -1 +1,3 @@ -ALTER TABLE {{.prefix}}category_boards ADD COLUMN sort_order BIGINT DEFAULT 0; +{{- /* addColumnIfNeeded tableName columnName datatype constraint */ -}} +{{ addColumnIfNeeded "category_boards" "sort_order" "BIGINT" "DEFAULT 0"}} + diff --git a/server/services/store/sqlstore/migrations/000032_move_boards_category_to_end.up.sql b/server/services/store/sqlstore/migrations/000032_move_boards_category_to_end.up.sql index 5b333a09e..76a62a3a6 100644 --- a/server/services/store/sqlstore/migrations/000032_move_boards_category_to_end.up.sql +++ b/server/services/store/sqlstore/migrations/000032_move_boards_category_to_end.up.sql @@ -9,7 +9,7 @@ UPDATE {{.prefix}}categories SET sort_order = (10 * (SELECT COUNT(*) FROM {{.pre {{if .mysql}} {{- /* MySQL doesn't allow referencing the same table in subquery and update query like Postgres, */ -}} {{- /* So we save the subquery result in a variable to use later. */ -}} -SET @focalboad_numCategories = (SELECT COUNT(*) FROM {{.prefix}}categories); -UPDATE {{.prefix}}categories SET sort_order = (10 * @focalboad_numCategories) WHERE lower(name) = 'boards'; -SET @focalboad_numCategories = NULL; +SET @focalboard_numCategories = (SELECT COUNT(*) FROM {{.prefix}}categories); +UPDATE {{.prefix}}categories SET sort_order = (10 * @focalboard_numCategories) WHERE lower(name) = 'boards'; +SET @focalboard_numCategories = NULL; {{end}} \ No newline at end of file diff --git a/server/services/store/sqlstore/migrations/README.md b/server/services/store/sqlstore/migrations/README.md new file mode 100644 index 000000000..78e6d7982 --- /dev/null +++ b/server/services/store/sqlstore/migrations/README.md @@ -0,0 +1,68 @@ +# Migration Scripts + +These scripts are executed against the current database on server start-up. Any scripts previously executed are skipped, however these scripts are designed to be idempotent for Postgres and MySQL. To correct common problems with schema and data migrations the `focalboard_schema_migrations` table can be cleared of all records and the server restarted. + +The following built-in variables are available: + +| Name | Syntax | Description | +| ----- | ----- | ----- | +| schemaName | {{ .schemaName }} | Returns the database/schema name (e.g. `mattermost_`, `mattermost_test`, `public`, ...) | +| prefix | {{ .prefix }} | Returns the table name prefix (e.g. `focalbaord_`) | +| postgres | {{if .postgres }} ... {{end}} | Returns true if the current database is Postgres. | +| sqlite | {{if .sqlite }} ... {{end}} | Returns true if the current database is Sqlite3. | +| mysql | {{if .mysql }} ... {{end}} | Returns true if the current database is MySQL. | +| plugin | {{if .plugin }} ... {{end}} | Returns true if the server is currently running as a plugin (or product). In others words this is true if the server is not running as stand-alone or personal server. | +| singleUser | {{if .singleUser }} ... {{end}} | Returns true if the server is currently running in single user mode. | + +To help with creating scripts that are idempotent some template functions have been added to the migration engine. + +| Name | Syntax | Description | +| ----- | ----- | ----- | +| addColumnIfNeeded | {{ addColumnIfNeeded schemaName tableName columnName datatype constraint }} | Adds column to table only if column doesn't already exist. | +| dropColumnIfNeeded | {{ dropColumnIfNeeded schemaName tableName columnName }} | Drops column from table if the column exists. | +| createIndexIfNeeded | {{ createIndexIfNeeded schemaName tableName columns }} | Creates an index if it does not already exist. The index name follows the existing convention of using `idx_` plus the table name and all columns separated by underscores. | +| renameTableIfNeeded | {{ renameTableIfNeeded schemaName oldTableName newTableName }} | Renames the table if the new table name does not exist. | +| renameColumnIfNeeded | {{ renameColumnIfNeeded schemaName tableName oldVolumnName newColumnName datatype }} | Renames a column if the new column name does not exist. | +| doesTableExist | {{if doesTableExist schemaName tableName }} ... {{end}} | Returns true if the table exists. Typically used in a `if` statement to conditionally include a section of script. Currently the existence of the table is determined before any scripts are executed (limitation of Morph). | +| doesColumnExist | {{if doesTableExist schemaName tableName columnName }} ... {{end}} | Returns true if the column exists. Typically used in a `if` statement to conditionally include a section of script. Currently the existence of the column is determined before any scripts are executed (limitation of Morph). | + +**Note, table names should not include table prefix or schema name.** + +## Examples + +```bash +{{ addColumnIfNeeded .schemaName "categories" "type" "varchar(64)" ""}} +{{ addColumnIfNeeded .schemaName "boards_history" "minimum_role" "varchar(36)" "NOT NULL DEFAULT ''"}} +``` + +```bash +{{ dropColumnIfNeeded .schemaName "blocks_history" "workspace_id" }} +``` + +```bash +{{ createIndexIfNeeded .schemaName "boards" "team_id, is_template" }} +``` + +```bash +{{ renameTableIfNeeded .schemaName "blocks" "blocks_history" }} +``` + +```bash +{{ renameColumnIfNeeded .schemaName "blocks_history" "workspace_id" "channel_id" "varchar(36)" }} +``` + +```bash +{{if doesTableExist .schemaName "blocks_history" }} + SELECT 'table exists'; +{{end}} + +{{if not (doesTableExist .schemaName "blocks_history") }} + SELECT 1; +{{end}} +``` + +```bash +{{if doesColumnExist .schemaName "boards_history" "minimum_role"}} + UPDATE ... + {{end}} +``` diff --git a/server/services/store/sqlstore/migrationstests/boards_migrator_test.go b/server/services/store/sqlstore/migrationstests/boards_migrator_test.go index bb76ce91a..9ec8ea3b2 100644 --- a/server/services/store/sqlstore/migrationstests/boards_migrator_test.go +++ b/server/services/store/sqlstore/migrationstests/boards_migrator_test.go @@ -139,7 +139,7 @@ func (bm *BoardsMigrator) getMorphConnection() (*morph.Morph, drivers.Driver, er return nil, mErr } - tmpl, pErr := template.New("sql").Parse(string(asset)) + tmpl, pErr := template.New("sql").Funcs(bm.store.GetTemplateHelperFuncs()).Parse(string(asset)) if pErr != nil { return nil, pErr } diff --git a/server/services/store/sqlstore/sqlstore.go b/server/services/store/sqlstore/sqlstore.go index 35bb37c84..057e737fe 100644 --- a/server/services/store/sqlstore/sqlstore.go +++ b/server/services/store/sqlstore/sqlstore.go @@ -28,6 +28,7 @@ type SQLStore struct { NewMutexFn MutexFactory servicesAPI servicesAPI isBinaryParam bool + schemaName string } // MutexFactory is used by the store in plugin mode to generate @@ -61,6 +62,12 @@ func New(params Params) (*SQLStore, error) { return nil, err } + store.schemaName, err = store.GetSchemaName() + if err != nil { + params.Logger.Error(`Cannot get schema name`, mlog.Err(err)) + return nil, err + } + if !params.SkipMigrations { if mErr := store.Migrate(); mErr != nil { params.Logger.Error(`Table creation / migration failed`, mlog.Err(mErr)) diff --git a/server/services/store/sqlstore/util.go b/server/services/store/sqlstore/util.go index 49fa72897..8f4bde5ed 100644 --- a/server/services/store/sqlstore/util.go +++ b/server/services/store/sqlstore/util.go @@ -138,3 +138,28 @@ func (s *SQLStore) castInt(val int64, as string) string { } return fmt.Sprintf("cast(%d as bigint) AS %s", val, as) } + +func (s *SQLStore) GetSchemaName() (string, error) { + var query sq.SelectBuilder + + switch s.dbType { + case model.MysqlDBType: + query = s.getQueryBuilder(s.db).Select("DATABASE()") + case model.PostgresDBType: + query = s.getQueryBuilder(s.db).Select("current_schema()") + case model.SqliteDBType: + return "", nil + default: + return "", ErrUnsupportedDatabaseType + } + + scanner := query.QueryRow() + + var result string + err := scanner.Scan(&result) + if err != nil && !model.IsErrNotFound(err) { + return "", err + } + + return result, nil +} diff --git a/server/ws/mocks/mockpluginapi.go b/server/ws/mocks/mockpluginapi.go index 1a2c131e1..c9ad2518e 100644 --- a/server/ws/mocks/mockpluginapi.go +++ b/server/ws/mocks/mockpluginapi.go @@ -261,6 +261,21 @@ func (mr *MockAPIMockRecorder) CreateTeamMembersGracefully(arg0, arg1, arg2 inte return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "CreateTeamMembersGracefully", reflect.TypeOf((*MockAPI)(nil).CreateTeamMembersGracefully), arg0, arg1, arg2) } +// CreateUploadSession mocks base method. +func (m *MockAPI) CreateUploadSession(arg0 *model.UploadSession) (*model.UploadSession, error) { + m.ctrl.T.Helper() + ret := m.ctrl.Call(m, "CreateUploadSession", arg0) + ret0, _ := ret[0].(*model.UploadSession) + ret1, _ := ret[1].(error) + return ret0, ret1 +} + +// CreateUploadSession indicates an expected call of CreateUploadSession. +func (mr *MockAPIMockRecorder) CreateUploadSession(arg0 interface{}) *gomock.Call { + mr.mock.ctrl.T.Helper() + return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "CreateUploadSession", reflect.TypeOf((*MockAPI)(nil).CreateUploadSession), arg0) +} + // CreateUser mocks base method. func (m *MockAPI) CreateUser(arg0 *model.User) (*model.User, *model.AppError) { m.ctrl.T.Helper() @@ -1440,6 +1455,21 @@ func (mr *MockAPIMockRecorder) GetUnsanitizedConfig() *gomock.Call { return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "GetUnsanitizedConfig", reflect.TypeOf((*MockAPI)(nil).GetUnsanitizedConfig)) } +// GetUploadSession mocks base method. +func (m *MockAPI) GetUploadSession(arg0 string) (*model.UploadSession, error) { + m.ctrl.T.Helper() + ret := m.ctrl.Call(m, "GetUploadSession", arg0) + ret0, _ := ret[0].(*model.UploadSession) + ret1, _ := ret[1].(error) + return ret0, ret1 +} + +// GetUploadSession indicates an expected call of GetUploadSession. +func (mr *MockAPIMockRecorder) GetUploadSession(arg0 interface{}) *gomock.Call { + mr.mock.ctrl.T.Helper() + return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "GetUploadSession", reflect.TypeOf((*MockAPI)(nil).GetUploadSession), arg0) +} + // GetUser mocks base method. func (m *MockAPI) GetUser(arg0 string) (*model.User, *model.AppError) { m.ctrl.T.Helper() @@ -2031,6 +2061,20 @@ func (mr *MockAPIMockRecorder) ReadFile(arg0 interface{}) *gomock.Call { return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "ReadFile", reflect.TypeOf((*MockAPI)(nil).ReadFile), arg0) } +// RegisterCollectionAndTopic mocks base method. +func (m *MockAPI) RegisterCollectionAndTopic(arg0, arg1 string) error { + m.ctrl.T.Helper() + ret := m.ctrl.Call(m, "RegisterCollectionAndTopic", arg0, arg1) + ret0, _ := ret[0].(error) + return ret0 +} + +// RegisterCollectionAndTopic indicates an expected call of RegisterCollectionAndTopic. +func (mr *MockAPIMockRecorder) RegisterCollectionAndTopic(arg0, arg1 interface{}) *gomock.Call { + mr.mock.ctrl.T.Helper() + return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "RegisterCollectionAndTopic", reflect.TypeOf((*MockAPI)(nil).RegisterCollectionAndTopic), arg0, arg1) +} + // RegisterCommand mocks base method. func (m *MockAPI) RegisterCommand(arg0 *model.Command) error { m.ctrl.T.Helper() @@ -2581,6 +2625,21 @@ func (mr *MockAPIMockRecorder) UpdateUserStatus(arg0, arg1 interface{}) *gomock. return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "UpdateUserStatus", reflect.TypeOf((*MockAPI)(nil).UpdateUserStatus), arg0, arg1) } +// UploadData mocks base method. +func (m *MockAPI) UploadData(arg0 *model.UploadSession, arg1 io.Reader) (*model.FileInfo, error) { + m.ctrl.T.Helper() + ret := m.ctrl.Call(m, "UploadData", arg0, arg1) + ret0, _ := ret[0].(*model.FileInfo) + ret1, _ := ret[1].(error) + return ret0, ret1 +} + +// UploadData indicates an expected call of UploadData. +func (mr *MockAPIMockRecorder) UploadData(arg0, arg1 interface{}) *gomock.Call { + mr.mock.ctrl.T.Helper() + return mr.mock.ctrl.RecordCallWithMethodType(mr.mock, "UploadData", reflect.TypeOf((*MockAPI)(nil).UploadData), arg0, arg1) +} + // UploadFile mocks base method. func (m *MockAPI) UploadFile(arg0 []byte, arg1, arg2 string) (*model.FileInfo, *model.AppError) { m.ctrl.T.Helper()