Skip to content

Commit

Permalink
fix: search_products function returns the correct values for add options
Browse files Browse the repository at this point in the history
  • Loading branch information
matthieu-foucault committed Jul 20, 2020
1 parent 3eba997 commit e1748d2
Show file tree
Hide file tree
Showing 6 changed files with 136 additions and 4 deletions.
4 changes: 2 additions & 2 deletions schema/deploy/search_functions/search_products.sql
Original file line number Diff line number Diff line change
Expand Up @@ -39,14 +39,14 @@ returns setof ggircs_portal.product as
then return query execute search_query_input_query ||
'select
id, product_name, units,
product_state, requires_emission_allocation, is_ciip_product, requires_product_amount, subtract_exported_electricity_emissions, subtract_exported_electricity_emissions, subtract_exported_heat_emissions, subtract_exported_heat_emissions,
product_state, requires_emission_allocation, is_ciip_product, requires_product_amount, add_purchased_electricity_emissions, subtract_exported_electricity_emissions, add_purchased_heat_emissions, subtract_exported_heat_emissions,
subtract_generated_electricity_emissions, subtract_generated_heat_emissions, add_emissions_from_eios, is_read_only, is_energy_product, created_at, created_by, updated_at, updated_by, deleted_at, deleted_by
from innerTable order by ' || order_by_field || ' ' || direction;
else
return query execute search_query_input_query ||
'select
id, product_name, units, product_state,
requires_emission_allocation, is_ciip_product, requires_product_amount, subtract_exported_electricity_emissions, subtract_exported_electricity_emissions, subtract_exported_heat_emissions, subtract_exported_heat_emissions,
requires_emission_allocation, is_ciip_product, requires_product_amount, add_purchased_electricity_emissions, subtract_exported_electricity_emissions, add_purchased_heat_emissions, subtract_exported_heat_emissions,
subtract_generated_electricity_emissions, subtract_generated_heat_emissions, add_emissions_from_eios, is_read_only, is_energy_product, created_at, created_by, updated_at, updated_by, deleted_at, deleted_by
from innerTable
where
Expand Down
62 changes: 62 additions & 0 deletions schema/deploy/search_functions/search_products@v1.0.0-rc.12.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,62 @@
-- Deploy ggircs-portal:function_search_products to pg
-- requires: table_product

begin;

create or replace function ggircs_portal.search_products(
search_field text,
search_value text,
order_by_field text default 'id',
direction text default 'asc'
)

returns setof ggircs_portal.product as
$function$
declare
search_query_input_query text;
begin

search_query_input_query :='with outerTable as
(
select
p.*,
benchmark,
eligibility_threshold,
incentive_multiplier,
start_reporting_year,
end_reporting_year,
b.created_at as benchmark_created_at
from ggircs_portal.product as p
left join ggircs_portal.benchmark as b
on p.id = b.product_id
),
innerTable as
(
select distinct on (id) * from outerTable order by id, benchmark_created_at desc
)';

if search_field is null or search_value is null
then return query execute search_query_input_query ||
'select
id, product_name, units,
product_state, requires_emission_allocation, is_ciip_product, requires_product_amount, subtract_exported_electricity_emissions, subtract_exported_electricity_emissions, subtract_exported_heat_emissions, subtract_exported_heat_emissions,
subtract_generated_electricity_emissions, subtract_generated_heat_emissions, add_emissions_from_eios, is_read_only, is_energy_product, created_at, created_by, updated_at, updated_by, deleted_at, deleted_by
from innerTable order by ' || order_by_field || ' ' || direction;
else
return query execute search_query_input_query ||
'select
id, product_name, units, product_state,
requires_emission_allocation, is_ciip_product, requires_product_amount, subtract_exported_electricity_emissions, subtract_exported_electricity_emissions, subtract_exported_heat_emissions, subtract_exported_heat_emissions,
subtract_generated_electricity_emissions, subtract_generated_heat_emissions, add_emissions_from_eios, is_read_only, is_energy_product, created_at, created_by, updated_at, updated_by, deleted_at, deleted_by
from innerTable
where
'|| search_field || '::text ilike ''%' || search_value || '%''
order by '|| order_by_field || ' ' || direction;

