# Database Migration - Final Design Specification **Date Created**: 2025-11-06 **Status**: DESIGN FINALIZED - Ready for SQL Script Creation **Version**: 2.0 - Simplified Design --- ## Executive Summary This document outlines the finalized database migration plan that: 1. Consolidates PCs into machines table (543 total machines) 2. Creates generic communications infrastructure 3. Adds compliance tracking from inventory.xlsx 4. Implements simplified warranty management 5. Adds liaison tracking in businessunits 6. Implements machine relationships tracking (dualpath, controller associations) **Key Design Principles:** - Simplicity over complexity - Generic/flexible structures (address field in communications) - Leverage existing tables (vendors for third-party management) - Minimal columns (remove unnecessary audit fields) --- ## NEW TABLES (7 Tables) ### 1. `comstypes` - Communication Types Lookup Defines types of communication methods available. ```sql CREATE TABLE comstypes ( comstypeid INT(11) PRIMARY KEY AUTO_INCREMENT, typename VARCHAR(50) NOT NULL UNIQUE, description VARCHAR(255), addresslabel VARCHAR(50), -- 'IP Address', 'COM Port', 'Interface Name' requiresport TINYINT(1) DEFAULT 0, -- Does this type use port field? settingsschema TEXT, -- JSON schema for validation (optional) displayorder INT(11) DEFAULT 0, isactive TINYINT(1) DEFAULT 1, KEY idx_isactive (isactive), KEY idx_displayorder (displayorder) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; ``` **Initial Data:** ```sql INSERT INTO comstypes (typename, description, addresslabel, requiresport, displayorder) VALUES ('IP', 'IP-based communication', 'IP Address', 1, 1), ('Serial', 'Serial port communication', 'COM Port', 0, 2), ('Network Interface', 'Network adapter/interface', 'Interface Name', 0, 3), ('USB', 'USB connection', 'USB Device ID', 0, 4), ('Parallel', 'Parallel port', 'LPT Port', 0, 5), ('VNC', 'VNC remote access', 'IP Address', 1, 6), ('FTP', 'FTP connection', 'IP Address', 1, 7); ``` **Columns: 8** --- ### 2. `communications` - Universal Communication Tracking **KEY INNOVATION**: Generic `address` field replaces specific fields (ipaddress, portname, etc.) ```sql CREATE TABLE communications ( comid INT(11) PRIMARY KEY AUTO_INCREMENT, machineid INT(11) NOT NULL, comstypeid INT(11) NOT NULL, -- GENERIC FIELDS address VARCHAR(255), -- Universal: '192.168.1.1', 'COM1', 'eth0', 'USB-001' port INT(11), -- Port/socket number (for IP types) macaddress VARCHAR(17), -- MAC address (network types) description VARCHAR(255), -- Human-readable description -- TYPE-SPECIFIC SETTINGS settings JSON, -- Flexible config (baud rate, subnet, dhcp, etc.) -- STATUS isactive TINYINT(1) DEFAULT 1, KEY idx_machineid (machineid), KEY idx_comstypeid (comstypeid), KEY idx_address (address), KEY idx_isactive (isactive), CONSTRAINT fk_communications_machineid FOREIGN KEY (machineid) REFERENCES machines(machineid), CONSTRAINT fk_communications_comstypeid FOREIGN KEY (comstypeid) REFERENCES comstypes(comstypeid) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; ``` **Examples:** | comstypeid | Type | address | port | settings | |------------|------|---------|------|----------| | 1 | IP | `192.168.1.100` | `8080` | `{"protocol":"tcp"}` | | 2 | Serial | `COM1` | NULL | `{"baud":9600,"databits":8,"parity":"None"}` | | 3 | Network Interface | `eth0` | NULL | `{"subnet":"255.255.255.0","gateway":"192.168.1.1","dhcp":true}` | **Columns: 9** **Replaces:** - `pc_comm_config` - `pc_network_interfaces` - `machines.ipaddress1` - `machines.ipaddress2` --- ### 3. `compliance` - Compliance & Security Tracking Data sourced from inventory.xlsx spreadsheet. ```sql CREATE TABLE compliance ( complianceid INT(11) PRIMARY KEY AUTO_INCREMENT, machineid INT(11) NOT NULL, -- Network & Software ongenetwork TINYINT(1), -- On GE Network? gecoreload TINYINT(1), -- Has GE Coreload software? -- Security Classification assetcriticality VARCHAR(10), -- 'Low', 'Medium', 'High' cuidataclassification VARCHAR(20), -- 'CUI', 'NON-CUI' dodassettype VARCHAR(100), -- 'Specialized Asset', etc. dodassetsubtype VARCHAR(50), -- 'IT', 'OT' otenvironment VARCHAR(100), -- 'Manufacturing/Production', 'Shipping/Receiving' -- Management & Access managedbyvendorid INT(11), -- FK to vendors (third-party management) changerestricted TINYINT(1), -- Change restricted? jumpbox TINYINT(1), -- Is a jump box? mft VARCHAR(100), -- Managed File Transfer designation -- Notes notes TEXT, isactive TINYINT(1) DEFAULT 1, KEY idx_machineid (machineid), KEY idx_managedbyvendorid (managedbyvendorid), KEY idx_assetcriticality (assetcriticality), KEY idx_cuidataclassification (cuidataclassification), CONSTRAINT fk_compliance_machineid FOREIGN KEY (machineid) REFERENCES machines(machineid), CONSTRAINT fk_compliance_managedbyvendorid FOREIGN KEY (managedbyvendorid) REFERENCES vendors(vendorid) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; ``` **Design Decision:** Use existing `vendors` table for third-party management instead of storing vendor names as strings. **Columns: 15** --- ### 4. `compliancescans` - Scan History Log Tracks antivirus/malware scan results over time. ```sql CREATE TABLE compliancescans ( scanid INT(11) PRIMARY KEY AUTO_INCREMENT, machineid INT(11) NOT NULL, scandate DATETIME, scanstatus VARCHAR(100), -- 'No Threats Found', 'Threats Found', 'CORELOADED' scandetails TEXT, -- Full scan results KEY idx_machineid (machineid), KEY idx_scandate (scandate), CONSTRAINT fk_compliancescans_machineid FOREIGN KEY (machineid) REFERENCES machines(machineid) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; ``` **Columns: 5** --- ### 5. `warranties` - Warranty Management **SIMPLIFIED DESIGN**: Just name and expiration date. No complex vendor/type tables. ```sql CREATE TABLE warranties ( warrantyid INT(11) PRIMARY KEY AUTO_INCREMENT, machineid INT(11) NOT NULL, warrantyname VARCHAR(100) NOT NULL, -- 'Dell ProSupport Plus', 'Standard 3-Year' enddate DATE NOT NULL, -- When warranty expires isactive TINYINT(1) DEFAULT 1, KEY idx_machineid (machineid), KEY idx_enddate (enddate), KEY idx_isactive (isactive), CONSTRAINT fk_warranties_machineid FOREIGN KEY (machineid) REFERENCES machines(machineid) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; ``` **Design Decision:** Keep it minimal. Multiple warranties per machine supported. **Columns: 5** --- ### 6. `relationshiptypes` - Machine Relationship Types Lookup Defines types of relationships between machines. ```sql CREATE TABLE relationshiptypes ( relationshiptypeid INT(11) PRIMARY KEY AUTO_INCREMENT, relationshiptype VARCHAR(50) NOT NULL UNIQUE, description VARCHAR(255), isbidirectional TINYINT(1) DEFAULT 0, -- Is relationship symmetric? isactive TINYINT(1) DEFAULT 1, KEY idx_isactive (isactive) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; ``` **Initial Data:** ```sql INSERT INTO relationshiptypes (relationshiptype, description, isbidirectional) VALUES ('Dualpath', 'Machines share same controller (bidirectional)', 1), ('Controlled By', 'Machine is controlled by PC/controller (directional)', 0), ('Controls', 'PC/controller controls machine (directional)', 0), ('Master/Slave', 'Master-slave relationship', 0), ('Linked', 'Generic link between machines', 1); ``` **Columns: 5** **Use Cases:** - Dualpath lathes (2001 & 2002 share same controller) - PC controlling multiple CNC machines - Future: Machine clusters, backup systems, etc. --- ### 7. `machinerelationships` - Machine-to-Machine Relationships Tracks relationships between machines (PC-to-CNC, dualpath, etc.) ```sql CREATE TABLE machinerelationships ( relationshipid INT(11) PRIMARY KEY AUTO_INCREMENT, relationshiptypeid INT(11) NOT NULL, -- FK to relationshiptypes machineid1 INT(11) NOT NULL, -- FK to machines (primary machine) machineid2 INT(11) NOT NULL, -- FK to machines (related machine) notes TEXT, isactive TINYINT(1) DEFAULT 1, KEY idx_relationshiptypeid (relationshiptypeid), KEY idx_machineid1 (machineid1), KEY idx_machineid2 (machineid2), CONSTRAINT fk_machinerel_machineid1 FOREIGN KEY (machineid1) REFERENCES machines(machineid), CONSTRAINT fk_machinerel_machineid2 FOREIGN KEY (machineid2) REFERENCES machines(machineid), CONSTRAINT fk_machinerel_typeid FOREIGN KEY (relationshiptypeid) REFERENCES relationshiptypes(relationshiptypeid) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; ``` **Columns: 6** **Example Data:** ```sql -- Machines 2001 and 2002 are dualpath (linked together) INSERT INTO machinerelationships (relationshiptypeid, machineid1, machineid2) VALUES (1, 2001, 2002); -- Dualpath relationship -- PC (machineid 500) controls machine 2001 INSERT INTO machinerelationships (relationshiptypeid, machineid1, machineid2) VALUES (2, 2001, 500); -- 2001 controlled by PC 500 -- PC (machineid 500) controls machine 2002 INSERT INTO machinerelationships (relationshiptypeid, machineid1, machineid2) VALUES (2, 2002, 500); -- 2002 controlled by PC 500 ``` **Key Feature:** Both machines and PCs are in the machines table, so relationships can link any machine to any other machine. **Query Examples:** ```sql -- Find dualpath partner of machine 2001 SELECT m2.machinenumber FROM machinerelationships mr JOIN machines m2 ON ( CASE WHEN mr.machineid1 = 2001 THEN mr.machineid2 ELSE mr.machineid1 END = m2.machineid ) WHERE (mr.machineid1 = 2001 OR mr.machineid2 = 2001) AND mr.relationshiptypeid = 1; -- Dualpath -- Find which PC controls machine 2001 SELECT pc.hostname, pc.machinenumber FROM machinerelationships mr JOIN machines pc ON mr.machineid2 = pc.machineid WHERE mr.machineid1 = 2001 AND mr.relationshiptypeid = 2; -- Controlled By -- Find all machines controlled by PC 500 SELECT m.machinenumber FROM machinerelationships mr JOIN machines m ON mr.machineid1 = m.machineid WHERE mr.machineid2 = 500 AND mr.relationshiptypeid = 2; -- Controlled By ``` --- ## MODIFIED TABLES (2 Tables) ### 8. `machines` - Extended for PC Data **NEW COLUMNS ADDED (11):** ```sql ALTER TABLE machines ADD COLUMN hostname VARCHAR(100) AFTER machinenumber, ADD COLUMN serialnumber VARCHAR(100) AFTER modelnumberid, ADD COLUMN loggedinuser VARCHAR(100) AFTER hostname, ADD COLUMN controllertypeid INT(11) AFTER modelnumberid, ADD COLUMN controllerosid INT(11) AFTER controllertypeid, ADD COLUMN osid INT(11) AFTER controllerosid, ADD COLUMN machinestatusid INT(11) AFTER osid, ADD COLUMN lastupdated DATETIME, ADD COLUMN dateadded DATETIME, ADD KEY idx_hostname (hostname), ADD KEY idx_serialnumber (serialnumber), ADD KEY idx_controllertypeid (controllertypeid), ADD KEY idx_controllerosid (controllerosid), ADD KEY idx_osid (osid), ADD KEY idx_machinestatusid (machinestatusid), ADD KEY idx_lastupdated (lastupdated), ADD CONSTRAINT fk_machines_controllertypeid FOREIGN KEY (controllertypeid) REFERENCES controllertypes(controllertypeid), ADD CONSTRAINT fk_machines_controllerosid FOREIGN KEY (controllerosid) REFERENCES operatingsystems(osid), ADD CONSTRAINT fk_machines_osid FOREIGN KEY (osid) REFERENCES operatingsystems(osid), ADD CONSTRAINT fk_machines_machinestatusid FOREIGN KEY (machinestatusid) REFERENCES machinestatus(machinestatusid); ``` **FINAL MACHINES TABLE (21 columns):** | # | Column | Type | Purpose | |---|--------|------|---------| | 1 | machineid | INT(11) PK | Primary key | | 2 | machinetypeid | INT(11) FK | Machine type (now includes PC types!) | | 3 | machinenumber | VARCHAR(50) | Machine number | | 4 | alias | VARCHAR(255) | Friendly name | | 5 | hostname | VARCHAR(100) | **NEW** - PC hostname | | 6 | serialnumber | VARCHAR(100) | **NEW** - Serial number | | 7 | loggedinuser | VARCHAR(100) | **NEW** - Logged in user | | 8 | modelnumberid | INT(11) FK | Model | | 9 | controllertypeid | INT(11) FK | **NEW** - Controller type (for CNC machines) | | 10 | controllerosid | INT(11) FK | **NEW** - Controller OS version (uses operatingsystems table) | | 11 | osid | INT(11) FK | **NEW** - Operating system (for PCs) | | 12 | machinestatusid | INT(11) FK | **NEW** - Machine status | | 13 | businessunitid | INT(11) FK | Business unit | | 14 | printerid | INT(11) FK | Associated printer | | 15 | mapleft | SMALLINT(6) | Map X position | | 16 | maptop | SMALLINT(6) | Map Y position | | 17 | isactive | INT(11) | Is active? | | 18 | islocationonly | BIT(1) | Location marker only? | | 19 | machinenotes | TEXT | Notes | | 20 | lastupdated | DATETIME | **NEW** - Last updated | | 21 | dateadded | DATETIME | **NEW** - Date added | **REMOVED FIELDS (after migration):** - `pctypeid` - No longer needed (use machinetypeid) - `isvnc` - Tracked in communications table - `requires_manual_machine_config` - Not needed - `ipaddress1` - Migrated to communications - `ipaddress2` - Migrated to communications --- ### 9. `businessunits` - Add Liaison Fields **NEW COLUMNS ADDED (2):** ```sql ALTER TABLE businessunits ADD COLUMN liaisonname VARCHAR(100) AFTER distributiongroupid, ADD COLUMN liaisonsso VARCHAR(50) AFTER liaisonname, ADD KEY idx_liaisonsso (liaisonsso); ``` **FINAL BUSINESSUNITS TABLE:** | # | Column | Purpose | |---|--------|---------| | 1 | businessunitid | Primary key | | 2 | businessunit | Business unit name | | 3 | distributiongroupid | Distribution group | | 4 | liaisonname | **NEW** - Liaison name (e.g., "Patrick Lipinski") | | 5 | liaisonsso | **NEW** - Liaison SSO/Employee ID | | 6 | isactive | Is active? | **Design Decision:** Added directly to businessunits instead of creating separate liaisons table. --- ## RENAMED TABLES (1 Table) ### 10. `pcstatus` → `machinestatus` Make naming consistent (applies to all machines, not just PCs). ```sql RENAME TABLE pcstatus TO machinestatus; ALTER TABLE machinestatus CHANGE pcstatusid machinestatusid INT(11) AUTO_INCREMENT, CHANGE pcstatus machinestatus CHAR(50); ``` **Final columns:** - machinestatusid (PK) - renamed from pcstatusid - machinestatus - renamed from pcstatus - isactive --- ## UPDATED LOOKUP TABLES ### 11. `machinetypes` - Add PC Types Consolidate PC types into machine types (eliminates need for separate pctype system). ```sql INSERT INTO machinetypes (machinetype, machinedescription, isactive) VALUES ('PC - Standard', 'Standard office/engineering workstation', 1), ('PC - Shopfloor', 'Shopfloor machine control PC', 1), ('PC - Engineer', 'Engineering workstation', 1), ('PC - Server', 'Server', 1), ('PC - Laptop', 'Laptop computer', 1); ``` --- ## DEPRECATED TABLES (Drop after 30-day testing) These tables will be migrated to new structure, then dropped: 1. **`pc`** (277 records) → Data migrated to `machines` 2. **`pc_comm_config`** → Data migrated to `communications` 3. **`pc_network_interfaces`** → Data migrated to `communications` 4. **`pctype`** → Data migrated to `machinetypes` as entries --- ## MIGRATION DATA FLOW ### From `pc` table (277 records): ``` pc.hostname → machines.hostname pc.serialnumber → machines.serialnumber pc.loggedinuser → machines.loggedinuser pc.machinenumber → machines.machinenumber pc.osid → machines.osid pc.pcstatusid → machines.machinestatusid pc.pctypeid → machines.machinetypeid (mapped to new PC types) pc.modelnumberid → machines.modelnumberid pc.isactive → machines.isactive pc.lastupdated → machines.lastupdated pc.dateadded → machines.dateadded Warranty fields → warranties table: pc.warrantyenddate → warranties.enddate pc.warrantyservicelevel → warranties.warrantyname (or derived) ``` ### From `machines.ipaddress1` and `machines.ipaddress2`: ```sql -- For each machine with ipaddress1 INSERT INTO communications (machineid, comstypeid, address, description, isactive) VALUES (machineid, 1, ipaddress1, 'Migrated from machines.ipaddress1', 1); -- For each machine with ipaddress2 INSERT INTO communications (machineid, comstypeid, address, description, isactive) VALUES (machineid, 1, ipaddress2, 'Migrated from machines.ipaddress2', 1); -- Then drop the columns after 30-day verification ALTER TABLE machines DROP COLUMN ipaddress1, DROP COLUMN ipaddress2; ``` ### From `pc_network_interfaces`: ```sql INSERT INTO communications (machineid, comstypeid, address, macaddress, description, settings, isactive) SELECT pcid AS machineid, 3 AS comstypeid, -- Network Interface type interfacename AS address, macaddress, 'Migrated from pc_network_interfaces' AS description, JSON_OBJECT( 'subnet', subnetmask, 'gateway', defaultgateway, 'dhcp', isdhcp, 'machineNetwork', ismachinenetwork ) AS settings, isactive FROM pc_network_interfaces; ``` ### From `pc_comm_config`: ```sql -- Serial communications INSERT INTO communications (machineid, comstypeid, address, settings, isactive) SELECT pcid AS machineid, 2 AS comstypeid, -- Serial type portid AS address, JSON_OBJECT( 'baud', baud, 'databits', databits, 'stopbits', stopbits, 'parity', parity ) AS settings, 1 AS isactive FROM pc_comm_config WHERE configtype = 'Serial'; -- IP communications INSERT INTO communications (machineid, comstypeid, address, port, settings, isactive) SELECT pcid AS machineid, 1 AS comstypeid, -- IP type ipaddress AS address, socketnumber AS port, additionalsettings AS settings, 1 AS isactive FROM pc_comm_config WHERE configtype = 'IP'; ``` --- ## SUMMARY STATISTICS **New Tables:** 7 - comstypes - communications - compliance - compliancescans - warranties - relationshiptypes - machinerelationships **Modified Tables:** 2 - machines (+11 columns) - businessunits (+2 columns) **Renamed Tables:** 1 - pcstatus → machinestatus **Deprecated Tables:** 4 - pc - pc_comm_config - pc_network_interfaces - pctype **Total New Columns:** 61 columns across all tables **Estimated Records After Migration:** - machines: 543 (266 existing + 277 from PCs) - communications: ~650+ (266 from machines.ipaddress, 277+ from pc tables) - warranties: ~277+ (from PC warranty data) - compliance: TBD (from inventory.xlsx) - compliancescans: TBD (ongoing logging) - machinerelationships: ~50+ (dualpath pairs, PC-to-machine controllers) --- ## KEY DESIGN DECISIONS ### Generic `address` Field **Decision:** Use single `address` field in communications instead of separate ipaddress/portname/etc fields. **Benefit:** Flexible, extensible, no unused columns per row. ### Simplified Warranties **Decision:** Just warrantyname and enddate. No complex vendor/type/cost tracking. **Benefit:** Easy to use, easy to maintain, covers 90% of use cases. ### Liaison in BusinessUnits **Decision:** Add liaison fields directly to businessunits instead of separate table. **Benefit:** Simpler structure, one less JOIN, appropriate granularity. ### Unified Machine Types **Decision:** Add PC types as entries in machinetypes instead of separate pctype system. **Benefit:** Single source of truth, eliminates pctypeid column. ### Vendor FK for Third-Party Management **Decision:** Use vendorid FK in compliance.managedbyvendorid instead of text field. **Benefit:** Normalized, prevents typos, enables vendor-based queries. ### JSON Settings Field **Decision:** Use JSON for type-specific config in communications. **Benefit:** Flexible, no table bloat, easy to extend. ### Minimal Audit Fields **Decision:** Removed dateadded/lastupdated from warranties and communications. **Benefit:** Simpler, only track audit fields where truly needed. ### Machine Relationships Table **Decision:** Generic relationship table instead of specific PC-to-machine or dualpath-only tables. **Benefit:** Flexible, extensible, supports bidirectional and directional relationships, future-proof for clusters/backup systems. --- ## NEXT STEPS ### Phase 1: Infrastructure Setup (Scripts 01-08) **Status:** Ready to create SQL scripts 1. Script 01: Create communications infrastructure (comstypes, communications) 2. Script 02: Extend machines table (+9 columns) 3. Script 03: Create PC machine types in machinetypes 4. Script 04: Create warranty infrastructure (warranties) 5. Script 05: Create compliance infrastructure (compliance, compliancescans) 6. Script 06: Extend businessunits table (+2 liaison fields) 7. Script 07: Rename pcstatus to machinestatus 8. Script 08: Create machine relationships infrastructure (relationshiptypes, machinerelationships) **Estimated Time:** 25 minutes **Reversible:** Yes (rollback scripts provided) ### Phase 2: Data Migration (Scripts 09-12) **Status:** Design complete, scripts pending 1. Script 09: Migrate PC data to machines 2. Script 10: Migrate communication data (ipaddress1/2, pc_network_interfaces, pc_comm_config) 3. Script 11: Migrate warranty data 4. Script 12: Populate machine relationships (dualpath, controller associations) **Estimated Time:** 30-45 minutes **Reversible:** Yes (with backups) ### Phase 3: Application Updates **Status:** Pending 1. Update 19 database views 2. Create compatibility views 3. Update ASP files 4. Test all functionality **Estimated Time:** 2-3 weeks ### Phase 4: Cleanup (After 30 days) **Status:** Pending 1. Drop pc table 2. Drop pc_comm_config, pc_network_interfaces 3. Drop pctype table 4. Drop compatibility views 5. Drop machines.ipaddress1, machines.ipaddress2 --- ## RISK MITIGATION **Critical Success Factors:** - Full database backup before any changes - Test all scripts on dev environment first - Rollback scripts for Phase 1 - 30-day verification period before dropping old tables - Compatibility views to support gradual application migration **Rollback Strategy:** - Phase 1: Run rollback scripts (drop new tables, revert ALTER TABLEs) - Phase 2: Restore from backup - Phase 3: Revert code deployment - Phase 4: IRREVERSIBLE - ensure 30-day testing complete --- **Document Status:** FINALIZED **Date Finalized:** 2025-11-06 **Ready for:** Phase 1 SQL Script Creation **Dependencies:** None - self-contained design --- *This document represents the final approved design. Any changes after this point should be documented as amendments with version numbers.*