From 0e3371f458b3300dfe927d32c28b67c6c4ddbafd Mon Sep 17 00:00:00 2001 From: cproudlock Date: Thu, 11 Dec 2025 11:16:48 -0500 Subject: [PATCH] Add database view consolidation and migrate legacy tables MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit - 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 --- deviceserver.asp | 15 +- displaydevice.asp | 86 ++- displaylocationdevice.asp | 12 +- displaymachine.asp | 4 + sql/fix_views_prod.sql | 20 + sql/migration_drop_legacy_tables.sql | 81 ++ sql/migration_drop_network_device_tables.sql | 161 ++++ sql/view_consolidation.sql | 763 +++++++++++++++++++ 8 files changed, 1095 insertions(+), 47 deletions(-) create mode 100644 sql/fix_views_prod.sql create mode 100644 sql/migration_drop_legacy_tables.sql create mode 100644 sql/migration_drop_network_device_tables.sql create mode 100644 sql/view_consolidation.sql diff --git a/deviceserver.asp b/deviceserver.asp index 92540bb..737306d 100644 --- a/deviceserver.asp +++ b/deviceserver.asp @@ -41,17 +41,18 @@ Response.End End If - If Not IsNull(rs("servername")) Then servername = rs("servername") Else servername = "" + ' Convert all text fields to string to avoid type mismatch with HTMLEncode + If Not IsNull(rs("servername")) Then servername = rs("servername") & "" Else servername = "" If Not IsNull(rs("modelid")) Then modelid = rs("modelid") Else modelid = "" - If Not IsNull(rs("serialnumber")) Then serialnumber = rs("serialnumber") Else serialnumber = "" - If Not IsNull(rs("ipaddress")) Then ipaddress = rs("ipaddress") Else ipaddress = "" - If Not IsNull(rs("fqdn")) Then fqdn = rs("fqdn") Else fqdn = "" - If Not IsNull(rs("description")) Then description = rs("description") Else description = "" + If Not IsNull(rs("serialnumber")) Then serialnumber = rs("serialnumber") & "" Else serialnumber = "" + If Not IsNull(rs("ipaddress")) Then ipaddress = rs("ipaddress") & "" Else ipaddress = "" + If Not IsNull(rs("fqdn")) Then fqdn = rs("fqdn") & "" Else fqdn = "" + If Not IsNull(rs("description")) Then description = rs("description") & "" Else description = "" If Not IsNull(rs("maptop")) Then maptop = rs("maptop") Else maptop = "" If Not IsNull(rs("mapleft")) Then mapleft = rs("mapleft") Else mapleft = "" If Not IsNull(rs("isactive")) Then isactive = rs("isactive") Else isactive = 1 - If Not IsNull(rs("vendor")) Then vendorname = rs("vendor") Else vendorname = "" - If Not IsNull(rs("modelnumber")) Then modelnumber = rs("modelnumber") Else modelnumber = "" + If Not IsNull(rs("vendor")) Then vendorname = rs("vendor") & "" Else vendorname = "" + If Not IsNull(rs("modelnumber")) Then modelnumber = rs("modelnumber") & "" Else modelnumber = "" rs.Close Set rs = Nothing diff --git a/displaydevice.asp b/displaydevice.asp index b723846..c07942a 100644 --- a/displaydevice.asp +++ b/displaydevice.asp @@ -26,61 +26,77 @@ End If ' Build query based on device type - Dim strSQL, rs, tableName, idField, editUrl, listUrl + ' All network devices now use unified machines table with machinetypeid: + ' 16 = Access Point, 17 = Camera, 18 = IDF, 19 = Switch, 20 = Server + Dim strSQL, rs, tableName, idField, editUrl, listUrl, machineTypeId Select Case LCase(deviceType) Case "idf" - tableName = "idfs" - idField = "idfid" + machineTypeId = 18 editUrl = "deviceidf.asp?id=" & deviceId listUrl = "networkdevices.asp?filter=IDF" - strSQL = "SELECT i.idfid, i.idfname, i.description, i.maptop, i.mapleft, i.isactive, " & _ - "NULL AS vendor, NULL AS modelnumber, NULL AS serialnumber, NULL AS ipaddress, NULL AS macaddress, 'IDF' AS devicetype " & _ - "FROM idfs i WHERE i.idfid = " & CLng(deviceId) + strSQL = "SELECT mac.machineid, COALESCE(mac.alias, mac.machinenumber) AS idfname, " & _ + "mac.machinenotes AS description, mac.maptop, mac.mapleft, mac.isactive, " & _ + "NULL AS vendor, NULL AS modelnumber, NULL AS serialnumber, NULL AS ipaddress, NULL AS macaddress, " & _ + "'IDF' AS devicetype " & _ + "FROM machines mac " & _ + "WHERE mac.machineid = " & CLng(deviceId) & " AND mac.machinetypeid = 18" Case "server" - tableName = "servers" - idField = "serverid" + machineTypeId = 20 editUrl = "deviceserver.asp?id=" & deviceId listUrl = "networkdevices.asp?filter=Server" - strSQL = "SELECT s.*, v.vendor, m.modelnumber, s.serialnumber, s.ipaddress, NULL AS macaddress, NULL AS idfname, 'Server' AS devicetype, " & _ - "s.servername AS devicename " & _ - "FROM servers s " & _ - "LEFT JOIN models m ON s.modelid = m.modelnumberid " & _ + strSQL = "SELECT mac.machineid, mac.alias AS servername, mac.machinenotes AS description, " & _ + "mac.maptop, mac.mapleft, mac.isactive, mac.serialnumber, mac.fqdn, " & _ + "v.vendor, m.modelnumber, c.address AS ipaddress, c.macaddress, " & _ + "NULL AS idfname, 'Server' AS devicetype, " & _ + "mac.alias AS devicename " & _ + "FROM machines mac " & _ + "LEFT JOIN models m ON mac.modelnumberid = m.modelnumberid " & _ "LEFT JOIN vendors v ON m.vendorid = v.vendorid " & _ - "WHERE s.serverid = " & CLng(deviceId) + "LEFT JOIN communications c ON mac.machineid = c.machineid AND c.isprimary = 1 AND c.comstypeid = 1 " & _ + "WHERE mac.machineid = " & CLng(deviceId) & " AND mac.machinetypeid = 20" Case "switch" - tableName = "switches" - idField = "switchid" + machineTypeId = 19 editUrl = "deviceswitch.asp?id=" & deviceId listUrl = "networkdevices.asp?filter=Switch" - strSQL = "SELECT s.*, v.vendor, m.modelnumber, s.serialnumber, s.ipaddress, NULL AS macaddress, NULL AS idfname, 'Switch' AS devicetype, " & _ - "s.switchname AS devicename " & _ - "FROM switches s " & _ - "LEFT JOIN models m ON s.modelid = m.modelnumberid " & _ + strSQL = "SELECT mac.machineid, mac.alias AS switchname, mac.machinenotes AS description, " & _ + "mac.maptop, mac.mapleft, mac.isactive, mac.serialnumber, mac.fqdn, " & _ + "v.vendor, m.modelnumber, c.address AS ipaddress, c.macaddress, " & _ + "NULL AS idfname, 'Switch' AS devicetype, " & _ + "mac.alias AS devicename " & _ + "FROM machines mac " & _ + "LEFT JOIN models m ON mac.modelnumberid = m.modelnumberid " & _ "LEFT JOIN vendors v ON m.vendorid = v.vendorid " & _ - "WHERE s.switchid = " & CLng(deviceId) + "LEFT JOIN communications c ON mac.machineid = c.machineid AND c.isprimary = 1 AND c.comstypeid = 1 " & _ + "WHERE mac.machineid = " & CLng(deviceId) & " AND mac.machinetypeid = 19" Case "camera" - tableName = "cameras" - idField = "cameraid" + machineTypeId = 17 editUrl = "devicecamera.asp?id=" & deviceId listUrl = "networkdevices.asp?filter=Camera" - strSQL = "SELECT c.*, v.vendor, m.modelnumber, c.serialnumber, c.ipaddress, c.macaddress, i.idfname, 'Camera' AS devicetype, " & _ - "c.cameraname AS devicename " & _ - "FROM cameras c " & _ - "LEFT JOIN models m ON c.modelid = m.modelnumberid " & _ + strSQL = "SELECT mac.machineid, mac.alias AS cameraname, mac.machinenotes AS description, " & _ + "mac.maptop, mac.mapleft, mac.isactive, mac.serialnumber, mac.fqdn, " & _ + "v.vendor, m.modelnumber, c.address AS ipaddress, c.macaddress, " & _ + "idf.alias AS idfname, idf.machineid AS idfid, 'Camera' AS devicetype, " & _ + "mac.alias AS devicename " & _ + "FROM machines mac " & _ + "LEFT JOIN models m ON mac.modelnumberid = m.modelnumberid " & _ "LEFT JOIN vendors v ON m.vendorid = v.vendorid " & _ - "LEFT JOIN idfs i ON c.idfid = i.idfid " & _ - "WHERE c.cameraid = " & CLng(deviceId) + "LEFT JOIN communications c ON mac.machineid = c.machineid AND c.isprimary = 1 AND c.comstypeid = 1 " & _ + "LEFT JOIN machinerelationships mr ON mac.machineid = mr.machineid AND mr.isactive = 1 " & _ + "LEFT JOIN machines idf ON mr.related_machineid = idf.machineid AND idf.machinetypeid = 18 " & _ + "WHERE mac.machineid = " & CLng(deviceId) & " AND mac.machinetypeid = 17" Case "accesspoint", "access point" - tableName = "accesspoints" - idField = "apid" + machineTypeId = 16 editUrl = "deviceaccesspoint.asp?id=" & deviceId listUrl = "networkdevices.asp?filter=Access Point" - strSQL = "SELECT ap.apid, ap.apname AS devicename, ap.modelid, ap.serialnumber, ap.ipaddress, ap.description, ap.maptop, ap.mapleft, ap.isactive, " & _ - "v.vendor, m.modelnumber, NULL AS macaddress, NULL AS idfname, NULL AS idfid, 'Access Point' AS devicetype " & _ - "FROM accesspoints ap " & _ - "LEFT JOIN models m ON ap.modelid = m.modelnumberid " & _ + strSQL = "SELECT mac.machineid AS apid, mac.alias AS devicename, mac.modelnumberid AS modelid, " & _ + "mac.serialnumber, mac.machinenotes AS description, mac.maptop, mac.mapleft, mac.isactive, " & _ + "v.vendor, m.modelnumber, c.address AS ipaddress, c.macaddress, " & _ + "NULL AS idfname, NULL AS idfid, 'Access Point' AS devicetype " & _ + "FROM machines mac " & _ + "LEFT JOIN models m ON mac.modelnumberid = m.modelnumberid " & _ "LEFT JOIN vendors v ON m.vendorid = v.vendorid " & _ - "WHERE ap.apid = " & CLng(deviceId) + "LEFT JOIN communications c ON mac.machineid = c.machineid AND c.isprimary = 1 AND c.comstypeid = 1 " & _ + "WHERE mac.machineid = " & CLng(deviceId) & " AND mac.machinetypeid = 16" Case Else Response.Redirect("networkdevices.asp") Response.End diff --git a/displaylocationdevice.asp b/displaylocationdevice.asp index 06f5011..68f4aa9 100644 --- a/displaylocationdevice.asp +++ b/displaylocationdevice.asp @@ -22,17 +22,19 @@ End If ' Build query based on device type + ' All network devices now use unified machines table with machinetypeid: + ' 16 = Access Point, 17 = Camera, 18 = IDF, 19 = Switch, 20 = Server Select Case LCase(deviceType) Case "idf" - strSQL = "SELECT mapleft, maptop, idfname AS devicename FROM idfs WHERE idfid = " & CLng(deviceId) + strSQL = "SELECT mapleft, maptop, COALESCE(alias, machinenumber) AS devicename FROM machines WHERE machineid = " & CLng(deviceId) & " AND machinetypeid = 18" Case "server" - strSQL = "SELECT mapleft, maptop, servername AS devicename FROM servers WHERE serverid = " & CLng(deviceId) + strSQL = "SELECT mapleft, maptop, alias AS devicename FROM machines WHERE machineid = " & CLng(deviceId) & " AND machinetypeid = 20" Case "switch" - strSQL = "SELECT mapleft, maptop, switchname AS devicename FROM switches WHERE switchid = " & CLng(deviceId) + strSQL = "SELECT mapleft, maptop, alias AS devicename FROM machines WHERE machineid = " & CLng(deviceId) & " AND machinetypeid = 19" Case "camera" - strSQL = "SELECT mapleft, maptop, cameraname AS devicename FROM cameras WHERE cameraid = " & CLng(deviceId) + strSQL = "SELECT mapleft, maptop, alias AS devicename FROM machines WHERE machineid = " & CLng(deviceId) & " AND machinetypeid = 17" Case "accesspoint", "access point" - strSQL = "SELECT mapleft, maptop, apname AS devicename FROM accesspoints WHERE apid = " & CLng(deviceId) + strSQL = "SELECT mapleft, maptop, alias AS devicename FROM machines WHERE machineid = " & CLng(deviceId) & " AND machinetypeid = 16" Case Else Response.Write("

