change system custom reports to use line wrapping arrays with a window function
This commit is contained in:
104
share/config.yml
104
share/config.yml
@@ -283,64 +283,84 @@ system_reports:
|
|||||||
columns:
|
columns:
|
||||||
- { ip: 'Device IP', _searchable: true }
|
- { ip: 'Device IP', _searchable: true }
|
||||||
- { vlans: 'VLAN List' }
|
- { vlans: 'VLAN List' }
|
||||||
|
bind_params: ['chunk_size']
|
||||||
query: |
|
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 (
|
||||||
FROM device_port_vlan dpv
|
SELECT ip, array_to_string(array_agg(vlan), ', ') AS vlans, (x / COALESCE(NULLIF(?,''), '20') ::integer) AS chunk FROM (
|
||||||
WHERE native IS false
|
SELECT *, (row_number() over (partition by ip)) AS x FROM (
|
||||||
AND vlan <> 1
|
|
||||||
AND (
|
SELECT DISTINCT ip, vlan
|
||||||
SELECT count(*) FROM device_port_vlan dpv2
|
FROM device_port_vlan dpv
|
||||||
WHERE dpv2.ip = dpv.ip
|
WHERE native IS false
|
||||||
AND dpv2.vlan = dpv.vlan
|
AND vlan <> 1
|
||||||
AND native IS true
|
AND (
|
||||||
) = 0
|
SELECT count(*) FROM device_port_vlan dpv2
|
||||||
GROUP BY ip
|
WHERE dpv2.ip = dpv.ip
|
||||||
ORDER BY 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
|
- tag: vlansneverconfigured
|
||||||
category: VLAN
|
category: VLAN
|
||||||
label: 'VLANs Known but Not Configured'
|
label: 'VLANs Known but Not Configured'
|
||||||
columns:
|
columns:
|
||||||
- { ip: 'Device IP', _searchable: true }
|
- { ip: 'Device IP', _searchable: true }
|
||||||
- { vlans: 'VLAN List' }
|
- { vlans: 'VLAN List' }
|
||||||
|
bind_params: ['chunk_size']
|
||||||
query: |
|
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 (
|
||||||
FROM device_vlan dv
|
SELECT ip, array_to_string(array_agg(vlan), ', ') AS vlans, (x / COALESCE(NULLIF(?,''), '20') ::integer) AS chunk FROM (
|
||||||
WHERE NOT EXISTS (
|
SELECT *, (row_number() over (partition by ip)) AS x FROM (
|
||||||
SELECT FROM device_port_vlan dpv
|
|
||||||
WHERE dpv.ip = dv.ip
|
SELECT DISTINCT ip, vlan
|
||||||
AND dpv.vlan = dv.vlan
|
FROM device_vlan dv
|
||||||
)
|
WHERE NOT EXISTS (
|
||||||
AND vlan NOT IN (1002, 1003, 1004, 1005)
|
SELECT FROM device_port_vlan dpv
|
||||||
GROUP BY ip
|
WHERE dpv.ip = dv.ip
|
||||||
ORDER BY 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
|
- tag: vlansunused
|
||||||
category: VLAN
|
category: VLAN
|
||||||
label: 'VLANs No Longer Used'
|
label: 'VLANs No Longer Used'
|
||||||
columns:
|
columns:
|
||||||
- { ip: 'Device IP', _searchable: true }
|
- { ip: 'Device IP', _searchable: true }
|
||||||
- { vlans: 'VLAN List' }
|
- { vlans: 'VLAN List' }
|
||||||
bind_params: ['free']
|
bind_params: ['chunk_size', 'free']
|
||||||
query: |
|
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 (
|
||||||
FROM device_port_vlan dpv
|
SELECT ip, array_to_string(array_agg(vlan), ', ') AS vlans, (x / COALESCE(NULLIF(?,''), '20') ::integer) AS chunk FROM (
|
||||||
WHERE dpv.native IS false
|
SELECT *, (row_number() over (partition by ip)) AS x FROM (
|
||||||
AND dpv.vlan <> 1
|
|
||||||
AND (
|
SELECT DISTINCT ip, vlan
|
||||||
SELECT count(*) FROM device_port_vlan dpv2
|
FROM device_port_vlan dpv
|
||||||
LEFT JOIN device_port dp USING (ip, port)
|
WHERE dpv.native IS false
|
||||||
LEFT JOIN device d USING (ip)
|
AND dpv.vlan <> 1
|
||||||
WHERE dpv2.ip = dpv.ip
|
|
||||||
AND dpv2.vlan = dpv.vlan
|
|
||||||
AND native IS true
|
|
||||||
AND (
|
AND (
|
||||||
dp.up_admin = 'up'
|
SELECT count(*) FROM device_port_vlan dpv2
|
||||||
OR age( LOCALTIMESTAMP,
|
LEFT JOIN device_port dp USING (ip, port)
|
||||||
to_timestamp( extract( epoch FROM d.last_discover ) - ( d.uptime - dp.lastchange ) /100 ) ::timestamp )
|
LEFT JOIN device d USING (ip)
|
||||||
< COALESCE(NULLIF(?,''), '3 months') ::interval
|
WHERE dpv2.ip = dpv.ip
|
||||||
)
|
AND dpv2.vlan = dpv.vlan
|
||||||
) = 0
|
AND native IS true
|
||||||
GROUP BY dpv.ip
|
AND (
|
||||||
ORDER BY dpv.ip
|
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
|
- tag: devicevlancount
|
||||||
category: VLAN
|
category: VLAN
|
||||||
label: 'VLAN Count per Device'
|
label: 'VLAN Count per Device'
|
||||||
|
|||||||
Reference in New Issue
Block a user