#436 new SQL query for neigbor map to allow mismatched/one-way links (Linwood-F)

This commit is contained in:
Oliver Gorwits
2019-01-02 20:37:19 +00:00
parent 505b7b5625
commit d614382fcd

View File

@@ -15,32 +15,59 @@ __PACKAGE__->table_class('DBIx::Class::ResultSource::View');
__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, ld.dns AS left_dns, ld.name AS left_name, WITH BothWays AS
array_agg(dp.port) AS left_port, array_agg(dp.name) AS left_descr, ( SELECT dp.ip AS left_ip,
sum( COALESCE(dpp.raw_speed,0) ) as aggspeed, ld.dns AS left_dns,
count(*) AS aggports, ld.name AS left_name,
di.ip AS right_ip, rd.dns AS right_dns, rd.name AS right_name, array_agg(dp.port) AS left_port,
array_agg(dp.remote_port) AS right_port, array_agg(dp2.name) AS right_descr array_agg(dp.name) AS left_descr,
FROM device_port dp sum(COALESCE(dpp.raw_speed, 0)) AS aggspeed,
LEFT OUTER JOIN device_port_properties dpp USING (ip, port) count(*) AS aggports,
INNER JOIN device ld ON dp.ip = ld.ip
INNER JOIN device_ip di ON dp.remote_ip = di.alias
INNER JOIN device rd ON di.ip = rd.ip
LEFT OUTER JOIN device_port dp2
ON (di.ip = dp2.ip
AND ((dp.remote_port = dp2.port)
OR (dp.remote_port = dp2.name)
OR (dp.remote_port = dp2.descr)))
WHERE dp.remote_port IS NOT NULL di.ip AS right_ip,
AND dp.port !~* 'vlan' rd.dns AS right_dns,
AND (dp.descr IS NULL OR dp.descr !~* 'vlan') rd.name AS right_name,
AND (dp.type IS NULL OR dp.type !~* '^(53|ieee8023adLag|propVirtual|l2vlan|l3ipvlan|135|136|137)\$') array_agg(dp.remote_port) AS right_port,
AND (dp.is_master = 'false' OR dp.slave_of IS NOT NULL) array_agg(dp2.name) AS right_descr
AND dp.ip <= di.ip
GROUP BY left_ip, left_dns, left_name, right_ip, right_dns, right_name FROM device_port dp
ORDER BY dp.ip LEFT OUTER JOIN device_port_properties dpp USING (ip,
port)
INNER JOIN device ld ON dp.ip = ld.ip
INNER JOIN device_ip di ON dp.remote_ip = di.alias
INNER JOIN device rd ON di.ip = rd.ip
LEFT OUTER JOIN device_port dp2 ON (di.ip = dp2.ip
AND ((dp.remote_port = dp2.port)
OR (dp.remote_port = dp2.name)
OR (dp.remote_port = dp2.descr)))
WHERE dp.remote_port IS NOT NULL
AND dp.port !~* 'vlan'
AND (dp.descr IS NULL
OR dp.descr !~* 'vlan')
AND (dp.type IS NULL
OR dp.type !~* '^(53|ieee8023adLag|propVirtual|l2vlan|l3ipvlan|135|136|137)\$')
AND (dp.is_master = 'false'
OR dp.slave_of IS NOT NULL)
GROUP BY left_ip,
left_dns,
left_name,
right_ip,
right_dns,
right_name )
SELECT *
FROM BothWays b
WHERE NOT EXISTS
( SELECT *
FROM BothWays b2
WHERE b2.right_ip = b.left_ip
AND b2.right_port = b.left_port
AND b2.left_ip < b.left_ip )
ORDER BY 1,
2
ENDSQL ENDSQL
); );