Unknown device type

") Response.End diff --git a/displaymachine.asp b/displaymachine.asp index 33f96e3..c4d73f3 100644 --- a/displaymachine.asp +++ b/displaymachine.asp @@ -164,9 +164,11 @@ +<% If Not IsNull(rs("pctypeid")) Then %> +<% End If %> @@ -756,6 +758,7 @@ End If End If %> +<% If Not IsNull(rs("pctypeid")) Then %>
@@ -784,6 +787,7 @@ End If
+<% End If %> diff --git a/sql/fix_views_prod.sql b/sql/fix_views_prod.sql new file mode 100644 index 0000000..ac3a31a --- /dev/null +++ b/sql/fix_views_prod.sql @@ -0,0 +1,20 @@ +-- ============================================================================ +-- Fix Views for Production +-- +-- This script has been superseded by view_consolidation.sql +-- +-- Run view_consolidation.sql instead, which: +-- 1. Drops 27 unused views +-- 2. Keeps 2 actually used views (vw_network_devices, vw_warranty_status) +-- 3. Creates 11 new purpose-built views for UI pages +-- +-- Also run these scripts for other pending migrations: +-- - migration_drop_network_device_tables.sql (migrates servers, drops legacy tables) +-- - migration_drop_legacy_tables.sql (drops machineoverrides, dualpathassignments, etc.) +-- +-- LocationOnly machine fix (run manually): +-- UPDATE machines SET modelnumberid = 1 WHERE islocationonly = 1; +-- ============================================================================ + +-- Just run view_consolidation.sql +SELECT 'Please run view_consolidation.sql instead of this script' AS message; diff --git a/sql/migration_drop_legacy_tables.sql b/sql/migration_drop_legacy_tables.sql new file mode 100644 index 0000000..bd3cfd5 --- /dev/null +++ b/sql/migration_drop_legacy_tables.sql @@ -0,0 +1,81 @@ +-- ============================================================================ +-- 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; diff --git a/sql/migration_drop_network_device_tables.sql b/sql/migration_drop_network_device_tables.sql new file mode 100644 index 0000000..f6d70d1 --- /dev/null +++ b/sql/migration_drop_network_device_tables.sql @@ -0,0 +1,161 @@ +-- ============================================================================ +-- 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; diff --git a/sql/view_consolidation.sql b/sql/view_consolidation.sql new file mode 100644 index 0000000..d9f02e1 --- /dev/null +++ b/sql/view_consolidation.sql @@ -0,0 +1,763 @@ +-- ============================================================================ +-- View Consolidation Script +-- +-- This script drops unused views and creates new purpose-built views that +-- match the actual UI page data needs for shopdb. +-- +-- Views Analysis: +-- - Only 2 views are actually used by ASP code: +-- * vw_network_devices (networkdevices.asp) +-- * vw_warranty_status (warrantychart.asp) +-- - 27 views are unused and will be dropped +-- - New views will be created to support list pages and potential framework migration +-- +-- IMPORTANT: Run this on DEV first and test thoroughly before production! +-- ============================================================================ + +-- ============================================================================ +-- STEP 1: Drop unused views (27 views) +-- ============================================================================ + +DROP VIEW IF EXISTS vw_active_pcs; +DROP VIEW IF EXISTS vw_compliance_summary; +DROP VIEW IF EXISTS vw_dnc_config; +DROP VIEW IF EXISTS vw_dualpath_machines; +DROP VIEW IF EXISTS vw_dualpath_management; +DROP VIEW IF EXISTS vw_engineer_pcs; +DROP VIEW IF EXISTS vw_ge_machines; +DROP VIEW IF EXISTS vw_idf_inventory; +DROP VIEW IF EXISTS vw_infrastructure_summary; +DROP VIEW IF EXISTS vw_machine_assignment_status; +DROP VIEW IF EXISTS vw_machine_assignments; +DROP VIEW IF EXISTS vw_machine_relationships; +DROP VIEW IF EXISTS vw_machine_type_stats; +DROP VIEW IF EXISTS vw_machinetype_comparison; +DROP VIEW IF EXISTS vw_multi_pc_machines; +DROP VIEW IF EXISTS vw_pc_network_summary; +DROP VIEW IF EXISTS vw_pc_resolved_machines; +DROP VIEW IF EXISTS vw_pc_summary; +DROP VIEW IF EXISTS vw_pcs_by_hardware; +DROP VIEW IF EXISTS vw_pctype_config; +DROP VIEW IF EXISTS vw_recent_updates; +DROP VIEW IF EXISTS vw_shopfloor_comm_config; +DROP VIEW IF EXISTS vw_shopfloor_pcs; +DROP VIEW IF EXISTS vw_standard_pcs; +DROP VIEW IF EXISTS vw_unmapped_machines; +DROP VIEW IF EXISTS vw_vendor_summary; +DROP VIEW IF EXISTS vw_warranties_expiring; + +SELECT 'Dropped 27 unused views' AS status; + +-- ============================================================================ +-- STEP 2: Keep existing used views (already exist, just documenting) +-- ============================================================================ +-- vw_network_devices - Used by networkdevices.asp +-- vw_warranty_status - Used by warrantychart.asp + +-- ============================================================================ +-- STEP 3: Create new purpose-built views for UI pages +-- ============================================================================ + +-- ----------------------------------------------------------------------------- +-- vw_equipment_list - For displaymachines.asp (Equipment List) +-- Shows all active equipment (non-PC, non-network-device machines) +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_equipment_list; + +CREATE VIEW vw_equipment_list AS +SELECT + m.machineid, + m.machinenumber, + m.hostname, + m.serialnumber, + m.maptop, + m.mapleft, + m.lastupdated, + m.isactive, + mt.machinetypeid, + mt.machinetype, + md.modelnumberid, + md.modelnumber, + v.vendorid, + v.vendor, + bu.businessunitid, + bu.businessunit, + -- Primary IP address from communications + (SELECT c.address FROM communications c + WHERE c.machineid = m.machineid AND c.isprimary = 1 AND c.comstypeid = 1 + LIMIT 1) AS ipaddress +FROM machines m +JOIN models md ON m.modelnumberid = md.modelnumberid +JOIN machinetypes mt ON md.machinetypeid = mt.machinetypeid +JOIN vendors v ON md.vendorid = v.vendorid +JOIN businessunits bu ON m.businessunitid = bu.businessunitid +WHERE m.isactive = 1 + AND m.islocationonly = 0 + AND md.machinetypeid NOT IN (1, 16, 17, 18, 19, 20) -- Exclude LocationOnly type and network devices + AND md.machinetypeid < 33; -- Exclude PC types + +-- ----------------------------------------------------------------------------- +-- vw_pc_list - For displaypcs.asp (PC List) +-- Shows all active PCs with equipment relationships, uptime, VNC/WinRM status +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_pc_list; + +CREATE VIEW vw_pc_list AS +SELECT + m.machineid, + m.hostname, + m.serialnumber, + m.machinenumber, + m.machinestatusid, + m.pctypeid, + m.modelnumberid, + m.osid, + m.loggedinuser, + m.lastupdated, + m.lastboottime, + m.isvnc, + m.iswinrm, + m.isactive, + -- Calculated uptime + DATEDIFF(NOW(), m.lastboottime) AS uptime_days, + -- Joined data + v.vendor, + md.modelnumber, + os.operatingsystem, + pt.typename AS pctype, + ms.machinestatus, + -- Primary IP/MAC from communications + c.address AS ipaddress, + c.macaddress, + -- Equipment relationship (PC controls equipment) + eq.machineid AS equipment_id, + eq.machinenumber AS equipment_number +FROM machines m +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 +LEFT JOIN pctype pt ON m.pctypeid = pt.pctypeid +LEFT JOIN machinestatus ms ON m.machinestatusid = ms.machinestatusid +LEFT JOIN communications c ON c.machineid = m.machineid AND c.isprimary = 1 +LEFT JOIN machinerelationships mr ON (mr.machineid = m.machineid OR mr.related_machineid = m.machineid) + AND mr.isactive = 1 AND mr.relationshiptypeid = 3 +LEFT JOIN machines eq ON (eq.machineid = mr.related_machineid OR eq.machineid = mr.machineid) + AND eq.machineid <> m.machineid AND eq.pctypeid IS NULL +WHERE m.isactive = 1 + AND m.pctypeid IS NOT NULL; + +-- ----------------------------------------------------------------------------- +-- vw_printer_list - For displayprinters.asp (Printer List) +-- Shows all active printers with machine/location info +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_printer_list; + +CREATE VIEW vw_printer_list AS +SELECT + p.printerid, + p.printerwindowsname, + p.printercsfname, + p.ipaddress, + p.serialnumber AS printer_serial, + md.image, + p.installpath, + p.isactive, + p.maptop, + p.mapleft, + -- Model/Vendor info + md.modelnumberid, + md.modelnumber, + md.documentationpath, + v.vendorid, + v.vendor, + -- Machine/Location info + m.machineid, + m.machinenumber, + m.islocationonly +FROM printers p +JOIN models md ON p.modelid = md.modelnumberid +JOIN vendors v ON md.vendorid = v.vendorid +JOIN machines m ON p.machineid = m.machineid +WHERE p.isactive = 1 +ORDER BY m.machinenumber; + +-- ----------------------------------------------------------------------------- +-- vw_machine_detail - For displaymachine.asp (Machine Detail Page) +-- Comprehensive machine info for the detail/edit page +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_machine_detail; + +CREATE VIEW vw_machine_detail AS +SELECT + m.machineid, + m.machinenumber, + m.hostname, + m.serialnumber, + m.alias, + m.fqdn, + m.machinenotes, + m.maptop, + m.mapleft, + m.lastupdated, + m.isactive, + m.islocationonly, + m.pctypeid, + m.machinestatusid, + m.businessunitid, + -- Type info + mt.machinetypeid, + mt.machinetype, + -- Model/Vendor info + md.modelnumberid, + md.modelnumber, + v.vendorid, + v.vendor, + -- Business unit + bu.businessunit, + -- Status + ms.machinestatus, + -- PC-specific info + pt.typename AS pctype, + os.operatingsystem, + m.loggedinuser, + m.lastboottime, + m.isvnc, + m.iswinrm, + -- Primary IP address + (SELECT c.address FROM communications c + WHERE c.machineid = m.machineid AND c.isprimary = 1 AND c.comstypeid = 1 + LIMIT 1) AS ipaddress, + -- Primary MAC address + (SELECT c.macaddress FROM communications c + WHERE c.machineid = m.machineid AND c.isprimary = 1 + LIMIT 1) AS macaddress +FROM machines m +LEFT JOIN models md ON m.modelnumberid = md.modelnumberid +LEFT JOIN machinetypes mt ON md.machinetypeid = mt.machinetypeid +LEFT JOIN vendors v ON md.vendorid = v.vendorid +LEFT JOIN businessunits bu ON m.businessunitid = bu.businessunitid +LEFT JOIN machinestatus ms ON m.machinestatusid = ms.machinestatusid +LEFT JOIN pctype pt ON m.pctypeid = pt.pctypeid +LEFT JOIN operatingsystems os ON m.osid = os.osid; + +-- ----------------------------------------------------------------------------- +-- vw_equipment_pc_relationships - For PC-Equipment relationship management +-- Shows which PCs control which equipment +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_equipment_pc_relationships; + +CREATE VIEW vw_equipment_pc_relationships AS +SELECT + mr.relationshipid, + mr.relationshiptypeid, + rt.relationshiptype, + -- PC info (the controller) + pc.machineid AS pc_machineid, + pc.hostname AS pc_hostname, + pc.machinenumber AS pc_machinenumber, + -- Equipment info (the controlled) + eq.machineid AS equipment_machineid, + eq.machinenumber AS equipment_machinenumber, + mt.machinetype AS equipment_type, + mr.isactive +FROM machinerelationships mr +JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid +JOIN machines pc ON mr.machineid = pc.machineid +JOIN machines eq ON mr.related_machineid = eq.machineid +LEFT JOIN models md ON eq.modelnumberid = md.modelnumberid +LEFT JOIN machinetypes mt ON md.machinetypeid = mt.machinetypeid +WHERE mr.relationshiptypeid = 3 -- 'Controls' relationship + AND pc.pctypeid IS NOT NULL -- PC must have a pctype + AND eq.pctypeid IS NULL; -- Equipment has no pctype + +-- ----------------------------------------------------------------------------- +-- vw_map_equipment - For machinemap.asp (Equipment Map) +-- Equipment with map coordinates for the shop floor map +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_map_equipment; + +CREATE VIEW vw_map_equipment AS +SELECT + m.machineid, + m.machinenumber, + m.maptop, + m.mapleft, + mt.machinetype, + m.islocationonly +FROM machines m +JOIN models md ON m.modelnumberid = md.modelnumberid +JOIN machinetypes mt ON md.machinetypeid = mt.machinetypeid +WHERE m.isactive = 1 + AND m.maptop IS NOT NULL + AND m.mapleft IS NOT NULL + AND md.machinetypeid < 16; -- Equipment only (not network devices or PCs) + +-- ----------------------------------------------------------------------------- +-- vw_map_printers - For printermap.asp (Printer Map) +-- Printers with map coordinates +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_map_printers; + +CREATE VIEW vw_map_printers AS +SELECT + p.printerid, + p.printerwindowsname, + p.printercsfname, + p.maptop, + p.mapleft, + m.machinenumber AS location_name +FROM printers p +JOIN machines m ON p.machineid = m.machineid +WHERE p.isactive = 1 + AND p.maptop IS NOT NULL + AND p.mapleft IS NOT NULL; + +-- ----------------------------------------------------------------------------- +-- vw_map_network_devices - For networkmap.asp (Network Device Map) +-- Network devices with map coordinates +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_map_network_devices; + +CREATE VIEW vw_map_network_devices AS +SELECT + m.machineid, + COALESCE(m.alias, m.machinenumber) AS device_name, + mt.machinetype AS device_type, + m.maptop, + m.mapleft +FROM machines m +JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid +WHERE m.isactive = 1 + AND m.machinetypeid IN (16, 17, 18, 19, 20) -- Network device types + AND m.maptop IS NOT NULL + AND m.mapleft IS NOT NULL; + +-- ----------------------------------------------------------------------------- +-- vw_warranty_summary - For warranty reporting/dashboard +-- Warranty status grouped for charts +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_warranty_summary; + +CREATE VIEW vw_warranty_summary AS +SELECT + CASE + WHEN w.enddate IS NULL THEN 'Unknown' + WHEN w.enddate < CURDATE() THEN 'Expired' + WHEN w.enddate < DATE_ADD(CURDATE(), INTERVAL 90 DAY) THEN 'Expiring Soon' + ELSE 'Active' + END AS warranty_status, + COUNT(*) AS device_count +FROM machines m +LEFT JOIN warranties w ON m.machineid = w.machineid +WHERE m.isactive = 1 + AND m.pctypeid IS NOT NULL -- PCs only for warranty tracking +GROUP BY warranty_status; + +-- ----------------------------------------------------------------------------- +-- vw_pctype_summary - For PC type breakdown/dashboard +-- Count of PCs by type +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_pctype_summary; + +CREATE VIEW vw_pctype_summary AS +SELECT + pt.pctypeid, + pt.typename, + COUNT(m.machineid) AS pc_count, + SUM(CASE WHEN m.isvnc = 1 THEN 1 ELSE 0 END) AS vnc_enabled_count, + SUM(CASE WHEN m.iswinrm = 1 THEN 1 ELSE 0 END) AS winrm_enabled_count +FROM pctype pt +LEFT JOIN machines m ON pt.pctypeid = m.pctypeid AND m.isactive = 1 +WHERE pt.isactive = 1 +GROUP BY pt.pctypeid, pt.typename +ORDER BY pt.typename; + +-- ----------------------------------------------------------------------------- +-- vw_equipment_type_summary - For equipment type breakdown/dashboard +-- Count of equipment by type +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_equipment_type_summary; + +CREATE VIEW vw_equipment_type_summary AS +SELECT + mt.machinetypeid, + mt.machinetype, + COUNT(m.machineid) AS equipment_count +FROM machinetypes mt +LEFT JOIN models md ON mt.machinetypeid = md.machinetypeid +LEFT JOIN machines m ON md.modelnumberid = m.modelnumberid AND m.isactive = 1 +WHERE mt.machinetypeid NOT IN (1, 16, 17, 18, 19, 20) -- Exclude LocationOnly and network devices + AND mt.machinetypeid < 33 -- Exclude PC types +GROUP BY mt.machinetypeid, mt.machinetype +ORDER BY mt.machinetype; + +-- ============================================================================= +-- NOTIFICATIONS VIEWS +-- ============================================================================= + +-- ----------------------------------------------------------------------------- +-- vw_active_notifications - For displaynotifications.asp +-- Active notifications with type info, business unit, and completion status +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_active_notifications; + +CREATE VIEW vw_active_notifications AS +SELECT + n.notificationid, + n.notification, + n.ticketnumber, + n.starttime, + n.endtime, + n.isactive, + n.notificationtypeid, + n.businessunitid, + nt.typename AS notification_type, + nt.typecolor, + bu.businessunit, + TIMESTAMPDIFF(MINUTE, n.endtime, NOW()) AS minutes_since_end, + CASE + WHEN n.endtime IS NOT NULL AND n.endtime < NOW() THEN 1 + ELSE 0 + END AS is_complete +FROM notifications n +LEFT JOIN notificationtypes nt ON n.notificationtypeid = nt.notificationtypeid +LEFT JOIN businessunits bu ON n.businessunitid = bu.businessunitid; + +-- ----------------------------------------------------------------------------- +-- vw_upcoming_notifications - For includes/notificationsbar.asp +-- Notifications for the top notification bar (upcoming and active) +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_upcoming_notifications; + +CREATE VIEW vw_upcoming_notifications AS +SELECT + n.notificationid, + n.notification, + n.ticketnumber, + n.starttime, + n.endtime, + n.isactive +FROM notifications n +WHERE n.starttime <= NOW() + INTERVAL 10 DAY + AND (n.endtime >= NOW() OR n.endtime IS NULL) + AND n.isactive = 1 +ORDER BY n.starttime ASC; + +-- ----------------------------------------------------------------------------- +-- vw_incident_durations - For charts/topincidentschart.asp +-- Resolved incidents with duration calculations for reporting +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_incident_durations; + +CREATE VIEW vw_incident_durations AS +SELECT + n.notificationid, + n.notification, + n.ticketnumber, + n.starttime, + n.endtime, + nt.typename AS notification_type, + TIMESTAMPDIFF(MINUTE, n.starttime, n.endtime) AS duration_minutes +FROM notifications n +INNER JOIN notificationtypes nt ON n.notificationtypeid = nt.notificationtypeid +WHERE n.starttime IS NOT NULL + AND n.endtime IS NOT NULL + AND n.endtime > n.starttime + AND nt.typename <> 'TBD'; + +-- ============================================================================= +-- APPLICATION VIEWS +-- ============================================================================= + +-- ----------------------------------------------------------------------------- +-- vw_applications_list - For displayapplications.asp +-- Applications with support team and app owner info +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_applications_list; + +CREATE VIEW vw_applications_list AS +SELECT + a.appid, + a.appname, + a.appdescription, + a.applicationlink, + a.installpath, + a.documentationpath, + a.isinstallable, + a.isactive, + st.supporteamid, + st.teamname AS supportteam, + ao.appownerid, + ao.appowner +FROM applications a +JOIN supportteams st ON a.supportteamid = st.supporteamid +JOIN appowners ao ON st.appownerid = ao.appownerid +WHERE a.isactive = 1; + +-- ----------------------------------------------------------------------------- +-- vw_knowledge_base - For displayknowledgebase.asp +-- Knowledge base articles with application names +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_knowledge_base; + +CREATE VIEW vw_knowledge_base AS +SELECT + kb.linkid, + kb.appid, + kb.shortdescription, + kb.linkurl, + kb.keywords, + kb.clicks, + kb.lastupdated, + kb.isactive, + app.appname +FROM knowledgebase kb +INNER JOIN applications app ON kb.appid = app.appid +WHERE kb.isactive = 1; + +-- ============================================================================= +-- USB DEVICE VIEWS +-- ============================================================================= + +-- ----------------------------------------------------------------------------- +-- vw_usb_checkout_history - For usbhistory.asp +-- USB checkout history with machine details and duration +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_usb_checkout_history; + +CREATE VIEW vw_usb_checkout_history AS +SELECT + uc.checkoutid, + uc.machineid, + uc.sso, + uc.checkout_time, + uc.checkin_time, + uc.checkout_reason, + uc.was_wiped, + m.serialnumber AS usb_serial, + m.alias AS usb_alias, + TIMESTAMPDIFF(MINUTE, uc.checkout_time, COALESCE(uc.checkin_time, NOW())) AS duration_minutes +FROM usbcheckouts uc +JOIN machines m ON uc.machineid = m.machineid; + +-- ============================================================================= +-- SUBNET VIEWS +-- ============================================================================= + +-- ----------------------------------------------------------------------------- +-- vw_subnet_list - For displaysubnets.asp +-- Subnets with type info and IP conversion +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_subnet_list; + +CREATE VIEW vw_subnet_list AS +SELECT + s.subnetid, + s.vlan, + s.ipstart, + INET_NTOA(s.ipstart) AS subnetstart, + s.cidr, + s.description, + s.isactive, + st.subnettypeid, + st.subnettype +FROM subnets s +JOIN subnettypes st ON s.subnettypeid = st.subnettypeid +WHERE s.isactive = 1 +ORDER BY s.vlan ASC; + +-- ============================================================================= +-- REPORT/CHART VIEWS +-- ============================================================================= + +-- ----------------------------------------------------------------------------- +-- vw_downtime_by_type - For charts/downtimechart.asp +-- Downtime summary grouped by notification type +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_downtime_by_type; + +CREATE VIEW vw_downtime_by_type AS +SELECT + nt.notificationtypeid, + nt.typename, + nt.typecolor, + COUNT(n.notificationid) AS incident_count, + COALESCE(SUM(TIMESTAMPDIFF(MINUTE, n.starttime, n.endtime)), 0) AS total_minutes, + n.starttime +FROM notifications n +INNER JOIN notificationtypes nt ON n.notificationtypeid = nt.notificationtypeid +WHERE n.starttime IS NOT NULL + AND n.endtime IS NOT NULL + AND n.endtime > n.starttime + AND nt.typename <> 'TBD' +GROUP BY nt.notificationtypeid, nt.typename, nt.typecolor, DATE(n.starttime); + +-- ----------------------------------------------------------------------------- +-- vw_installed_apps_summary - For charts/udcchart.asp and ma3chart.asp +-- Installed application counts for dashboard charts +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_installed_apps_summary; + +CREATE VIEW vw_installed_apps_summary AS +SELECT + a.appid, + a.appname, + COUNT(DISTINCT ia.machineid) AS install_count +FROM applications a +LEFT JOIN installedapps ia ON a.appid = ia.appid AND ia.isactive = 1 +WHERE a.isactive = 1 +GROUP BY a.appid, a.appname; + +-- ----------------------------------------------------------------------------- +-- vw_pc_app_stats - For UDC/CLM/MA3 charts +-- PC count with specific application install status +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_pc_app_stats; + +CREATE VIEW vw_pc_app_stats AS +SELECT + (SELECT COUNT(*) FROM machines WHERE isactive = 1 AND pctypeid IS NOT NULL) AS total_pcs, + COALESCE(SUM(CASE WHEN ia.appid = 2 THEN 1 ELSE 0 END), 0) AS udc_count, + COALESCE(SUM(CASE WHEN ia.appid = 4 THEN 1 ELSE 0 END), 0) AS clm_count, + COALESCE(SUM(CASE WHEN ia.appid = 42 THEN 1 ELSE 0 END), 0) AS ma3_count +FROM installedapps ia +WHERE ia.isactive = 1 + AND ia.appid IN (2, 4, 42); + +-- ----------------------------------------------------------------------------- +-- vw_kb_by_application - For charts/kbchart.asp +-- Knowledge base article counts grouped by application +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_kb_by_application; + +CREATE VIEW vw_kb_by_application AS +SELECT + a.appid, + a.appname, + COUNT(k.linkid) AS article_count +FROM applications a +LEFT JOIN knowledgebase k ON a.appid = k.appid AND k.isactive = 1 +WHERE a.isactive = 1 +GROUP BY a.appid, a.appname +HAVING article_count > 0 +ORDER BY article_count DESC; + +-- ----------------------------------------------------------------------------- +-- vw_network_map_devices - For networkmap.asp +-- Combined printers and network devices with map coordinates for the network map +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_network_map_devices; + +CREATE VIEW vw_network_map_devices AS +-- Printers +SELECT + p.printerid AS id, + m.machinenumber AS name, + m.alias, + p.mapleft, + p.maptop, + p.ipaddress, + NULL AS machinetypeid, + 'Printer' AS device_type, + mo.modelnumber, + v.vendor, + 'printers' AS source +FROM printers p +INNER JOIN machines m ON p.machineid = m.machineid +LEFT JOIN models mo ON p.modelid = mo.modelnumberid +LEFT JOIN vendors v ON mo.vendorid = v.vendorid +WHERE p.isactive = 1 + AND p.mapleft IS NOT NULL + AND p.maptop IS NOT NULL + +UNION ALL + +-- Network devices (Access Points, IDFs, Cameras, Switches, Servers) +SELECT + m.machineid AS id, + m.machinenumber AS name, + m.alias, + m.mapleft, + m.maptop, + c.address AS ipaddress, + m.machinetypeid, + mt.machinetype AS device_type, + mo.modelnumber, + v.vendor, + 'machines' AS source +FROM machines m +LEFT JOIN models mo ON m.modelnumberid = mo.modelnumberid +LEFT JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid +LEFT JOIN vendors v ON mo.vendorid = v.vendorid +LEFT JOIN communications c ON m.machineid = c.machineid AND c.isprimary = 1 AND c.comstypeid = 1 +WHERE m.machinetypeid IN (16, 17, 18, 19, 20) + AND m.isactive = 1 + AND m.mapleft IS NOT NULL + AND m.maptop IS NOT NULL; + +-- ----------------------------------------------------------------------------- +-- vw_installed_apps_by_machine - For displayinstalledapps.asp +-- Installed applications with machine and version info +-- ----------------------------------------------------------------------------- +DROP VIEW IF EXISTS vw_installed_apps_by_machine; + +CREATE VIEW vw_installed_apps_by_machine AS +SELECT + ia.machineid, + ia.appid, + ia.appversionid, + ia.isactive, + m.machinenumber, + m.hostname, + a.appname, + av.version +FROM installedapps ia +INNER JOIN machines m ON ia.machineid = m.machineid +INNER JOIN applications a ON ia.appid = a.appid +LEFT JOIN appversions av ON ia.appversionid = av.appversionid +WHERE ia.isactive = 1; + +-- ============================================================================ +-- STEP 4: Verify new views +-- ============================================================================ + +SELECT 'View consolidation complete. Testing new views:' AS status; + +-- Equipment & Machine views +SELECT 'vw_equipment_list' AS view_name, COUNT(*) AS row_count FROM vw_equipment_list +UNION ALL SELECT 'vw_pc_list', COUNT(*) FROM vw_pc_list +UNION ALL SELECT 'vw_printer_list', COUNT(*) FROM vw_printer_list +UNION ALL SELECT 'vw_machine_detail', COUNT(*) FROM vw_machine_detail +UNION ALL SELECT 'vw_equipment_pc_relationships', COUNT(*) FROM vw_equipment_pc_relationships +-- Map views +UNION ALL SELECT 'vw_map_equipment', COUNT(*) FROM vw_map_equipment +UNION ALL SELECT 'vw_map_printers', COUNT(*) FROM vw_map_printers +UNION ALL SELECT 'vw_map_network_devices', COUNT(*) FROM vw_map_network_devices +-- Summary views +UNION ALL SELECT 'vw_warranty_summary', COUNT(*) FROM vw_warranty_summary +UNION ALL SELECT 'vw_pctype_summary', COUNT(*) FROM vw_pctype_summary +UNION ALL SELECT 'vw_equipment_type_summary', COUNT(*) FROM vw_equipment_type_summary +-- Notification views +UNION ALL SELECT 'vw_active_notifications', COUNT(*) FROM vw_active_notifications +UNION ALL SELECT 'vw_upcoming_notifications', COUNT(*) FROM vw_upcoming_notifications +UNION ALL SELECT 'vw_incident_durations', COUNT(*) FROM vw_incident_durations +-- Application views +UNION ALL SELECT 'vw_applications_list', COUNT(*) FROM vw_applications_list +UNION ALL SELECT 'vw_knowledge_base', COUNT(*) FROM vw_knowledge_base +-- USB views +UNION ALL SELECT 'vw_usb_checkout_history', COUNT(*) FROM vw_usb_checkout_history +-- Subnet views +UNION ALL SELECT 'vw_subnet_list', COUNT(*) FROM vw_subnet_list +-- Report/Chart views +UNION ALL SELECT 'vw_downtime_by_type', COUNT(*) FROM vw_downtime_by_type +UNION ALL SELECT 'vw_installed_apps_summary', COUNT(*) FROM vw_installed_apps_summary +UNION ALL SELECT 'vw_pc_app_stats', COUNT(*) FROM vw_pc_app_stats +UNION ALL SELECT 'vw_kb_by_application', COUNT(*) FROM vw_kb_by_application +-- Additional views +UNION ALL SELECT 'vw_network_map_devices', COUNT(*) FROM vw_network_map_devices +UNION ALL SELECT 'vw_installed_apps_by_machine', COUNT(*) FROM vw_installed_apps_by_machine +-- Kept existing views +UNION ALL SELECT 'vw_network_devices (kept)', COUNT(*) FROM vw_network_devices +UNION ALL SELECT 'vw_warranty_status (kept)', COUNT(*) FROM vw_warranty_status; + +SELECT 'All 26 views created successfully!' AS status;