Files
shopdb/sql/migration_drop_legacy_tables.sql
cproudlock 0e3371f458 Add database view consolidation and migrate legacy tables
- Drop 27 unused views, create 24 new purpose-built views
- New views cover: equipment, PCs, printers, notifications, applications,
  knowledge base, USB history, subnets, maps, and reports/charts
- Migration scripts for legacy network device tables (servers, cameras,
  switches, accesspoints, idfs) to unified machines table
- Migration scripts for legacy tables (machineoverrides, dualpathassignments,
  networkinterfaces)
- Update displaydevice.asp and displaylocationdevice.asp to use machines table
- Fix deviceserver.asp type mismatch error with HTMLEncode
- Hide Applications tab for equipment in displaymachine.asp

🤖 Generated with [Claude Code](https://claude.com/claude-code)

Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
2025-12-11 11:16:48 -05:00

82 lines
3.3 KiB
SQL

-- ============================================================================
-- Migration: Drop Legacy Tables
--
-- This script removes unused legacy tables after data migration to unified
-- tables (machinerelationships, communications).
--
-- Tables to drop:
-- - machineoverrides (empty, functionality not used)
-- - dualpathassignments (migrated to machinerelationships)
-- - networkinterfaces (migrated to communications)
-- - _backup_equipment_ips_phase1_5 (old migration backup)
--
-- IMPORTANT: Run this on DEV first and test thoroughly before production!
-- ============================================================================
-- ============================================================================
-- STEP 1: Drop views that reference legacy tables
-- ============================================================================
DROP VIEW IF EXISTS vw_shopfloor_pcs;
-- ============================================================================
-- STEP 2: Drop FK constraints on legacy tables
-- ============================================================================
ALTER TABLE dualpathassignments DROP FOREIGN KEY fk_dualpathassignments_machines;
ALTER TABLE machineoverrides DROP FOREIGN KEY fk_machineoverrides_machines;
ALTER TABLE networkinterfaces DROP FOREIGN KEY fk_networkinterfaces_machines;
-- ============================================================================
-- STEP 3: Drop the legacy tables
-- ============================================================================
DROP TABLE IF EXISTS machineoverrides;
DROP TABLE IF EXISTS dualpathassignments;
DROP TABLE IF EXISTS networkinterfaces;
DROP TABLE IF EXISTS _backup_equipment_ips_phase1_5;
-- ============================================================================
-- STEP 4: Recreate vw_shopfloor_pcs without machineoverrides reference
-- ============================================================================
CREATE VIEW vw_shopfloor_pcs AS
SELECT
m.machineid,
m.hostname,
m.serialnumber,
v.vendor AS manufacturer,
md.modelnumber AS model,
m.loggedinuser,
m.machinenumber,
COALESCE(os.operatingsystem, 'Unknown') AS operatingsystem,
m.lastupdated,
m.lastboottime,
DATEDIFF(NOW(), m.lastboottime) AS uptime_days
FROM machines m
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 = 'Shopfloor'
AND m.lastupdated > DATE_SUB(NOW(), INTERVAL 30 DAY)
AND m.pctypeid IS NOT NULL
ORDER BY m.machinenumber, m.hostname;
-- ============================================================================
-- STEP 5: Verify
-- ============================================================================
-- Should NOT show dropped tables
SELECT 'Verifying tables are dropped:' AS status;
SHOW TABLES LIKE 'machineoverrides';
SHOW TABLES LIKE 'dualpathassignments';
SHOW TABLES LIKE 'networkinterfaces';
SHOW TABLES LIKE '_backup%';
-- Verify view works
SELECT 'Testing vw_shopfloor_pcs:' AS status;
SELECT COUNT(*) AS shopfloor_pc_count FROM vw_shopfloor_pcs;
SELECT 'Migration complete! Legacy tables have been dropped.' AS status;