93 lines
3.6 KiB
SQL
93 lines
3.6 KiB
SQL
USE emergency_tracker;
|
|
|
|
-- Create managed types table for dynamic fields, departments, and teams.
|
|
CREATE TABLE IF NOT EXISTS managed_types (
|
|
id INT AUTO_INCREMENT PRIMARY KEY,
|
|
type ENUM('field', 'department', 'team') NOT NULL,
|
|
name VARCHAR(100) NOT NULL,
|
|
parent_id INT DEFAULT NULL,
|
|
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
|
UNIQUE KEY uniq_type_name (type, name),
|
|
INDEX idx_managed_parent (parent_id),
|
|
CONSTRAINT fk_managed_parent FOREIGN KEY (parent_id) REFERENCES managed_types(id) ON DELETE RESTRICT
|
|
);
|
|
|
|
-- If managed_types already existed, add hierarchy columns safely.
|
|
SET @parent_exists = (
|
|
SELECT COUNT(*)
|
|
FROM INFORMATION_SCHEMA.COLUMNS
|
|
WHERE TABLE_SCHEMA = DATABASE()
|
|
AND TABLE_NAME = 'managed_types'
|
|
AND COLUMN_NAME = 'parent_id'
|
|
);
|
|
SET @add_parent_sql = IF(@parent_exists = 0, 'ALTER TABLE managed_types ADD COLUMN parent_id INT DEFAULT NULL', 'SELECT 1');
|
|
PREPARE add_parent_stmt FROM @add_parent_sql;
|
|
EXECUTE add_parent_stmt;
|
|
DEALLOCATE PREPARE add_parent_stmt;
|
|
|
|
SET @idx_exists = (
|
|
SELECT COUNT(*)
|
|
FROM INFORMATION_SCHEMA.STATISTICS
|
|
WHERE TABLE_SCHEMA = DATABASE()
|
|
AND TABLE_NAME = 'managed_types'
|
|
AND INDEX_NAME = 'idx_managed_parent'
|
|
);
|
|
SET @add_index_sql = IF(@idx_exists = 0, 'ALTER TABLE managed_types ADD INDEX idx_managed_parent (parent_id)', 'SELECT 1');
|
|
PREPARE add_index_stmt FROM @add_index_sql;
|
|
EXECUTE add_index_stmt;
|
|
DEALLOCATE PREPARE add_index_stmt;
|
|
|
|
SET @fk_exists = (
|
|
SELECT COUNT(*)
|
|
FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE
|
|
WHERE TABLE_SCHEMA = DATABASE()
|
|
AND TABLE_NAME = 'managed_types'
|
|
AND CONSTRAINT_NAME = 'fk_managed_parent'
|
|
);
|
|
SET @add_fk_sql = IF(@fk_exists = 0, 'ALTER TABLE managed_types ADD CONSTRAINT fk_managed_parent FOREIGN KEY (parent_id) REFERENCES managed_types(id) ON DELETE RESTRICT', 'SELECT 1');
|
|
PREPARE add_fk_stmt FROM @add_fk_sql;
|
|
EXECUTE add_fk_stmt;
|
|
DEALLOCATE PREPARE add_fk_stmt;
|
|
|
|
-- Relax enum columns so new values can be inserted dynamically.
|
|
ALTER TABLE users MODIFY COLUMN field VARCHAR(100) DEFAULT NULL;
|
|
ALTER TABLE users MODIFY COLUMN department VARCHAR(100) DEFAULT NULL;
|
|
ALTER TABLE users MODIFY COLUMN team VARCHAR(100) DEFAULT NULL;
|
|
|
|
-- Seed managed types from existing user data.
|
|
INSERT IGNORE INTO managed_types (type, name, parent_id)
|
|
SELECT 'field', field, NULL
|
|
FROM users
|
|
WHERE field IS NOT NULL AND field <> ''
|
|
GROUP BY field;
|
|
|
|
INSERT IGNORE INTO managed_types (type, name, parent_id)
|
|
SELECT 'department', department, field_types.id
|
|
FROM users
|
|
JOIN managed_types field_types
|
|
ON field_types.type = 'field' AND field_types.name = users.field
|
|
WHERE department IS NOT NULL AND department <> ''
|
|
GROUP BY department, field_types.id;
|
|
|
|
INSERT IGNORE INTO managed_types (type, name, parent_id)
|
|
SELECT 'team', team, department_types.id
|
|
FROM users
|
|
JOIN managed_types department_types
|
|
ON department_types.type = 'department' AND department_types.name = users.department
|
|
WHERE team IS NOT NULL AND team <> ''
|
|
GROUP BY team, department_types.id;
|
|
|
|
-- Backfill parent_id for existing managed types if they were created without hierarchy.
|
|
UPDATE managed_types department_types
|
|
JOIN users ON department_types.type = 'department' AND department_types.name = users.department
|
|
JOIN managed_types field_types ON field_types.type = 'field' AND field_types.name = users.field
|
|
SET department_types.parent_id = field_types.id
|
|
WHERE department_types.parent_id IS NULL;
|
|
|
|
UPDATE managed_types team_types
|
|
JOIN users ON team_types.type = 'team' AND team_types.name = users.team
|
|
JOIN managed_types department_types
|
|
ON department_types.type = 'department' AND department_types.name = users.department
|
|
SET team_types.parent_id = department_types.id
|
|
WHERE team_types.parent_id IS NULL;
|