# Production Migration to Phase 2 Schema - CRITICAL PLAN **Date:** 2025-11-20 **Source:** Production Database (database-backup-11-20-25-eod-with-drop.sql) **Target:** Phase 2 Schema (as in current dev) **Goal:** Migrate production to Phase 2 schema WITHOUT losing production data --- ## ⚠️ CRITICAL DATA PRESERVATION **Production has MORE data than dev:** - Production PCs: **286** (in `pc` table) - Dev PCs: **238** (in `machines` table) - Production network interfaces: **705** - Dev communications: **746** **Production also has more current data in:** - applications (59 in prod) - knowledgebase (219 in prod) - notifications (64 in prod) - machines (275 in prod) - printers (45 in prod) **We MUST preserve ALL production data during migration!** --- ## Migration Strategy: PHASE-BY-PHASE ### Phase 1: Extend Existing Tables (Non-Destructive) - ALTER TABLE to add new columns - No data loss - Reversible ### Phase 2: Create New Tables (Safe) - CREATE new Phase 2 tables (communications, compliance, etc.) - No impact on existing data - Reversible ### Phase 3: Migrate PC Data (Complex) - Copy data from `pc` → `machines` (with pctypeid NOT NULL) - Copy data from `pc_network_interfaces` → `communications` - Keep old tables as backup for 30 days - Reversible with rollback scripts ### Phase 4: Update ASP Pages (Application Layer) - Deploy Phase 2 ASP code - Test thoroughly - Rollback ASP code if issues --- ## Data Comparison: Production vs Dev | Item | Production | Dev | Difference | |------|-----------|-----|------------| | PCs (in pc table) | 286 | 0 | Prod +286 | | PCs (in machines) | 0 | 238 | Dev +238 | | Machines (equipment) | 275 | 355 | Dev +80 | | Network Interfaces | 705 | 0 | Prod +705 | | Communications | 0 | 746 | Dev +746 | | Applications | 59 | ? | Prod data | | Knowledge Base | 219 | ? | Prod data | | Notifications | 64 | ? | Prod data | **Conclusion:** Production has significant data added since dev started. We must preserve it! --- ## Tables Requiring Changes ### 1. ALTER TABLE (4 tables - preserve data) #### `machines` - Add 11 Phase 2 columns ```sql ALTER TABLE machines ADD COLUMN hostname varchar(100) DEFAULT NULL AFTER machinenumber, ADD COLUMN serialnumber varchar(50) DEFAULT NULL COMMENT 'Equipment serial number', ADD COLUMN loggedinuser varchar(100) DEFAULT NULL, ADD COLUMN pctypeid int(11) DEFAULT NULL, ADD COLUMN osid int(11) DEFAULT NULL COMMENT 'Foreign key to operatingsystems table', ADD COLUMN controllertypeid int(11) DEFAULT NULL, ADD COLUMN controllerosid int(11) DEFAULT NULL, ADD COLUMN controllermodelid int(11) DEFAULT NULL, ADD COLUMN machinestatusid int(11) DEFAULT NULL, ADD COLUMN lastupdated datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, ADD COLUMN requires_manual_machine_config tinyint(1) DEFAULT '0', DROP COLUMN ipaddress1, DROP COLUMN ipaddress2; ``` **Impact:** - ✅ Preserves all 275 production machines - ⚠️ Removes ipaddress1/ipaddress2 (will be migrated to communications) - ✅ Makes room for 286 PCs to be added #### `businessunits` - Add 5 columns ```sql ALTER TABLE businessunits ADD COLUMN liaisonname varchar(100) DEFAULT NULL, ADD COLUMN liaisonsso varchar(50) DEFAULT NULL, ADD COLUMN facility_id varchar(50) DEFAULT NULL COMMENT 'Facility ID (e.g., 212788513)', ADD COLUMN dt_lead varchar(100) DEFAULT NULL COMMENT 'DT Lead name (e.g., Patrick Lipinski)', ADD COLUMN dt_lead_sso varchar(50) DEFAULT NULL COMMENT 'DT Lead SSO'; ``` **Impact:** ✅ No data loss, adds metadata fields #### `controllertypes` - Add 4 columns ```sql ALTER TABLE controllertypes ADD COLUMN vendorid int(11) DEFAULT NULL, ADD COLUMN controllermodel varchar(100) DEFAULT NULL, ADD COLUMN controller_os varchar(100) DEFAULT NULL COMMENT 'Controller OS (e.g., FANUC OS)', ADD COLUMN controllernotes text; ``` **Impact:** ✅ No data loss, adds metadata fields #### `machine_overrides` - Definition changes **Action:** Need to investigate exact differences --- ### 2. CREATE NEW TABLES (8 tables - safe) #### `communications` - Replaces pc_network_interfaces ```sql CREATE TABLE communications ( comid int(11) NOT NULL AUTO_INCREMENT, machineid int(11) NOT NULL, comstypeid int(11) NOT NULL DEFAULT 1, address varchar(100) DEFAULT NULL, macaddress varchar(17) DEFAULT NULL, interfacename varchar(50) DEFAULT NULL, isprimary tinyint(1) DEFAULT 0, isactive tinyint(1) DEFAULT 1, settings text, PRIMARY KEY (comid), KEY idx_machineid (machineid), KEY idx_isprimary (isprimary) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; ``` #### `comstypes` - Communication types ```sql CREATE TABLE comstypes ( comstypeid int(11) NOT NULL AUTO_INCREMENT, comstype varchar(50) NOT NULL, description text, isactive tinyint(1) DEFAULT 1, PRIMARY KEY (comstypeid) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; INSERT INTO comstypes (comstypeid, comstype, description) VALUES (1, 'Network', 'TCP/IP Network Connection'), (2, 'Serial', 'Serial Port (RS-232, RS-485)'), (3, 'USB', 'USB Connection'), (4, 'Bluetooth', 'Bluetooth Connection'), (5, 'WiFi', 'Wireless Network'), (6, 'Other', 'Other Communication Type'); ``` #### `compliance` - Compliance tracking ```sql CREATE TABLE compliance ( complianceid int(11) NOT NULL AUTO_INCREMENT, machineid int(11) NOT NULL, is_third_party_managed enum('Yes','No','NA') DEFAULT 'NA', third_party_vendorid int(11) DEFAULT NULL, ot_asset_system varchar(100) DEFAULT NULL, ot_asset_device_type varchar(100) DEFAULT NULL, mft varchar(100) DEFAULT NULL, last_scan_date datetime DEFAULT NULL, compliance_status varchar(50) DEFAULT NULL, compliance_notes text, isactive tinyint(1) DEFAULT 1, lastupdated datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, PRIMARY KEY (complianceid), KEY idx_machineid (machineid) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; ``` #### `compliancescans` - Scan history ```sql CREATE TABLE compliancescans ( scanid int(11) NOT NULL AUTO_INCREMENT, machineid int(11) NOT NULL, scan_date datetime DEFAULT CURRENT_TIMESTAMP, scan_result text, scan_status varchar(50) DEFAULT NULL, PRIMARY KEY (scanid), KEY idx_machineid (machineid) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; ``` #### `machinerelationships` - Machine relationships ```sql CREATE TABLE machinerelationships ( relationshipid int(11) NOT NULL AUTO_INCREMENT, machineid int(11) NOT NULL, related_machineid int(11) NOT NULL, relationshiptypeid int(11) NOT NULL, isactive tinyint(1) DEFAULT 1, notes text, PRIMARY KEY (relationshipid), KEY idx_machineid (machineid), KEY idx_related_machineid (related_machineid) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; ``` #### `relationshiptypes` - Relationship types ```sql CREATE TABLE relationshiptypes ( relationshiptypeid int(11) NOT NULL AUTO_INCREMENT, relationshiptype varchar(50) NOT NULL, description text, isdirectional tinyint(1) DEFAULT 0, isactive tinyint(1) DEFAULT 1, PRIMARY KEY (relationshiptypeid) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; INSERT INTO relationshiptypes (relationshiptypeid, relationshiptype, description, isdirectional) VALUES (1, 'Controls', 'PC controls this equipment', 1), (2, 'Dualpath', 'Machines share redundant connection', 0); ``` #### `machinestatus` - Replaces pcstatus ```sql CREATE TABLE machinestatus ( machinestatusid int(11) NOT NULL AUTO_INCREMENT, machinestatus varchar(50) NOT NULL, description text, isactive tinyint(1) DEFAULT 1, PRIMARY KEY (machinestatusid) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- Copy data from pcstatus INSERT INTO machinestatus (machinestatusid, machinestatus, description) SELECT pcstatusid, pcstatus, NULL FROM pcstatus; ``` #### `warranties` - Warranty tracking ```sql CREATE TABLE warranties ( warrantyid int(11) NOT NULL AUTO_INCREMENT, machineid int(11) NOT NULL, warrantyname varchar(100) DEFAULT NULL, warrantyenddate date DEFAULT NULL, isactive tinyint(1) DEFAULT 1, PRIMARY KEY (warrantyid), KEY idx_machineid (machineid) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; ``` --- ### 3. MIGRATE DATA (Critical - Most Complex) #### Step 1: Backup Production Machine IPs ```sql -- Save machine IPs before dropping columns CREATE TABLE _backup_machine_ips AS SELECT machineid, machinenumber, ipaddress1, ipaddress2 FROM machines WHERE ipaddress1 IS NOT NULL OR ipaddress2 IS NOT NULL; ``` #### Step 2: Migrate PCs from `pc` to `machines` ```sql -- Insert PCs into machines table INSERT INTO machines ( hostname, serialnumber, loggedinuser, pctypeid, osid, modelnumberid, businessunitid, machinestatusid, machinenumber, alias, machinenotes, printerid, mapleft, maptop, isactive, islocationonly ) SELECT p.hostname, p.serialnumber, p.loggedinuser, p.pctypeid, p.osid, p.modelnumberid, p.businessunitid, p.pcstatusid AS machinestatusid, p.machinenumber, p.alias, p.notes AS machinenotes, p.printerid, NULL AS mapleft, NULL AS maptop, p.isactive, 0 AS islocationonly FROM pc p WHERE NOT EXISTS ( SELECT 1 FROM machines m WHERE m.hostname = p.hostname ); ``` #### Step 3: Migrate Machine IPs to Communications ```sql -- Migrate machine IP addresses (from backup) INSERT INTO communications (machineid, comstypeid, address, isprimary, interfacename, isactive) SELECT machineid, 1 AS comstypeid, -- Network type ipaddress1, 1 AS isprimary, 'Interface 1' AS interfacename, 1 AS isactive FROM _backup_machine_ips WHERE ipaddress1 IS NOT NULL AND ipaddress1 != ''; INSERT INTO communications (machineid, comstypeid, address, isprimary, interfacename, isactive) SELECT machineid, 1 AS comstypeid, ipaddress2, 0 AS isprimary, 'Interface 2' AS interfacename, 1 AS isactive FROM _backup_machine_ips WHERE ipaddress2 IS NOT NULL AND ipaddress2 != ''; ``` #### Step 4: Migrate PC Network Interfaces to Communications ```sql -- Migrate pc_network_interfaces to communications INSERT INTO communications (machineid, comstypeid, address, macaddress, isprimary, interfacename, isactive) SELECT m.machineid, 1 AS comstypeid, pni.ipaddress, pni.macaddress, pni.isprimary, CONCAT('Interface ', ROW_NUMBER() OVER (PARTITION BY m.machineid ORDER BY pni.isprimary DESC)) AS interfacename, pni.isactive FROM pc_network_interfaces pni JOIN pc p ON pni.pcid = p.pcid JOIN machines m ON m.hostname = p.hostname AND m.pctypeid IS NOT NULL; ``` #### Step 5: Migrate PC Relationships ```sql -- Migrate pc_dualpath_assignments to machinerelationships INSERT INTO machinerelationships (machineid, related_machineid, relationshiptypeid, isactive) SELECT m1.machineid, m2.machineid, 2 AS relationshiptypeid, -- Dualpath 1 AS isactive FROM pc_dualpath_assignments pda JOIN pc p1 ON pda.pcid = p1.pcid JOIN pc p2 ON pda.dualpath_pcid = p2.pcid JOIN machines m1 ON m1.hostname = p1.hostname AND m1.pctypeid IS NOT NULL JOIN machines m2 ON m2.hostname = p2.hostname AND m2.pctypeid IS NOT NULL; -- Migrate machine_pc_relationships (PC controls equipment) INSERT INTO machinerelationships (machineid, related_machineid, relationshiptypeid, isactive) SELECT mpc.pcid AS machineid, mpc.machineid AS related_machineid, 1 AS relationshiptypeid, -- Controls mpc.isactive FROM machine_pc_relationships mpc; ``` --- ## Migration Execution Order ### PRE-MIGRATION (Do First!) 1. ✅ **BACKUP PRODUCTION DATABASE** (already done: database-backup-11-20-25-eod-with-drop.sql) 2. ✅ Test all scripts on dev database first 3. ✅ Schedule maintenance window 4. ✅ Notify users ### MIGRATION EXECUTION (In Order) 1. **Phase 1a:** Create backup tables for IPs (5 seconds) 2. **Phase 1b:** ALTER TABLE machines, businessunits, controllertypes (30 seconds) 3. **Phase 2:** CREATE new Phase 2 tables (comstypes, communications, etc.) (1 minute) 4. **Phase 3a:** Migrate PCs from `pc` → `machines` (2 minutes) 5. **Phase 3b:** Migrate machine IPs to communications (1 minute) 6. **Phase 3c:** Migrate pc_network_interfaces → communications (2 minutes) 7. **Phase 3d:** Migrate relationships (1 minute) 8. **Phase 4:** Verify data integrity (5 minutes) 9. **Phase 5:** Deploy Phase 2 ASP code (10 minutes) 10. **Phase 6:** Test all critical pages (30 minutes) **Total Estimated Time:** 45-60 minutes --- ## Rollback Plan ### If Issues Occur Before ASP Deployment: 1. Run rollback SQL scripts (reverse ALTERs) 2. Drop new tables 3. Restore from backup if needed ### If Issues Occur After ASP Deployment: 1. Deploy Phase 1 ASP code (revert) 2. Users can continue working with old schema 3. Fix issues in dev 4. Retry migration later --- ## Data Verification Queries After migration, run these to verify: ```sql -- Check PC count matches SELECT 'Production PCs' as source, COUNT(*) FROM pc; SELECT 'Migrated PCs' as source, COUNT(*) FROM machines WHERE pctypeid IS NOT NULL; -- Check network interfaces migrated SELECT 'Production Interfaces' as source, COUNT(*) FROM pc_network_interfaces; SELECT 'Migrated Communications' as source, COUNT(*) FROM communications WHERE machineid IN (SELECT machineid FROM machines WHERE pctypeid IS NOT NULL); -- Check machines preserved SELECT 'Production Machines' as source, COUNT(*) FROM machines; -- Should match before/after -- Check relationships migrated SELECT 'Production Dualpath' as source, COUNT(*) FROM pc_dualpath_assignments; SELECT 'Migrated Dualpath' as source, COUNT(*) FROM machinerelationships WHERE relationshiptypeid = 2; SELECT 'Production PC-Machine' as source, COUNT(*) FROM machine_pc_relationships; SELECT 'Migrated Controls' as source, COUNT(*) FROM machinerelationships WHERE relationshiptypeid = 1; ``` --- ## Next Steps 1. **Review this plan** carefully 2. **Create migration SQL scripts** in proper order 3. **Test on dev database** first (with production data copy) 4. **Create rollback scripts** for each phase 5. **Schedule maintenance window** (2-3 hours) 6. **Execute migration** with full team monitoring 7. **Verify data** thoroughly before marking complete --- ## Files to Create 1. `/sql/production_migration/01_backup_machine_ips.sql` 2. `/sql/production_migration/02_alter_machines.sql` 3. `/sql/production_migration/03_alter_businessunits.sql` 4. `/sql/production_migration/04_alter_controllertypes.sql` 5. `/sql/production_migration/05_create_phase2_tables.sql` 6. `/sql/production_migration/06_migrate_pcs.sql` 7. `/sql/production_migration/07_migrate_machine_ips.sql` 8. `/sql/production_migration/08_migrate_pc_interfaces.sql` 9. `/sql/production_migration/09_migrate_relationships.sql` 10. `/sql/production_migration/10_verify_data.sql` 11. `/sql/production_migration/ROLLBACK_*.sql` (for each phase) --- **Status:** Plan Complete - Ready for Script Creation **Risk Level:** HIGH (Production data migration) **Estimated Downtime:** 1-2 hours **Reversibility:** HIGH (with rollback scripts and backup)