Add DevicePoeStatus virtual view to support device PoE Status report
Add with_poestats to DevicePower ResultSet to support power report in device detail tab Remove with_poestats_as_hashref from Device ResultSet as DevicePoeStatus view and with_poestats are more efficient
This commit is contained in:
		@@ -0,0 +1,87 @@
 | 
			
		||||
package App::Netdisco::DB::Result::Virtual::DevicePoeStatus;
 | 
			
		||||
 | 
			
		||||
use strict;
 | 
			
		||||
use warnings;
 | 
			
		||||
 | 
			
		||||
use base 'DBIx::Class::Core';
 | 
			
		||||
 | 
			
		||||
__PACKAGE__->table_class('DBIx::Class::ResultSource::View');
 | 
			
		||||
 | 
			
		||||
__PACKAGE__->table('device_poe_status');
 | 
			
		||||
__PACKAGE__->result_source_instance->is_virtual(1);
 | 
			
		||||
__PACKAGE__->result_source_instance->view_definition(<<'ENDSQL');
 | 
			
		||||
SELECT DISTINCT ON (dp.ip,dp.module)
 | 
			
		||||
       dp.ip,
 | 
			
		||||
       dp.module,
 | 
			
		||||
       dp.power::bigint,
 | 
			
		||||
       dp.status,
 | 
			
		||||
       d.dns,
 | 
			
		||||
       d.name,
 | 
			
		||||
       d.model,
 | 
			
		||||
       d.location,
 | 
			
		||||
       COUNT(dpp.port) OVER (PARTITION BY dp.ip, dp.module) AS poe_capable_ports,
 | 
			
		||||
       SUM(CASE WHEN dpp.status = 'deliveringPower' THEN 1 ELSE 0 END) OVER (PARTITION BY dp.ip, dp.module) AS poe_powered_ports,
 | 
			
		||||
       SUM(CASE WHEN dpp.admin = 'false' THEN 1 ELSE 0 END) OVER (PARTITION BY dp.ip, dp.module) AS poe_disabled_ports,
 | 
			
		||||
       SUM(CASE WHEN dpp.status ILIKE '%fault' THEN 1 
 | 
			
		||||
                ELSE 0 END) OVER (PARTITION BY dp.ip, dp.module) AS poe_errored_ports,
 | 
			
		||||
       SUM(CASE WHEN dpp.status = 'deliveringPower' AND dpp.class = 'class4' THEN 30.0 
 | 
			
		||||
                WHEN dpp.status = 'deliveringPower' AND dpp.class = 'class2' THEN 7.0 
 | 
			
		||||
                WHEN dpp.status = 'deliveringPower' AND dpp.class = 'class1' THEN 4.0 
 | 
			
		||||
                WHEN dpp.status = 'deliveringPower' AND dpp.class = 'class3' THEN 15.4
 | 
			
		||||
                WHEN dpp.status = 'deliveringPower' AND dpp.class = 'class0' THEN 15.4
 | 
			
		||||
                WHEN dpp.status = 'deliveringPower' AND dpp.class IS NULL THEN 15.4
 | 
			
		||||
                ELSE 0 END) OVER (PARTITION BY dp.ip, dp.module) AS poe_power_committed,
 | 
			
		||||
       SUM(CASE WHEN (dpp.power IS NULL OR dpp.power = '0') THEN 0
 | 
			
		||||
           ELSE round(dpp.power/1000.0, 1) END) OVER (PARTITION BY dp.ip, dp.module) AS poe_power_delivering
 | 
			
		||||
FROM device_power dp
 | 
			
		||||
JOIN device_port_power dpp ON dpp.ip = dp.ip
 | 
			
		||||
AND dpp.module = dp.module
 | 
			
		||||
JOIN device d ON dp.ip = d.ip
 | 
			
		||||
ENDSQL
 | 
			
		||||
 | 
			
		||||
