-
Notifications
You must be signed in to change notification settings - Fork 2
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
chore: add project type and score to tables and computed columns
- Loading branch information
Showing
14 changed files
with
64,455 additions
and
51,157 deletions.
There are no files selected for viewing
Large diffs are not rendered by default.
Oops, something went wrong.
Large diffs are not rendered by default.
Oops, something went wrong.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,41 @@ | ||
-- Deploy cif:computed_columns/form_change_as_project to pg | ||
-- requires: tables/project | ||
-- requires: tables/project_001 | ||
-- requires: tables/form_change | ||
|
||
begin; | ||
|
||
create or replace function cif.form_change_as_project(cif.form_change) | ||
returns cif.project | ||
as $$ | ||
select | ||
/** | ||
Given form_data_record_id can be null for some form_change records, it is not a reliable id value for the returned project_contact record. | ||
The returned id must not be null, so we use the form_change id being passed in as a parameter (multiplied by -1 to ensure we are not touching any existing records). | ||
This means the id value is not going to be the correct id for the returned project_contact record, which should be ok since we're only interested | ||
in the data in new_form_data. | ||
**/ | ||
($1.id * -1) as id, | ||
(new_form_data->>'operatorId')::integer as operator_id, | ||
(new_form_data->>'fundingStreamRfpId')::integer as funding_stream_rfp_id, | ||
(new_form_data->>'projectStatusId')::integer as project_status_id, | ||
(new_form_data->>'proposalReference')::varchar as proposal_reference, | ||
new_form_data->>'summary' as summary, | ||
new_form_data->>'projectName' as project_name, | ||
(new_form_data->>'totalFundingRequest')::numeric as total_funding_request, | ||
(new_form_data->>'sectorName')::varchar as sector_name, | ||
(new_form_data->>'additionalSectorInformation')::varchar as additional_sector_information, | ||
(new_form_data->>'comments')::varchar as comments, | ||
null::int as created_by, | ||
now()::timestamptz created_at, | ||
null::int as updated_by, | ||
now()::timestamptz updated_at, | ||
null::int as archived_by, | ||
null::timestamptz as archived_at | ||
from cif.form_change fc where fc.id = $1.id and fc.form_data_table_name = 'project' | ||
|
||
$$ language sql stable; | ||
|
||
comment on function cif.form_change_as_project(cif.form_change) is 'Computed column returns data from the new_form_data column as if it were a project to allow graph traversal via the foreign keys.'; | ||
|
||
commit; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,10 @@ | ||
-- Deploy cif:tables/project_001 to pg | ||
|
||
begin; | ||
|
||
alter table cif.project add column score decimal, add column project_type varchar(1000) references cif.project_type(name); | ||
|
||
comment on column cif.project.score is 'The score of the project after evaluation by the CIF team'; | ||
comment on column cif.project.project_type is 'The type of the project (e.g. fuel switching)'; | ||
|
||
commit; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,50 @@ | ||
-- Deploy cif:tables/project_type to pg | ||
|
||
begin; | ||
|
||
create table cif.project_type | ||
( | ||
name varchar(1000) primary key | ||
); | ||
|
||
select cif_private.upsert_timestamp_columns('cif', 'project_type'); | ||
|
||
do | ||
$grant$ | ||
begin | ||
|
||
-- Grant cif_internal permissions | ||
perform cif_private.grant_permissions('select', 'project_type', 'cif_internal'); | ||
perform cif_private.grant_permissions('insert', 'project_type', 'cif_internal'); | ||
perform cif_private.grant_permissions('update', 'project_type', 'cif_internal'); | ||
|
||
-- Grant cif_admin permissions | ||
perform cif_private.grant_permissions('select', 'project_type', 'cif_admin'); | ||
perform cif_private.grant_permissions('insert', 'project_type', 'cif_admin'); | ||
perform cif_private.grant_permissions('update', 'project_type', 'cif_admin'); | ||
|
||
-- Grant cif_external no permissions | ||
-- Grant cif_guest no permissions | ||
|
||
end | ||
$grant$; | ||
|
||
comment on table cif.project_type is 'Table containing information about project types'; | ||
comment on column cif.project_type.name is 'The name of the project type as the primary key'; | ||
|
||
|
||
insert into cif.project_type (name) | ||
values | ||
('Fuel Switching'), | ||
('Waste Heat Recovery'), | ||
('Renewable Energy'), | ||
('Carbon Capture'), | ||
('Utilization and Storage'), | ||
('Methane Reduction'), | ||
('Process Improvement'), | ||
('Electrification'), | ||
('Fleet Electrification'), | ||
('Hydrogen Production/Blending'), | ||
('Other'); | ||
|
||
commit; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,7 +1,43 @@ | ||
-- Revert cif:computed_columns/form_change_as_project from pg | ||
-- Deploy cif:computed_columns/form_change_as_project to pg | ||
-- requires: tables/project | ||
-- requires: tables/project_001 | ||
-- requires: tables/form_change | ||
|
||
begin; | ||
|
||
drop function cif.form_change_as_project(cif.form_change); | ||
create or replace function cif.form_change_as_project(cif.form_change) | ||
returns cif.project | ||
as $$ | ||
select | ||
/** | ||
Given form_data_record_id can be null for some form_change records, it is not a reliable id value for the returned project_contact record. | ||
The returned id must not be null, so we use the form_change id being passed in as a parameter (multiplied by -1 to ensure we are not touching any existing records). | ||
This means the id value is not going to be the correct id for the returned project_contact record, which should be ok since we're only interested | ||
in the data in new_form_data. | ||
**/ | ||
($1.id * -1) as id, | ||
(new_form_data->>'operatorId')::integer as operator_id, | ||
(new_form_data->>'fundingStreamRfpId')::integer as funding_stream_rfp_id, | ||
(new_form_data->>'projectStatusId')::integer as project_status_id, | ||
(new_form_data->>'proposalReference')::varchar as proposal_reference, | ||
new_form_data->>'summary' as summary, | ||
new_form_data->>'projectName' as project_name, | ||
(new_form_data->>'totalFundingRequest')::numeric as total_funding_request, | ||
(new_form_data->>'sectorName')::varchar as sector_name, | ||
(new_form_data->>'additionalSectorInformation')::varchar as additional_sector_information, | ||
(new_form_data->>'comments')::varchar as comments, | ||
null::int as created_by, | ||
now()::timestamptz created_at, | ||
null::int as updated_by, | ||
now()::timestamptz updated_at, | ||
null::int as archived_by, | ||
null::timestamptz as archived_at, | ||
(new_form_data->>'score')::decimal as score, | ||
(new_form_data->>'projectType')::varchar as project_type | ||
from cif.form_change fc where fc.id = $1.id and fc.form_data_table_name = 'project' | ||
|
||
$$ language sql stable; | ||
|
||
comment on function cif.form_change_as_project(cif.form_change) is 'Computed column returns data from the new_form_data column as if it were a project to allow graph traversal via the foreign keys.'; | ||
|
||
commit; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,7 @@ | ||
-- Revert cif:computed_columns/form_change_as_project from pg | ||
|
||
begin; | ||
|
||
drop function cif.form_change_as_project(cif.form_change); | ||
|
||
commit; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,7 @@ | ||
-- Revert cif:tables/project_001 from pg | ||
|
||
begin; | ||
|
||
alter table cif.project drop column score, drop column project_type; | ||
|
||
commit; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,7 @@ | ||
-- Revert cif:tables/project_type from pg | ||
|
||
begin; | ||
|
||
drop table cif.project_type; | ||
|
||
commit; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -103,6 +103,8 @@ mutations/create_project_revision [mutations/[email protected]] | |
computed_columns/emission_intensity_report_calculated_ei_performance 2022-07-27T20:07:35Z Brianna Cerkiewicz <briannacerkiewicz@pop-os> # Returns the calculated EI intensity value | ||
computed_columns/form_change_as_emission_intensity_report 2022-08-03T17:12:52Z Brianna Cerkiewicz <briannacerkiewicz@pop-os> # Computed column to return form change as emission intensity report type | ||
@1.0.0-rc.3 2022-08-08T22:14:42Z Pierre Bastianelli <[email protected]> # release v1.0.0-rc.3 | ||
|
||
mutations/discard_funding_parameter_form_change 2022-08-10T23:11:54Z Gurjeet Matharu <[email protected]> # Discarding funding parameter form change | ||
@1.0.0-rc.4 2022-08-15T18:49:49Z Dylan Leard <[email protected]> # release v1.0.0-rc.4 | ||
tables/project_type 2022-08-08T18:26:33Z Brianna Cerkiewicz <briannacerkiewicz@pop-os> # Adding a table for project type | ||
tables/project_001 2022-08-08T15:28:44Z Brianna Cerkiewicz <briannacerkiewicz@pop-os> # Add a score and project type column to the project table | ||
computed_columns/form_change_as_project [computed_columns/[email protected] tables/project_001] 2022-08-08T21:44:08Z Brianna Cerkiewicz <briannacerkiewicz@pop-os> # Add score and project type to project computed column |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,7 @@ | ||
-- Verify cif:computed_columns/form_change_as_project on pg | ||
|
||
begin; | ||
|
||
select pg_get_functiondef('cif.form_change_as_project(cif.form_change)'::regprocedure); | ||
|
||
rollback; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,9 @@ | ||
-- Verify cif:tables/project_001 on pg | ||
|
||
begin; | ||
|
||
select column_name | ||
from information_schema.columns | ||
where table_schema='cif' and table_name='project' and column_name='score'; | ||
|
||
rollback; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,18 @@ | ||
-- Verify cif:tables/project_type on pg | ||
|
||
begin; | ||
|
||
select pg_catalog.has_table_privilege('cif.project_type', 'select'); | ||
|
||
-- cif_internal Grants | ||
select cif_private.verify_grant('select', 'project_type', 'cif_internal'); | ||
select cif_private.verify_grant('insert', 'project_type', 'cif_internal'); | ||
select cif_private.verify_grant('update', 'project_type', 'cif_internal'); | ||
|
||
-- cif_admin Grants | ||
select cif_private.verify_grant('select', 'project_type', 'cif_admin'); | ||
select cif_private.verify_grant('insert', 'project_type', 'cif_admin'); | ||
select cif_private.verify_grant('update', 'project_type', 'cif_admin'); | ||
|
||
|
||
rollback; |