-- ===================================================== -- VERIFICATION: Phase 3 Migration -- ===================================================== -- Date: 2025-11-10 -- Purpose: Comprehensive verification of Phase 3 migration -- Part of: Phase 3 Migration (Network Devices → machines table) -- Run After: All migration scripts (01-09) -- ===================================================== USE shopdb; SELECT '============================================================' AS ''; SELECT 'PHASE 3 MIGRATION VERIFICATION' AS ''; SELECT 'Network Devices Consolidation into machines Table' AS ''; SELECT '============================================================' AS ''; -- ===================================================== -- TEST 1: Record Count Verification -- ===================================================== SELECT '' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; SELECT 'TEST 1: Record Count Verification' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; -- Count old table records SELECT 'Source Tables (Before Migration):' AS status; SELECT 'servers' AS table_name, COUNT(*) AS record_count FROM servers WHERE isactive = 1 UNION ALL SELECT 'switches', COUNT(*) FROM switches WHERE isactive = 1 UNION ALL SELECT 'cameras', COUNT(*) FROM cameras WHERE isactive = 1; -- Count new table records SELECT 'Target Table (After Migration):' AS status; SELECT mt.machinetype, COUNT(*) AS record_count FROM machines m JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid WHERE mt.machinetypeid BETWEEN 30 AND 36 GROUP BY mt.machinetype ORDER BY mt.machinetypeid; -- ===================================================== -- TEST 2: Machine Types Verification -- ===================================================== SELECT '' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; SELECT 'TEST 2: Machine Types Exist' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; SELECT machinetypeid, machinetype, category, CASE WHEN isactive = 1 THEN 'Active' ELSE 'Inactive' END AS status FROM machinetypes WHERE machinetypeid BETWEEN 30 AND 36 ORDER BY machinetypeid; -- Check for missing machinetypes SELECT 'Missing machinetypes:' AS status, CASE WHEN COUNT(*) = 7 THEN 'PASS - All 7 network machinetypes exist' ELSE CONCAT('FAIL - Only ', COUNT(*), ' of 7 machinetypes exist') END AS result FROM machinetypes WHERE machinetypeid BETWEEN 30 AND 36; -- ===================================================== -- TEST 3: Data Integrity - No NULL Required Fields -- ===================================================== SELECT '' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; SELECT 'TEST 3: Data Integrity - Required Fields' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; -- Check for NULL machinetypeid SELECT 'Devices with NULL machinetypeid:' AS test, CASE WHEN COUNT(*) = 0 THEN 'PASS - No NULL machinetypeids' ELSE CONCAT('FAIL - ', COUNT(*), ' devices with NULL machinetypeid') END AS result FROM machines WHERE machinetypeid BETWEEN 30 AND 36 AND machinetypeid IS NULL; -- Check for NULL machinenumber SELECT 'Devices with NULL machinenumber:' AS test, CASE WHEN COUNT(*) = 0 THEN 'PASS - No NULL machinenumbers' ELSE CONCAT('FAIL - ', COUNT(*), ' devices with NULL machinenumber') END AS result FROM machines WHERE machinetypeid BETWEEN 30 AND 36 AND machinenumber IS NULL; -- Check for incorrect pctypeid (should be NULL for network devices) SELECT 'Network devices with non-NULL pctypeid:' AS test, CASE WHEN COUNT(*) = 0 THEN 'PASS - All network devices have pctypeid = NULL' ELSE CONCAT('FAIL - ', COUNT(*), ' network devices with incorrect pctypeid') END AS result FROM machines WHERE machinetypeid BETWEEN 30 AND 36 AND pctypeid IS NOT NULL; -- ===================================================== -- TEST 4: Communications Migration -- ===================================================== SELECT '' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; SELECT 'TEST 4: Communications (IP Addresses) Migration' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; -- Count IPs in old tables SELECT 'IP addresses in source tables:' AS status; SELECT 'servers' AS table_name, COUNT(*) AS ip_count FROM servers WHERE ipaddress IS NOT NULL AND ipaddress != '' AND isactive = 1 UNION ALL SELECT 'switches', COUNT(*) FROM switches WHERE ipaddress IS NOT NULL AND ipaddress != '' AND isactive = 1 UNION ALL SELECT 'cameras', COUNT(*) FROM cameras WHERE ipaddress IS NOT NULL AND ipaddress != '' AND isactive = 1; -- Count IPs in communications table SELECT 'IP addresses in communications table:' AS status; SELECT mt.machinetype, COUNT(DISTINCT c.comid) AS ip_count FROM machines m JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid JOIN communications c ON m.machineid = c.machineid AND c.comstypeid = 1 WHERE mt.machinetypeid BETWEEN 30 AND 36 GROUP BY mt.machinetype ORDER BY mt.machinetypeid; -- ===================================================== -- TEST 5: Relationship Types -- ===================================================== SELECT '' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; SELECT 'TEST 5: New Relationship Types' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; SELECT 'Network relationship types:' AS status; SELECT relationshiptype, description, CASE WHEN isbidirectional = 1 THEN 'Yes' ELSE 'No' END AS bidirectional FROM relationshiptypes WHERE relationshiptype IN ('Connected To', 'Powered By', 'Mounted In', 'Feeds Video To', 'Provides Network') ORDER BY relationshiptype; -- Check if all expected relationship types exist SELECT 'Expected relationship types:' AS test, CASE WHEN COUNT(*) >= 5 THEN 'PASS - All network relationship types exist' ELSE CONCAT('FAIL - Only ', COUNT(*), ' of 5 relationship types exist') END AS result FROM relationshiptypes WHERE relationshiptype IN ('Connected To', 'Powered By', 'Mounted In', 'Feeds Video To', 'Provides Network'); -- ===================================================== -- TEST 6: Views Verification -- ===================================================== SELECT '' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; SELECT 'TEST 6: Views Created Successfully' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; -- Check if views exist SELECT 'Views status:' AS test; SELECT TABLE_NAME AS view_name, 'EXISTS' AS status FROM INFORMATION_SCHEMA.VIEWS WHERE TABLE_SCHEMA = 'shopdb' AND TABLE_NAME IN ('vw_all_infrastructure', 'vw_network_devices_summary', 'vw_network_topology'); -- Check view record counts SELECT 'Records in vw_all_infrastructure:' AS test, COUNT(*) AS record_count FROM vw_all_infrastructure; SELECT 'Records in vw_network_devices_summary:' AS test, COUNT(*) AS record_count FROM vw_network_devices_summary; SELECT 'Records in vw_network_topology:' AS test, COUNT(*) AS record_count FROM vw_network_topology; -- ===================================================== -- TEST 7: Sample Data Verification -- ===================================================== SELECT '' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; SELECT 'TEST 7: Sample Migrated Data' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; SELECT 'Sample network devices:' AS status; SELECT m.machinenumber, mt.machinetype, mo.modelnumber, v.vendor, c.address AS ipaddress, m.isactive FROM machines m JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid LEFT JOIN models mo ON m.modelnumberid = mo.modelnumberid LEFT JOIN vendors v ON mo.vendorid = v.vendorid LEFT JOIN communications c ON m.machineid = c.machineid AND c.isprimary = 1 WHERE mt.machinetypeid BETWEEN 30 AND 36 ORDER BY mt.machinetypeid, m.machinenumber LIMIT 15; -- ===================================================== -- TEST 8: Duplicate Detection -- ===================================================== SELECT '' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; SELECT 'TEST 8: Duplicate Detection' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; -- Check for duplicate serial numbers within network devices SELECT 'Duplicate serial numbers:' AS test, CASE WHEN COUNT(*) = 0 THEN 'PASS - No duplicates found' ELSE CONCAT('WARNING - ', COUNT(*), ' duplicate serial numbers found') END AS result FROM ( SELECT serialnumber, COUNT(*) as cnt FROM machines WHERE machinetypeid BETWEEN 30 AND 36 AND serialnumber IS NOT NULL AND serialnumber != '' GROUP BY serialnumber HAVING cnt > 1 ) AS duplicates; -- Check for duplicate machinenumbers within network devices SELECT 'Duplicate machinenumbers:' AS test, CASE WHEN COUNT(*) = 0 THEN 'PASS - No duplicates found' ELSE CONCAT('FAIL - ', COUNT(*), ' duplicate machinenumbers found') END AS result FROM ( SELECT machinenumber, COUNT(*) as cnt FROM machines WHERE machinetypeid BETWEEN 30 AND 36 GROUP BY machinenumber HAVING cnt > 1 ) AS duplicates; -- ===================================================== -- TEST 9: Old Table Preservation -- ===================================================== SELECT '' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; SELECT 'TEST 9: Old Tables Preserved (Rollback Safety)' AS ''; SELECT '══════════════════════════════════════════════════════' AS ''; SELECT 'Old tables status:' AS test; SELECT 'servers' AS table_name, COUNT(*) AS record_count FROM servers UNION ALL SELECT 'switches', COUNT(*) FROM switches UNION ALL SELECT 'cameras', COUNT(*) FROM cameras; -- ===================================================== -- FINAL SUMMARY -- ===================================================== SELECT '' AS ''; SELECT '============================================================' AS ''; SELECT 'VERIFICATION SUMMARY' AS ''; SELECT '============================================================' AS ''; SELECT 'Total Network Devices' AS metric, COUNT(*) AS value FROM machines WHERE machinetypeid BETWEEN 30 AND 36 UNION ALL SELECT 'Devices with IP Addresses', COUNT(DISTINCT m.machineid) FROM machines m JOIN communications c ON m.machineid = c.machineid AND c.comstypeid = 1 WHERE m.machinetypeid BETWEEN 30 AND 36 UNION ALL SELECT 'New Relationship Types', COUNT(*) FROM relationshiptypes WHERE relationshiptype IN ('Connected To', 'Powered By', 'Mounted In', 'Feeds Video To', 'Provides Network') UNION ALL SELECT 'Views Created', COUNT(*) FROM INFORMATION_SCHEMA.VIEWS WHERE TABLE_SCHEMA = 'shopdb' AND TABLE_NAME IN ('vw_all_infrastructure', 'vw_network_devices_summary', 'vw_network_topology'); SELECT '' AS ''; SELECT '✓ Phase 3 migration verification complete' AS status; SELECT 'Review results above for any FAIL messages' AS note; SELECT '============================================================' AS ''; -- ===================================================== -- NOTES -- ===================================================== -- If all tests show PASS: -- - Migration successful -- - Safe to update application code -- - Monitor for 30 days before dropping old tables -- -- If any tests show FAIL: -- - Review specific failures -- - Consider running ROLLBACK script -- - Fix issues and re-run migration -- =====================================================