__PACKAGE__->add_columns(
 | 
			
		||||
  'ip' => {
 | 
			
		||||
    data_type => 'inet',
 | 
			
		||||
  },
 | 
			
		||||
  'module' => {
 | 
			
		||||
    data_type => 'integer',
 | 
			
		||||
  },
 | 
			
		||||
  'power' => {
 | 
			
		||||
    data_type => 'integer',
 | 
			
		||||
  },
 | 
			
		||||
  'status' => {
 | 
			
		||||
    data_type => 'text',
 | 
			
		||||
  },
 | 
			
		||||
  'dns' => {
 | 
			
		||||
    data_type => 'text',
 | 
			
		||||
  },
 | 
			
		||||
  'name' => {
 | 
			
		||||
    data_type => 'text',
 | 
			
		||||
  },
 | 
			
		||||
  'model' => {
 | 
			
		||||
    data_type => 'text',
 | 
			
		||||
  },
 | 
			
		||||
  'location' => {
 | 
			
		||||
    data_type => 'text',
 | 
			
		||||
  },
 | 
			
		||||
  'poe_capable_ports' => {
 | 
			
		||||
    data_type => 'bigint',
 | 
			
		||||
  },
 | 
			
		||||
  'poe_powered_ports' => {
 | 
			
		||||
    data_type => 'bigint',
 | 
			
		||||
  },
 | 
			
		||||
  'poe_disabled_ports' => {
 | 
			
		||||
    data_type => 'bigint',
 | 
			
		||||
  },
 | 
			
		||||
  'poe_errored_ports' => {
 | 
			
		||||
    data_type => 'bigint',
 | 
			
		||||
  },
 | 
			
		||||
  'poe_power_committed' => {
 | 
			
		||||
    data_type => 'numeric',
 | 
			
		||||
  },
 | 
			
		||||
  'poe_power_delivering' => {
 | 
			
		||||
    data_type => 'numeric',
 | 
			
		||||
  },
 | 
			
		||||
);
 | 
			
		||||
 | 
			
		||||
1;
 | 
			
		||||
@@ -610,96 +610,4 @@ sub delete {
 | 
			
		||||
  return $self->next::method();
 | 
			
		||||
}
 | 
			
		||||
 | 
			
		||||
=head2 with_poestats_as_hashref
 | 
			
		||||
 | 
			
		||||
This is a modifier for C<search()> which returns a list of hash references
 | 
			
		||||
with the power_modules hash augmented with the following statistics as keys:
 | 
			
		||||
 | 
			
		||||
=over 4
 | 
			
		||||
 | 
			
		||||
=item capable_ports
 | 
			
		||||
 | 
			
		||||
Count of ports which have the ability to supply PoE.
 | 
			
		||||
 | 
			
		||||
=item disabled_ports
 | 
			
		||||
 | 
			
		||||
Count of ports with PoE administratively disabled.
 | 
			
		||||
 | 
			
		||||
=item powered_ports
 | 
			
		||||
 | 
			
		||||
Count of ports which are delivering power.
 | 
			
		||||
 | 
			
		||||
=item errored_ports
 | 
			
		||||
 | 
			
		||||
Count of ports either reporting a fault or in test mode.
 | 
			
		||||
 | 
			
		||||
=item pwr_committed
 | 
			
		||||
 | 
			
		||||
Total power that has been negotiated and therefore committed on ports
 | 
			
		||||
actively supplying power.
 | 
			
		||||
 | 
			
		||||
=item pwr_delivering
 | 
			
		||||
 | 
			
		||||
Total power as measured on ports actively supplying power.
 | 
			
		||||
 | 
			
		||||
=back
 | 
			
		||||
 | 
			
		||||
=cut
 | 
			
		||||
 | 
			
		||||
