-- ============================================================================ -- FILE: update_network_devices_view.sql -- PURPOSE: Update vw_network_devices to use model's machinetypeid (with fallback) -- DATE: 2026-01-29 -- -- DESCRIPTION: -- This update changes vw_network_devices to prefer model.machinetypeid over -- machines.machinetypeid (deprecating the latter). Uses a hybrid approach: -- - If model has a valid network device machinetypeid (16,17,18,19,20,46), use it -- - Otherwise fall back to machines.machinetypeid for backward compatibility -- -- Also adds Firewall (machinetypeid=46) to the list of network device types. -- ============================================================================ CREATE OR REPLACE VIEW vw_network_devices AS -- Printers (from separate printers table) SELECT 'Printer' AS device_type, p.printerid AS device_id, p.printerwindowsname AS device_name, p.modelid AS modelid, m.modelnumber AS modelnumber, v.vendor AS vendor, p.serialnumber AS serialnumber, p.ipaddress AS ipaddress, NULL AS description, p.maptop AS maptop, p.mapleft AS mapleft, p.isactive AS isactive, NULL AS idfid, NULL AS idfname, NULL AS macaddress, p.fqdn AS fqdn FROM printers p LEFT JOIN models m ON p.modelid = m.modelnumberid LEFT JOIN vendors v ON m.vendorid = v.vendorid UNION ALL -- Network devices from machines table -- HYBRID: Use model's machinetypeid if valid network device type, -- otherwise fall back to machine's machinetypeid SELECT mt.machinetype AS device_type, ma.machineid AS device_id, COALESCE(ma.alias, ma.machinenumber) AS device_name, ma.modelnumberid AS modelid, mo.modelnumber AS modelnumber, ve.vendor AS vendor, ma.serialnumber AS serialnumber, c.address AS ipaddress, ma.machinenotes AS description, ma.maptop AS maptop, ma.mapleft AS mapleft, ma.isactive AS isactive, NULL AS idfid, NULL AS idfname, c.macaddress AS macaddress, ma.fqdn AS fqdn FROM machines ma LEFT JOIN models mo ON ma.modelnumberid = mo.modelnumberid JOIN machinetypes mt ON mt.machinetypeid = COALESCE( -- Prefer model's machinetypeid if it's a valid network device type CASE WHEN mo.machinetypeid IN (16,17,18,19,20,46) THEN mo.machinetypeid ELSE NULL END, -- Fall back to machine's machinetypeid ma.machinetypeid ) LEFT JOIN vendors ve ON mo.vendorid = ve.vendorid LEFT JOIN communications c ON ma.machineid = c.machineid AND c.isprimary = 1 AND c.comstypeid = 1 WHERE COALESCE( CASE WHEN mo.machinetypeid IN (16,17,18,19,20,46) THEN mo.machinetypeid ELSE NULL END, ma.machinetypeid ) IN (16, 17, 18, 19, 20, 46); -- Network device type IDs: -- 16 = Access Point -- 17 = IDF -- 18 = Camera -- 19 = Switch -- 20 = Server -- 46 = Firewall (newly added)