-- ===================================================== -- VERIFY PHASE 2 MIGRATION -- ===================================================== -- Date: 2025-11-06 -- Purpose: Comprehensive verification of Phase 2 data migration -- Status: Run after all Phase 2 scripts complete -- ===================================================== USE shopdb; -- ===================================================== -- SECTION 1: PC TO MACHINES MIGRATION -- ===================================================== SELECT '========================================' AS ''; SELECT 'PHASE 2 MIGRATION VERIFICATION' AS ''; SELECT '========================================' AS ''; SELECT '' AS ''; SELECT '========================================' AS ''; SELECT '1. PC TO MACHINES MIGRATION' AS ''; SELECT '========================================' AS ''; SELECT '' AS ''; -- Compare counts SELECT 'Record counts:' AS ''; SELECT 'Original active PCs' AS category, COUNT(*) as count FROM pc WHERE isactive = 1 UNION ALL SELECT 'New machines with pctypeid' AS category, COUNT(*) as count FROM machines WHERE pctypeid IS NOT NULL UNION ALL SELECT 'Mapping table records' AS category, COUNT(*) as count FROM pc_to_machine_id_mapping; SELECT '' AS ''; -- Check for unmapped PCs SELECT 'Unmapped PCs (should be 0):' AS ''; SELECT COUNT(*) as unmapped_pcs FROM pc p WHERE p.isactive = 1 AND NOT EXISTS ( SELECT 1 FROM pc_to_machine_id_mapping m WHERE m.pcid = p.pcid ); SELECT '' AS ''; -- Machine type distribution SELECT 'Machine type distribution:' AS ''; SELECT mt.machinetype, COUNT(*) as count FROM machines m JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid WHERE m.pctypeid IS NOT NULL GROUP BY mt.machinetype ORDER BY count DESC; SELECT '' AS ''; -- Data quality checks SELECT 'Data quality checks:' AS ''; SELECT 'Machines with NULL hostname' AS check_name, COUNT(*) as count, CASE WHEN COUNT(*) = 0 THEN '✓' ELSE '⚠️' END as status FROM machines WHERE pctypeid IS NOT NULL AND hostname IS NULL UNION ALL SELECT 'Machines with NULL machinetypeid', COUNT(*), CASE WHEN COUNT(*) = 0 THEN '✓' ELSE '⚠️' END FROM machines WHERE pctypeid IS NOT NULL AND machinetypeid IS NULL UNION ALL SELECT 'Machines with NULL machinestatusid', COUNT(*), CASE WHEN COUNT(*) = 0 THEN '✓' ELSE '⚠️' END FROM machines WHERE pctypeid IS NOT NULL AND machinestatusid IS NULL; SELECT '' AS ''; -- ===================================================== -- SECTION 2: NETWORK INTERFACES MIGRATION -- ===================================================== SELECT '========================================' AS ''; SELECT '2. NETWORK INTERFACES MIGRATION' AS ''; SELECT '========================================' AS ''; SELECT '' AS ''; -- Count comparison SELECT 'Network interface counts:' AS ''; SELECT 'Original pc_network_interfaces (active)' AS category, COUNT(*) as count FROM pc_network_interfaces WHERE isactive = 1 UNION ALL SELECT 'Migrated to communications (Network_Interface type)' AS category, COUNT(*) as count FROM communications c JOIN comstypes ct ON c.comstypeid = ct.comstypeid WHERE ct.typename = 'Network_Interface'; SELECT '' AS ''; -- Check for unmapped interfaces SELECT 'Unmapped network interfaces (should be 0):' AS ''; SELECT COUNT(*) as unmapped_interfaces FROM pc_network_interfaces ni WHERE ni.isactive = 1 AND NOT EXISTS ( SELECT 1 FROM communications c JOIN comstypes ct ON c.comstypeid = ct.comstypeid JOIN pc_to_machine_id_mapping m ON c.machineid = m.new_machineid WHERE m.pcid = ni.pcid AND ct.typename = 'Network_Interface' AND c.address = ni.ipaddress ); SELECT '' AS ''; -- Sample migrated data SELECT 'Sample migrated network interfaces (first 3):' AS ''; SELECT c.comid, m.hostname, c.address AS ipaddress, c.macaddress, c.interfacename, c.isdhcp FROM communications c JOIN machines m ON c.machineid = m.machineid JOIN comstypes ct ON c.comstypeid = ct.comstypeid WHERE ct.typename = 'Network_Interface' LIMIT 3; SELECT '' AS ''; -- ===================================================== -- SECTION 3: COMM CONFIG MIGRATION -- ===================================================== SELECT '========================================' AS ''; SELECT '3. COMM CONFIG MIGRATION' AS ''; SELECT '========================================' AS ''; SELECT '' AS ''; -- Count by type SELECT 'Comm config counts by type:' AS ''; SELECT 'Original pc_comm_config' AS category, COUNT(*) as count FROM pc_comm_config UNION ALL SELECT 'Migrated Serial configs' AS category, COUNT(*) as count FROM communications c JOIN comstypes ct ON c.comstypeid = ct.comstypeid WHERE ct.typename = 'Serial' UNION ALL SELECT 'Migrated IP configs' AS category, COUNT(*) as count FROM communications c JOIN comstypes ct ON c.comstypeid = ct.comstypeid WHERE ct.typename = 'IP'; SELECT '' AS ''; -- Check for unmapped configs SELECT 'Unmapped comm configs (should be 0):' AS ''; SELECT COUNT(*) as unmapped_configs FROM pc_comm_config cc WHERE NOT EXISTS ( SELECT 1 FROM communications c JOIN pc_to_machine_id_mapping m ON c.machineid = m.new_machineid WHERE m.pcid = cc.pcid ); SELECT '' AS ''; -- Sample serial configs SELECT 'Sample serial communications (first 2):' AS ''; SELECT c.comid, m.hostname, c.address AS port, c.baud, c.databits, c.stopbits, c.parity FROM communications c JOIN machines m ON c.machineid = m.machineid JOIN comstypes ct ON c.comstypeid = ct.comstypeid WHERE ct.typename = 'Serial' LIMIT 2; SELECT '' AS ''; -- Sample IP configs SELECT 'Sample IP communications (first 2):' AS ''; SELECT c.comid, m.hostname, c.address AS ipaddress, c.port AS socket FROM communications c JOIN machines m ON c.machineid = m.machineid JOIN comstypes ct ON c.comstypeid = ct.comstypeid WHERE ct.typename = 'IP' LIMIT 2; SELECT '' AS ''; -- ===================================================== -- SECTION 4: WARRANTIES MIGRATION -- ===================================================== SELECT '========================================' AS ''; SELECT '4. WARRANTIES MIGRATION' AS ''; SELECT '========================================' AS ''; SELECT '' AS ''; -- Count comparison SELECT 'Warranty counts:' AS ''; SELECT 'Original PCs with warranty dates' AS category, COUNT(*) as count FROM pc WHERE warrantyenddate IS NOT NULL AND isactive = 1 UNION ALL SELECT 'Migrated warranty records' AS category, COUNT(*) as count FROM warranties w WHERE w.machineid IN (SELECT new_machineid FROM pc_to_machine_id_mapping); SELECT '' AS ''; -- Warranty status distribution SELECT 'Warranty status distribution:' AS ''; SELECT warrantystatus, COUNT(*) as count FROM vw_warranty_status WHERE machineid IN (SELECT new_machineid FROM pc_to_machine_id_mapping) GROUP BY warrantystatus ORDER BY count DESC; SELECT '' AS ''; -- Warranties expiring soon SELECT 'Warranties expiring in next 90 days:' AS ''; SELECT COUNT(*) as expiring_soon FROM vw_warranties_expiring WHERE machineid IN (SELECT new_machineid FROM pc_to_machine_id_mapping); SELECT '' AS ''; -- Sample warranties SELECT 'Sample migrated warranties (first 3):' AS ''; SELECT w.warrantyid, m.hostname, w.enddate, w.servicelevel, DATEDIFF(w.enddate, CURDATE()) as days_remaining FROM warranties w JOIN machines m ON w.machineid = m.machineid WHERE m.pctypeid IS NOT NULL LIMIT 3; SELECT '' AS ''; -- ===================================================== -- SECTION 5: DUALPATH ASSIGNMENTS MIGRATION -- ===================================================== SELECT '========================================' AS ''; SELECT '5. DUALPATH ASSIGNMENTS MIGRATION' AS ''; SELECT '========================================' AS ''; SELECT '' AS ''; -- Count comparison SELECT 'Dualpath assignment counts:' AS ''; SELECT 'Original pc_dualpath_assignments' AS category, COUNT(*) as count FROM pc_dualpath_assignments UNION ALL SELECT 'Dualpath relationships (total)' AS category, COUNT(*) as count FROM machinerelationships mr JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid WHERE rt.relationshiptype = 'Dualpath' AND mr.isactive = 1 UNION ALL SELECT 'Expected dualpath relationships (assignments × 2)' AS category, COUNT(*) * 2 as count FROM pc_dualpath_assignments WHERE primary_machine IS NOT NULL AND secondary_machine IS NOT NULL; SELECT '' AS ''; -- Check bidirectional consistency SELECT 'Bidirectional relationship check:' AS ''; SELECT 'One-way relationships (should be 0)' AS check_name, COUNT(*) as count, CASE WHEN COUNT(*) = 0 THEN '✓' ELSE '⚠️' END as status FROM machinerelationships mr1 JOIN relationshiptypes rt ON mr1.relationshiptypeid = rt.relationshiptypeid WHERE rt.relationshiptype = 'Dualpath' AND mr1.isactive = 1 AND NOT EXISTS ( SELECT 1 FROM machinerelationships mr2 WHERE mr2.machineid = mr1.related_machineid AND mr2.related_machineid = mr1.machineid AND mr2.relationshiptypeid = mr1.relationshiptypeid AND mr2.isactive = 1 ); SELECT '' AS ''; -- Sample dualpath pairs SELECT 'Sample dualpath machine pairs (first 3):' AS ''; SELECT machine1_number, machine1_hostname, machine2_number, machine2_hostname FROM vw_dualpath_machines LIMIT 3; SELECT '' AS ''; -- ===================================================== -- SECTION 6: OVERALL COMMUNICATIONS SUMMARY -- ===================================================== SELECT '========================================' AS ''; SELECT '6. OVERALL COMMUNICATIONS SUMMARY' AS ''; SELECT '========================================' AS ''; SELECT '' AS ''; -- Communications by type SELECT 'Communications by type (all):' AS ''; SELECT ct.typename, COUNT(*) as count FROM communications c JOIN comstypes ct ON c.comstypeid = ct.comstypeid WHERE c.isactive = 1 GROUP BY ct.typename ORDER BY count DESC; SELECT '' AS ''; -- Communications data quality SELECT 'Communications data quality:' AS ''; SELECT 'Communications with NULL machineid' AS check_name, COUNT(*) as count, CASE WHEN COUNT(*) = 0 THEN '✓' ELSE '⚠️' END as status FROM communications WHERE machineid IS NULL UNION ALL SELECT 'Communications with NULL comstypeid' AS check_name, COUNT(*) as count, CASE WHEN COUNT(*) = 0 THEN '✓' ELSE '⚠️' END as status FROM communications WHERE comstypeid IS NULL UNION ALL SELECT 'Network interfaces without IP address' AS check_name, COUNT(*) as count, CASE WHEN COUNT(*) = 0 THEN '✓' ELSE '⚠️' END as status FROM communications c JOIN comstypes ct ON c.comstypeid = ct.comstypeid WHERE ct.typename = 'Network_Interface' AND (c.address IS NULL OR c.address = ''); SELECT '' AS ''; -- ===================================================== -- SECTION 7: RELATIONSHIP SUMMARY -- ===================================================== SELECT '========================================' AS ''; SELECT '7. RELATIONSHIP SUMMARY' AS ''; SELECT '========================================' AS ''; SELECT '' AS ''; -- Relationships by type SELECT 'Relationships by type:' AS ''; SELECT rt.relationshiptype, COUNT(*) as count FROM machinerelationships mr JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid WHERE mr.isactive = 1 GROUP BY rt.relationshiptype ORDER BY count DESC; SELECT '' AS ''; -- ===================================================== -- SECTION 8: BACKUP TABLE VERIFICATION -- ===================================================== SELECT '========================================' AS ''; SELECT '8. BACKUP TABLE VERIFICATION' AS ''; SELECT '========================================' AS ''; SELECT '' AS ''; -- Verify all backup tables exist SELECT 'Backup tables created:' AS ''; SELECT 'pc_backup_phase2' AS backup_table, COUNT(*) as record_count, CASE WHEN COUNT(*) > 0 THEN '✓' ELSE '⚠️' END as status FROM pc_backup_phase2 UNION ALL SELECT 'pc_network_interfaces_backup_phase2' AS backup_table, COUNT(*) as record_count, CASE WHEN COUNT(*) > 0 THEN '✓' ELSE '⚠️' END as status FROM pc_network_interfaces_backup_phase2 UNION ALL SELECT 'pc_comm_config_backup_phase2' AS backup_table, COUNT(*) as record_count, CASE WHEN COUNT(*) > 0 THEN '✓' ELSE '⚠️' END as status FROM pc_comm_config_backup_phase2 UNION ALL SELECT 'pc_dualpath_assignments_backup_phase2' AS backup_table, COUNT(*) as record_count, CASE WHEN COUNT(*) > 0 THEN '✓' ELSE '⚠️' END as status FROM pc_dualpath_assignments_backup_phase2; SELECT '' AS ''; -- ===================================================== -- SECTION 9: FINAL SUMMARY -- ===================================================== SELECT '========================================' AS ''; SELECT 'MIGRATION SUMMARY' AS ''; SELECT '========================================' AS ''; SELECT '' AS ''; -- Overall migration statistics SELECT 'Overall migration statistics:' AS ''; SELECT CONCAT('PCs migrated: ', COUNT(*)) AS statistic FROM machines WHERE pctypeid IS NOT NULL UNION ALL SELECT CONCAT('Network interfaces migrated: ', COUNT(*)) FROM communications c JOIN comstypes ct ON c.comstypeid = ct.comstypeid WHERE ct.typename = 'Network_Interface' UNION ALL SELECT CONCAT('Serial/IP configs migrated: ', COUNT(*)) FROM communications c JOIN comstypes ct ON c.comstypeid = ct.comstypeid WHERE ct.typename IN ('Serial', 'IP') UNION ALL SELECT CONCAT('Warranty records migrated: ', COUNT(*)) FROM warranties w WHERE w.machineid IN (SELECT new_machineid FROM pc_to_machine_id_mapping) UNION ALL SELECT CONCAT('Dualpath relationships created: ', COUNT(*)) FROM machinerelationships mr JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid WHERE rt.relationshiptype = 'Dualpath' AND mr.isactive = 1; SELECT '' AS ''; -- Critical issues check SELECT 'Critical issues (should all be 0):' AS ''; SELECT COUNT(*) as unmapped_pcs, (SELECT COUNT(*) FROM pc_network_interfaces ni WHERE ni.isactive = 1 AND NOT EXISTS ( SELECT 1 FROM communications c JOIN pc_to_machine_id_mapping m ON c.machineid = m.new_machineid WHERE m.pcid = ni.pcid )) as unmapped_interfaces, (SELECT COUNT(*) FROM pc_comm_config cc WHERE NOT EXISTS ( SELECT 1 FROM communications c JOIN pc_to_machine_id_mapping m ON c.machineid = m.new_machineid WHERE m.pcid = cc.pcid )) as unmapped_configs, (SELECT COUNT(*) FROM communications WHERE machineid IS NULL) as null_machineids FROM pc p WHERE p.isactive = 1 AND NOT EXISTS ( SELECT 1 FROM pc_to_machine_id_mapping m WHERE m.pcid = p.pcid ); SELECT '' AS ''; SELECT '========================================' AS ''; SELECT '✓ PHASE 2 VERIFICATION COMPLETE' AS ''; SELECT '========================================' AS ''; SELECT '' AS ''; -- Next steps SELECT 'Next steps:' AS ''; SELECT '1. Review verification results above' AS ''; SELECT '2. Check for any warnings (⚠️) or non-zero critical issues' AS ''; SELECT '3. If all checks pass, proceed to Phase 3 (view updates)' AS ''; SELECT '4. If issues found, investigate using backup tables' AS ''; -- ===================================================== -- NOTES -- ===================================================== -- This script provides comprehensive verification of Phase 2 migration -- -- Sections verified: -- 1. PC to machines migration (277 PCs) -- 2. Network interfaces to communications -- 3. Comm config to communications (Serial/IP) -- 4. Warranty data migration -- 5. Dualpath assignments to machine relationships -- 6. Overall communications summary -- 7. Relationship types summary -- 8. Backup table verification -- 9. Final summary and critical issues -- -- All checks should show ✓ status -- Critical issues count should be 0 -- -- If any issues found, use backup tables: -- - pc_backup_phase2 -- - pc_network_interfaces_backup_phase2 -- - pc_comm_config_backup_phase2 -- - pc_dualpath_assignments_backup_phase2 -- =====================================================