-- ============================================================================ -- Add Name Fields to Infrastructure Tables -- ============================================================================ -- Purpose: Add proper name fields to servers, switches, and cameras -- Date: 2025-10-23 -- Reason: All devices should have a name field, not just description -- ============================================================================ SET SQL_SAFE_UPDATES = 0; SET FOREIGN_KEY_CHECKS = 0; SELECT '============================================' AS sep; SELECT 'ADDING NAME FIELDS TO INFRASTRUCTURE' AS status; SELECT '============================================' AS sep; -- ============================================================================ -- SECTION 1: ADD NAME FIELD TO SERVERS -- ============================================================================ -- Check if column exists SET @col_exists_server = (SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'servers' AND COLUMN_NAME = 'servername'); SET @sql_server = IF(@col_exists_server = 0, 'ALTER TABLE servers ADD COLUMN servername VARCHAR(100) AFTER serverid, ADD INDEX idx_servers_servername (servername)', 'SELECT "servername already exists" AS notice'); PREPARE stmt FROM @sql_server; EXECUTE stmt; DEALLOCATE PREPARE stmt; SELECT 'Step 1 Complete: Added servername to servers table' AS status; -- ============================================================================ -- SECTION 2: ADD NAME FIELD TO SWITCHES -- ============================================================================ SET @col_exists_switch = (SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'switches' AND COLUMN_NAME = 'switchname'); SET @sql_switch = IF(@col_exists_switch = 0, 'ALTER TABLE switches ADD COLUMN switchname VARCHAR(100) AFTER switchid, ADD INDEX idx_switches_switchname (switchname)', 'SELECT "switchname already exists" AS notice'); PREPARE stmt FROM @sql_switch; EXECUTE stmt; DEALLOCATE PREPARE stmt; SELECT 'Step 2 Complete: Added switchname to switches table' AS status; -- ============================================================================ -- SECTION 3: ADD NAME FIELD TO CAMERAS -- ============================================================================ SET @col_exists_camera = (SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'cameras' AND COLUMN_NAME = 'cameraname'); SET @sql_camera = IF(@col_exists_camera = 0, 'ALTER TABLE cameras ADD COLUMN cameraname VARCHAR(100) AFTER cameraid, ADD INDEX idx_cameras_cameraname (cameraname)', 'SELECT "cameraname already exists" AS notice'); PREPARE stmt FROM @sql_camera; EXECUTE stmt; DEALLOCATE PREPARE stmt; SELECT 'Step 3 Complete: Added cameraname to cameras table' AS status; -- ============================================================================ -- SECTION 4: ADD NAME FIELD TO ACCESSPOINTS -- ============================================================================ SET @col_exists_ap = (SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'accesspoints' AND COLUMN_NAME = 'apname'); SET @sql_ap = IF(@col_exists_ap = 0, 'ALTER TABLE accesspoints ADD COLUMN apname VARCHAR(100) AFTER apid, ADD INDEX idx_accesspoints_apname (apname)', 'SELECT "apname already exists" AS notice'); PREPARE stmt FROM @sql_ap; EXECUTE stmt; DEALLOCATE PREPARE stmt; SELECT 'Step 4 Complete: Added apname to accesspoints table' AS status; -- ============================================================================ -- SECTION 5: UPDATE VW_NETWORK_DEVICES VIEW -- ============================================================================ -- Drop and recreate view with name fields and camera-specific columns DROP VIEW IF EXISTS vw_network_devices; CREATE VIEW vw_network_devices AS SELECT 'IDF' AS device_type, i.idfid AS device_id, i.idfname AS device_name, NULL AS modelid, NULL AS modelnumber, NULL AS vendor, NULL AS serialnumber, NULL AS ipaddress, i.description, i.maptop, i.mapleft, i.isactive, NULL AS idfid, NULL AS idfname, NULL AS macaddress FROM idfs i UNION ALL SELECT 'Server' AS device_type, s.serverid AS device_id, s.servername AS device_name, s.modelid, m.modelnumber, v.vendor, s.serialnumber, s.ipaddress, s.description, s.maptop, s.mapleft, s.isactive, NULL AS idfid, NULL AS idfname, NULL AS macaddress FROM servers s LEFT JOIN models m ON s.modelid = m.modelnumberid LEFT JOIN vendors v ON m.vendorid = v.vendorid UNION ALL SELECT 'Switch' AS device_type, sw.switchid AS device_id, sw.switchname AS device_name, sw.modelid, m.modelnumber, v.vendor, sw.serialnumber, sw.ipaddress, sw.description, sw.maptop, sw.mapleft, sw.isactive, NULL AS idfid, NULL AS idfname, NULL AS macaddress FROM switches sw LEFT JOIN models m ON sw.modelid = m.modelnumberid LEFT JOIN vendors v ON m.vendorid = v.vendorid UNION ALL SELECT 'Camera' AS device_type, c.cameraid AS device_id, c.cameraname AS device_name, c.modelid, m.modelnumber, v.vendor, c.serialnumber, c.ipaddress, c.description, c.maptop, c.mapleft, c.isactive, c.idfid, i.idfname, c.macaddress FROM cameras c LEFT JOIN models m ON c.modelid = m.modelnumberid LEFT JOIN vendors v ON m.vendorid = v.vendorid LEFT JOIN idfs i ON c.idfid = i.idfid UNION ALL SELECT 'Access Point' AS device_type, a.apid AS device_id, a.apname AS device_name, a.modelid, m.modelnumber, v.vendor, a.serialnumber, a.ipaddress, a.description, a.maptop, a.mapleft, a.isactive, NULL AS idfid, NULL AS idfname, NULL AS macaddress FROM accesspoints a LEFT JOIN models m ON a.modelid = m.modelnumberid LEFT JOIN vendors v ON m.vendorid = v.vendorid UNION ALL SELECT 'Printer' AS device_type, p.printerid AS device_id, p.printerwindowsname AS device_name, p.modelid, m.modelnumber, v.vendor, p.serialnumber, p.ipaddress, NULL AS description, p.maptop, p.mapleft, p.isactive, NULL AS idfid, NULL AS idfname, NULL AS macaddress FROM printers p LEFT JOIN models m ON p.modelid = m.modelnumberid LEFT JOIN vendors v ON m.vendorid = v.vendorid; SELECT 'Step 5 Complete: Updated vw_network_devices view with name fields, camera columns, and printers' AS status; -- ============================================================================ -- SECTION 6: VERIFICATION -- ============================================================================ SELECT '============================================' AS sep; SELECT 'MIGRATION COMPLETE - VERIFICATION' AS report_title; SELECT '============================================' AS sep; -- Verify name columns were added SELECT 'Name Columns in Infrastructure Tables:' AS section; SELECT TABLE_NAME, COLUMN_NAME, DATA_TYPE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME IN ('servers', 'switches', 'cameras', 'idfs', 'accesspoints') AND COLUMN_NAME LIKE '%name%' ORDER BY TABLE_NAME; -- Test view SELECT 'Testing vw_network_devices view:' AS section; SELECT device_type, COUNT(*) as count FROM vw_network_devices GROUP BY device_type; -- Re-enable safety features SET FOREIGN_KEY_CHECKS = 1; SET SQL_SAFE_UPDATES = 1; SELECT '============================================' AS sep; SELECT 'NAME FIELDS ADDED SUCCESSFULLY!' AS final_status; SELECT '============================================' AS sep; -- ============================================================================ -- END OF MIGRATION SCRIPT -- ============================================================================