133 lines
5.0 KiB
SQL
133 lines
5.0 KiB
SQL
-- Initialize the NextGen PPR database
|
|
-- This script creates the tables based on the existing schema but with improvements
|
|
|
|
-- Enable foreign key checks
|
|
SET FOREIGN_KEY_CHECKS = 1;
|
|
|
|
-- Users table with improved structure
|
|
CREATE TABLE users (
|
|
id INT AUTO_INCREMENT PRIMARY KEY,
|
|
username VARCHAR(50) NOT NULL UNIQUE,
|
|
password VARCHAR(255) NOT NULL,
|
|
role ENUM('ADMINISTRATOR','OPERATOR','READ_ONLY') NOT NULL DEFAULT 'READ_ONLY',
|
|
email VARCHAR(128),
|
|
full_name VARCHAR(100),
|
|
is_active BOOLEAN DEFAULT TRUE,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
|
INDEX idx_username (username),
|
|
INDEX idx_email (email)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
|
|
|
|
-- Main PPR submissions table with improvements
|
|
CREATE TABLE submitted (
|
|
id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY,
|
|
status ENUM('NEW','CONFIRMED','CANCELED','LANDED','DELETED','DEPARTED') NOT NULL DEFAULT 'NEW',
|
|
ac_reg VARCHAR(16) NOT NULL,
|
|
ac_type VARCHAR(32) NOT NULL,
|
|
ac_call VARCHAR(16) DEFAULT NULL,
|
|
captain VARCHAR(64) NOT NULL,
|
|
fuel VARCHAR(16) DEFAULT NULL,
|
|
in_from VARCHAR(64) NOT NULL,
|
|
eta DATETIME NOT NULL,
|
|
pob_in INT NOT NULL,
|
|
out_to VARCHAR(64) DEFAULT NULL,
|
|
etd DATETIME DEFAULT NULL,
|
|
pob_out INT DEFAULT NULL,
|
|
email VARCHAR(128) DEFAULT NULL,
|
|
phone VARCHAR(16) DEFAULT NULL,
|
|
notes TEXT DEFAULT NULL,
|
|
landed_dt DATETIME DEFAULT NULL,
|
|
departed_dt DATETIME DEFAULT NULL,
|
|
created_by VARCHAR(16) DEFAULT NULL,
|
|
submitted_dt TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
public_token VARCHAR(128) DEFAULT NULL UNIQUE,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
|
|
|
-- Indexes for better performance
|
|
INDEX idx_status (status),
|
|
INDEX idx_eta (eta),
|
|
INDEX idx_etd (etd),
|
|
INDEX idx_ac_reg (ac_reg),
|
|
INDEX idx_submitted_dt (submitted_dt),
|
|
INDEX idx_created_by (created_by),
|
|
INDEX idx_public_token (public_token)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
|
|
|
|
-- Activity journal table with foreign key
|
|
CREATE TABLE journal (
|
|
id BIGINT AUTO_INCREMENT PRIMARY KEY,
|
|
ppr_id BIGINT UNSIGNED NOT NULL,
|
|
entry TEXT NOT NULL,
|
|
user VARCHAR(50) NOT NULL,
|
|
ip VARCHAR(45) NOT NULL, -- IPv6 compatible
|
|
entry_dt TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
|
|
INDEX idx_ppr_id (ppr_id),
|
|
INDEX idx_entry_dt (entry_dt),
|
|
INDEX idx_user (user),
|
|
|
|
FOREIGN KEY (ppr_id) REFERENCES submitted(id) ON DELETE CASCADE
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
|
|
|
|
-- Airports reference table with proper structure
|
|
CREATE TABLE airports (
|
|
id INT AUTO_INCREMENT PRIMARY KEY,
|
|
icao VARCHAR(4) NOT NULL,
|
|
iata VARCHAR(3) DEFAULT NULL,
|
|
name VARCHAR(255) NOT NULL,
|
|
country VARCHAR(100) NOT NULL,
|
|
city VARCHAR(100) DEFAULT NULL,
|
|
timezone VARCHAR(50) DEFAULT NULL,
|
|
latitude DECIMAL(10, 8) DEFAULT NULL,
|
|
longitude DECIMAL(11, 8) DEFAULT NULL,
|
|
elevation INT DEFAULT NULL,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
|
|
UNIQUE KEY unique_icao (icao),
|
|
INDEX idx_iata (iata),
|
|
INDEX idx_country (country),
|
|
INDEX idx_name (name)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
|
|
|
|
-- Aircraft reference table with improved structure
|
|
CREATE TABLE aircraft (
|
|
id INT AUTO_INCREMENT PRIMARY KEY,
|
|
icao24 VARCHAR(6) DEFAULT NULL,
|
|
registration VARCHAR(25) DEFAULT NULL,
|
|
manufacturer_icao VARCHAR(50) DEFAULT NULL,
|
|
type_code VARCHAR(30) DEFAULT NULL,
|
|
manufacturer_name VARCHAR(255) DEFAULT NULL,
|
|
model VARCHAR(255) DEFAULT NULL,
|
|
clean_reg VARCHAR(25) GENERATED ALWAYS AS (UPPER(REPLACE(REPLACE(registration, '-', ''), ' ', ''))) STORED,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
|
|
|
INDEX idx_registration (registration),
|
|
INDEX idx_clean_reg (clean_reg),
|
|
INDEX idx_icao24 (icao24),
|
|
INDEX idx_type_code (type_code)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
|
|
|
|
-- Insert default admin user (password: admin123)
|
|
-- Password hash for 'admin123' using bcrypt
|
|
INSERT INTO users (username, password, role, email, full_name) VALUES
|
|
('admin', '$2b$12$BJOha2yRxkxuHL./BaMfpu2fMDgGMYISuRV2.B1sSklVpRjz3Y4a6', 'ADMINISTRATOR', 'admin@ppr.local', 'System Administrator');
|
|
|
|
-- Create a view for active PPRs
|
|
CREATE VIEW active_pprs AS
|
|
SELECT
|
|
s.*,
|
|
af.name as arrival_airport_name,
|
|
df.name as departure_airport_name,
|
|
ac.manufacturer_name,
|
|
ac.model
|
|
FROM submitted s
|
|
LEFT JOIN airports af ON s.in_from = af.icao OR s.in_from = af.iata
|
|
LEFT JOIN airports df ON s.out_to = df.icao OR s.out_to = df.iata
|
|
LEFT JOIN aircraft ac ON s.ac_reg = ac.registration
|
|
WHERE s.status != 'DELETED';
|
|
|
|
-- Create indexes for the view performance
|
|
-- ALTER TABLE submitted ADD INDEX idx_in_from (in_from);
|
|
-- ALTER TABLE submitted ADD INDEX idx_out_to (out_to); |