-- ============================================================================= -- Migration: Add FQDN column to machines table -- Purpose: Allow network devices to store fully qualified domain names -- Date: 2025-12-01 -- -- Run on PRODUCTION: -- mysql -u root -p shopdb < add_fqdn_to_machines.sql -- ============================================================================= -- Check if column already exists before adding SET @dbname = DATABASE(); SET @tablename = 'machines'; SET @columnname = 'fqdn'; SET @preparedStatement = (SELECT IF( ( SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_SCHEMA = @dbname AND TABLE_NAME = @tablename AND COLUMN_NAME = @columnname ) > 0, 'SELECT ''Column fqdn already exists in machines table'' AS message;', 'ALTER TABLE machines ADD COLUMN fqdn VARCHAR(255) NULL AFTER hostname;' )); PREPARE alterIfNotExists FROM @preparedStatement; EXECUTE alterIfNotExists; DEALLOCATE PREPARE alterIfNotExists; -- Verify the column was added SELECT 'Column migration complete.' AS status; -- ============================================================================= -- Update vw_network_devices view to include FQDN from machines table -- ============================================================================= CREATE OR REPLACE VIEW vw_network_devices AS -- Printers from printers table SELECT 'Printer' AS device_type, p.printerid AS device_id, p.printerwindowsname AS device_name, p.modelid AS modelid, m.modelnumber AS modelnumber, v.vendor AS vendor, p.serialnumber AS serialnumber, p.ipaddress AS ipaddress, NULL AS description, p.maptop AS maptop, p.mapleft AS mapleft, p.isactive AS isactive, NULL AS idfid, NULL AS idfname, NULL AS macaddress, p.fqdn AS fqdn FROM printers p LEFT JOIN models m ON p.modelid = m.modelnumberid LEFT JOIN vendors v ON m.vendorid = v.vendorid UNION ALL -- Network devices from machines table (machinetypeid 16-20) SELECT mt.machinetype AS device_type, ma.machineid AS device_id, COALESCE(ma.alias, ma.machinenumber) AS device_name, ma.modelnumberid AS modelid, mo.modelnumber AS modelnumber, ve.vendor AS vendor, ma.serialnumber AS serialnumber, c.address AS ipaddress, ma.machinenotes AS description, ma.maptop AS maptop, ma.mapleft AS mapleft, ma.isactive AS isactive, NULL AS idfid, NULL AS idfname, c.macaddress AS macaddress, ma.fqdn AS fqdn FROM machines ma JOIN machinetypes mt ON ma.machinetypeid = mt.machinetypeid LEFT JOIN models mo ON ma.modelnumberid = mo.modelnumberid LEFT JOIN vendors ve ON mo.vendorid = ve.vendorid LEFT JOIN communications c ON ma.machineid = c.machineid AND c.isprimary = 1 AND c.comstypeid = 1 WHERE mt.machinetypeid IN (16, 17, 18, 19, 20); SELECT 'View vw_network_devices updated to include FQDN from machines table.' AS status;