From b548f652fa5e7fe740f18738274f52df6c8773a1 Mon Sep 17 00:00:00 2001 From: Matthew Jadud Date: Fri, 8 Dec 2023 16:06:18 -0500 Subject: [PATCH] Administrative API and improved tribal data API access controls (#2860) * Seems to run... backs up between buckets Uses a Python-based approach and a Django command as opposed to a shell script. Lots of issues with configuration; this would want to be refactored/improved after we improved how configuration for the app as a whole takes place. It should be much easier to access buckets, etc. regardless of the environment we are working in (local, prod). * Forgot `handle()`. * Moving files around This proabbly belongs in support as an admin API. * Can add, remove, and check keys. * Moving everything to UUIDs. This moves both admin access and tribal data access to a table that is explicitly created via INSERTs that are static/loaded at creation-time. The intent (which could be enforced by schema/privileges) would be to have a table that cannot be modified by the Postgrest user. This way, we have a table that is lookup-only. This would require creating a schema for the table, and prohibiting anything but SELECT perms on that schema from the api_fac_gov user. For now, this is still "for discussion." I have tests to add, etc. This looks very promising, however. The admin functions "work." The file "test.rest" in support/api/admin_api_v1_0_0 allow some quick experimentation. They'll want to be turned into Python functions that run locally/in GH Actions as part of a test suite. * Updating functions to bulk add, adding comments. * This should not have been in this branch. * Fixing errors This brings everything up, and tests are underway. * Adds test coverage for core functions Need to add multi-add. * More tests. * Makes sure we cannot access the view * Linting. * Remove 'assert' statements * One more assert? Linting. * Tests, comments Also, using a slug and SELECT to get rid of a magic number. * Updating test code, view query * Need select on the tribal access table The public views rely on that table, so SELECT access is needed. This fixes the Cypress tests. * Might be more correct to include the table space. Added `public.`... to the table name. * API access request Addresses a review question, of how we initiate this process/track it. The issue template can be used/required for adding people. * Improving comment, removing code Removed unused function. Removed comments of unneeded code. Improved comment around process. Github issue template created. * Updating TF for Admin API Forgot this has to be done in order to test on `preview`. * Updating profile to test a migration failure. * Removing the errant migration Removing it completely. * Refactoring run.sh/.profile This was ultimately a variety of problems, but part of it was our confusing .profile/run.sh situation. Everything is now: 1. A function 2. Has error checking 3. Is reused between the two scripts * Historic tables are not ready. Commenting out until the VCAP grab is fixed. * Updates API code for PG15 The public site (for tribal data access via API) still needs to be updated. However, there are no users (yet) hitting that, so it is behaving correctly (blocking access). This enables the Admin API to work in production (probably). * Reverting to `main` on a migration. * Fixes from review. Separates functions out so they are not on the API schema. * Updates from review. 1. Adding functions to their own (not-exposed) schema. 2. Making tests run always. * Adding DS for tribal access API. * Satisfying the linter. * Lint. * Fixing... parallel test issue? * lint --------- Co-authored-by: danswick <2365503+danswick@users.noreply.github.com> --- .../ISSUE_TEMPLATE/api-access-template.yaml | 37 ++ .../api/api_v1_0_0/create_functions.sql | 60 ---- .../api/api_v1_0_0/create_schema.sql | 50 --- .../api/api_v1_0_0/create_views.sql | 325 ------------------ backend/dissemination/api/api_v1_0_0/drop.sql | 11 - .../api/api_v1_0_0/drop_schema.sql | 11 - .../api/api_v1_0_0/drop_views.sql | 15 - backend/dissemination/api/api_v1_0_1/base.sql | 29 -- .../api/api_v1_0_1/create_functions.sql | 60 ---- .../api/api_v1_0_1/create_schema.sql | 48 --- .../api/api_v1_0_1/create_views.sql | 315 ----------------- backend/dissemination/api/api_v1_0_1/drop.sql | 11 - .../api/api_v1_0_1/drop_schema.sql | 11 - .../api/api_v1_0_1/drop_views.sql | 15 - backend/dissemination/api/api_v1_0_2/base.sql | 29 -- .../api/api_v1_0_2/create_functions.sql | 60 ---- .../api/api_v1_0_2/create_schema.sql | 48 --- .../api/api_v1_0_2/create_views.sql | 317 ----------------- backend/dissemination/api/api_v1_0_2/drop.sql | 11 - .../api/api_v1_0_2/drop_schema.sql | 11 - .../api/api_v1_0_2/drop_views.sql | 15 - .../api/api_v1_0_3/create_functions.sql | 48 +-- .../api/api_v1_0_3/create_schema.sql | 4 + .../api/api_v1_0_3/create_views.sql | 20 +- backend/dissemination/api_versions.py | 82 +++-- .../commands/create_api_access_tables.py | 1 - .../management/commands/create_api_schema.py | 6 +- .../management/commands/create_api_views.py | 6 +- .../management/commands/drop_api_schema.py | 3 +- .../management/commands/drop_api_views.py | 3 +- .../drop_deprecated_api_schema_and_views.py | 3 +- backend/docker-compose-web.yml | 6 +- backend/docker-compose.yml | 6 +- .../api/admin_api_v1_0_0}/base.sql | 0 .../admin_api_v1_0_0/create_access_tables.sql | 47 +++ .../api/admin_api_v1_0_0/create_functions.sql | 281 +++++++++++++++ .../api/admin_api_v1_0_0/create_schema.sql | 53 +++ .../api/admin_api_v1_0_0/create_views.sql | 92 +++++ backend/support/api/admin_api_v1_0_0/drop.sql | 9 + .../api/admin_api_v1_0_0/drop_schema.sql | 9 + .../api/admin_api_v1_0_0/drop_views.sql | 8 + .../support/api/admin_api_v1_0_0/test.rest | 114 ++++++ .../support/migrations/0006_adminapievent.py | 38 ++ backend/support/models/__init__.py | 10 + backend/support/models/admin_api_event.py | 20 ++ .../support/{models.py => models/cog_over.py} | 0 backend/support/test_admin_api.py | 320 +++++++++++++++++ backend/tools/api_standup.sh | 2 +- terraform/shared/modules/env/postgrest.tf | 2 +- 49 files changed, 1124 insertions(+), 1558 deletions(-) create mode 100644 .github/ISSUE_TEMPLATE/api-access-template.yaml delete mode 100644 backend/dissemination/api/api_v1_0_0/create_functions.sql delete mode 100644 backend/dissemination/api/api_v1_0_0/create_schema.sql delete mode 100644 backend/dissemination/api/api_v1_0_0/create_views.sql delete mode 100644 backend/dissemination/api/api_v1_0_0/drop.sql delete mode 100644 backend/dissemination/api/api_v1_0_0/drop_schema.sql delete mode 100644 backend/dissemination/api/api_v1_0_0/drop_views.sql delete mode 100644 backend/dissemination/api/api_v1_0_1/base.sql delete mode 100644 backend/dissemination/api/api_v1_0_1/create_functions.sql delete mode 100644 backend/dissemination/api/api_v1_0_1/create_schema.sql delete mode 100644 backend/dissemination/api/api_v1_0_1/create_views.sql delete mode 100644 backend/dissemination/api/api_v1_0_1/drop.sql delete mode 100644 backend/dissemination/api/api_v1_0_1/drop_schema.sql delete mode 100644 backend/dissemination/api/api_v1_0_1/drop_views.sql delete mode 100644 backend/dissemination/api/api_v1_0_2/base.sql delete mode 100644 backend/dissemination/api/api_v1_0_2/create_functions.sql delete mode 100644 backend/dissemination/api/api_v1_0_2/create_schema.sql delete mode 100644 backend/dissemination/api/api_v1_0_2/create_views.sql delete mode 100644 backend/dissemination/api/api_v1_0_2/drop.sql delete mode 100644 backend/dissemination/api/api_v1_0_2/drop_schema.sql delete mode 100644 backend/dissemination/api/api_v1_0_2/drop_views.sql rename backend/{dissemination/api/api_v1_0_0 => support/api/admin_api_v1_0_0}/base.sql (100%) create mode 100644 backend/support/api/admin_api_v1_0_0/create_access_tables.sql create mode 100644 backend/support/api/admin_api_v1_0_0/create_functions.sql create mode 100644 backend/support/api/admin_api_v1_0_0/create_schema.sql create mode 100644 backend/support/api/admin_api_v1_0_0/create_views.sql create mode 100644 backend/support/api/admin_api_v1_0_0/drop.sql create mode 100644 backend/support/api/admin_api_v1_0_0/drop_schema.sql create mode 100644 backend/support/api/admin_api_v1_0_0/drop_views.sql create mode 100644 backend/support/api/admin_api_v1_0_0/test.rest create mode 100644 backend/support/migrations/0006_adminapievent.py create mode 100644 backend/support/models/__init__.py create mode 100644 backend/support/models/admin_api_event.py rename backend/support/{models.py => models/cog_over.py} (100%) create mode 100644 backend/support/test_admin_api.py diff --git a/.github/ISSUE_TEMPLATE/api-access-template.yaml b/.github/ISSUE_TEMPLATE/api-access-template.yaml new file mode 100644 index 0000000000..10207c818c --- /dev/null +++ b/.github/ISSUE_TEMPLATE/api-access-template.yaml @@ -0,0 +1,37 @@ +name: Request for administrative API access +description: Used to record when and why we granted increased permissions on an API. +title: "[API access]: " +labels: ["api"] +projects: ["GSA-TTS/11"] +assignees: + - jadudm + - danswick +body: + - type: markdown + attributes: + value: | + A request for elevated API access is recorded for reasons of security and compliance. + + * A request for *tribal data access* will begin a process that requires additional conversation with the agency involved. + Access will only be granted to designated staff at confirmed agency partners. + * A request for *admniistrative API access* will only be granted to members of the GSA FAC team. + + - type: dropdown + id: accesstype + attributes: + label: Access type + description: What kind of access is being requested? + options: + - Administrative API access + - Tribal data access API + default: 0 + validations: + required: true + - type: input + id: email + attributes: + label: Email address + description: What is your email address? + placeholder: ex. someone@agency.gov + validations: + required: true diff --git a/backend/dissemination/api/api_v1_0_0/create_functions.sql b/backend/dissemination/api/api_v1_0_0/create_functions.sql deleted file mode 100644 index a5c340ffab..0000000000 --- a/backend/dissemination/api/api_v1_0_0/create_functions.sql +++ /dev/null @@ -1,60 +0,0 @@ --- WARNING --- Under PostgreSQL 12, the functions below work. --- Under PostgreSQL 14, these will break. --- --- Note the differences: --- --- raise info 'Works under PostgreSQL 12'; --- raise info 'request.header.x-magic %', (SELECT current_setting('request.header.x-magic', true)); --- raise info 'request.jwt.claim.expires %', (SELECT current_setting('request.jwt.claim.expires', true)); --- raise info 'Works under PostgreSQL 14'; --- raise info 'request.headers::json->>x-magic %', (SELECT current_setting('request.headers', true)::json->>'x-magic'); --- raise info 'request.jwt.claims::json->expires %', (SELECT current_setting('request.jwt.claims', true)::json->>'expires'); --- --- To quote the work of Dav Pilkey, "remember this now." - -create or replace function getter(base text, item text) returns text -as $getter$ -begin - return current_setting(concat(base, '.', item), true); -end; -$getter$ language plpgsql; - -create or replace function get_jwt_claim(item text) returns text -as $get_jwt_claim$ -begin - return getter('request.jwt.claim', item); -end; -$get_jwt_claim$ language plpgsql; - -create or replace function get_header(item text) returns text -as $get_header$ -begin - raise info 'request.header % %', item, getter('request.header', item); - return getter('request.header', item); -end; -$get_header$ LANGUAGE plpgsql; - --- https://api-umbrella.readthedocs.io/en/latest/admin/api-backends/http-headers.html --- I'd like to go to a model where we provide the API keys. --- However, for now, we're going to look for a role attached to an api.data.gov account. --- These come in on `X-Api-Roles` as a comma-separated string. -create or replace function has_tribal_data_access() returns boolean -as $has_tribal_data_access$ -declare - roles text; -begin - select get_header('x-api-roles') into roles; - return (roles like '%fac_gov_tribal_access%'); -end; -$has_tribal_data_access$ LANGUAGE plpgsql; - -create or replace function has_public_data_access_only() returns boolean -as $has_public_data_access_only$ -begin - return not has_tribal_data_access(); -end; -$has_public_data_access_only$ LANGUAGE plpgsql; - - -NOTIFY pgrst, 'reload schema'; \ No newline at end of file diff --git a/backend/dissemination/api/api_v1_0_0/create_schema.sql b/backend/dissemination/api/api_v1_0_0/create_schema.sql deleted file mode 100644 index 673c7a3edf..0000000000 --- a/backend/dissemination/api/api_v1_0_0/create_schema.sql +++ /dev/null @@ -1,50 +0,0 @@ ---This will be used by the postgrest API_V1_0_0-BETA - -begin; - -do -$$ -begin - DROP SCHEMA IF EXISTS api_v1_0_0 CASCADE; - - if not exists (select schema_name from information_schema.schemata where schema_name = 'api_v1_0_0') then - create schema api_v1_0_0; - - -- Grant access to tables and views - alter default privileges - in schema api_v1_0_0 - grant select - -- this includes views - on tables - to api_fac_gov; - - -- Grant access to sequences, if we have them - grant usage on schema api_v1_0_0 to api_fac_gov; - grant select, usage on all sequences in schema api_v1_0_0 to api_fac_gov; - alter default privileges - in schema api_v1_0_0 - grant select, usage - on sequences - to api_fac_gov; - end if; -end -$$ -; - --- This is the description -COMMENT ON SCHEMA api_v1_0_0 IS - 'The FAC dissemation API version 1.0.0-beta.' -; - --- https://postgrest.org/en/stable/references/api/openapi.html --- This is the title -COMMENT ON SCHEMA api_v1_0_0 IS -$$v1.0.0-beta - -A RESTful API that serves data from the SF-SAC.$$; - -commit; - -notify pgrst, - 'reload schema'; - diff --git a/backend/dissemination/api/api_v1_0_0/create_views.sql b/backend/dissemination/api/api_v1_0_0/create_views.sql deleted file mode 100644 index 44f65bbe94..0000000000 --- a/backend/dissemination/api/api_v1_0_0/create_views.sql +++ /dev/null @@ -1,325 +0,0 @@ - -begin; - ---------------------------------------- --- finding_text ---------------------------------------- -create view api_v1_0_0.findings_text as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - ft.finding_ref_number, - ft.contains_chart_or_table, - ft.finding_text - from - dissemination_findingtext ft, - dissemination_general gen - where - (ft.report_id = gen.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by ft.id -; - ---------------------------------------- --- additional_ueis ---------------------------------------- -create view api_v1_0_0.additional_ueis as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - uei.additional_uei - from - dissemination_general gen, - dissemination_additionaluei uei - where - (gen.report_id = uei.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by uei.id -; - ---------------------------------------- --- finding ---------------------------------------- -create view api_v1_0_0.findings as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - finding.award_reference, - finding.reference_number, - finding.is_material_weakness, - finding.is_modified_opinion, - finding.is_other_findings, - finding.is_other_matters, - finding.prior_finding_ref_numbers, - finding.is_questioned_costs, - finding.is_repeat_finding, - finding.is_significant_deficiency, - finding.type_requirement - from - dissemination_finding finding, - dissemination_general gen - where - (finding.report_id = gen.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by finding.id -; - ---------------------------------------- --- federal award ---------------------------------------- -create view api_v1_0_0.federal_awards as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - award.award_reference, - award.federal_agency_prefix, - award.federal_award_extension, - award.additional_award_identification, - award.federal_program_name, - award.amount_expended, - award.cluster_name, - award.other_cluster_name, - award.state_cluster_name, - award.cluster_total, - award.federal_program_total, - award.is_major, - award.is_loan, - award.loan_balance, - award.is_direct, - award.audit_report_type, - award.findings_count, - award.is_passthrough_award, - award.passthrough_amount - from - dissemination_federalaward award, - dissemination_general gen - where - (award.report_id = gen.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by award.id -; - - ---------------------------------------- --- corrective_action_plan ---------------------------------------- -create view api_v1_0_0.corrective_action_plans as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - ct.finding_ref_number, - ct.contains_chart_or_table, - ct.planned_action - from - dissemination_CAPText ct, - dissemination_General gen - where - (ct.report_id = gen.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by ct.id -; - ---------------------------------------- --- notes_to_sefa ---------------------------------------- -create view api_v1_0_0.notes_to_sefa as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - note.note_title as title, - note.accounting_policies, - note.is_minimis_rate_used, - note.rate_explained, - note.content, - note.contains_chart_or_table - from - dissemination_general gen, - dissemination_note note - where - (note.report_id = gen.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by note.id -; - ---------------------------------------- --- passthrough ---------------------------------------- -create view api_v1_0_0.passthrough as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - pass.award_reference, - pass.passthrough_id, - pass.passthrough_name - from - dissemination_general as gen, - dissemination_passthrough as pass - where - (gen.report_id = pass.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by pass.id -; - - ---------------------------------------- --- general ---------------------------------------- -create view api_v1_0_0.general as - select - -- every table starts with report_id, UEI, and year - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - -- award.federal_agency_prefix, - -- award.federal_award_extension, - gen.auditee_certify_name, - gen.auditee_certify_title, - gen.auditee_contact_name, - gen.auditee_email, - gen.auditee_name, - gen.auditee_phone, - gen.auditee_contact_title, - gen.auditee_address_line_1, - gen.auditee_city, - gen.auditee_state, - gen.auditee_ein, - gen.auditee_zip, - -- auditor - gen.auditor_phone, - gen.auditor_state, - gen.auditor_city, - gen.auditor_contact_title, - gen.auditor_address_line_1, - gen.auditor_zip, - gen.auditor_country, - gen.auditor_contact_name, - gen.auditor_email, - gen.auditor_firm_name, - -- gen.auditor_foreign_addr, - gen.auditor_ein, - -- agency - gen.cognizant_agency, - gen.oversight_agency, - -- dates - gen.date_created, - gen.ready_for_certification_date, - -- gen.auditor_certified_date, - -- gen.auditee_certified_date, - gen.submitted_date, - gen.fy_end_date, - gen.fy_start_date, - gen.audit_type, - gen.gaap_results, - gen.sp_framework_basis, - gen.is_sp_framework_required, - gen.sp_framework_opinions, - gen.is_going_concern_included, - gen.is_internal_control_deficiency_disclosed, - gen.is_internal_control_material_weakness_disclosed, - gen.is_material_noncompliance_disclosed, - -- gen.is_duplicate_reports, - gen.dollar_threshold, - gen.is_low_risk_auditee, - gen.agencies_with_prior_findings, - gen.entity_type, - gen.number_months, - gen.audit_period_covered, - gen.total_amount_expended, - gen.type_audit_code, - gen.is_public, - gen.data_source - from - dissemination_General gen, - dissemination_FederalAward award - where - (gen.report_id = award.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by gen.id - - -- MCJ When it comes time to enable tribal access, this is what it looks like. - -- For each view, we add a conditional clause where the data is not public and - -- the user also has tribal access based on headers from api.data.gov. - -- or (gen.is_public=false and has_tribal_data_access()) -; - ---------------------------------------- --- auditor (secondary auditor) ---------------------------------------- -create view api_v1_0_0.secondary_auditors as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - sa.auditor_ein, - sa.auditor_name, - sa.contact_name, - sa.contact_email, - sa.contact_phone, - sa.address_street, - sa.address_city, - sa.address_state, - sa.address_zipcode - from - dissemination_General gen, - dissemination_SecondaryAuditor sa - where - (sa.report_id = gen.report_id - and - gen.is_public=True) - or (gen.is_public=false and has_tribal_data_access()) - order by sa.id -; - --- create view api_v1_0_0.additional_eins as --- select --- gen.report_id, --- gen.auditee_uei, --- gen.audit_year, --- --- --- ein.additional_ein --- from --- dissemination_general gen, --- dissemination_additionalein ein --- where --- gen.report_id = ein.report_id --- and --- gen.is_public = true --- or (gen.is_public = false and has_tribal_data_access()) --- order by ein.id --- ; - - -commit; - -notify pgrst, - 'reload schema'; diff --git a/backend/dissemination/api/api_v1_0_0/drop.sql b/backend/dissemination/api/api_v1_0_0/drop.sql deleted file mode 100644 index 958dd94e34..0000000000 --- a/backend/dissemination/api/api_v1_0_0/drop.sql +++ /dev/null @@ -1,11 +0,0 @@ - -begin; - -DROP SCHEMA IF EXISTS api_v1_0_0 CASCADE; --- DROP ROLE IF EXISTS authenticator; --- DROP ROLE IF EXISTS api_fac_gov; - -commit; - -notify pgrst, - 'reload schema'; diff --git a/backend/dissemination/api/api_v1_0_0/drop_schema.sql b/backend/dissemination/api/api_v1_0_0/drop_schema.sql deleted file mode 100644 index 958dd94e34..0000000000 --- a/backend/dissemination/api/api_v1_0_0/drop_schema.sql +++ /dev/null @@ -1,11 +0,0 @@ - -begin; - -DROP SCHEMA IF EXISTS api_v1_0_0 CASCADE; --- DROP ROLE IF EXISTS authenticator; --- DROP ROLE IF EXISTS api_fac_gov; - -commit; - -notify pgrst, - 'reload schema'; diff --git a/backend/dissemination/api/api_v1_0_0/drop_views.sql b/backend/dissemination/api/api_v1_0_0/drop_views.sql deleted file mode 100644 index 190be5c256..0000000000 --- a/backend/dissemination/api/api_v1_0_0/drop_views.sql +++ /dev/null @@ -1,15 +0,0 @@ -begin; - - drop table if exists api_v1_0_0.metadata; - drop view if exists api_v1_0_0.general; - drop view if exists api_v1_0_0.auditor; - drop view if exists api_v1_0_0.federal_award; - drop view if exists api_v1_0_0.finding; - drop view if exists api_v1_0_0.finding_text; - drop view if exists api_v1_0_0.cap_text; - drop view if exists api_v1_0_0.note; - -commit; - -notify pgrst, - 'reload schema'; diff --git a/backend/dissemination/api/api_v1_0_1/base.sql b/backend/dissemination/api/api_v1_0_1/base.sql deleted file mode 100644 index dedabe0cb7..0000000000 --- a/backend/dissemination/api/api_v1_0_1/base.sql +++ /dev/null @@ -1,29 +0,0 @@ -DO -$do$ -BEGIN - IF EXISTS ( - SELECT FROM pg_catalog.pg_roles - WHERE rolname = 'authenticator') THEN - RAISE NOTICE 'Role "authenticator" already exists. Skipping.'; - ELSE - CREATE ROLE authenticator LOGIN NOINHERIT NOCREATEDB NOCREATEROLE NOSUPERUSER; - END IF; -END -$do$; - -DO -$do$ -BEGIN - IF EXISTS ( - SELECT FROM pg_catalog.pg_roles - WHERE rolname = 'api_fac_gov') THEN - RAISE NOTICE 'Role "api_fac_gov" already exists. Skipping.'; - ELSE - CREATE ROLE api_fac_gov NOLOGIN; - END IF; -END -$do$; - -GRANT api_fac_gov TO authenticator; - -NOTIFY pgrst, 'reload schema'; diff --git a/backend/dissemination/api/api_v1_0_1/create_functions.sql b/backend/dissemination/api/api_v1_0_1/create_functions.sql deleted file mode 100644 index a5c340ffab..0000000000 --- a/backend/dissemination/api/api_v1_0_1/create_functions.sql +++ /dev/null @@ -1,60 +0,0 @@ --- WARNING --- Under PostgreSQL 12, the functions below work. --- Under PostgreSQL 14, these will break. --- --- Note the differences: --- --- raise info 'Works under PostgreSQL 12'; --- raise info 'request.header.x-magic %', (SELECT current_setting('request.header.x-magic', true)); --- raise info 'request.jwt.claim.expires %', (SELECT current_setting('request.jwt.claim.expires', true)); --- raise info 'Works under PostgreSQL 14'; --- raise info 'request.headers::json->>x-magic %', (SELECT current_setting('request.headers', true)::json->>'x-magic'); --- raise info 'request.jwt.claims::json->expires %', (SELECT current_setting('request.jwt.claims', true)::json->>'expires'); --- --- To quote the work of Dav Pilkey, "remember this now." - -create or replace function getter(base text, item text) returns text -as $getter$ -begin - return current_setting(concat(base, '.', item), true); -end; -$getter$ language plpgsql; - -create or replace function get_jwt_claim(item text) returns text -as $get_jwt_claim$ -begin - return getter('request.jwt.claim', item); -end; -$get_jwt_claim$ language plpgsql; - -create or replace function get_header(item text) returns text -as $get_header$ -begin - raise info 'request.header % %', item, getter('request.header', item); - return getter('request.header', item); -end; -$get_header$ LANGUAGE plpgsql; - --- https://api-umbrella.readthedocs.io/en/latest/admin/api-backends/http-headers.html --- I'd like to go to a model where we provide the API keys. --- However, for now, we're going to look for a role attached to an api.data.gov account. --- These come in on `X-Api-Roles` as a comma-separated string. -create or replace function has_tribal_data_access() returns boolean -as $has_tribal_data_access$ -declare - roles text; -begin - select get_header('x-api-roles') into roles; - return (roles like '%fac_gov_tribal_access%'); -end; -$has_tribal_data_access$ LANGUAGE plpgsql; - -create or replace function has_public_data_access_only() returns boolean -as $has_public_data_access_only$ -begin - return not has_tribal_data_access(); -end; -$has_public_data_access_only$ LANGUAGE plpgsql; - - -NOTIFY pgrst, 'reload schema'; \ No newline at end of file diff --git a/backend/dissemination/api/api_v1_0_1/create_schema.sql b/backend/dissemination/api/api_v1_0_1/create_schema.sql deleted file mode 100644 index 28b2757db4..0000000000 --- a/backend/dissemination/api/api_v1_0_1/create_schema.sql +++ /dev/null @@ -1,48 +0,0 @@ -begin; - -do -$$ -begin - DROP SCHEMA IF EXISTS api_v1_0_1 CASCADE; - - if not exists (select schema_name from information_schema.schemata where schema_name = 'api_v1_0_1') then - create schema api_v1_0_1; - - -- Grant access to tables and views - alter default privileges - in schema api_v1_0_1 - grant select - -- this includes views - on tables - to api_fac_gov; - - -- Grant access to sequences, if we have them - grant usage on schema api_v1_0_1 to api_fac_gov; - grant select, usage on all sequences in schema api_v1_0_1 to api_fac_gov; - alter default privileges - in schema api_v1_0_1 - grant select, usage - on sequences - to api_fac_gov; - end if; -end -$$ -; - --- This is the description -COMMENT ON SCHEMA api_v1_0_1 IS - 'The FAC dissemation API version 1.0.1.' -; - --- https://postgrest.org/en/stable/references/api/openapi.html --- This is the title -COMMENT ON SCHEMA api_v1_0_1 IS -$$v1.0.1 - -A RESTful API that serves data from the SF-SAC.$$; - -commit; - -notify pgrst, - 'reload schema'; - diff --git a/backend/dissemination/api/api_v1_0_1/create_views.sql b/backend/dissemination/api/api_v1_0_1/create_views.sql deleted file mode 100644 index 808aed62de..0000000000 --- a/backend/dissemination/api/api_v1_0_1/create_views.sql +++ /dev/null @@ -1,315 +0,0 @@ - -begin; - ---------------------------------------- --- finding_text ---------------------------------------- -create view api_v1_0_1.findings_text as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - ft.finding_ref_number, - ft.contains_chart_or_table, - ft.finding_text - from - dissemination_findingtext ft, - dissemination_general gen - where - (ft.report_id = gen.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by ft.id -; - ---------------------------------------- --- additional_ueis ---------------------------------------- -create view api_v1_0_1.additional_ueis as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - uei.additional_uei - from - dissemination_general gen, - dissemination_additionaluei uei - where - (gen.report_id = uei.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by uei.id -; - ---------------------------------------- --- finding ---------------------------------------- -create view api_v1_0_1.findings as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - finding.award_reference, - finding.reference_number, - finding.is_material_weakness, - finding.is_modified_opinion, - finding.is_other_findings, - finding.is_other_matters, - finding.prior_finding_ref_numbers, - finding.is_questioned_costs, - finding.is_repeat_finding, - finding.is_significant_deficiency, - finding.type_requirement - from - dissemination_finding finding, - dissemination_general gen - where - (finding.report_id = gen.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by finding.id -; - ---------------------------------------- --- federal award ---------------------------------------- -create view api_v1_0_1.federal_awards as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - award.award_reference, - award.federal_agency_prefix, - award.federal_award_extension, - award.additional_award_identification, - award.federal_program_name, - award.amount_expended, - award.cluster_name, - award.other_cluster_name, - award.state_cluster_name, - award.cluster_total, - award.federal_program_total, - award.is_major, - award.is_loan, - award.loan_balance, - award.is_direct, - award.audit_report_type, - award.findings_count, - award.is_passthrough_award, - award.passthrough_amount - from - dissemination_federalaward award, - dissemination_general gen - where - (award.report_id = gen.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by award.id -; - - ---------------------------------------- --- corrective_action_plan ---------------------------------------- -create view api_v1_0_1.corrective_action_plans as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - ct.finding_ref_number, - ct.contains_chart_or_table, - ct.planned_action - from - dissemination_CAPText ct, - dissemination_General gen - where - (ct.report_id = gen.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by ct.id -; - ---------------------------------------- --- notes_to_sefa ---------------------------------------- -create view api_v1_0_1.notes_to_sefa as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - note.note_title as title, - note.accounting_policies, - note.is_minimis_rate_used, - note.rate_explained, - note.content, - note.contains_chart_or_table - from - dissemination_general gen, - dissemination_note note - where - (note.report_id = gen.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by note.id -; - ---------------------------------------- --- passthrough ---------------------------------------- -create view api_v1_0_1.passthrough as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - pass.award_reference, - pass.passthrough_id, - pass.passthrough_name - from - dissemination_general as gen, - dissemination_passthrough as pass - where - (gen.report_id = pass.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by pass.id -; - - ---------------------------------------- --- general ---------------------------------------- -create view api_v1_0_1.general as - select - -- every table starts with report_id, UEI, and year - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - gen.auditee_certify_name, - gen.auditee_certify_title, - gen.auditee_contact_name, - gen.auditee_email, - gen.auditee_name, - gen.auditee_phone, - gen.auditee_contact_title, - gen.auditee_address_line_1, - gen.auditee_city, - gen.auditee_state, - gen.auditee_ein, - gen.auditee_zip, - -- auditor - gen.auditor_phone, - gen.auditor_state, - gen.auditor_city, - gen.auditor_contact_title, - gen.auditor_address_line_1, - gen.auditor_zip, - gen.auditor_country, - gen.auditor_contact_name, - gen.auditor_email, - gen.auditor_firm_name, - gen.auditor_foreign_address, - gen.auditor_ein, - -- agency - gen.cognizant_agency, - gen.oversight_agency, - -- dates - gen.date_created, - gen.ready_for_certification_date, - gen.auditor_certified_date, - gen.auditee_certified_date, - gen.submitted_date, - gen.fac_accepted_date, - gen.fy_end_date, - gen.fy_start_date, - gen.audit_type, - gen.gaap_results, - gen.sp_framework_basis, - gen.is_sp_framework_required, - gen.sp_framework_opinions, - gen.is_going_concern_included, - gen.is_internal_control_deficiency_disclosed, - gen.is_internal_control_material_weakness_disclosed, - gen.is_material_noncompliance_disclosed, - gen.dollar_threshold, - gen.is_low_risk_auditee, - gen.agencies_with_prior_findings, - gen.entity_type, - gen.number_months, - gen.audit_period_covered, - gen.total_amount_expended, - gen.type_audit_code, - gen.is_public, - gen.data_source - from - dissemination_General gen - where - (gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by gen.id -; - ---------------------------------------- --- auditor (secondary auditor) ---------------------------------------- -create view api_v1_0_1.secondary_auditors as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - sa.auditor_ein, - sa.auditor_name, - sa.contact_name, - sa.contact_email, - sa.contact_phone, - sa.address_street, - sa.address_city, - sa.address_state, - sa.address_zipcode - from - dissemination_General gen, - dissemination_SecondaryAuditor sa - where - (sa.report_id = gen.report_id - and - gen.is_public=True) - or (gen.is_public=false and has_tribal_data_access()) - order by sa.id -; - -create view api_v1_0_1.additional_eins as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - ein.additional_ein - from - dissemination_general gen, - dissemination_additionalein ein - where - (gen.report_id = ein.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by ein.id -; - - -commit; - -notify pgrst, - 'reload schema'; diff --git a/backend/dissemination/api/api_v1_0_1/drop.sql b/backend/dissemination/api/api_v1_0_1/drop.sql deleted file mode 100644 index b182fd0600..0000000000 --- a/backend/dissemination/api/api_v1_0_1/drop.sql +++ /dev/null @@ -1,11 +0,0 @@ - -begin; - -DROP SCHEMA IF EXISTS api_v1_0_1 CASCADE; --- DROP ROLE IF EXISTS authenticator; --- DROP ROLE IF EXISTS api_fac_gov; - -commit; - -notify pgrst, - 'reload schema'; diff --git a/backend/dissemination/api/api_v1_0_1/drop_schema.sql b/backend/dissemination/api/api_v1_0_1/drop_schema.sql deleted file mode 100644 index b182fd0600..0000000000 --- a/backend/dissemination/api/api_v1_0_1/drop_schema.sql +++ /dev/null @@ -1,11 +0,0 @@ - -begin; - -DROP SCHEMA IF EXISTS api_v1_0_1 CASCADE; --- DROP ROLE IF EXISTS authenticator; --- DROP ROLE IF EXISTS api_fac_gov; - -commit; - -notify pgrst, - 'reload schema'; diff --git a/backend/dissemination/api/api_v1_0_1/drop_views.sql b/backend/dissemination/api/api_v1_0_1/drop_views.sql deleted file mode 100644 index b962190fec..0000000000 --- a/backend/dissemination/api/api_v1_0_1/drop_views.sql +++ /dev/null @@ -1,15 +0,0 @@ -begin; - - drop table if exists api_v1_0_1.metadata; - drop view if exists api_v1_0_1.general; - drop view if exists api_v1_0_1.auditor; - drop view if exists api_v1_0_1.federal_award; - drop view if exists api_v1_0_1.finding; - drop view if exists api_v1_0_1.finding_text; - drop view if exists api_v1_0_1.cap_text; - drop view if exists api_v1_0_1.note; - -commit; - -notify pgrst, - 'reload schema'; diff --git a/backend/dissemination/api/api_v1_0_2/base.sql b/backend/dissemination/api/api_v1_0_2/base.sql deleted file mode 100644 index dedabe0cb7..0000000000 --- a/backend/dissemination/api/api_v1_0_2/base.sql +++ /dev/null @@ -1,29 +0,0 @@ -DO -$do$ -BEGIN - IF EXISTS ( - SELECT FROM pg_catalog.pg_roles - WHERE rolname = 'authenticator') THEN - RAISE NOTICE 'Role "authenticator" already exists. Skipping.'; - ELSE - CREATE ROLE authenticator LOGIN NOINHERIT NOCREATEDB NOCREATEROLE NOSUPERUSER; - END IF; -END -$do$; - -DO -$do$ -BEGIN - IF EXISTS ( - SELECT FROM pg_catalog.pg_roles - WHERE rolname = 'api_fac_gov') THEN - RAISE NOTICE 'Role "api_fac_gov" already exists. Skipping.'; - ELSE - CREATE ROLE api_fac_gov NOLOGIN; - END IF; -END -$do$; - -GRANT api_fac_gov TO authenticator; - -NOTIFY pgrst, 'reload schema'; diff --git a/backend/dissemination/api/api_v1_0_2/create_functions.sql b/backend/dissemination/api/api_v1_0_2/create_functions.sql deleted file mode 100644 index a5c340ffab..0000000000 --- a/backend/dissemination/api/api_v1_0_2/create_functions.sql +++ /dev/null @@ -1,60 +0,0 @@ --- WARNING --- Under PostgreSQL 12, the functions below work. --- Under PostgreSQL 14, these will break. --- --- Note the differences: --- --- raise info 'Works under PostgreSQL 12'; --- raise info 'request.header.x-magic %', (SELECT current_setting('request.header.x-magic', true)); --- raise info 'request.jwt.claim.expires %', (SELECT current_setting('request.jwt.claim.expires', true)); --- raise info 'Works under PostgreSQL 14'; --- raise info 'request.headers::json->>x-magic %', (SELECT current_setting('request.headers', true)::json->>'x-magic'); --- raise info 'request.jwt.claims::json->expires %', (SELECT current_setting('request.jwt.claims', true)::json->>'expires'); --- --- To quote the work of Dav Pilkey, "remember this now." - -create or replace function getter(base text, item text) returns text -as $getter$ -begin - return current_setting(concat(base, '.', item), true); -end; -$getter$ language plpgsql; - -create or replace function get_jwt_claim(item text) returns text -as $get_jwt_claim$ -begin - return getter('request.jwt.claim', item); -end; -$get_jwt_claim$ language plpgsql; - -create or replace function get_header(item text) returns text -as $get_header$ -begin - raise info 'request.header % %', item, getter('request.header', item); - return getter('request.header', item); -end; -$get_header$ LANGUAGE plpgsql; - --- https://api-umbrella.readthedocs.io/en/latest/admin/api-backends/http-headers.html --- I'd like to go to a model where we provide the API keys. --- However, for now, we're going to look for a role attached to an api.data.gov account. --- These come in on `X-Api-Roles` as a comma-separated string. -create or replace function has_tribal_data_access() returns boolean -as $has_tribal_data_access$ -declare - roles text; -begin - select get_header('x-api-roles') into roles; - return (roles like '%fac_gov_tribal_access%'); -end; -$has_tribal_data_access$ LANGUAGE plpgsql; - -create or replace function has_public_data_access_only() returns boolean -as $has_public_data_access_only$ -begin - return not has_tribal_data_access(); -end; -$has_public_data_access_only$ LANGUAGE plpgsql; - - -NOTIFY pgrst, 'reload schema'; \ No newline at end of file diff --git a/backend/dissemination/api/api_v1_0_2/create_schema.sql b/backend/dissemination/api/api_v1_0_2/create_schema.sql deleted file mode 100644 index 6a91c6c40d..0000000000 --- a/backend/dissemination/api/api_v1_0_2/create_schema.sql +++ /dev/null @@ -1,48 +0,0 @@ -begin; - -do -$$ -begin - DROP SCHEMA IF EXISTS api_v1_0_2 CASCADE; - - if not exists (select schema_name from information_schema.schemata where schema_name = 'api_v1_0_2') then - create schema api_v1_0_2; - - -- Grant access to tables and views - alter default privileges - in schema api_v1_0_2 - grant select - -- this includes views - on tables - to api_fac_gov; - - -- Grant access to sequences, if we have them - grant usage on schema api_v1_0_2 to api_fac_gov; - grant select, usage on all sequences in schema api_v1_0_2 to api_fac_gov; - alter default privileges - in schema api_v1_0_2 - grant select, usage - on sequences - to api_fac_gov; - end if; -end -$$ -; - --- This is the description -COMMENT ON SCHEMA api_v1_0_2 IS - 'The FAC dissemation API version 1.0.2.' -; - --- https://postgrest.org/en/stable/references/api/openapi.html --- This is the title -COMMENT ON SCHEMA api_v1_0_2 IS -$$v1.0.2 - -A RESTful API that serves data from the SF-SAC.$$; - -commit; - -notify pgrst, - 'reload schema'; - diff --git a/backend/dissemination/api/api_v1_0_2/create_views.sql b/backend/dissemination/api/api_v1_0_2/create_views.sql deleted file mode 100644 index 88ff608352..0000000000 --- a/backend/dissemination/api/api_v1_0_2/create_views.sql +++ /dev/null @@ -1,317 +0,0 @@ - -begin; - ---------------------------------------- --- finding_text ---------------------------------------- -create view api_v1_0_2.findings_text as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - ft.finding_ref_number, - ft.contains_chart_or_table, - ft.finding_text - from - dissemination_findingtext ft, - dissemination_general gen - where - (ft.report_id = gen.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by ft.id -; - ---------------------------------------- --- additional_ueis ---------------------------------------- -create view api_v1_0_2.additional_ueis as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - uei.additional_uei - from - dissemination_general gen, - dissemination_additionaluei uei - where - (gen.report_id = uei.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by uei.id -; - ---------------------------------------- --- finding ---------------------------------------- -create view api_v1_0_2.findings as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - finding.award_reference, - finding.reference_number, - finding.is_material_weakness, - finding.is_modified_opinion, - finding.is_other_findings, - finding.is_other_matters, - finding.prior_finding_ref_numbers, - finding.is_questioned_costs, - finding.is_repeat_finding, - finding.is_significant_deficiency, - finding.type_requirement - from - dissemination_finding finding, - dissemination_general gen - where - (finding.report_id = gen.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by finding.id -; - ---------------------------------------- --- federal award ---------------------------------------- -create view api_v1_0_2.federal_awards as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - award.award_reference, - award.federal_agency_prefix, - award.federal_award_extension, - award.additional_award_identification, - award.federal_program_name, - award.amount_expended, - award.cluster_name, - award.other_cluster_name, - award.state_cluster_name, - award.cluster_total, - award.federal_program_total, - award.is_major, - award.is_loan, - award.loan_balance, - award.is_direct, - award.audit_report_type, - award.findings_count, - award.is_passthrough_award, - award.passthrough_amount - from - dissemination_federalaward award, - dissemination_general gen - where - (award.report_id = gen.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by award.id -; - - ---------------------------------------- --- corrective_action_plan ---------------------------------------- -create view api_v1_0_2.corrective_action_plans as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - ct.finding_ref_number, - ct.contains_chart_or_table, - ct.planned_action - from - dissemination_CAPText ct, - dissemination_General gen - where - (ct.report_id = gen.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by ct.id -; - ---------------------------------------- --- notes_to_sefa ---------------------------------------- -create view api_v1_0_2.notes_to_sefa as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - note.note_title as title, - note.accounting_policies, - note.is_minimis_rate_used, - note.rate_explained, - note.content, - note.contains_chart_or_table - from - dissemination_general gen, - dissemination_note note - where - (note.report_id = gen.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by note.id -; - ---------------------------------------- --- passthrough ---------------------------------------- -create view api_v1_0_2.passthrough as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - pass.award_reference, - pass.passthrough_id, - pass.passthrough_name - from - dissemination_general as gen, - dissemination_passthrough as pass - where - (gen.report_id = pass.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by pass.id -; - - ---------------------------------------- --- general ---------------------------------------- -create view api_v1_0_2.general as - select - -- every table starts with report_id, UEI, and year - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - gen.auditee_certify_name, - gen.auditee_certify_title, - gen.auditee_contact_name, - gen.auditee_email, - gen.auditee_name, - gen.auditee_phone, - gen.auditee_contact_title, - gen.auditee_address_line_1, - gen.auditee_city, - gen.auditee_state, - gen.auditee_ein, - gen.auditee_zip, - -- auditor - gen.auditor_phone, - gen.auditor_state, - gen.auditor_city, - gen.auditor_contact_title, - gen.auditor_address_line_1, - gen.auditor_zip, - gen.auditor_country, - gen.auditor_contact_name, - gen.auditor_email, - gen.auditor_firm_name, - gen.auditor_foreign_address, - gen.auditor_ein, - -- agency - gen.cognizant_agency, - gen.oversight_agency, - -- dates - gen.date_created, - gen.ready_for_certification_date, - gen.auditor_certified_date, - gen.auditee_certified_date, - gen.submitted_date, - gen.fac_accepted_date, - gen.fy_end_date, - gen.fy_start_date, - gen.audit_type, - gen.gaap_results, - gen.sp_framework_basis, - gen.is_sp_framework_required, - gen.sp_framework_opinions, - gen.is_going_concern_included, - gen.is_internal_control_deficiency_disclosed, - gen.is_internal_control_material_weakness_disclosed, - gen.is_material_noncompliance_disclosed, - gen.dollar_threshold, - gen.is_low_risk_auditee, - gen.agencies_with_prior_findings, - gen.entity_type, - gen.number_months, - gen.audit_period_covered, - gen.total_amount_expended, - gen.type_audit_code, - gen.is_public, - gen.data_source, - gen.is_aicpa_audit_guide_included - from - dissemination_General gen - where - (gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by gen.id -; - ---------------------------------------- --- auditor (secondary auditor) ---------------------------------------- -create view api_v1_0_2.secondary_auditors as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - sa.auditor_ein, - sa.auditor_name, - sa.contact_name, - sa.contact_title, - sa.contact_email, - sa.contact_phone, - sa.address_street, - sa.address_city, - sa.address_state, - sa.address_zipcode - from - dissemination_General gen, - dissemination_SecondaryAuditor sa - where - (sa.report_id = gen.report_id - and - gen.is_public=True) - or (gen.is_public=false and has_tribal_data_access()) - order by sa.id -; - -create view api_v1_0_2.additional_eins as - select - gen.report_id, - gen.auditee_uei, - gen.audit_year, - --- - ein.additional_ein - from - dissemination_general gen, - dissemination_additionalein ein - where - (gen.report_id = ein.report_id - and - gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) - order by ein.id -; - - -commit; - -notify pgrst, - 'reload schema'; diff --git a/backend/dissemination/api/api_v1_0_2/drop.sql b/backend/dissemination/api/api_v1_0_2/drop.sql deleted file mode 100644 index 19db364b3a..0000000000 --- a/backend/dissemination/api/api_v1_0_2/drop.sql +++ /dev/null @@ -1,11 +0,0 @@ - -begin; - -DROP SCHEMA IF EXISTS api_v1_0_2 CASCADE; --- DROP ROLE IF EXISTS authenticator; --- DROP ROLE IF EXISTS api_fac_gov; - -commit; - -notify pgrst, - 'reload schema'; diff --git a/backend/dissemination/api/api_v1_0_2/drop_schema.sql b/backend/dissemination/api/api_v1_0_2/drop_schema.sql deleted file mode 100644 index 19db364b3a..0000000000 --- a/backend/dissemination/api/api_v1_0_2/drop_schema.sql +++ /dev/null @@ -1,11 +0,0 @@ - -begin; - -DROP SCHEMA IF EXISTS api_v1_0_2 CASCADE; --- DROP ROLE IF EXISTS authenticator; --- DROP ROLE IF EXISTS api_fac_gov; - -commit; - -notify pgrst, - 'reload schema'; diff --git a/backend/dissemination/api/api_v1_0_2/drop_views.sql b/backend/dissemination/api/api_v1_0_2/drop_views.sql deleted file mode 100644 index 84a23adb4e..0000000000 --- a/backend/dissemination/api/api_v1_0_2/drop_views.sql +++ /dev/null @@ -1,15 +0,0 @@ -begin; - - drop table if exists api_v1_0_2.metadata; - drop view if exists api_v1_0_2.general; - drop view if exists api_v1_0_2.auditor; - drop view if exists api_v1_0_2.federal_award; - drop view if exists api_v1_0_2.finding; - drop view if exists api_v1_0_2.finding_text; - drop view if exists api_v1_0_2.cap_text; - drop view if exists api_v1_0_2.note; - -commit; - -notify pgrst, - 'reload schema'; diff --git a/backend/dissemination/api/api_v1_0_3/create_functions.sql b/backend/dissemination/api/api_v1_0_3/create_functions.sql index a5c340ffab..62d2b400e7 100644 --- a/backend/dissemination/api/api_v1_0_3/create_functions.sql +++ b/backend/dissemination/api/api_v1_0_3/create_functions.sql @@ -13,48 +13,12 @@ -- -- To quote the work of Dav Pilkey, "remember this now." -create or replace function getter(base text, item text) returns text -as $getter$ -begin - return current_setting(concat(base, '.', item), true); -end; -$getter$ language plpgsql; - -create or replace function get_jwt_claim(item text) returns text -as $get_jwt_claim$ -begin - return getter('request.jwt.claim', item); -end; -$get_jwt_claim$ language plpgsql; - -create or replace function get_header(item text) returns text -as $get_header$ -begin - raise info 'request.header % %', item, getter('request.header', item); - return getter('request.header', item); -end; -$get_header$ LANGUAGE plpgsql; - --- https://api-umbrella.readthedocs.io/en/latest/admin/api-backends/http-headers.html --- I'd like to go to a model where we provide the API keys. --- However, for now, we're going to look for a role attached to an api.data.gov account. --- These come in on `X-Api-Roles` as a comma-separated string. -create or replace function has_tribal_data_access() returns boolean +-- We don't grant tribal access (yet) +create or replace function api_v1_0_3_functions.has_tribal_data_access() returns boolean as $has_tribal_data_access$ -declare - roles text; -begin - select get_header('x-api-roles') into roles; - return (roles like '%fac_gov_tribal_access%'); -end; +BEGIN + RETURN 0::BOOLEAN; +END; $has_tribal_data_access$ LANGUAGE plpgsql; -create or replace function has_public_data_access_only() returns boolean -as $has_public_data_access_only$ -begin - return not has_tribal_data_access(); -end; -$has_public_data_access_only$ LANGUAGE plpgsql; - - -NOTIFY pgrst, 'reload schema'; \ No newline at end of file +NOTIFY pgrst, 'reload schema'; diff --git a/backend/dissemination/api/api_v1_0_3/create_schema.sql b/backend/dissemination/api/api_v1_0_3/create_schema.sql index 41372fffef..089e746f2f 100644 --- a/backend/dissemination/api/api_v1_0_3/create_schema.sql +++ b/backend/dissemination/api/api_v1_0_3/create_schema.sql @@ -4,9 +4,13 @@ do $$ begin DROP SCHEMA IF EXISTS api_v1_0_3 CASCADE; + DROP SCHEMA IF EXISTS api_v1_0_3_functions CASCADE; if not exists (select schema_name from information_schema.schemata where schema_name = 'api_v1_0_3') then create schema api_v1_0_3; + create schema api_v1_0_3_functions; + + grant usage on schema api_v1_0_3_functions to api_fac_gov; -- Grant access to tables and views alter default privileges diff --git a/backend/dissemination/api/api_v1_0_3/create_views.sql b/backend/dissemination/api/api_v1_0_3/create_views.sql index 183062693e..7b1e3a9433 100644 --- a/backend/dissemination/api/api_v1_0_3/create_views.sql +++ b/backend/dissemination/api/api_v1_0_3/create_views.sql @@ -19,7 +19,7 @@ create view api_v1_0_3.findings_text as (ft.report_id = gen.report_id and gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) + or (gen.is_public = false and api_v1_0_3_functions.has_tribal_data_access()) order by ft.id ; @@ -40,7 +40,7 @@ create view api_v1_0_3.additional_ueis as (gen.report_id = uei.report_id and gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) + or (gen.is_public = false and api_v1_0_3_functions.has_tribal_data_access()) order by uei.id ; @@ -70,7 +70,7 @@ create view api_v1_0_3.findings as (finding.report_id = gen.report_id and gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) + or (gen.is_public = false and api_v1_0_3_functions.has_tribal_data_access()) order by finding.id ; @@ -109,7 +109,7 @@ create view api_v1_0_3.federal_awards as (award.report_id = gen.report_id and gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) + or (gen.is_public = false and api_v1_0_3_functions.has_tribal_data_access()) order by award.id ; @@ -133,7 +133,7 @@ create view api_v1_0_3.corrective_action_plans as (ct.report_id = gen.report_id and gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) + or (gen.is_public = false and api_v1_0_3_functions.has_tribal_data_access()) order by ct.id ; @@ -159,7 +159,7 @@ create view api_v1_0_3.notes_to_sefa as (note.report_id = gen.report_id and gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) + or (gen.is_public = false and api_v1_0_3_functions.has_tribal_data_access()) order by note.id ; @@ -182,7 +182,7 @@ create view api_v1_0_3.passthrough as (gen.report_id = pass.report_id and gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) + or (gen.is_public = false and api_v1_0_3_functions.has_tribal_data_access()) order by pass.id ; @@ -270,7 +270,7 @@ create view api_v1_0_3.general as (aud.report_id = gen.report_id and gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) + or (gen.is_public = false and api_v1_0_3_functions.has_tribal_data_access()) order by gen.id ; @@ -300,7 +300,7 @@ create view api_v1_0_3.secondary_auditors as (sa.report_id = gen.report_id and gen.is_public=True) - or (gen.is_public=false and has_tribal_data_access()) + or (gen.is_public=false and api_v1_0_3_functions.has_tribal_data_access()) order by sa.id ; @@ -318,7 +318,7 @@ create view api_v1_0_3.additional_eins as (gen.report_id = ein.report_id and gen.is_public = true) - or (gen.is_public = false and has_tribal_data_access()) + or (gen.is_public = false and api_v1_0_3_functions.has_tribal_data_access()) order by ein.id ; diff --git a/backend/dissemination/api_versions.py b/backend/dissemination/api_versions.py index 88f89ea3a7..0579639905 100644 --- a/backend/dissemination/api_versions.py +++ b/backend/dissemination/api_versions.py @@ -1,81 +1,87 @@ from psycopg2._psycopg import connection from config import settings +import logging + +logger = logging.getLogger(__name__) # These are API versions we want live. -live = ( - # These are API versions we have in flight. - "api_v1_0_3", -) +live = {"dissemination": ["api_v1_0_3"], "support": ["admin_api_v1_0_0"]} # These are API versions we have deprecated. # They will be removed. It should be safe to leave them # here for repeated runs. -deprecated = ("api", "api_v1_0_0", "api_v1_0_1", "api_v1_0_2") +deprecated = {"dissemination": ["api"], "support": []} def get_conn_string(): # Default to the production connection string conn_string = None - if settings.ENVIRONMENT not in ["DEVELOPMENT", "PREVIEW", "STAGING", "PRODUCTION"]: + if settings.ENVIRONMENT in ["LOCAL", "TESTING"]: conn_string = "dbname='postgres' user='postgres' port='5432' host='db'" else: conn_string = settings.CONNECTION_STRING return conn_string -def exec_sql(version, filename): +def exec_sql(location, version, filename): conn = connection(get_conn_string()) conn.autocommit = True with conn.cursor() as curs: - filename = f"dissemination/api/{version}/{filename}" - sql = open(filename, "r").read() + path = f"{location}/api/{version}/{filename}" + logger.info(f"EXEC SQL {location} {version} {filename}") + sql = open(path, "r").read() curs.execute(sql) -def create_views(version): - exec_sql(version, "create_views.sql") +def create_views(location, version): + exec_sql(location, version, "create_views.sql") + + +def drop_views(location, version): + exec_sql(location, version, "drop_views.sql") -def drop_views(version): - exec_sql(version, "drop_views.sql") +def create_schema(location, version): + exec_sql(location, version, "create_schema.sql") -def create_schema(version): - exec_sql(version, "create_schema.sql") +def drop_schema(location, version): + exec_sql(location, version, "drop_schema.sql") -def drop_schema(version): - exec_sql(version, "drop_schema.sql") +def create_live_schemas(location): + for version in live[location]: + drop_schema(location, version) + exec_sql(location, version, "base.sql") + create_schema(location, version) -def create_live_schemas(): - for version in live: - drop_schema(version) - exec_sql(version, "base.sql") - create_schema(version) +def drop_live_schema(location): + for version in live[location]: + drop_schema(location, version) -def drop_live_schema(): - for version in live: - drop_schema(version) +def drop_live_views(location): + for version in live[location]: + drop_views(location, version) -def drop_live_views(): - for version in live: - drop_views(version) +def create_live_views(location): + for version in live[location]: + drop_views(location, version) + create_views(location, version) -def create_live_views(): - for version in live: - drop_views(version) - create_views(version) +def create_functions(location): + for version in live[location]: + exec_sql(location, version, "create_functions.sql") -def create_functions(): - for version in live: - exec_sql(version, "create_functions.sql") +def deprecate_schemas_and_views(location): + for version in deprecated[location]: + exec_sql(location, version, "drop.sql") -def deprecate_schemas_and_views(): - for version in deprecated: - exec_sql(version, "drop.sql") +def create_access_tables(location): + for version in live[location]: + exec_sql(location, version, "create_access_tables.sql") diff --git a/backend/dissemination/management/commands/create_api_access_tables.py b/backend/dissemination/management/commands/create_api_access_tables.py index a3c1cd28f0..8635ae9e36 100644 --- a/backend/dissemination/management/commands/create_api_access_tables.py +++ b/backend/dissemination/management/commands/create_api_access_tables.py @@ -8,5 +8,4 @@ class Command(BaseCommand): """ def handle(self, *args, **kwargs): - api_versions.create_access_tables("dissemination") api_versions.create_access_tables("support") diff --git a/backend/dissemination/management/commands/create_api_schema.py b/backend/dissemination/management/commands/create_api_schema.py index d831e3ad15..764c41fffb 100644 --- a/backend/dissemination/management/commands/create_api_schema.py +++ b/backend/dissemination/management/commands/create_api_schema.py @@ -8,5 +8,7 @@ class Command(BaseCommand): """ def handle(self, *args, **kwargs): - api_versions.drop_live_schema() - api_versions.create_live_schemas() + api_versions.drop_live_schema("dissemination") + api_versions.create_live_schemas("dissemination") + api_versions.drop_live_schema("support") + api_versions.create_live_schemas("support") diff --git a/backend/dissemination/management/commands/create_api_views.py b/backend/dissemination/management/commands/create_api_views.py index 045dfc3f5f..105b87a780 100644 --- a/backend/dissemination/management/commands/create_api_views.py +++ b/backend/dissemination/management/commands/create_api_views.py @@ -8,5 +8,7 @@ class Command(BaseCommand): """ def handle(self, *args, **kwargs): - api_versions.create_functions() - api_versions.create_live_views() + api_versions.create_functions("dissemination") + api_versions.create_functions("support") + api_versions.create_live_views("dissemination") + api_versions.create_live_views("support") diff --git a/backend/dissemination/management/commands/drop_api_schema.py b/backend/dissemination/management/commands/drop_api_schema.py index 717bc5a0c5..38453ed5c9 100644 --- a/backend/dissemination/management/commands/drop_api_schema.py +++ b/backend/dissemination/management/commands/drop_api_schema.py @@ -8,4 +8,5 @@ class Command(BaseCommand): """ def handle(self, *args, **kwargs): - api_versions.drop_live_schema() + api_versions.drop_live_schema("dissemination") + api_versions.drop_live_schema("support") diff --git a/backend/dissemination/management/commands/drop_api_views.py b/backend/dissemination/management/commands/drop_api_views.py index f648c32429..c4b137b68b 100644 --- a/backend/dissemination/management/commands/drop_api_views.py +++ b/backend/dissemination/management/commands/drop_api_views.py @@ -8,4 +8,5 @@ class Command(BaseCommand): """ def handle(self, *args, **kwargs): - api_versions.drop_live_views() + api_versions.drop_live_views("dissemination") + api_versions.drop_live_views("support") diff --git a/backend/dissemination/management/commands/drop_deprecated_api_schema_and_views.py b/backend/dissemination/management/commands/drop_deprecated_api_schema_and_views.py index 3452bf7dfc..26222eaa12 100644 --- a/backend/dissemination/management/commands/drop_deprecated_api_schema_and_views.py +++ b/backend/dissemination/management/commands/drop_deprecated_api_schema_and_views.py @@ -8,4 +8,5 @@ class Command(BaseCommand): """ def handle(self, *args, **kwargs): - api_versions.deprecate_schemas_and_views() + api_versions.deprecate_schemas_and_views("dissemination") + api_versions.deprecate_schemas_and_views("support") diff --git a/backend/docker-compose-web.yml b/backend/docker-compose-web.yml index 293ba25550..4aa8765393 100644 --- a/backend/docker-compose-web.yml +++ b/backend/docker-compose-web.yml @@ -3,7 +3,7 @@ version: "3.7" services: db: - image: "postgres:12" + image: "postgres:15" environment: POSTGRES_HOST_AUTH_METHOD: "trust" volumes: @@ -17,7 +17,7 @@ services: retries: 10 census-to-gsafac-db: - image: "postgres:12" + image: "postgres:15" environment: POSTGRES_HOST_AUTH_METHOD: "trust" volumes: @@ -92,7 +92,7 @@ services: PGRST_OPENAPI_SERVER_PROXY_URI: http://127.0.0.1:3000 PGRST_DB_ANON_ROLE: anon # See https://postgrest.org/en/stable/references/api/schemas.html#multiple-schemas for multiple schemas - PGRST_DB_SCHEMAS: "api_v1_0_3" + PGRST_DB_SCHEMAS: "api_v1_0_3, admin_api_v1_0_0" PGRST_JWT_SECRET: ${PGRST_JWT_SECRET:-32_chars_fallback_secret_testing} # Fallback value for testing environments depends_on: db: diff --git a/backend/docker-compose.yml b/backend/docker-compose.yml index d64892ae0b..fba2961f34 100644 --- a/backend/docker-compose.yml +++ b/backend/docker-compose.yml @@ -5,7 +5,7 @@ services: # Postgres DB #--------------------------------------------- db: - image: "postgres:12" + image: "postgres:15" environment: POSTGRES_HOST_AUTH_METHOD: trust volumes: @@ -19,7 +19,7 @@ services: retries: 10 census-to-gsafac-db: - image: "postgres:12" + image: "postgres:15" environment: POSTGRES_HOST_AUTH_METHOD: trust volumes: @@ -126,7 +126,7 @@ services: PGRST_OPENAPI_SERVER_PROXY_URI: http://127.0.0.1:3000 PGRST_DB_ANON_ROLE: anon # See https://postgrest.org/en/stable/references/api/schemas.html#multiple-schemas for multiple schemas - PGRST_DB_SCHEMAS: "api_v1_0_3" + PGRST_DB_SCHEMAS: "api_v1_0_3, admin_api_v1_0_0" PGRST_JWT_SECRET: ${PGRST_JWT_SECRET:-32_chars_fallback_secret_testing} # Fallback value for testing environments depends_on: db: diff --git a/backend/dissemination/api/api_v1_0_0/base.sql b/backend/support/api/admin_api_v1_0_0/base.sql similarity index 100% rename from backend/dissemination/api/api_v1_0_0/base.sql rename to backend/support/api/admin_api_v1_0_0/base.sql diff --git a/backend/support/api/admin_api_v1_0_0/create_access_tables.sql b/backend/support/api/admin_api_v1_0_0/create_access_tables.sql new file mode 100644 index 0000000000..c392adc2bc --- /dev/null +++ b/backend/support/api/admin_api_v1_0_0/create_access_tables.sql @@ -0,0 +1,47 @@ +-- This is explicitly not a Django managed table. +-- In order to have an administrative key added, +-- it must be added via a Github commit, and a PR +-- must be performed to merge the key into the tree. + +-- This is because administrative keys can read/write +-- to some tables in the database. They can read internal and +-- in-flight data. +DROP TABLE IF EXISTS support_administrative_key_uuids; + +CREATE TABLE support_administrative_key_uuids + ( + id BIGSERIAL PRIMARY KEY, + email TEXT, + uuid TEXT, + permissions TEXT, + added DATE + ); + +INSERT INTO support_administrative_key_uuids + (email, uuid, permissions, added) + VALUES + ( + 'matthew.jadud@gsa.gov', + '61ba59b2-f545-4c2f-9b24-9655c706a06c', + 'CREATE,READ,DELETE', + '2023-12-04' + ), + ( + 'carley.jackson@gsa.gov', + 'a938cfca-c8eb-4065-b2eb-782d04bd58ef', + 'CREATE,READ,DELETE', + '2023-12-04' + ), + ( + 'timothy.ballard@gsa.gov', + '1e2845a0-c844-4a6f-84ac-f398b58ce7c9', + 'READ', + '2023-12-08' + ), + ( + 'daniel.swick@gsa.gov', + 'b6e08808-ecb2-4b6a-b928-46d4205497ff', + 'CREATE,READ,DELETE', + '2023-12-08' + ) + ; diff --git a/backend/support/api/admin_api_v1_0_0/create_functions.sql b/backend/support/api/admin_api_v1_0_0/create_functions.sql new file mode 100644 index 0000000000..8b7782884b --- /dev/null +++ b/backend/support/api/admin_api_v1_0_0/create_functions.sql @@ -0,0 +1,281 @@ +-- WARNING +-- Under PostgreSQL 12, the functions below work. +-- Under PostgreSQL 14, these will break. +-- +-- Note the differences: +-- +-- raise info 'Works under PostgreSQL 12'; +-- raise info 'request.header.x-magic %', (SELECT current_setting('request.header.x-magic', true)); +-- raise info 'request.jwt.claim.expires %', (SELECT current_setting('request.jwt.claim.expires', true)); +-- raise info 'Works under PostgreSQL 14'; +-- raise info 'request.headers::json->>x-magic %', (SELECT current_setting('request.headers', true)::json->>'x-magic'); +-- raise info 'request.jwt.claims::json->expires %', (SELECT current_setting('request.jwt.claims', true)::json->>'expires'); +-- +-- To quote the work of Dav Pilkey, "remember this now." + +begin; + + +CREATE OR REPLACE FUNCTION admin_api_v1_0_0_functions.get_header(item text) RETURNS text + AS $get_header$ + declare res text; + begin + SELECT (current_setting('request.headers', true)::json)->>item into res; + return res; + end; +$get_header$ LANGUAGE plpgsql; + +create or replace function admin_api_v1_0_0_functions.get_api_key_uuid() returns TEXT +as $gaku$ +declare uuid text; +begin + select admin_api_v1_0_0_functions.get_header('x-api-user-id') into uuid; + return uuid; +end; +$gaku$ LANGUAGE plpgsql; + +-- log_api_event +-- Maintain an internal table of administrative API events. +-- Also RAISE INFO so that NR gets a copy. +create or replace function admin_api_v1_0_0_functions.log_admin_api_event(event TEXT, meta JSON) +returns boolean +as $log_admin_api_event$ +DECLARE + uuid_header text; +BEGIN + SELECT admin_api_v1_0_0_functions.get_api_key_uuid() INTO uuid_header; + + INSERT INTO public.support_adminapievent + (api_key_uuid, event, event_data, "timestamp") + VALUES (uuid_header, event, meta, NOW()); + + RAISE INFO 'ADMIN_API % % %', uuid_header, event, meta; + RETURN 1; +END; +$log_admin_api_event$ LANGUAGE plpgsql; + + +-- has_admin_data_access :: permission -> bool +-- The permissions (insert, select, delete) allow us to have users who can +-- read administrative data in addition to users who can (say) update +-- select tables like the tribal access lists. +create or replace function admin_api_v1_0_0_functions.has_admin_data_access(perm TEXT) returns boolean +as $has_admin_data_access$ +DECLARE + uuid_header text; + key_exists boolean; + has_permission boolean; +BEGIN + SELECT admin_api_v1_0_0_functions.get_api_key_uuid() INTO uuid_header; + + SELECT + CASE WHEN EXISTS ( + SELECT uuid + FROM public.support_administrative_key_uuids aku + WHERE aku.uuid = uuid_header) + THEN 1::BOOLEAN + ELSE 0::BOOLEAN + END + INTO key_exists; + + SELECT + CASE WHEN EXISTS ( + SELECT permissions + FROM public.support_administrative_key_uuids aku + WHERE aku.uuid = uuid_header + AND aku.permissions like '%' || perm || '%') + THEN 1::BOOLEAN + ELSE 0::BOOLEAN + END + INTO has_permission; + + -- This log event is an INSERT. When called from a VIEW (a SELECT-only context), + -- a call to log_admin_api_event() fails. So, we'll RAISE INFO right here, so we can + -- see the resultse of access checks in the log. We might later comment this out if + -- it becomes too noisy. + RAISE INFO 'ADMIN_API has_access_check % % %', uuid_header, key_exists, has_permission; + + RETURN key_exists AND has_permission; +END; +$has_admin_data_access$ LANGUAGE plpgsql; + +-- Takes an email address and, if that address is not in the access table, +-- inserts it. If the address already exists, the insert is skipped. +-- +-- ### Example from REST client +-- POST http://localhost:3000/rpc/add_tribal_access_email +-- authorization: Bearer {{$processEnv CYPRESS_API_GOV_JWT}} +-- content-profile: admin_api_v1_0_0 +-- content-type: application/json +-- Prefer: params=single-object +-- // Not actually a key UUID. +-- X-Api-User-Id: 18ef0e72-8976-11ee-ad35-3f80b454d3cc +-- { +-- "email": "darth.vader@deathstar.org" +-- } +create or replace function admin_api_v1_0_0.add_tribal_access_email(params JSON) +returns BOOLEAN +as $add_tribal_access_email$ +DECLARE + already_exists INTEGER; + read_tribal_id INTEGER; +BEGIN + -- If the API user has insert permissions, give it a go + IF admin_api_v1_0_0_functions.has_admin_data_access('CREATE') + THEN + -- Are they already in the table? + SELECT count(up.email) + FROM public.users_userpermission as up + WHERE email = params->>'email' INTO already_exists; + + -- If they are, we're going to exit. + IF already_exists <> 0 + THEN + RETURN 0; + END IF; + + -- Grab the permission ID that we need for the insert below. + -- We want the 'read-tribal' permission, which has a human-readable + -- slug. But, we need it's ID, because that is the PK. + SELECT up.id INTO read_tribal_id + FROM public.users_permission AS up + WHERE up.slug = 'read-tribal'; + + IF already_exists = 0 + THEN + -- Can we make the 1 not magic... do a select into. + INSERT INTO public.users_userpermission + (email, permission_id, user_id) + VALUES (params->>'email', read_tribal_id, null); + RETURN admin_api_v1_0_0_functions.log_admin_api_event('tribal-access-email-added', + json_build_object('email', params->>'email')); + END IF; + ELSE + RETURN 0; + END IF; +end; +$add_tribal_access_email$ LANGUAGE plpgsql; + +-- Adds many email addresses. Calls `add_tribal_access_email` for each address. +-- +-- ### Example from REST client +-- POST http://localhost:3000/rpc/add_tribal_access_emails +-- authorization: Bearer {{$processEnv CYPRESS_API_GOV_JWT}} +-- content-profile: admin_api_v1_0_0 +-- content-type: application/json +-- Prefer: params=single-object +-- // Not actually a key UUID. +-- X-Api-User-Id: 18ef0e72-8976-11ee-ad35-3f80b454d3cc +-- { +-- "emails": [ +-- "darth.vader@deathstar.org", +-- "bob.darth.vader@deathstar.org", +-- "darthy.vader@deathstar.org", +-- "bob@deathstar.org" +-- ] +-- } +CREATE OR REPLACE FUNCTION admin_api_v1_0_0.add_tribal_access_emails(params JSON) +returns BOOLEAN +as $add_tribal_access_emails$ +DECLARE + ele TEXT; + em record; +BEGIN + IF admin_api_v1_0_0_functions.has_admin_data_access('CREATE') + THEN + -- This is a FOR loop over a JSON array in plPgSQL + FOR em IN (SELECT json_array_elements_text((params->>'emails')::JSON) ele) + LOOP + -- PERFORM is how to execute code that does not return anything. + -- If a SELECT was used here, the SQL compiler would complain. + PERFORM admin_api_v1_0_0.add_tribal_access_email(json_build_object('email', em.ele)::JSON); + END LOOP; + RETURN 1; + END IF; + RETURN 0; +END; +$add_tribal_access_emails$ LANGUAGE plpgsql; + +-- Removes the email. Will remove multiple rows. That shouldn't happen, but still. +-- +-- ### Example from REST client +-- POST http://localhost:3000/rpc/remove_tribal_access_email +-- authorization: Bearer {{$processEnv CYPRESS_API_GOV_JWT}} +-- content-profile: admin_api_v1_0_0 +-- content-type: application/json +-- Prefer: params=single-object +-- // Not actually a key UUID. +-- X-Api-User-Id: 18ef0e72-8976-11ee-ad35-3f80b454d3cc +-- { +-- "email": "darth.vader@deathstar.org" +-- } +CREATE OR REPLACE FUNCTION admin_api_v1_0_0.remove_tribal_access_email(params JSON) +returns BOOLEAN +as $remove_tribal_access_email$ +DECLARE + affected_rows INTEGER; +BEGIN + + IF admin_api_v1_0_0_functions.has_admin_data_access('DELETE') + THEN + -- Delete rows where the email address matches + DELETE FROM public.users_userpermission as up + WHERE up.email = params->>'email'; + -- This is the Postgres way to find out how many rows + -- were affected by a DELETE. + GET DIAGNOSTICS affected_rows = ROW_COUNT; + -- If that is greater than zero, we were successful. + IF affected_rows > 0 + THEN + RETURN admin_api_v1_0_0_functions.log_admin_api_event('tribal-access-email-removed', + json_build_object('email', params->>'email')); + ELSE + RETURN 0; + END IF; + ELSE + -- If we did not have permission, consider it a failure. + RETURN 0; + END IF; +end; +$remove_tribal_access_email$ LANGUAGE plpgsql; + +-- Removes many email addresses. Calls `remove_tribal_access_email` for each address. +-- +-- ### Example from REST client +-- POST http://localhost:3000/rpc/remove_tribal_access_emails +-- authorization: Bearer {{$processEnv CYPRESS_API_GOV_JWT}} +-- content-profile: admin_api_v1_0_0 +-- content-type: application/json +-- Prefer: params=single-object +-- // Not actually a key UUID. +-- X-Api-User-Id: 18ef0e72-8976-11ee-ad35-3f80b454d3cc +-- { +-- "emails": [ +-- "darth.vader@deathstar.org", +-- "bob.darth.vader@deathstar.org", +-- "darthy.vader@deathstar.org", +-- "bob@deathstar.org" +-- ] +-- } +CREATE OR REPLACE FUNCTION admin_api_v1_0_0.remove_tribal_access_emails(params JSON) +returns BOOLEAN +as $remove_tribal_access_emails$ +DECLARE + ele TEXT; + em record; +BEGIN + IF admin_api_v1_0_0_functions.has_admin_data_access('DELETE') + THEN + FOR em IN (SELECT json_array_elements_text((params->>'emails')::JSON) ele) + LOOP + PERFORM admin_api_v1_0_0.remove_tribal_access_email(json_build_object('email', em.ele)::JSON); + END LOOP; + RETURN 1; + END IF; + RETURN 0; +END; +$remove_tribal_access_emails$ LANGUAGE plpgsql; + +commit; + +NOTIFY pgrst, 'reload schema'; diff --git a/backend/support/api/admin_api_v1_0_0/create_schema.sql b/backend/support/api/admin_api_v1_0_0/create_schema.sql new file mode 100644 index 0000000000..325d868bb8 --- /dev/null +++ b/backend/support/api/admin_api_v1_0_0/create_schema.sql @@ -0,0 +1,53 @@ +begin; + +do +$$ +begin + DROP SCHEMA IF EXISTS admin_api_v1_0_0 CASCADE; + DROP SCHEMA IF EXISTS admin_api_v1_0_0_functions CASCADE; + + if not exists (select schema_name from information_schema.schemata where schema_name = 'admin_api_v1_0_0') then + create schema admin_api_v1_0_0; + create schema admin_api_v1_0_0_functions; + + grant usage on schema admin_api_v1_0_0_functions to api_fac_gov; + + -- Grant access to tables and views + alter default privileges + in schema admin_api_v1_0_0 + grant select + -- this includes views + on tables + to api_fac_gov; + + -- Grant access to sequences, if we have them + grant usage on schema admin_api_v1_0_0 to api_fac_gov; + grant select, usage on all sequences in schema admin_api_v1_0_0 to api_fac_gov; + alter default privileges + in schema admin_api_v1_0_0 + grant select, usage + on sequences + to api_fac_gov; + + -- The admin API needs to be able to write user permissions. + -- This is so we can add and remove people who will have tribal data access + -- via the administrative API. + GRANT INSERT, SELECT, DELETE on public.users_userpermission to api_fac_gov; + -- We need to be able to look up slugs and turn them into permission IDs. + GRANT SELECT on public.users_permission to api_fac_gov; + -- It also needs to be able to log events. + GRANT INSERT on public.support_adminapievent to api_fac_gov; + -- And, it wants to read the UUIDs of administrative keys + GRANT SELECT ON public.support_administrative_key_uuids TO api_fac_gov; + -- We want to see data in flight as admins. + GRANT SELECT ON public.audit_singleauditchecklist TO api_fac_gov; + end if; +end +$$ +; + +commit; + +notify pgrst, + 'reload schema'; + diff --git a/backend/support/api/admin_api_v1_0_0/create_views.sql b/backend/support/api/admin_api_v1_0_0/create_views.sql new file mode 100644 index 0000000000..bed57b4ad6 --- /dev/null +++ b/backend/support/api/admin_api_v1_0_0/create_views.sql @@ -0,0 +1,92 @@ + +begin; + + +--------------------------------------- +-- accesses +--------------------------------------- +-- public.audit_access definition + +-- Drop table + +-- DROP TABLE public.audit_access; + +CREATE OR REPLACE VIEW admin_api_v1_0_0.audit_access AS + SELECT + aa.role, + aa.fullname, + aa.email, + aa.sac_id, + aa.user_id + FROM + public.audit_access aa + WHERE + admin_api_v1_0_0_functions.has_admin_data_access('READ') + ORDER BY aa.id +; + +CREATE OR REPLACE VIEW admin_api_v1_0_0.singleauditchecklist AS + SELECT + sac.id, + sac.date_created, + sac.submission_status, + sac.data_source, + sac.transition_name, + sac.transition_date, + sac.report_id, + sac.audit_type, + sac.general_information, + sac.audit_information, + sac.federal_awards, + sac.corrective_action_plan, + sac.findings_text, + sac.findings_uniform_guidance, + sac.additional_ueis, + sac.additional_eins, + sac.secondary_auditors, + sac.notes_to_sefa, + sac.auditor_certification, + sac.auditee_certification, + sac.tribal_data_consent, + sac.cognizant_agency, + sac.oversight_agency, + sac.submitted_by_id + from + public.audit_singleauditchecklist sac + where + admin_api_v1_0_0_functions.has_admin_data_access('READ') + order by sac.id +; + +CREATE OR REPLACE VIEW admin_api_v1_0_0.tribal_access AS + SELECT + uup.email, + up.slug as permission + FROM + users_userpermission uup, + users_permission up + WHERE + (uup.permission_id = up.id) + AND (up.slug = 'read-tribal') + AND admin_api_v1_0_0_functions.has_admin_data_access('READ') + ORDER BY uup.id +; + +CREATE OR REPLACE VIEW admin_api_v1_0_0.admin_api_events AS + SELECT + ae.timestamp, + ae.api_key_uuid, + ae.event, + ae.event_data + FROM + public.support_adminapievent ae + WHERE + admin_api_v1_0_0_functions.has_admin_data_access('READ') + ORDER BY ae.id +; + + +commit; + +notify pgrst, + 'reload schema'; diff --git a/backend/support/api/admin_api_v1_0_0/drop.sql b/backend/support/api/admin_api_v1_0_0/drop.sql new file mode 100644 index 0000000000..1b45ddc3df --- /dev/null +++ b/backend/support/api/admin_api_v1_0_0/drop.sql @@ -0,0 +1,9 @@ + +begin; + +DROP SCHEMA IF EXISTS admin_api_v1_0_0 CASCADE; + +commit; + +notify pgrst, + 'reload schema'; diff --git a/backend/support/api/admin_api_v1_0_0/drop_schema.sql b/backend/support/api/admin_api_v1_0_0/drop_schema.sql new file mode 100644 index 0000000000..1b45ddc3df --- /dev/null +++ b/backend/support/api/admin_api_v1_0_0/drop_schema.sql @@ -0,0 +1,9 @@ + +begin; + +DROP SCHEMA IF EXISTS admin_api_v1_0_0 CASCADE; + +commit; + +notify pgrst, + 'reload schema'; diff --git a/backend/support/api/admin_api_v1_0_0/drop_views.sql b/backend/support/api/admin_api_v1_0_0/drop_views.sql new file mode 100644 index 0000000000..a49a02cb79 --- /dev/null +++ b/backend/support/api/admin_api_v1_0_0/drop_views.sql @@ -0,0 +1,8 @@ +begin; + + drop table if exists admin_api_v1_0_0.audit_access; + +commit; + +notify pgrst, + 'reload schema'; diff --git a/backend/support/api/admin_api_v1_0_0/test.rest b/backend/support/api/admin_api_v1_0_0/test.rest new file mode 100644 index 0000000000..d80c517f37 --- /dev/null +++ b/backend/support/api/admin_api_v1_0_0/test.rest @@ -0,0 +1,114 @@ +@api_user_id = 61ba59b2-f545-4c2f-9b24-9655c706a06c +# @api_user_id = 1e2845a0-c844-4a6f-84ac-f398b58ce7c9 +@scheme = http +@api_url = localhost:3000 +# @scheme = https +# @api_url = api-preview.fac.gov + +### +GET {{scheme}}://{{api_url}}/general?limit=1 +// Have to use the JWT when testing locally. +authorization: Bearer {{$processEnv CYPRESS_API_GOV_JWT}} +x-api-key: {{$processEnv API_GOV_KEY}} + + +### +GET {{scheme}}://{{api_url}}/audit_access +// Have to use the JWT and API UUID when testing locally. +authorization: Bearer {{$processEnv CYPRESS_API_GOV_JWT}} +x-api-user-id: {{api_user_id}} +x-api-key: {{$processEnv API_GOV_KEY}} +accept-profile: admin_api_v1_0_0 + +### +GET {{scheme}}://{{api_url}}/singleauditchecklist +authorization: Bearer {{$processEnv CYPRESS_API_GOV_JWT}} +x-api-user-id: {{api_user_id}} +accept-profile: admin_api_v1_0_0 +x-api-key: {{$processEnv API_GOV_KEY}} + +### +// This should list everything using a view. +GET {{scheme}}://{{api_url}}/tribal_access +authorization: Bearer {{$processEnv CYPRESS_API_GOV_JWT}} +x-api-user-id: {{api_user_id}} +accept-profile: admin_api_v1_0_0 +x-api-key: {{$processEnv API_GOV_KEY}} + + +### +// Call the RPC to add access +POST {{scheme}}://{{api_url}}/rpc/add_tribal_access_email +authorization: Bearer {{$processEnv CYPRESS_API_GOV_JWT}} +x-api-user-id: {{api_user_id}} +content-profile: admin_api_v1_0_0 +content-type: application/json +Prefer: params=single-object +x-api-key: {{$processEnv API_GOV_KEY}} + +{ + "email": "darth.vader@deathstar.gsa.gov" +} + +### +// Call the RPC to remove access +POST {{scheme}}://{{api_url}}/rpc/add_tribal_access_emails +authorization: Bearer {{$processEnv CYPRESS_API_GOV_JWT}} +x-api-user-id: {{api_user_id}} +content-profile: admin_api_v1_0_0 +content-type: application/json +Prefer: params=single-object +x-api-key: {{$processEnv API_GOV_KEY}} + +{ + "emails": [ + "darth.vader@deathstar.gsa.gov", + "bob.darth.vader@deathstar.gsa.gov", + "darthy.vader@deathstar.gsa.gov", + "bob@deathstar.gsa.gov" + ] +} + +### +// Call the RPC to remove access +POST {{scheme}}://{{api_url}}/rpc/remove_tribal_access_email +authorization: Bearer {{$processEnv CYPRESS_API_GOV_JWT}} +x-api-user-id: {{api_user_id}} +content-profile: admin_api_v1_0_0 +content-type: application/json +Prefer: params=single-object +x-api-key: {{$processEnv API_GOV_KEY}} + +{ + "email": "darth.vader@deathstar.gsa.gov" +} + + +### +// Call the RPC to remove access +POST {{scheme}}://{{api_url}}/rpc/remove_tribal_access_emails +authorization: Bearer {{$processEnv CYPRESS_API_GOV_JWT}} +x-api-user-id: {{api_user_id}} +content-profile: admin_api_v1_0_0 +content-type: application/json +Prefer: params=single-object +x-api-key: {{$processEnv API_GOV_KEY}} + +{ + "emails": [ + "darth.vader@deathstar.gsa.gov", + "bob.darth.vader@deathstar.gsa.gov", + "darthy.vader@deathstar.gsa.gov", + "bob@deathstar.gsa.gov" + ] +} + + +### +// This should list everything using a view. +GET {{scheme}}://{{api_url}}/admin_api_events +authorization: Bearer {{$processEnv CYPRESS_API_GOV_JWT}} +x-api-user-id: {{api_user_id}} +accept-profile: admin_api_v1_0_0 +x-api-key: {{$processEnv API_GOV_KEY}} + diff --git a/backend/support/migrations/0006_adminapievent.py b/backend/support/migrations/0006_adminapievent.py new file mode 100644 index 0000000000..ed30fdad46 --- /dev/null +++ b/backend/support/migrations/0006_adminapievent.py @@ -0,0 +1,38 @@ +# Generated by Django 4.2.6 on 2023-11-23 00:33 + +from django.db import migrations, models + + +class Migration(migrations.Migration): + dependencies = [ + ("support", "0005_alter_cognizantbaseline_cognizant_agency_and_more"), + ] + + operations = [ + migrations.CreateModel( + name="AdminApiEvent", + fields=[ + ( + "id", + models.BigAutoField( + auto_created=True, + primary_key=True, + serialize=False, + verbose_name="ID", + ), + ), + ("api_key_uuid", models.TextField()), + ( + "event", + models.CharField( + choices=[ + ("tribal-access-email-added", "Tribal access granted"), + ("tribal-access-email-removed", "Trbial access removed"), + ] + ), + ), + ("event_data", models.JSONField()), + ("timestamp", models.DateTimeField(auto_now_add=True)), + ], + ), + ] diff --git a/backend/support/models/__init__.py b/backend/support/models/__init__.py new file mode 100644 index 0000000000..c38889ea56 --- /dev/null +++ b/backend/support/models/__init__.py @@ -0,0 +1,10 @@ +from .admin_api_event import AdminApiEvent +from .cog_over import ( + CognizantBaseline, + CognizantAssignment, +) +from .cog_over import AssignmentTypeCode +from .cog_over import reset_baseline + +models = [AdminApiEvent, CognizantBaseline, CognizantAssignment] +_for_the_linter = [AssignmentTypeCode, reset_baseline] diff --git a/backend/support/models/admin_api_event.py b/backend/support/models/admin_api_event.py new file mode 100644 index 0000000000..749ba13c49 --- /dev/null +++ b/backend/support/models/admin_api_event.py @@ -0,0 +1,20 @@ +import logging +from django.db import models +from django.utils.translation import gettext_lazy as _ + +logger = logging.getLogger(__name__) + + +class AdminApiEvent(models.Model): + class EventType: + TRIBAL_ACCESS_EMAIL_ADDED = "tribal-access-email-added" + TRIBAL_ACCESS_EMAIL_REMOVED = "tribal-access-email-removed" + + EVENT_TYPES = ( + (EventType.TRIBAL_ACCESS_EMAIL_ADDED, _("Tribal access granted")), + (EventType.TRIBAL_ACCESS_EMAIL_REMOVED, _("Trbial access removed")), + ) + api_key_uuid = models.TextField() + event = models.CharField(choices=EVENT_TYPES) + event_data = models.JSONField() + timestamp = models.DateTimeField(auto_now_add=True, blank=True) diff --git a/backend/support/models.py b/backend/support/models/cog_over.py similarity index 100% rename from backend/support/models.py rename to backend/support/models/cog_over.py diff --git a/backend/support/test_admin_api.py b/backend/support/test_admin_api.py new file mode 100644 index 0000000000..f54c790a05 --- /dev/null +++ b/backend/support/test_admin_api.py @@ -0,0 +1,320 @@ +from django.test import TestCase +from psycopg2._psycopg import connection +from django.conf import settings + +from datetime import datetime +import jwt +import os +import requests + + +class TestAdminAPI(TestCase): + # We can force a UUID locally that would not work when using api.data.gov, + # because api.data.gov sets/overwrites this. + api_user_uuid = "61ba59b2-f545-4c2f-9b24-9655c706a06c" + admin_api_version = "admin_api_v1_0_0" + + def get_connection(self): + cloudgov = ["DEVELOPMENT", "PREVIEW", "STAGING", "PRODUCTION"] + if settings.ENVIRONMENT not in cloudgov: + conn_string = "dbname='postgres' user='postgres' port='5432' host='db'" + else: + conn_string = settings.CONNECTION_STRING + conn = connection(conn_string) + return conn + + def admin_api_events_exist(self): + # If we did the above, there should be non-zero events in the + # admin API event log. + + query_url = self.api_url + "/admin_api_events" + response = requests.get( + query_url, + headers={ + "authorization": f"Bearer {self.encoded_jwt}", + "accept-profile": TestAdminAPI.admin_api_version, + "x-api-user-id": TestAdminAPI.api_user_uuid, + }, + timeout=10, + ) + objects = response.json() + self.assertGreater(len(objects), 0) + + # And, we should have at least added and removed things. + added = False + removed = False + for o in objects: + if "added" in o["event"]: + added = True + if "removed" in o["event"]: + removed = True + self.assertEquals(added and removed, True) + + # https://stackoverflow.com/questions/2511679/python-number-of-rows-affected-by-cursor-executeselect + def test_users_exist_in_perms_table(self): + with self.get_connection().cursor() as cur: + cur.execute("SELECT count(*) FROM public.support_administrative_key_uuids;") + (number_of_rows,) = cur.fetchone() + self.assertGreaterEqual(number_of_rows, 1) + + def setUp(self): + self.api_url = settings.POSTGREST.get("URL") + self.encoded_jwt = jwt.encode( + self.create_payload(role="api_fac_gov"), + os.getenv("PGRST_JWT_SECRET"), + algorithm="HS256", + ) + + def create_payload(self, role="api_fac_gov"): + payload = { + # PostgREST only cares about the role. + "role": role, + "created": datetime.today().isoformat(), + } + return payload + + def test_postgrest_url_is_reachable(self): + # We must pass a properly signed JWT to access the API + encoded_jwt = jwt.encode( + self.create_payload(), os.getenv("PGRST_JWT_SECRET"), algorithm="HS256" + ) + response = requests.get( + self.api_url, headers={"Authorization": f"Bearer {encoded_jwt}"}, timeout=10 + ) + self.assertEquals(response.status_code, 200) + + def test_assert_fails_with_bad_user_id(self): + # We must pass a properly signed JWT to access the API + + # Insert a user via API + query_url = self.api_url + "/rpc/add_tribal_access_email" + response = requests.post( + query_url, + headers={ + "authorization": f"Bearer {self.encoded_jwt}", + "content-profile": TestAdminAPI.admin_api_version, + "content-type": "application/json", + "prefer": "params=single-object", + # We can force a UUID locally that would not work when using api.data.gov, + # because api.data.gov sets/overwrites this. + "x-api-user-id": "not-a-user-id", + }, + timeout=10, + json={"email": "not.a.test.user@fac.gsa.gov"}, + ) + print("response", response.text) + self.assertEquals(response.text, "false") + self.assertEquals(response.status_code, 200) + + def test_cannot_find_without_access(self): + # We must pass a properly signed JWT to access the API + + # Insert a user via API + query_url = self.api_url + "/rpc/add_tribal_access_email" + response = requests.post( + query_url, + headers={ + "authorization": f"Bearer {self.encoded_jwt}", + "content-profile": TestAdminAPI.admin_api_version, + "content-type": "application/json", + "prefer": "params=single-object", + # We can force a UUID locally that would not work when using api.data.gov, + # because api.data.gov sets/overwrites this. + "x-api-user-id": TestAdminAPI.api_user_uuid, + }, + timeout=10, + json={"email": "test.user@fac.gsa.gov"}, + ) + self.assertEquals(response.text, "true") + self.assertEquals(response.status_code, 200) + + # With the right permissions, I can check if things are present + # via the associated view. + query_url = self.api_url + "/tribal_access" + response = requests.get( + query_url, + headers={ + "authorization": f"Bearer {self.encoded_jwt}", + "accept-profile": TestAdminAPI.admin_api_version, + "x-api-user-id": "not-a-user-id", + }, + timeout=10, + ) + found = False + objects = response.json() + for o in objects: + if "test.user@fac.gsa.gov" in o["email"]: + found = True + self.assertEquals(objects, []) + self.assertEquals(found, False) + + # Now, remove the user, and find them absent. + query_url = self.api_url + "/rpc/remove_tribal_access_email" + response = requests.post( + query_url, + headers={ + "authorization": f"Bearer {self.encoded_jwt}", + "content-profile": TestAdminAPI.admin_api_version, + "content-type": "application/json", + "prefer": "params=single-object", + "x-api-user-id": TestAdminAPI.api_user_uuid, + }, + timeout=10, + json={"email": "test.user@fac.gsa.gov"}, + ) + self.assertEquals(response.text, "true") + self.assertEquals(response.status_code, 200) + + def test_find_gsa_users_in_table(self): + # We must pass a properly signed JWT to access the API + + # Insert a user via API + query_url = self.api_url + "/rpc/add_tribal_access_email" + response = requests.post( + query_url, + headers={ + "authorization": f"Bearer {self.encoded_jwt}", + "content-profile": TestAdminAPI.admin_api_version, + "content-type": "application/json", + "prefer": "params=single-object", + # We can force a UUID locally that would not work when using api.data.gov, + # because api.data.gov sets/overwrites this. + "x-api-user-id": TestAdminAPI.api_user_uuid, + }, + timeout=10, + json={"email": "test.user@fac.gsa.gov"}, + ) + self.assertEquals(response.text, "true") + self.assertEquals(response.status_code, 200) + + # With the right permissions, I can check if things are present + # via the associated view. + query_url = self.api_url + "/tribal_access" + response = requests.get( + query_url, + headers={ + "authorization": f"Bearer {self.encoded_jwt}", + "accept-profile": TestAdminAPI.admin_api_version, + "x-api-user-id": TestAdminAPI.api_user_uuid, + }, + timeout=10, + ) + found = False + for o in response.json(): + if "test.user@fac.gsa.gov" in o["email"]: + found = True + self.assertEquals(found, True) + + # Now, remove the user, and find them absent. + query_url = self.api_url + "/rpc/remove_tribal_access_email" + response = requests.post( + query_url, + headers={ + "authorization": f"Bearer {self.encoded_jwt}", + "content-profile": TestAdminAPI.admin_api_version, + "content-type": "application/json", + "prefer": "params=single-object", + "x-api-user-id": TestAdminAPI.api_user_uuid, + }, + timeout=10, + json={"email": "test.user@fac.gsa.gov"}, + ) + self.assertEquals(response.status_code, 200) + + query_url = self.api_url + "/tribal_access" + response = requests.get( + query_url, + headers={ + "authorization": f"Bearer {self.encoded_jwt}", + "accept-profile": TestAdminAPI.admin_api_version, + "x-api-user-id": TestAdminAPI.api_user_uuid, + }, + timeout=10, + ) + found = False + for o in response.json(): + if "test.user@fac.gsa.gov" in o["email"]: + found = True + self.assertEquals(found, False) + + def test_find_many_gsa_users_in_table(self): + all_emails = [ + "test.user@fac.gsa.gov", + "alice@fac.gsa.gov", + "bob@fac.gsa.gov", + ] + + # Insert a user via API + query_url = self.api_url + "/rpc/add_tribal_access_emails" + response = requests.post( + query_url, + headers={ + "authorization": f"Bearer {self.encoded_jwt}", + "content-profile": TestAdminAPI.admin_api_version, + "content-type": "application/json", + "prefer": "params=single-object", + # We can force a UUID locally that would not work when using api.data.gov, + # because api.data.gov sets/overwrites this. + "x-api-user-id": TestAdminAPI.api_user_uuid, + }, + timeout=10, + json={"emails": all_emails}, + ) + self.assertEquals(response.text, "true") + self.assertEquals(response.status_code, 200) + + # With the right permissions, I can check if things are present + # via the associated view. + query_url = self.api_url + "/tribal_access" + response = requests.get( + query_url, + headers={ + "authorization": f"Bearer {self.encoded_jwt}", + "accept-profile": TestAdminAPI.admin_api_version, + "x-api-user-id": TestAdminAPI.api_user_uuid, + }, + timeout=10, + ) + + found = 0 + for email in all_emails: + for o in response.json(): + if email in o["email"]: + found += 1 + self.assertEquals(found, len(all_emails)) + + # Now, remove the user, and find them absent. + query_url = self.api_url + "/rpc/remove_tribal_access_emails" + response = requests.post( + query_url, + headers={ + "authorization": f"Bearer {self.encoded_jwt}", + "content-profile": TestAdminAPI.admin_api_version, + "content-type": "application/json", + "prefer": "params=single-object", + "x-api-user-id": TestAdminAPI.api_user_uuid, + }, + timeout=10, + json={"emails": all_emails}, + ) + self.assertEquals(response.status_code, 200) + + query_url = self.api_url + "/tribal_access" + response = requests.get( + query_url, + headers={ + "authorization": f"Bearer {self.encoded_jwt}", + "accept-profile": TestAdminAPI.admin_api_version, + "x-api-user-id": TestAdminAPI.api_user_uuid, + }, + timeout=10, + ) + + found = 0 + for email in all_emails: + for o in response.json(): + if email in o["email"]: + found += 1 + self.assertEquals(found, 0) + + self.admin_api_events_exist() diff --git a/backend/tools/api_standup.sh b/backend/tools/api_standup.sh index 57d6079520..23567bed9a 100644 --- a/backend/tools/api_standup.sh +++ b/backend/tools/api_standup.sh @@ -22,7 +22,7 @@ function api_standup { startup_log "API_STANDUP" "END" - result=$(($d1 + $d2 + $d3)) + result=$((($d1 + $d2) + $d3)) # If these are all zero, we're all good. return $result } diff --git a/terraform/shared/modules/env/postgrest.tf b/terraform/shared/modules/env/postgrest.tf index ff33846f82..30c37a9532 100644 --- a/terraform/shared/modules/env/postgrest.tf +++ b/terraform/shared/modules/env/postgrest.tf @@ -32,7 +32,7 @@ resource "cloudfoundry_app" "postgrest" { environment = { PGRST_DB_URI : cloudfoundry_service_key.postgrest.credentials.uri - PGRST_DB_SCHEMAS : "api_v1_0_3" + PGRST_DB_SCHEMAS : "api_v1_0_3,admin_api_v1_0_0" PGRST_DB_ANON_ROLE : "anon" PGRST_JWT_SECRET : var.pgrst_jwt_secret PGRST_DB_MAX_ROWS : 20000