#1111 Support for OUI28/MA-M and OUI36/MA-S
* new oui importer using IEEE csv for MA-L+M+S * schema update for new vendor table * change vendor to manufacturer because Device has a vendor field * remove oui from manuf table, and update node oui after manuf update * faster way to bulk update node oui * switch from using oui table to manufacturer table for vendor lookup * some other oui cleanup * faster/scalable way to join a macaddr to manuf table * remove device.oui support * update node oui in bulk at end of macsuck run * correct literal sql instead of bind * more efficient to get oui base for each mac * comment better the base lookup in macsuck
This commit is contained in:
178
bin/ieee-oui-import
Executable file
178
bin/ieee-oui-import
Executable file
@@ -0,0 +1,178 @@
|
|||||||
|
#!/usr/bin/env perl
|
||||||
|
|
||||||
|
use strict;
|
||||||
|
use warnings;
|
||||||
|
|
||||||
|
our $home;
|
||||||
|
|
||||||
|
BEGIN {
|
||||||
|
use FindBin;
|
||||||
|
FindBin::again();
|
||||||
|
|
||||||
|
$home = ($ENV{NETDISCO_HOME} || $ENV{HOME});
|
||||||
|
|
||||||
|
# try to find a localenv if one isn't already in place.
|
||||||
|
if (!exists $ENV{PERL_LOCAL_LIB_ROOT}) {
|
||||||
|
use File::Spec;
|
||||||
|
my $localenv = File::Spec->catfile($FindBin::RealBin, 'localenv');
|
||||||
|
exec($localenv, $0, @ARGV) if -f $localenv;
|
||||||
|
$localenv = File::Spec->catfile($home, 'perl5', 'bin', 'localenv');
|
||||||
|
exec($localenv, $0, @ARGV) if -f $localenv;
|
||||||
|
|
||||||
|
die "Sorry, can't find libs required for App::Netdisco.\n"
|
||||||
|
if !exists $ENV{PERLBREW_PERL};
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
BEGIN {
|
||||||
|
use Path::Class;
|
||||||
|
|
||||||
|
# stuff useful locations into @INC and $PATH
|
||||||
|
unshift @INC,
|
||||||
|
dir($FindBin::RealBin)->parent->subdir('lib')->stringify,
|
||||||
|
dir($FindBin::RealBin, 'lib')->stringify;
|
||||||
|
|
||||||
|
use Config;
|
||||||
|
$ENV{PATH} = $FindBin::RealBin . $Config{path_sep} . $ENV{PATH};
|
||||||
|
}
|
||||||
|
|
||||||
|
use App::Netdisco;
|
||||||
|
use Dancer ':script';
|
||||||
|
use Dancer::Plugin::DBIC 'schema';
|
||||||
|
|
||||||
|
use HTTP::Tiny;
|
||||||
|
use Text::CSV 'csv';
|
||||||
|
use Math::BigInt;
|
||||||
|
|
||||||
|
binmode STDOUT, ":utf8";
|
||||||
|
|
||||||
|
my %urls = (
|
||||||
|
MAL => 'https://raw.githubusercontent.com/netdisco/upstream-sources/master/ieee/MA/MA-L.csv',
|
||||||
|
MAM => 'https://raw.githubusercontent.com/netdisco/upstream-sources/master/ieee/MA/MA-M.csv',
|
||||||
|
MAS => 'https://raw.githubusercontent.com/netdisco/upstream-sources/master/ieee/MA/MA-S.csv',
|
||||||
|
);
|
||||||
|
|
||||||
|
my %oui = ();
|
||||||
|
|
||||||
|
foreach my $MA (sort keys %urls) {
|
||||||
|
my $resp = HTTP::Tiny->new->get($urls{$MA});
|
||||||
|
my $content = $resp->{content};
|
||||||
|
my $aoh = csv( in => \$content, headers => 'auto', encoding => 'UTF-8' );
|
||||||
|
foreach my $row (@$aoh) {
|
||||||
|
next if $row->{'Organization Name'} eq 'IEEE Registration Authority';
|
||||||
|
next if exists $oui{ lc $row->{'Assignment'} };
|
||||||
|
|
||||||
|
$row->{abbrev} = shorten($row->{'Organization Name'});
|
||||||
|
|
||||||
|
$row->{base} = lc $row->{'Assignment'};
|
||||||
|
$row->{bits} = length($row->{base}) * 4;
|
||||||
|
|
||||||
|
$row->{first} = $row->{'Assignment'} . '0' x ( 12 - length( $row->{'Assignment'} ) );
|
||||||
|
$row->{last} = $row->{'Assignment'} . 'F' x ( 12 - length( $row->{'Assignment'} ) );
|
||||||
|
|
||||||
|
$row->{range} = '['. Math::BigInt->from_hex($row->{first})->as_int()
|
||||||
|
.','. Math::BigInt->from_hex($row->{last})->as_int() .']';
|
||||||
|
|
||||||
|
$oui{ $row->{base} } = $row;
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
# roll everything back if we're testing
|
||||||
|
my $txn_guard = $ENV{ND2_DB_ROLLBACK}
|
||||||
|
? schema('netdisco')->storage->txn_scope_guard : undef;
|
||||||
|
|
||||||
|
schema('netdisco')->txn_do(sub{
|
||||||
|
schema('netdisco')->resultset('Manufacturer')->delete;
|
||||||
|
|
||||||
|
schema('netdisco')->resultset('Manufacturer')->populate([
|
||||||
|
map {{
|
||||||
|
company => $oui{$_}->{'Organization Name'},
|
||||||
|
abbrev => $oui{$_}->{abbrev},
|
||||||
|
base => $oui{$_}->{base},
|
||||||
|
bits => $oui{$_}->{bits},
|
||||||
|
first => $oui{$_}->{first},
|
||||||
|
last => $oui{$_}->{last},
|
||||||
|
range => $oui{$_}->{range},
|
||||||
|
}} sort keys %oui
|
||||||
|
]);
|
||||||
|
|
||||||
|
schema('netdisco')->storage->dbh_do(
|
||||||
|
sub {
|
||||||
|
my ($storage, $dbh, @args) = @_;
|
||||||
|
|
||||||
|
local $dbh->{TraceLevel} =
|
||||||
|
($ENV{DBIC_TRACE} ? '1|SQL' : $dbh->{TraceLevel});
|
||||||
|
|
||||||
|
$dbh->do(q{
|
||||||
|
UPDATE node SET oui = (
|
||||||
|
SELECT base FROM manufacturer
|
||||||
|
WHERE ('x' || lpad( translate( mac::text, ':', ''), 16, '0')) ::bit(64) ::bigint <@ range
|
||||||
|
LIMIT 1
|
||||||
|
)
|
||||||
|
});
|
||||||
|
},
|
||||||
|
);
|
||||||
|
});
|
||||||
|
|
||||||
|
exit 0;
|
||||||
|
|
||||||
|
# This subroutine is based on Wireshark's make-manuf
|
||||||
|
# http://anonsvn.wireshark.org/wireshark/trunk/tools/make-manuf
|
||||||
|
sub shorten {
|
||||||
|
my $manuf = shift;
|
||||||
|
|
||||||
|
#$manuf = decode("utf8", $manuf, Encode::FB_CROAK);
|
||||||
|
$manuf = " " . $manuf . " ";
|
||||||
|
|
||||||
|
# Remove any punctuation
|
||||||
|
$manuf =~ tr/',.()/ /;
|
||||||
|
|
||||||
|
# & isn't needed when Standalone
|
||||||
|
$manuf =~ s/ \& / /g;
|
||||||
|
|
||||||
|
# remove junk whitespace
|
||||||
|
$manuf =~ s/\s+/ /g;
|
||||||
|
|
||||||
|
# Remove any "the", "inc", "plc" ...
|
||||||
|
$manuf
|
||||||
|
=~ s/\s(?:the|inc|incorporated|plc|systems|corp|corporation|s\/a|a\/s|ab|ag|kg|gmbh|co|company|limited|ltd|holding|spa)(?= )//gi;
|
||||||
|
|
||||||
|
# Convert to consistent case
|
||||||
|
$manuf =~ s/(\w+)/\u\L$1/g;
|
||||||
|
|
||||||
|
# Deviating from make-manuf for HP
|
||||||
|
$manuf =~ s/Hewlett[-]?Packard/Hp/;
|
||||||
|
|
||||||
|
# Truncate all names to first two words max 20 chars
|
||||||
|
if (length($manuf) > 21) {
|
||||||
|
my @twowords = grep {defined} (split ' ', $manuf)[0 .. 1];
|
||||||
|
$manuf = join ' ', @twowords;
|
||||||
|
}
|
||||||
|
|
||||||
|
# Remove all spaces
|
||||||
|
$manuf =~ s/\s+//g;
|
||||||
|
|
||||||
|
#return encode( "utf8", $manuf );
|
||||||
|
return $manuf;
|
||||||
|
}
|
||||||
|
|
||||||
|
__DATA__
|
||||||
|
|
||||||
|
0C15C5000000 {
|
||||||
|
Assignment "0C15C5",
|
||||||
|
bits 24,
|
||||||
|
first "0C15C5000000",
|
||||||
|
last "0C15C5FFFFFF",
|
||||||
|
"Organization Address" "167, Churye-2Dong, Sasang-Gu, Busan KR 617-716 " (dualvar: 167),
|
||||||
|
"Organization Name" "SDTEC Co., Ltd.",
|
||||||
|
oui "0c:15:c5",
|
||||||
|
Registry "MA-L",
|
||||||
|
abbrev "Sdtec"
|
||||||
|
},
|
||||||
|
|
||||||
|
[98] {
|
||||||
|
Assignment "8C1F64117" (dualvar: 8),
|
||||||
|
"Organization Address" "Spinnereistrasse 10 St. Gallen CH 9008 ",
|
||||||
|
"Organization Name" "Grossenbacher Systeme AG",
|
||||||
|
Registry "MA-S"
|
||||||
|
},
|
||||||
@@ -224,111 +224,13 @@ sub get_userpass {
|
|||||||
}
|
}
|
||||||
|
|
||||||
sub deploy_oui {
|
sub deploy_oui {
|
||||||
my $schema = schema('netdisco');
|
print color 'bold blue';
|
||||||
$schema->storage->disconnect;
|
print 'Updating OUI... ';
|
||||||
my @lines = ();
|
system('ieee-oui-import') == 0 or die "\n";
|
||||||
my %data = ();
|
say 'done.';
|
||||||
|
|
||||||
if (@ARGV) {
|
|
||||||
@lines = File::Slurper::read_lines($ARGV[0], 'iso-8859-1');
|
|
||||||
}
|
|
||||||
else {
|
|
||||||
my $url = 'https://raw.githubusercontent.com/netdisco/upstream-sources/master/ieee/oui.txt';
|
|
||||||
my $resp = HTTP::Tiny->new->get($url);
|
|
||||||
@lines = split /\n/, $resp->{content};
|
|
||||||
}
|
|
||||||
|
|
||||||
if (scalar @lines > 50) {
|
|
||||||
foreach my $line (@lines) {
|
|
||||||
if ($line =~ m/^\s*(.{2}-.{2}-.{2})\s+\(hex\)\s+(.*)\s*$/i) {
|
|
||||||
my ($oui, $company) = ($1, $2);
|
|
||||||
$oui =~ s/-/:/g;
|
|
||||||
$company =~ s/[\r\n]//g;
|
|
||||||
my $abbrev = shorten($company);
|
|
||||||
$data{lc($oui)}{'company'} = $company;
|
|
||||||
$data{lc($oui)}{'abbrev'} = $abbrev;
|
|
||||||
}
|
|
||||||
}
|
|
||||||
|
|
||||||
if ((scalar keys %data) > 15_000) {
|
|
||||||
# roll everything back if we're testing
|
|
||||||
my $txn_guard = $ENV{ND2_DB_ROLLBACK}
|
|
||||||
? schema('netdisco')->storage->txn_scope_guard : undef;
|
|
||||||
|
|
||||||
$schema->txn_do(sub{
|
|
||||||
$schema->resultset('Oui')->delete;
|
|
||||||
$schema->resultset('Oui')->populate([
|
|
||||||
map {
|
|
||||||
{ oui => $_,
|
|
||||||
company => Encode::decode('UTF-8', $data{$_}{'company'}),
|
|
||||||
abbrev => Encode::decode('UTF-8', $data{$_}{'abbrev'}),
|
|
||||||
}
|
|
||||||
} keys %data
|
|
||||||
]);
|
|
||||||
});
|
|
||||||
|
|
||||||
if (scalar @ARGV > 1) {
|
|
||||||
my @sql_lines = ('COPY oui (oui, company, abbrev) FROM stdin;');
|
|
||||||
foreach my $oui (sort {$a cmp $b} keys %data) {
|
|
||||||
push @sql_lines, sprintf "%s\t%s\t%s",
|
|
||||||
$oui,
|
|
||||||
Encode::decode('UTF-8', $data{$oui}{'company'}),
|
|
||||||
Encode::decode('UTF-8', $data{$oui}{'abbrev'});
|
|
||||||
}
|
|
||||||
File::Slurper::write_text($ARGV[1], join "\n", @sql_lines, "\\.\n\n");
|
|
||||||
}
|
|
||||||
}
|
|
||||||
|
|
||||||
print color 'bold blue';
|
|
||||||
say 'OUI update complete.';
|
|
||||||
}
|
|
||||||
else {
|
|
||||||
print color 'bold red';
|
|
||||||
say 'OUI update failed!';
|
|
||||||
}
|
|
||||||
|
|
||||||
print color 'reset';
|
print color 'reset';
|
||||||
}
|
}
|
||||||
|
|
||||||
# This subroutine is based on Wireshark's make-manuf
|
|
||||||
# http://anonsvn.wireshark.org/wireshark/trunk/tools/make-manuf
|
|
||||||
sub shorten {
|
|
||||||
my $manuf = shift;
|
|
||||||
|
|
||||||
$manuf = decode("utf8", $manuf, Encode::FB_CROAK);
|
|
||||||
$manuf = " " . $manuf . " ";
|
|
||||||
|
|
||||||
# Remove any punctuation
|
|
||||||
$manuf =~ tr/',.()/ /;
|
|
||||||
|
|
||||||
# & isn't needed when Standalone
|
|
||||||
$manuf =~ s/ \& / /g;
|
|
||||||
|
|
||||||
# remove junk whitespace
|
|
||||||
$manuf =~ s/\s+/ /g;
|
|
||||||
|
|
||||||
# Remove any "the", "inc", "plc" ...
|
|
||||||
$manuf
|
|
||||||
=~ s/\s(?:the|inc|incorporated|plc|systems|corp|corporation|s\/a|a\/s|ab|ag|kg|gmbh|co|company|limited|ltd|holding|spa)(?= )//gi;
|
|
||||||
|
|
||||||
# Convert to consistent case
|
|
||||||
$manuf =~ s/(\w+)/\u\L$1/g;
|
|
||||||
|
|
||||||
# Deviating from make-manuf for HP
|
|
||||||
$manuf =~ s/Hewlett[-]?Packard/Hp/;
|
|
||||||
|
|
||||||
# Truncate all names to first two words max 20 chars
|
|
||||||
if (length($manuf) > 21) {
|
|
||||||
my @twowords = grep {defined} (split ' ', $manuf)[0 .. 1];
|
|
||||||
$manuf = join ' ', @twowords;
|
|
||||||
}
|
|
||||||
|
|
||||||
# Remove all spaces
|
|
||||||
$manuf =~ s/\s+//g;
|
|
||||||
|
|
||||||
return encode( "utf8", $manuf );
|
|
||||||
}
|
|
||||||
|
|
||||||
sub deploy_mibs {
|
sub deploy_mibs {
|
||||||
my $mibhome = dir(shift); # /path/to/netdisco-mibs
|
my $mibhome = dir(shift); # /path/to/netdisco-mibs
|
||||||
my $fail = 0;
|
my $fail = 0;
|
||||||
|
|||||||
@@ -11,7 +11,7 @@ __PACKAGE__->load_namespaces(
|
|||||||
);
|
);
|
||||||
|
|
||||||
our # try to hide from kwalitee
|
our # try to hide from kwalitee
|
||||||
$VERSION = 84; # schema version used for upgrades, keep as integer
|
$VERSION = 85; # schema version used for upgrades, keep as integer
|
||||||
|
|
||||||
use Path::Class;
|
use Path::Class;
|
||||||
use File::ShareDir 'dist_dir';
|
use File::ShareDir 'dist_dir';
|
||||||
|
|||||||
@@ -384,14 +384,6 @@ sub renumber {
|
|||||||
|
|
||||||
=head1 ADDITIONAL COLUMNS
|
=head1 ADDITIONAL COLUMNS
|
||||||
|
|
||||||
=head2 oui
|
|
||||||
|
|
||||||
Returns the first half of the device MAC address.
|
|
||||||
|
|
||||||
=cut
|
|
||||||
|
|
||||||
sub oui { return substr( ((shift)->mac || ''), 0, 8 ) }
|
|
||||||
|
|
||||||
=head2 port_count
|
=head2 port_count
|
||||||
|
|
||||||
Returns the number of ports on this device. Enable this
|
Returns the number of ports on this device. Enable this
|
||||||
|
|||||||
@@ -302,6 +302,8 @@ __PACKAGE__->many_to_many( vlans => 'port_vlans', 'vlan_entry' );
|
|||||||
|
|
||||||
=head2 oui
|
=head2 oui
|
||||||
|
|
||||||
|
DEPRECATED: USE MANUFACTURER INSTEAD
|
||||||
|
|
||||||
Returns the C<oui> table entry matching this Port. You can then join on this
|
Returns the C<oui> table entry matching this Port. You can then join on this
|
||||||
relation and retrieve the Company name from the related table.
|
relation and retrieve the Company name from the related table.
|
||||||
|
|
||||||
@@ -320,6 +322,26 @@ __PACKAGE__->belongs_to( oui => 'App::Netdisco::DB::Result::Oui',
|
|||||||
{ join_type => 'LEFT' }
|
{ join_type => 'LEFT' }
|
||||||
);
|
);
|
||||||
|
|
||||||
|
=head2 manufacturer
|
||||||
|
|
||||||
|
Returns the C<manufacturer> table entry matching this Port. You can then join on this
|
||||||
|
relation and retrieve the Company name from the related table.
|
||||||
|
|
||||||
|
The JOIN is of type LEFT, in case the Manufacturer table has not been populated.
|
||||||
|
|
||||||
|
=cut
|
||||||
|
|
||||||
|
__PACKAGE__->belongs_to( manufacturer => 'App::Netdisco::DB::Result::Manufacturer',
|
||||||
|
sub {
|
||||||
|
my $args = shift;
|
||||||
|
return {
|
||||||
|
"$args->{foreign_alias}.range" => { '@>' =>
|
||||||
|
\qq{('x' || lpad( translate( $args->{self_alias}.mac ::text, ':', ''), 16, '0')) ::bit(64) ::bigint} },
|
||||||
|
};
|
||||||
|
},
|
||||||
|
{ join_type => 'LEFT' }
|
||||||
|
);
|
||||||
|
|
||||||
=head1 ADDITIONAL METHODS
|
=head1 ADDITIONAL METHODS
|
||||||
|
|
||||||
=head2 neighbor
|
=head2 neighbor
|
||||||
|
|||||||
29
lib/App/Netdisco/DB/Result/Manufacturer.pm
Normal file
29
lib/App/Netdisco/DB/Result/Manufacturer.pm
Normal file
@@ -0,0 +1,29 @@
|
|||||||
|
use utf8;
|
||||||
|
package App::Netdisco::DB::Result::Manufacturer;
|
||||||
|
|
||||||
|
use strict;
|
||||||
|
use warnings;
|
||||||
|
|
||||||
|
use base 'App::Netdisco::DB::Result';
|
||||||
|
__PACKAGE__->table("manufacturer");
|
||||||
|
|
||||||
|
__PACKAGE__->add_columns(
|
||||||
|
"company",
|
||||||
|
{ data_type => "text", is_nullable => 1 },
|
||||||
|
"abbrev",
|
||||||
|
{ data_type => "text", is_nullable => 1 },
|
||||||
|
"base",
|
||||||
|
{ data_type => "text", is_nullable => 0 },
|
||||||
|
"bits",
|
||||||
|
{ data_type => "integer", is_nullable => 1 },
|
||||||
|
"first",
|
||||||
|
{ data_type => "macaddr", is_nullable => 1 },
|
||||||
|
"last",
|
||||||
|
{ data_type => "macaddr", is_nullable => 1 },
|
||||||
|
"range",
|
||||||
|
{ data_type => "int8range", is_nullable => 1 },
|
||||||
|
);
|
||||||
|
|
||||||
|
__PACKAGE__->set_primary_key("base");
|
||||||
|
|
||||||
|
1;
|
||||||
@@ -19,7 +19,7 @@ __PACKAGE__->add_columns(
|
|||||||
"active",
|
"active",
|
||||||
{ data_type => "boolean", is_nullable => 1 },
|
{ data_type => "boolean", is_nullable => 1 },
|
||||||
"oui",
|
"oui",
|
||||||
{ data_type => "varchar", is_nullable => 1, is_serializable => 0, size => 8 },
|
{ data_type => "varchar", is_nullable => 1, is_serializable => 0, size => 9 },
|
||||||
"time_first",
|
"time_first",
|
||||||
{
|
{
|
||||||
data_type => "timestamp",
|
data_type => "timestamp",
|
||||||
@@ -149,6 +149,8 @@ __PACKAGE__->has_many( wireless => 'App::Netdisco::DB::Result::NodeWireless',
|
|||||||
|
|
||||||
=head2 oui
|
=head2 oui
|
||||||
|
|
||||||
|
DEPRECATED: USE MANUFACTURER INSTEAD
|
||||||
|
|
||||||
Returns the C<oui> table entry matching this Node. You can then join on this
|
Returns the C<oui> table entry matching this Node. You can then join on this
|
||||||
relation and retrieve the Company name from the related table.
|
relation and retrieve the Company name from the related table.
|
||||||
|
|
||||||
@@ -159,6 +161,21 @@ The JOIN is of type LEFT, in case the OUI table has not been populated.
|
|||||||
__PACKAGE__->belongs_to( oui => 'App::Netdisco::DB::Result::Oui', 'oui',
|
__PACKAGE__->belongs_to( oui => 'App::Netdisco::DB::Result::Oui', 'oui',
|
||||||
{ join_type => 'LEFT' } );
|
{ join_type => 'LEFT' } );
|
||||||
|
|
||||||
|
=head2 manufacturer
|
||||||
|
|
||||||
|
Returns the C<manufacturer> table entry matching this Node. You can then join on this
|
||||||
|
relation and retrieve the Company name from the related table.
|
||||||
|
|
||||||
|
The JOIN is of type LEFT, in case the Manufacturer table has not been populated.
|
||||||
|
|
||||||
|
=cut
|
||||||
|
|
||||||
|
__PACKAGE__->belongs_to( manufacturer => 'App::Netdisco::DB::Result::Manufacturer', {
|
||||||
|
'foreign.base' => 'self.oui',
|
||||||
|
},
|
||||||
|
{ join_type => 'LEFT' }
|
||||||
|
);
|
||||||
|
|
||||||
=head1 ADDITIONAL COLUMNS
|
=head1 ADDITIONAL COLUMNS
|
||||||
|
|
||||||
=head2 time_first_stamp
|
=head2 time_first_stamp
|
||||||
|
|||||||
@@ -41,6 +41,8 @@ __PACKAGE__->set_primary_key("mac", "ip");
|
|||||||
|
|
||||||
=head2 oui
|
=head2 oui
|
||||||
|
|
||||||
|
DEPRECATED: USE MANUFACTURER INSTEAD
|
||||||
|
|
||||||
Returns the C<oui> table entry matching this Node. You can then join on this
|
Returns the C<oui> table entry matching this Node. You can then join on this
|
||||||
relation and retrieve the Company name from the related table.
|
relation and retrieve the Company name from the related table.
|
||||||
|
|
||||||
@@ -59,6 +61,26 @@ __PACKAGE__->belongs_to( oui => 'App::Netdisco::DB::Result::Oui',
|
|||||||
{ join_type => 'LEFT' }
|
{ join_type => 'LEFT' }
|
||||||
);
|
);
|
||||||
|
|
||||||
|
=head2 manufacturer
|
||||||
|
|
||||||
|
Returns the C<manufacturer> table entry matching this Node. You can then join on this
|
||||||
|
relation and retrieve the Company name from the related table.
|
||||||
|
|
||||||
|
The JOIN is of type LEFT, in case the Manufacturer table has not been populated.
|
||||||
|
|
||||||
|
=cut
|
||||||
|
|
||||||
|
__PACKAGE__->belongs_to( manufacturer => 'App::Netdisco::DB::Result::Manufacturer',
|
||||||
|
sub {
|
||||||
|
my $args = shift;
|
||||||
|
return {
|
||||||
|
"$args->{foreign_alias}.range" => { '@>' =>
|
||||||
|
\qq{('x' || lpad( translate( $args->{self_alias}.mac ::text, ':', ''), 16, '0')) ::bit(64) ::bigint} },
|
||||||
|
};
|
||||||
|
},
|
||||||
|
{ join_type => 'LEFT' }
|
||||||
|
);
|
||||||
|
|
||||||
=head2 node_ips
|
=head2 node_ips
|
||||||
|
|
||||||
Returns the set of all C<node_ip> entries which are associated together with
|
Returns the set of all C<node_ip> entries which are associated together with
|
||||||
|
|||||||
@@ -47,6 +47,8 @@ __PACKAGE__->set_primary_key("mac");
|
|||||||
|
|
||||||
=head2 oui
|
=head2 oui
|
||||||
|
|
||||||
|
DEPRECATED: USE MANUFACTURER INSTEAD
|
||||||
|
|
||||||
Returns the C<oui> table entry matching this Node. You can then join on this
|
Returns the C<oui> table entry matching this Node. You can then join on this
|
||||||
relation and retrieve the Company name from the related table.
|
relation and retrieve the Company name from the related table.
|
||||||
|
|
||||||
@@ -65,6 +67,26 @@ __PACKAGE__->belongs_to( oui => 'App::Netdisco::DB::Result::Oui',
|
|||||||
{ join_type => 'LEFT' }
|
{ join_type => 'LEFT' }
|
||||||
);
|
);
|
||||||
|
|
||||||
|
=head2 manufacturer
|
||||||
|
|
||||||
|
Returns the C<manufacturer> table entry matching this Node. You can then join on this
|
||||||
|
relation and retrieve the Company name from the related table.
|
||||||
|
|
||||||
|
The JOIN is of type LEFT, in case the Manufacturer table has not been populated.
|
||||||
|
|
||||||
|
=cut
|
||||||
|
|
||||||
|
__PACKAGE__->belongs_to( manufacturer => 'App::Netdisco::DB::Result::Manufacturer',
|
||||||
|
sub {
|
||||||
|
my $args = shift;
|
||||||
|
return {
|
||||||
|
"$args->{foreign_alias}.range" => { '@>' =>
|
||||||
|
\qq{('x' || lpad( translate( $args->{self_alias}.mac ::text, ':', ''), 16, '0')) ::bit(64) ::bigint} },
|
||||||
|
};
|
||||||
|
},
|
||||||
|
{ join_type => 'LEFT' }
|
||||||
|
);
|
||||||
|
|
||||||
=head2 nodes
|
=head2 nodes
|
||||||
|
|
||||||
Returns the set of C<node> entries associated with this IP. That is, all the
|
Returns the set of C<node> entries associated with this IP. That is, all the
|
||||||
|
|||||||
@@ -48,6 +48,8 @@ __PACKAGE__->set_primary_key("mac", "ssid");
|
|||||||
|
|
||||||
=head2 oui
|
=head2 oui
|
||||||
|
|
||||||
|
DEPRECATED: USE MANUFACTURER INSTEAD
|
||||||
|
|
||||||
Returns the C<oui> table entry matching this Node. You can then join on this
|
Returns the C<oui> table entry matching this Node. You can then join on this
|
||||||
relation and retrieve the Company name from the related table.
|
relation and retrieve the Company name from the related table.
|
||||||
|
|
||||||
@@ -66,6 +68,26 @@ __PACKAGE__->belongs_to( oui => 'App::Netdisco::DB::Result::Oui',
|
|||||||
{ join_type => 'LEFT' }
|
{ join_type => 'LEFT' }
|
||||||
);
|
);
|
||||||
|
|
||||||
|
=head2 manufacturer
|
||||||
|
|
||||||
|
Returns the C<manufacturer> table entry matching this Node. You can then join on this
|
||||||
|
relation and retrieve the Company name from the related table.
|
||||||
|
|
||||||
|
The JOIN is of type LEFT, in case the Manufacturer table has not been populated.
|
||||||
|
|
||||||
|
=cut
|
||||||
|
|
||||||
|
__PACKAGE__->belongs_to( manufacturer => 'App::Netdisco::DB::Result::Manufacturer',
|
||||||
|
sub {
|
||||||
|
my $args = shift;
|
||||||
|
return {
|
||||||
|
"$args->{foreign_alias}.range" => { '@>' =>
|
||||||
|
\qq{('x' || lpad( translate( $args->{self_alias}.mac ::text, ':', ''), 16, '0')) ::bit(64) ::bigint} },
|
||||||
|
};
|
||||||
|
},
|
||||||
|
{ join_type => 'LEFT' }
|
||||||
|
);
|
||||||
|
|
||||||
=head2 node
|
=head2 node
|
||||||
|
|
||||||
Returns the C<node> table entry matching this wireless entry.
|
Returns the C<node> table entry matching this wireless entry.
|
||||||
|
|||||||
@@ -25,7 +25,7 @@ __PACKAGE__->add_columns(
|
|||||||
"active",
|
"active",
|
||||||
{ data_type => "boolean", is_nullable => 1 },
|
{ data_type => "boolean", is_nullable => 1 },
|
||||||
"oui",
|
"oui",
|
||||||
{ data_type => "varchar", is_nullable => 1, size => 8 },
|
{ data_type => "varchar", is_nullable => 1, size => 9 },
|
||||||
"time_first",
|
"time_first",
|
||||||
{
|
{
|
||||||
data_type => "timestamp",
|
data_type => "timestamp",
|
||||||
|
|||||||
@@ -8,15 +8,15 @@ __PACKAGE__->load_components(qw/
|
|||||||
+App::Netdisco::DB::ExplicitLocking
|
+App::Netdisco::DB::ExplicitLocking
|
||||||
/);
|
/);
|
||||||
|
|
||||||
my $order_by_time_last_and_join_oui = {
|
my $order_by_time_last_and_join_manufacturer = {
|
||||||
order_by => {'-desc' => 'time_last'},
|
order_by => {'-desc' => 'time_last'},
|
||||||
'+columns' => [
|
'+columns' => [
|
||||||
'oui.company',
|
'manufacturer.company',
|
||||||
'oui.abbrev',
|
'manufacturer.abbrev',
|
||||||
{ time_first_stamp => \"to_char(time_first, 'YYYY-MM-DD HH24:MI')" },
|
{ time_first_stamp => \"to_char(time_first, 'YYYY-MM-DD HH24:MI')" },
|
||||||
{ time_last_stamp => \"to_char(time_last, 'YYYY-MM-DD HH24:MI')" },
|
{ time_last_stamp => \"to_char(time_last, 'YYYY-MM-DD HH24:MI')" },
|
||||||
],
|
],
|
||||||
join => 'oui'
|
join => 'manufacturer'
|
||||||
};
|
};
|
||||||
|
|
||||||
=head1 with_times
|
=head1 with_times
|
||||||
@@ -38,7 +38,7 @@ sub with_times {
|
|||||||
my ($rs, $cond, $attrs) = @_;
|
my ($rs, $cond, $attrs) = @_;
|
||||||
|
|
||||||
return $rs
|
return $rs
|
||||||
->search_rs({}, $order_by_time_last_and_join_oui)
|
->search_rs({}, $order_by_time_last_and_join_manufacturer)
|
||||||
->search($cond, $attrs);
|
->search($cond, $attrs);
|
||||||
}
|
}
|
||||||
|
|
||||||
@@ -69,7 +69,7 @@ preformatted timestamps of the C<time_first> and C<time_last> fields.
|
|||||||
|
|
||||||
=item *
|
=item *
|
||||||
|
|
||||||
A JOIN is performed on the OUI table and the OUI C<company> column prefetched.
|
A JOIN is performed on the Manufacturer table and the Manufacturer C<company> column prefetched.
|
||||||
|
|
||||||
=back
|
=back
|
||||||
|
|
||||||
@@ -93,7 +93,7 @@ sub search_by_ip {
|
|||||||
$cond->{ip} = { $op => $ip };
|
$cond->{ip} = { $op => $ip };
|
||||||
|
|
||||||
return $rs
|
return $rs
|
||||||
->search_rs({}, $order_by_time_last_and_join_oui)
|
->search_rs({}, $order_by_time_last_and_join_manufacturer)
|
||||||
->search($cond, $attrs);
|
->search($cond, $attrs);
|
||||||
}
|
}
|
||||||
|
|
||||||
@@ -137,7 +137,7 @@ preformatted timestamps of the C<time_first> and C<time_last> fields.
|
|||||||
|
|
||||||
=item *
|
=item *
|
||||||
|
|
||||||
A JOIN is performed on the OUI table and the OUI C<company> column prefetched.
|
A JOIN is performed on the Manufacturer table and the Manufacturer C<company> column prefetched.
|
||||||
|
|
||||||
=back
|
=back
|
||||||
|
|
||||||
@@ -183,7 +183,7 @@ sub search_by_dns {
|
|||||||
|
|
||||||
delete $cond->{suffix};
|
delete $cond->{suffix};
|
||||||
return $rs
|
return $rs
|
||||||
->search_rs({}, $order_by_time_last_and_join_oui)
|
->search_rs({}, $order_by_time_last_and_join_manufacturer)
|
||||||
->search($cond, $attrs);
|
->search($cond, $attrs);
|
||||||
}
|
}
|
||||||
|
|
||||||
@@ -212,7 +212,7 @@ preformatted timestamps of the C<time_first> and C<time_last> fields.
|
|||||||
|
|
||||||
=item *
|
=item *
|
||||||
|
|
||||||
A JOIN is performed on the OUI table and the OUI C<company> column prefetched.
|
A JOIN is performed on the Manufacturer table and the Manufacturer C<company> column prefetched.
|
||||||
|
|
||||||
=back
|
=back
|
||||||
|
|
||||||
@@ -227,7 +227,7 @@ sub search_by_mac {
|
|||||||
if ref {} ne ref $cond or !exists $cond->{mac};
|
if ref {} ne ref $cond or !exists $cond->{mac};
|
||||||
|
|
||||||
return $rs
|
return $rs
|
||||||
->search_rs({}, $order_by_time_last_and_join_oui)
|
->search_rs({}, $order_by_time_last_and_join_manufacturer)
|
||||||
->search($cond, $attrs);
|
->search($cond, $attrs);
|
||||||
}
|
}
|
||||||
|
|
||||||
|
|||||||
@@ -11,11 +11,11 @@ __PACKAGE__->load_components(qw/
|
|||||||
my $search_attr = {
|
my $search_attr = {
|
||||||
order_by => {'-desc' => 'time_last'},
|
order_by => {'-desc' => 'time_last'},
|
||||||
'+columns' => [
|
'+columns' => [
|
||||||
'oui.company',
|
'manufacturer.company',
|
||||||
{ time_first_stamp => \"to_char(time_first, 'YYYY-MM-DD HH24:MI')" },
|
{ time_first_stamp => \"to_char(time_first, 'YYYY-MM-DD HH24:MI')" },
|
||||||
{ time_last_stamp => \"to_char(time_last, 'YYYY-MM-DD HH24:MI')" },
|
{ time_last_stamp => \"to_char(time_last, 'YYYY-MM-DD HH24:MI')" },
|
||||||
],
|
],
|
||||||
join => 'oui'
|
join => 'manufacturer'
|
||||||
};
|
};
|
||||||
|
|
||||||
=head1 with_times
|
=head1 with_times
|
||||||
@@ -68,7 +68,7 @@ preformatted timestamps of the C<time_first> and C<time_last> fields.
|
|||||||
|
|
||||||
=item *
|
=item *
|
||||||
|
|
||||||
A JOIN is performed on the OUI table and the OUI C<company> column prefetched.
|
A JOIN is performed on the Manufacturer table and the Manufacturer C<company> column prefetched.
|
||||||
|
|
||||||
=back
|
=back
|
||||||
|
|
||||||
@@ -121,7 +121,7 @@ preformatted timestamps of the C<time_first> and C<time_last> fields.
|
|||||||
|
|
||||||
=item *
|
=item *
|
||||||
|
|
||||||
A JOIN is performed on the OUI table and the OUI C<company> column prefetched.
|
A JOIN is performed on the Manufacturer table and the Manufacturer C<company> column prefetched.
|
||||||
|
|
||||||
=back
|
=back
|
||||||
|
|
||||||
@@ -167,7 +167,7 @@ preformatted timestamps of the C<time_first> and C<time_last> fields.
|
|||||||
|
|
||||||
=item *
|
=item *
|
||||||
|
|
||||||
A JOIN is performed on the OUI table and the OUI C<company> column prefetched.
|
A JOIN is performed on the Manufacturer table and the Manufacturer C<company> column prefetched.
|
||||||
|
|
||||||
=back
|
=back
|
||||||
|
|
||||||
|
|||||||
@@ -174,7 +174,7 @@ get '/ajax/content/device/ports' => require_login sub {
|
|||||||
if param('n_netbios');
|
if param('n_netbios');
|
||||||
|
|
||||||
# retrieve vendor, if asked for
|
# retrieve vendor, if asked for
|
||||||
$set = $set->search({}, { prefetch => [{$nodes_name => 'oui'}] })
|
$set = $set->search({}, { prefetch => [{$nodes_name => 'manufacturer'}] })
|
||||||
if param('n_vendor');
|
if param('n_vendor');
|
||||||
}
|
}
|
||||||
|
|
||||||
|
|||||||
@@ -88,11 +88,11 @@ get '/ajax/content/report/ipinventory' => require_login sub {
|
|||||||
|
|
||||||
my $rs2 = schema(vars->{'tenant'})->resultset('NodeIp')->search(
|
my $rs2 = schema(vars->{'tenant'})->resultset('NodeIp')->search(
|
||||||
undef,
|
undef,
|
||||||
{ join => ['oui', 'netbios'],
|
{ join => ['manufacturer', 'netbios'],
|
||||||
columns => [qw( ip mac time_first time_last dns active)],
|
columns => [qw( ip mac time_first time_last dns active)],
|
||||||
'+select' => [ \'true AS node',
|
'+select' => [ \'true AS node',
|
||||||
\qq/replace( date_trunc( 'minute', age( LOCALTIMESTAMP, me.time_last ) ) ::text, 'mon', 'month') AS age/,
|
\qq/replace( date_trunc( 'minute', age( LOCALTIMESTAMP, me.time_last ) ) ::text, 'mon', 'month') AS age/,
|
||||||
'oui.company',
|
'manufacturer.company',
|
||||||
'netbios.nbname',
|
'netbios.nbname',
|
||||||
],
|
],
|
||||||
'+as' => [ 'node', 'age', 'vendor', 'nbname' ],
|
'+as' => [ 'node', 'age', 'vendor', 'nbname' ],
|
||||||
@@ -101,14 +101,14 @@ get '/ajax/content/report/ipinventory' => require_login sub {
|
|||||||
|
|
||||||
my $rs3 = schema(vars->{'tenant'})->resultset('NodeNbt')->search(
|
my $rs3 = schema(vars->{'tenant'})->resultset('NodeNbt')->search(
|
||||||
undef,
|
undef,
|
||||||
{ join => ['oui'],
|
{ join => ['manufacturer'],
|
||||||
columns => [qw( ip mac time_first time_last )],
|
columns => [qw( ip mac time_first time_last )],
|
||||||
'+select' => [
|
'+select' => [
|
||||||
\'null AS dns',
|
\'null AS dns',
|
||||||
'active',
|
'active',
|
||||||
\'true AS node',
|
\'true AS node',
|
||||||
\qq/replace( date_trunc( 'minute', age( LOCALTIMESTAMP, time_last ) ) ::text, 'mon', 'month') AS age/,
|
\qq/replace( date_trunc( 'minute', age( LOCALTIMESTAMP, time_last ) ) ::text, 'mon', 'month') AS age/,
|
||||||
'oui.company',
|
'manufacturer.company',
|
||||||
'nbname'
|
'nbname'
|
||||||
],
|
],
|
||||||
'+as' => [ 'dns', 'active', 'node', 'age', 'vendor', 'nbname' ],
|
'+as' => [ 'dns', 'active', 'node', 'age', 'vendor', 'nbname' ],
|
||||||
|
|||||||
@@ -19,15 +19,15 @@ get '/ajax/content/report/nodemultiips' => require_login sub {
|
|||||||
my @results = schema(vars->{'tenant'})->resultset('Node')->search(
|
my @results = schema(vars->{'tenant'})->resultset('Node')->search(
|
||||||
{},
|
{},
|
||||||
{ select => [ 'mac', 'switch', 'port' ],
|
{ select => [ 'mac', 'switch', 'port' ],
|
||||||
join => [qw/device ips oui/],
|
join => [qw/device ips manufacturer/],
|
||||||
'+columns' => [
|
'+columns' => [
|
||||||
{ 'dns' => 'device.dns' },
|
{ 'dns' => 'device.dns' },
|
||||||
{ 'name' => 'device.name' },
|
{ 'name' => 'device.name' },
|
||||||
{ 'ip_count' => { count => 'ips.ip' } },
|
{ 'ip_count' => { count => 'ips.ip' } },
|
||||||
{ 'vendor' => 'oui.company' }
|
{ 'vendor' => 'manufacturer.company' }
|
||||||
],
|
],
|
||||||
group_by => [
|
group_by => [
|
||||||
qw/ me.mac me.switch me.port device.dns device.name oui.company/
|
qw/ me.mac me.switch me.port device.dns device.name manufacturer.company/
|
||||||
],
|
],
|
||||||
having => \[ 'count(ips.ip) > ?', [ count => 1 ] ],
|
having => \[ 'count(ips.ip) > ?', [ count => 1 ] ],
|
||||||
order_by => { -desc => [qw/count/] },
|
order_by => { -desc => [qw/count/] },
|
||||||
|
|||||||
@@ -46,9 +46,9 @@ get '/ajax/content/report/nodevendor/data' => require_login sub {
|
|||||||
|
|
||||||
my $match = $vendor eq 'blank' ? undef : $vendor;
|
my $match = $vendor eq 'blank' ? undef : $vendor;
|
||||||
|
|
||||||
$rs = $rs->search( { 'oui.abbrev' => $match },
|
$rs = $rs->search( { 'manufacturer.abbrev' => $match },
|
||||||
{ '+columns' => [qw/ device.dns device.name oui.abbrev oui.company /],
|
{ '+columns' => [qw/ device.dns device.name manufacturer.abbrev manufacturer.company /],
|
||||||
join => [qw/ oui device /],
|
join => [qw/ manufacturer device /],
|
||||||
collapse => 1,
|
collapse => 1,
|
||||||
});
|
});
|
||||||
|
|
||||||
@@ -85,9 +85,9 @@ get '/ajax/content/report/nodevendor' => require_login sub {
|
|||||||
|
|
||||||
my $match = $vendor eq 'blank' ? undef : $vendor;
|
my $match = $vendor eq 'blank' ? undef : $vendor;
|
||||||
|
|
||||||
$rs = $rs->search( { 'oui.abbrev' => $match },
|
$rs = $rs->search( { 'manufacturer.abbrev' => $match },
|
||||||
{ '+columns' => [qw/ device.dns device.name oui.abbrev oui.company /],
|
{ '+columns' => [qw/ device.dns device.name manufacturer.abbrev manufacturer.company /],
|
||||||
join => [qw/ oui device /],
|
join => [qw/ manufacturer device /],
|
||||||
collapse => 1,
|
collapse => 1,
|
||||||
});
|
});
|
||||||
|
|
||||||
@@ -101,10 +101,10 @@ get '/ajax/content/report/nodevendor' => require_login sub {
|
|||||||
elsif ( !defined $vendor ) {
|
elsif ( !defined $vendor ) {
|
||||||
$rs = $rs->search(
|
$rs = $rs->search(
|
||||||
{ },
|
{ },
|
||||||
{ join => 'oui',
|
{ join => 'manufacturer',
|
||||||
select => [ 'oui.abbrev', 'oui.company', { count => {distinct => 'me.mac'}} ],
|
select => [ 'manufacturer.abbrev', 'manufacturer.company', { count => {distinct => 'me.mac'}} ],
|
||||||
as => [qw/ abbrev vendor count /],
|
as => [qw/ abbrev vendor count /],
|
||||||
group_by => [qw/ oui.abbrev oui.company /]
|
group_by => [qw/ manufacturer.abbrev manufacturer.company /]
|
||||||
}
|
}
|
||||||
)->order_by( { -desc => 'count' } );
|
)->order_by( { -desc => 'count' } );
|
||||||
|
|
||||||
|
|||||||
@@ -148,36 +148,36 @@ get '/ajax/content/search/node' => require_login sub {
|
|||||||
->search({-and => [@where_mac, @active, @times]}, {
|
->search({-and => [@where_mac, @active, @times]}, {
|
||||||
order_by => {'-desc' => 'time_last'},
|
order_by => {'-desc' => 'time_last'},
|
||||||
'+columns' => [
|
'+columns' => [
|
||||||
'oui.company',
|
'manufacturer.company',
|
||||||
'oui.abbrev',
|
'manufacturer.abbrev',
|
||||||
{ time_first_stamp => \"to_char(time_first, 'YYYY-MM-DD HH24:MI')" },
|
{ time_first_stamp => \"to_char(time_first, 'YYYY-MM-DD HH24:MI')" },
|
||||||
{ time_last_stamp => \"to_char(time_last, 'YYYY-MM-DD HH24:MI')" },
|
{ time_last_stamp => \"to_char(time_last, 'YYYY-MM-DD HH24:MI')" },
|
||||||
],
|
],
|
||||||
join => 'oui'
|
join => 'manufacturer'
|
||||||
});
|
});
|
||||||
|
|
||||||
my $netbios = schema(vars->{'tenant'})->resultset('NodeNbt')
|
my $netbios = schema(vars->{'tenant'})->resultset('NodeNbt')
|
||||||
->search({-and => [@where_mac, @active, @times]}, {
|
->search({-and => [@where_mac, @active, @times]}, {
|
||||||
order_by => {'-desc' => 'time_last'},
|
order_by => {'-desc' => 'time_last'},
|
||||||
'+columns' => [
|
'+columns' => [
|
||||||
'oui.company',
|
'manufacturer.company',
|
||||||
'oui.abbrev',
|
'manufacturer.abbrev',
|
||||||
{ time_first_stamp => \"to_char(time_first, 'YYYY-MM-DD HH24:MI')" },
|
{ time_first_stamp => \"to_char(time_first, 'YYYY-MM-DD HH24:MI')" },
|
||||||
{ time_last_stamp => \"to_char(time_last, 'YYYY-MM-DD HH24:MI')" },
|
{ time_last_stamp => \"to_char(time_last, 'YYYY-MM-DD HH24:MI')" },
|
||||||
],
|
],
|
||||||
join => 'oui'
|
join => 'manufacturer'
|
||||||
});
|
});
|
||||||
|
|
||||||
my $wireless = schema(vars->{'tenant'})->resultset('NodeWireless')->search(
|
my $wireless = schema(vars->{'tenant'})->resultset('NodeWireless')->search(
|
||||||
{ -and => [@where_mac, @wifitimes] },
|
{ -and => [@where_mac, @wifitimes] },
|
||||||
{ order_by => { '-desc' => 'time_last' },
|
{ order_by => { '-desc' => 'time_last' },
|
||||||
'+columns' => [
|
'+columns' => [
|
||||||
'oui.company',
|
'manufacturer.company',
|
||||||
'oui.abbrev',
|
'manufacturer.abbrev',
|
||||||
{
|
{
|
||||||
time_last_stamp => \"to_char(time_last, 'YYYY-MM-DD HH24:MI')"
|
time_last_stamp => \"to_char(time_last, 'YYYY-MM-DD HH24:MI')"
|
||||||
}],
|
}],
|
||||||
join => 'oui'
|
join => 'manufacturer'
|
||||||
}
|
}
|
||||||
);
|
);
|
||||||
|
|
||||||
@@ -245,14 +245,14 @@ get '/ajax/content/search/node' => require_login sub {
|
|||||||
}
|
}
|
||||||
|
|
||||||
# if the user selects Vendor search opt, then
|
# if the user selects Vendor search opt, then
|
||||||
# we'll try the OUI company name as a fallback
|
# we'll try the manufacturer company name as a fallback
|
||||||
|
|
||||||
if (param('show_vendor') and not $have_rows) {
|
if (param('show_vendor') and not $have_rows) {
|
||||||
$set = schema(vars->{'tenant'})->resultset('NodeIp')
|
$set = schema(vars->{'tenant'})->resultset('NodeIp')
|
||||||
->with_times
|
->with_times
|
||||||
->search(
|
->search(
|
||||||
{'oui.company' => { -ilike => ''.sql_match($node)}, @times},
|
{'manufacturer.company' => { -ilike => ''.sql_match($node)}, @times},
|
||||||
{'prefetch' => 'oui'},
|
{'prefetch' => 'manufacturer'},
|
||||||
);
|
);
|
||||||
++$have_rows if $set->has_rows;
|
++$have_rows if $set->has_rows;
|
||||||
}
|
}
|
||||||
|
|||||||
@@ -30,10 +30,10 @@ get '/report/*' => require_login sub {
|
|||||||
$vendor_list = [
|
$vendor_list = [
|
||||||
schema(vars->{'tenant'})->resultset('Node')->search(
|
schema(vars->{'tenant'})->resultset('Node')->search(
|
||||||
{},
|
{},
|
||||||
{ join => 'oui',
|
{ join => 'manufacturer',
|
||||||
columns => ['oui.abbrev'],
|
columns => ['manufacturer.abbrev'],
|
||||||
order_by => 'oui.abbrev',
|
order_by => 'manufacturer.abbrev',
|
||||||
group_by => 'oui.abbrev',
|
group_by => 'manufacturer.abbrev',
|
||||||
}
|
}
|
||||||
)->get_column('abbrev')->all
|
)->get_column('abbrev')->all
|
||||||
];
|
];
|
||||||
|
|||||||
@@ -235,6 +235,13 @@ sub store_node {
|
|||||||
$now ||= 'LOCALTIMESTAMP';
|
$now ||= 'LOCALTIMESTAMP';
|
||||||
$vlan ||= 0;
|
$vlan ||= 0;
|
||||||
|
|
||||||
|
# ideally we just store the first 36 bits of the mac in the oui field
|
||||||
|
# and then no need for this query. haven't yet worked out the SQL for that.
|
||||||
|
my $oui = schema('netdisco')->resultset('Manufacturer')
|
||||||
|
->search({ range => { '@>' =>
|
||||||
|
\[q{('x' || lpad( translate( ? ::text, ':', ''), 16, '0')) ::bit(64) ::bigint}, $mac]} },
|
||||||
|
{ rows => 1, columns => 'base' })->first;
|
||||||
|
|
||||||
schema('netdisco')->txn_do(sub {
|
schema('netdisco')->txn_do(sub {
|
||||||
my $nodes = schema('netdisco')->resultset('Node');
|
my $nodes = schema('netdisco')->resultset('Node');
|
||||||
|
|
||||||
@@ -257,7 +264,7 @@ sub store_node {
|
|||||||
vlan => $vlan,
|
vlan => $vlan,
|
||||||
mac => $mac,
|
mac => $mac,
|
||||||
active => \'true',
|
active => \'true',
|
||||||
oui => substr($mac,0,8),
|
oui => ($oui ? $oui->base : undef),
|
||||||
time_last => \$now,
|
time_last => \$now,
|
||||||
(($old != 0) ? (time_recent => \$now) : ()),
|
(($old != 0) ? (time_recent => \$now) : ()),
|
||||||
},
|
},
|
||||||
|
|||||||
21
share/schema_versions/App-Netdisco-DB-84-85-PostgreSQL.sql
Normal file
21
share/schema_versions/App-Netdisco-DB-84-85-PostgreSQL.sql
Normal file
@@ -0,0 +1,21 @@
|
|||||||
|
BEGIN;
|
||||||
|
|
||||||
|
UPDATE node SET oui = NULL;
|
||||||
|
|
||||||
|
ALTER TABLE node ALTER COLUMN oui TYPE varchar(9);
|
||||||
|
|
||||||
|
CREATE TABLE manufacturer (
|
||||||
|
"company" text NOT NULL,
|
||||||
|
"abbrev" text NOT NULL,
|
||||||
|
"base" text NOT NULL,
|
||||||
|
"bits" integer NOT NULL,
|
||||||
|
"first" macaddr NOT NULL,
|
||||||
|
"last" macaddr NOT NULL,
|
||||||
|
"range" int8range NOT NULL,
|
||||||
|
PRIMARY KEY ("base"),
|
||||||
|
EXCLUDE USING GIST (range WITH &&)
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE INDEX idx_manufacturer_first_last ON manufacturer ("first", "last" DESC);
|
||||||
|
|
||||||
|
COMMIT;
|
||||||
@@ -406,10 +406,10 @@
|
|||||||
[% END %]
|
[% END %]
|
||||||
)
|
)
|
||||||
[% END %]
|
[% END %]
|
||||||
[% IF params.n_vendor AND node.oui.defined %]
|
[% IF params.n_vendor AND node.manufacturer.defined %]
|
||||||
(Vendor:
|
(Vendor:
|
||||||
[% FOREACH oui IN node.oui %]
|
[% FOREACH manufacturer IN node.manufacturer %]
|
||||||
<a href="[%+ uri_for('/report/nodevendor') %]?vendor=[% oui.abbrev | uri %]">[% oui.abbrev | html_entity %]</a>
|
<a href="[%+ uri_for('/report/nodevendor') %]?vendor=[% manufacturer.abbrev | uri %]">[% manufacturer.abbrev | html_entity %]</a>
|
||||||
[% END %]
|
[% END %]
|
||||||
)
|
)
|
||||||
[% END %]
|
[% END %]
|
||||||
|
|||||||
@@ -40,9 +40,9 @@ $(document).ready(function() {
|
|||||||
return '<a href="[% search_node | none %]&q=' + encodeURIComponent(data) + '">' + he.encode(data.toUpperCase()) + icon + '</a>';
|
return '<a href="[% search_node | none %]&q=' + encodeURIComponent(data) + '">' + he.encode(data.toUpperCase()) + icon + '</a>';
|
||||||
}
|
}
|
||||||
}, {
|
}, {
|
||||||
"data": 'oui.abbrev',
|
"data": 'manufacturer.abbrev',
|
||||||
"render": function(data, type, row, meta) {
|
"render": function(data, type, row, meta) {
|
||||||
return '<a href="[% uri_for('/report/nodevendor') | none %]?vendor=' + encodeURIComponent(row.oui.abbrev || 'blank') + '">' + he.encode(row.oui.company ||'(Unknown Vendor)') + '</a>';
|
return '<a href="[% uri_for('/report/nodevendor') | none %]?vendor=' + encodeURIComponent(row.manufacturer.abbrev || 'blank') + '">' + he.encode(row.manufacturer.company ||'(Unknown Vendor)') + '</a>';
|
||||||
}
|
}
|
||||||
}, {
|
}, {
|
||||||
"data": 'switch',
|
"data": 'switch',
|
||||||
|
|||||||
@@ -5,7 +5,7 @@
|
|||||||
[% FOREACH row IN results %]
|
[% FOREACH row IN results %]
|
||||||
[% mylist = [] %]
|
[% mylist = [] %]
|
||||||
[% device = row.device.dns || row.device.name || row.switch %]
|
[% device = row.device.dns || row.device.name || row.switch %]
|
||||||
[% FOREACH col IN [ row.mac.upper row.oui.company device row.port ] %]
|
[% FOREACH col IN [ row.mac.upper row.manufacturer.company device row.port ] %]
|
||||||
[% mylist.push(col) %]
|
[% mylist.push(col) %]
|
||||||
[% END %]
|
[% END %]
|
||||||
[% CSV.dump(mylist) %]
|
[% CSV.dump(mylist) %]
|
||||||
|
|||||||
@@ -20,8 +20,8 @@
|
|||||||
<td>MAC <a href="[% search_node | none %]&q=[% row.net_mac.$mac_format_call | uri %]">
|
<td>MAC <a href="[% search_node | none %]&q=[% row.net_mac.$mac_format_call | uri %]">
|
||||||
[% row.net_mac.$mac_format_call | html_entity %]</a>
|
[% row.net_mac.$mac_format_call | html_entity %]</a>
|
||||||
[% IF params.show_vendor %]
|
[% IF params.show_vendor %]
|
||||||
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% row.oui.abbrev | uri %]">
|
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% row.manufacturer.abbrev | uri %]">
|
||||||
[% row.oui.company | html_entity %]</a> )
|
[% row.manufacturer.company | html_entity %]</a> )
|
||||||
[% END %]
|
[% END %]
|
||||||
seen as:
|
seen as:
|
||||||
[% INCLUDE external_mac_links item = row %]
|
[% INCLUDE external_mac_links item = row %]
|
||||||
@@ -40,8 +40,8 @@
|
|||||||
<td>MAC <a href="[% search_node | none %]&q=[% row.net_mac.$mac_format_call | uri %]">
|
<td>MAC <a href="[% search_node | none %]&q=[% row.net_mac.$mac_format_call | uri %]">
|
||||||
[% row.net_mac.$mac_format_call | html_entity %]</a>
|
[% row.net_mac.$mac_format_call | html_entity %]</a>
|
||||||
[% IF params.show_vendor %]
|
[% IF params.show_vendor %]
|
||||||
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% row.oui.abbrev | uri %]">
|
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% row.manufacturer.abbrev | uri %]">
|
||||||
[% row.oui.company | html_entity %]</a> )
|
[% row.manufacturer.company | html_entity %]</a> )
|
||||||
[% END %]
|
[% END %]
|
||||||
seen as:
|
seen as:
|
||||||
[% INCLUDE external_mac_links item = row %]
|
[% INCLUDE external_mac_links item = row %]
|
||||||
@@ -63,8 +63,8 @@
|
|||||||
<td>MAC <a href="[% search_node | none %]&q=[% nbt.net_mac.$mac_format_call | uri %]">
|
<td>MAC <a href="[% search_node | none %]&q=[% nbt.net_mac.$mac_format_call | uri %]">
|
||||||
[% nbt.net_mac.$mac_format_call | html_entity %]</a>
|
[% nbt.net_mac.$mac_format_call | html_entity %]</a>
|
||||||
[% IF params.show_vendor %]
|
[% IF params.show_vendor %]
|
||||||
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% nbt.oui.abbrev | uri %]">
|
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% nbt.manufacturer.abbrev | uri %]">
|
||||||
[% nbt.oui.company | html_entity %]</a> )
|
[% nbt.manufacturer.company | html_entity %]</a> )
|
||||||
[% END %]
|
[% END %]
|
||||||
seen as:
|
seen as:
|
||||||
[% INCLUDE external_mac_links item = nbt %]
|
[% INCLUDE external_mac_links item = nbt %]
|
||||||
@@ -84,8 +84,8 @@
|
|||||||
<td>MAC <a href="[% search_node | none %]&q=[% ni.net_mac.$mac_format_call | uri %]">
|
<td>MAC <a href="[% search_node | none %]&q=[% ni.net_mac.$mac_format_call | uri %]">
|
||||||
[% ni.net_mac.$mac_format_call | html_entity %]</a>
|
[% ni.net_mac.$mac_format_call | html_entity %]</a>
|
||||||
[% IF params.show_vendor %]
|
[% IF params.show_vendor %]
|
||||||
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% ni.oui.abbrev | uri %]">
|
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% ni.manufacturer.abbrev | uri %]">
|
||||||
[% ni.oui.company | html_entity %]</a> )
|
[% ni.manufacturer.company | html_entity %]</a> )
|
||||||
[% END %]
|
[% END %]
|
||||||
seen as:
|
seen as:
|
||||||
[% INCLUDE external_mac_links item = ni %]
|
[% INCLUDE external_mac_links item = ni %]
|
||||||
@@ -107,8 +107,8 @@
|
|||||||
<td>MAC <a href="[% search_node | none %]&q=[% node.net_mac.$mac_format_call | uri %]">
|
<td>MAC <a href="[% search_node | none %]&q=[% node.net_mac.$mac_format_call | uri %]">
|
||||||
[% node.net_mac.$mac_format_call | html_entity %]</a>
|
[% node.net_mac.$mac_format_call | html_entity %]</a>
|
||||||
[% IF params.show_vendor %]
|
[% IF params.show_vendor %]
|
||||||
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% node.oui.abbrev | uri %]">
|
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% node.manufacturer.abbrev | uri %]">
|
||||||
[% node.oui.company | html_entity %]</a> )
|
[% node.manufacturer.company | html_entity %]</a> )
|
||||||
[% END %]
|
[% END %]
|
||||||
seen as:
|
seen as:
|
||||||
[% INCLUDE external_mac_links item = node %]
|
[% INCLUDE external_mac_links item = node %]
|
||||||
@@ -131,8 +131,8 @@
|
|||||||
<td>MAC <a href="[% search_node | none %]&q=[% wlan.net_mac.$mac_format_call | uri %]">
|
<td>MAC <a href="[% search_node | none %]&q=[% wlan.net_mac.$mac_format_call | uri %]">
|
||||||
[% wlan.net_mac.$mac_format_call | html_entity %]</a>
|
[% wlan.net_mac.$mac_format_call | html_entity %]</a>
|
||||||
[% IF params.show_vendor %]
|
[% IF params.show_vendor %]
|
||||||
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% wlan.oui.abbrev | uri %]">
|
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% wlan.manufacturer.abbrev | uri %]">
|
||||||
[% wlan.oui.company | html_entity %]</a> )
|
[% wlan.manufacturer.company | html_entity %]</a> )
|
||||||
[% END %]
|
[% END %]
|
||||||
seen as:
|
seen as:
|
||||||
[% INCLUDE external_mac_links item = wlan %]
|
[% INCLUDE external_mac_links item = wlan %]
|
||||||
@@ -156,8 +156,8 @@
|
|||||||
<td>MAC <a href="[% search_node | none %]&q=[% nodeip.net_mac.$mac_format_call | uri %]">
|
<td>MAC <a href="[% search_node | none %]&q=[% nodeip.net_mac.$mac_format_call | uri %]">
|
||||||
[% nodeip.net_mac.$mac_format_call | html_entity %]</a>
|
[% nodeip.net_mac.$mac_format_call | html_entity %]</a>
|
||||||
[% IF params.show_vendor %]
|
[% IF params.show_vendor %]
|
||||||
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% nodeip.oui.abbrev | uri %]">
|
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% nodeip.manufacturer.abbrev | uri %]">
|
||||||
[% nodeip.oui.company | html_entity %]</a> )
|
[% nodeip.manufacturer.company | html_entity %]</a> )
|
||||||
[% END %]
|
[% END %]
|
||||||
seen as:
|
seen as:
|
||||||
[% INCLUDE external_mac_links item = nodeip %]
|
[% INCLUDE external_mac_links item = nodeip %]
|
||||||
|
|||||||
@@ -19,8 +19,8 @@
|
|||||||
MAC <a href="[% search_node | none %]&q=[% row.net_mac.$mac_format_call | uri %]">
|
MAC <a href="[% search_node | none %]&q=[% row.net_mac.$mac_format_call | uri %]">
|
||||||
[% row.net_mac.$mac_format_call | html_entity %]</a>
|
[% row.net_mac.$mac_format_call | html_entity %]</a>
|
||||||
[% IF params.show_vendor %]
|
[% IF params.show_vendor %]
|
||||||
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% row.oui.abbrev | uri %]">
|
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% row.manufacturer.abbrev | uri %]">
|
||||||
[% row.oui.company | html_entity %]</a> )
|
[% row.manufacturer.company | html_entity %]</a> )
|
||||||
[% END %]
|
[% END %]
|
||||||
seen as:
|
seen as:
|
||||||
[% INCLUDE external_mac_links item = row %]
|
[% INCLUDE external_mac_links item = row %]
|
||||||
@@ -45,8 +45,8 @@
|
|||||||
MAC <a href="[% search_node | none %]&q=[% node.net_mac.$mac_format_call | uri %]">
|
MAC <a href="[% search_node | none %]&q=[% node.net_mac.$mac_format_call | uri %]">
|
||||||
[% node.net_mac.$mac_format_call | html_entity %]</a>
|
[% node.net_mac.$mac_format_call | html_entity %]</a>
|
||||||
[% IF params.show_vendor %]
|
[% IF params.show_vendor %]
|
||||||
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% node.oui.abbrev | uri %]">
|
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% node.manufacturer.abbrev | uri %]">
|
||||||
[% node.oui.company | html_entity %]</a> )
|
[% node.manufacturer.company | html_entity %]</a> )
|
||||||
[% END %]
|
[% END %]
|
||||||
seen as:
|
seen as:
|
||||||
[% INCLUDE external_mac_links item = node %]
|
[% INCLUDE external_mac_links item = node %]
|
||||||
@@ -72,8 +72,8 @@
|
|||||||
<td>
|
<td>
|
||||||
MAC <a href="[% search_node | none %]&q=[% port.net_mac.$mac_format_call | uri %]">[% port.net_mac.$mac_format_call | html_entity %]</a>
|
MAC <a href="[% search_node | none %]&q=[% port.net_mac.$mac_format_call | uri %]">[% port.net_mac.$mac_format_call | html_entity %]</a>
|
||||||
[% IF params.show_vendor %]
|
[% IF params.show_vendor %]
|
||||||
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% port.oui.abbrev | uri %]">
|
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% port.manufacturer.abbrev | uri %]">
|
||||||
[% port.oui.company | html_entity %]</a> )
|
[% port.manufacturer.company | html_entity %]</a> )
|
||||||
[% END %]
|
[% END %]
|
||||||
seen as:
|
seen as:
|
||||||
[% INCLUDE external_mac_links item = port %]
|
[% INCLUDE external_mac_links item = port %]
|
||||||
@@ -95,8 +95,8 @@
|
|||||||
<td>
|
<td>
|
||||||
MAC <a href="[% search_node | none %]&q=[% nbt.net_mac.$mac_format_call | uri %]">[% nbt.net_mac.$mac_format_call | html_entity %]</a>
|
MAC <a href="[% search_node | none %]&q=[% nbt.net_mac.$mac_format_call | uri %]">[% nbt.net_mac.$mac_format_call | html_entity %]</a>
|
||||||
[% IF params.show_vendor %]
|
[% IF params.show_vendor %]
|
||||||
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% nbt.oui.abbrev | uri %]">
|
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% nbt.manufacturer.abbrev | uri %]">
|
||||||
[% nbt.oui.company | html_entity %]</a> )
|
[% nbt.manufacturer.company | html_entity %]</a> )
|
||||||
[% END %]
|
[% END %]
|
||||||
seen as:
|
seen as:
|
||||||
[% INCLUDE external_mac_links item = nbt %]
|
[% INCLUDE external_mac_links item = nbt %]
|
||||||
@@ -116,8 +116,8 @@
|
|||||||
<td>
|
<td>
|
||||||
MAC <a href="[% search_node | none %]&q=[% wlan.net_mac.$mac_format_call | uri %]">[% wlan.net_mac.$mac_format_call | html_entity %]</a>
|
MAC <a href="[% search_node | none %]&q=[% wlan.net_mac.$mac_format_call | uri %]">[% wlan.net_mac.$mac_format_call | html_entity %]</a>
|
||||||
[% IF params.show_vendor %]
|
[% IF params.show_vendor %]
|
||||||
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% wlan.oui.abbrev | uri %]">
|
( <a href="[% uri_for('/report/nodevendor') | none %]?vendor=[% wlan.manufacturer.abbrev | uri %]">
|
||||||
[% wlan.oui.company | html_entity %]</a> )
|
[% wlan.manufacturer.company | html_entity %]</a> )
|
||||||
[% END %]
|
[% END %]
|
||||||
seen as:
|
seen as:
|
||||||
[% INCLUDE external_mac_links item = wlan %]
|
[% INCLUDE external_mac_links item = wlan %]
|
||||||
|
|||||||
Reference in New Issue
Block a user