From 07cc5ad92d1bce23560d9b1273d2f48a25fc351f Mon Sep 17 00:00:00 2001 From: Robert Latta <robert.latta@geant.org> Date: Tue, 7 May 2019 12:21:17 +0000 Subject: [PATCH] Updated SQL to get correct information for each end of services --- inventory_provider/db/opsdb.py | 83 ++++++++++++++++++---------------- 1 file changed, 43 insertions(+), 40 deletions(-) diff --git a/inventory_provider/db/opsdb.py b/inventory_provider/db/opsdb.py index ab3a6443..392f2359 100644 --- a/inventory_provider/db/opsdb.py +++ b/inventory_provider/db/opsdb.py @@ -30,46 +30,47 @@ retrieve_services_query = """SELECT * LOWER(c.circuit_type) AS circuit_type, LOWER(c.service_type) AS service_type, events.short_descr AS project, - pop.name as pop_name, - pop.abbreviation as pop_abbreviation, + pop_a.name as pop_name, + pop_a.abbreviation as pop_abbreviation, pop_b.name as other_end_pop_name, pop_b.abbreviation as other_end_pop_abbreviation, - e.name AS equipment, + e_a.name AS equipment, e_b.name AS other_end_equipment, cc.port_a AS port, cc.port_b AS other_end_port, cc.int_LU_a AS logical_unit, cc.int_LU_b AS other_end_logical_unit, LOWER(o.name) AS manufacturer, - LOWER(ec.card_id) AS card_id, + LOWER(ec_a.card_id) AS card_id, LOWER(ec_b.card_id) AS other_end_card_id, LOWER( - IF(pp.interface_name IS NULL, - '', pp.interface_name)) AS interface_name, + IF(pp_a.interface_name IS NULL, + '', pp_a.interface_name)) AS interface_name, LOWER( IF(pp_b.interface_name IS NULL, '', pp_b.interface_name)) AS other_end_interface_name FROM circuit c INNER JOIN circuit_connections cc ON cc.circ_absid = c.absid - LEFT JOIN pop pop - ON pop.absid = cc.PTR_pop_a + LEFT JOIN pop pop_a + ON pop_a.absid = cc.PTR_pop_a LEFT JOIN pop pop_b ON pop_b.absid = cc.PTR_pop_b - INNER JOIN equipment e - ON e.absid = cc.PTR_equip_a + INNER JOIN equipment e_a + ON e_a.absid = cc.PTR_equip_a LEFT JOIN equipment e_b ON e_b.absid = cc.PTR_equip_b LEFT JOIN events ON events.absid = cc.PTR_project - INNER JOIN equipment_card ec - ON ec.absid = cc.PTR_card_a + INNER JOIN equipment_card ec_a + ON ec_a.absid = cc.PTR_card_a LEFT JOIN equipment_card ec_b ON ec_b.absid = cc.PTR_card_b LEFT JOIN organisation o - ON o.absid = ec.manufacturer - LEFT JOIN port_plugin pp - ON pp.PTR_card = cc.PTR_card_a AND pp.port = cc.port_a + ON o.absid = ec_a.manufacturer + LEFT JOIN port_plugin pp_a + ON pp_a.PTR_card = cc.PTR_card_a + AND pp_a.port = cc.port_a LEFT JOIN port_plugin pp_b ON pp_b.PTR_card = cc.PTR_card_b AND pp_b.port = cc.port_b @@ -82,46 +83,47 @@ retrieve_services_query = """SELECT * LOWER(c.circuit_type) AS circuit_type, LOWER(c.service_type) AS service_type, events.short_descr AS project, - pop.name as pop_name, - pop.abbreviation as pop_abbreviation, - pop_b.name as other_end_pop_name, - pop_b.abbreviation as other_end_pop_abbreviation, - e.name AS equipment, - e_b.name AS other_end_equipment, - cc.port_a AS port, - cc.port_b AS other_end_port, - cc.int_LU_a AS logical_unit, - cc.int_LU_b AS other_end_logical_unit, + pop_b.name as pop_name, + pop_b.abbreviation as pop_abbreviation, + pop_a.name as other_end_pop_name, + pop_a.abbreviation as other_end_pop_abbreviation, + e_b.name AS equipment, + e_a.name AS other_end_equipment, + cc.port_b AS port, + cc.port_a AS other_end_port, + cc.int_LU_b AS logical_unit, + cc.int_LU_a AS other_end_logical_unit, LOWER(o.name) AS manufacturer, - LOWER(ec.card_id) AS card_id, - LOWER(ec_b.card_id) AS other_end_card_id, - LOWER( - IF(pp.interface_name IS NULL, - '', pp.interface_name)) AS interface_name, + LOWER(ec_b.card_id) AS card_id, + LOWER(ec_a.card_id) AS other_end_card_id, LOWER( IF(pp_b.interface_name IS NULL, - '', pp_b.interface_name)) AS other_end_interface_name + '', pp_b.interface_name)) AS interface_name, + LOWER( + IF(pp_a.interface_name IS NULL, + '', pp_a.interface_name)) AS other_end_interface_name FROM circuit c INNER JOIN circuit_connections cc ON cc.circ_absid = c.absid - LEFT JOIN pop pop - ON pop.absid = cc.PTR_pop_a + LEFT JOIN pop pop_a + ON pop_a.absid = cc.PTR_pop_a LEFT JOIN pop pop_b ON pop_b.absid = cc.PTR_pop_b - INNER JOIN equipment e - ON e.absid = cc.PTR_equip_a + INNER JOIN equipment e_a + ON e_a.absid = cc.PTR_equip_a LEFT JOIN equipment e_b ON e_b.absid = cc.PTR_equip_b LEFT JOIN events ON events.absid = cc.PTR_project - INNER JOIN equipment_card ec - ON ec.absid = cc.PTR_card_a + INNER JOIN equipment_card ec_a + ON ec_a.absid = cc.PTR_card_a LEFT JOIN equipment_card ec_b ON ec_b.absid = cc.PTR_card_b LEFT JOIN organisation o - ON o.absid = ec.manufacturer - LEFT JOIN port_plugin pp - ON pp.PTR_card = cc.PTR_card_a AND pp.port = cc.port_a + ON o.absid = ec_a.manufacturer + LEFT JOIN port_plugin pp_a + ON pp_a.PTR_card = cc.PTR_card_a + AND pp_a.port = cc.port_a LEFT JOIN port_plugin pp_b ON pp_b.PTR_card = cc.PTR_card_b AND pp_b.port = cc.port_b @@ -129,6 +131,7 @@ retrieve_services_query = """SELECT * AS inner_query WHERE circuit_type IN ('path', 'service', 'l2circuit') ORDER BY + name, FIELD(status, 'spare', 'planned', -- GitLab