-- ============================================================================ -- 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;