Add views to support json based device port view

This commit is contained in:
Eric A. Miller
2014-08-05 23:05:21 -04:00
parent 18f507ec56
commit 8337f5b0af
3 changed files with 175 additions and 0 deletions

View File

@@ -109,6 +109,15 @@ Returns the set of ports on this Device.
__PACKAGE__->has_many( ports => 'App::Netdisco::DB::Result::DevicePort', 'ip' ); __PACKAGE__->has_many( ports => 'App::Netdisco::DB::Result::DevicePort', 'ip' );
=head2 ports_flattened
Returns the set of ports on this Device with vlan_membership and ssid
returned as an array.
=cut
__PACKAGE__->has_many( ports_flattened => 'App::Netdisco::DB::Result::Virtual::DevicePortFlattened', 'ip' );
=head2 modules =head2 modules
Returns the set chassis modules on this Device. Returns the set chassis modules on this Device.

View File

@@ -0,0 +1,79 @@
package App::Netdisco::DB::Result::Virtual::DevicePortFlattened;
use strict;
use warnings;
use utf8;
use base 'App::Netdisco::DB::Result::DevicePort';
__PACKAGE__->load_components('Helper::Row::SubClass');
__PACKAGE__->subclass;
__PACKAGE__->table_class('DBIx::Class::ResultSource::View');
__PACKAGE__->table('device_port_flattened');
__PACKAGE__->result_source_instance->is_virtual(1);
__PACKAGE__->result_source_instance->view_definition(<<'ENDSQL');
SELECT
dp.*,
to_char(d.last_discover - (d.uptime - dp.lastchange) / 100 * interval '1 second', 'YYYY-MM-DD HH24:MI:SS') AS lastchange_stamp,
agg_master.up_admin AS agg_master_up_admin,
agg_master.up AS agg_master_up,
(SELECT array_agg(dpv.vlan) FROM device_port_vlan dpv WHERE dpv.ip = dp.ip AND dpv.port = dp.port) AS vlan_membership,
(SELECT dpv.vlan FROM device_port_vlan dpv WHERE dpv.ip = dp.ip AND dpv.port = dp.port AND native) AS native_vlan,
(SELECT array_agg(ssid.ssid) FROM device_port_ssid ssid WHERE ssid.ip = dp.ip AND ssid.port = dp.port) AS ssids,
neighbor_alias.ip AS neighbor_alias_ip,
neighbor_alias.dns AS neighbor_alias_dns,
d.uptime AS device_uptime,
d.last_discover AS device_last_discover,
dpp.admin AS power_admin,
dpp.status AS power_status,
dpp.power AS power
FROM device_port dp
JOIN device d ON d.ip = dp.ip
LEFT JOIN device_port agg_master ON agg_master.ip = dp.ip
AND agg_master.port = dp.slave_of
LEFT JOIN device_ip neighbor_alias ON neighbor_alias.alias = dp.remote_ip
LEFT JOIN device_port_power dpp ON dp.ip = dpp.ip
AND dp.port = dpp.port
ENDSQL
__PACKAGE__->add_columns(
"lastchange_stamp",
{ data_type => "text", is_nullable => 1 },
"agg_master_up_admin",
{ data_type => "text", is_nullable => 1 },
"agg_master_up",
{ data_type => "text", is_nullable => 1 },
"vlan_membership",
{ data_type => "integer[]", is_nullable => 1 },
"native_vlan",
{ data_type => "integer", is_nullable => 1 },
"ssids",
{ data_type => "text[]", is_nullable => 1 },
"neighbor_alias_ip",
{ data_type => "inet", is_nullable => 0 },
"neighbor_alias_dns",
{ data_type => "text", is_nullable => 1 },
"device_uptime",
{ data_type => "bigint", is_nullable => 1 },
"device_last_discover",
{ data_type => "timestamp", is_nullable => 1 },
"power_admin",
{ data_type => "text", is_nullable => 1 },
"power_status",
{ data_type => "text", is_nullable => 1 },
"power",
{ data_type => "integer", is_nullable => 1 },
);
__PACKAGE__->has_many( nodes => 'App::Netdisco::DB::Result::Virtual::NodeFlattened',
{
'foreign.switch' => 'self.ip',
'foreign.port' => 'self.port',
},
{ join_type => 'LEFT',
where => { 'foreign.switch' => 'self.ip' }
},
);
1;

View File

@@ -0,0 +1,87 @@
package App::Netdisco::DB::Result::Virtual::NodeFlattened;
use strict;
use warnings;
use utf8;
use base 'App::Netdisco::DB::Result::Node';
__PACKAGE__->load_components('Helper::Row::SubClass');
__PACKAGE__->subclass;
__PACKAGE__->table_class('DBIx::Class::ResultSource::View');
__PACKAGE__->table('node_flattened');
__PACKAGE__->result_source_instance->is_virtual(1);
__PACKAGE__->result_source_instance->view_definition(<<'ENDSQL');
SELECT DISTINCT ON (n.mac,
n.port) n.*,
(SELECT array_agg(n2.vlan)
FROM node n2
WHERE n2.port = n.port
AND n2.mac = n.mac) AS vlans,
(SELECT array_agg(ip)
FROM
(SELECT ni.ip
FROM node_ip ni
WHERE ni.mac = n.mac
ORDER BY ni.ip) AS tab) AS ip,
(SELECT array_agg(dns)
FROM
(SELECT ni.dns
FROM node_ip ni
WHERE ni.mac = n.mac
ORDER BY ni.ip) AS tab) AS dns,
(SELECT array_agg(active)
FROM
(SELECT ni.active
FROM node_ip ni
WHERE ni.mac = n.mac
ORDER BY ni.ip) AS tab) AS ip_active,
(SELECT array_agg(w.ssid)
FROM node_wireless w
WHERE w.mac = n.mac) AS ssids,
nb.nbname,
nb.domain,
nb.nbuser,
nb.ip AS nb_ip,
oui.abbrev
FROM node n
LEFT JOIN node_nbt nb ON nb.mac = n.mac
LEFT JOIN oui oui ON oui.oui = n.oui
WHERE n.switch = ?
ENDSQL
__PACKAGE__->add_columns(
"vlans",
{ data_type => "integer[]", is_nullable => 1 },
"ip",
{ data_type => "inet[]", is_nullable => 1 },
"dns",
{ data_type => "text[]", is_nullable => 1 },
"ip_active",
{ data_type => "boolean[]", is_nullable => 1 },
"ssids",
{ data_type => "text[]", is_nullable => 1 },
"nbname",
{ data_type => "text", is_nullable => 1 },
"domain",
{ data_type => "text", is_nullable => 1 },
"nbuser",
{ data_type => "text", is_nullable => 1 },
"nb_ip",
{ data_type => "inet[]", is_nullable => 1 },
"abbrev",
{ data_type => "text", is_nullable => 1 },
);
__PACKAGE__->belongs_to( device_port => 'App::Netdisco::DB::Result::Virtual::DevicePortFlattened',
{ 'foreign.ip' => 'self.switch', 'foreign.port' => 'self.port' },
{ join_type => 'LEFT' }
);
1;