Try to fix #1044 by subquery inlining instead of CTE (#1046)

This commit is contained in:
Christian Ramseyer
2023-06-08 17:29:14 +02:00
committed by GitHub
parent 1aef847af3
commit 82dea7de2a
2 changed files with 12 additions and 12 deletions

View File

@@ -8,9 +8,8 @@ __PACKAGE__->table_class('DBIx::Class::ResultSource::View');
__PACKAGE__->table('port_vlan_mismatch');
__PACKAGE__->result_source_instance->is_virtual(1);
__PACKAGE__->result_source_instance->view_definition(<<'ENDSQL');
WITH all_vlans AS
(SELECT ip, port,
my $all_vlans = qq/
SELECT ip, port,
array_to_string(array_agg( CASE WHEN native THEN 'n:' || vlan::text
ELSE vlan::text END
ORDER BY vlan ASC ), ', ') AS vlist
@@ -20,28 +19,29 @@ __PACKAGE__->result_source_instance->view_definition(<<'ENDSQL');
LEFT JOIN device_port dp2 ON (dp.ip = dp2.ip and dp.port = dp2.slave_of)
LEFT JOIN device_port_vlan dp2v ON (dp2.ip = dp2v.ip and dp2.port = dp2v.port)
WHERE dp.has_subinterfaces) alldpv
WHERE vlan::text NOT IN (?, ?, ?, ?) GROUP BY ip, port)
WHERE vlan::text NOT IN (?, ?, ?, ?) GROUP BY ip, port
/;
__PACKAGE__->result_source_instance->view_definition("
SELECT CASE WHEN length(ld.dns) > 0 THEN ld.dns ELSE host(ld.ip) END AS left_device,
ld.name AS left_name,
lp.port AS left_port,
lp.name AS left_portname,
(SELECT vlist FROM all_vlans WHERE ip=lp.ip AND port=lp.port) AS left_vlans,
(SELECT vlist FROM ($all_vlans) a0 WHERE ip=lp.ip AND port=lp.port) AS left_vlans,
CASE WHEN length(rd.dns) > 0 THEN rd.dns ELSE host(rd.ip) END AS right_device,
rd.name AS right_name,
rp.port AS right_port,
rp.name AS right_portname,
(SELECT vlist FROM all_vlans WHERE ip=rp.ip AND port=rp.port) AS right_vlans
FROM device ld
(SELECT vlist FROM ($all_vlans) a1 WHERE ip=rp.ip AND port=rp.port) AS right_vlans
FROM device ld
JOIN device_port lp USING (ip)
JOIN device_port rp ON lp.remote_ip=rp.ip AND lp.remote_port=rp.port
JOIN device rd ON rp.ip=rd.ip
WHERE ld.ip < rd.ip AND
(SELECT vlist FROM all_vlans WHERE ip=lp.ip AND port=lp.port)
(SELECT vlist FROM ($all_vlans) a2 WHERE ip=lp.ip AND port=lp.port)
!=
(SELECT vlist FROM all_vlans WHERE ip=rp.ip AND port=rp.port)
(SELECT vlist FROM ($all_vlans) a3 WHERE ip=rp.ip AND port=rp.port)
ORDER BY left_device, left_port
ENDSQL
");
__PACKAGE__->add_columns(
'left_device' => { data_type => 'text' },

View File

@@ -21,7 +21,7 @@ get '/ajax/content/report/portvlanmismatch' => require_login sub {
my @results = schema(vars->{'tenant'})
->resultset('Virtual::PortVLANMismatch')->search({},{
bind => [ setting('sidebar_defaults')->{'device_ports'}->{'p_hide1002'}->{'default'}
? (1002, 1003, 1004, 1005) : (0, 0, 0, 0) ],
? (1002, 1003, 1004, 1005, 1002, 1003, 1004, 1005, 1002, 1003, 1004, 1005, 1002, 1003, 1004, 1005) : (0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0) ],
})
->hri->all;