# Machine Relationships - Usage Examples **Date:** 2025-11-06 **Purpose:** Show real-world examples of how machine relationships work --- ## Example Scenario: Dualpath Lathes with Shared Controller **Setup:** - Machine 2001 (CNC Lathe) - Machine 2002 (CNC Lathe) - PC 500 (Shopfloor PC, hostname: PC-CNC-01) **Relationships:** 1. 2001 and 2002 share the same controller (dualpath) 2. Both machines communicate directly with PC 500 --- ## Data Setup ### Step 1: Insert Relationship Types (one-time setup) ```sql INSERT INTO relationshiptypes (relationshiptype, description, isbidirectional) VALUES ('Dualpath', 'Machines share same controller', 1), ('Controlled By', 'Machine controlled by PC/controller', 0), ('Controls', 'PC/controller controls machine', 0); ``` ### Step 2: Link the dualpath machines ```sql -- 2001 and 2002 are dualpath INSERT INTO machinerelationships (relationshiptypeid, machineid1, machineid2, notes) VALUES (1, 2001, 2002, 'Dualpath lathe pair - share controller'); ``` ### Step 3: Link machines to controlling PC ```sql -- 2001 is controlled by PC 500 INSERT INTO machinerelationships (relationshiptypeid, machineid1, machineid2, notes) VALUES (2, 2001, 500, 'Primary CNC controller'); -- 2002 is controlled by PC 500 INSERT INTO machinerelationships (relationshiptypeid, machineid1, machineid2, notes) VALUES (2, 2002, 500, 'Primary CNC controller'); ``` --- ## Common Queries ### Q1: Is machine 2001 dualpath? With what machine? ```sql SELECT m.machinenumber AS this_machine, CASE WHEN m2.machineid IS NOT NULL THEN 'Yes' ELSE 'No' END AS is_dualpath, m2.machinenumber AS dualpath_partner, rt.relationshiptype FROM machines m LEFT JOIN machinerelationships mr ON ( (mr.machineid1 = m.machineid OR mr.machineid2 = m.machineid) AND mr.relationshiptypeid = 1 ) LEFT JOIN machines m2 ON ( CASE WHEN mr.machineid1 = m.machineid THEN mr.machineid2 ELSE mr.machineid1 END = m2.machineid ) LEFT JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid WHERE m.machineid = 2001; ``` **Result:** ``` this_machine | is_dualpath | dualpath_partner | relationshiptype 2001 | Yes | 2002 | Dualpath ``` --- ### Q2: Which PC controls machine 2001? ```sql SELECT m.machinenumber AS cnc_machine, pc.machineid AS controller_id, pc.machinenumber AS controller_location, pc.hostname AS controller_hostname, rt.relationshiptype FROM machines m JOIN machinerelationships mr ON mr.machineid1 = m.machineid JOIN machines pc ON mr.machineid2 = pc.machineid JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid WHERE m.machineid = 2001 AND mr.relationshiptypeid = 2; ``` **Result:** ``` cnc_machine | controller_id | controller_location | controller_hostname | relationshiptype 2001 | 500 | IT-LAB-01 | PC-CNC-01 | Controlled By ``` --- ### Q3: What machines does PC 500 control? ```sql SELECT pc.hostname AS controller, m.machinenumber AS controlled_machine, mt.machinetype, mr.notes FROM machines pc JOIN machinerelationships mr ON mr.machineid2 = pc.machineid JOIN machines m ON mr.machineid1 = m.machineid JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid WHERE pc.machineid = 500 AND mr.relationshiptypeid = 2 ORDER BY m.machinenumber; ``` **Result:** ``` controller | controlled_machine | machinetype | notes PC-CNC-01 | 2001 | CNC - Lathe | Primary CNC controller PC-CNC-01 | 2002 | CNC - Lathe | Primary CNC controller ``` --- ### Q4: Complete picture - Machine + Dualpath + Controller + IP ```sql SELECT m.machinenumber AS machine, mt.machinetype, -- Dualpath info m_dual.machinenumber AS dualpath_partner, -- Controller info pc.hostname AS controller, pc.machinenumber AS controller_location, -- Controller's IP c.address AS controller_ip FROM machines m JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid -- Find dualpath partner LEFT JOIN machinerelationships mr_dual ON ( (mr_dual.machineid1 = m.machineid OR mr_dual.machineid2 = m.machineid) AND mr_dual.relationshiptypeid = 1 ) LEFT JOIN machines m_dual ON ( CASE WHEN mr_dual.machineid1 = m.machineid THEN mr_dual.machineid2 ELSE mr_dual.machineid1 END = m_dual.machineid ) -- Find controller LEFT JOIN machinerelationships mr_ctrl ON ( mr_ctrl.machineid1 = m.machineid AND mr_ctrl.relationshiptypeid = 2 ) LEFT JOIN machines pc ON mr_ctrl.machineid2 = pc.machineid -- Get controller's IP address LEFT JOIN communications c ON ( pc.machineid = c.machineid AND c.comstypeid = 1 -- IP type ) WHERE m.machineid IN (2001, 2002); ``` **Result:** ``` machine | machinetype | dualpath_partner | controller | controller_location | controller_ip 2001 | CNC - Lathe | 2002 | PC-CNC-01 | IT-LAB-01 | 192.168.1.50 2002 | CNC - Lathe | 2001 | PC-CNC-01 | IT-LAB-01 | 192.168.1.50 ``` --- ## Recommended View: vw_machine_relationships Create a view for easy access: ```sql CREATE VIEW vw_machine_relationships AS SELECT m.machineid, m.machinenumber, m.alias, mt.machinetype, -- Dualpath info CASE WHEN m_dual.machineid IS NOT NULL THEN 1 ELSE 0 END AS is_dualpath, m_dual.machineid AS dualpath_partner_id, m_dual.machinenumber AS dualpath_partner, -- Controller info pc.machineid AS controller_id, pc.hostname AS controller_hostname, pc.machinenumber AS controller_location, -- Controller IP c.address AS controller_ip, -- Relationship counts (SELECT COUNT(*) FROM machinerelationships mr WHERE mr.machineid1 = m.machineid OR mr.machineid2 = m.machineid ) AS total_relationships FROM machines m JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid -- Dualpath partner LEFT JOIN machinerelationships mr_dual ON ( (mr_dual.machineid1 = m.machineid OR mr_dual.machineid2 = m.machineid) AND mr_dual.relationshiptypeid = 1 AND mr_dual.isactive = 1 ) LEFT JOIN machines m_dual ON ( CASE WHEN mr_dual.machineid1 = m.machineid THEN mr_dual.machineid2 ELSE mr_dual.machineid1 END = m_dual.machineid ) -- Controller PC LEFT JOIN machinerelationships mr_ctrl ON ( mr_ctrl.machineid1 = m.machineid AND mr_ctrl.relationshiptypeid = 2 AND mr_ctrl.isactive = 1 ) LEFT JOIN machines pc ON mr_ctrl.machineid2 = pc.machineid -- Controller IP LEFT JOIN communications c ON ( pc.machineid = c.machineid AND c.comstypeid = 1 ) WHERE m.isactive = 1; ``` ### Using the View: ```sql -- Simple query for machine 2001 SELECT * FROM vw_machine_relationships WHERE machineid = 2001; -- Show all dualpath machines SELECT * FROM vw_machine_relationships WHERE is_dualpath = 1; -- Show all machines controlled by PC 500 SELECT * FROM vw_machine_relationships WHERE controller_id = 500; ``` --- ## ASP Code Examples ### Check if machine is dualpath: ```vbscript strSQL = "SELECT * FROM vw_machine_relationships WHERE machineid = ?" Set rs = ExecuteParameterizedQuery(objConn, strSQL, Array(CLng(machineId))) If Not rs.EOF Then isDualpath = rs("is_dualpath") If isDualpath = 1 Then Response.Write("Dualpath with: " & rs("dualpath_partner")) End If If Not IsNull(rs("controller_hostname")) Then Response.Write("Controller: " & rs("controller_hostname")) Response.Write(" (IP: " & rs("controller_ip") & ")") End If End If ``` ### Display machine card with relationships: ```vbscript

