- Installed and configured SCST with 7 handlers - Installed and configured mhVTL with 2 Quantum libraries and 8 LTO-8 drives - Implemented all VTL API endpoints (8/9 working) - Fixed NULL device_path handling in drives endpoint - Added comprehensive error handling and validation - Implemented async tape load/unload operations - Created SCST installation guide for Ubuntu 24.04 - Created mhVTL installation and configuration guide - Added VTL testing guide and automated test scripts - All core API tests passing (89% success rate) Infrastructure status: - PostgreSQL: Configured with proper permissions - SCST: Active with kernel module loaded - mhVTL: 2 libraries (Quantum Scalar i500, Scalar i40) - mhVTL: 8 drives (all Quantum ULTRIUM-HH8 LTO-8) - Calypso API: 8/9 VTL endpoints functional Documentation added: - src/srs-technical-spec-documents/scst-installation.md - src/srs-technical-spec-documents/mhvtl-installation.md - VTL-TESTING-GUIDE.md - scripts/test-vtl.sh Co-Authored-By: Warp <agent@warp.dev>
214 lines
7.6 KiB
SQL
214 lines
7.6 KiB
SQL
-- AtlasOS - Calypso
|
|
-- Initial Database Schema
|
|
-- Version: 1.0
|
|
|
|
-- Users table
|
|
CREATE TABLE IF NOT EXISTS users (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
username VARCHAR(255) NOT NULL UNIQUE,
|
|
email VARCHAR(255) NOT NULL UNIQUE,
|
|
password_hash VARCHAR(255) NOT NULL,
|
|
full_name VARCHAR(255),
|
|
is_active BOOLEAN NOT NULL DEFAULT true,
|
|
is_system BOOLEAN NOT NULL DEFAULT false,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
last_login_at TIMESTAMP
|
|
);
|
|
|
|
-- Roles table
|
|
CREATE TABLE IF NOT EXISTS roles (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
name VARCHAR(100) NOT NULL UNIQUE,
|
|
description TEXT,
|
|
is_system BOOLEAN NOT NULL DEFAULT false,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Permissions table
|
|
CREATE TABLE IF NOT EXISTS permissions (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
name VARCHAR(255) NOT NULL UNIQUE,
|
|
resource VARCHAR(100) NOT NULL,
|
|
action VARCHAR(100) NOT NULL,
|
|
description TEXT,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- User roles junction table
|
|
CREATE TABLE IF NOT EXISTS user_roles (
|
|
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
role_id UUID NOT NULL REFERENCES roles(id) ON DELETE CASCADE,
|
|
assigned_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
assigned_by UUID REFERENCES users(id),
|
|
PRIMARY KEY (user_id, role_id)
|
|
);
|
|
|
|
-- Role permissions junction table
|
|
CREATE TABLE IF NOT EXISTS role_permissions (
|
|
role_id UUID NOT NULL REFERENCES roles(id) ON DELETE CASCADE,
|
|
permission_id UUID NOT NULL REFERENCES permissions(id) ON DELETE CASCADE,
|
|
granted_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
PRIMARY KEY (role_id, permission_id)
|
|
);
|
|
|
|
-- Sessions table
|
|
CREATE TABLE IF NOT EXISTS sessions (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
token_hash VARCHAR(255) NOT NULL UNIQUE,
|
|
ip_address INET,
|
|
user_agent TEXT,
|
|
expires_at TIMESTAMP NOT NULL,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
last_activity_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Audit log table
|
|
CREATE TABLE IF NOT EXISTS audit_log (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
user_id UUID REFERENCES users(id),
|
|
username VARCHAR(255),
|
|
action VARCHAR(100) NOT NULL,
|
|
resource_type VARCHAR(100) NOT NULL,
|
|
resource_id VARCHAR(255),
|
|
method VARCHAR(10),
|
|
path TEXT,
|
|
ip_address INET,
|
|
user_agent TEXT,
|
|
request_body JSONB,
|
|
response_status INTEGER,
|
|
error_message TEXT,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Tasks table (for async operations)
|
|
CREATE TABLE IF NOT EXISTS tasks (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
type VARCHAR(100) NOT NULL,
|
|
status VARCHAR(50) NOT NULL DEFAULT 'pending',
|
|
progress INTEGER NOT NULL DEFAULT 0,
|
|
message TEXT,
|
|
error_message TEXT,
|
|
created_by UUID REFERENCES users(id),
|
|
started_at TIMESTAMP,
|
|
completed_at TIMESTAMP,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
metadata JSONB
|
|
);
|
|
|
|
-- Alerts table
|
|
CREATE TABLE IF NOT EXISTS alerts (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
severity VARCHAR(20) NOT NULL,
|
|
source VARCHAR(100) NOT NULL,
|
|
title VARCHAR(255) NOT NULL,
|
|
message TEXT NOT NULL,
|
|
resource_type VARCHAR(100),
|
|
resource_id VARCHAR(255),
|
|
is_acknowledged BOOLEAN NOT NULL DEFAULT false,
|
|
acknowledged_by UUID REFERENCES users(id),
|
|
acknowledged_at TIMESTAMP,
|
|
resolved_at TIMESTAMP,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
metadata JSONB
|
|
);
|
|
|
|
-- System configuration table
|
|
CREATE TABLE IF NOT EXISTS system_config (
|
|
key VARCHAR(255) PRIMARY KEY,
|
|
value TEXT NOT NULL,
|
|
description TEXT,
|
|
is_encrypted BOOLEAN NOT NULL DEFAULT false,
|
|
updated_by UUID REFERENCES users(id),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Indexes for performance
|
|
CREATE INDEX IF NOT EXISTS idx_users_username ON users(username);
|
|
CREATE INDEX IF NOT EXISTS idx_users_email ON users(email);
|
|
CREATE INDEX IF NOT EXISTS idx_users_active ON users(is_active);
|
|
CREATE INDEX IF NOT EXISTS idx_sessions_user_id ON sessions(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_sessions_token_hash ON sessions(token_hash);
|
|
CREATE INDEX IF NOT EXISTS idx_sessions_expires_at ON sessions(expires_at);
|
|
CREATE INDEX IF NOT EXISTS idx_audit_log_user_id ON audit_log(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_audit_log_created_at ON audit_log(created_at);
|
|
CREATE INDEX IF NOT EXISTS idx_audit_log_resource ON audit_log(resource_type, resource_id);
|
|
CREATE INDEX IF NOT EXISTS idx_tasks_status ON tasks(status);
|
|
CREATE INDEX IF NOT EXISTS idx_tasks_type ON tasks(type);
|
|
CREATE INDEX IF NOT EXISTS idx_tasks_created_by ON tasks(created_by);
|
|
CREATE INDEX IF NOT EXISTS idx_alerts_severity ON alerts(severity);
|
|
CREATE INDEX IF NOT EXISTS idx_alerts_acknowledged ON alerts(is_acknowledged);
|
|
CREATE INDEX IF NOT EXISTS idx_alerts_created_at ON alerts(created_at);
|
|
|
|
-- Insert default system roles
|
|
INSERT INTO roles (name, description, is_system) VALUES
|
|
('admin', 'Full system access and configuration', true),
|
|
('operator', 'Day-to-day operations and monitoring', true),
|
|
('readonly', 'Read-only access for monitoring and reporting', true)
|
|
ON CONFLICT (name) DO NOTHING;
|
|
|
|
-- Insert default permissions
|
|
INSERT INTO permissions (name, resource, action, description) VALUES
|
|
-- System permissions
|
|
('system:read', 'system', 'read', 'View system information'),
|
|
('system:write', 'system', 'write', 'Modify system configuration'),
|
|
('system:manage', 'system', 'manage', 'Full system management'),
|
|
|
|
-- Storage permissions
|
|
('storage:read', 'storage', 'read', 'View storage information'),
|
|
('storage:write', 'storage', 'write', 'Modify storage configuration'),
|
|
('storage:manage', 'storage', 'manage', 'Full storage management'),
|
|
|
|
-- Tape permissions
|
|
('tape:read', 'tape', 'read', 'View tape library information'),
|
|
('tape:write', 'tape', 'write', 'Perform tape operations'),
|
|
('tape:manage', 'tape', 'manage', 'Full tape management'),
|
|
|
|
-- iSCSI permissions
|
|
('iscsi:read', 'iscsi', 'read', 'View iSCSI configuration'),
|
|
('iscsi:write', 'iscsi', 'write', 'Modify iSCSI configuration'),
|
|
('iscsi:manage', 'iscsi', 'manage', 'Full iSCSI management'),
|
|
|
|
-- IAM permissions
|
|
('iam:read', 'iam', 'read', 'View users and roles'),
|
|
('iam:write', 'iam', 'write', 'Modify users and roles'),
|
|
('iam:manage', 'iam', 'manage', 'Full IAM management'),
|
|
|
|
-- Audit permissions
|
|
('audit:read', 'audit', 'read', 'View audit logs'),
|
|
|
|
-- Monitoring permissions
|
|
('monitoring:read', 'monitoring', 'read', 'View monitoring data'),
|
|
('monitoring:write', 'monitoring', 'write', 'Acknowledge alerts')
|
|
ON CONFLICT (name) DO NOTHING;
|
|
|
|
-- Assign permissions to roles
|
|
-- Admin gets all permissions
|
|
INSERT INTO role_permissions (role_id, permission_id)
|
|
SELECT r.id, p.id
|
|
FROM roles r, permissions p
|
|
WHERE r.name = 'admin'
|
|
ON CONFLICT DO NOTHING;
|
|
|
|
-- Operator gets read and write (but not manage) for most resources
|
|
INSERT INTO role_permissions (role_id, permission_id)
|
|
SELECT r.id, p.id
|
|
FROM roles r, permissions p
|
|
WHERE r.name = 'operator'
|
|
AND p.action IN ('read', 'write')
|
|
AND p.resource IN ('storage', 'tape', 'iscsi', 'monitoring')
|
|
ON CONFLICT DO NOTHING;
|
|
|
|
-- ReadOnly gets only read permissions
|
|
INSERT INTO role_permissions (role_id, permission_id)
|
|
SELECT r.id, p.id
|
|
FROM roles r, permissions p
|
|
WHERE r.name = 'readonly'
|
|
AND p.action = 'read'
|
|
ON CONFLICT DO NOTHING;
|
|
|