diff --git a/sql/naming_convention_fix/01_drop_migration_backup_tables.sql b/sql/naming_convention_fix/01_drop_migration_backup_tables.sql new file mode 100644 index 0000000..24e2614 --- /dev/null +++ b/sql/naming_convention_fix/01_drop_migration_backup_tables.sql @@ -0,0 +1,31 @@ +-- ============================================================================ +-- Script: 01_drop_migration_backup_tables.sql +-- Purpose: Drop migration backup tables that are no longer needed +-- Target: MySQL 5.6 (dev and production) +-- +-- IMPORTANT: Run this AFTER verifying migration is complete and stable +-- ============================================================================ + +-- Safety check: Verify these tables exist before dropping +SELECT 'Checking tables to drop...' AS status; + +SELECT TABLE_NAME, TABLE_ROWS +FROM INFORMATION_SCHEMA.TABLES +WHERE TABLE_SCHEMA = DATABASE() +AND TABLE_NAME IN ('_backup_equipment_ips_phase1_5', 'pc_backup_phase2', 'pc_to_machine_id_mapping'); + +-- ============================================================================ +-- WARNING: The following drops are destructive and cannot be undone! +-- Make sure you have a full database backup before running. +-- ============================================================================ + +-- Uncomment these lines when ready to execute: + +-- DROP TABLE IF EXISTS _backup_equipment_ips_phase1_5; +-- DROP TABLE IF EXISTS pc_backup_phase2; + +-- NOTE: pc_to_machine_id_mapping is still used by 9 views! +-- Must update views FIRST before dropping this table. +-- See script 04_recreate_views.sql + +SELECT 'Script complete. Uncomment DROP statements when ready.' AS status; diff --git a/sql/naming_convention_fix/02_backup_view_definitions.sql b/sql/naming_convention_fix/02_backup_view_definitions.sql new file mode 100644 index 0000000..64f3498 --- /dev/null +++ b/sql/naming_convention_fix/02_backup_view_definitions.sql @@ -0,0 +1,35 @@ +-- ============================================================================ +-- Script: 02_backup_view_definitions.sql +-- Purpose: Export current view definitions before making changes +-- Target: MySQL 5.6 (dev and production) +-- +-- Run this to capture current views for reference/rollback +-- ============================================================================ + +-- View definitions that reference underscore tables (pc_to_machine_id_mapping, machine_overrides) +-- These will need to be recreated after table renames + +-- vw_active_pcs - uses pc_to_machine_id_mapping +-- vw_dnc_config - uses pc_to_machine_id_mapping +-- vw_engineer_pcs - uses pc_to_machine_id_mapping +-- vw_pc_network_summary - uses pc_to_machine_id_mapping +-- vw_pc_resolved_machines - uses pc_to_machine_id_mapping +-- vw_pcs_by_hardware - uses pc_to_machine_id_mapping +-- vw_shopfloor_comm_config - uses pc_to_machine_id_mapping +-- vw_shopfloor_pcs - uses pc_to_machine_id_mapping AND machine_overrides +-- vw_standard_pcs - uses pc_to_machine_id_mapping + +-- Export commands (run from command line): +-- mysqldump -u root -p shopdb --no-data --routines > views_backup.sql + +-- Or query individual views: +SELECT 'Run these SHOW CREATE VIEW commands to backup:' AS instruction; +SHOW CREATE VIEW vw_active_pcs; +SHOW CREATE VIEW vw_dnc_config; +SHOW CREATE VIEW vw_engineer_pcs; +SHOW CREATE VIEW vw_pc_network_summary; +SHOW CREATE VIEW vw_pc_resolved_machines; +SHOW CREATE VIEW vw_pcs_by_hardware; +SHOW CREATE VIEW vw_shopfloor_comm_config; +SHOW CREATE VIEW vw_shopfloor_pcs; +SHOW CREATE VIEW vw_standard_pcs; diff --git a/sql/naming_convention_fix/03_rename_tables.sql b/sql/naming_convention_fix/03_rename_tables.sql new file mode 100644 index 0000000..cd0a43c --- /dev/null +++ b/sql/naming_convention_fix/03_rename_tables.sql @@ -0,0 +1,83 @@ +-- ============================================================================ +-- Script: 03_rename_tables.sql +-- Purpose: Rename tables from snake_case to camelCase +-- Target: MySQL 5.6 (dev and production) +-- +-- IMPORTANT: +-- 1. Run 04_drop_and_recreate_views.sql FIRST to drop dependent views +-- 2. Then run this script +-- 3. Then run 04_drop_and_recreate_views.sql again to recreate views +-- ============================================================================ + +-- Pre-flight check: Verify tables exist +SELECT 'Verifying tables to rename exist...' AS status; + +SELECT TABLE_NAME, TABLE_ROWS, CREATE_TIME +FROM INFORMATION_SCHEMA.TABLES +WHERE TABLE_SCHEMA = DATABASE() +AND TABLE_NAME IN ( + 'machine_overrides', + 'pc_comm_config', + 'pc_dnc_config', + 'pc_dualpath_assignments', + 'pc_network_interfaces', + 'usb_checkouts' +); + +-- ============================================================================ +-- TABLE RENAMES +-- ============================================================================ + +-- Rename: machine_overrides -> machineoverrides +RENAME TABLE machine_overrides TO machineoverrides; + +-- Rename: pc_comm_config -> commconfig +RENAME TABLE pc_comm_config TO commconfig; + +-- Rename: pc_dnc_config -> dncconfig +RENAME TABLE pc_dnc_config TO dncconfig; + +-- Rename: pc_dualpath_assignments -> dualpathassignments +RENAME TABLE pc_dualpath_assignments TO dualpathassignments; + +-- Rename: pc_network_interfaces -> networkinterfaces +RENAME TABLE pc_network_interfaces TO networkinterfaces; + +-- Rename: usb_checkouts -> usbcheckouts +RENAME TABLE usb_checkouts TO usbcheckouts; + +-- ============================================================================ +-- VERIFICATION +-- ============================================================================ + +SELECT 'Verifying renames completed...' AS status; + +SELECT TABLE_NAME, TABLE_ROWS +FROM INFORMATION_SCHEMA.TABLES +WHERE TABLE_SCHEMA = DATABASE() +AND TABLE_NAME IN ( + 'machineoverrides', + 'commconfig', + 'dncconfig', + 'dualpathassignments', + 'networkinterfaces', + 'usbcheckouts' +); + +-- Check old names no longer exist +SELECT 'Checking old table names are gone...' AS status; + +SELECT TABLE_NAME +FROM INFORMATION_SCHEMA.TABLES +WHERE TABLE_SCHEMA = DATABASE() +AND TABLE_NAME IN ( + 'machine_overrides', + 'pc_comm_config', + 'pc_dnc_config', + 'pc_dualpath_assignments', + 'pc_network_interfaces', + 'usb_checkouts' +); +-- Should return 0 rows + +SELECT 'Table renames complete!' AS status; diff --git a/sql/naming_convention_fix/04_drop_and_recreate_views.sql b/sql/naming_convention_fix/04_drop_and_recreate_views.sql new file mode 100644 index 0000000..398cd96 --- /dev/null +++ b/sql/naming_convention_fix/04_drop_and_recreate_views.sql @@ -0,0 +1,261 @@ +-- ============================================================================ +-- Script: 04_drop_and_recreate_views.sql +-- Purpose: Drop views that reference underscore tables, recreate with new names +-- Target: MySQL 5.6 (dev and production) +-- +-- USAGE: +-- 1. Run Part 1 (DROP) BEFORE running 03_rename_tables.sql +-- 2. Run 03_rename_tables.sql +-- 3. Run Part 2 (CREATE) AFTER running 03_rename_tables.sql +-- ============================================================================ + +-- ============================================================================ +-- PART 1: DROP VIEWS (run BEFORE table renames) +-- ============================================================================ + +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; + +SELECT 'Views dropped. Now run 03_rename_tables.sql, then run Part 2 below.' AS status; + +-- ============================================================================ +-- PART 2: RECREATE VIEWS (run AFTER table renames) +-- Note: These views now reference machineoverrides instead of machine_overrides +-- Note: pc_to_machine_id_mapping is kept for now as it's used for pcid mapping +-- ============================================================================ + +-- vw_active_pcs +CREATE VIEW vw_active_pcs AS +SELECT + pcmap.pcid AS pcid, + m.hostname AS hostname, + m.serialnumber AS serialnumber, + COALESCE(v.vendor,'Unknown') AS manufacturer, + md.modelnumber AS model, + m.loggedinuser AS loggedinuser, + m.machinenumber AS machinenumber, + COALESCE(os.operatingsystem,'Unknown') AS operatingsystem, + COALESCE(pt.typename,'Unknown') AS pctype, + COALESCE(pt.description,'Unknown') AS typedescription, + CASE + WHEN w.enddate IS NULL THEN 'Unknown' + WHEN w.enddate < CURDATE() THEN 'Expired' + WHEN w.enddate < (CURDATE() + INTERVAL 90 DAY) THEN 'Expiring Soon' + ELSE 'Active' + END AS warrantystatus, + w.enddate AS warrantyenddate, + CASE + WHEN w.enddate IS NULL THEN NULL + ELSE (TO_DAYS(w.enddate) - TO_DAYS(CURDATE())) + END AS warrantydaysremaining, + m.lastupdated AS lastupdated, + (TO_DAYS(NOW()) - TO_DAYS(m.lastupdated)) AS daysold, + 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 +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 +LEFT JOIN operatingsystems os ON m.osid = os.osid +LEFT JOIN warranties w ON m.machineid = w.machineid +WHERE m.lastupdated > (NOW() - INTERVAL 30 DAY) +AND m.pctypeid IS NOT NULL; + +-- vw_dnc_config +CREATE VIEW vw_dnc_config AS +SELECT + pcmap.pcid AS pcid, + m.hostname AS hostname, + m.machinenumber AS machinenumber, + c.address AS ip_address, + c.port AS socket, + c.settings AS config_settings, + ct.typename AS comm_type +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.isactive = 1 +LEFT JOIN comstypes ct ON c.comstypeid = ct.comstypeid +WHERE m.pctypeid IS NOT NULL +AND ct.typename IN ('IP','Serial') +ORDER BY m.hostname, ct.typename; + +-- 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, + m1.machineid AS pc_machineid, + m1.hostname AS pc_hostname, + m1.machinenumber AS pc_machinenumber, + m2.machineid AS assigned_machine_id, + m2.machinenumber AS assigned_machine_number, + m2.hostname AS assigned_machine_hostname, + rt.relationshiptype AS relationshiptype +FROM machines m1 +JOIN pc_to_machine_id_mapping pcmap ON m1.machineid = pcmap.new_machineid +LEFT JOIN machinerelationships mr ON m1.machineid = mr.machineid AND mr.isactive = 1 +LEFT JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid AND rt.relationshiptype = 'Controlled By' +LEFT JOIN machines m2 ON mr.related_machineid = m2.machineid +WHERE m1.pctypeid IS NOT NULL +ORDER BY m1.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 (uses machineoverrides - NEW NAME) +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; + +-- ============================================================================ +-- VERIFICATION +-- ============================================================================ + +SELECT 'Verifying views recreated...' AS status; + +SELECT TABLE_NAME, VIEW_DEFINITION IS NOT NULL AS has_definition +FROM INFORMATION_SCHEMA.VIEWS +WHERE TABLE_SCHEMA = DATABASE() +AND TABLE_NAME IN ( + 'vw_active_pcs', + 'vw_dnc_config', + 'vw_engineer_pcs', + 'vw_pc_network_summary', + 'vw_pc_resolved_machines', + 'vw_pcs_by_hardware', + 'vw_shopfloor_comm_config', + 'vw_shopfloor_pcs', + 'vw_standard_pcs' +); + +SELECT 'Views recreated successfully!' AS status; diff --git a/sql/naming_convention_fix/05_update_asp_files.sh b/sql/naming_convention_fix/05_update_asp_files.sh new file mode 100644 index 0000000..8ba6cde --- /dev/null +++ b/sql/naming_convention_fix/05_update_asp_files.sh @@ -0,0 +1,98 @@ +#!/bin/bash +# ============================================================================ +# Script: 05_update_asp_files.sh +# Purpose: Update ASP files to use new table names +# Target: ShopDB ASP files +# +# USAGE: Run from shopdb directory +# cd /path/to/shopdb +# bash sql/naming_convention_fix/05_update_asp_files.sh +# +# This will show what changes will be made. Add --execute to actually apply. +# ============================================================================ + +set -e + +SHOPDB_DIR="${1:-.}" +EXECUTE_MODE="${2:-}" + +echo "============================================" +echo "ASP File Table Name Updates" +echo "============================================" +echo "" + +# Define replacements (old -> new) +declare -A REPLACEMENTS=( + ["machine_overrides"]="machineoverrides" + ["pc_comm_config"]="commconfig" + ["pc_dnc_config"]="dncconfig" + ["pc_dualpath_assignments"]="dualpathassignments" + ["pc_network_interfaces"]="networkinterfaces" + ["usb_checkouts"]="usbcheckouts" +) + +# Files to update (from impact analysis) +declare -A FILE_TABLES=( + ["api.asp"]="pc_comm_config pc_dnc_config" + ["displaypc.asp"]="pc_network_interfaces" + ["displaysubnet.asp"]="pc_network_interfaces" + ["displaymachine.asp"]="pc_network_interfaces" + ["usb_history.asp"]="usb_checkouts" + ["savecheckin_usb.asp"]="usb_checkouts" + ["displayprofile.asp"]="usb_checkouts" + ["displayusb.asp"]="usb_checkouts" + ["savecheckout_usb.asp"]="usb_checkouts" + ["api_usb.asp"]="usb_checkouts" +) + +echo "Changes to be made:" +echo "" + +for file in "${!FILE_TABLES[@]}"; do + filepath="$SHOPDB_DIR/$file" + if [ -f "$filepath" ]; then + tables="${FILE_TABLES[$file]}" + echo "--- $file ---" + for table in $tables; do + new_name="${REPLACEMENTS[$table]}" + matches=$(grep -c "$table" "$filepath" 2>/dev/null || echo "0") + if [ "$matches" -gt 0 ]; then + echo " $table -> $new_name ($matches occurrences)" + grep -n "$table" "$filepath" | head -5 + fi + done + echo "" + else + echo "WARNING: $file not found!" + fi +done + +if [ "$EXECUTE_MODE" == "--execute" ]; then + echo "" + echo "============================================" + echo "EXECUTING CHANGES..." + echo "============================================" + echo "" + + for file in "${!FILE_TABLES[@]}"; do + filepath="$SHOPDB_DIR/$file" + if [ -f "$filepath" ]; then + tables="${FILE_TABLES[$file]}" + for table in $tables; do + new_name="${REPLACEMENTS[$table]}" + sed -i "s/$table/$new_name/g" "$filepath" + echo "Updated $file: $table -> $new_name" + done + fi + done + + echo "" + echo "ASP files updated successfully!" +else + echo "" + echo "============================================" + echo "DRY RUN COMPLETE" + echo "============================================" + echo "To apply changes, run:" + echo " bash sql/naming_convention_fix/05_update_asp_files.sh . --execute" +fi diff --git a/sql/naming_convention_fix/06_update_docs.sh b/sql/naming_convention_fix/06_update_docs.sh new file mode 100644 index 0000000..abf64c4 --- /dev/null +++ b/sql/naming_convention_fix/06_update_docs.sh @@ -0,0 +1,79 @@ +#!/bin/bash +# ============================================================================ +# Script: 06_update_docs.sh +# Purpose: Update documentation files to reference new table names +# Target: ShopDB and PowerShell-scripts repos +# +# USAGE: +# cd /path/to/shopdb +# bash sql/naming_convention_fix/06_update_docs.sh [--execute] +# +# This is lower priority - docs can be updated anytime after migration +# ============================================================================ + +set -e + +EXECUTE_MODE="${1:-}" + +echo "============================================" +echo "Documentation Table Name Updates" +echo "============================================" +echo "" + +# Define replacements +declare -A REPLACEMENTS=( + ["machine_overrides"]="machineoverrides" + ["pc_comm_config"]="commconfig" + ["pc_dnc_config"]="dncconfig" + ["pc_dualpath_assignments"]="dualpathassignments" + ["pc_network_interfaces"]="networkinterfaces" + ["usb_checkouts"]="usbcheckouts" +) + +echo "Searching for documentation files with old table names..." +echo "" + +# Find all md files with old table names +for old_name in "${!REPLACEMENTS[@]}"; do + new_name="${REPLACEMENTS[$old_name]}" + echo "--- $old_name -> $new_name ---" + + # Search in current directory and subdirectories + files=$(grep -rl "$old_name" --include="*.md" . 2>/dev/null || true) + + if [ -n "$files" ]; then + for f in $files; do + count=$(grep -c "$old_name" "$f" 2>/dev/null || echo "0") + echo " $f ($count occurrences)" + done + else + echo " (no matches)" + fi + echo "" +done + +if [ "$EXECUTE_MODE" == "--execute" ]; then + echo "============================================" + echo "EXECUTING CHANGES..." + echo "============================================" + echo "" + + for old_name in "${!REPLACEMENTS[@]}"; do + new_name="${REPLACEMENTS[$old_name]}" + # Update all md files + find . -name "*.md" -type f -exec sed -i "s/$old_name/$new_name/g" {} \; + echo "Updated all .md files: $old_name -> $new_name" + done + + echo "" + echo "Documentation updated successfully!" +else + echo "============================================" + echo "DRY RUN COMPLETE" + echo "============================================" + echo "To apply changes, run:" + echo " bash sql/naming_convention_fix/06_update_docs.sh --execute" + echo "" + echo "NOTE: Documentation updates are low priority." + echo " Focus on database and ASP changes first." +fi diff --git a/sql/naming_convention_fix/PRODUCTION_DEPLOYMENT_GUIDE.md b/sql/naming_convention_fix/PRODUCTION_DEPLOYMENT_GUIDE.md new file mode 100644 index 0000000..3ad4259 --- /dev/null +++ b/sql/naming_convention_fix/PRODUCTION_DEPLOYMENT_GUIDE.md @@ -0,0 +1,251 @@ +# Database Naming Convention Fix - Production Deployment Guide + +## Overview + +This guide covers migrating table names from `snake_case` to `camelCase` to match the existing naming convention in ShopDB. + +**Target Environment:** +- Production Server: Windows with IIS +- Database: MySQL 5.6 + +**Tables being renamed:** +| Old Name | New Name | +|----------|----------| +| `machine_overrides` | `machineoverrides` | +| `pc_comm_config` | `commconfig` | +| `pc_dnc_config` | `dncconfig` | +| `pc_dualpath_assignments` | `dualpathassignments` | +| `pc_network_interfaces` | `networkinterfaces` | +| `usb_checkouts` | `usbcheckouts` | + +**Tables being dropped (migration backups):** +- `_backup_equipment_ips_phase1_5` +- `pc_backup_phase2` + +**Note:** `pc_to_machine_id_mapping` is kept for now as views depend on it for pcid->machineid mapping. + +--- + +## Pre-Deployment Checklist + +- [ ] Full database backup completed +- [ ] IIS can be stopped briefly (coordinate with users) +- [ ] All scripts tested on dev environment +- [ ] ASP file changes committed to git and ready to deploy +- [ ] Rollback plan ready + +--- + +## Deployment Steps + +### Phase 1: Preparation (No Downtime) + +1. **Backup production database (Windows)** + ```cmd + "C:\Program Files\MySQL\MySQL Server 5.6\bin\mysqldump.exe" -u root -p shopdb > C:\backups\shopdb_backup_%date:~-4,4%%date:~-10,2%%date:~-7,2%.sql + ``` + + Or using MySQL Workbench: + - Server > Data Export + - Select `shopdb` database + - Export to Self-Contained File + +2. **Prepare ASP files for deployment** + - Pull latest from Gitea with updated table names + - Or have files ready to copy + +### Phase 2: Database Migration (Brief Downtime ~2-5 min) + +1. **Stop IIS** (Administrator Command Prompt) + ```cmd + iisreset /stop + ``` + +2. **Connect to production MySQL 5.6** + ```cmd + "C:\Program Files\MySQL\MySQL Server 5.6\bin\mysql.exe" -u root -p shopdb + ``` + + Or use MySQL Workbench to connect. + +3. **Drop dependent views (Part 1 of script 04)** + ```sql + 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; + ``` + +4. **Rename tables (script 03)** + ```sql + 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; + ``` + +5. **Recreate views (Part 2 of script 04)** + - Run the CREATE VIEW statements from `04_drop_and_recreate_views.sql` + - Can copy/paste into MySQL Workbench or run as script + +6. **Verify tables renamed** + ```sql + SHOW TABLES LIKE '%config%'; + SHOW TABLES LIKE '%override%'; + SHOW TABLES LIKE '%checkout%'; + ``` + +7. **Verify views working** + ```sql + SELECT COUNT(*) FROM vw_shopfloor_pcs; + SELECT COUNT(*) FROM vw_active_pcs; + ``` + +8. **Deploy updated ASP files** + - Copy updated ASP files to IIS web directory + - Or pull from git + +9. **Start IIS** + ```cmd + iisreset /start + ``` + +10. **Test key pages in browser:** + - http://yourserver/displaypcs.asp + - http://yourserver/displayusb.asp + - http://yourserver/api.asp (test endpoint) + +### Phase 3: Cleanup (Optional, No Downtime) + +1. **Drop migration backup tables** (only after confirming everything works) + ```sql + DROP TABLE IF EXISTS _backup_equipment_ips_phase1_5; + DROP TABLE IF EXISTS pc_backup_phase2; + ``` + +2. **Update documentation** (low priority, can do anytime) + +--- + +## Rollback Plan + +If issues occur, restore from backup: + +**Windows Command Prompt (as Administrator):** +```cmd +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_YYYYMMDD.sql + +REM Restore original ASP files from git or backup +cd C:\inetpub\wwwroot\shopdb +git checkout HEAD~1 -- *.asp + +REM Start IIS +iisreset /start +``` + +--- + +## Files Changed + +### ASP Files (9 files) +| File | Tables Referenced | +|------|-------------------| +| api.asp | commconfig, dncconfig | +| displaypc.asp | networkinterfaces | +| displaysubnet.asp | networkinterfaces | +| displaymachine.asp | networkinterfaces | +| usb_history.asp | usbcheckouts | +| savecheckin_usb.asp | usbcheckouts | +| displayprofile.asp | usbcheckouts | +| displayusb.asp | usbcheckouts | +| savecheckout_usb.asp | usbcheckouts | +| api_usb.asp | usbcheckouts | + +### Views Recreated (9 views) +- vw_active_pcs +- vw_dnc_config +- vw_engineer_pcs +- vw_pc_network_summary +- vw_pc_resolved_machines +- vw_pcs_by_hardware +- vw_shopfloor_comm_config +- vw_shopfloor_pcs (references machineoverrides) +- vw_standard_pcs + +--- + +## Production Commands Quick Reference + +Copy and paste these into MySQL Workbench or mysql command line: + +```sql +-- ============================================= +-- STEP 1: Drop 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; + +-- ============================================= +-- STEP 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; + +-- ============================================= +-- STEP 3: Recreate views +-- Copy from 04_drop_and_recreate_views.sql Part 2 +-- ============================================= + +-- ============================================= +-- STEP 4: Verify +-- ============================================= +SHOW TABLES; +SELECT COUNT(*) FROM vw_shopfloor_pcs; +SELECT COUNT(*) FROM vw_active_pcs; +``` + +--- + +## Windows IIS Commands Reference + +```cmd +REM Stop IIS completely +iisreset /stop + +REM Start IIS +iisreset /start + +REM Restart IIS (stop then start) +iisreset /restart + +REM Check IIS status +iisreset /status +``` + +--- + +## Gitea Issue + +Track progress at: http://localhost:3000/cproudlock/shopdb/issues/1