-- Clean slate for development SET FOREIGN_KEY_CHECKS = 0; DROP TABLE IF EXISTS audit_logs; DROP TABLE IF EXISTS votes; DROP TABLE IF EXISTS candidates; DROP TABLE IF EXISTS positions; DROP TABLE IF EXISTS election_assignments; DROP TABLE IF EXISTS elections; DROP TABLE IF EXISTS users; SET FOREIGN_KEY_CHECKS = 1; -- Production-Ready Schema for Online Election System CREATE TABLE users ( id CHAR(36) PRIMARY KEY, student_id VARCHAR(10) UNIQUE NOT NULL, -- Format: XX-XXXX name VARCHAR(255) NOT NULL, email VARCHAR(255) UNIQUE NOT NULL, password_hash VARCHAR(255) NOT NULL, grade_level INT NULL, track VARCHAR(100) NULL, section VARCHAR(100) NULL, role ENUM('Admin', 'Adviser', 'Officer', 'Voter') DEFAULT 'Voter', access_level INT DEFAULT 0, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, deleted_at TIMESTAMP NULL ); CREATE TABLE elections ( id CHAR(36) PRIMARY KEY, title VARCHAR(255) NOT NULL, description TEXT, status ENUM('Preparing', 'Ongoing', 'Finished') DEFAULT 'Preparing', start_date_and_time TIMESTAMP NOT NULL, end_date_and_time TIMESTAMP NOT NULL, created_by CHAR(36) NOT NULL, archived BOOLEAN DEFAULT FALSE, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (created_by) REFERENCES users(id) ); CREATE TABLE election_assignments ( id CHAR(36) PRIMARY KEY, election_id CHAR(36) NOT NULL, user_id CHAR(36) NOT NULL, role_in_election ENUM('Adviser', 'Officer', 'Candidate', 'Voter') DEFAULT 'Voter', assigned_by CHAR(36) NOT NULL, assigned_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (election_id) REFERENCES elections(id) ON DELETE CASCADE, FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE, FOREIGN KEY (assigned_by) REFERENCES users(id) ); CREATE TABLE positions ( id CHAR(36) PRIMARY KEY, election_id CHAR(36) NOT NULL, name VARCHAR(255) NOT NULL, max_votes INT DEFAULT 1, sort_order INT DEFAULT 0, FOREIGN KEY (election_id) REFERENCES elections(id) ON DELETE CASCADE ); CREATE TABLE candidates ( id CHAR(36) PRIMARY KEY, election_id CHAR(36) NOT NULL, position_id CHAR(36) NOT NULL, user_id CHAR(36) NOT NULL, party_name VARCHAR(255) NULL, manifesto TEXT NULL, approved BOOLEAN DEFAULT FALSE, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (election_id) REFERENCES elections(id) ON DELETE CASCADE, FOREIGN KEY (position_id) REFERENCES positions(id) ON DELETE CASCADE, FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE ); CREATE TABLE votes ( id CHAR(36) PRIMARY KEY, election_id CHAR(36) NOT NULL, position_id CHAR(36) NOT NULL, candidate_id CHAR(36) NOT NULL, voter_id CHAR(36) NOT NULL, casted_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, ip_address VARCHAR(45), user_agent TEXT, UNIQUE KEY unique_vote (election_id, position_id, voter_id), FOREIGN KEY (election_id) REFERENCES elections(id), FOREIGN KEY (position_id) REFERENCES positions(id), FOREIGN KEY (candidate_id) REFERENCES candidates(id), FOREIGN KEY (voter_id) REFERENCES users(id) ); CREATE TABLE audit_logs ( id CHAR(36) PRIMARY KEY, user_id CHAR(36) NULL, action VARCHAR(255) NOT NULL, table_name VARCHAR(100) NULL, record_id CHAR(36) NULL, old_values TEXT NULL, new_values TEXT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (user_id) REFERENCES users(id) ); -- Insert a default admin (password is 'admin123') INSERT INTO users (id, student_id, name, email, password_hash, role, access_level) VALUES ('admin-uuid-1', '00-0000', 'Admin User', 'admin@school.edu', '$2y$10$92IXUNpkjO0rOQ5byMi.Ye4oKoEa3Ro9llC/.og/at2.uheWG/igi', 'Admin', 4);