When a PC is assigned to control equipment that has a dualpath relationship, the controller is now automatically propagated to the dualpath partner machine. Changes: - includes/db_helpers.asp: Add PropagateControllerToDualpathMachines() and PropagateControllerFromDualpathMachine() helper functions - savemachine_direct.asp: Call propagation on new equipment creation - savemachineedit.asp: Call propagation when editing equipment relationships - api.asp: Add PropagateControllerToDualpathMachinesAPI() for PowerShell API Also includes one-time fix script (sql/fix_dualpath_controller_relationships.sql) that fixes 140 backwards relationships (Equipment->PC to PC->Equipment) and propagates controllers to 30 dualpath machines that were missing them. Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
154 lines
6.1 KiB
SQL
154 lines
6.1 KiB
SQL
-- ============================================================================
|
|
-- Script: fix_dualpath_controller_relationships.sql
|
|
-- Purpose: Fix existing relationship issues and propagate controllers to dualpath machines
|
|
-- Target: MySQL 5.6 (dev and production)
|
|
--
|
|
-- Issues Fixed:
|
|
-- 1. Incorrect direction: Equipment -> Controls -> PC (should be PC -> Controls -> Equipment)
|
|
-- 2. Missing controller relationships on dualpath machines
|
|
-- ============================================================================
|
|
|
|
-- ============================================================================
|
|
-- STEP 1: FIX INCORRECTLY DIRECTED RELATIONSHIPS
|
|
-- Equipment should NOT "Control" a PC - flip these to PC -> Controls -> Equipment
|
|
-- ============================================================================
|
|
|
|
-- First, identify the bad relationships (Equipment -> Controls -> PC)
|
|
SELECT
|
|
'BAD RELATIONSHIP' AS issue,
|
|
mr.relationshipid,
|
|
m1.machinenumber AS equipment_number,
|
|
m1.hostname AS equipment_hostname,
|
|
rt.relationshiptype,
|
|
m2.hostname AS pc_hostname,
|
|
m2.machinenumber AS pc_machinenumber
|
|
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
|
|
WHERE rt.relationshiptype = 'Controls'
|
|
AND m1.pctypeid IS NULL -- m1 is Equipment (not a PC)
|
|
AND m2.pctypeid IS NOT NULL -- m2 IS a PC
|
|
AND mr.isactive = 1;
|
|
|
|
-- Fix: Delete the bad relationships and recreate them correctly
|
|
-- First, save the IDs we need to fix
|
|
CREATE TEMPORARY TABLE IF NOT EXISTS temp_bad_controls AS
|
|
SELECT
|
|
mr.relationshipid,
|
|
mr.machineid AS equipment_machineid,
|
|
mr.related_machineid AS pc_machineid,
|
|
mr.relationshiptypeid
|
|
FROM machinerelationships mr
|
|
JOIN machines m1 ON mr.machineid = m1.machineid
|
|
JOIN machines m2 ON mr.related_machineid = m2.machineid
|
|
WHERE mr.relationshiptypeid = (SELECT relationshiptypeid FROM relationshiptypes WHERE relationshiptype = 'Controls')
|
|
AND m1.pctypeid IS NULL
|
|
AND m2.pctypeid IS NOT NULL
|
|
AND mr.isactive = 1;
|
|
|
|
-- Show what will be fixed
|
|
SELECT 'Will fix these relationships:' AS status;
|
|
SELECT * FROM temp_bad_controls;
|
|
|
|
-- Delete the bad relationships
|
|
DELETE mr FROM machinerelationships mr
|
|
INNER JOIN temp_bad_controls t ON mr.relationshipid = t.relationshipid;
|
|
|
|
-- Create the correct relationships (PC -> Controls -> Equipment)
|
|
INSERT INTO machinerelationships (machineid, related_machineid, relationshiptypeid, isactive)
|
|
SELECT
|
|
pc_machineid AS machineid,
|
|
equipment_machineid AS related_machineid,
|
|
relationshiptypeid,
|
|
1 AS isactive
|
|
FROM temp_bad_controls t
|
|
WHERE NOT EXISTS (
|
|
SELECT 1 FROM machinerelationships mr2
|
|
WHERE mr2.machineid = t.pc_machineid
|
|
AND mr2.related_machineid = t.equipment_machineid
|
|
AND mr2.relationshiptypeid = t.relationshiptypeid
|
|
AND mr2.isactive = 1
|
|
);
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS temp_bad_controls;
|
|
|
|
-- ============================================================================
|
|
-- STEP 2: PROPAGATE CONTROLLERS TO DUALPATH MACHINES
|
|
-- If Machine A is controlled by PC, and Machine A has dualpath to Machine B,
|
|
-- then Machine B should also be controlled by PC
|
|
-- ============================================================================
|
|
|
|
-- Find dualpath machines missing controller relationships
|
|
SELECT
|
|
'MISSING CONTROLLER' AS issue,
|
|
m1.machinenumber AS machine_with_controller,
|
|
pc.hostname AS controller_pc,
|
|
m2.machinenumber AS dualpath_machine_missing_controller
|
|
FROM machinerelationships ctrl
|
|
JOIN machines m1 ON ctrl.related_machineid = m1.machineid
|
|
JOIN machines pc ON ctrl.machineid = pc.machineid
|
|
JOIN machinerelationships dp ON m1.machineid = dp.machineid
|
|
JOIN machines m2 ON dp.related_machineid = m2.machineid
|
|
JOIN relationshiptypes rt_ctrl ON ctrl.relationshiptypeid = rt_ctrl.relationshiptypeid
|
|
JOIN relationshiptypes rt_dp ON dp.relationshiptypeid = rt_dp.relationshiptypeid
|
|
WHERE rt_ctrl.relationshiptype = 'Controls'
|
|
AND rt_dp.relationshiptype = 'Dualpath'
|
|
AND ctrl.isactive = 1
|
|
AND dp.isactive = 1
|
|
AND NOT EXISTS (
|
|
SELECT 1 FROM machinerelationships ctrl2
|
|
WHERE ctrl2.machineid = pc.machineid
|
|
AND ctrl2.related_machineid = m2.machineid
|
|
AND ctrl2.relationshiptypeid = ctrl.relationshiptypeid
|
|
AND ctrl2.isactive = 1
|
|
);
|
|
|
|
-- Create the missing controller relationships
|
|
INSERT INTO machinerelationships (machineid, related_machineid, relationshiptypeid, isactive)
|
|
SELECT DISTINCT
|
|
pc.machineid AS machineid,
|
|
m2.machineid AS related_machineid,
|
|
ctrl.relationshiptypeid,
|
|
1 AS isactive
|
|
FROM machinerelationships ctrl
|
|
JOIN machines m1 ON ctrl.related_machineid = m1.machineid
|
|
JOIN machines pc ON ctrl.machineid = pc.machineid
|
|
JOIN machinerelationships dp ON m1.machineid = dp.machineid
|
|
JOIN machines m2 ON dp.related_machineid = m2.machineid
|
|
JOIN relationshiptypes rt_ctrl ON ctrl.relationshiptypeid = rt_ctrl.relationshiptypeid
|
|
JOIN relationshiptypes rt_dp ON dp.relationshiptypeid = rt_dp.relationshiptypeid
|
|
WHERE rt_ctrl.relationshiptype = 'Controls'
|
|
AND rt_dp.relationshiptype = 'Dualpath'
|
|
AND ctrl.isactive = 1
|
|
AND dp.isactive = 1
|
|
AND NOT EXISTS (
|
|
SELECT 1 FROM machinerelationships ctrl2
|
|
WHERE ctrl2.machineid = pc.machineid
|
|
AND ctrl2.related_machineid = m2.machineid
|
|
AND ctrl2.relationshiptypeid = ctrl.relationshiptypeid
|
|
AND ctrl2.isactive = 1
|
|
);
|
|
|
|
-- ============================================================================
|
|
-- VERIFICATION
|
|
-- ============================================================================
|
|
|
|
-- Show all Controls relationships (should be PC -> Equipment)
|
|
SELECT
|
|
'CONTROLS RELATIONSHIPS' AS type,
|
|
pc.hostname AS pc_hostname,
|
|
pc.machinenumber AS pc_machinenumber,
|
|
'-> Controls ->' AS direction,
|
|
equip.machinenumber AS equipment_number,
|
|
equip.hostname AS equipment_hostname
|
|
FROM machinerelationships mr
|
|
JOIN machines pc ON mr.machineid = pc.machineid
|
|
JOIN machines equip ON mr.related_machineid = equip.machineid
|
|
JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid
|
|
WHERE rt.relationshiptype = 'Controls'
|
|
AND mr.isactive = 1
|
|
ORDER BY pc.hostname, equip.machinenumber;
|
|
|
|
SELECT 'Fix complete!' AS status;
|