-- ============================================================================= -- Migration: Move Compliance Columns from machines to compliance Table -- Date: 2025-11-14 -- Purpose: Consolidate compliance-related data into dedicated compliance table -- ============================================================================= -- STEP 1: Add missing compliance columns to compliance table -- Note: gecoreload already exists in compliance table (172 records populated) -- MySQL 5.6 compatible (no IF NOT EXISTS support) -- Add systemname column ALTER TABLE compliance ADD COLUMN systemname TEXT NULL COMMENT 'System name for compliance tracking'; -- Add devicedescription column ALTER TABLE compliance ADD COLUMN devicedescription VARCHAR(1000) NULL COMMENT 'Device description'; -- Add on_ge_network column ALTER TABLE compliance ADD COLUMN on_ge_network ENUM('Yes','No','N/A') NULL COMMENT 'Whether device is on GE network'; -- Add asset_criticality column ALTER TABLE compliance ADD COLUMN asset_criticality ENUM('High','Medium','Low','N/A') NULL COMMENT 'Asset criticality level'; -- Add jump_box column ALTER TABLE compliance ADD COLUMN jump_box ENUM('Yes','No','N/A') NULL COMMENT 'Whether device is a jump box'; -- Add mft column ALTER TABLE compliance ADD COLUMN mft ENUM('Yes','No','N/A') NULL COMMENT 'Managed File Transfer status'; -- STEP 2: Migrate any existing data from machines to compliance -- (Current analysis shows 0 records with data in these columns, but script handles it anyway) INSERT INTO compliance (machineid, systemname, devicedescription, on_ge_network, asset_criticality, jump_box, mft, gecoreload) SELECT m.machineid, m.systemname, m.devicedescription, m.on_ge_network, m.asset_criticality, m.jump_box, m.mft, m.gecoreload FROM machines m WHERE ( m.systemname IS NOT NULL OR m.devicedescription IS NOT NULL OR m.on_ge_network IS NOT NULL OR m.asset_criticality IS NOT NULL OR m.jump_box IS NOT NULL OR m.mft IS NOT NULL OR m.gecoreload IS NOT NULL ) AND NOT EXISTS ( SELECT 1 FROM compliance c WHERE c.machineid = m.machineid ) ON DUPLICATE KEY UPDATE systemname = COALESCE(VALUES(systemname), compliance.systemname), devicedescription = COALESCE(VALUES(devicedescription), compliance.devicedescription), on_ge_network = COALESCE(VALUES(on_ge_network), compliance.on_ge_network), asset_criticality = COALESCE(VALUES(asset_criticality), compliance.asset_criticality), jump_box = COALESCE(VALUES(jump_box), compliance.jump_box), mft = COALESCE(VALUES(mft), compliance.mft), gecoreload = COALESCE(VALUES(gecoreload), compliance.gecoreload); -- STEP 3: Drop compliance columns from machines table -- These belong in the compliance table, not the machines table -- MySQL 5.6 compatible (separate statements) ALTER TABLE machines DROP COLUMN systemname; ALTER TABLE machines DROP COLUMN devicedescription; ALTER TABLE machines DROP COLUMN on_ge_network; ALTER TABLE machines DROP COLUMN asset_criticality; ALTER TABLE machines DROP COLUMN jump_box; ALTER TABLE machines DROP COLUMN mft; ALTER TABLE machines DROP COLUMN gecoreload; -- ============================================================================= -- Verification Queries -- ============================================================================= -- Check compliance table structure -- SHOW COLUMNS FROM compliance; -- Check machines table no longer has these columns -- SHOW COLUMNS FROM machines WHERE Field IN ('systemname','devicedescription','on_ge_network','asset_criticality','jump_box','mft','gecoreload'); -- Check data migrated successfully -- SELECT COUNT(*) as compliance_records FROM compliance WHERE systemname IS NOT NULL OR devicedescription IS NOT NULL; -- ============================================================================= -- Status: Ready to execute -- Impact: Low - No ASP pages reference these columns, all data already in compliance table -- Tested: No -- =============================================================================