#436 new SQL query for neigbor map to allow mismatched/one-way links (Linwood-F)
This commit is contained in:
@@ -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,
|
||||||
|
ld.name AS left_name,
|
||||||
|
array_agg(dp.port) AS left_port,
|
||||||
|
array_agg(dp.name) AS left_descr,
|
||||||
|
|
||||||
|
sum(COALESCE(dpp.raw_speed, 0)) AS aggspeed,
|
||||||
count(*) AS aggports,
|
count(*) AS aggports,
|
||||||
di.ip AS right_ip, rd.dns AS right_dns, rd.name AS right_name,
|
|
||||||
array_agg(dp.remote_port) AS right_port, array_agg(dp2.name) AS right_descr
|
di.ip AS right_ip,
|
||||||
|
rd.dns AS right_dns,
|
||||||
|
rd.name AS right_name,
|
||||||
|
array_agg(dp.remote_port) AS right_port,
|
||||||
|
array_agg(dp2.name) AS right_descr
|
||||||
|
|
||||||
FROM device_port dp
|
FROM device_port dp
|
||||||
LEFT OUTER JOIN device_port_properties dpp USING (ip, port)
|
LEFT OUTER JOIN device_port_properties dpp USING (ip,
|
||||||
|
port)
|
||||||
INNER JOIN device ld ON dp.ip = ld.ip
|
INNER JOIN device ld ON dp.ip = ld.ip
|
||||||
INNER JOIN device_ip di ON dp.remote_ip = di.alias
|
INNER JOIN device_ip di ON dp.remote_ip = di.alias
|
||||||
INNER JOIN device rd ON di.ip = rd.ip
|
INNER JOIN device rd ON di.ip = rd.ip
|
||||||
LEFT OUTER JOIN device_port dp2
|
|
||||||
ON (di.ip = dp2.ip
|
LEFT OUTER JOIN device_port dp2 ON (di.ip = dp2.ip
|
||||||
AND ((dp.remote_port = dp2.port)
|
AND ((dp.remote_port = dp2.port)
|
||||||
OR (dp.remote_port = dp2.name)
|
OR (dp.remote_port = dp2.name)
|
||||||
OR (dp.remote_port = dp2.descr)))
|
OR (dp.remote_port = dp2.descr)))
|
||||||
|
|
||||||
WHERE dp.remote_port IS NOT NULL
|
WHERE dp.remote_port IS NOT NULL
|
||||||
AND dp.port !~* 'vlan'
|
AND dp.port !~* 'vlan'
|
||||||
AND (dp.descr IS NULL OR dp.descr !~* 'vlan')
|
AND (dp.descr IS NULL
|
||||||
AND (dp.type IS NULL OR dp.type !~* '^(53|ieee8023adLag|propVirtual|l2vlan|l3ipvlan|135|136|137)\$')
|
OR dp.descr !~* 'vlan')
|
||||||
AND (dp.is_master = 'false' OR dp.slave_of IS NOT NULL)
|
AND (dp.type IS NULL
|
||||||
AND dp.ip <= di.ip
|
OR dp.type !~* '^(53|ieee8023adLag|propVirtual|l2vlan|l3ipvlan|135|136|137)\$')
|
||||||
GROUP BY left_ip, left_dns, left_name, right_ip, right_dns, right_name
|
AND (dp.is_master = 'false'
|
||||||
ORDER BY dp.ip
|
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
|
||||||
);
|
);
|
||||||
|
|
||||||
|
|||||||
Reference in New Issue
Block a user