fix to get aggregate ports in matching order on left and right side
This commit is contained in:
@@ -7,43 +7,32 @@ use base 'DBIx::Class::Core';
|
|||||||
|
|
||||||
__PACKAGE__->table_class('DBIx::Class::ResultSource::View');
|
__PACKAGE__->table_class('DBIx::Class::ResultSource::View');
|
||||||
|
|
||||||
# notes to future devs:
|
# note to future devs:
|
||||||
|
|
||||||
# this query does not use the slave_of field in device_port table to group
|
# this query does not use the slave_of field in device_port table to group
|
||||||
# ports because what we actually want is total b/w between devices on all
|
# ports because what we actually want is total b/w between devices on all
|
||||||
# links, regardless of whether those links are in an aggregate.
|
# links, regardless of whether those links are in an aggregate.
|
||||||
|
|
||||||
# PG 8.4 does not have sorting within an aggregate so we cannot ensure that
|
|
||||||
# left and right ports and names correspond within arrays. this is why the
|
|
||||||
# right ports are the left's remote_ports (and right_descr should be ignored)
|
|
||||||
|
|
||||||
__PACKAGE__->table('device_links');
|
__PACKAGE__->table('device_links');
|
||||||
__PACKAGE__->result_source_instance->is_virtual(1);
|
__PACKAGE__->result_source_instance->is_virtual(1);
|
||||||
__PACKAGE__->result_source_instance->view_definition(<<ENDSQL
|
__PACKAGE__->result_source_instance->view_definition(<<ENDSQL
|
||||||
SELECT dp.ip AS left_ip, dp.ports AS left_port, dp.descriptions AS left_descr,
|
SELECT dp.ip AS left_ip, array_agg(dp.port) AS left_port, array_agg(dp.name) AS left_descr,
|
||||||
dp.speed AS aggspeed, dp.aggports,
|
sum(btrim(dp.speed, ' MGTbps')::float
|
||||||
dp2.ip AS right_ip, dp.remote_ports AS right_port, array_agg(dp2.name) AS right_descr
|
* (CASE btrim(dp.speed, ' 0123456789.')
|
||||||
|
WHEN 'Gbps' THEN 1000
|
||||||
|
WHEN 'Tbps' THEN 1000000
|
||||||
|
ELSE 1 END)) AS aggspeed,
|
||||||
|
count(*) AS aggports,
|
||||||
|
dp2.ip AS right_ip, array_agg(dp2.port) AS right_port, array_agg(dp2.name) AS right_descr
|
||||||
|
|
||||||
FROM ( SELECT device_port.ip, device_port.remote_ip,
|
FROM device_port dp
|
||||||
array_agg(device_port.port) as ports,
|
INNER JOIN device_ip di ON dp.remote_ip = di.alias
|
||||||
array_agg(device_port.name) as descriptions,
|
INNER JOIN device_port dp2 ON (di.ip = dp2.ip AND dp.remote_port = dp2.port)
|
||||||
array_agg(device_port.remote_port) as remote_ports,
|
|
||||||
count(*) AS aggports,
|
|
||||||
sum(btrim(device_port.speed, ' MGTbps')::float
|
|
||||||
* (CASE btrim(device_port.speed, ' 0123456789.')
|
|
||||||
WHEN 'Gbps' THEN 1000
|
|
||||||
WHEN 'Tbps' THEN 1000000
|
|
||||||
ELSE 1 END)) AS speed
|
|
||||||
FROM device_port
|
|
||||||
WHERE device_port.remote_port IS NOT NULL
|
|
||||||
AND device_port.type = 'ethernetCsmacd'
|
|
||||||
AND device_port.speed LIKE '%bps'
|
|
||||||
GROUP BY device_port.ip, device_port.remote_ip) dp
|
|
||||||
|
|
||||||
INNER JOIN device_ip di ON dp.remote_ip = di.alias
|
WHERE dp.remote_port IS NOT NULL
|
||||||
INNER JOIN device_port dp2 ON (di.ip = dp2.ip AND dp.remote_ports @> ARRAY[dp2.port])
|
AND dp.type = 'ethernetCsmacd'
|
||||||
WHERE dp.ip <= dp2.ip
|
AND dp.speed LIKE '%bps'
|
||||||
GROUP BY left_ip, left_port, left_descr, aggspeed, aggports, right_ip, right_port
|
AND dp.ip <= dp2.ip
|
||||||
|
GROUP BY left_ip, right_ip
|
||||||
ORDER BY dp.ip
|
ORDER BY dp.ip
|
||||||
ENDSQL
|
ENDSQL
|
||||||
);
|
);
|
||||||
|
|||||||
Reference in New Issue
Block a user