Updated to using managed types instead of
hard coded ones.
This commit is contained in:
16
scripts/README.md
Normal file
16
scripts/README.md
Normal file
@@ -0,0 +1,16 @@
|
||||
# Database Scripts
|
||||
|
||||
Use these scripts in the order that matches your environment.
|
||||
|
||||
Fresh install:
|
||||
1) `scripts/setup-database-user.sql` (optional, run as MySQL root)
|
||||
2) `scripts/schema.sql` (creates tables + default admin user)
|
||||
|
||||
Existing database upgrades:
|
||||
1) `scripts/migrate-managed-types.sql` (adds managed types + hierarchy)
|
||||
|
||||
Maintenance:
|
||||
- `scripts/database-maintenance.sql`
|
||||
|
||||
Archived scripts:
|
||||
- Legacy one-off migrations are in `scripts/archive/` for reference only.
|
||||
2
scripts/archive/README.md
Normal file
2
scripts/archive/README.md
Normal file
@@ -0,0 +1,2 @@
|
||||
These scripts are retained for historical reference.
|
||||
Use `scripts/schema.sql` and `scripts/migrate-managed-types.sql` instead.
|
||||
92
scripts/migrate-managed-types.sql
Normal file
92
scripts/migrate-managed-types.sql
Normal file
@@ -0,0 +1,92 @@
|
||||
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;
|
||||
66
scripts/schema.sql
Normal file
66
scripts/schema.sql
Normal file
@@ -0,0 +1,66 @@
|
||||
CREATE DATABASE IF NOT EXISTS emergency_tracker CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
|
||||
|
||||
USE emergency_tracker;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS users (
|
||||
national_id CHAR(9) PRIMARY KEY,
|
||||
password VARCHAR(255) NOT NULL,
|
||||
name VARCHAR(100) NOT NULL,
|
||||
in_shelter ENUM('yes', 'no', 'no_alarm', 'safe_after_exit') DEFAULT NULL,
|
||||
last_updated DATETIME DEFAULT NULL,
|
||||
is_admin BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
role ENUM('user', 'team_admin', 'department_admin', 'field_admin', 'global_admin') NOT NULL DEFAULT 'user',
|
||||
lock_status BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
must_change_password BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
password_changed_at DATETIME DEFAULT NULL,
|
||||
field VARCHAR(100) DEFAULT NULL,
|
||||
department VARCHAR(100) DEFAULT NULL,
|
||||
team VARCHAR(100) DEFAULT NULL
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS admin_actions (
|
||||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||||
admin_id CHAR(9) NOT NULL,
|
||||
action_type ENUM(
|
||||
'reset_all',
|
||||
'reset_password',
|
||||
'reset_team',
|
||||
'reset_department',
|
||||
'reset_field',
|
||||
'role_change',
|
||||
'report_on_behalf'
|
||||
) NOT NULL,
|
||||
target_user_id CHAR(9) DEFAULT NULL,
|
||||
target_role VARCHAR(50) DEFAULT NULL,
|
||||
timestamp DATETIME DEFAULT CURRENT_TIMESTAMP,
|
||||
FOREIGN KEY (admin_id) REFERENCES users(national_id),
|
||||
FOREIGN KEY (target_user_id) REFERENCES users(national_id)
|
||||
);
|
||||
|
||||
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
|
||||
);
|
||||
|
||||
-- Insert a default admin user (password: "admin123")
|
||||
INSERT IGNORE INTO users (
|
||||
national_id,
|
||||
password,
|
||||
name,
|
||||
is_admin,
|
||||
role,
|
||||
must_change_password
|
||||
) VALUES (
|
||||
'123456782',
|
||||
'$2a$12$LQv3c1yqBWVHxkd0LHAkCOYz6TtxMQJqhN8/LewdBdXzz.JrKIFHy',
|
||||
'Admin',
|
||||
TRUE,
|
||||
'global_admin',
|
||||
FALSE
|
||||
);
|
||||
Reference in New Issue
Block a user