Consolidates all database changes into a single step-by-step guide: 1. Table naming convention fix (6 tables renamed) 2. View recreation (9 views) 3. Fix backwards Controls relationships 4. Propagate controllers to dualpath machines 5. Sync equipment data between dualpath partners Includes pre-deployment checklist, rollback plan, and verification steps. Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
20 KiB
Production Database Migration Guide - December 10, 2025
Overview
This guide covers all database changes made on December 10, 2025 that need to be applied to production. The changes are organized in the order they should be executed.
Target Environment:
- Production Server: Windows with IIS
- Database: MySQL 5.6
Changes Summary:
- Table naming convention fix (snake_case to camelCase)
- Fix backwards Controls relationships (Equipment->PC to PC->Equipment)
- Propagate controller assignments to dualpath machines
- Sync equipment data between dualpath partners
Pre-Deployment Checklist
- Full database backup completed
- IIS scheduled for maintenance window
- All scripts tested on dev environment
- ASP file changes ready to deploy (pull from Gitea)
- Rollback plan understood
Step 1: Full Database Backup
CRITICAL: Do this before any other steps!
REM Windows Command Prompt (as Administrator)
"C:\Program Files\MySQL\MySQL Server 5.6\bin\mysqldump.exe" -u root -p shopdb > C:\backups\shopdb_backup_20251210_pre_migration.sql
Or using MySQL Workbench:
- Server > Data Export
- Select
shopdbdatabase - Export to Self-Contained File
Step 2: Stop IIS
iisreset /stop
Step 3: Table Naming Convention Fix
3.1 Drop dependent views
DROP VIEW IF EXISTS vw_active_pcs;
DROP VIEW IF EXISTS vw_dnc_config;
DROP VIEW IF EXISTS vw_engineer_pcs;
DROP VIEW IF EXISTS vw_pc_network_summary;
DROP VIEW IF EXISTS vw_pc_resolved_machines;
DROP VIEW IF EXISTS vw_pcs_by_hardware;
DROP VIEW IF EXISTS vw_shopfloor_comm_config;
DROP VIEW IF EXISTS vw_shopfloor_pcs;
DROP VIEW IF EXISTS vw_standard_pcs;
3.2 Rename tables
RENAME TABLE machine_overrides TO machineoverrides;
RENAME TABLE pc_comm_config TO commconfig;
RENAME TABLE pc_dnc_config TO dncconfig;
RENAME TABLE pc_dualpath_assignments TO dualpathassignments;
RENAME TABLE pc_network_interfaces TO networkinterfaces;
RENAME TABLE usb_checkouts TO usbcheckouts;
3.3 Recreate views
Run the CREATE VIEW statements from sql/naming_convention_fix/04_drop_and_recreate_views.sql
Or copy/paste each view below:
-- vw_active_pcs
CREATE VIEW vw_active_pcs AS
SELECT
pcmap.pcid AS pcid,
m.hostname AS hostname,
m.serialnumber AS serialnumber,
v.vendor AS manufacturer,
md.modelnumber AS model,
m.loggedinuser AS loggedinuser,
m.machinenumber AS machinenumber,
COALESCE(os.operatingsystem,'Unknown') AS operatingsystem,
m.lastupdated AS lastupdated,
pt.typename AS pctype
FROM machines m
JOIN pc_to_machine_id_mapping pcmap ON m.machineid = pcmap.new_machineid
JOIN pctype pt ON m.pctypeid = pt.pctypeid
LEFT JOIN models md ON m.modelnumberid = md.modelnumberid
LEFT JOIN vendors v ON md.vendorid = v.vendorid
LEFT JOIN operatingsystems os ON m.osid = os.osid
WHERE m.lastupdated > (NOW() - INTERVAL 30 DAY)
AND m.pctypeid IS NOT NULL
ORDER BY m.hostname;
-- vw_dnc_config
CREATE VIEW vw_dnc_config AS
SELECT
pcmap.pcid AS pcid,
m.hostname AS hostname,
dc.machineid AS machineid,
dc.dncpath AS dncpath,
dc.dnctype AS dnctype,
dc.isactive AS isactive
FROM dncconfig dc
JOIN machines m ON dc.machineid = m.machineid
JOIN pc_to_machine_id_mapping pcmap ON m.machineid = pcmap.new_machineid
WHERE dc.isactive = 1
ORDER BY m.hostname;
-- vw_engineer_pcs
CREATE VIEW vw_engineer_pcs AS
SELECT
pcmap.pcid AS pcid,
m.hostname AS hostname,
m.serialnumber AS serialnumber,
v.vendor AS manufacturer,
md.modelnumber AS model,
m.loggedinuser AS loggedinuser,
m.machinenumber AS machinenumber,
COALESCE(os.operatingsystem,'Unknown') AS operatingsystem,
m.lastupdated AS lastupdated
FROM machines m
JOIN pc_to_machine_id_mapping pcmap ON m.machineid = pcmap.new_machineid
JOIN pctype pt ON m.pctypeid = pt.pctypeid
LEFT JOIN models md ON m.modelnumberid = md.modelnumberid
LEFT JOIN vendors v ON md.vendorid = v.vendorid
LEFT JOIN operatingsystems os ON m.osid = os.osid
WHERE pt.typename = 'Engineer'
AND m.lastupdated > (NOW() - INTERVAL 30 DAY)
AND m.pctypeid IS NOT NULL
ORDER BY m.hostname;
-- vw_pc_network_summary
CREATE VIEW vw_pc_network_summary AS
SELECT
pcmap.pcid AS pcid,
m.hostname AS hostname,
m.machinenumber AS machinenumber,
COUNT(c.comid) AS interface_count,
GROUP_CONCAT(c.address ORDER BY c.comid ASC SEPARATOR ', ') AS ip_addresses,
GROUP_CONCAT(c.macaddress ORDER BY c.comid ASC SEPARATOR ', ') AS mac_addresses
FROM machines m
JOIN pc_to_machine_id_mapping pcmap ON m.machineid = pcmap.new_machineid
LEFT JOIN communications c ON m.machineid = c.machineid
AND c.comstypeid = (SELECT comstypeid FROM comstypes WHERE typename = 'Network_Interface' LIMIT 1)
AND c.isactive = 1
WHERE m.pctypeid IS NOT NULL
GROUP BY pcmap.pcid, m.hostname, m.machinenumber
ORDER BY m.hostname;
-- vw_pc_resolved_machines
CREATE VIEW vw_pc_resolved_machines AS
SELECT
pcmap.pcid AS pcid,
m.machineid AS machineid,
m.hostname AS hostname,
m.machinenumber AS machinenumber,
pt.typename AS pctype,
COALESCE(mo.machinenumber, m.machinenumber) AS resolved_machinenumber
FROM machines m
JOIN pc_to_machine_id_mapping pcmap ON m.machineid = pcmap.new_machineid
JOIN pctype pt ON m.pctypeid = pt.pctypeid
LEFT JOIN machineoverrides mo ON pcmap.pcid = mo.pcid
WHERE m.pctypeid IS NOT NULL
ORDER BY m.hostname;
-- vw_pcs_by_hardware
CREATE VIEW vw_pcs_by_hardware AS
SELECT
COALESCE(v.vendor,'Unknown') AS manufacturer,
COALESCE(md.modelnumber,'Unknown') AS model,
COUNT(m.machineid) AS count,
GROUP_CONCAT(DISTINCT pt.typename ORDER BY pt.typename ASC SEPARATOR ', ') AS pc_types
FROM machines m
JOIN pc_to_machine_id_mapping pcmap ON m.machineid = pcmap.new_machineid
LEFT JOIN models md ON m.modelnumberid = md.modelnumberid
LEFT JOIN vendors v ON md.vendorid = v.vendorid
LEFT JOIN pctype pt ON m.pctypeid = pt.pctypeid
WHERE m.lastupdated > (NOW() - INTERVAL 30 DAY)
AND m.pctypeid IS NOT NULL
GROUP BY v.vendor, md.modelnumber
ORDER BY COUNT(m.machineid) DESC, v.vendor, md.modelnumber;
-- vw_shopfloor_comm_config
CREATE VIEW vw_shopfloor_comm_config AS
SELECT
pcmap.pcid AS pcid,
m.hostname AS hostname,
m.machinenumber AS machinenumber,
pt.typename AS pctype,
c.address AS ip_address,
c.port AS port_or_socket,
c.baud AS baud,
c.databits AS databits,
c.stopbits AS stopbits,
c.parity AS parity,
ct.typename AS comm_type
FROM machines m
JOIN pc_to_machine_id_mapping pcmap ON m.machineid = pcmap.new_machineid
JOIN pctype pt ON m.pctypeid = pt.pctypeid
LEFT JOIN communications c ON m.machineid = c.machineid AND c.isactive = 1
LEFT JOIN comstypes ct ON c.comstypeid = ct.comstypeid
WHERE pt.typename = 'Shopfloor'
AND m.pctypeid IS NOT NULL
AND ct.typename IN ('IP','Serial')
ORDER BY m.machinenumber, m.hostname;
-- vw_shopfloor_pcs
CREATE VIEW vw_shopfloor_pcs AS
SELECT
pcmap.pcid AS pcid,
m.hostname AS hostname,
m.serialnumber AS serialnumber,
v.vendor AS manufacturer,
md.modelnumber AS model,
m.loggedinuser AS loggedinuser,
COALESCE(CONVERT(mo.machinenumber USING utf8mb4), CONVERT(m.machinenumber USING utf8mb4)) AS machinenumber,
COALESCE(os.operatingsystem,'Unknown') AS operatingsystem,
m.lastupdated AS lastupdated,
m.lastboottime AS lastboottime,
(TO_DAYS(NOW()) - TO_DAYS(m.lastboottime)) AS uptime_days
FROM machines m
JOIN pc_to_machine_id_mapping pcmap ON m.machineid = pcmap.new_machineid
JOIN pctype pt ON m.pctypeid = pt.pctypeid
LEFT JOIN machineoverrides mo ON pcmap.pcid = mo.pcid
LEFT JOIN models md ON m.modelnumberid = md.modelnumberid
LEFT JOIN vendors v ON md.vendorid = v.vendorid
LEFT JOIN operatingsystems os ON m.osid = os.osid
WHERE pt.typename = 'Shopfloor'
AND m.lastupdated > (NOW() - INTERVAL 30 DAY)
AND m.pctypeid IS NOT NULL
ORDER BY COALESCE(CONVERT(mo.machinenumber USING utf8mb4), CONVERT(m.machinenumber USING utf8mb4)), m.hostname;
-- vw_standard_pcs
CREATE VIEW vw_standard_pcs AS
SELECT
pcmap.pcid AS pcid,
m.hostname AS hostname,
m.serialnumber AS serialnumber,
v.vendor AS manufacturer,
md.modelnumber AS model,
m.loggedinuser AS loggedinuser,
m.machinenumber AS machinenumber,
COALESCE(os.operatingsystem,'Unknown') AS operatingsystem,
m.lastupdated AS lastupdated
FROM machines m
JOIN pc_to_machine_id_mapping pcmap ON m.machineid = pcmap.new_machineid
JOIN pctype pt ON m.pctypeid = pt.pctypeid
LEFT JOIN models md ON m.modelnumberid = md.modelnumberid
LEFT JOIN vendors v ON md.vendorid = v.vendorid
LEFT JOIN operatingsystems os ON m.osid = os.osid
WHERE pt.typename = 'Standard'
AND m.lastupdated > (NOW() - INTERVAL 30 DAY)
AND m.pctypeid IS NOT NULL
ORDER BY m.hostname;
3.4 Verify naming changes
-- Should show new names
SHOW TABLES LIKE '%config%';
SHOW TABLES LIKE '%override%';
SHOW TABLES LIKE '%checkout%';
-- Should return data
SELECT COUNT(*) FROM vw_shopfloor_pcs;
SELECT COUNT(*) FROM vw_active_pcs;
Step 4: Fix Dualpath Controller Relationships
This fixes two issues:
- Backwards relationship direction (Equipment->Controls->PC should be PC->Controls->Equipment)
- Missing controller assignments on dualpath partner machines
Run sql/fix_dualpath_controller_relationships.sql or execute:
-- ============================================================================
-- STEP 4.1: Fix incorrectly directed relationships
-- ============================================================================
-- Create temp table to store bad relationships
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 'Fixing these backwards 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 4.2: Propagate controllers to dualpath machines
-- ============================================================================
-- Create missing controller relationships for dualpath partners
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
);
-- ============================================================================
-- STEP 4.3: Verify
-- ============================================================================
-- Should show 0 backwards relationships
SELECT
'Backwards relationships remaining:' AS check_type,
COUNT(*) AS count
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
AND m2.pctypeid IS NOT NULL
AND mr.isactive = 1;
SELECT 'Controller relationship fix complete!' AS status;
Step 5: Sync Dualpath Equipment Data
This syncs controller type, model, and communication settings between dualpath partners.
Run sql/sync_dualpath_equipment_data.sql or execute:
-- ============================================================================
-- STEP 5.1: Sync controller settings
-- ============================================================================
-- 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
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
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
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 5.2: Sync communication settings
-- ============================================================================
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 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 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
);
SELECT 'Dualpath data sync complete!' AS status;
Step 6: Deploy Updated ASP Files
Pull the latest code from Gitea which includes:
- Updated table names in all ASP files
- New dualpath propagation functions in
includes/db_helpers.asp - Updated save pages that call propagation functions
cd C:\inetpub\wwwroot\shopdb
git pull origin master
Or copy files manually from a prepared deployment package.
Step 7: Start IIS
iisreset /start
Step 8: Verify Everything Works
8.1 Test key pages in browser:
- http://yourserver/displaypcs.asp - PC listing
- http://yourserver/displaymachines.asp - Equipment listing
- http://yourserver/displayusb.asp - USB checkout
8.2 Test a dualpath machine:
- Find a machine with a dualpath relationship
- Verify it shows the correct controlling PC
- Verify both dualpath partners show same controller
8.3 Test the API:
http://yourserver/api.asp?action=getDashboardData
Step 9: Optional Cleanup
After confirming everything works (wait at least a day):
-- Drop old migration backup tables
DROP TABLE IF EXISTS _backup_equipment_ips_phase1_5;
DROP TABLE IF EXISTS pc_backup_phase2;
Rollback Plan
If issues occur, restore from backup:
REM Stop IIS
iisreset /stop
REM Restore database
"C:\Program Files\MySQL\MySQL Server 5.6\bin\mysql.exe" -u root -p shopdb < C:\backups\shopdb_backup_20251210_pre_migration.sql
REM Restore ASP files
cd C:\inetpub\wwwroot\shopdb
git checkout HEAD~3 -- .
REM Start IIS
iisreset /start
Summary of Changes
| Category | Change | Script |
|---|---|---|
| Naming | Rename 6 tables (snake_case to camelCase) | naming_convention_fix/*.sql |
| Naming | Recreate 9 views with new table names | naming_convention_fix/04_*.sql |
| Relationships | Fix backwards Controls relationships | fix_dualpath_controller_relationships.sql |
| Relationships | Propagate controllers to dualpath machines | fix_dualpath_controller_relationships.sql |
| Data Sync | Sync equipment data between dualpath pairs | sync_dualpath_equipment_data.sql |
| ASP Files | Update table references in 10 ASP files | git pull |
| ASP Files | Add dualpath propagation functions | git pull |
Scripts Reference
All scripts are in /sql/ directory:
| Script | Purpose |
|---|---|
naming_convention_fix/03_rename_tables.sql |
Table renames |
naming_convention_fix/04_drop_and_recreate_views.sql |
View recreation |
fix_dualpath_controller_relationships.sql |
Fix relationship direction + propagate |
sync_dualpath_equipment_data.sql |
Sync equipment data between dualpath pairs |
Contact
If issues occur during migration, check:
- IIS logs:
C:\inetpub\logs\LogFiles\ - MySQL error log
- Gitea issues: http://localhost:3000/cproudlock/shopdb/issues