Machine <%= rs("machinenumber") %>

Type: <%= rs("machinetype") %>

<% If rs("is_dualpath") = 1 Then %>
Dualpath: Linked with <%= rs("dualpath_partner") %>
<% End If %> <% If Not IsNull(rs("controller_hostname")) Then %>
Controller: <%= rs("controller_hostname") %>
Location: <%= rs("controller_location") %>
IP: <%= rs("controller_ip") %>
<% End If %>
``` --- ## Benefits of This Design **Flexible** - Any machine can relate to any other machine **Bidirectional** - Dualpath works both ways automatically **Directional** - "Controlled By" has clear direction **Extensible** - Easy to add new relationship types **Query-friendly** - Simple JOINs to get related machines **Unified** - PCs are machines too, so PC-to-machine relationships use same table **Future-proof** - Supports clusters, backups, master-slave, etc. --- ## Future Relationship Types (Examples) ```sql INSERT INTO relationshiptypes (relationshiptype, description, isbidirectional) VALUES ('Backup', 'Backup/redundant machine', 1), ('Cluster Member', 'Member of machine cluster', 1), ('Feeds Into', 'Output feeds into next machine', 0), ('Mirror', 'Mirrored configuration', 1), ('Hot Standby', 'Hot standby/failover machine', 0); ``` These would all work with the same `machinerelationships` table!