sub with_poestats_as_hashref {
 | 
			
		||||
  my ( $rs, $cond, $attrs ) = @_;
 | 
			
		||||
 | 
			
		||||
  my @return = $rs->search(
 | 
			
		||||
    {},
 | 
			
		||||
    { result_class => 'DBIx::Class::ResultClass::HashRefInflator',
 | 
			
		||||
      prefetch     => { power_modules => 'ports' },
 | 
			
		||||
      order_by     => { -asc => [qw/me.ip power_modules.module/] }
 | 
			
		||||
  })->all;
 | 
			
		||||
 | 
			
		||||
  my $poemax = {
 | 
			
		||||
    'class0' => 15.4,
 | 
			
		||||
    'class1' => 4.0,
 | 
			
		||||
    'class2' => 7.0,
 | 
			
		||||
    'class3' => 15.4,
 | 
			
		||||
    'class4' => 30.0
 | 
			
		||||
  };
 | 
			
		||||
 | 
			
		||||
  foreach my $device (@return) {
 | 
			
		||||
    foreach my $module (@{$device->{power_modules}}) {
 | 
			
		||||
      $module->{capable_ports}  = 0;
 | 
			
		||||
      $module->{disabled_ports} = 0;
 | 
			
		||||
      $module->{powered_ports}  = 0;
 | 
			
		||||
      $module->{errored_ports}  = 0;
 | 
			
		||||
      $module->{pwr_committed}  = 0;
 | 
			
		||||
      $module->{pwr_delivering} = 0;
 | 
			
		||||
 | 
			
		||||
      foreach my $port ( @{$module->{ports}} ) {
 | 
			
		||||
        $module->{capable_ports}++;
 | 
			
		||||
 | 
			
		||||
        if ( $port->{admin} eq 'false' ) {
 | 
			
		||||
          $module->{disabled_ports}++;
 | 
			
		||||
        }
 | 
			
		||||
        elsif ( $port->{status} ne 'searching'
 | 
			
		||||
                and $port->{status} ne 'deliveringPower' )
 | 
			
		||||
            {
 | 
			
		||||
              $module->{errored_ports}++;
 | 
			
		||||
            }
 | 
			
		||||
        elsif ( $port->{status} eq 'deliveringPower' ) {
 | 
			
		||||
            # Default is class0
 | 
			
		||||
            my $class = $port->{class} || 'class0';
 | 
			
		||||
            $module->{powered_ports}++;
 | 
			
		||||
            if ( defined $port->{power} and $port->{power} ) {
 | 
			
		||||
              $module->{pwr_delivering} += int( $port->{power} / 1000 );
 | 
			
		||||
               $module->{pwr_committed}  += $poemax->{ $class };
 | 
			
		||||
            }
 | 
			
		||||
            else {
 | 
			
		||||
              $module->{pwr_committed} += $poemax->{ $class };
 | 
			
		||||
            }
 | 
			
		||||
          }
 | 
			
		||||
        }
 | 
			
		||||
      }
 | 
			
		||||
    }
 | 
			
		||||
  return \@return;
 | 
			
		||||
}
 | 
			
		||||
 | 
			
		||||
1;
 | 
			
		||||
 
 | 
			
		||||
							
								
								
									
										78
									
								
								Netdisco/lib/App/Netdisco/DB/ResultSet/DevicePower.pm
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										78
									
								
								Netdisco/lib/App/Netdisco/DB/ResultSet/DevicePower.pm
									
									
									
									
									
										Normal file
									
								
							@@ -0,0 +1,78 @@
 | 
			
		||||
package App::Netdisco::DB::ResultSet::DevicePower;
 | 
			
		||||
use base 'App::Netdisco::DB::ResultSet';
 | 
			
		||||
 | 
			
		||||
use strict;
 | 
			
		||||
use warnings;
 | 
			
		||||
 | 
			
		||||
=head1 ADDITIONAL METHODS
 | 
			
		||||
 | 
			
		||||
 | 
			
		||||
=head2 with_poestats
 | 
			
		||||
 | 
			
		||||
This is a modifier for any C<search()> which will add the following
 | 
			
		||||
additional synthesized columns to the result set:
 | 
			
		||||
 | 
			
		||||
=over 4
 | 
			
		||||
 | 
			
		||||
=item poe_capable_ports
 | 
			
		||||
 | 
			
		||||
Count of ports which have the ability to supply PoE.
 | 
			
		||||
 | 
			
		||||
