Files
shopdb/sql/migration_drop_network_device_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

162 lines
6.1 KiB
SQL

-- ============================================================================
-- Migration: Drop Legacy Network Device Tables
--
-- This script removes the old network device tables (accesspoints, cameras,
-- idfs, servers, switches) after migrating all data and dependencies to use
-- the unified machines table.
--
-- IMPORTANT: Run this on DEV first and test thoroughly before production!
--
-- Prerequisites:
-- - All network devices should already be in machines table with appropriate
-- machinetypeid values (16=Access Point, 17=Camera, 18=IDF, 19=Switch, 20=Server)
-- - displaydevice.asp and displaylocationdevice.asp should be updated to
-- use machines table instead of legacy tables
-- - networkdevices.asp already uses vw_network_devices (no changes needed)
-- - deviceserver.asp already uses machines table (no changes needed)
-- ============================================================================
-- ============================================================================
-- STEP 1: Migrate any remaining data from legacy servers table to machines
-- ============================================================================
-- The 3 servers in the legacy table need to be migrated to machines table
-- Check if they already exist (by hostname/alias or IP)
-- If not, insert them
-- First, check what we're working with
SELECT 'Servers to migrate:' AS status;
SELECT serverid, servername, ipaddress, description, fqdn FROM servers;
-- Insert servers that don't already exist in machines (matching by FQDN or name)
INSERT INTO machines (alias, machinetypeid, serialnumber, fqdn, machinenotes, isactive, maptop, mapleft, lastupdated)
SELECT
TRIM(s.servername) AS alias,
20 AS machinetypeid, -- Server
s.serialnumber,
s.fqdn,
s.description AS machinenotes,
CASE WHEN s.isactive = '' OR s.isactive IS NULL THEN 1 ELSE 1 END AS isactive,
NULL AS maptop,
NULL AS mapleft,
NOW() AS lastupdated
FROM servers s
WHERE NOT EXISTS (
SELECT 1 FROM machines m
WHERE m.machinetypeid = 20
AND (
(m.fqdn IS NOT NULL AND m.fqdn = s.fqdn)
OR (m.alias IS NOT NULL AND m.alias = TRIM(s.servername))
)
);
-- Add IP addresses to communications table for migrated servers
INSERT INTO communications (machineid, comstypeid, address, isprimary, isactive)
SELECT
m.machineid,
1 AS comstypeid, -- IP type
TRIM(s.ipaddress) AS address,
1 AS isprimary,
1 AS isactive
FROM servers s
JOIN machines m ON (
m.machinetypeid = 20
AND (
(m.fqdn IS NOT NULL AND m.fqdn = s.fqdn)
OR (m.alias IS NOT NULL AND m.alias = TRIM(s.servername))
)
)
WHERE s.ipaddress IS NOT NULL
AND TRIM(s.ipaddress) <> ''
AND NOT EXISTS (
SELECT 1 FROM communications c
WHERE c.machineid = m.machineid
AND c.address = TRIM(s.ipaddress)
);
-- ============================================================================
-- STEP 2: Drop Foreign Key Constraints
-- ============================================================================
-- cameras.idfid references idfs.idfid
ALTER TABLE cameras DROP FOREIGN KEY cameras_ibfk_1;
-- ============================================================================
-- STEP 3: Drop Views that depend on legacy tables
-- ============================================================================
DROP VIEW IF EXISTS vw_idf_inventory;
DROP VIEW IF EXISTS vw_infrastructure_summary;
-- ============================================================================
-- STEP 4: Drop the legacy tables
-- ============================================================================
DROP TABLE IF EXISTS cameras;
DROP TABLE IF EXISTS switches;
DROP TABLE IF EXISTS accesspoints;
DROP TABLE IF EXISTS servers;
DROP TABLE IF EXISTS idfs;
-- ============================================================================
-- STEP 5: Recreate views using machines table
-- ============================================================================
-- vw_idf_inventory: IDF locations with camera counts
-- IDFs are machinetypeid = 17, Cameras are machinetypeid = 18
CREATE VIEW vw_idf_inventory AS
SELECT
m.machineid AS idfid,
COALESCE(m.alias, m.machinenumber) AS idfname,
m.machinenotes AS description,
m.maptop,
m.mapleft,
(SELECT COUNT(DISTINCT cam.machineid)
FROM machines cam
JOIN machinerelationships mr ON cam.machineid = mr.machineid
WHERE mr.related_machineid = m.machineid
AND cam.machinetypeid = 18
AND cam.isactive = 1) AS camera_count,
m.isactive
FROM machines m
WHERE m.machinetypeid = 17 -- IDF
AND m.isactive = 1;
-- vw_infrastructure_summary: Counts of network device types
CREATE VIEW vw_infrastructure_summary AS
SELECT
mt.machinetype AS device_type,
COUNT(*) AS total_count,
SUM(CASE WHEN m.isactive = 1 THEN 1 ELSE 0 END) AS active_count
FROM machines m
JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid
WHERE m.machinetypeid IN (16, 17, 18, 19, 20) -- Network device types
GROUP BY mt.machinetypeid, mt.machinetype
ORDER BY mt.machinetype;
-- ============================================================================
-- STEP 6: Verify
-- ============================================================================
-- Should NOT show legacy tables anymore
SELECT 'Tables remaining with legacy names:' AS status;
SHOW TABLES LIKE 'accesspoints';
SHOW TABLES LIKE 'cameras';
SHOW TABLES LIKE 'idfs';
SHOW TABLES LIKE 'servers';
SHOW TABLES LIKE 'switches';
-- Verify network devices are accessible via machines table
SELECT 'Network devices in machines table:' AS status;
SELECT mt.machinetype, COUNT(*) as cnt
FROM machines m
JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid
WHERE m.machinetypeid IN (16, 17, 18, 19, 20)
GROUP BY mt.machinetypeid, mt.machinetype;
-- Verify views work
SELECT 'Testing vw_infrastructure_summary:' AS status;
SELECT * FROM vw_infrastructure_summary;
SELECT 'Migration complete! Legacy network device tables have been dropped.' AS status;