-- ============================================================================= -- FIX: Migrate Remaining PCs -- ============================================================================= -- Date: 2025-11-21 -- Purpose: Migrate PCs that weren't migrated in the initial run due to: -- 1. NULL pctypeid (60 PCs) -- 2. Unmapped pctype names (CMM, etc.) -- -- This fixes the machine type name mismatch: -- Script looked for: 'PC - Standard', 'PC - Shopfloor', etc. -- But we created: 'Standard PC', 'Shopfloor PC', etc. -- ============================================================================= USE shopdb; SET SQL_SAFE_UPDATES = 0; SELECT '============================================================' AS ''; SELECT 'FIX: MIGRATE REMAINING PCS' AS ''; SELECT '============================================================' AS ''; SELECT CONCAT('Start time: ', NOW()) AS ''; SELECT '' AS ''; -- ============================================================================= -- STEP 1: Check unmigrated PCs -- ============================================================================= SELECT 'Checking for unmigrated PCs...' AS ''; SELECT '' AS ''; SELECT 'PCs in original pc table (active):' AS category, COUNT(*) AS count FROM pc WHERE isactive = 1 UNION ALL SELECT 'PCs already migrated', COUNT(*) FROM pc_to_machine_id_mapping UNION ALL SELECT 'PCs NOT yet migrated', COUNT(*) 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 ''; -- Show distribution of unmigrated PCs SELECT 'Unmigrated PCs by type:' AS ''; SELECT COALESCE(pt.typename, 'NULL') AS pctype, COUNT(*) AS count FROM pc p LEFT JOIN pctype pt ON p.pctypeid = pt.pctypeid WHERE p.isactive = 1 AND NOT EXISTS (SELECT 1 FROM pc_to_machine_id_mapping m WHERE m.pcid = p.pcid) GROUP BY COALESCE(pt.typename, 'NULL'); SELECT '' AS ''; -- ============================================================================= -- STEP 2: Create corrected PC type mapping -- ============================================================================= SELECT 'Creating corrected PC type mapping...' AS ''; DROP TEMPORARY TABLE IF EXISTS temp_pctype_mapping_fixed; CREATE TEMPORARY TABLE temp_pctype_mapping_fixed ( pctypeid INT, typename VARCHAR(50), target_machinetypeid INT ); -- Map all PC types to correct machine type IDs INSERT INTO temp_pctype_mapping_fixed (pctypeid, typename, target_machinetypeid) SELECT pt.pctypeid, pt.typename, CASE pt.typename WHEN 'Standard' THEN 33 -- Standard PC WHEN 'Shopfloor' THEN 35 -- Shopfloor PC WHEN 'Engineer' THEN 34 -- Engineering PC WHEN 'Server' THEN 33 -- Map to Standard PC (no Server PC type exists) WHEN 'VM' THEN 33 -- Map to Standard PC WHEN 'Laptop' THEN 33 -- Map to Standard PC WHEN 'CMM' THEN 33 -- CMM is mislabeled, map to Standard PC WHEN 'Uncategorized' THEN 33 -- Map to Standard PC WHEN 'Wax / Trace' THEN 33 -- Map to Standard PC ELSE 33 -- Default to Standard PC END AS target_machinetypeid FROM pctype pt; -- Handle NULL pctypeid case INSERT INTO temp_pctype_mapping_fixed (pctypeid, typename, target_machinetypeid) VALUES (NULL, 'NULL', 33); -- Map NULL to Standard PC SELECT '✓ Corrected mapping created' AS status; SELECT * FROM temp_pctype_mapping_fixed ORDER BY pctypeid; SELECT '' AS ''; -- ============================================================================= -- STEP 3: Migrate remaining PCs -- ============================================================================= SELECT 'Migrating remaining PCs...' AS ''; -- Insert remaining PCs into machines table INSERT INTO machines ( machinetypeid, pctypeid, machinenumber, hostname, alias, loggedinuser, modelnumberid, controllertypeid, controllerosid, serialnumber, osid, machinestatusid, businessunitid, printerid, mapleft, maptop, isvnc, islocationonly, requires_manual_machine_config, machinenotes, isactive, lastupdated, dateadded ) SELECT COALESCE(m.target_machinetypeid, 33) AS machinetypeid, -- Default to Standard PC (33) p.pctypeid, COALESCE(p.hostname, CONCAT('PC_', p.pcid)) AS machinenumber, -- Use hostname or generate p.hostname, p.hostname AS alias, -- Use hostname as alias (pc table has no alias column) p.loggedinuser, p.modelnumberid, NULL AS controllertypeid, NULL AS controllerosid, p.serialnumber, p.osid, COALESCE(p.pcstatusid, 3) AS machinestatusid, -- Default to status 3 COALESCE( (SELECT businessunitid FROM machines WHERE machinenumber = p.machinenumber AND isactive = 1 LIMIT 1), 1 ) AS businessunitid, (SELECT printerid FROM machines WHERE machinenumber = p.machinenumber AND isactive = 1 LIMIT 1) AS printerid, (SELECT mapleft FROM machines WHERE machinenumber = p.machinenumber AND isactive = 1 LIMIT 1) AS mapleft, (SELECT maptop FROM machines WHERE machinenumber = p.machinenumber AND isactive = 1 LIMIT 1) AS maptop, 0 AS isvnc, 0 AS islocationonly, p.requires_manual_machine_config, NULL AS machinenotes, p.isactive, p.lastupdated, p.dateadded FROM pc p LEFT JOIN temp_pctype_mapping_fixed m ON COALESCE(p.pctypeid, -999) = COALESCE(m.pctypeid, -999) WHERE p.isactive = 1 AND NOT EXISTS ( SELECT 1 FROM pc_to_machine_id_mapping map WHERE map.pcid = p.pcid ) AND NOT EXISTS ( -- Don't insert if PC already exists in machines table SELECT 1 FROM machines mach WHERE mach.pctypeid IS NOT NULL AND ( (p.hostname IS NOT NULL AND mach.hostname = p.hostname) OR (p.hostname IS NULL AND mach.machinenumber = CONCAT('PC_', p.pcid)) ) ); SELECT CONCAT('✓ Migrated ', ROW_COUNT(), ' additional PCs') AS status; SELECT '' AS ''; -- ============================================================================= -- STEP 4: Fix NULL pctypeid in machines table -- ============================================================================= SELECT 'Fixing PCs with NULL pctypeid in machines table...' AS ''; -- Fix PCs that were migrated with NULL pctypeid UPDATE machines SET pctypeid = 1 -- Set to Standard (pctypeid 1) WHERE machinetypeid IN (33, 34, 35) AND pctypeid IS NULL; SELECT CONCAT('✓ Fixed ', ROW_COUNT(), ' PCs with NULL pctypeid') AS status; SELECT '' AS ''; -- ============================================================================= -- STEP 5: Update mapping table -- ============================================================================= SELECT 'Updating PC to machine ID mapping...' AS ''; INSERT INTO pc_to_machine_id_mapping (pcid, new_machineid, migration_date) SELECT p.pcid, m.machineid, NOW() FROM pc p JOIN machines m ON ( -- Match by hostname (if both have hostname) (p.hostname IS NOT NULL AND m.hostname = p.hostname) OR -- Match by PC_[pcid] pattern for NULL hostname PCs (p.hostname IS NULL AND m.machinenumber = CONCAT('PC_', p.pcid)) ) WHERE p.isactive = 1 AND m.pctypeid IS NOT NULL AND NOT EXISTS ( SELECT 1 FROM pc_to_machine_id_mapping map WHERE map.pcid = p.pcid ) AND p.pcid IS NOT NULL; SELECT CONCAT('✓ Updated mapping table with ', ROW_COUNT(), ' new mappings') AS status; SELECT '' AS ''; -- ============================================================================= -- STEP 6: Verification -- ============================================================================= SELECT 'Verifying fix...' AS ''; SELECT '' AS ''; SELECT 'Final counts:' AS ''; SELECT 'Active PCs in pc table' AS category, COUNT(*) AS count FROM pc WHERE isactive = 1 UNION ALL SELECT 'PCs in mapping table', COUNT(*) FROM pc_to_machine_id_mapping UNION ALL SELECT 'PCs in machines table (pctypeid NOT NULL)', COUNT(*) FROM machines WHERE pctypeid IS NOT NULL UNION ALL SELECT 'PCs still unmigrated', COUNT(*) 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 ''; -- Check if any PCs still unmigrated SET @unmigrated_count = ( SELECT COUNT(*) 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 CASE WHEN @unmigrated_count = 0 THEN '✓✓✓ ALL PCS MIGRATED SUCCESSFULLY ✓✓✓' ELSE CONCAT('⚠️ Still ', @unmigrated_count, ' PCs unmigrated - review above') END AS status; SELECT '' AS ''; -- Show sample of newly migrated PCs SELECT 'Sample of newly migrated PCs:' AS ''; SELECT m.machineid, m.machinenumber, m.hostname, mt.machinetype, pt.typename AS original_pctype FROM machines m JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid LEFT JOIN pc p ON m.hostname = p.hostname LEFT JOIN pctype pt ON p.pctypeid = pt.pctypeid WHERE m.pctypeid IS NOT NULL AND m.machineid NOT IN (SELECT new_machineid FROM pc_to_machine_id_mapping WHERE migration_date < NOW() - INTERVAL 1 MINUTE) LIMIT 10; SELECT '' AS ''; SELECT CONCAT('Completed at: ', NOW()) AS ''; SELECT '============================================================' AS ''; SET SQL_SAFE_UPDATES = 1;