end if;
end
$function$ language plpgsql stable;

grant execute on function ggircs_portal.search_products to ciip_administrator, ciip_analyst, ciip_industry_user;

commit;
59 changes: 57 additions & 2 deletions schema/revert/search_functions/search_products.sql
Original file line number Diff line number Diff line change
@@ -1,7 +1,62 @@
-- Revert ggircs-portal:function_search_products from pg
-- Deploy ggircs-portal:function_search_products to pg
-- requires: table_product

begin;

drop function ggircs_portal.search_products;
create or replace function ggircs_portal.search_products(
search_field text,
search_value text,
order_by_field text default 'id',
direction text default 'asc'
)

returns setof ggircs_portal.product as
$function$
declare
search_query_input_query text;
begin

search_query_input_query :='with outerTable as
(
select
p.*,
benchmark,
eligibility_threshold,
incentive_multiplier,
start_reporting_year,
end_reporting_year,
b.created_at as benchmark_created_at
from ggircs_portal.product as p
left join ggircs_portal.benchmark as b
on p.id = b.product_id
),
innerTable as
(
select distinct on (id) * from outerTable order by id, benchmark_created_at desc
)';

if search_field is null or search_value is null
then return query execute search_query_input_query ||
'select
id, product_name, units,
product_state, requires_emission_allocation, is_ciip_product, requires_product_amount, subtract_exported_electricity_emissions, subtract_exported_electricity_emissions, subtract_exported_heat_emissions, subtract_exported_heat_emissions,
subtract_generated_electricity_emissions, subtract_generated_heat_emissions, add_emissions_from_eios, is_read_only, is_energy_product, created_at, created_by, updated_at, updated_by, deleted_at, deleted_by
from innerTable order by ' || order_by_field || ' ' || direction;
else
return query execute search_query_input_query ||
'select
id, product_name, units, product_state,
requires_emission_allocation, is_ciip_product, requires_product_amount, subtract_exported_electricity_emissions, subtract_exported_electricity_emissions, subtract_exported_heat_emissions, subtract_exported_heat_emissions,
subtract_generated_electricity_emissions, subtract_generated_heat_emissions, add_emissions_from_eios, is_read_only, is_energy_product, created_at, created_by, updated_at, updated_by, deleted_at, deleted_by
from innerTable
where
'|| search_field || '::text ilike ''%' || search_value || '%''
order by '|| order_by_field || ' ' || direction;

end if;
end
$function$ language plpgsql stable;

grant execute on function ggircs_portal.search_products to ciip_administrator, ciip_analyst, ciip_industry_user;

commit;
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
-- Revert ggircs-portal:function_search_products from pg

begin;

drop function ggircs_portal.search_products;

commit;
1 change: 1 addition & 0 deletions schema/sqitch.plan
Original file line number Diff line number Diff line change
Expand Up @@ -157,3 +157,4 @@ computed_columns/application_revision_ciip_incentive [computed_columns/applicati
@v1.0.0 2020-07-16T00:27:28Z Matthieu Foucault <matthieu@button.is> # release v1.0.0
@v1.0.1 2020-07-16T01:12:49Z Matthieu Foucault <matthieu@button.is> # release v1.0.1
@v1.0.2 2020-07-16T19:48:33Z Matthieu Foucault <matthieu@button.is> # release v1.0.2
search_functions/search_products [search_functions/search_products@v1.0.0-rc.12] 2020-07-20T17:26:50Z Matthieu Foucault <matthieu@button.is> # fix wrong fields being returned by search_product function
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
-- Verify ggircs-portal:function_search_products on pg

begin;

select pg_get_functiondef('ggircs_portal.search_products(text,text,text,text)'::regprocedure);

rollback;

0 comments on commit e1748d2

Please sign in to comment.