From d70a8d329c808b154bd451ef0eaf47d64081c9eb Mon Sep 17 00:00:00 2001 From: Irka Date: Mon, 11 Aug 2014 00:05:46 +0200 Subject: [PATCH] MT#8371 Optimize select actual billing_mappings with virtual view --- .../Schema/Result/billing_mappings_actual.pm | 70 +++++++++++++++++++ lib/NGCP/Schema/Result/contracts.pm | 6 ++ 2 files changed, 76 insertions(+) create mode 100644 lib/NGCP/Schema/Result/billing_mappings_actual.pm diff --git a/lib/NGCP/Schema/Result/billing_mappings_actual.pm b/lib/NGCP/Schema/Result/billing_mappings_actual.pm new file mode 100644 index 00000000..2831e8f0 --- /dev/null +++ b/lib/NGCP/Schema/Result/billing_mappings_actual.pm @@ -0,0 +1,70 @@ +package NGCP::Schema::Result::billing_mappings_actual; +use Scalar::Util qw(blessed); +use base qw/DBIx::Class::Core/; + +our $VERSION = '2.007'; + +__PACKAGE__->load_components( + "InflateColumn::DateTime", + "Helper::Row::ToJSON", + "+NGCP::Schema::InflateColumn::DateTime::EpochMicro", +); +__PACKAGE__->table_class('DBIx::Class::ResultSource::View'); +__PACKAGE__->table("billing_mappings_actual"); + + +__PACKAGE__->add_columns( + "actual_bm_id", + { + data_type => "integer", + extra => { unsigned => 1 }, + is_auto_increment => 1, + is_nullable => 0, + }, + "contract_id", + { + data_type => "integer", + extra => { unsigned => 1 }, + is_foreign_key => 1, + is_nullable => 0, + }, +); +__PACKAGE__->belongs_to( + "contract", + "NGCP::Schema::Result::contracts", + { id => "contract_id" }, + { is_deferrable => 1, on_delete => "CASCADE", on_update => "CASCADE" }, +); + +__PACKAGE__->has_many( + "billing_mappings", + "NGCP::Schema::Result::billing_mappings", + { "foreign.id" => "self.actual_bm_id" }, + { cascade_copy => 0, cascade_delete => 0 }, +); + +__PACKAGE__->set_primary_key("actual_bm_id"); + +sub TO_JSON { + my ($self) = @_; + return { + map { blessed($_) && $_->isa('DateTime') ? $_->datetime : $_ } %{ $self->next::method } + }; +} + +__PACKAGE__->result_source_instance->is_virtual(1); + +__PACKAGE__->result_source_instance->view_definition(" +select bm.contract_id,max(bm.id) as actual_bm_id from billing.billing_mappings bm + inner join + (select bmm.contract_id, max(bmm.start_date) max_start_date + from billing.billing_mappings bmm + where ( bmm.`end_date` >= ? OR bmm.`end_date` IS NULL ) + AND ( bmm.`start_date` <= ? OR bmm.`start_date` IS NULL ) + group by bmm.contract_id + ) bmm on bm.contract_id=bmm.contract_id and (bm.start_date=bmm.max_start_date or bmm.max_start_date is null) +group by bm.contract_id +"); + +1; + diff --git a/lib/NGCP/Schema/Result/contracts.pm b/lib/NGCP/Schema/Result/contracts.pm index 280268f8..b9eb61c0 100644 --- a/lib/NGCP/Schema/Result/contracts.pm +++ b/lib/NGCP/Schema/Result/contracts.pm @@ -119,6 +119,12 @@ __PACKAGE__->has_many( { "foreign.contract_id" => "self.id" }, { cascade_copy => 0, cascade_delete => 0 }, ); +__PACKAGE__->has_many( + "billing_mappings_actual", + "NGCP::Schema::Result::billing_mappings_actual", + { "foreign.contract_id" => "self.id" }, + { cascade_copy => 0, cascade_delete => 0 }, +); __PACKAGE__->belongs_to( "contact",