Files
shopdb/sql/sync_dualpath_equipment_data.sql
cproudlock b4b81b850a Add equipment data sync for dualpath partner machines
When a dualpath relationship is created, equipment data is now automatically
synced between partners. This ensures both machines share the same:
- Controller type and OS
- Model number
- Serial number
- Communication settings (IP, Serial config)

Location data (mapleft, maptop) is NOT synced since dualpath machines
occupy slightly different physical positions.

Changes:
- includes/db_helpers.asp: Add CopyEquipmentDataToDualpathPartner(),
  CopyCommConfigToDualpathPartner(), and SyncDualpathPartnerData() functions
- savemachineedit.asp: Call SyncDualpathPartnerData() on dualpath creation
- savemachine_direct.asp: Call SyncDualpathPartnerData() on dualpath creation
- sql/sync_dualpath_equipment_data.sql: One-time script to sync existing pairs

Generated with [Claude Code](https://claude.com/claude-code)

Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
2025-12-10 20:09:56 -05:00

185 lines
7.3 KiB
SQL

-- ============================================================================
-- Script: sync_dualpath_equipment_data.sql
-- Purpose: Sync equipment data (controller type, model, comm config) between
-- dualpath partner machines
-- Target: MySQL 5.6 (dev and production)
--
-- Data Synced:
-- - controllertypeid (equipment controller type)
-- - controllerosid (controller OS)
-- - modelnumberid (equipment model)
-- - serialnumber (equipment serial)
-- - communications (IP and Serial config)
--
-- NOT Synced (location-specific):
-- - mapleft, maptop (map position)
-- - machinenumber, hostname (unique identifiers)
-- ============================================================================
-- ============================================================================
-- STEP 1: SHOW DUALPATH PAIRS WITH MISMATCHED DATA
-- ============================================================================
SELECT 'Dualpath pairs with mismatched controller settings:' AS analysis;
SELECT
m1.machinenumber AS machine1,
m1.controllertypeid AS m1_ctrl_type,
ct1.controllertype AS m1_controller,
m2.machinenumber AS machine2,
m2.controllertypeid AS m2_ctrl_type,
ct2.controllertype AS m2_controller
FROM machinerelationships mr
JOIN machines m1 ON mr.machineid = m1.machineid
JOIN machines m2 ON mr.related_machineid = m2.machineid
JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid
LEFT JOIN controllertypes ct1 ON m1.controllertypeid = ct1.controllertypeid
LEFT JOIN controllertypes ct2 ON m2.controllertypeid = ct2.controllertypeid
WHERE rt.relationshiptype = 'Dualpath'
AND mr.isactive = 1
AND (
COALESCE(m1.controllertypeid, 0) <> COALESCE(m2.controllertypeid, 0)
OR COALESCE(m1.controllerosid, 0) <> COALESCE(m2.controllerosid, 0)
OR COALESCE(m1.modelnumberid, 0) <> COALESCE(m2.modelnumberid, 0)
)
ORDER BY m1.machinenumber;
-- ============================================================================
-- STEP 2: SYNC CONTROLLER TYPE, OS, AND MODEL
-- Copy from m1 to m2 where m1 has data and m2 doesn't
-- ============================================================================
SELECT 'Syncing controller settings from populated machines to empty partners...' AS status;
-- Update controllertypeid where m1 has it and m2 doesn't
UPDATE machines m2
JOIN machinerelationships mr ON m2.machineid = mr.related_machineid
JOIN machines m1 ON mr.machineid = m1.machineid
JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid
SET m2.controllertypeid = m1.controllertypeid
WHERE rt.relationshiptype = 'Dualpath'
AND mr.isactive = 1
AND m1.controllertypeid IS NOT NULL
AND m2.controllertypeid IS NULL;
-- Update controllerosid where m1 has it and m2 doesn't
UPDATE machines m2
JOIN machinerelationships mr ON m2.machineid = mr.related_machineid
JOIN machines m1 ON mr.machineid = m1.machineid
JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid
SET m2.controllerosid = m1.controllerosid
WHERE rt.relationshiptype = 'Dualpath'
AND mr.isactive = 1
AND m1.controllerosid IS NOT NULL
AND m2.controllerosid IS NULL;
-- Update modelnumberid where m1 has it and m2 doesn't
UPDATE machines m2
JOIN machinerelationships mr ON m2.machineid = mr.related_machineid
JOIN machines m1 ON mr.machineid = m1.machineid
JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid
SET m2.modelnumberid = m1.modelnumberid
WHERE rt.relationshiptype = 'Dualpath'
AND mr.isactive = 1
AND m1.modelnumberid IS NOT NULL
AND m2.modelnumberid IS NULL;
-- Update serialnumber where m1 has it and m2 doesn't
UPDATE machines m2
JOIN machinerelationships mr ON m2.machineid = mr.related_machineid
JOIN machines m1 ON mr.machineid = m1.machineid
JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid
SET m2.serialnumber = m1.serialnumber
WHERE rt.relationshiptype = 'Dualpath'
AND mr.isactive = 1
AND m1.serialnumber IS NOT NULL AND m1.serialnumber <> ''
AND (m2.serialnumber IS NULL OR m2.serialnumber = '');
-- ============================================================================
-- STEP 3: SYNC COMMUNICATION SETTINGS (IP AND SERIAL)
-- Copy comm config from m1 to m2 where m2 is missing it
-- ============================================================================
SELECT 'Syncing communication settings...' AS status;
-- Get IP and Serial comstypeids
SET @ip_comstypeid = (SELECT comstypeid FROM comstypes WHERE typename = 'IP' LIMIT 1);
SET @serial_comstypeid = (SELECT comstypeid FROM comstypes WHERE typename = 'Serial' LIMIT 1);
-- Insert IP comm config for dualpath partners that are missing it
INSERT INTO communications (machineid, comstypeid, address, port, isactive)
SELECT DISTINCT
m2.machineid,
c1.comstypeid,
c1.address,
c1.port,
1
FROM machinerelationships mr
JOIN machines m1 ON mr.machineid = m1.machineid
JOIN machines m2 ON mr.related_machineid = m2.machineid
JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid
JOIN communications c1 ON m1.machineid = c1.machineid AND c1.comstypeid = @ip_comstypeid AND c1.isactive = 1
WHERE rt.relationshiptype = 'Dualpath'
AND mr.isactive = 1
AND NOT EXISTS (
SELECT 1 FROM communications c2
WHERE c2.machineid = m2.machineid
AND c2.comstypeid = @ip_comstypeid
AND c2.isactive = 1
);
-- Insert Serial comm config for dualpath partners that are missing it
INSERT INTO communications (machineid, comstypeid, address, port, baud, databits, stopbits, parity, isactive)
SELECT DISTINCT
m2.machineid,
c1.comstypeid,
c1.address,
c1.port,
c1.baud,
c1.databits,
c1.stopbits,
c1.parity,
1
FROM machinerelationships mr
JOIN machines m1 ON mr.machineid = m1.machineid
JOIN machines m2 ON mr.related_machineid = m2.machineid
JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid
JOIN communications c1 ON m1.machineid = c1.machineid AND c1.comstypeid = @serial_comstypeid AND c1.isactive = 1
WHERE rt.relationshiptype = 'Dualpath'
AND mr.isactive = 1
AND NOT EXISTS (
SELECT 1 FROM communications c2
WHERE c2.machineid = m2.machineid
AND c2.comstypeid = @serial_comstypeid
AND c2.isactive = 1
);
-- ============================================================================
-- VERIFICATION
-- ============================================================================
SELECT 'Verification - dualpath pairs after sync:' AS status;
SELECT
m1.machinenumber AS machine1,
ct1.controllertype AS m1_controller,
mo1.modelnumber AS m1_model,
m2.machinenumber AS machine2,
ct2.controllertype AS m2_controller,
mo2.modelnumber AS m2_model,
CASE WHEN COALESCE(m1.controllertypeid,0) = COALESCE(m2.controllertypeid,0) THEN 'MATCH' ELSE 'MISMATCH' END AS ctrl_status
FROM machinerelationships mr
JOIN machines m1 ON mr.machineid = m1.machineid
JOIN machines m2 ON mr.related_machineid = m2.machineid
JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid
LEFT JOIN controllertypes ct1 ON m1.controllertypeid = ct1.controllertypeid
LEFT JOIN controllertypes ct2 ON m2.controllertypeid = ct2.controllertypeid
LEFT JOIN models mo1 ON m1.modelnumberid = mo1.modelnumberid
LEFT JOIN models mo2 ON m2.modelnumberid = mo2.modelnumberid
WHERE rt.relationshiptype = 'Dualpath'
AND mr.isactive = 1
ORDER BY m1.machinenumber
LIMIT 20;
SELECT 'Sync complete!' AS status;