diff --git a/.idea/runConfigurations/Migrate_DB.xml b/.idea/runConfigurations/Migrate_DB.xml new file mode 100644 index 000000000..c7063d27b --- /dev/null +++ b/.idea/runConfigurations/Migrate_DB.xml @@ -0,0 +1,26 @@ + + + + + + + true + true + false + false + + + \ No newline at end of file diff --git a/backend/src/main/kotlin/app/ehrenamtskarte/backend/EntryPoint.kt b/backend/src/main/kotlin/app/ehrenamtskarte/backend/EntryPoint.kt index 4259bd001..4b1145085 100644 --- a/backend/src/main/kotlin/app/ehrenamtskarte/backend/EntryPoint.kt +++ b/backend/src/main/kotlin/app/ehrenamtskarte/backend/EntryPoint.kt @@ -4,6 +4,8 @@ import app.ehrenamtskarte.backend.common.database.Database import app.ehrenamtskarte.backend.common.webservice.GraphQLHandler import app.ehrenamtskarte.backend.common.webservice.WebService import app.ehrenamtskarte.backend.config.BackendConfiguration +import app.ehrenamtskarte.backend.migration.MigrationUtils +import app.ehrenamtskarte.backend.migration.database.Migrations import app.ehrenamtskarte.backend.stores.importer.Importer import com.expediagroup.graphql.generator.extensions.print import com.github.ajalt.clikt.core.CliktCommand @@ -17,6 +19,8 @@ import com.github.ajalt.clikt.parameters.options.option import com.github.ajalt.clikt.parameters.types.choice import com.github.ajalt.clikt.parameters.types.file import com.github.ajalt.clikt.parameters.types.int +import org.jetbrains.exposed.sql.exists +import org.jetbrains.exposed.sql.transactions.transaction import java.io.File import java.util.TimeZone @@ -116,9 +120,47 @@ class Execute : CliktCommand(help = "Starts the webserver") { } } +class Migrate : CliktCommand(help = "Migrates the database") { + private val config by requireObject() + + override fun run() { + val db = Database.setupWithoutMigrationCheck(config) + MigrationUtils.applyRequiredMigrations(db) + } +} + +class MigrateSkipBaseline : CliktCommand( + help = """ + Applies all migrations except for the baseline step. + + This command allows the production system to be upgraded to the new DB migration system. + It adds the migrations table without applying the baseline migration step. + It should be used only once when introducing the new DB migration system on the production server. + Once this is done, this command can be safely removed. + """.trimIndent(), +) { + private val config by requireObject() + + override fun run() { + val db = Database.setupWithoutMigrationCheck(config) + if (transaction { Migrations.exists() }) { + throw IllegalArgumentException("The migrations table has already been created. Use the migrate command instead.") + } + MigrationUtils.applyRequiredMigrations(db, skipBaseline = true) + } +} + fun main(args: Array) { // Set the default time zone to UTC in order to make timestamps work properly in every configuration. TimeZone.setDefault(TimeZone.getTimeZone("UTC")) - Entry().subcommands(Execute(), Import(), ImportSingle(), CreateAdmin(), GraphQLExport()).main(args) + Entry().subcommands( + Execute(), + Import(), + ImportSingle(), + Migrate(), + MigrateSkipBaseline(), + CreateAdmin(), + GraphQLExport() + ).main(args) } diff --git a/backend/src/main/kotlin/app/ehrenamtskarte/backend/application/database/Setup.kt b/backend/src/main/kotlin/app/ehrenamtskarte/backend/application/database/Setup.kt deleted file mode 100644 index 5e618507b..000000000 --- a/backend/src/main/kotlin/app/ehrenamtskarte/backend/application/database/Setup.kt +++ /dev/null @@ -1,10 +0,0 @@ -package app.ehrenamtskarte.backend.application.database - -import org.jetbrains.exposed.sql.SchemaUtils - -fun setupDatabase() { - SchemaUtils.create( - Applications, - ApplicationVerifications, - ) -} diff --git a/backend/src/main/kotlin/app/ehrenamtskarte/backend/auth/database/Schema.kt b/backend/src/main/kotlin/app/ehrenamtskarte/backend/auth/database/Schema.kt index a05f6b10b..7adb115b5 100644 --- a/backend/src/main/kotlin/app/ehrenamtskarte/backend/auth/database/Schema.kt +++ b/backend/src/main/kotlin/app/ehrenamtskarte/backend/auth/database/Schema.kt @@ -11,7 +11,6 @@ import org.jetbrains.exposed.sql.Op import org.jetbrains.exposed.sql.and import org.jetbrains.exposed.sql.javatime.timestamp import org.jetbrains.exposed.sql.or -import org.jetbrains.exposed.sql.transactions.TransactionManager object Administrators : IntIdTable() { val email = varchar("email", 100) @@ -37,11 +36,6 @@ object Administrators : IntIdTable() { } } -fun createEmailIndexIfNotExists() { - val sql = "CREATE UNIQUE INDEX IF NOT EXISTS email_lower_idx ON ${Administrators.nameInDatabaseCase()} (lower(${Administrators.email.nameInDatabaseCase()}))" - TransactionManager.current().exec(sql) -} - class AdministratorEntity(id: EntityID) : IntEntity(id) { companion object : IntEntityClass(Administrators) diff --git a/backend/src/main/kotlin/app/ehrenamtskarte/backend/auth/database/Setup.kt b/backend/src/main/kotlin/app/ehrenamtskarte/backend/auth/database/Setup.kt deleted file mode 100644 index b214ecaa0..000000000 --- a/backend/src/main/kotlin/app/ehrenamtskarte/backend/auth/database/Setup.kt +++ /dev/null @@ -1,10 +0,0 @@ -package app.ehrenamtskarte.backend.auth.database - -import org.jetbrains.exposed.sql.SchemaUtils - -fun setupDatabase() { - SchemaUtils.create( - Administrators, - ) - createEmailIndexIfNotExists() -} diff --git a/backend/src/main/kotlin/app/ehrenamtskarte/backend/common/database/Database.kt b/backend/src/main/kotlin/app/ehrenamtskarte/backend/common/database/Database.kt index a669c6f47..52d6ee7d1 100644 --- a/backend/src/main/kotlin/app/ehrenamtskarte/backend/common/database/Database.kt +++ b/backend/src/main/kotlin/app/ehrenamtskarte/backend/common/database/Database.kt @@ -3,6 +3,11 @@ package app.ehrenamtskarte.backend.common.database import app.ehrenamtskarte.backend.auth.database.repos.AdministratorsRepository import app.ehrenamtskarte.backend.auth.webservice.schema.types.Role import app.ehrenamtskarte.backend.config.BackendConfiguration +import app.ehrenamtskarte.backend.migration.assertDatabaseIsInSync +import app.ehrenamtskarte.backend.projects.database.insertOrUpdateProjects +import app.ehrenamtskarte.backend.regions.database.insertOrUpdateRegions +import app.ehrenamtskarte.backend.stores.database.createOrReplaceStoreFunctions +import app.ehrenamtskarte.backend.stores.database.insertOrUpdateCategories import org.jetbrains.exposed.sql.Database.Companion.connect import org.jetbrains.exposed.sql.DatabaseConfig import org.jetbrains.exposed.sql.StdOutSqlLogger @@ -11,12 +16,6 @@ import org.jetbrains.exposed.sql.transactions.transaction import java.io.BufferedReader import java.io.InputStreamReader import java.util.stream.Collectors -import app.ehrenamtskarte.backend.application.database.setupDatabase as setupDatabaseForApplication -import app.ehrenamtskarte.backend.auth.database.setupDatabase as setupDatabaseForAuth -import app.ehrenamtskarte.backend.projects.database.setupDatabase as setupDatabaseForProjects -import app.ehrenamtskarte.backend.regions.database.setupDatabase as setupDatabaseForRegions -import app.ehrenamtskarte.backend.stores.database.setupDatabase as setupDatabaseForStores -import app.ehrenamtskarte.backend.verification.database.setupDatabase as setupDatabaseForVerification class Database { @@ -46,8 +45,20 @@ class Database { } } - fun setup(config: BackendConfiguration) { - connect( + fun setup(config: BackendConfiguration): org.jetbrains.exposed.sql.Database { + val database = setupWithoutMigrationCheck(config) + transaction { + assertDatabaseIsInSync() + insertOrUpdateProjects(config) + insertOrUpdateRegions() + insertOrUpdateCategories(Companion::executeScript) + createOrReplaceStoreFunctions(Companion::executeScript) + } + return database + } + + fun setupWithoutMigrationCheck(config: BackendConfiguration): org.jetbrains.exposed.sql.Database { + val database = connect( config.postgres.url, driver = "org.postgresql.Driver", user = config.postgres.user, @@ -57,22 +68,15 @@ class Database { // Note(michael-markl): I believe this is postgres specific syntax. it.prepareStatement("SET TIME ZONE 'UTC';").executeUpdate() }, - databaseConfig = if (config.production) { - null - } else { - DatabaseConfig.invoke { + databaseConfig = DatabaseConfig.invoke { + // Nested transactions are helpful for applying migrations in subtransactions. + useNestedTransactions = true + if (!config.production) { this.sqlLogger = StdOutSqlLogger } }, ) - transaction { - setupDatabaseForProjects(config) - setupDatabaseForRegions() - setupDatabaseForStores(Companion::executeScript) - setupDatabaseForVerification() - setupDatabaseForApplication() - setupDatabaseForAuth() - } + return database } } } diff --git a/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/AssertDatabaseInSync.kt b/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/AssertDatabaseInSync.kt new file mode 100644 index 000000000..c28f32983 --- /dev/null +++ b/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/AssertDatabaseInSync.kt @@ -0,0 +1,106 @@ +package app.ehrenamtskarte.backend.migration + +import app.ehrenamtskarte.backend.migration.database.Migrations +import app.ehrenamtskarte.backend.migration.migrations.MigrationsRegistry +import org.jetbrains.exposed.sql.ColumnDiff +import org.jetbrains.exposed.sql.SchemaUtils +import org.jetbrains.exposed.sql.Table +import org.jetbrains.exposed.sql.transactions.TransactionManager +import org.jetbrains.exposed.sql.vendors.currentDialect + +class DatabaseOutOfSyncException(suggestedMigrationStatements: List? = null, comment: String? = null) : + Exception( + run { + var message = "" + if (comment != null) { + message += "\n$comment" + } + if (suggestedMigrationStatements != null) { + message += "\nThe following migrations are suggested:\n--- START OF SUGGESTED MIGRATIONS\n" + + suggestedMigrationStatements.joinToString("\n") { "$it;" } + + "\n--- END OF SUGGESTED MIGRATIONS" + } + message + }, + ) + +fun assertDatabaseIsInSync() { + val allTables = TablesRegistry.getAllTables() + val allMigrations = MigrationsRegistry.getAllMigrations() + val versionDb = Migrations.getCurrentVersionOrNull() + val versionCode = allMigrations.maxOfOrNull { it.version } + if (versionCode != versionDb) { + throw DatabaseOutOfSyncException(comment = "Latest migration versions do not match: Version on DB $versionDb - Code Version $versionCode") + } + + var outOfSyncComment: String? = null + + // Check if all tables in the DB appear in `allTables` and vice versa. + // We ignore spatial_ref_sys. + val tablesInDb = + currentDialect.allTablesNames().map { it.substringAfter(".") } + .filter { it != "spatial_ref_sys" }.toSet() + val tablesInCode = allTables.map { it.nameInDatabaseCase() }.toSet() + if (tablesInDb != tablesInCode) { + val tablesNotInCode = tablesInDb - tablesInCode + val tablesNotInDb = tablesInCode - tablesInDb + outOfSyncComment = "List of tables is out sync with database:" + if (tablesNotInCode.isNotEmpty()) { + outOfSyncComment += "\nUnknown tables found in DB: $tablesNotInCode" + } + if (tablesNotInDb.isNotEmpty()) { + outOfSyncComment += "\nTables missing in DB: $tablesNotInDb" + } + } + + val statements = statementsRequiredToActualizeScheme(*allTables) + dropExcessiveColumns(*allTables) + if (statements.isNotEmpty() || outOfSyncComment != null) { + throw DatabaseOutOfSyncException(statements, comment = outOfSyncComment) + } +} + +/** + * Checks whether there exist any excessive columns for the passed tables. + * Returns a list of SQL statements to drop these excessive columns. + */ +private fun dropExcessiveColumns(vararg tables: Table): List { + val transaction = TransactionManager.current() + + val statements = mutableListOf() + val existingColumnsByTable = currentDialect.tableColumns(*tables) + for (table in tables) { + val columns = existingColumnsByTable[table] ?: continue + for (column in columns) { + val columnInCode = table.columns.singleOrNull { it.name.equals(column.name, ignoreCase = true) } + if (columnInCode == null) { + statements += "ALTER TABLE ${transaction.identity(table)} DROP ${column.name}" + } + } + } + + return statements +} + +/** + * Workaround for https://github.com/JetBrains/Exposed/issues/1486 + */ +internal fun statementsRequiredToActualizeScheme(vararg tables: Table): List { + val statements = SchemaUtils.statementsRequiredToActualizeScheme(*tables) + val existingColumnsByTable = currentDialect.tableColumns(*tables) + val allColumns = tables.map { table -> table.columns }.flatten() + val problematicColumns = allColumns.filter { column -> + val hasDefaultInCode = column.descriptionDdl().contains("DEFAULT (CURRENT_TIMESTAMP)") + val existingColumn = existingColumnsByTable[column.table]?.singleOrNull { + column.name.equals(it.name, true) + } + val hasDefaultInDb = existingColumn?.defaultDbValue == "CURRENT_TIMESTAMP" + hasDefaultInCode && hasDefaultInDb + } + val problematicStatements = problematicColumns.map { + currentDialect.modifyColumn( + it, + ColumnDiff(defaults = true, nullability = false, autoInc = false, caseSensitiveName = false), + ).single() + } + return statements.filter { it !in problematicStatements } +} diff --git a/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/Migration.kt b/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/Migration.kt new file mode 100644 index 000000000..3727073f0 --- /dev/null +++ b/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/Migration.kt @@ -0,0 +1,23 @@ +package app.ehrenamtskarte.backend.migration + +import org.jetbrains.exposed.sql.Transaction + +typealias Statement = (Transaction.() -> Unit?) + +abstract class Migration { + + val name: String + val version: Int + + init { + val className = this::class.simpleName!! + val groups = + Regex("^V(\\d{4})_(.*)").matchEntire(className)?.groupValues ?: throw IllegalArgumentException( + "Migration class name $className doesn't match convention.", + ) + version = groups[1].toInt() + name = groups[2] + } + + abstract val migrate: Statement +} diff --git a/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/MigrationUtils.kt b/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/MigrationUtils.kt new file mode 100644 index 000000000..397782ffd --- /dev/null +++ b/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/MigrationUtils.kt @@ -0,0 +1,89 @@ +package app.ehrenamtskarte.backend.migration + +import app.ehrenamtskarte.backend.migration.database.MigrationEntity +import app.ehrenamtskarte.backend.migration.database.Migrations +import app.ehrenamtskarte.backend.migration.migrations.MigrationsRegistry +import app.ehrenamtskarte.backend.migration.migrations.V0001_Baseline +import org.jetbrains.exposed.dao.id.EntityID +import org.jetbrains.exposed.exceptions.ExposedSQLException +import org.jetbrains.exposed.sql.Database +import org.jetbrains.exposed.sql.SchemaUtils +import org.jetbrains.exposed.sql.exists +import org.jetbrains.exposed.sql.transactions.transaction +import org.jetbrains.exposed.sql.vendors.currentDialect +import org.slf4j.LoggerFactory +import java.time.Instant.now + +object MigrationUtils { + private val logger = LoggerFactory.getLogger(MigrationUtils::class.java) + + class MigrationException(message: String, cause: Exception? = null) : Exception(message, cause) + + /** + * @throws MigrationException + */ + fun applyRequiredMigrations(database: Database, skipBaseline: Boolean = false) { + val migrations = MigrationsRegistry.getAllMigrations() + + if (migrations.map { it.version } != (1..migrations.size).toList()) { + throw MigrationException("List of versions is not consecutive: ${migrations.map { it.version }}") + } + + logger.info("Running migrations on database ${database.url}") + try { + // Apply all migrations in a single transaction, to make sure nothing changes if any migration step fails. + transaction { + val versionBeforeMigration = transaction { Migrations.getCurrentVersionOrNull() } + + logger.info("Database version before migrations: ${versionBeforeMigration ?: "(none)"}") + logger.info("Latest migration version: ${migrations.maxOfOrNull { it.version } ?: "(none)"}") + + if (!Migrations.exists()) { + logger.info("Migrations table did not exist. Creating it.") + transaction { SchemaUtils.create(Migrations) } + currentDialect.resetCaches() + } else { + // If changes to the Migrations table ever need to made, they need to be handled here (before any + // migrations are applied). + // Changes to the Migrations table should not be done through migrations (see discussion on + // https://github.com/digitalfabrik/entitlementcard/pull/906) + } + + for (migration in migrations) { + if (versionBeforeMigration != null && migration.version <= versionBeforeMigration) { + logger.debug("Skipping ${migration.javaClass.simpleName}") + continue + } + if (migration is V0001_Baseline && skipBaseline) { + logger.info("Skipping ${migration.javaClass.simpleName} as requested.") + } else { + logger.info("Applying ${migration.javaClass.simpleName}") + transaction(statement = migration.migrate) + // If we create or drop tables in a migration, we need to reset Exposed's caches. + currentDialect.resetCaches() + } + transaction { + MigrationEntity.new { + version = EntityID(migration.version, Migrations) + name = migration.name + executedAt = now() + } + } + } + + assertDatabaseIsInSync() + } + } catch (exception: DatabaseOutOfSyncException) { + throw MigrationException( + "Database was still out sync after attempted migration. Hence, NO CHANGES were committed onto the DB.", + exception + ) + } catch (exception: ExposedSQLException) { + throw MigrationException( + "The above SQL error occuring during attempted migration. Hence, NO CHANGES were committed onto the DB.", + exception + ) + } + logger.info("Migrations finished successfully") + } +} diff --git a/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/TablesRegistry.kt b/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/TablesRegistry.kt new file mode 100644 index 000000000..f1fb2952a --- /dev/null +++ b/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/TablesRegistry.kt @@ -0,0 +1,31 @@ +package app.ehrenamtskarte.backend.migration + +import app.ehrenamtskarte.backend.application.database.ApplicationVerifications +import app.ehrenamtskarte.backend.application.database.Applications +import app.ehrenamtskarte.backend.auth.database.Administrators +import app.ehrenamtskarte.backend.migration.database.Migrations +import app.ehrenamtskarte.backend.projects.database.Projects +import app.ehrenamtskarte.backend.regions.database.Regions +import app.ehrenamtskarte.backend.stores.database.AcceptingStores +import app.ehrenamtskarte.backend.stores.database.Addresses +import app.ehrenamtskarte.backend.stores.database.Categories +import app.ehrenamtskarte.backend.stores.database.Contacts +import app.ehrenamtskarte.backend.stores.database.PhysicalStores +import app.ehrenamtskarte.backend.verification.database.Cards + +object TablesRegistry { + fun getAllTables() = arrayOf( + Cards, + Applications, + ApplicationVerifications, + Administrators, + Migrations, + Projects, + Regions, + PhysicalStores, + AcceptingStores, + Addresses, + Contacts, + Categories, + ) +} diff --git a/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/database/Schema.kt b/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/database/Schema.kt new file mode 100644 index 000000000..d6a84cec2 --- /dev/null +++ b/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/database/Schema.kt @@ -0,0 +1,34 @@ +package app.ehrenamtskarte.backend.migration.database + +import org.jetbrains.exposed.dao.EntityClass +import org.jetbrains.exposed.dao.IntEntity +import org.jetbrains.exposed.dao.id.EntityID +import org.jetbrains.exposed.dao.id.IdTable +import org.jetbrains.exposed.sql.exists +import org.jetbrains.exposed.sql.javatime.timestamp +import org.jetbrains.exposed.sql.max +import org.jetbrains.exposed.sql.selectAll + +object Migrations : IdTable() { + override val id = integer("version").entityId() + val version = id + + override val primaryKey = PrimaryKey(version) + + val name = varchar("name", length = 400) + val executedAt = timestamp("executed_at") + + fun getCurrentVersionOrNull() = if (Migrations.exists()) { + Migrations.slice(version.max()).selectAll().singleOrNull()?.get(version.max())?.value + } else { + null + } +} + +class MigrationEntity(version: EntityID) : IntEntity(version) { + companion object : EntityClass(Migrations) + + var version by Migrations.version + var name by Migrations.name + var executedAt by Migrations.executedAt +} diff --git a/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/migrations/MigrationsRegistry.kt b/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/migrations/MigrationsRegistry.kt new file mode 100644 index 000000000..9d80e65bf --- /dev/null +++ b/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/migrations/MigrationsRegistry.kt @@ -0,0 +1,8 @@ +package app.ehrenamtskarte.backend.migration.migrations + +object MigrationsRegistry { + fun getAllMigrations() = arrayOf( + V0001_Baseline(), + V0002_DropCaseSensitiveEmailConstraint() + ) +} diff --git a/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/migrations/V0001_Baseline.kt b/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/migrations/V0001_Baseline.kt new file mode 100644 index 000000000..72a04ca54 --- /dev/null +++ b/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/migrations/V0001_Baseline.kt @@ -0,0 +1,456 @@ +package app.ehrenamtskarte.backend.migration.migrations + +import app.ehrenamtskarte.backend.migration.Migration +import app.ehrenamtskarte.backend.migration.Statement + +@Suppress("ClassName") +internal class V0001_Baseline() : Migration() { + override val migrate: Statement = { + exec( + """ + CREATE FUNCTION physical_stores(z integer, x integer, y integer, query_params json) RETURNS bytea + LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE + AS ${'$'}${'$'} + DECLARE + -- DEPRECATED: Fallback only used in old ehrenamtskarten app, released January, 2021 + project_id text = CASE WHEN query_params::jsonb ? 'project_id' THEN (query_params->>'project_id')::text ELSE 'bayern.ehrenamtskarte.app' END; + BEGIN + + IF ((query_params->>'clustered')::boolean) THEN + RETURN physical_stores_clusters(z, x, y, project_id); + ELSE + RETURN physical_stores_points(z, x, y, project_id); + END IF; + END + ${'$'}${'$'}; + + CREATE FUNCTION physical_stores_clustered(z integer, x integer, y integer, query_params json) RETURNS bytea + LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE + AS ${'$'}${'$'} + DECLARE + -- DEPRECATED: Fallback only used in old ehrenamtskarten app, released January, 2021 + project_id text = CASE WHEN query_params::jsonb ? 'project_id' THEN (query_params->>'project_id')::text ELSE 'bayern.ehrenamtskarte.app' END; + BEGIN + RETURN physical_stores_clusters(z, x, y, project_id); + END + ${'$'}${'$'}; + + CREATE FUNCTION physical_stores_clusters(z integer, x integer, y integer, project_id text) RETURNS bytea + LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE + AS ${'$'}${'$'} + DECLARE + clip_geom boolean = false; + buffer integer = 64; + extend integer = 4096; + mvt bytea; + cluster_k integer = 3; + tile_bbox geometry = TileBBox(z, x, y, 4326); + BEGIN + SELECT INTO mvt ST_AsMVT(tile, 'physical_stores_clustered', extend, 'mvt_geom') + FROM ( + WITH locations AS ( + SELECT store.coordinates + FROM physicalstores store + JOIN acceptingstores ON acceptingstores.id = store."storeId" + JOIN projects ON projects.id = acceptingstores."projectId" + WHERE store.coordinates && tile_bbox AND projects.project = project_id + ), + k AS ( + SELECT CAST(LEAST(cluster_k, COUNT(*)) AS int) + FROM locations + ), + clusters AS ( + SELECT ST_ClusterKMeans(locations.coordinates, (SELECT * FROM k)) + OVER () AS cluster_index, + locations.coordinates + FROM locations + ) + SELECT cluster_index, + count(*) AS cluster_count, + ST_AsMVTGeom( + ST_CENTROID(ST_COLLECT(clusters.coordinates)), tile_bbox, extend, buffer, + clip_geom + ) AS mvt_geom + FROM clusters + GROUP BY cluster_index) AS tile + WHERE mvt_geom IS NOT NULL; + + RETURN mvt; + END + ${'$'}${'$'}; + + CREATE FUNCTION physical_stores_points(z integer, x integer, y integer, project_id text) RETURNS bytea + LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE + AS ${'$'}${'$'} + DECLARE + clip_geom boolean = false; + buffer integer = 64; + extend integer = 4096; + mvt bytea; + BEGIN + SELECT INTO mvt ST_AsMVT(tile, 'physical_stores', 4096, 'mvt_geom') + FROM ( + SELECT ST_AsMVTGeom(ST_Transform(coordinates, 3857), TileBBox(z, x, y, 3857), extend, buffer, + clip_geom) AS mvt_geom, + physicalstores.id, + acceptingstores."categoryId" + FROM physicalstores + JOIN acceptingstores ON acceptingstores.id = physicalstores."storeId" + JOIN projects ON projects.id = acceptingstores."projectId" + WHERE coordinates && TileBBox(z, x, y, 4326) AND projects.project = project_id + LIMIT 100 + ) as tile + WHERE mvt_geom IS NOT NULL; + + RETURN mvt; + END + ${'$'}${'$'}; + + CREATE FUNCTION tilebbox(z integer, x integer, y integer, srid integer DEFAULT 3857) RETURNS geometry + LANGUAGE plpgsql IMMUTABLE + AS ${'$'}${'$'} + declare + max numeric := 20037508.34; + res numeric := (max * 2) / (2 ^ z); + bbox geometry; + begin + bbox := ST_MakeEnvelope( + -max + (x * res), + max - (y * res), + -max + (x * res) + res, + max - (y * res) - res, + 3857 + ); + if srid = 3857 then + return bbox; + else + return ST_Transform(bbox, srid); + end if; + end; + ${'$'}${'$'}; + + CREATE TABLE acceptingstores ( + id integer NOT NULL, + name character varying(150) NOT NULL, + description character varying(2500), + "contactId" integer NOT NULL, + "categoryId" integer NOT NULL, + "projectId" integer NOT NULL, + "regionId" integer + ); + CREATE SEQUENCE acceptingstores_id_seq + AS integer + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + ALTER SEQUENCE acceptingstores_id_seq OWNED BY acceptingstores.id; + + CREATE TABLE addresses ( + id integer NOT NULL, + street character varying(200), + "postalCode" character varying(10) NOT NULL, + location character varying(200) NOT NULL, + "countryCode" character varying(2) NOT NULL + ); + CREATE SEQUENCE addresses_id_seq + AS integer + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + ALTER SEQUENCE addresses_id_seq OWNED BY addresses.id; + + CREATE TABLE administrators ( + id integer NOT NULL, + email character varying(100) NOT NULL, + "projectId" integer NOT NULL, + "regionId" integer, + role character varying(32) NOT NULL, + "passwordHash" bytea, + "passwordResetKey" character varying(100), + "passwordResetKeyExpiry" timestamp without time zone, + deleted boolean NOT NULL, + CONSTRAINT deletedifandonlyifnorights CHECK ((((deleted = true) AND ((role)::text = 'NO_RIGHTS'::text)) OR ((deleted = false) AND ((role)::text <> 'NO_RIGHTS'::text)))), + CONSTRAINT roleregioncombinationconstraint CHECK (((("regionId" IS NULL) AND ((role)::text = ANY ((ARRAY['PROJECT_ADMIN'::character varying, 'NO_RIGHTS'::character varying])::text[]))) OR (("regionId" IS NOT NULL) AND ((role)::text = ANY ((ARRAY['REGION_MANAGER'::character varying, 'REGION_ADMIN'::character varying, 'NO_RIGHTS'::character varying])::text[]))))) + ); + + CREATE SEQUENCE administrators_id_seq + AS integer + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + ALTER SEQUENCE administrators_id_seq OWNED BY administrators.id; + + CREATE TABLE applications ( + id integer NOT NULL, + "regionId" integer NOT NULL, + "jsonValue" text NOT NULL, + "createdDate" timestamp without time zone DEFAULT CURRENT_TIMESTAMP NOT NULL, + "accessKey" character varying(100) NOT NULL, + "withdrawalDate" timestamp without time zone + ); + + CREATE SEQUENCE applications_id_seq + AS integer + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + ALTER SEQUENCE applications_id_seq OWNED BY applications.id; + + CREATE TABLE applicationverifications ( + id integer NOT NULL, + "applicationId" integer NOT NULL, + "contactEmailAddress" character varying(300) NOT NULL, + "contactName" character varying(300) NOT NULL, + "organizationName" character varying(300) NOT NULL, + "verifiedDate" timestamp without time zone, + "rejectedDate" timestamp without time zone, + "accessKey" character varying(100) NOT NULL, + CONSTRAINT notverifiedandrejected CHECK ((NOT (("verifiedDate" IS NOT NULL) AND ("rejectedDate" IS NOT NULL)))) + ); + + CREATE SEQUENCE applicationverifications_id_seq + AS integer + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + ALTER SEQUENCE applicationverifications_id_seq OWNED BY applicationverifications.id; + + CREATE TABLE cards ( + id integer NOT NULL, + "activationSecretHash" bytea, + "totpSecret" bytea, + "expirationDay" bigint, + "issueDate" timestamp without time zone DEFAULT CURRENT_TIMESTAMP NOT NULL, + revoked boolean NOT NULL, + "regionId" integer NOT NULL, + "issuerId" integer NOT NULL, + "cardInfoHash" bytea NOT NULL, + "codeType" integer NOT NULL, + CONSTRAINT codetypeconstraint CHECK (((("activationSecretHash" IS NULL) AND ("totpSecret" IS NULL) AND ("codeType" = 0)) OR (("activationSecretHash" IS NOT NULL) AND ("codeType" = 1)))) + ); + + CREATE SEQUENCE cards_id_seq + AS integer + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + ALTER SEQUENCE cards_id_seq OWNED BY cards.id; + + CREATE TABLE categories ( + id integer NOT NULL, + name character varying(50) NOT NULL + ); + + CREATE SEQUENCE categories_id_seq + AS integer + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + ALTER SEQUENCE categories_id_seq OWNED BY categories.id; + + CREATE TABLE contacts ( + id integer NOT NULL, + email character varying(100), + telephone character varying(100), + website character varying(200) + ); + + CREATE SEQUENCE contacts_id_seq + AS integer + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + ALTER SEQUENCE contacts_id_seq OWNED BY contacts.id; + + CREATE TABLE physicalstores ( + id integer NOT NULL, + coordinates geometry(Point,4326) NOT NULL, + "addressId" integer NOT NULL, + "storeId" integer NOT NULL + ); + + CREATE SEQUENCE physicalstores_id_seq + AS integer + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + ALTER SEQUENCE physicalstores_id_seq OWNED BY physicalstores.id; + + CREATE TABLE projects ( + id integer NOT NULL, + project character varying(50) NOT NULL + ); + + CREATE SEQUENCE projects_id_seq + AS integer + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + ALTER SEQUENCE projects_id_seq OWNED BY projects.id; + + CREATE TABLE regions ( + id integer NOT NULL, + "projectId" integer NOT NULL, + "regionIdentifier" character(5), + website character varying(400) NOT NULL, + name character varying(100) NOT NULL, + prefix character varying(30) NOT NULL, + "dataPrivacyPolicy" character varying(20000) + ); + + CREATE SEQUENCE regions_id_seq + AS integer + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + ALTER SEQUENCE regions_id_seq OWNED BY regions.id; + + ALTER TABLE ONLY acceptingstores ALTER COLUMN id SET DEFAULT nextval('acceptingstores_id_seq'::regclass); + + ALTER TABLE ONLY addresses ALTER COLUMN id SET DEFAULT nextval('addresses_id_seq'::regclass); + + ALTER TABLE ONLY administrators ALTER COLUMN id SET DEFAULT nextval('administrators_id_seq'::regclass); + + ALTER TABLE ONLY applications ALTER COLUMN id SET DEFAULT nextval('applications_id_seq'::regclass); + + ALTER TABLE ONLY applicationverifications ALTER COLUMN id SET DEFAULT nextval('applicationverifications_id_seq'::regclass); + + ALTER TABLE ONLY cards ALTER COLUMN id SET DEFAULT nextval('cards_id_seq'::regclass); + + ALTER TABLE ONLY categories ALTER COLUMN id SET DEFAULT nextval('categories_id_seq'::regclass); + + ALTER TABLE ONLY contacts ALTER COLUMN id SET DEFAULT nextval('contacts_id_seq'::regclass); + + ALTER TABLE ONLY physicalstores ALTER COLUMN id SET DEFAULT nextval('physicalstores_id_seq'::regclass); + + ALTER TABLE ONLY projects ALTER COLUMN id SET DEFAULT nextval('projects_id_seq'::regclass); + + ALTER TABLE ONLY regions ALTER COLUMN id SET DEFAULT nextval('regions_id_seq'::regclass); + + ALTER TABLE ONLY acceptingstores + ADD CONSTRAINT acceptingstores_pkey PRIMARY KEY (id); + + ALTER TABLE ONLY addresses + ADD CONSTRAINT addresses_pkey PRIMARY KEY (id); + + ALTER TABLE ONLY administrators + ADD CONSTRAINT administrators_email_unique UNIQUE (email); + + ALTER TABLE ONLY administrators + ADD CONSTRAINT administrators_pkey PRIMARY KEY (id); + + ALTER TABLE ONLY applications + ADD CONSTRAINT applications_accesskey_unique UNIQUE ("accessKey"); + + ALTER TABLE ONLY applications + ADD CONSTRAINT applications_pkey PRIMARY KEY (id); + + ALTER TABLE ONLY applicationverifications + ADD CONSTRAINT applicationverifications_accesskey_unique UNIQUE ("accessKey"); + + ALTER TABLE ONLY applicationverifications + ADD CONSTRAINT applicationverifications_pkey PRIMARY KEY (id); + + ALTER TABLE ONLY cards + ADD CONSTRAINT cards_cardinfohash_unique UNIQUE ("cardInfoHash"); + + ALTER TABLE ONLY cards + ADD CONSTRAINT cards_pkey PRIMARY KEY (id); + + ALTER TABLE ONLY categories + ADD CONSTRAINT categories_pkey PRIMARY KEY (id); + + ALTER TABLE ONLY contacts + ADD CONSTRAINT contacts_pkey PRIMARY KEY (id); + + ALTER TABLE ONLY physicalstores + ADD CONSTRAINT physicalstores_pkey PRIMARY KEY (id); + + ALTER TABLE ONLY projects + ADD CONSTRAINT projects_pkey PRIMARY KEY (id); + + ALTER TABLE ONLY projects + ADD CONSTRAINT projects_project_unique UNIQUE (project); + + ALTER TABLE ONLY regions + ADD CONSTRAINT regions_pkey PRIMARY KEY (id); + + ALTER TABLE ONLY regions + ADD CONSTRAINT regions_regionidentifier_unique UNIQUE ("regionIdentifier"); + + CREATE UNIQUE INDEX email_lower_idx ON administrators USING btree (lower((email)::text)); + + ALTER TABLE ONLY acceptingstores + ADD CONSTRAINT fk_acceptingstores_categoryid__id FOREIGN KEY ("categoryId") REFERENCES categories(id) ON UPDATE RESTRICT ON DELETE RESTRICT; + + ALTER TABLE ONLY acceptingstores + ADD CONSTRAINT fk_acceptingstores_contactid__id FOREIGN KEY ("contactId") REFERENCES contacts(id) ON UPDATE RESTRICT ON DELETE RESTRICT; + + ALTER TABLE ONLY acceptingstores + ADD CONSTRAINT fk_acceptingstores_projectid__id FOREIGN KEY ("projectId") REFERENCES projects(id) ON UPDATE RESTRICT ON DELETE RESTRICT; + + ALTER TABLE ONLY acceptingstores + ADD CONSTRAINT fk_acceptingstores_regionid__id FOREIGN KEY ("regionId") REFERENCES regions(id) ON UPDATE RESTRICT ON DELETE RESTRICT; + + ALTER TABLE ONLY administrators + ADD CONSTRAINT fk_administrators_projectid__id FOREIGN KEY ("projectId") REFERENCES projects(id) ON UPDATE RESTRICT ON DELETE RESTRICT; + + ALTER TABLE ONLY administrators + ADD CONSTRAINT fk_administrators_regionid__id FOREIGN KEY ("regionId") REFERENCES regions(id) ON UPDATE RESTRICT ON DELETE RESTRICT; + + ALTER TABLE ONLY applications + ADD CONSTRAINT fk_applications_regionid__id FOREIGN KEY ("regionId") REFERENCES regions(id) ON UPDATE RESTRICT ON DELETE RESTRICT; + + ALTER TABLE ONLY applicationverifications + ADD CONSTRAINT fk_applicationverifications_applicationid__id FOREIGN KEY ("applicationId") REFERENCES applications(id) ON UPDATE RESTRICT ON DELETE RESTRICT; + + ALTER TABLE ONLY cards + ADD CONSTRAINT fk_cards_issuerid__id FOREIGN KEY ("issuerId") REFERENCES administrators(id) ON UPDATE RESTRICT ON DELETE RESTRICT; + + ALTER TABLE ONLY cards + ADD CONSTRAINT fk_cards_regionid__id FOREIGN KEY ("regionId") REFERENCES regions(id) ON UPDATE RESTRICT ON DELETE RESTRICT; + + ALTER TABLE ONLY physicalstores + ADD CONSTRAINT fk_physicalstores_addressid__id FOREIGN KEY ("addressId") REFERENCES addresses(id) ON UPDATE RESTRICT ON DELETE RESTRICT; + + ALTER TABLE ONLY physicalstores + ADD CONSTRAINT fk_physicalstores_storeid__id FOREIGN KEY ("storeId") REFERENCES acceptingstores(id) ON UPDATE RESTRICT ON DELETE RESTRICT; + + ALTER TABLE ONLY regions + ADD CONSTRAINT fk_regions_projectid__id FOREIGN KEY ("projectId") REFERENCES projects(id) ON UPDATE RESTRICT ON DELETE RESTRICT; + """.trimIndent() + ) + } +} diff --git a/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/migrations/V0002_DropCaseSensitiveEmailConstraint.kt b/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/migrations/V0002_DropCaseSensitiveEmailConstraint.kt new file mode 100644 index 000000000..4f9b83731 --- /dev/null +++ b/backend/src/main/kotlin/app/ehrenamtskarte/backend/migration/migrations/V0002_DropCaseSensitiveEmailConstraint.kt @@ -0,0 +1,18 @@ +package app.ehrenamtskarte.backend.migration.migrations + +import app.ehrenamtskarte.backend.migration.Migration +import app.ehrenamtskarte.backend.migration.Statement + +/** + * Drops administrators_email_unique as we already have the unique index email_lower_idx. + */ +@Suppress("ClassName") +internal class V0002_DropCaseSensitiveEmailConstraint() : Migration() { + override val migrate: Statement = { + exec( + """ + ALTER TABLE administrators DROP CONSTRAINT administrators_email_unique; + """.trimIndent() + ) + } +} diff --git a/backend/src/main/kotlin/app/ehrenamtskarte/backend/projects/database/Setup.kt b/backend/src/main/kotlin/app/ehrenamtskarte/backend/projects/database/Setup.kt index 5de399869..818db39bb 100644 --- a/backend/src/main/kotlin/app/ehrenamtskarte/backend/projects/database/Setup.kt +++ b/backend/src/main/kotlin/app/ehrenamtskarte/backend/projects/database/Setup.kt @@ -1,14 +1,9 @@ package app.ehrenamtskarte.backend.projects.database import app.ehrenamtskarte.backend.config.BackendConfiguration -import org.jetbrains.exposed.sql.SchemaUtils import org.jetbrains.exposed.sql.transactions.transaction -fun setupDatabase(config: BackendConfiguration) { - SchemaUtils.create( - Projects, - ) - +fun insertOrUpdateProjects(config: BackendConfiguration) { transaction { val dbProjects = ProjectEntity.all() diff --git a/backend/src/main/kotlin/app/ehrenamtskarte/backend/regions/database/Setup.kt b/backend/src/main/kotlin/app/ehrenamtskarte/backend/regions/database/Setup.kt index 284511006..1a1223307 100644 --- a/backend/src/main/kotlin/app/ehrenamtskarte/backend/regions/database/Setup.kt +++ b/backend/src/main/kotlin/app/ehrenamtskarte/backend/regions/database/Setup.kt @@ -3,14 +3,9 @@ package app.ehrenamtskarte.backend.regions.database import app.ehrenamtskarte.backend.common.webservice.EAK_BAYERN_PROJECT import app.ehrenamtskarte.backend.common.webservice.NUERNBERG_PASS_PROJECT import app.ehrenamtskarte.backend.projects.database.ProjectEntity -import org.jetbrains.exposed.sql.SchemaUtils import org.jetbrains.exposed.sql.transactions.transaction -fun setupDatabase() { - SchemaUtils.create( - Regions - ) - +fun insertOrUpdateRegions() { transaction { val projects = ProjectEntity.all() val dbRegions = RegionEntity.all() diff --git a/backend/src/main/kotlin/app/ehrenamtskarte/backend/stores/database/Setup.kt b/backend/src/main/kotlin/app/ehrenamtskarte/backend/stores/database/Setup.kt index 1e76cc0a5..2cad547ed 100644 --- a/backend/src/main/kotlin/app/ehrenamtskarte/backend/stores/database/Setup.kt +++ b/backend/src/main/kotlin/app/ehrenamtskarte/backend/stores/database/Setup.kt @@ -1,16 +1,9 @@ package app.ehrenamtskarte.backend.stores.database -import org.jetbrains.exposed.sql.SchemaUtils - -fun setupDatabase(executeScript: (path: String) -> Unit) { - SchemaUtils.create( - Categories, - Contacts, - AcceptingStores, - PhysicalStores, - Addresses - ) +fun insertOrUpdateCategories(executeScript: (path: String) -> Unit) { + executeScript("sql/create_categories.sql") +} +fun createOrReplaceStoreFunctions(executeScript: (path: String) -> Unit) { executeScript("sql/martin_setup.sql") - executeScript("sql/create_categories.sql") } diff --git a/backend/src/main/kotlin/app/ehrenamtskarte/backend/verification/database/Setup.kt b/backend/src/main/kotlin/app/ehrenamtskarte/backend/verification/database/Setup.kt deleted file mode 100644 index d6bd17d50..000000000 --- a/backend/src/main/kotlin/app/ehrenamtskarte/backend/verification/database/Setup.kt +++ /dev/null @@ -1,9 +0,0 @@ -package app.ehrenamtskarte.backend.verification.database - -import org.jetbrains.exposed.sql.SchemaUtils - -fun setupDatabase() { - SchemaUtils.create( - Cards - ) -}