SSO Update :)
This commit is contained in:
17
migrations/001_create_users_table.sql
Normal file
17
migrations/001_create_users_table.sql
Normal file
@@ -0,0 +1,17 @@
|
||||
-- Create users table for SSO integration
|
||||
CREATE TABLE IF NOT EXISTS users (
|
||||
user_id INT AUTO_INCREMENT PRIMARY KEY,
|
||||
username VARCHAR(100) UNIQUE NOT NULL,
|
||||
display_name VARCHAR(255),
|
||||
email VARCHAR(255),
|
||||
groups TEXT,
|
||||
is_admin BOOLEAN DEFAULT FALSE,
|
||||
last_login TIMESTAMP NULL,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
INDEX idx_username (username)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
||||
|
||||
-- Insert system user for hwmonDaemon
|
||||
INSERT INTO users (username, display_name, email, groups, is_admin, created_at)
|
||||
VALUES ('system', 'System', 'system@lotusguild.org', '', FALSE, NOW())
|
||||
ON DUPLICATE KEY UPDATE username = username;
|
||||
15
migrations/002_create_api_keys_table.sql
Normal file
15
migrations/002_create_api_keys_table.sql
Normal file
@@ -0,0 +1,15 @@
|
||||
-- Create API keys table for external service authentication
|
||||
CREATE TABLE IF NOT EXISTS api_keys (
|
||||
api_key_id INT AUTO_INCREMENT PRIMARY KEY,
|
||||
key_name VARCHAR(100) NOT NULL,
|
||||
key_hash VARCHAR(255) UNIQUE NOT NULL,
|
||||
key_prefix VARCHAR(20) NOT NULL,
|
||||
is_active BOOLEAN DEFAULT TRUE,
|
||||
created_by INT,
|
||||
last_used TIMESTAMP NULL,
|
||||
expires_at TIMESTAMP NULL,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
FOREIGN KEY (created_by) REFERENCES users(user_id) ON DELETE SET NULL,
|
||||
INDEX idx_key_hash (key_hash),
|
||||
INDEX idx_is_active (is_active)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
||||
16
migrations/003_create_audit_log_table.sql
Normal file
16
migrations/003_create_audit_log_table.sql
Normal file
@@ -0,0 +1,16 @@
|
||||
-- Create audit log table for tracking all user actions
|
||||
CREATE TABLE IF NOT EXISTS audit_log (
|
||||
audit_id BIGINT AUTO_INCREMENT PRIMARY KEY,
|
||||
user_id INT,
|
||||
action_type VARCHAR(50) NOT NULL,
|
||||
entity_type VARCHAR(50) NOT NULL,
|
||||
entity_id VARCHAR(50),
|
||||
details JSON,
|
||||
ip_address VARCHAR(45),
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
FOREIGN KEY (user_id) REFERENCES users(user_id) ON DELETE SET NULL,
|
||||
INDEX idx_user_id (user_id),
|
||||
INDEX idx_created_at (created_at),
|
||||
INDEX idx_entity (entity_type, entity_id),
|
||||
INDEX idx_action_type (action_type)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
||||
30
migrations/004_alter_tickets_table.sql
Normal file
30
migrations/004_alter_tickets_table.sql
Normal file
@@ -0,0 +1,30 @@
|
||||
-- Add user tracking columns to tickets table
|
||||
ALTER TABLE tickets
|
||||
ADD COLUMN IF NOT EXISTS created_by INT,
|
||||
ADD COLUMN IF NOT EXISTS updated_by INT,
|
||||
ADD COLUMN IF NOT EXISTS updated_at TIMESTAMP NULL;
|
||||
|
||||
-- Add foreign key constraints if they don't exist
|
||||
SET @fk_exists = (SELECT COUNT(*) FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS
|
||||
WHERE CONSTRAINT_NAME = 'fk_tickets_created_by'
|
||||
AND TABLE_NAME = 'tickets'
|
||||
AND TABLE_SCHEMA = DATABASE());
|
||||
|
||||
SET @sql = IF(@fk_exists = 0,
|
||||
'ALTER TABLE tickets ADD CONSTRAINT fk_tickets_created_by FOREIGN KEY (created_by) REFERENCES users(user_id) ON DELETE SET NULL',
|
||||
'SELECT "Foreign key fk_tickets_created_by already exists"');
|
||||
PREPARE stmt FROM @sql;
|
||||
EXECUTE stmt;
|
||||
DEALLOCATE PREPARE stmt;
|
||||
|
||||
SET @fk_exists = (SELECT COUNT(*) FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS
|
||||
WHERE CONSTRAINT_NAME = 'fk_tickets_updated_by'
|
||||
AND TABLE_NAME = 'tickets'
|
||||
AND TABLE_SCHEMA = DATABASE());
|
||||
|
||||
SET @sql = IF(@fk_exists = 0,
|
||||
'ALTER TABLE tickets ADD CONSTRAINT fk_tickets_updated_by FOREIGN KEY (updated_by) REFERENCES users(user_id) ON DELETE SET NULL',
|
||||
'SELECT "Foreign key fk_tickets_updated_by already exists"');
|
||||
PREPARE stmt FROM @sql;
|
||||
EXECUTE stmt;
|
||||
DEALLOCATE PREPARE stmt;
|
||||
19
migrations/005_alter_comments_table.sql
Normal file
19
migrations/005_alter_comments_table.sql
Normal file
@@ -0,0 +1,19 @@
|
||||
-- Add user_id column to ticket_comments table
|
||||
ALTER TABLE ticket_comments
|
||||
ADD COLUMN IF NOT EXISTS user_id INT;
|
||||
|
||||
-- Add foreign key constraint if it doesn't exist
|
||||
SET @fk_exists = (SELECT COUNT(*) FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS
|
||||
WHERE CONSTRAINT_NAME = 'fk_comments_user_id'
|
||||
AND TABLE_NAME = 'ticket_comments'
|
||||
AND TABLE_SCHEMA = DATABASE());
|
||||
|
||||
SET @sql = IF(@fk_exists = 0,
|
||||
'ALTER TABLE ticket_comments ADD CONSTRAINT fk_comments_user_id FOREIGN KEY (user_id) REFERENCES users(user_id) ON DELETE SET NULL',
|
||||
'SELECT "Foreign key fk_comments_user_id already exists"');
|
||||
PREPARE stmt FROM @sql;
|
||||
EXECUTE stmt;
|
||||
DEALLOCATE PREPARE stmt;
|
||||
|
||||
-- Update existing comments to reference jared user (first admin)
|
||||
-- This will be done after jared user is created via web login
|
||||
39
migrations/006_add_indexes.sql
Normal file
39
migrations/006_add_indexes.sql
Normal file
@@ -0,0 +1,39 @@
|
||||
-- Add database indexes for performance optimization
|
||||
-- Check and create index on tickets.status
|
||||
SET @index_exists = (SELECT COUNT(*) FROM INFORMATION_SCHEMA.STATISTICS
|
||||
WHERE TABLE_NAME = 'tickets'
|
||||
AND INDEX_NAME = 'idx_status'
|
||||
AND TABLE_SCHEMA = DATABASE());
|
||||
|
||||
SET @sql = IF(@index_exists = 0,
|
||||
'CREATE INDEX idx_status ON tickets(status)',
|
||||
'SELECT "Index idx_status already exists"');
|
||||
PREPARE stmt FROM @sql;
|
||||
EXECUTE stmt;
|
||||
DEALLOCATE PREPARE stmt;
|
||||
|
||||
-- Check and create index on tickets.priority
|
||||
SET @index_exists = (SELECT COUNT(*) FROM INFORMATION_SCHEMA.STATISTICS
|
||||
WHERE TABLE_NAME = 'tickets'
|
||||
AND INDEX_NAME = 'idx_priority'
|
||||
AND TABLE_SCHEMA = DATABASE());
|
||||
|
||||
SET @sql = IF(@index_exists = 0,
|
||||
'CREATE INDEX idx_priority ON tickets(priority)',
|
||||
'SELECT "Index idx_priority already exists"');
|
||||
PREPARE stmt FROM @sql;
|
||||
EXECUTE stmt;
|
||||
DEALLOCATE PREPARE stmt;
|
||||
|
||||
-- Check and create index on tickets.created_at
|
||||
SET @index_exists = (SELECT COUNT(*) FROM INFORMATION_SCHEMA.STATISTICS
|
||||
WHERE TABLE_NAME = 'tickets'
|
||||
AND INDEX_NAME = 'idx_tickets_created_at'
|
||||
AND TABLE_SCHEMA = DATABASE());
|
||||
|
||||
SET @sql = IF(@index_exists = 0,
|
||||
'CREATE INDEX idx_tickets_created_at ON tickets(created_at)',
|
||||
'SELECT "Index idx_tickets_created_at already exists"');
|
||||
PREPARE stmt FROM @sql;
|
||||
EXECUTE stmt;
|
||||
DEALLOCATE PREPARE stmt;
|
||||
25
migrations/rollback_all.sql
Normal file
25
migrations/rollback_all.sql
Normal file
@@ -0,0 +1,25 @@
|
||||
-- Rollback script to undo all SSO integration changes
|
||||
-- WARNING: This will delete all user data, API keys, and audit logs
|
||||
|
||||
-- Drop foreign keys first
|
||||
ALTER TABLE ticket_comments DROP FOREIGN KEY IF EXISTS fk_comments_user_id;
|
||||
ALTER TABLE tickets DROP FOREIGN KEY IF EXISTS fk_tickets_created_by;
|
||||
ALTER TABLE tickets DROP FOREIGN KEY IF EXISTS fk_tickets_updated_by;
|
||||
ALTER TABLE api_keys DROP FOREIGN KEY IF EXISTS api_keys_ibfk_1;
|
||||
ALTER TABLE audit_log DROP FOREIGN KEY IF EXISTS audit_log_ibfk_1;
|
||||
|
||||
-- Drop columns from existing tables
|
||||
ALTER TABLE ticket_comments DROP COLUMN IF EXISTS user_id;
|
||||
ALTER TABLE tickets DROP COLUMN IF EXISTS created_by;
|
||||
ALTER TABLE tickets DROP COLUMN IF EXISTS updated_by;
|
||||
ALTER TABLE tickets DROP COLUMN IF EXISTS updated_at;
|
||||
|
||||
-- Drop new tables
|
||||
DROP TABLE IF EXISTS audit_log;
|
||||
DROP TABLE IF EXISTS api_keys;
|
||||
DROP TABLE IF EXISTS users;
|
||||
|
||||
-- Drop indexes
|
||||
DROP INDEX IF EXISTS idx_status ON tickets;
|
||||
DROP INDEX IF EXISTS idx_priority ON tickets;
|
||||
DROP INDEX IF EXISTS idx_tickets_created_at ON tickets;
|
||||
107
migrations/run_migrations.php
Normal file
107
migrations/run_migrations.php
Normal file
@@ -0,0 +1,107 @@
|
||||
<?php
|
||||
/**
|
||||
* Database Migration Runner
|
||||
* Executes all migration files in order
|
||||
*/
|
||||
|
||||
error_reporting(E_ALL);
|
||||
ini_set('display_errors', 1);
|
||||
|
||||
// Load environment variables
|
||||
$envFile = dirname(__DIR__) . '/.env';
|
||||
if (!file_exists($envFile)) {
|
||||
die("Error: .env file not found at $envFile\n");
|
||||
}
|
||||
|
||||
$envVars = parse_ini_file($envFile);
|
||||
if (!$envVars) {
|
||||
die("Error: Could not parse .env file\n");
|
||||
}
|
||||
|
||||
// Connect to database
|
||||
$conn = new mysqli(
|
||||
$envVars['DB_HOST'],
|
||||
$envVars['DB_USER'],
|
||||
$envVars['DB_PASS'],
|
||||
$envVars['DB_NAME']
|
||||
);
|
||||
|
||||
if ($conn->connect_error) {
|
||||
die("Database connection failed: " . $conn->connect_error . "\n");
|
||||
}
|
||||
|
||||
echo "Connected to database: {$envVars['DB_NAME']}\n\n";
|
||||
|
||||
// Get all migration files
|
||||
$migrationFiles = glob(__DIR__ . '/*.sql');
|
||||
sort($migrationFiles);
|
||||
|
||||
// Filter out rollback script
|
||||
$migrationFiles = array_filter($migrationFiles, function($file) {
|
||||
return !strpos($file, 'rollback');
|
||||
});
|
||||
|
||||
if (empty($migrationFiles)) {
|
||||
echo "No migration files found.\n";
|
||||
exit(0);
|
||||
}
|
||||
|
||||
echo "Found " . count($migrationFiles) . " migration(s):\n";
|
||||
foreach ($migrationFiles as $file) {
|
||||
echo " - " . basename($file) . "\n";
|
||||
}
|
||||
echo "\n";
|
||||
|
||||
// Execute each migration
|
||||
$successCount = 0;
|
||||
$errorCount = 0;
|
||||
|
||||
foreach ($migrationFiles as $file) {
|
||||
$filename = basename($file);
|
||||
echo "Executing: $filename... ";
|
||||
|
||||
$sql = file_get_contents($file);
|
||||
|
||||
// Split SQL into individual statements
|
||||
// This handles multi-statement migrations
|
||||
if ($conn->multi_query($sql)) {
|
||||
do {
|
||||
// Store first result set
|
||||
if ($result = $conn->store_result()) {
|
||||
$result->free();
|
||||
}
|
||||
// Check for errors
|
||||
if ($conn->errno) {
|
||||
echo "FAILED\n";
|
||||
echo " Error: " . $conn->error . "\n";
|
||||
$errorCount++;
|
||||
break;
|
||||
}
|
||||
} while ($conn->more_results() && $conn->next_result());
|
||||
|
||||
// If we got through all results without error
|
||||
if (!$conn->errno) {
|
||||
echo "OK\n";
|
||||
$successCount++;
|
||||
}
|
||||
} else {
|
||||
echo "FAILED\n";
|
||||
echo " Error: " . $conn->error . "\n";
|
||||
$errorCount++;
|
||||
}
|
||||
}
|
||||
|
||||
echo "\n";
|
||||
echo "Migration Summary:\n";
|
||||
echo " Success: $successCount\n";
|
||||
echo " Errors: $errorCount\n";
|
||||
|
||||
if ($errorCount > 0) {
|
||||
echo "\nSome migrations failed. Please review errors above.\n";
|
||||
exit(1);
|
||||
} else {
|
||||
echo "\nAll migrations completed successfully!\n";
|
||||
exit(0);
|
||||
}
|
||||
|
||||
$conn->close();
|
||||
Reference in New Issue
Block a user