change system custom reports to use line wrapping arrays with a window function
This commit is contained in:
@@ -283,8 +283,13 @@ 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
|
||||
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
|
||||
@@ -294,16 +299,23 @@ system_reports:
|
||||
AND dpv2.vlan = dpv.vlan
|
||||
AND native IS true
|
||||
) = 0
|
||||
GROUP BY ip
|
||||
ORDER BY ip
|
||||
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
|
||||
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
|
||||
@@ -311,17 +323,23 @@ system_reports:
|
||||
AND dpv.vlan = dv.vlan
|
||||
)
|
||||
AND vlan NOT IN (1002, 1003, 1004, 1005)
|
||||
GROUP BY ip
|
||||
ORDER BY ip
|
||||
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
|
||||
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
|
||||
@@ -339,8 +357,10 @@ system_reports:
|
||||
< COALESCE(NULLIF(?,''), '3 months') ::interval
|
||||
)
|
||||
) = 0
|
||||
GROUP BY dpv.ip
|
||||
ORDER BY dpv.ip
|
||||
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'
|
||||
|
||||
Reference in New Issue
Block a user