-- ===================================================== -- SCRIPT 05: Create Compliance Infrastructure -- ===================================================== -- Date: 2025-11-06 -- Purpose: Create compliance and compliancescans tables -- Status: REVERSIBLE (see ROLLBACK_05) -- Estimated Time: 2-3 minutes -- ===================================================== USE shopdb; SET SQL_SAFE_UPDATES = 0; -- ===================================================== -- STEP 1: Create compliance table -- ===================================================== CREATE TABLE IF NOT EXISTS compliance ( complianceid INT(11) PRIMARY KEY AUTO_INCREMENT, machineid INT(11) NOT NULL, -- Security Compliance Fields scan VARCHAR(255), -- Last scan name/ID scan_date DATETIME, -- Last scan date deployment_notes TEXT, -- Deployment/configuration notes -- Third Party Management is_third_party_managed ENUM('Yes', 'No', 'NA') DEFAULT 'NA', third_party_manager VARCHAR(255), -- Company name managing the asset -- File Transfer mft VARCHAR(100), -- Managed File Transfer tool/status -- OT Asset Tracking (from inventory.xlsx) ot_asset_system VARCHAR(255), -- OT Asset System Name ot_asset_device VARCHAR(255), -- OT Asset Device Name ot_asset_location VARCHAR(255), -- OT Asset Location ot_asset_device_type VARCHAR(100), -- OT Asset Device Type ot_asset_category VARCHAR(100), -- OT Asset Category ot_asset_last_seen DATETIME, -- OT Asset Last Seen ot_asset_ip_source VARCHAR(100), -- OT Asset IP Source -- Compliance Status is_compliant TINYINT(1) DEFAULT NULL, -- NULL=Unknown, 0=Non-compliant, 1=Compliant compliance_notes TEXT, -- Additional compliance notes -- Audit fields lastupdated DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, dateadded DATETIME DEFAULT CURRENT_TIMESTAMP, -- Indexes KEY idx_machineid (machineid), KEY idx_scan_date (scan_date), KEY idx_is_third_party_managed (is_third_party_managed), KEY idx_is_compliant (is_compliant), KEY idx_ot_asset_system (ot_asset_system(100)), -- Foreign Key CONSTRAINT fk_compliance_machineid FOREIGN KEY (machineid) REFERENCES machines(machineid) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='Compliance and security tracking for machines'; -- ===================================================== -- STEP 2: Create compliancescans table -- ===================================================== CREATE TABLE IF NOT EXISTS compliancescans ( scanid INT(11) PRIMARY KEY AUTO_INCREMENT, machineid INT(11) NOT NULL, scan_name VARCHAR(255), -- Scan identifier scan_date DATETIME NOT NULL, scan_result ENUM('Pass', 'Fail', 'Warning', 'Info') DEFAULT 'Info', scan_details TEXT, -- Scan findings/details -- Audit fields dateadded DATETIME DEFAULT CURRENT_TIMESTAMP, -- Indexes KEY idx_machineid (machineid), KEY idx_scan_date (scan_date), KEY idx_scan_result (scan_result), -- Foreign Key CONSTRAINT fk_compliancescans_machineid FOREIGN KEY (machineid) REFERENCES machines(machineid) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='Historical compliance scan records'; -- ===================================================== -- STEP 3: Create compliance summary view -- ===================================================== CREATE OR REPLACE VIEW vw_compliance_summary AS SELECT m.machineid, m.machinenumber, m.hostname, m.serialnumber, c.scan, c.scan_date, c.is_third_party_managed, c.third_party_manager, c.mft, c.is_compliant, c.deployment_notes, c.ot_asset_system, c.ot_asset_device, c.ot_asset_location, DATEDIFF(CURDATE(), c.scan_date) AS days_since_scan, CASE WHEN c.scan_date IS NULL THEN 'Never Scanned' WHEN c.scan_date < DATE_SUB(CURDATE(), INTERVAL 90 DAY) THEN 'Scan Overdue' WHEN c.scan_date < DATE_SUB(CURDATE(), INTERVAL 30 DAY) THEN 'Scan Due Soon' ELSE 'Scan Current' END AS scan_status FROM machines m LEFT JOIN compliance c ON m.machineid = c.machineid WHERE m.isactive = 1; -- ===================================================== -- VERIFICATION -- ===================================================== SELECT '✓ compliance table created' AS status; DESCRIBE compliance; SELECT '✓ compliancescans table created' AS status; DESCRIBE compliancescans; SELECT '✓ Compliance views created' AS status; SHOW TABLES LIKE 'vw_compliance%'; SELECT '✓ Script 05 completed successfully' AS status; SET SQL_SAFE_UPDATES = 1; -- ===================================================== -- NOTES -- ===================================================== -- Next: Run script 06_extend_businessunits_table.sql -- Rollback: Run ROLLBACK_05_compliance_infrastructure.sql -- -- Data Migration Sources (from inventory.xlsx): -- - Column 19 "Scan" → scan -- - Column 20 "Scan Date" → scan_date -- - Column 21 "Deployment Notes" → deployment_notes -- - Column 28 "3rd Party Managed" → is_third_party_managed + third_party_manager -- - Column 29 "MFT" → mft -- - Column 30 "OT Asset System Name" → ot_asset_system -- - Column 31 "OT Asset Device Name" → ot_asset_device -- - Column 32 "OT Asset Location" → ot_asset_location -- - Column 33 "OT Asset Device Type" → ot_asset_device_type -- - Column 34 "OT Asset Category" → ot_asset_category -- - Column 35 "OT Asset Last Seen" → ot_asset_last_seen -- - Column 36 "OT Asset IP Source" → ot_asset_ip_source -- =====================================================