/** * Database Layer using better-sqlite3 * Synchronous, simpler, and faster than callback-based sqlite3 */ const Database = require('better-sqlite3'); const config = require('./config'); class DatacenterDB { constructor() { this.db = null; } /** * Initialize database connection and schema */ init() { // Open database connection this.db = new Database(config.database.path); // Configure database if (config.database.walMode) { this.db.pragma('journal_mode = WAL'); } if (config.database.foreignKeys) { this.db.pragma('foreign_keys = ON'); } if (config.database.busyTimeout) { this.db.pragma(`busy_timeout = ${config.database.busyTimeout}`); } console.log('Connected to SQLite database with better-sqlite3'); // Create schema this.createTables(); this.seedDeviceTypes(); this.ensureDefaultProject(); return this; } /** * Create all database tables */ createTables() { this.db.exec(` CREATE TABLE IF NOT EXISTS projects ( id INTEGER PRIMARY KEY AUTOINCREMENT, name TEXT NOT NULL UNIQUE, description TEXT, created_at DATETIME DEFAULT CURRENT_TIMESTAMP, updated_at DATETIME DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS racks ( id INTEGER PRIMARY KEY AUTOINCREMENT, project_id INTEGER NOT NULL, name TEXT NOT NULL, x REAL NOT NULL, y REAL NOT NULL, width REAL DEFAULT ${config.rack.defaultWidth}, height REAL DEFAULT ${config.rack.defaultHeight}, created_at DATETIME DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (project_id) REFERENCES projects(id) ON DELETE CASCADE, UNIQUE(project_id, name) ); CREATE TABLE IF NOT EXISTS device_types ( id INTEGER PRIMARY KEY AUTOINCREMENT, name TEXT NOT NULL UNIQUE, ports_count INTEGER NOT NULL DEFAULT 24, color TEXT DEFAULT '#4A90E2', rack_units INTEGER DEFAULT 1 ); CREATE TABLE IF NOT EXISTS devices ( id INTEGER PRIMARY KEY AUTOINCREMENT, device_type_id INTEGER NOT NULL, rack_id INTEGER NOT NULL, project_id INTEGER NOT NULL, position INTEGER NOT NULL, name TEXT NOT NULL, rack_units INTEGER DEFAULT 1, logical_x REAL, logical_y REAL, created_at DATETIME DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (device_type_id) REFERENCES device_types(id), FOREIGN KEY (rack_id) REFERENCES racks(id) ON DELETE CASCADE, FOREIGN KEY (project_id) REFERENCES projects(id) ON DELETE CASCADE, UNIQUE(project_id, name) ); CREATE TABLE IF NOT EXISTS connections ( id INTEGER PRIMARY KEY AUTOINCREMENT, source_device_id INTEGER NOT NULL, source_port INTEGER NOT NULL, target_device_id INTEGER NOT NULL, target_port INTEGER NOT NULL, waypoints_physical TEXT, waypoints_logical TEXT, created_at DATETIME DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (source_device_id) REFERENCES devices(id) ON DELETE CASCADE, FOREIGN KEY (target_device_id) REFERENCES devices(id) ON DELETE CASCADE, UNIQUE(source_device_id, source_port), UNIQUE(target_device_id, target_port) ); CREATE INDEX IF NOT EXISTS idx_racks_project ON racks(project_id); CREATE INDEX IF NOT EXISTS idx_devices_rack ON devices(rack_id); CREATE INDEX IF NOT EXISTS idx_devices_project ON devices(project_id); CREATE INDEX IF NOT EXISTS idx_devices_type ON devices(device_type_id); CREATE INDEX IF NOT EXISTS idx_connections_source ON connections(source_device_id); CREATE INDEX IF NOT EXISTS idx_connections_target ON connections(target_device_id); `); console.log('Database schema created'); } /** * Seed device types with defaults */ seedDeviceTypes() { const insert = this.db.prepare(` INSERT OR IGNORE INTO device_types (name, ports_count, color, rack_units) VALUES (?, ?, ?, ?) `); const insertMany = this.db.transaction((types) => { for (const type of types) { insert.run(type.name, type.portsCount, type.color, type.rackUnits); } }); insertMany(config.deviceTypes); console.log('Device types seeded'); } /** * Ensure default project exists */ ensureDefaultProject() { const insert = this.db.prepare(` INSERT OR IGNORE INTO projects (id, name, description) VALUES (1, ?, ?) `); insert.run('Default Project', 'Default datacenter project'); console.log('Default project ensured'); } // ==================== PROJECT OPERATIONS ==================== getAllProjects() { return this.db.prepare('SELECT * FROM projects ORDER BY updated_at DESC').all(); } getProject(id) { return this.db.prepare('SELECT * FROM projects WHERE id = ?').get(id); } createProject(name, description = '') { const stmt = this.db.prepare('INSERT INTO projects (name, description) VALUES (?, ?)'); const info = stmt.run(name, description); return { id: info.lastInsertRowid, name, description }; } updateProject(id, name, description) { const stmt = this.db.prepare(` UPDATE projects SET name = ?, description = ?, updated_at = CURRENT_TIMESTAMP WHERE id = ? `); stmt.run(name, description, id); } deleteProject(id) { // Check if this is the last project const count = this.db.prepare('SELECT COUNT(*) as count FROM projects').get(); if (count.count <= 1) { throw new Error('Cannot delete the last project'); } const stmt = this.db.prepare('DELETE FROM projects WHERE id = ?'); stmt.run(id); } // ==================== RACK OPERATIONS ==================== getAllRacks(projectId) { return this.db.prepare('SELECT * FROM racks WHERE project_id = ? ORDER BY name').all(projectId); } createRack(projectId, name, x, y) { const stmt = this.db.prepare(` INSERT INTO racks (project_id, name, x, y) VALUES (?, ?, ?, ?) `); const info = stmt.run(projectId, name, x, y); // Fetch and return the complete rack data return this.db.prepare('SELECT * FROM racks WHERE id = ?').get(info.lastInsertRowid); } updateRackPosition(id, x, y) { const stmt = this.db.prepare('UPDATE racks SET x = ?, y = ? WHERE id = ?'); stmt.run(x, y, id); } updateRackName(id, name) { const stmt = this.db.prepare('UPDATE racks SET name = ? WHERE id = ?'); stmt.run(name, id); } deleteRack(id) { const stmt = this.db.prepare('DELETE FROM racks WHERE id = ?'); stmt.run(id); } getNextRackName(projectId, prefix = 'RACK') { const racks = this.db.prepare(` SELECT name FROM racks WHERE project_id = ? AND name LIKE ? ORDER BY name DESC LIMIT 1 `).all(projectId, `${prefix}%`); if (racks.length === 0) { return `${prefix}01`; } // Extract number from last rack name const lastNum = parseInt(racks[0].name.replace(prefix, '')) || 0; const nextNum = (lastNum + 1).toString().padStart(2, '0'); return `${prefix}${nextNum}`; } // ==================== DEVICE TYPE OPERATIONS ==================== getAllDeviceTypes() { return this.db.prepare('SELECT * FROM device_types ORDER BY name').all(); } // ==================== DEVICE OPERATIONS ==================== getAllDevices(projectId) { return this.db.prepare(` SELECT d.*, dt.name as type_name, dt.ports_count, dt.color FROM devices d JOIN device_types dt ON d.device_type_id = dt.id JOIN racks r ON d.rack_id = r.id WHERE r.project_id = ? ORDER BY d.rack_id, d.position `).all(projectId); } createDevice(deviceTypeId, rackId, projectId, position, name) { // Get rack_units from device_type const deviceType = this.db.prepare('SELECT rack_units FROM device_types WHERE id = ?').get(deviceTypeId); const rackUnits = deviceType ? deviceType.rack_units : 1; const stmt = this.db.prepare(` INSERT INTO devices (device_type_id, rack_id, project_id, position, name, rack_units) VALUES (?, ?, ?, ?, ?, ?) `); const info = stmt.run(deviceTypeId, rackId, projectId, position, name, rackUnits); return { id: info.lastInsertRowid }; } deleteDevice(id) { const stmt = this.db.prepare('DELETE FROM devices WHERE id = ?'); stmt.run(id); } updateDeviceRack(id, rackId, position) { // Get project_id from the new rack const rack = this.db.prepare('SELECT project_id FROM racks WHERE id = ?').get(rackId); if (!rack) { throw new Error('Rack not found'); } const stmt = this.db.prepare(` UPDATE devices SET rack_id = ?, project_id = ?, position = ? WHERE id = ? `); stmt.run(rackId, rack.project_id, position, id); } updateDeviceLogicalPosition(id, x, y) { const stmt = this.db.prepare(` UPDATE devices SET logical_x = ?, logical_y = ? WHERE id = ? `); stmt.run(x, y, id); } updateDeviceName(id, name) { const stmt = this.db.prepare('UPDATE devices SET name = ? WHERE id = ?'); stmt.run(name, id); } updateDeviceRackUnits(id, rackUnits) { const stmt = this.db.prepare('UPDATE devices SET rack_units = ? WHERE id = ?'); stmt.run(rackUnits, id); } getUsedPorts(deviceId) { const ports = this.db.prepare(` SELECT source_port as port FROM connections WHERE source_device_id = ? UNION SELECT target_port as port FROM connections WHERE target_device_id = ? `).all(deviceId, deviceId); return ports.map(p => p.port); } // ==================== CONNECTION OPERATIONS ==================== getAllConnections(projectId) { return this.db.prepare(` SELECT c.* FROM connections c JOIN devices d ON c.source_device_id = d.id JOIN racks r ON d.rack_id = r.id WHERE r.project_id = ? `).all(projectId); } createConnection(sourceDeviceId, sourcePort, targetDeviceId, targetPort) { const stmt = this.db.prepare(` INSERT INTO connections (source_device_id, source_port, target_device_id, target_port) VALUES (?, ?, ?, ?) `); const info = stmt.run(sourceDeviceId, sourcePort, targetDeviceId, targetPort); return { id: info.lastInsertRowid }; } updateConnection(id, sourceDeviceId, sourcePort, targetDeviceId, targetPort) { const stmt = this.db.prepare(` UPDATE connections SET source_device_id = ?, source_port = ?, target_device_id = ?, target_port = ? WHERE id = ? `); stmt.run(sourceDeviceId, sourcePort, targetDeviceId, targetPort, id); } updateConnectionWaypoints(id, waypoints, view = null) { const waypointsJson = JSON.stringify(waypoints); let query; if (view === 'physical') { query = 'UPDATE connections SET waypoints_physical = ? WHERE id = ?'; } else if (view === 'logical') { query = 'UPDATE connections SET waypoints_logical = ? WHERE id = ?'; } else { // For backwards compatibility query = 'UPDATE connections SET waypoints_physical = ?, waypoints_logical = ? WHERE id = ?'; const stmt = this.db.prepare(query); stmt.run(waypointsJson, waypointsJson, id); return; } const stmt = this.db.prepare(query); stmt.run(waypointsJson, id); } deleteConnection(id) { const stmt = this.db.prepare('DELETE FROM connections WHERE id = ?'); stmt.run(id); } // ==================== UTILITY METHODS ==================== /** * Execute a transaction * @param {Function} fn - Function containing database operations * @returns {*} - Return value of the transaction function */ transaction(fn) { return this.db.transaction(fn)(); } /** * Close database connection */ close() { if (this.db) { this.db.close(); console.log('Database connection closed'); } } /** * Get database statistics */ getStats() { const projects = this.db.prepare('SELECT COUNT(*) as count FROM projects').get(); const racks = this.db.prepare('SELECT COUNT(*) as count FROM racks').get(); const devices = this.db.prepare('SELECT COUNT(*) as count FROM devices').get(); const connections = this.db.prepare('SELECT COUNT(*) as count FROM connections').get(); return { projects: projects.count, racks: racks.count, devices: devices.count, connections: connections.count }; } } // Export singleton instance module.exports = new DatacenterDB();