Merge branch 'master' into og-multiple-domain-suffix
This commit is contained in:
@@ -242,6 +242,23 @@ __PACKAGE__->belongs_to( neighbor_alias => 'App::Netdisco::DB::Result::DeviceIp'
|
||||
{ join_type => 'LEFT' },
|
||||
);
|
||||
|
||||
=head2 last_node
|
||||
|
||||
This relationship will return the last node that was seen on the port.
|
||||
|
||||
The JOIN is of type "LEFT" in case there isn't any such node.
|
||||
|
||||
=cut
|
||||
|
||||
__PACKAGE__->belongs_to(
|
||||
last_node => 'App::Netdisco::DB::Result::Virtual::LastNode', {
|
||||
'foreign.switch' => 'self.ip',
|
||||
'foreign.port' => 'self.port',
|
||||
}, {
|
||||
join_type => 'LEFT',
|
||||
}
|
||||
);
|
||||
|
||||
=head2 vlans
|
||||
|
||||
As compared to C<port_vlans>, this relationship returns a set of Device VLAN
|
||||
|
||||
@@ -29,6 +29,8 @@ __PACKAGE__->add_columns(
|
||||
{ data_type => "boolean", default_value => \"false", is_nullable => 1 },
|
||||
"ldap",
|
||||
{ data_type => "boolean", default_value => \"false", is_nullable => 1 },
|
||||
"radius",
|
||||
{ data_type => "boolean", default_value => \"false", is_nullable => 1 },
|
||||
"admin",
|
||||
{ data_type => "boolean", default_value => \"false", is_nullable => 1 },
|
||||
"fullname",
|
||||
|
||||
54
lib/App/Netdisco/DB/Result/Virtual/LastNode.pm
Normal file
54
lib/App/Netdisco/DB/Result/Virtual/LastNode.pm
Normal file
@@ -0,0 +1,54 @@
|
||||
package App::Netdisco::DB::Result::Virtual::LastNode;
|
||||
|
||||
use strict;
|
||||
use warnings;
|
||||
|
||||
use base 'DBIx::Class::Core';
|
||||
|
||||
__PACKAGE__->table_class('DBIx::Class::ResultSource::View');
|
||||
|
||||
__PACKAGE__->table('last_node');
|
||||
__PACKAGE__->result_source_instance->is_virtual(1);
|
||||
__PACKAGE__->result_source_instance->view_definition(<<ENDSQL
|
||||
SELECT DISTINCT ON (switch, port) * FROM node
|
||||
ORDER BY switch, port, time_last desc
|
||||
ENDSQL
|
||||
);
|
||||
|
||||
__PACKAGE__->add_columns(
|
||||
"mac",
|
||||
{ data_type => "macaddr", is_nullable => 0 },
|
||||
"switch",
|
||||
{ data_type => "inet", is_nullable => 0 },
|
||||
"port",
|
||||
{ data_type => "text", is_nullable => 0 },
|
||||
"active",
|
||||
{ data_type => "boolean", is_nullable => 1 },
|
||||
"oui",
|
||||
{ data_type => "varchar", is_nullable => 1, size => 8 },
|
||||
"time_first",
|
||||
{
|
||||
data_type => "timestamp",
|
||||
default_value => \"current_timestamp",
|
||||
is_nullable => 1,
|
||||
original => { default_value => \"now()" },
|
||||
},
|
||||
"time_recent",
|
||||
{
|
||||
data_type => "timestamp",
|
||||
default_value => \"current_timestamp",
|
||||
is_nullable => 1,
|
||||
original => { default_value => \"now()" },
|
||||
},
|
||||
"time_last",
|
||||
{
|
||||
data_type => "timestamp",
|
||||
default_value => \"current_timestamp",
|
||||
is_nullable => 1,
|
||||
original => { default_value => \"now()" },
|
||||
},
|
||||
"vlan",
|
||||
{ data_type => "text", is_nullable => 0, default_value => '0' },
|
||||
);
|
||||
|
||||
1;
|
||||
@@ -7,6 +7,7 @@ use base 'DBIx::Class::Core';
|
||||
|
||||
__PACKAGE__->table_class('DBIx::Class::ResultSource::View');
|
||||
|
||||
# NOTE this query is in `git grep 'THREE PLACES'`
|
||||
__PACKAGE__->table('port_utilization');
|
||||
__PACKAGE__->result_source_instance->is_virtual(1);
|
||||
__PACKAGE__->result_source_instance->view_definition(<<ENDSQL
|
||||
@@ -17,11 +18,23 @@ __PACKAGE__->result_source_instance->view_definition(<<ENDSQL
|
||||
ELSE 0 END) as ports_in_use,
|
||||
sum(CASE WHEN (dp.type != 'propVirtual' AND dp.up_admin != 'up') THEN 1
|
||||
ELSE 0 END) as ports_shutdown,
|
||||
sum(CASE WHEN (dp.type != 'propVirtual' AND dp.up_admin = 'up' AND dp.up != 'up'
|
||||
AND ( age(now(), to_timestamp(extract(epoch from d.last_discover) - (d.uptime - dp.lastchange)/100)) > ?::interval )) THEN 1
|
||||
ELSE 0 END) as ports_free
|
||||
FROM device d LEFT JOIN device_port dp
|
||||
sum(CASE
|
||||
WHEN ( dp.type != 'propVirtual' AND dp.up_admin = 'up' AND dp.up != 'up'
|
||||
AND (age(now(), to_timestamp(extract(epoch from d.last_discover) - (d.uptime/100))) < ?::interval)
|
||||
AND (last_node.time_last IS NULL OR (age(now(), last_node.time_last)) > ?::interval) )
|
||||
THEN 1
|
||||
WHEN ( dp.type != 'propVirtual' AND dp.up_admin = 'up' AND dp.up != 'up'
|
||||
AND (age(now(), to_timestamp(extract(epoch from d.last_discover) - (d.uptime - dp.lastchange)/100)) > ?::interval) )
|
||||
THEN 1
|
||||
ELSE 0
|
||||
END) as ports_free
|
||||
FROM device d
|
||||
LEFT JOIN device_port dp
|
||||
ON d.ip = dp.ip
|
||||
LEFT JOIN
|
||||
( SELECT DISTINCT ON (switch, port) * FROM node
|
||||
ORDER BY switch, port, time_last desc ) AS last_node
|
||||
ON dp.port = last_node.port AND dp.ip = last_node.switch
|
||||
GROUP BY d.dns, d.ip
|
||||
ORDER BY d.dns, d.ip
|
||||
ENDSQL
|
||||
|
||||
@@ -20,6 +20,9 @@ __PACKAGE__->result_source_instance->view_definition(<<ENDSQL
|
||||
SELECT username, 'ldap' AS role FROM users
|
||||
WHERE ldap
|
||||
UNION
|
||||
SELECT username, 'radius' AS role FROM users
|
||||
WHERE radius
|
||||
UNION
|
||||
SELECT username, 'api' AS role FROM users
|
||||
WHERE token IS NOT NULL AND token_from IS NOT NULL
|
||||
ENDSQL
|
||||
|
||||
@@ -38,7 +38,7 @@ sub get_distinct_col {
|
||||
|
||||
Returns a ResultSet for DataTables Server-side processing which populates
|
||||
the displayed table. Evaluates the supplied query parameters for filtering,
|
||||
paging, and ordering information. Note: query paramters are expected to be
|
||||
paging, and ordering information. Note: query parameters are expected to be
|
||||
passed as a reference to an expanded hash of hashes.
|
||||
|
||||
Filtering if present, will generate simple LIKE matching conditions for each
|
||||
@@ -75,7 +75,7 @@ sub get_datatables_data {
|
||||
Returns the total records, after filtering (i.e. the total number of
|
||||
records after filtering has been applied - not just the number of records
|
||||
being returned for this page of data) for a datatables ResultSet and
|
||||
query parameters. Note: query paramters are expected to be passed as a
|
||||
query parameters. Note: query parameters are expected to be passed as a
|
||||
reference to an expanded hash of hashes.
|
||||
|
||||
=cut
|
||||
|
||||
@@ -12,7 +12,7 @@ __PACKAGE__->load_components(qw/
|
||||
|
||||
=head2 skipped( $backend?, $max_deferrals?, $retry_after? )
|
||||
|
||||
Retuns a correlated subquery for the set of C<device_skip> entries that apply
|
||||
Returns a correlated subquery for the set of C<device_skip> entries that apply
|
||||
to some jobs. They match the device IP, current backend, and job action.
|
||||
|
||||
Pass the C<backend> FQDN (or the current host will be used as a default), the
|
||||
|
||||
@@ -187,11 +187,11 @@ Will match exactly the C<model> field.
|
||||
|
||||
=item os
|
||||
|
||||
Will match exactly the C<os> field, which is the operating sytem.
|
||||
Will match exactly the C<os> field, which is the operating system.
|
||||
|
||||
=item os_ver
|
||||
|
||||
Will match exactly the C<os_ver> field, which is the operating sytem software version.
|
||||
Will match exactly the C<os_ver> field, which is the operating system software version.
|
||||
|
||||
=item vendor
|
||||
|
||||
@@ -226,21 +226,20 @@ sub search_by_field {
|
||||
}
|
||||
|
||||
# For Search on Layers
|
||||
my @layer_search = ( '_', '_', '_', '_', '_', '_', '_' );
|
||||
# @layer_search is computer indexed, left->right
|
||||
my $layers = $p->{layers};
|
||||
my @layer_select = ();
|
||||
if ( defined $layers && ref $layers ) {
|
||||
foreach my $layer (@$layers) {
|
||||
next unless defined $layer and length($layer);
|
||||
next if ( $layer < 1 || $layer > 7 );
|
||||
$layer_search[ $layer - 1 ] = 1;
|
||||
push @layer_select,
|
||||
\[ 'substring(me.layers,9-?, 1)::int = 1', $layer ];
|
||||
}
|
||||
}
|
||||
elsif ( defined $layers ) {
|
||||
$layer_search[ $layers - 1 ] = 1;
|
||||
push @layer_select,
|
||||
\[ 'substring(me.layers,9-?, 1)::int = 1', $layers ];
|
||||
}
|
||||
# the database field is in order 87654321
|
||||
my $layer_string = join( '', reverse @layer_search );
|
||||
|
||||
return $rs
|
||||
->search_rs({}, $attrs)
|
||||
@@ -252,8 +251,6 @@ sub search_by_field {
|
||||
{ '-ilike' => "\%$p->{location}\%" }) : ()),
|
||||
($p->{description} ? ('me.description' =>
|
||||
{ '-ilike' => "\%$p->{description}\%" }) : ()),
|
||||
($p->{layers} ? ('me.layers' =>
|
||||
{ '-ilike' => "\%$layer_string" }) : ()),
|
||||
|
||||
($p->{model} ? ('me.model' =>
|
||||
{ '-in' => $p->{model} }) : ()),
|
||||
@@ -264,6 +261,8 @@ sub search_by_field {
|
||||
($p->{vendor} ? ('me.vendor' =>
|
||||
{ '-in' => $p->{vendor} }) : ()),
|
||||
|
||||
($p->{layers} ? (-or => \@layer_select) : ()),
|
||||
|
||||
($p->{dns} ? (
|
||||
-or => [
|
||||
'me.dns' => { '-ilike' => "\%$p->{dns}\%" },
|
||||
|
||||
@@ -40,7 +40,7 @@ sub with_times {
|
||||
});
|
||||
}
|
||||
|
||||
=head2 with_free_ports
|
||||
=head2 with_is_free
|
||||
|
||||
This is a modifier for any C<search()> (including the helpers below) which
|
||||
will add the following additional synthesized columns to the result set:
|
||||
@@ -67,12 +67,13 @@ sub with_is_free {
|
||||
->search({},
|
||||
{
|
||||
'+columns' => { is_free =>
|
||||
\["me.up != 'up' and "
|
||||
."age(now(), to_timestamp(extract(epoch from device.last_discover) "
|
||||
."- (device.uptime - me.lastchange)/100)) "
|
||||
."> ?::interval",
|
||||
[{} => $interval]] },
|
||||
join => 'device',
|
||||
# NOTE this query is in `git grep 'THREE PLACES'`
|
||||
\["me.up_admin = 'up' AND me.up != 'up' AND me.type != 'propVirtual' AND "
|
||||
."((age(now(), to_timestamp(extract(epoch from device.last_discover) - (device.uptime/100))) < ?::interval "
|
||||
."AND (last_node.time_last IS NULL OR age(now(), last_node.time_last) > ?::interval)) "
|
||||
."OR age(now(), to_timestamp(extract(epoch from device.last_discover) - (device.uptime - me.lastchange)/100)) > ?::interval)",
|
||||
[{} => $interval],[ {} => $interval],[ {} => $interval]] },
|
||||
join => [qw/device last_node/],
|
||||
});
|
||||
}
|
||||
|
||||
@@ -96,14 +97,23 @@ sub only_free_ports {
|
||||
->search_rs($cond, $attrs)
|
||||
->search(
|
||||
{
|
||||
'me.up' => { '!=' => 'up' },
|
||||
},{
|
||||
where =>
|
||||
\["age(now(), to_timestamp(extract(epoch from device.last_discover) "
|
||||
."- (device.uptime - me.lastchange)/100)) "
|
||||
."> ?::interval",
|
||||
# NOTE this query is in `git grep 'THREE PLACES'`
|
||||
'me.up_admin' => 'up',
|
||||
'me.up' => { '!=' => 'up' },
|
||||
'me.type' => { '!=' => 'propVirtual' },
|
||||
-or => [
|
||||
-and => [
|
||||
\["age(now(), to_timestamp(extract(epoch from device.last_discover) - (device.uptime/100))) < ?::interval",
|
||||
[{} => $interval]],
|
||||
-or => [
|
||||
'last_node.time_last' => undef,
|
||||
\["age(now(), last_node.time_last) > ?::interval", [{} => $interval]],
|
||||
]
|
||||
],
|
||||
\["age(now(), to_timestamp(extract(epoch from device.last_discover) - (device.uptime - me.lastchange)/100)) > ?::interval",
|
||||
[{} => $interval]],
|
||||
join => 'device' },
|
||||
],
|
||||
},{ join => [qw/device last_node/] },
|
||||
);
|
||||
}
|
||||
|
||||
|
||||
Reference in New Issue
Block a user