-- init.sql CREATE DATABASE IF NOT EXISTS forms_db; USE forms_db; -- Users table for authentication and authorization CREATE TABLE IF NOT EXISTS `users` ( `id` INTEGER PRIMARY KEY AUTOINCREMENT, `uuid` TEXT NOT NULL UNIQUE, `email` TEXT NOT NULL UNIQUE, `password_hash` TEXT NOT NULL, `first_name` TEXT DEFAULT NULL, `last_name` TEXT DEFAULT NULL, `role` TEXT DEFAULT 'user' CHECK(`role` IN ('user', 'admin', 'super_admin')), `is_verified` INTEGER DEFAULT 0, `is_active` INTEGER DEFAULT 1, `verification_token` TEXT DEFAULT NULL, `password_reset_token` TEXT DEFAULT NULL, `password_reset_expires` DATETIME NULL DEFAULT NULL, `last_login` DATETIME NULL DEFAULT NULL, `failed_login_attempts` INTEGER DEFAULT 0, `account_locked_until` DATETIME NULL DEFAULT NULL, `must_change_password` INTEGER DEFAULT 0, `created_at` DATETIME DEFAULT CURRENT_TIMESTAMP, `updated_at` DATETIME DEFAULT CURRENT_TIMESTAMP, UNIQUE (`email`), UNIQUE (`uuid`) ); CREATE INDEX IF NOT EXISTS `idx_email` ON `users` (`email`); CREATE INDEX IF NOT EXISTS `idx_verification_token` ON `users` (`verification_token`); CREATE INDEX IF NOT EXISTS `idx_password_reset_token` ON `users` (`password_reset_token`); CREATE INDEX IF NOT EXISTS `idx_uuid_users` ON `users` (`uuid`); -- User sessions table for JWT blacklisting and session management CREATE TABLE IF NOT EXISTS `user_sessions` ( `id` INTEGER PRIMARY KEY AUTOINCREMENT, `user_id` INTEGER NOT NULL, `token_jti` TEXT NOT NULL UNIQUE, `expires_at` DATETIME NOT NULL, `created_at` DATETIME DEFAULT CURRENT_TIMESTAMP, `user_agent` TEXT DEFAULT NULL, `ip_address` TEXT DEFAULT NULL, FOREIGN KEY (`user_id`) REFERENCES `users`(`id`) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS `idx_token_jti` ON `user_sessions` (`token_jti`); CREATE INDEX IF NOT EXISTS `idx_user_id_sessions` ON `user_sessions` (`user_id`); CREATE INDEX IF NOT EXISTS `idx_expires_at_sessions` ON `user_sessions` (`expires_at`); -- Update forms table to associate with users CREATE TABLE IF NOT EXISTS `forms` ( `id` INTEGER PRIMARY KEY AUTOINCREMENT, `uuid` TEXT NOT NULL UNIQUE, `user_id` INTEGER NOT NULL, `name` TEXT DEFAULT 'My Form', `created_at` DATETIME DEFAULT CURRENT_TIMESTAMP, `updated_at` DATETIME DEFAULT CURRENT_TIMESTAMP, `thank_you_url` TEXT DEFAULT NULL, `thank_you_message` TEXT DEFAULT NULL, `ntfy_enabled` INTEGER DEFAULT 1, `is_archived` INTEGER DEFAULT 0, `allowed_domains` TEXT DEFAULT NULL, `email_notifications_enabled` INTEGER NOT NULL DEFAULT 0, `notification_email_address` TEXT DEFAULT NULL, `recaptcha_enabled` INTEGER NOT NULL DEFAULT 0, FOREIGN KEY (`user_id`) REFERENCES `users`(`id`) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS `idx_user_id_forms` ON `forms` (`user_id`); CREATE INDEX IF NOT EXISTS `idx_uuid_forms` ON `forms` (`uuid`); CREATE TABLE IF NOT EXISTS `submissions` ( `id` INTEGER PRIMARY KEY AUTOINCREMENT, `form_uuid` TEXT NOT NULL, `user_id` INTEGER NOT NULL, `data` TEXT NOT NULL, -- Storing JSON as TEXT `ip_address` TEXT NULL, `submitted_at` DATETIME DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (`form_uuid`) REFERENCES `forms`(`uuid`) ON DELETE CASCADE, FOREIGN KEY (`user_id`) REFERENCES `users`(`id`) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS `idx_form_uuid_submissions` ON `submissions` (`form_uuid`); CREATE INDEX IF NOT EXISTS `idx_user_id_submissions` ON `submissions` (`user_id`); CREATE INDEX IF NOT EXISTS `idx_submitted_at_submissions` ON `submissions` (`submitted_at`); -- Rate limiting table for enhanced security (Simplified for SQLite) -- Note: TIMESTAMP logic for window_start and expires_at might need application-level management -- depending on how it was used with MySQL. CREATE TABLE IF NOT EXISTS `rate_limits` ( `id` INTEGER PRIMARY KEY AUTOINCREMENT, `identifier` TEXT NOT NULL, `action` TEXT NOT NULL, `count` INTEGER DEFAULT 1, `window_start` DATETIME DEFAULT CURRENT_TIMESTAMP, `expires_at` DATETIME NOT NULL, UNIQUE (`identifier`, `action`) ); CREATE INDEX IF NOT EXISTS `idx_identifier_action_rate_limits` ON `rate_limits` (`identifier`, `action`); CREATE INDEX IF NOT EXISTS `idx_expires_at_rate_limits` ON `rate_limits` (`expires_at`); -- Create default admin user (password will be set on first login) -- You should change this immediately after first login INSERT OR IGNORE INTO users (email, password_hash, first_name, last_name, role, is_verified, is_active, must_change_password, uuid) VALUES ('admin@formies.local', 'NEEDS_TO_BE_SET_ON_FIRST_LOGIN', 'Admin', 'User', 'super_admin', 1, 1, 1, 'a0eebc99-9c0b-4ef8-bb6d-6bb9bd380a11'); -- Placeholder UUID, generate dynamically in app if needed -- API Keys table for user-generated API access CREATE TABLE IF NOT EXISTS `api_keys` ( `id` INTEGER PRIMARY KEY AUTOINCREMENT, `uuid` TEXT NOT NULL UNIQUE, `user_id` INTEGER NOT NULL, `key_name` TEXT DEFAULT NULL, `api_key_identifier` TEXT NOT NULL UNIQUE, -- Public, non-secret identifier for lookup `hashed_api_key_secret` TEXT NOT NULL, -- Hashed version of the secret part of the API key `created_at` DATETIME DEFAULT CURRENT_TIMESTAMP, `last_used_at` DATETIME NULL DEFAULT NULL, `expires_at` DATETIME NULL DEFAULT NULL, -- For future use FOREIGN KEY (`user_id`) REFERENCES `users`(`id`) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS `idx_user_id_api_keys` ON `api_keys` (`user_id`); CREATE INDEX IF NOT EXISTS `idx_api_key_identifier_api_keys` ON `api_keys` (`api_key_identifier`); -- Trigger to update 'updated_at' timestamp on users table (optional, can be handled in app code) CREATE TRIGGER IF NOT EXISTS update_users_updated_at AFTER UPDATE ON users FOR EACH ROW BEGIN UPDATE users SET updated_at = CURRENT_TIMESTAMP WHERE id = OLD.id; END; -- Trigger to update 'updated_at' timestamp on forms table (optional, can be handled in app code) CREATE TRIGGER IF NOT EXISTS update_forms_updated_at AFTER UPDATE ON forms FOR EACH ROW BEGIN UPDATE forms SET updated_at = CURRENT_TIMESTAMP WHERE id = OLD.id; END;