change system custom reports to use line wrapping arrays with a window function

This commit is contained in:
Oliver Gorwits
2023-12-06 07:20:58 +00:00
parent 8397eabe50
commit a068960b51

View File

@@ -283,64 +283,84 @@ system_reports:
columns:
- { ip: 'Device IP', _searchable: true }
- { vlans: 'VLAN List' }
bind_params: ['chunk_size']
query: |
SELECT ip, array_to_string(array_agg(DISTINCT vlan::integer ORDER BY vlan::integer ASC), ', ') AS vlans
FROM device_port_vlan dpv
WHERE native IS false
AND vlan <> 1
AND (
SELECT count(*) FROM device_port_vlan dpv2
WHERE dpv2.ip = dpv.ip
AND dpv2.vlan = dpv.vlan
AND native IS true
) = 0
GROUP BY ip
ORDER BY ip
SELECT ip, array_agg(vlans) AS vlans FROM (
SELECT ip, array_to_string(array_agg(vlan), ', ') AS vlans, (x / COALESCE(NULLIF(?,''), '20') ::integer) AS chunk FROM (
SELECT *, (row_number() over (partition by ip)) AS x FROM (
SELECT DISTINCT ip, vlan
FROM device_port_vlan dpv
WHERE native IS false
AND vlan <> 1
AND (
SELECT count(*) FROM device_port_vlan dpv2
WHERE dpv2.ip = dpv.ip
AND dpv2.vlan = dpv.vlan
AND native IS true
) = 0
ORDER BY ip, vlan)
) GROUP BY ip, chunk
) GROUP BY ip ORDER BY ip
- tag: vlansneverconfigured
category: VLAN
label: 'VLANs Known but Not Configured'
columns:
- { ip: 'Device IP', _searchable: true }
- { vlans: 'VLAN List' }
bind_params: ['chunk_size']
query: |
SELECT ip, array_to_string(array_agg(DISTINCT dv.vlan::integer ORDER BY dv.vlan::integer ASC), ', ') AS vlans
FROM device_vlan dv
WHERE NOT EXISTS (
SELECT FROM device_port_vlan dpv
WHERE dpv.ip = dv.ip
AND dpv.vlan = dv.vlan
)
AND vlan NOT IN (1002, 1003, 1004, 1005)
GROUP BY ip
ORDER BY ip
SELECT ip, array_agg(vlans) AS vlans FROM (
SELECT ip, array_to_string(array_agg(vlan), ', ') AS vlans, (x / COALESCE(NULLIF(?,''), '20') ::integer) AS chunk FROM (
SELECT *, (row_number() over (partition by ip)) AS x FROM (
SELECT DISTINCT ip, vlan
FROM device_vlan dv
WHERE NOT EXISTS (
SELECT FROM device_port_vlan dpv
WHERE dpv.ip = dv.ip
AND dpv.vlan = dv.vlan
)
AND vlan NOT IN (1002, 1003, 1004, 1005)
ORDER BY ip, vlan)
) GROUP BY ip, chunk
) GROUP BY ip ORDER BY ip
- tag: vlansunused
category: VLAN
label: 'VLANs No Longer Used'
columns:
- { ip: 'Device IP', _searchable: true }
- { vlans: 'VLAN List' }
bind_params: ['free']
bind_params: ['chunk_size', 'free']
query: |
SELECT dpv.ip, array_to_string(array_agg(DISTINCT dpv.vlan::integer ORDER BY dpv.vlan::integer ASC), ', ') AS vlans
FROM device_port_vlan dpv
WHERE dpv.native IS false
AND dpv.vlan <> 1
AND (
SELECT count(*) FROM device_port_vlan dpv2
LEFT JOIN device_port dp USING (ip, port)
LEFT JOIN device d USING (ip)
WHERE dpv2.ip = dpv.ip
AND dpv2.vlan = dpv.vlan
AND native IS true
SELECT ip, array_agg(vlans) AS vlans FROM (
SELECT ip, array_to_string(array_agg(vlan), ', ') AS vlans, (x / COALESCE(NULLIF(?,''), '20') ::integer) AS chunk FROM (
SELECT *, (row_number() over (partition by ip)) AS x FROM (
SELECT DISTINCT ip, vlan
FROM device_port_vlan dpv
WHERE dpv.native IS false
AND dpv.vlan <> 1
AND (
dp.up_admin = 'up'
OR age( LOCALTIMESTAMP,
to_timestamp( extract( epoch FROM d.last_discover ) - ( d.uptime - dp.lastchange ) /100 ) ::timestamp )
< COALESCE(NULLIF(?,''), '3 months') ::interval
)
) = 0
GROUP BY dpv.ip
ORDER BY dpv.ip
SELECT count(*) FROM device_port_vlan dpv2
LEFT JOIN device_port dp USING (ip, port)
LEFT JOIN device d USING (ip)
WHERE dpv2.ip = dpv.ip
AND dpv2.vlan = dpv.vlan
AND native IS true
AND (
dp.up_admin = 'up'
OR age( LOCALTIMESTAMP,
to_timestamp( extract( epoch FROM d.last_discover ) - ( d.uptime - dp.lastchange ) /100 ) ::timestamp )
< COALESCE(NULLIF(?,''), '3 months') ::interval
)
) = 0
ORDER BY dpv.ip, dpv.vlan)
) GROUP BY ip, chunk
) GROUP BY ip ORDER BY ip
- tag: devicevlancount
category: VLAN
label: 'VLAN Count per Device'