<?php
use Index\Db\DbConnection;
use Index\Db\Migration\DbMigration;

final class CreateStorageTables_20250326_164049 implements DbMigration {
    public function migrate(DbConnection $conn): void {
        $conn->execute(<<<SQL
            CREATE TABLE msz_storage_denylist (
                deny_id      INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
                deny_hash    BINARY(32)       NOT NULL,
                deny_reason  ENUM('copyright','rules','other') NOT NULL COLLATE 'ascii_general_ci',
                deny_created TIMESTAMP        NOT NULL DEFAULT current_timestamp(),
                PRIMARY KEY (deny_id),
                UNIQUE KEY msz_storage_denylist_hash_unique (deny_hash)
            ) COLLATE='utf8mb4_bin' ENGINE=InnoDB;
        SQL);

        $conn->execute(<<<SQL
            CREATE TABLE msz_storage_files (
                file_id      BIGINT(20) UNSIGNED NOT NULL,
                file_hash    BINARY(32)          NOT NULL,
                file_type    VARCHAR(255)        NOT NULL COLLATE 'ascii_general_ci',
                file_size    INT(11)             NOT NULL,
                file_created TIMESTAMP           NOT NULL DEFAULT current_timestamp(),
                PRIMARY KEY (file_id),
                UNIQUE KEY msz_storage_files_hash_unique (file_hash),
                KEY msz_storage_files_created_index (file_created),
                KEY msz_storage_files_type_index (file_type),
                KEY msz_storage_files_size_index (file_size)
            ) COLLATE='utf8mb4_bin' ENGINE=InnoDB;
        SQL);

        $conn->execute(<<<SQL
            CREATE TABLE msz_storage_pools (
                pool_id         INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
                pool_name       VARCHAR(32)      NOT NULL              COLLATE 'ascii_general_ci',
                pool_secret     VARCHAR(255)         NULL DEFAULT NULL COLLATE 'ascii_bin',
                pool_created    TIMESTAMP        NOT NULL DEFAULT current_timestamp(),
                pool_deprecated TIMESTAMP            NULL DEFAULT NULL,
                PRIMARY KEY (pool_id),
                UNIQUE KEY msz_storage_pools_name_unique (pool_name),
                KEY msz_storage_pools_created_index (pool_created),
                KEY msz_storage_pools_deprecated_index (pool_deprecated)
            ) COLLATE='utf8mb4_bin' ENGINE=InnoDB;
        SQL);

        $conn->execute(<<<SQL
            CREATE TABLE msz_storage_pools_rules (
                rule_id     INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
                pool_id     INT(10) UNSIGNED NOT NULL,
                rule_type   VARCHAR(64)      NOT NULL              COLLATE 'ascii_general_ci',
                rule_params LONGTEXT         NOT NULL DEFAULT '{}' COLLATE 'utf8mb4_bin',
                PRIMARY KEY (rule_id),
                KEY msz_storage_pools_rules_pool_foreign (pool_id),
                KEY msz_storage_pools_rules_type_index (rule_type),
                CONSTRAINT msz_storage_pools_rules_pool_foreign
                    FOREIGN KEY (pool_id)
                    REFERENCES msz_storage_pools (pool_id)
                    ON UPDATE CASCADE
                    ON DELETE CASCADE,
                CONSTRAINT rule_params
                    CHECK (json_valid(rule_params)),
                CONSTRAINT msz_storage_pools_rules_params_ensure_object
                    CHECK (json_type(rule_params) = 'OBJECT')
            ) COLLATE='utf8mb4_bin' ENGINE=InnoDB;
        SQL);

        $conn->execute(<<<SQL
            CREATE TABLE msz_storage_tasks (
                task_id      BIGINT(20) UNSIGNED NOT NULL,
                task_secret  CHAR(16)            NOT NULL COLLATE 'ascii_bin',
                user_id      INT(10) UNSIGNED    NOT NULL,
                pool_id      INT(10) UNSIGNED    NOT NULL,
                task_state   ENUM('pending','complete','error') NOT NULL DEFAULT 'pending' COLLATE 'ascii_general_ci',
                task_ip      VARBINARY(16)       NOT NULL,
                task_name    VARCHAR(255)        NOT NULL COLLATE 'utf8mb4_unicode_520_ci',
                task_size    INT(10) UNSIGNED    NOT NULL,
                task_type    VARCHAR(255)        NOT NULL COLLATE 'ascii_general_ci',
                task_hash    BINARY(32)          NOT NULL,
                task_error   TEXT                NOT NULL DEFAULT '' COLLATE 'utf8mb4_bin',
                task_created TIMESTAMP           NOT NULL DEFAULT current_timestamp(),
                PRIMARY KEY (task_id),
                KEY msz_storage_tasks_user_foreign (user_id),
                KEY msz_storage_tasks_pool_foreign (pool_id),
                KEY msz_storage_tasks_created_index (task_created),
                KEY msz_storage_tasks_state_index (task_state),
                CONSTRAINT msz_storage_tasks_user_foreign
                    FOREIGN KEY (user_id)
                    REFERENCES msz_users (user_id)
                    ON UPDATE CASCADE
                    ON DELETE CASCADE,
                CONSTRAINT msz_storage_tasks_pool_foreign
                    FOREIGN KEY (pool_id)
                    REFERENCES msz_storage_pools (pool_id)
                    ON UPDATE CASCADE
                    ON DELETE CASCADE
            ) COLLATE='utf8mb4_bin' ENGINE=InnoDB;
        SQL);

        $conn->execute(<<<SQL
            CREATE TABLE msz_storage_uploads (
                upload_id       BIGINT(20) UNSIGNED NOT NULL,
                user_id         INT(10) UNSIGNED    NOT NULL,
                pool_id         INT(10) UNSIGNED    NOT NULL,
                upload_secret   CHAR(4)             NOT NULL COLLATE 'ascii_bin',
                upload_name     VARCHAR(255)        NOT NULL COLLATE 'utf8mb4_unicode_520_ci',
                upload_ip       VARBINARY(16)       NOT NULL,
                upload_created  TIMESTAMP           NOT NULL DEFAULT current_timestamp(),
                upload_accessed TIMESTAMP           NOT NULL DEFAULT current_timestamp(),
                PRIMARY KEY (upload_id),
                KEY msz_storage_uploads_ip_index (upload_ip),
                KEY msz_storage_uploads_created_index (upload_created),
                KEY msz_storage_uploads_accessed_index (upload_accessed),
                KEY msz_storage_uploads_user_foreign (user_id),
                KEY msz_storage_uploads_pool_foreign (pool_id),
                CONSTRAINT msz_storage_uploads_user_foreign
                    FOREIGN KEY (user_id)
                    REFERENCES msz_users (user_id)
                    ON UPDATE CASCADE
                    ON DELETE CASCADE,
                CONSTRAINT msz_storage_uploads_pool_foreign
                    FOREIGN KEY (pool_id)
                    REFERENCES msz_storage_pools (pool_id)
                    ON UPDATE CASCADE
                    ON DELETE CASCADE
            ) COLLATE='utf8mb4_bin' ENGINE=InnoDB;
        SQL);

        $conn->execute(<<<SQL
            CREATE TABLE msz_storage_uploads_files (
                upload_id      BIGINT(20) UNSIGNED NOT NULL,
                upload_variant VARCHAR(255)        NOT NULL              COLLATE 'ascii_general_ci',
                file_id        BIGINT(20) UNSIGNED NOT NULL,
                file_type      VARCHAR(255)            NULL DEFAULT NULL COLLATE 'ascii_general_ci',
                PRIMARY KEY (upload_id, upload_variant),
                KEY msz_storage_uploads_files_upload_foreign (upload_id),
                KEY msz_storage_uploads_files_file_foreign (file_id),
                CONSTRAINT msz_storage_uploads_files_upload_foreign
                    FOREIGN KEY (upload_id)
                    REFERENCES msz_storage_uploads (upload_id)
                    ON UPDATE CASCADE
                    ON DELETE CASCADE,
                CONSTRAINT msz_storage_uploads_files_file_foreign
                    FOREIGN KEY (file_id)
                    REFERENCES msz_storage_files (file_id)
                    ON UPDATE CASCADE
                    ON DELETE RESTRICT
            ) COLLATE='utf8mb4_bin' ENGINE=InnoDB;
        SQL);

        $conn->execute(<<<SQL
            CREATE TABLE msz_storage_uploads_legacy (
                upload_id_legacy BINARY(32)          NOT NULL,
                upload_id        BIGINT(20) UNSIGNED NOT NULL,
                UNIQUE KEY msz_storage_uploads_legacy_unique (upload_id_legacy),
                KEY msz_storage_uploads_legacy_foreign (upload_id),
                CONSTRAINT msz_storage_uploads_legacy_foreign
                    FOREIGN KEY (upload_id)
                    REFERENCES msz_storage_uploads (upload_id)
                    ON UPDATE CASCADE
                    ON DELETE CASCADE
            ) COLLATE='utf8mb4_bin' ENGINE=InnoDB;
        SQL);
    }
}