=item poe_powered_ports
 | 
			
		||||
 | 
			
		||||
Count of ports with PoE administratively disabled.
 | 
			
		||||
 | 
			
		||||
=item poe_disabled_ports
 | 
			
		||||
 | 
			
		||||
Count of ports which are delivering power.
 | 
			
		||||
 | 
			
		||||
=item poe_errored_ports
 | 
			
		||||
 | 
			
		||||
Count of ports either reporting a fault or in test mode.
 | 
			
		||||
 | 
			
		||||
=item poe_power_committed
 | 
			
		||||
 | 
			
		||||
Total power that has been negotiated and therefore committed on ports
 | 
			
		||||
actively supplying power.
 | 
			
		||||
 | 
			
		||||
=item poe_power_delivering
 | 
			
		||||
 | 
			
		||||
Total power as measured on ports actively supplying power.
 | 
			
		||||
 | 
			
		||||
=back
 | 
			
		||||
 | 
			
		||||
=cut
 | 
			
		||||
 | 
			
		||||
sub with_poestats {
 | 
			
		||||
  my ($rs, $cond, $attrs) = @_;
 | 
			
		||||
 | 
			
		||||
  return $rs
 | 
			
		||||
    ->search_rs($cond, $attrs)
 | 
			
		||||
    ->search({},
 | 
			
		||||
      {
 | 
			
		||||
        'columns' => {
 | 
			
		||||
          ip => \"DISTINCT ON (me.ip, me.module) me.ip",
 | 
			
		||||
          module => 'module',
 | 
			
		||||
          power => 'power::bigint',
 | 
			
		||||
          status => 'status',
 | 
			
		||||
          poe_capable_ports => \"COUNT(ports.port) OVER (PARTITION BY me.ip, me.module)",
 | 
			
		||||
          poe_powered_ports => \"SUM(CASE WHEN ports.status = 'deliveringPower' THEN 1 ELSE 0 END) OVER (PARTITION BY me.ip, me.module)",
 | 
			
		||||
          poe_disabled_ports => \"SUM(CASE WHEN ports.admin = 'false' THEN 1 ELSE 0 END) OVER (PARTITION BY me.ip, me.module)",
 | 
			
		||||
          poe_errored_ports => \"SUM(CASE WHEN ports.status ILIKE '%fault' THEN 1 ELSE 0 END) OVER (PARTITION BY me.ip, me.module)",
 | 
			
		||||
          poe_power_committed => \("SUM(CASE "
 | 
			
		||||
                . "WHEN ports.status = 'deliveringPower' AND ports.class = 'class0' THEN 15.4 "
 | 
			
		||||
                . "WHEN ports.status = 'deliveringPower' AND ports.class = 'class1' THEN 4.0 " 
 | 
			
		||||
                . "WHEN ports.status = 'deliveringPower' AND ports.class = 'class2' THEN 7.0 "
 | 
			
		||||
                . "WHEN ports.status = 'deliveringPower' AND ports.class = 'class3' THEN 15.4 "
 | 
			
		||||
                . "WHEN ports.status = 'deliveringPower' AND ports.class = 'class4' THEN 30.0 "
 | 
			
		||||
                . "WHEN ports.status = 'deliveringPower' AND ports.class IS NULL THEN 15.4 "
 | 
			
		||||
                . "ELSE 0 END) OVER (PARTITION BY me.ip, me.module)"),
 | 
			
		||||
          poe_power_delivering => \("SUM(CASE WHEN (ports.power IS NULL OR ports.power = '0') "
 | 
			
		||||
                . "THEN 0 ELSE round(ports.power/1000.0, 1) END) "
 | 
			
		||||
                . "OVER (PARTITION BY me.ip, me.module)")
 | 
			
		||||
        },
 | 
			
		||||
          join => 'ports'
 | 
			
		||||
      });
 | 
			
		||||
}
 | 
			
		||||
 | 
			
		||||
1;
 | 
			
		||||
		Reference in New Issue
	
	Block a user