921 lines
45 KiB
JavaScript
921 lines
45 KiB
JavaScript
const mysql = require('mysql2/promise');
|
||
require('dotenv').config();
|
||
const fs = require('fs');
|
||
const path = require('path');
|
||
|
||
const NODE_ENV = process.env.NODE_ENV || 'development';
|
||
|
||
const getSSLConfig = () => {
|
||
const useSSL = String(process.env.DB_SSL || '').toLowerCase() === 'true';
|
||
const caPath = process.env.DB_SSL_CA_PATH;
|
||
if (!useSSL) return undefined;
|
||
|
||
try {
|
||
if (caPath) {
|
||
const resolved = path.resolve(caPath);
|
||
if (fs.existsSync(resolved)) {
|
||
console.log('🔐 (createDb) Loading DB CA certificate from:', resolved);
|
||
return {
|
||
ca: fs.readFileSync(resolved),
|
||
rejectUnauthorized: false
|
||
};
|
||
} else {
|
||
console.warn('⚠️ (createDb) CA file not found at:', resolved, '- proceeding with rejectUnauthorized:false');
|
||
}
|
||
} else {
|
||
console.warn('⚠️ (createDb) DB_SSL_CA_PATH not set - proceeding with rejectUnauthorized:false');
|
||
}
|
||
} catch (e) {
|
||
console.warn('⚠️ (createDb) Failed to load CA file:', e.message, '- proceeding with rejectUnauthorized:false');
|
||
}
|
||
return { rejectUnauthorized: false };
|
||
};
|
||
|
||
let dbConfig;
|
||
if (NODE_ENV === 'development') {
|
||
dbConfig = {
|
||
host: process.env.DEV_DB_HOST || 'localhost',
|
||
port: Number(process.env.DEV_DB_PORT) || 3306,
|
||
user: process.env.DEV_DB_USER || 'root',
|
||
password: process.env.DEV_DB_PASSWORD || '', // XAMPP default: no password
|
||
database: process.env.DEV_DB_NAME || 'profitplanet_centralserver',
|
||
ssl: undefined
|
||
};
|
||
} else {
|
||
dbConfig = {
|
||
host: process.env.DB_HOST,
|
||
port: Number(process.env.DB_PORT) || 3306,
|
||
user: process.env.DB_USER,
|
||
password: process.env.DB_PASSWORD,
|
||
database: process.env.DB_NAME,
|
||
ssl: getSSLConfig()
|
||
};
|
||
}
|
||
|
||
const allowCreateDb = String(process.env.DB_ALLOW_CREATE_DB || 'false').toLowerCase() === 'true';
|
||
|
||
// --- Performance Helpers (added) ---
|
||
async function ensureIndex(conn, table, indexName, indexDDL) {
|
||
const [rows] = await conn.query(`SHOW INDEX FROM \`${table}\` WHERE Key_name = ?`, [indexName]);
|
||
if (!rows.length) {
|
||
await conn.query(`CREATE INDEX \`${indexName}\` ON \`${table}\` (${indexDDL})`);
|
||
console.log(`🆕 Created index ${indexName} ON ${table}`);
|
||
} else {
|
||
console.log(`ℹ️ Index ${indexName} already exists on ${table}`);
|
||
}
|
||
}
|
||
|
||
async function createDatabase() {
|
||
console.log('🚀 Starting MySQL database initialization...');
|
||
console.log('📍 Database host:', process.env.DB_HOST);
|
||
console.log('📍 Database name:', process.env.DB_NAME);
|
||
|
||
let connection;
|
||
try {
|
||
if (allowCreateDb) {
|
||
// Connect without specifying a database to create it if it doesn't exist
|
||
connection = await mysql.createConnection({
|
||
host: dbConfig.host,
|
||
port: dbConfig.port,
|
||
user: dbConfig.user,
|
||
password: dbConfig.password,
|
||
ssl: dbConfig.ssl
|
||
});
|
||
|
||
await connection.query(`CREATE DATABASE IF NOT EXISTS \`${dbConfig.database}\`;`);
|
||
console.log(`✅ Database "${dbConfig.database}" created/verified`);
|
||
await connection.end();
|
||
} else {
|
||
console.log('ℹ️ Skipping database creation (DB_ALLOW_CREATE_DB=false)');
|
||
}
|
||
|
||
// Reconnect with the database specified
|
||
connection = await mysql.createConnection(dbConfig);
|
||
console.log('✅ Connected to MySQL database');
|
||
|
||
// --- Core Tables ---
|
||
|
||
// 1. users table: Central user authentication and common attributes
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS users (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
email VARCHAR(255) UNIQUE NOT NULL,
|
||
password VARCHAR(255) NOT NULL,
|
||
user_type ENUM('personal', 'company') NOT NULL,
|
||
role ENUM('user', 'admin', 'super_admin') DEFAULT 'user',
|
||
iban VARCHAR(34),
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
last_login_at TIMESTAMP NULL,
|
||
INDEX idx_email (email),
|
||
INDEX idx_user_type (user_type),
|
||
INDEX idx_role (role)
|
||
);
|
||
`);
|
||
console.log('✅ Users table created/verified');
|
||
|
||
// 2. personal_profiles table: Details specific to personal users
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS personal_profiles (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
user_id INT NOT NULL,
|
||
first_name VARCHAR(255) NOT NULL,
|
||
last_name VARCHAR(255) NOT NULL,
|
||
phone VARCHAR(255) NULL,
|
||
date_of_birth DATE,
|
||
nationality VARCHAR(255),
|
||
address TEXT,
|
||
zip_code VARCHAR(20),
|
||
city VARCHAR(100),
|
||
country VARCHAR(100),
|
||
phone_secondary VARCHAR(255),
|
||
emergency_contact_name VARCHAR(255),
|
||
emergency_contact_phone VARCHAR(255),
|
||
account_holder_name VARCHAR(255),
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
UNIQUE KEY unique_user_profile (user_id)
|
||
);
|
||
`);
|
||
console.log('✅ Personal profiles table created/verified');
|
||
|
||
// 3. company_profiles table: Details specific to company users
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS company_profiles (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
user_id INT NOT NULL,
|
||
company_name VARCHAR(255) NOT NULL,
|
||
registration_number VARCHAR(255) UNIQUE,
|
||
phone VARCHAR(255) NULL,
|
||
address TEXT,
|
||
zip_code VARCHAR(20),
|
||
city VARCHAR(100),
|
||
country VARCHAR(100),
|
||
branch VARCHAR(255),
|
||
number_of_employees INT,
|
||
business_type VARCHAR(255),
|
||
contact_person_name VARCHAR(255),
|
||
contact_person_phone VARCHAR(255),
|
||
account_holder_name VARCHAR(255),
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
UNIQUE KEY unique_user_profile (user_id),
|
||
UNIQUE KEY unique_registration_number (registration_number)
|
||
);
|
||
`);
|
||
console.log('✅ Company profiles table created/verified');
|
||
|
||
// 4. user_status table: Comprehensive tracking of user verification and completion steps
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS user_status (
|
||
user_id INT PRIMARY KEY,
|
||
status ENUM('inactive', 'pending', 'active', 'suspended', 'archived') DEFAULT 'pending',
|
||
previous_status ENUM('inactive', 'pending', 'active', 'suspended', 'archived') NULL,
|
||
email_verified BOOLEAN DEFAULT FALSE,
|
||
email_verified_at TIMESTAMP NULL,
|
||
profile_completed BOOLEAN DEFAULT FALSE,
|
||
profile_completed_at TIMESTAMP NULL,
|
||
documents_uploaded BOOLEAN DEFAULT FALSE,
|
||
documents_uploaded_at TIMESTAMP NULL,
|
||
contract_signed BOOLEAN DEFAULT FALSE,
|
||
contract_signed_at TIMESTAMP NULL,
|
||
is_admin_verified BOOLEAN DEFAULT FALSE,
|
||
admin_verified_at TIMESTAMP NULL,
|
||
registration_completed BOOLEAN DEFAULT FALSE,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE
|
||
);
|
||
`);
|
||
console.log('✅ User status table created/verified');
|
||
|
||
// Modify existing ENUM columns to add 'archived' status (for existing databases)
|
||
try {
|
||
await connection.query(`
|
||
ALTER TABLE user_status
|
||
MODIFY COLUMN status ENUM('inactive', 'pending', 'active', 'suspended', 'archived') DEFAULT 'pending'
|
||
`);
|
||
console.log('✅ Updated status column to include archived');
|
||
} catch (err) {
|
||
console.warn('⚠️ Could not modify status column:', err.message);
|
||
}
|
||
|
||
try {
|
||
await connection.query(`
|
||
ALTER TABLE user_status
|
||
MODIFY COLUMN previous_status ENUM('inactive', 'pending', 'active', 'suspended', 'archived') NULL
|
||
`);
|
||
console.log('✅ Updated previous_status column to include archived');
|
||
} catch (err) {
|
||
console.warn('⚠️ Could not modify previous_status column:', err.message);
|
||
}
|
||
|
||
// --- Authentication & Verification Tables ---
|
||
|
||
// 5. refresh_tokens table: For refresh token authentication
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS refresh_tokens (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
user_id INT NOT NULL,
|
||
token VARCHAR(255) UNIQUE NOT NULL,
|
||
expires_at DATETIME NOT NULL,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
revoked_at TIMESTAMP NULL,
|
||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
INDEX idx_user_id (user_id),
|
||
INDEX idx_expires_at (expires_at)
|
||
);
|
||
`);
|
||
console.log('✅ Refresh tokens table created/verified');
|
||
|
||
// 6. email_verifications table: For email verification codes
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS email_verifications (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
user_id INT NOT NULL,
|
||
verification_code VARCHAR(6) NOT NULL,
|
||
expires_at DATETIME NOT NULL,
|
||
verified_at TIMESTAMP NULL,
|
||
attempts INT DEFAULT 0,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
INDEX idx_user_code (user_id, verification_code),
|
||
INDEX idx_expires_at (expires_at)
|
||
);
|
||
`);
|
||
console.log('✅ Email verifications table created/verified');
|
||
|
||
// 7. password_resets table: For password reset tokens
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS password_resets (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
user_id INT NOT NULL,
|
||
token VARCHAR(255) UNIQUE NOT NULL,
|
||
expires_at DATETIME NOT NULL,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
used_at TIMESTAMP NULL,
|
||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
INDEX idx_user_token (user_id, token),
|
||
INDEX idx_expires_at (expires_at)
|
||
);
|
||
`);
|
||
console.log('✅ Password resets table created/verified');
|
||
|
||
// --- Document & Logging Tables ---
|
||
|
||
// 8. user_documents table: Stores object storage IDs
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS user_documents (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
user_id INT NOT NULL,
|
||
document_type ENUM('personal_id', 'company_id', 'signature', 'contract', 'other') NOT NULL,
|
||
object_storage_id VARCHAR(255) UNIQUE NOT NULL,
|
||
original_filename VARCHAR(255),
|
||
file_size INT,
|
||
mime_type VARCHAR(100),
|
||
upload_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
verified_by_admin BOOLEAN DEFAULT FALSE,
|
||
admin_verified_at TIMESTAMP NULL,
|
||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
INDEX idx_user_document_type (user_id, document_type),
|
||
INDEX idx_object_storage_id (object_storage_id)
|
||
);
|
||
`);
|
||
console.log('✅ User documents table created/verified');
|
||
|
||
// 8c. document_templates table: Stores template metadata and object storage keys
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS document_templates (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
name VARCHAR(255) NOT NULL,
|
||
type VARCHAR(100) NOT NULL,
|
||
storageKey VARCHAR(255) NOT NULL,
|
||
description TEXT,
|
||
lang VARCHAR(10) NOT NULL,
|
||
user_type ENUM('personal','company','both') DEFAULT 'both',
|
||
version INT DEFAULT 1,
|
||
state ENUM('active','inactive') DEFAULT 'inactive',
|
||
createdAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updatedAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP
|
||
);
|
||
`);
|
||
console.log('✅ Document templates table created/verified');
|
||
|
||
// 8b. user_id_documents table: Stores ID-specific metadata (front/back object storage IDs)
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS user_id_documents (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
user_id INT NOT NULL,
|
||
document_type ENUM('personal_id', 'company_id') NOT NULL,
|
||
front_object_storage_id VARCHAR(255) NOT NULL,
|
||
back_object_storage_id VARCHAR(255) NULL,
|
||
original_filename_front VARCHAR(255),
|
||
original_filename_back VARCHAR(255),
|
||
id_type VARCHAR(50),
|
||
id_number VARCHAR(100),
|
||
expiry_date DATE,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE
|
||
);
|
||
`);
|
||
console.log('✅ User ID documents table created/verified');
|
||
|
||
// 9. user_action_logs table: For detailed user activity logging
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS user_action_logs (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
user_id INT NULL,
|
||
affected_user_id INT NULL,
|
||
action VARCHAR(100) NOT NULL,
|
||
performed_by_user_id INT NULL,
|
||
details JSON,
|
||
ip_address VARCHAR(45),
|
||
user_agent TEXT,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE SET NULL ON UPDATE CASCADE, -- NEW FK
|
||
FOREIGN KEY (affected_user_id) REFERENCES users(id) ON DELETE SET NULL ON UPDATE CASCADE,
|
||
FOREIGN KEY (performed_by_user_id) REFERENCES users(id) ON DELETE SET NULL ON UPDATE CASCADE,
|
||
INDEX idx_user_id (user_id), -- NEW index
|
||
INDEX idx_affected_user (affected_user_id),
|
||
INDEX idx_performed_by (performed_by_user_id),
|
||
INDEX idx_action (action),
|
||
INDEX idx_created_at (created_at)
|
||
);
|
||
`);
|
||
console.log('✅ User action logs table created/verified');
|
||
|
||
// --- Add missing user_id column for existing databases + backfill ---
|
||
try {
|
||
// Add column if missing
|
||
await connection.query(`ALTER TABLE user_action_logs ADD COLUMN user_id INT NULL`);
|
||
console.log('🆕 Added user_action_logs.user_id column');
|
||
|
||
// Add FK if just added
|
||
try {
|
||
await connection.query(`
|
||
ALTER TABLE user_action_logs
|
||
ADD CONSTRAINT fk_user_action_logs_user
|
||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE SET NULL ON UPDATE CASCADE
|
||
`);
|
||
console.log('🆕 Added FK fk_user_action_logs_user');
|
||
} catch (e) {
|
||
console.log('ℹ️ FK fk_user_action_logs_user already exists or cannot add:', e.message);
|
||
}
|
||
|
||
// Add index if missing
|
||
try {
|
||
await connection.query(`CREATE INDEX idx_user_id ON user_action_logs (user_id)`);
|
||
console.log('🆕 Added index idx_user_id on user_action_logs.user_id');
|
||
} catch (e) {
|
||
console.log('ℹ️ idx_user_id already exists or cannot add:', e.message);
|
||
}
|
||
|
||
// Backfill: prefer performed_by_user_id, else affected_user_id
|
||
try {
|
||
const [res1] = await connection.query(`
|
||
UPDATE user_action_logs
|
||
SET user_id = performed_by_user_id
|
||
WHERE user_id IS NULL AND performed_by_user_id IS NOT NULL
|
||
`);
|
||
const [res2] = await connection.query(`
|
||
UPDATE user_action_logs
|
||
SET user_id = affected_user_id
|
||
WHERE user_id IS NULL AND affected_user_id IS NOT NULL
|
||
`);
|
||
console.log('🧹 Backfilled user_action_logs.user_id from performed_by_user_id/affected_user_id');
|
||
} catch (e) {
|
||
console.warn('⚠️ Could not backfill user_action_logs.user_id:', e.message);
|
||
}
|
||
} catch (e) {
|
||
// Column may already exist; ignore
|
||
if (!/Duplicate column name|exists/i.test(e.message)) {
|
||
console.log('ℹ️ user_action_logs.user_id add skipped or not required:', e.message);
|
||
} else {
|
||
console.log('ℹ️ user_action_logs.user_id already exists');
|
||
}
|
||
}
|
||
|
||
// --- Email & Registration Flow Tables ---
|
||
|
||
// 10. email_attempts table: For tracking email sending attempts
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS email_attempts (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
user_id INT NOT NULL,
|
||
attempt_type ENUM('verification', 'password_reset', 'registration_completion', 'notification', 'other') NOT NULL,
|
||
email_address VARCHAR(255) NOT NULL,
|
||
success BOOLEAN DEFAULT FALSE,
|
||
error_message TEXT,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
INDEX idx_user_attempts (user_id, attempt_type),
|
||
INDEX idx_created_at (created_at)
|
||
);
|
||
`);
|
||
console.log('✅ Email attempts table created/verified');
|
||
|
||
// --- Referral Tables ---
|
||
|
||
// 12. referral_tokens table: Manages referral codes
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS referral_tokens (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
token VARCHAR(64) UNIQUE NOT NULL,
|
||
created_by_user_id INT NOT NULL,
|
||
expires_at DATETIME NOT NULL,
|
||
max_uses INT DEFAULT -1,
|
||
uses_remaining INT DEFAULT -1,
|
||
status ENUM('active', 'inactive', 'expired', 'exhausted') DEFAULT 'active',
|
||
deactivation_reason VARCHAR(50),
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
FOREIGN KEY (created_by_user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
INDEX idx_token (token),
|
||
INDEX idx_status_expires (status, expires_at),
|
||
INDEX idx_created_by (created_by_user_id)
|
||
);
|
||
`);
|
||
|
||
// News table for News Manager
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS news (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
title VARCHAR(255) NOT NULL,
|
||
summary TEXT NULL,
|
||
content MEDIUMTEXT NULL,
|
||
slug VARCHAR(255) UNIQUE NOT NULL,
|
||
category VARCHAR(128) NULL,
|
||
object_storage_id VARCHAR(255) NULL,
|
||
original_filename VARCHAR(255) NULL,
|
||
is_active TINYINT(1) NOT NULL DEFAULT 1,
|
||
published_at DATETIME NULL,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP
|
||
);
|
||
`);
|
||
console.log('✅ News table created/verified');
|
||
console.log('✅ Referral tokens table created/verified');
|
||
|
||
// 13. referral_token_usage table: Tracks each use of a referral token
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS referral_token_usage (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
referral_token_id INT NOT NULL,
|
||
used_by_user_id INT NOT NULL,
|
||
used_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
FOREIGN KEY (referral_token_id) REFERENCES referral_tokens(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
FOREIGN KEY (used_by_user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
UNIQUE KEY unique_token_user_usage (referral_token_id, used_by_user_id),
|
||
INDEX idx_token_usage (referral_token_id),
|
||
INDEX idx_user_usage (used_by_user_id)
|
||
);
|
||
`);
|
||
console.log('✅ Referral token usage table created/verified');
|
||
|
||
// --- Authorization Tables ---
|
||
|
||
// 14. permissions table: Defines granular permissions
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS permissions (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
name VARCHAR(100) UNIQUE NOT NULL,
|
||
description VARCHAR(255),
|
||
is_active BOOLEAN DEFAULT TRUE,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, -- Added
|
||
created_by INT NULL, -- Added
|
||
FOREIGN KEY (created_by) REFERENCES users(id) ON DELETE SET NULL ON UPDATE CASCADE
|
||
);
|
||
`);
|
||
console.log('✅ Permissions table created/verified');
|
||
|
||
// 15. user_permissions join table: Assigns specific permissions to users
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS user_permissions (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
user_id INT NOT NULL,
|
||
permission_id INT NOT NULL,
|
||
granted_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
granted_by INT NULL, -- Added column
|
||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
FOREIGN KEY (permission_id) REFERENCES permissions(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
FOREIGN KEY (granted_by) REFERENCES users(id) ON DELETE SET NULL ON UPDATE CASCADE, -- FK constraint
|
||
UNIQUE KEY unique_user_permission (user_id, permission_id)
|
||
);
|
||
`);
|
||
console.log('✅ User permissions table created/verified');
|
||
|
||
// --- User Settings Table ---
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS user_settings (
|
||
user_id INT PRIMARY KEY,
|
||
theme ENUM('light', 'dark') DEFAULT 'light',
|
||
font_size ENUM('normal', 'large') DEFAULT 'normal',
|
||
high_contrast_mode BOOLEAN DEFAULT FALSE,
|
||
two_factor_auth_enabled BOOLEAN DEFAULT FALSE,
|
||
account_visibility ENUM('public', 'private') DEFAULT 'public',
|
||
show_email BOOLEAN DEFAULT TRUE,
|
||
show_phone BOOLEAN DEFAULT TRUE,
|
||
data_export_requested BOOLEAN DEFAULT FALSE,
|
||
last_data_export_at TIMESTAMP NULL,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE
|
||
);
|
||
`);
|
||
console.log('✅ User settings table created/verified');
|
||
|
||
// --- Rate Limiting Table ---
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS rate_limit (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
rate_key VARCHAR(255) NOT NULL,
|
||
window_start DATETIME NOT NULL,
|
||
count INT DEFAULT 0,
|
||
window_seconds INT NOT NULL,
|
||
max INT NOT NULL,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
UNIQUE KEY unique_key_window (rate_key, window_start)
|
||
);
|
||
`);
|
||
console.log('✅ Rate limit table created/verified');
|
||
|
||
// --- Tax: countries and VAT rates ---
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS countries (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
country_code VARCHAR(3) NOT NULL,
|
||
country_name VARCHAR(255) NOT NULL,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
created_by INT NULL,
|
||
updated_by INT NULL,
|
||
CONSTRAINT uq_country_code UNIQUE (country_code),
|
||
INDEX idx_country_name (country_name),
|
||
FOREIGN KEY (created_by) REFERENCES users(id) ON DELETE SET NULL ON UPDATE CASCADE,
|
||
FOREIGN KEY (updated_by) REFERENCES users(id) ON DELETE SET NULL ON UPDATE CASCADE
|
||
);
|
||
`);
|
||
console.log('✅ Countries table created/verified');
|
||
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS vat_rates (
|
||
id BIGINT AUTO_INCREMENT PRIMARY KEY,
|
||
country_id INT NOT NULL,
|
||
standard_rate DECIMAL(6,3) NULL,
|
||
reduced_rate DECIMAL(6,3) NULL,
|
||
super_reduced_rate DECIMAL(6,3) NULL,
|
||
parking_rate DECIMAL(6,3) NULL,
|
||
effective_from DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
effective_to DATETIME NULL,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
created_by INT NULL,
|
||
updated_by INT NULL,
|
||
FOREIGN KEY (country_id) REFERENCES countries(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
FOREIGN KEY (created_by) REFERENCES users(id) ON DELETE SET NULL ON UPDATE CASCADE,
|
||
FOREIGN KEY (updated_by) REFERENCES users(id) ON DELETE SET NULL ON UPDATE CASCADE,
|
||
INDEX idx_vat_country_eff_to (country_id, effective_to),
|
||
INDEX idx_vat_standard (standard_rate)
|
||
);
|
||
`);
|
||
console.log('✅ VAT rates table created/verified');
|
||
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS vat_rate_history (
|
||
id BIGINT AUTO_INCREMENT PRIMARY KEY,
|
||
country_id INT NOT NULL,
|
||
standard_rate DECIMAL(6,3) NULL,
|
||
reduced_rate DECIMAL(6,3) NULL,
|
||
super_reduced_rate DECIMAL(6,3) NULL,
|
||
parking_rate DECIMAL(6,3) NULL,
|
||
effective_from DATETIME NOT NULL,
|
||
effective_to DATETIME NULL,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
created_by INT NULL,
|
||
updated_by INT NULL,
|
||
FOREIGN KEY (country_id) REFERENCES countries(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
FOREIGN KEY (created_by) REFERENCES users(id) ON DELETE SET NULL ON UPDATE CASCADE,
|
||
FOREIGN KEY (updated_by) REFERENCES users(id) ON DELETE SET NULL ON UPDATE CASCADE,
|
||
INDEX idx_vat_hist_country_from (country_id, effective_from),
|
||
INDEX idx_vat_hist_country_to (country_id, effective_to)
|
||
);
|
||
`);
|
||
console.log('✅ VAT rate history table created/verified');
|
||
|
||
// --- NEW: company_stamps table (for company/admin managed stamps) ---
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS company_stamps (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
company_id INT NOT NULL,
|
||
label VARCHAR(100) NULL,
|
||
mime_type VARCHAR(50) NOT NULL,
|
||
image_base64 LONGTEXT NOT NULL,
|
||
is_active BOOLEAN DEFAULT FALSE,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
FOREIGN KEY (company_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
UNIQUE KEY unique_company_label (company_id, label),
|
||
INDEX idx_company_active (company_id, is_active)
|
||
);
|
||
`);
|
||
console.log('✅ Company stamps table created/verified');
|
||
|
||
// --- Coffee / Subscriptions Table (simplified) ---
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS coffee_table (
|
||
id BIGINT AUTO_INCREMENT PRIMARY KEY,
|
||
title VARCHAR(200) NOT NULL,
|
||
description TEXT NOT NULL,
|
||
price DECIMAL(10,2) NOT NULL DEFAULT 0.00,
|
||
currency CHAR(3) NOT NULL DEFAULT 'EUR',
|
||
is_featured BOOLEAN NOT NULL DEFAULT FALSE,
|
||
billing_interval ENUM('day','week','month','year') NULL,
|
||
interval_count INT UNSIGNED NULL,
|
||
object_storage_id VARCHAR(255) NULL,
|
||
original_filename VARCHAR(255) NULL,
|
||
state BOOLEAN NOT NULL DEFAULT TRUE,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP
|
||
);
|
||
`);
|
||
console.log('✅ Coffee table (simplified) created/verified');
|
||
|
||
// --- Pools Table ---
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS pools (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
pool_name VARCHAR(255) NOT NULL,
|
||
description TEXT,
|
||
price DECIMAL(10,2) NOT NULL DEFAULT 0.00,
|
||
pool_type ENUM('coffee', 'other') NOT NULL DEFAULT 'other',
|
||
is_active BOOLEAN DEFAULT TRUE,
|
||
created_by INT NULL,
|
||
updated_by INT NULL,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
FOREIGN KEY (created_by) REFERENCES users(id) ON DELETE SET NULL ON UPDATE CASCADE,
|
||
FOREIGN KEY (updated_by) REFERENCES users(id) ON DELETE SET NULL ON UPDATE CASCADE,
|
||
INDEX idx_pool_type (pool_type),
|
||
INDEX idx_is_active (is_active)
|
||
);
|
||
`);
|
||
console.log('✅ Pools table created/verified');
|
||
|
||
// --- Affiliates Table ---
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS affiliates (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
name VARCHAR(255) NOT NULL,
|
||
description TEXT,
|
||
url VARCHAR(512) NOT NULL,
|
||
object_storage_id VARCHAR(255) NULL,
|
||
original_filename VARCHAR(255) NULL,
|
||
category VARCHAR(100) NOT NULL,
|
||
is_active BOOLEAN DEFAULT TRUE,
|
||
commission_rate VARCHAR(50),
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
INDEX idx_category (category),
|
||
INDEX idx_is_active (is_active)
|
||
);
|
||
`);
|
||
console.log('✅ Affiliates table created/verified');
|
||
|
||
// --- Matrix: Global 5-ary tree config and relations ---
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS matrix_config (
|
||
id TINYINT PRIMARY KEY DEFAULT 1,
|
||
master_top_user_id INT NOT NULL,
|
||
name VARCHAR(255) NULL, -- ADDED (was missing, caused Unknown column 'name')
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
CONSTRAINT fk_matrix_config_master FOREIGN KEY (master_top_user_id) REFERENCES users(id) ON DELETE RESTRICT ON UPDATE CASCADE,
|
||
CONSTRAINT chk_matrix_singleton CHECK (id = 1)
|
||
);
|
||
`);
|
||
// Safeguard: if table pre-existed without name column, add it
|
||
try {
|
||
await connection.query(`ALTER TABLE matrix_config ADD COLUMN name VARCHAR(255) NULL`);
|
||
console.log('🆕 Added missing matrix_config.name column');
|
||
} catch (e) {
|
||
if (!/Duplicate column/i.test(e.message)) {
|
||
console.log('ℹ️ matrix_config.name alter skipped:', e.message);
|
||
}
|
||
}
|
||
console.log('✅ Matrix config table created/verified');
|
||
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS user_tree_edges (
|
||
id BIGINT AUTO_INCREMENT PRIMARY KEY,
|
||
parent_user_id INT NOT NULL,
|
||
child_user_id INT NOT NULL,
|
||
position INT NOT NULL, -- CHANGED: allow unlimited positions
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
CONSTRAINT fk_edges_parent FOREIGN KEY (parent_user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
CONSTRAINT fk_edges_child FOREIGN KEY (child_user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
CONSTRAINT uq_child UNIQUE (child_user_id),
|
||
CONSTRAINT uq_parent_position UNIQUE (parent_user_id, position)
|
||
-- REMOVED: chk_position CHECK (position BETWEEN 1 AND 5)
|
||
);
|
||
`);
|
||
console.log('✅ User tree edges table created/verified');
|
||
|
||
// --- Migration: relax position constraints on existing schemas ---
|
||
try {
|
||
await connection.query(`ALTER TABLE user_tree_edges MODIFY COLUMN position INT NOT NULL`);
|
||
console.log('🛠️ user_tree_edges.position changed to INT');
|
||
} catch (e) {
|
||
console.log('ℹ️ position type change skipped:', e.message);
|
||
}
|
||
try {
|
||
await connection.query(`ALTER TABLE user_tree_edges DROP CHECK chk_position`);
|
||
console.log('🧹 Dropped CHECK constraint chk_position on user_tree_edges');
|
||
} catch (e) {
|
||
// MySQL versions or engines may report different messages if CHECK is not enforced or named differently
|
||
console.log('ℹ️ DROP CHECK chk_position skipped:', e.message);
|
||
}
|
||
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS matrix_instances (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
root_user_id INT NOT NULL,
|
||
name VARCHAR(255) NULL,
|
||
is_active BOOLEAN DEFAULT TRUE,
|
||
max_depth INT NULL,
|
||
ego_activated_at TIMESTAMP NULL,
|
||
immediate_children_count INT DEFAULT 0,
|
||
first_free_position TINYINT NULL,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
CONSTRAINT fk_matrix_instances_root FOREIGN KEY (root_user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
CONSTRAINT chk_first_free_pos CHECK (first_free_position IS NULL OR (first_free_position BETWEEN 1 AND 5))
|
||
);
|
||
`);
|
||
console.log('✅ matrix_instances table created/verified');
|
||
|
||
// Legacy: ensure legacy matrix_config exists (still needed short-term for migration)
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS matrix_config (
|
||
id TINYINT PRIMARY KEY DEFAULT 1,
|
||
master_top_user_id INT NOT NULL,
|
||
name VARCHAR(255) NULL,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
CONSTRAINT fk_matrix_config_master FOREIGN KEY (master_top_user_id) REFERENCES users(id) ON DELETE RESTRICT ON UPDATE CASCADE
|
||
);
|
||
`);
|
||
console.log('ℹ️ matrix_config (legacy) verified');
|
||
|
||
// --- user_matrix_metadata: add matrix_instance_id + alter PK ---
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS user_matrix_metadata (
|
||
matrix_instance_id INT PRIMARY KEY,
|
||
root_user_id INT NOT NULL,
|
||
ego_activated_at TIMESTAMP NULL,
|
||
last_bfs_fill_at TIMESTAMP NULL,
|
||
immediate_children_count INT DEFAULT 0,
|
||
first_free_position TINYINT NULL,
|
||
name VARCHAR(255) NULL,
|
||
is_active BOOLEAN DEFAULT TRUE,
|
||
max_depth INT NULL,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||
CONSTRAINT fk_meta_instance FOREIGN KEY (matrix_instance_id) REFERENCES matrix_instances(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
CONSTRAINT fk_meta_root FOREIGN KEY (root_user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
CONSTRAINT chk_meta_first_free CHECK (first_free_position IS NULL OR (first_free_position BETWEEN 1 AND 5)),
|
||
INDEX idx_meta_root (root_user_id)
|
||
);
|
||
`);
|
||
console.log('✅ user_matrix_metadata (multi) created/verified');
|
||
|
||
// Migration: if legacy data without matrix_instances rows
|
||
const [instCheck] = await connection.query(`SELECT COUNT(*) AS cnt FROM matrix_instances`);
|
||
if (Number(instCheck[0].cnt) === 0) {
|
||
const [legacyCfg] = await connection.query(`SELECT master_top_user_id, name FROM matrix_config WHERE id=1`);
|
||
if (legacyCfg.length) {
|
||
const legacyRoot = legacyCfg[0].master_top_user_id;
|
||
const legacyName = legacyCfg[0].name || null;
|
||
// Determine existing root children stats
|
||
const [legacyEdges] = await connection.query(`SELECT position FROM user_tree_edges WHERE parent_user_id = ?`, [legacyRoot]);
|
||
const usedRootPos = new Set(legacyEdges.map(r => Number(r.position)));
|
||
let firstFree = null;
|
||
for (let i = 1; i <= 5; i++) { if (!usedRootPos.has(i)) { firstFree = i; break; } }
|
||
// Create initial instance
|
||
const [instRes] = await connection.query(`
|
||
INSERT INTO matrix_instances
|
||
(root_user_id, name, is_active, max_depth, ego_activated_at, immediate_children_count, first_free_position)
|
||
VALUES (?, ?, TRUE, NULL, NOW(), ?, NULL) -- CHANGED: first_free_position NULL for root
|
||
`, [legacyRoot, legacyName, legacyEdges.length, /* firstFree removed */ null]);
|
||
const firstInstanceId = instRes.insertId;
|
||
// Backfill metadata
|
||
await connection.query(`
|
||
INSERT INTO user_matrix_metadata
|
||
(matrix_instance_id, root_user_id, ego_activated_at, immediate_children_count, first_free_position, name, is_active, max_depth)
|
||
VALUES (?, ?, NOW(), ?, ?, ?, TRUE, NULL)
|
||
`, [firstInstanceId, legacyRoot, legacyEdges.length, firstFree, legacyName]);
|
||
console.log('🧩 Migration: created first matrix_instance id=', firstInstanceId);
|
||
}
|
||
}
|
||
|
||
// --- Legacy cleanup: remove old matrix_id / fk_edges_matrix referencing obsolete `matrices` table ---
|
||
try {
|
||
const [legacyCols] = await connection.query(`SHOW COLUMNS FROM user_tree_edges LIKE 'matrix_id'`);
|
||
if (legacyCols.length) {
|
||
console.log('🧹 Found legacy user_tree_edges.matrix_id; dropping old FK & column');
|
||
try { await connection.query(`ALTER TABLE user_tree_edges DROP FOREIGN KEY fk_edges_matrix`); } catch (e) {
|
||
console.log('ℹ️ fk_edges_matrix drop skipped:', e.message);
|
||
}
|
||
try { await connection.query(`ALTER TABLE user_tree_edges DROP COLUMN matrix_id`); } catch (e) {
|
||
console.log('ℹ️ matrix_id column drop skipped:', e.message);
|
||
}
|
||
}
|
||
} catch (e) {
|
||
console.log('ℹ️ Legacy matrix_id cleanup check failed:', e.message);
|
||
}
|
||
|
||
// --- Ensure multi-instance columns (idempotent) ---
|
||
try { await connection.query(`ALTER TABLE user_tree_edges ADD COLUMN matrix_instance_id INT NULL`); } catch (_) {}
|
||
try { await connection.query(`ALTER TABLE user_tree_edges ADD COLUMN rogue_user BOOLEAN DEFAULT FALSE`); } catch (_) {}
|
||
try {
|
||
await connection.query(`
|
||
ALTER TABLE user_tree_edges
|
||
ADD CONSTRAINT fk_edges_instance FOREIGN KEY (matrix_instance_id)
|
||
REFERENCES matrix_instances(id) ON DELETE CASCADE ON UPDATE CASCADE
|
||
`);
|
||
console.log('🆕 FK fk_edges_instance added');
|
||
} catch (e) {
|
||
console.log('ℹ️ fk_edges_instance already exists or failed:', e.message);
|
||
}
|
||
|
||
// Backfill matrix_instance_id for existing edges
|
||
const [firstInstRow] = await connection.query(`SELECT id FROM matrix_instances ORDER BY id ASC LIMIT 1`);
|
||
const firstInstanceId = firstInstRow[0]?.id;
|
||
if (firstInstanceId) {
|
||
await connection.query(`UPDATE user_tree_edges SET matrix_instance_id = ? WHERE matrix_instance_id IS NULL`, [firstInstanceId]);
|
||
}
|
||
|
||
// Indexes (idempotent)
|
||
try { await connection.query(`CREATE INDEX idx_edges_instance_parent ON user_tree_edges (matrix_instance_id, parent_user_id)`); } catch (_) {}
|
||
try { await connection.query(`CREATE INDEX idx_edges_instance_child ON user_tree_edges (matrix_instance_id, child_user_id)`); } catch (_) {}
|
||
try { await connection.query(`CREATE INDEX idx_edges_rogue ON user_tree_edges (matrix_instance_id, rogue_user)`); } catch (_) {}
|
||
|
||
// --- Alter user_tree_closure: add matrix_instance_id ---
|
||
await connection.query(`
|
||
CREATE TABLE IF NOT EXISTS user_tree_closure (
|
||
matrix_instance_id INT NOT NULL,
|
||
ancestor_user_id INT NOT NULL,
|
||
descendant_user_id INT NOT NULL,
|
||
depth INT NOT NULL,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
CONSTRAINT pk_closure PRIMARY KEY (matrix_instance_id, ancestor_user_id, descendant_user_id),
|
||
CONSTRAINT fk_closure_instance FOREIGN KEY (matrix_instance_id) REFERENCES matrix_instances(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
CONSTRAINT fk_closure_ancestor FOREIGN KEY (ancestor_user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
CONSTRAINT fk_closure_descendant FOREIGN KEY (descendant_user_id) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
CONSTRAINT chk_depth_nonneg CHECK (depth >= 0)
|
||
);
|
||
`);
|
||
console.log('✅ user_tree_closure (multi) created/verified');
|
||
|
||
// If legacy closure rows without matrix_instance_id (older separate table definition), attempt add column & backfill
|
||
try {
|
||
await connection.query(`ALTER TABLE user_tree_closure ADD COLUMN matrix_instance_id INT NOT NULL`);
|
||
console.log('🆕 Added matrix_instance_id column to existing user_tree_closure');
|
||
} catch (e) {
|
||
// already integrated new definition
|
||
}
|
||
if (firstInstanceId) {
|
||
try {
|
||
await connection.query(`UPDATE user_tree_closure SET matrix_instance_id = ? WHERE matrix_instance_id IS NULL`, [firstInstanceId]);
|
||
console.log('🧩 Backfilled closure matrix_instance_id');
|
||
} catch (e) {
|
||
console.log('ℹ️ Closure backfill skipped:', e.message);
|
||
}
|
||
}
|
||
try { await connection.query(`CREATE INDEX idx_closure_instance_depth ON user_tree_closure (matrix_instance_id, depth)`); } catch (_) {}
|
||
try { await connection.query(`CREATE INDEX idx_closure_instance_ancestor ON user_tree_closure (matrix_instance_id, ancestor_user_id)`); } catch (_) {}
|
||
|
||
// Remove singleton constraint if present (best effort)
|
||
try {
|
||
await connection.query(`ALTER TABLE matrix_config DROP CHECK chk_matrix_singleton`);
|
||
console.log('🧹 Dropped chk_matrix_singleton');
|
||
} catch (e) {
|
||
console.log('ℹ️ chk_matrix_singleton drop skipped:', e.message);
|
||
}
|
||
|
||
console.log('🎉 Normalized database schema created/updated successfully!');
|
||
|
||
await connection.end();
|
||
return true;
|
||
|
||
} catch (error) {
|
||
console.error('💥 Error during database initialization:', error.message);
|
||
if (connection) {
|
||
await connection.end();
|
||
}
|
||
throw error;
|
||
}
|
||
}
|
||
|
||
module.exports = { createDatabase };
|