From 8f0fa0f5fcd06600b023e8630c99464b77b2a80a Mon Sep 17 00:00:00 2001 From: Purvin Patel <146017183+purvinptl@users.noreply.github.com> Date: Mon, 4 Mar 2024 16:55:06 -0600 Subject: [PATCH] Enable tribal data & file download access from API (#3359) * Tribal api add_remove function and request access function * Removed request_file_access since it was implemented in create_function.sql in admin api * bugfixes; grant permissions for tribal access tables * 3288 cannot convert string to integer (#3290) * Code refactoring * #3288 More refactoring * Added logic to handle empty finding count, empty program total, empty cluster total and empty amount expend * Ensure calculated value are returned as string * Erroring on "GSA_MIGRATION" in emails when not migrating (#3275) * Checking for GSA_MIGRATION when not migrating * Adding unit tests * Fixing test name * Fixing test names * Reverting is_gsa_migration param * Trailing comma * Moving check to validate_general_information_json * Removing print * Lint * Setting is_gsa_migration to False for api serializer * Using getattr to fix tests * Adding test_views.py test * Lint * Not using getattr * Back up prod media files every two hours. (#3239) * Copy Updates Re: Our Lack of Email Notifications (#3229) * Copy re email notifs: audit access form * Copy re email notifs: lock for certification * Copy re email notifs: auditor certification * Keep wording consistent * add prefix-ALN note to program name validation (#3230) * Adds columns to FederalAwards, Findings in summary sheets (#3296) * Adds columns to FederalAwards, Findings Adds "_aln" to FederalAward Adds "_federal_agency_prefix", "_federal_award_extension" and "_aln" to Finding. This makes it possible for resolution officials to easily find the reference numbers on their awards without having to manually flip back-and-forth between tabs, which is error prone. * Linting. * Speed up search queries (#3283) * Trying to optimize queries. Result of cowork with JP. Handing off. * This is a step towards improving queries. The first part, intersecting things, is a good way to filter down. ALNs could still use improvement. * Updating Moving towards implementing ALN sorting. * Handing off... * THIS WORKS * Checkpoint * Checkpoint from end of day * Forgot the constants * This... makes it work. However, like the rest of the code, it assumes we have indicies. So. We may roll this back. * Backing out the ForeignKey * Adding the API back, reverting summary reports * Commenting out possible indexes for future * Undoing debug toolbar * Linting! * "Finding all ALN" -> "Finding other ALN" * Test fixes/updates, minor finding_all_aln tweaks * is_public = True OR is_public = False, not AND * Really, really working v2.3.2 * Actually really working 3.0 * Adds ALN Y/N based on ALNs, not just agency numbers. * Handoff. * Default to a 2023 search over getting everything * Readd annotate_findings_two, to compare approaches * A little linting * Test updates for 2023-default behavior * Final push * Logging changes * Working things. * A blank line, for fun * Linting. * Eliminating incorrect comment. * Don't create dict as default argument. * Clearer tribal test * Undo RAM grab in Postgres local container. --------- Co-authored-by: James Person Co-authored-by: Tadhg O'Higgins <2626258+tadhg-ohiggins@users.noreply.github.com> * TEST SITE Banner (#3261) * Test site banner, test implementation * Linting to appease the lint gods. * Sometimes we copy/paste too fast. * Mshd/handle reports without notes (#3300) * Updated Schema to Allow GSA migration keyword in NotesToSefa coversheet * Prevent use of GSA migration keyword outside of migration process * Added logic to generate Note records with GSA migration keyword only when no record found for 2018/17/16 * Fixed failing test * Uncomment Schedule Block (#3308) * 3309 unexpected loan balance (#3311) * #3309 Updated logic to default zero loan balance to empty when loan flag is false * #3309 Updated test cases * 3312 discrepancy in the number of passthrough names compared to passthrough ids (#3316) * Renamed function to improve readability * #3312 Updated logic to handle cardinality mismatch between passthrough names and ids * #3312 Adding test * 3315 missing reference numbers in audit findings text records (#3319) * Updated logic to handle missing reference numbers * Updated schema * Census migration: Adding CAP text missing ref unit tests (#3321) * Adding cap text tests * Generating wb * Generator fix * Lint * Cleaning up generator * Lint * "!=" is not the same thing as "is not" (#3326) * Context for 500s, Resolve Pre-cert Report 500s (#3333) * 500 errors should have (some limited) context. * Pre-cert reports should not append bonus fields. * Pre-cert reports should not append bonus fields. * Updated dev and preview instance memories (#3334) * django admin tooling for dissem (#3342) * Omit Underscored Fields from Pre-certification Reports (#3340) * 500 errors should have (some limited) context. * Pre-cert reports should not append bonus fields. * Pre-cert reports should not append bonus fields. * Omit underscored fields from column names. * Added has_tribal_data_access function * fix tribal filtering clause, fix migration conflict * Bumped api versions for dissemination/api and support/admin_api to 1_1_0 * linter * fix add/remove privs for tribal access * add cypress test for tribal API access * update testing docs * Github Action Version Updates (#3310) * Bump create-or-update-comment * Bump Zap * Bump repository-dispatch * Bump create-pull-request * Bump auto-approve-action * Increase production RAM to 6G. (#3376) * Search - Banish the ALN Columns (#3378) * Banish the ALN columns, for now... * Return the right results. Disable column tests. * Capture search parameters in NR (#3382) * try add search params as NR attributes * make them strings * maybe all of the search fields now? * audit_years is a special case because they're ints * maybe spell it right though * lint * Search - Default FederalAward Results to Empty QuerySet (#3384) * r_full_alns should default to an empty queryset, not None. * Now with a test! * Update Django And Cryptography package (#3380) * bump requirements * python lib updates * Use only disseminated data in the public API (#3381) * Fixes gross error in API. The `OR` conjunction in every view was causing a combinatoric explosion on every single API query, destroying performance as the DB grew. This fixes that problem. * Fixes the general view Uses only disseminated data instead of the internal table. THis broke with historical data, because not all environments have a historical singleauditchecklist (at this time). * Fixing accidental removal Leave the additional_ueis there. * Updating version on dropped tables * Search - Banish the ALN Columns (#3378) * Banish the ALN columns, for now... * Return the right results. Disable column tests. * Search - Default FederalAward Results to Empty QuerySet (#3384) * r_full_alns should default to an empty queryset, not None. * Now with a test! * Use only disseminated data in the public API (#3381) * Fixes gross error in API. The `OR` conjunction in every view was causing a combinatoric explosion on every single API query, destroying performance as the DB grew. This fixes that problem. * Fixes the general view Uses only disseminated data instead of the internal table. THis broke with historical data, because not all environments have a historical singleauditchecklist (at this time). * Fixing accidental removal Leave the additional_ueis there. * Search - Banish the ALN Columns (#3378) * Banish the ALN columns, for now... * Return the right results. Disable column tests. * Search - Default FederalAward Results to Empty QuerySet (#3384) * r_full_alns should default to an empty queryset, not None. * Now with a test! * Use only disseminated data in the public API (#3381) * Fixes gross error in API. The `OR` conjunction in every view was causing a combinatoric explosion on every single API query, destroying performance as the DB grew. This fixes that problem. * Fixes the general view Uses only disseminated data instead of the internal table. THis broke with historical data, because not all environments have a historical singleauditchecklist (at this time). * Fixing accidental removal Leave the additional_ueis there. * Search - Banish the ALN Columns (#3378) * Banish the ALN columns, for now... * Return the right results. Disable column tests. * Search - Default FederalAward Results to Empty QuerySet (#3384) * r_full_alns should default to an empty queryset, not None. * Now with a test! * Removed the old api version api_v1_0_3 * Made suggested changes during code review * api versioning fixes * keep 1_0_3 the default * also docker-compose-web * rollback changes to api 1_0_3 * newlines * Dropping the redundant drop.sql file since we have drop_schema.sql * Similar changes to api_v1_0_3 with redundant drop schema. * resolve migration conflict * Renamed drop.sql to drop_schema.sql to match other changes * Making the hasAgency const logic clear. * Refactored p_report_id to report_id for consistent naming. * Dropped the redundant drop.sql file * specify API version in cypress tests * add api_v1_1_0 to tf --------- Co-authored-by: Tim Ballard <1425377+timoballard@users.noreply.github.com> Co-authored-by: Hassan D. M. Sambo Co-authored-by: Phil Dominguez <142051477+phildominguez-gsa@users.noreply.github.com> Co-authored-by: Tadhg O'Higgins <2626258+tadhg-ohiggins@users.noreply.github.com> Co-authored-by: James Person Co-authored-by: Dan Swick <2365503+danswick@users.noreply.github.com> Co-authored-by: Matthew Jadud Co-authored-by: James Person Co-authored-by: Alex Steel <130377221+asteel-gsa@users.noreply.github.com> --- .../cypress/support/dissemination-table.js | 105 +++++- backend/cypress/support/full-submission.js | 8 +- backend/cypress/support/initialize-audit.js | 5 +- .../api/api/{drop.sql => drop_schema.sql} | 0 .../api/api_v1_1_0}/base.sql | 0 .../api/api_v1_1_0/create_functions.sql | 40 +++ .../api/api_v1_1_0/create_schema.sql | 49 +++ .../api/api_v1_1_0/create_views.sql | 326 ++++++++++++++++++ .../drop.sql => api_v1_1_0/drop_schema.sql} | 2 +- .../api/api_v1_1_0/drop_views.sql | 17 + backend/dissemination/api_versions.py | 4 +- .../migrations/0014_tribalapiaccesskeyids.py | 35 ++ backend/dissemination/models.py | 13 + backend/docker-compose-web.yml | 2 +- backend/docker-compose.yml | 2 +- backend/support/api/admin_api_v1_0_0/drop.sql | 9 - backend/support/api/admin_api_v1_1_0/base.sql | 29 ++ .../create_access_tables.sql | 2 +- .../create_functions.sql | 170 +++++++-- .../create_schema.sql | 23 +- .../create_views.sql | 16 +- .../drop_schema.sql | 2 +- .../drop_views.sql | 2 +- .../test.rest | 16 +- backend/support/test_admin_api.py | 2 +- docs/testing.md | 9 +- terraform/shared/modules/env/postgrest.tf | 2 +- 27 files changed, 811 insertions(+), 79 deletions(-) rename backend/dissemination/api/api/{drop.sql => drop_schema.sql} (100%) rename backend/{support/api/admin_api_v1_0_0 => dissemination/api/api_v1_1_0}/base.sql (100%) create mode 100644 backend/dissemination/api/api_v1_1_0/create_functions.sql create mode 100644 backend/dissemination/api/api_v1_1_0/create_schema.sql create mode 100644 backend/dissemination/api/api_v1_1_0/create_views.sql rename backend/dissemination/api/{api_v1_0_3/drop.sql => api_v1_1_0/drop_schema.sql} (75%) create mode 100644 backend/dissemination/api/api_v1_1_0/drop_views.sql create mode 100644 backend/dissemination/migrations/0014_tribalapiaccesskeyids.py delete mode 100644 backend/support/api/admin_api_v1_0_0/drop.sql create mode 100644 backend/support/api/admin_api_v1_1_0/base.sql rename backend/support/api/{admin_api_v1_0_0 => admin_api_v1_1_0}/create_access_tables.sql (97%) rename backend/support/api/{admin_api_v1_0_0 => admin_api_v1_1_0}/create_functions.sql (59%) rename backend/support/api/{admin_api_v1_0_0 => admin_api_v1_1_0}/create_schema.sql (67%) rename backend/support/api/{admin_api_v1_0_0 => admin_api_v1_1_0}/create_views.sql (76%) rename backend/support/api/{admin_api_v1_0_0 => admin_api_v1_1_0}/drop_schema.sql (54%) rename backend/support/api/{admin_api_v1_0_0 => admin_api_v1_1_0}/drop_views.sql (51%) rename backend/support/api/{admin_api_v1_0_0 => admin_api_v1_1_0}/test.rest (91%) diff --git a/backend/cypress/support/dissemination-table.js b/backend/cypress/support/dissemination-table.js index 13c22e279c..6f061eb9fe 100644 --- a/backend/cypress/support/dissemination-table.js +++ b/backend/cypress/support/dissemination-table.js @@ -4,7 +4,10 @@ const API_GOV_JWT = Cypress.env('API_GOV_JWT') || ''; const API_GOV_KEY = Cypress.env('API_GOV_KEY') || ''; +const API_GOV_USER_ID_ADMIN = Cypress.env('API_GOV_USER_ID_ADMIN'); const API_GOV_URL = Cypress.env('API_GOV_URL'); +const API_VERSION = Cypress.env('API_VERSION'); +const ADMIN_API_VERSION = Cypress.env('ADMIN_API_VERSION'); const requestOptions = { method: 'GET', @@ -15,7 +18,51 @@ const requestOptions = { }, } -export function testReportIdNotFound(reportId) { +function grantTribalAccess(email, user_id) { + // use admin user to grant tribal access to user + cy.request({ + method: 'POST', + url: `${API_GOV_URL}/rpc/add_tribal_api_key_access`, + headers: { + Authorization: `Bearer ${API_GOV_JWT}`, + 'X-Api-Key': API_GOV_KEY, + 'X-Api-User-Id': API_GOV_USER_ID_ADMIN, + 'Content-Profile': ADMIN_API_VERSION, + 'Content-Type': 'application/json', + 'Prefer': 'params=single-object', + }, + body: { + "email": `${email}`, + "key_id": `${user_id}`, + } + }).should((response) => { + expect(response.body).to.equal(true); + }); +} + +function revokeTribalAccess(email, user_id) { + // use admin user to revoke tribal access to user + cy.request({ + method: 'POST', + url: `${API_GOV_URL}/rpc/remove_tribal_api_key_access`, + headers: { + Authorization: `Bearer ${API_GOV_JWT}`, + 'X-Api-Key': API_GOV_KEY, + 'X-Api-User-Id': API_GOV_USER_ID_ADMIN, + 'Content-Profile': ADMIN_API_VERSION, + 'Content-Type': 'application/json', + 'Prefer': 'params=single-object', + }, + body: { + "email": `${email}`, + "key_id": `${user_id}`, + } + }).should((response) => { + expect(response.body).to.equal(true); + }); +} + +export function testReportIdNotFoundWithoutTribalAccess(reportId) { cy.request({ ...requestOptions, qs: {report_id: `eq.${reportId}`}, @@ -24,13 +71,63 @@ export function testReportIdNotFound(reportId) { }); } -export function testReportIdFound(reportId) { +export function testReportIdFoundWithoutTribalAccess(reportId) { cy.request({ ...requestOptions, qs: {report_id: `eq.${reportId}`}, }).should((response) => { expect(response.body).to.have.length(1); - const hasAgency = !!(response.body[0]?.cognizant_agency || response.body[0]?.oversight_agency); - expect(hasAgency).to.be.true; + const hasAgency = response.body[0]?.cognizant_agency || response.body[0]?.oversight_agency; + expect(Boolean(hasAgency)).to.be.true; + }); +} + +export function testReportIdFoundWithTribalAccess(reportId) { + const tribal_access_email = `${crypto.randomUUID()}@example.com`; + const tribal_access_user_id = crypto.randomUUID(); + + grantTribalAccess(tribal_access_email, tribal_access_user_id); + + // try to pull the tribal, non-public data from the API using the (now) privileged user + cy.request({ + method: 'GET', + url: `${API_GOV_URL}/general`, + headers: { + Authorization: `Bearer ${API_GOV_JWT}`, + 'X-Api-Key': API_GOV_KEY, + 'X-Api-User-Id': tribal_access_user_id, + 'Accept-Profile': API_VERSION + }, + qs: {report_id: `eq.${reportId}`}, + }).should((response) => { + expect(response.body).to.have.length(1); + const hasAgency = response.body[0]?.cognizant_agency || response.body[0]?.oversight_agency; + expect(Boolean(hasAgency)).to.be.true; + }); + + revokeTribalAccess(tribal_access_email, tribal_access_user_id); +} + +export function testReportIdNotFoundWithTribalAccess(reportId) { + const tribal_access_email = `${crypto.randomUUID()}@example.com`; + const tribal_access_user_id = crypto.randomUUID(); + + grantTribalAccess(tribal_access_email, tribal_access_user_id); + + // try to pull the tribal, non-public data from the API using the (now) privileged user + cy.request({ + method: 'GET', + url: `${API_GOV_URL}/general`, + headers: { + Authorization: `Bearer ${API_GOV_JWT}`, + 'X-Api-Key': API_GOV_KEY, + 'X-Api-User-Id': tribal_access_user_id, + 'Accept-Profile': API_VERSION + }, + qs: {report_id: `eq.${reportId}`}, + }).should((response) => { + expect(response.body).to.have.length(0); }); + + revokeTribalAccess(tribal_access_email, tribal_access_user_id); } diff --git a/backend/cypress/support/full-submission.js b/backend/cypress/support/full-submission.js index b7fb1e4df1..5e907c375c 100644 --- a/backend/cypress/support/full-submission.js +++ b/backend/cypress/support/full-submission.js @@ -5,7 +5,7 @@ import { testAuditInformationForm } from './audit-info-form.js'; import { testPdfAuditReport } from './report-pdf.js'; import { testAuditorCertification } from './auditor-certification.js'; import { testAuditeeCertification } from './auditee-certification.js'; -import { testReportIdFound, testReportIdNotFound } from './dissemination-table.js'; +import { testReportIdFoundWithTribalAccess, testReportIdFoundWithoutTribalAccess, testReportIdNotFoundWithoutTribalAccess } from './dissemination-table.js'; import { testTribalAuditPublic, testTribalAuditPrivate } from './tribal-audit-form.js'; import { testInitializeAudit } from './initialize-audit.js'; import { @@ -131,9 +131,11 @@ export function testFullSubmission(isTribal, isPublic) { // The Report should not be in the dissemination table if (isPublic) { - testReportIdFound(reportId); + testReportIdFoundWithoutTribalAccess(reportId); + testReportIdFoundWithTribalAccess(reportId); } else { - testReportIdNotFound(reportId); + testReportIdNotFoundWithoutTribalAccess(reportId); + testReportIdFoundWithTribalAccess(reportId); } }); diff --git a/backend/cypress/support/initialize-audit.js b/backend/cypress/support/initialize-audit.js index 2c825c2837..7f76430dff 100644 --- a/backend/cypress/support/initialize-audit.js +++ b/backend/cypress/support/initialize-audit.js @@ -2,7 +2,7 @@ import { testValidAccess } from './check-access.js'; import { testValidEligibility } from './check-eligibility.js'; import { testValidAuditeeInfo } from './auditee-info.js'; import { testValidGeneralInfo } from './general-info.js'; -import { testReportIdNotFound } from './dissemination-table.js'; +import { testReportIdNotFoundWithTribalAccess, testReportIdNotFoundWithoutTribalAccess } from './dissemination-table.js'; export function testInitializeAudit(isTribal=false) { // Check the terms and conditions link and click "Accept and start..." @@ -22,7 +22,8 @@ export function testInitializeAudit(isTribal=false) { // Report should not yet be in the dissemination table cy.url().then(url => { const reportId = url.split('/').pop(); - testReportIdNotFound(reportId); + testReportIdNotFoundWithTribalAccess(reportId); + testReportIdNotFoundWithoutTribalAccess(reportId); }); // Fill out the general info form diff --git a/backend/dissemination/api/api/drop.sql b/backend/dissemination/api/api/drop_schema.sql similarity index 100% rename from backend/dissemination/api/api/drop.sql rename to backend/dissemination/api/api/drop_schema.sql diff --git a/backend/support/api/admin_api_v1_0_0/base.sql b/backend/dissemination/api/api_v1_1_0/base.sql similarity index 100% rename from backend/support/api/admin_api_v1_0_0/base.sql rename to backend/dissemination/api/api_v1_1_0/base.sql diff --git a/backend/dissemination/api/api_v1_1_0/create_functions.sql b/backend/dissemination/api/api_v1_1_0/create_functions.sql new file mode 100644 index 0000000000..c6f69ef91b --- /dev/null +++ b/backend/dissemination/api/api_v1_1_0/create_functions.sql @@ -0,0 +1,40 @@ +-- 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." + +-- We don't grant tribal access (yet) +create or replace function api_v1_1_0_functions.has_tribal_data_access() +returns boolean +as $has_tribal_data_access$ +DECLARE + uuid_header UUID; + key_exists boolean; +BEGIN + + SELECT admin_api_v1_1_0_functions.get_api_key_uuid() INTO uuid_header; + SELECT + CASE WHEN EXISTS ( + SELECT key_id + FROM public.dissemination_TribalApiAccessKeyIds taaki + WHERE taaki.key_id = uuid_header::TEXT) + THEN 1::BOOLEAN + ELSE 0::BOOLEAN + END + INTO key_exists; + RETURN key_exists; +END; +$has_tribal_data_access$ LANGUAGE plpgsql; + + +NOTIFY pgrst, 'reload schema'; diff --git a/backend/dissemination/api/api_v1_1_0/create_schema.sql b/backend/dissemination/api/api_v1_1_0/create_schema.sql new file mode 100644 index 0000000000..9075b4aecb --- /dev/null +++ b/backend/dissemination/api/api_v1_1_0/create_schema.sql @@ -0,0 +1,49 @@ +begin; + +do +$$ +begin + DROP SCHEMA IF EXISTS api_v1_1_0 CASCADE; + DROP SCHEMA IF EXISTS api_v1_1_0_functions CASCADE; + + if not exists (select schema_name from information_schema.schemata where schema_name = 'api_v1_1_0') then + create schema api_v1_1_0; + create schema api_v1_1_0_functions; + + grant usage on schema api_v1_1_0_functions to api_fac_gov; + + -- Grant access to tables and views + alter default privileges + in schema api_v1_1_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_1_0 to api_fac_gov; + grant select, usage on all sequences in schema api_v1_1_0 to api_fac_gov; + alter default privileges + in schema api_v1_1_0 + grant select, usage + on sequences + to api_fac_gov; + end if; +end +$$ +; + +-- This is the description +COMMENT ON SCHEMA api_v1_1_0 IS + 'The FAC dissemation API version 1.0.3.' +; + +-- https://postgrest.org/en/stable/references/api/openapi.html +-- This is the title +COMMENT ON SCHEMA api_v1_1_0 IS 'A RESTful API that serves data from the SF-SAC.'; + +commit; + +notify pgrst, + 'reload schema'; + diff --git a/backend/dissemination/api/api_v1_1_0/create_views.sql b/backend/dissemination/api/api_v1_1_0/create_views.sql new file mode 100644 index 0000000000..6cbeb5fbda --- /dev/null +++ b/backend/dissemination/api/api_v1_1_0/create_views.sql @@ -0,0 +1,326 @@ +begin; + +--------------------------------------- +-- finding_text +--------------------------------------- +create view api_v1_1_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 api_v1_1_0_functions.has_tribal_data_access())) + order by ft.id +; + +--------------------------------------- +-- additional_ueis +--------------------------------------- +create view api_v1_1_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 api_v1_1_0_functions.has_tribal_data_access())) + order by uei.id +; + +--------------------------------------- +-- finding +--------------------------------------- +create view api_v1_1_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 api_v1_1_0_functions.has_tribal_data_access())) + order by finding.id +; + +--------------------------------------- +-- federal award +--------------------------------------- +create view api_v1_1_0.federal_awards as + select + award.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 api_v1_1_0_functions.has_tribal_data_access())) + order by award.id +; + + +--------------------------------------- +-- corrective_action_plan +--------------------------------------- +create view api_v1_1_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 api_v1_1_0_functions.has_tribal_data_access())) + order by ct.id +; + +--------------------------------------- +-- notes_to_sefa +--------------------------------------- +create view api_v1_1_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 api_v1_1_0_functions.has_tribal_data_access())) + order by note.id +; + +--------------------------------------- +-- passthrough +--------------------------------------- +create view api_v1_1_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 api_v1_1_0_functions.has_tribal_data_access())) + order by pass.id +; + + +--------------------------------------- +-- general +--------------------------------------- +create view api_v1_1_0.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, + gen.is_additional_ueis, + CASE EXISTS(SELECT ein.report_id FROM dissemination_additionalein ein WHERE ein.report_id = gen.report_id) + WHEN FALSE THEN 'No' + ELSE 'Yes' + END AS is_multiple_eins, + CASE EXISTS(SELECT aud.report_id FROM dissemination_secondaryauditor aud WHERE aud.report_id = gen.report_id) + WHEN FALSE THEN 'No' + ELSE 'Yes' + END AS is_secondary_auditors + from + dissemination_general gen + where + gen.is_public = true + or + (gen.is_public = false and api_v1_1_0_functions.has_tribal_data_access()) + order by gen.id +; + +--------------------------------------- +-- auditor (secondary auditor) +--------------------------------------- +create view api_v1_1_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_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 api_v1_1_0_functions.has_tribal_data_access())) + order by sa.id +; + +create view api_v1_1_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 api_v1_1_0_functions.has_tribal_data_access())) + order by ein.id +; + +commit; + +notify pgrst, + 'reload schema'; + diff --git a/backend/dissemination/api/api_v1_0_3/drop.sql b/backend/dissemination/api/api_v1_1_0/drop_schema.sql similarity index 75% rename from backend/dissemination/api/api_v1_0_3/drop.sql rename to backend/dissemination/api/api_v1_1_0/drop_schema.sql index cf1aca6d91..e32038ee46 100644 --- a/backend/dissemination/api/api_v1_0_3/drop.sql +++ b/backend/dissemination/api/api_v1_1_0/drop_schema.sql @@ -1,7 +1,7 @@ begin; -DROP SCHEMA IF EXISTS api_v1_0_3 CASCADE; +DROP SCHEMA IF EXISTS api_v1_1_0 CASCADE; -- DROP ROLE IF EXISTS authenticator; -- DROP ROLE IF EXISTS api_fac_gov; diff --git a/backend/dissemination/api/api_v1_1_0/drop_views.sql b/backend/dissemination/api/api_v1_1_0/drop_views.sql new file mode 100644 index 0000000000..877d5920c6 --- /dev/null +++ b/backend/dissemination/api/api_v1_1_0/drop_views.sql @@ -0,0 +1,17 @@ +begin; + drop table if exists api_v1_1_0.metadata; + drop view if exists api_v1_1_0.general; + drop view if exists api_v1_1_0.auditor; + drop view if exists api_v1_1_0.federal_awards; + drop view if exists api_v1_1_0.findings; + drop view if exists api_v1_1_0.findings_text; + drop view if exists api_v1_1_0.corrective_action_plans; + drop view if exists api_v1_1_0.additional_ueis; + drop view if exists api_v1_1_0.notes_to_sefa; + drop view if exists api_v1_1_0.passthrough; + drop view if exists api_v1_1_0.secondary_auditors; + drop view if exists api_v1_1_0.additional_eins; +commit; + +notify pgrst, + 'reload schema'; diff --git a/backend/dissemination/api_versions.py b/backend/dissemination/api_versions.py index 0579639905..1c21efbab7 100644 --- a/backend/dissemination/api_versions.py +++ b/backend/dissemination/api_versions.py @@ -5,7 +5,7 @@ logger = logging.getLogger(__name__) # These are API versions we want live. -live = {"dissemination": ["api_v1_0_3"], "support": ["admin_api_v1_0_0"]} +live = {"dissemination": ["api_v1_0_3", "api_v1_1_0"], "support": ["admin_api_v1_1_0"]} # These are API versions we have deprecated. # They will be removed. It should be safe to leave them @@ -79,7 +79,7 @@ def create_functions(location): def deprecate_schemas_and_views(location): for version in deprecated[location]: - exec_sql(location, version, "drop.sql") + exec_sql(location, version, "drop_schema.sql") def create_access_tables(location): diff --git a/backend/dissemination/migrations/0014_tribalapiaccesskeyids.py b/backend/dissemination/migrations/0014_tribalapiaccesskeyids.py new file mode 100644 index 0000000000..954c7480bf --- /dev/null +++ b/backend/dissemination/migrations/0014_tribalapiaccesskeyids.py @@ -0,0 +1,35 @@ +# Generated by Django 4.2.6 on 2024-02-20 21:57 + +from django.db import migrations, models + + +class Migration(migrations.Migration): + dependencies = [ + ("dissemination", "0013_alter_additionalein_report_id_and_more"), + ] + + operations = [ + migrations.CreateModel( + name="TribalApiAccessKeyIds", + fields=[ + ( + "id", + models.BigAutoField( + auto_created=True, + primary_key=True, + serialize=False, + verbose_name="ID", + ), + ), + ( + "email", + models.TextField(unique=True, verbose_name="Email of the user"), + ), + ("key_id", models.TextField(verbose_name="Key ID for the api access")), + ( + "date_added", + models.DateField(verbose_name="Added date of the record"), + ), + ], + ), + ] diff --git a/backend/dissemination/models.py b/backend/dissemination/models.py index c9cd073e7f..1de4f46d5a 100644 --- a/backend/dissemination/models.py +++ b/backend/dissemination/models.py @@ -592,6 +592,19 @@ class OneTimeAccess(models.Model): ) +class TribalApiAccessKeyIds(models.Model): + email = models.TextField( + "Email of the user", + unique=True, + ) + key_id = models.TextField( + "Key ID for the api access", + ) + date_added = models.DateField( + "Added date of the record", + ) + + class MigrationInspectionRecord(models.Model): audit_year = models.TextField(blank=True, null=True) dbkey = models.TextField(blank=True, null=True) diff --git a/backend/docker-compose-web.yml b/backend/docker-compose-web.yml index b4bd92c743..610b95c2cf 100644 --- a/backend/docker-compose-web.yml +++ b/backend/docker-compose-web.yml @@ -75,7 +75,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, admin_api_v1_0_0" + PGRST_DB_SCHEMAS: "api_v1_0_3, api_v1_1_0, admin_api_v1_1_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 e15b9bba58..5c406ab336 100644 --- a/backend/docker-compose.yml +++ b/backend/docker-compose.yml @@ -109,7 +109,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, admin_api_v1_0_0" + PGRST_DB_SCHEMAS: "api_v1_0_3, api_v1_1_0, admin_api_v1_1_0" PGRST_JWT_SECRET: ${PGRST_JWT_SECRET:-32_chars_fallback_secret_testing} # Fallback value for testing environments # Enable this to inspect the DB plans for queries via EXPLAIN PGRST_DB_PLAN_ENABLED: ${PGRST_DB_PLAN_ENABLED:-false} diff --git a/backend/support/api/admin_api_v1_0_0/drop.sql b/backend/support/api/admin_api_v1_0_0/drop.sql deleted file mode 100644 index 1b45ddc3df..0000000000 --- a/backend/support/api/admin_api_v1_0_0/drop.sql +++ /dev/null @@ -1,9 +0,0 @@ - -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_1_0/base.sql b/backend/support/api/admin_api_v1_1_0/base.sql new file mode 100644 index 0000000000..dedabe0cb7 --- /dev/null +++ b/backend/support/api/admin_api_v1_1_0/base.sql @@ -0,0 +1,29 @@ +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/support/api/admin_api_v1_0_0/create_access_tables.sql b/backend/support/api/admin_api_v1_1_0/create_access_tables.sql similarity index 97% rename from backend/support/api/admin_api_v1_0_0/create_access_tables.sql rename to backend/support/api/admin_api_v1_1_0/create_access_tables.sql index c392adc2bc..ce9dda43ee 100644 --- a/backend/support/api/admin_api_v1_0_0/create_access_tables.sql +++ b/backend/support/api/admin_api_v1_1_0/create_access_tables.sql @@ -35,7 +35,7 @@ INSERT INTO support_administrative_key_uuids ( 'timothy.ballard@gsa.gov', '1e2845a0-c844-4a6f-84ac-f398b58ce7c9', - 'READ', + '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_1_0/create_functions.sql similarity index 59% rename from backend/support/api/admin_api_v1_0_0/create_functions.sql rename to backend/support/api/admin_api_v1_1_0/create_functions.sql index 8b7782884b..2a641f2931 100644 --- a/backend/support/api/admin_api_v1_0_0/create_functions.sql +++ b/backend/support/api/admin_api_v1_1_0/create_functions.sql @@ -16,7 +16,7 @@ begin; -CREATE OR REPLACE FUNCTION admin_api_v1_0_0_functions.get_header(item text) RETURNS text +CREATE OR REPLACE FUNCTION admin_api_v1_1_0_functions.get_header(item text) RETURNS text AS $get_header$ declare res text; begin @@ -25,11 +25,11 @@ CREATE OR REPLACE FUNCTION admin_api_v1_0_0_functions.get_header(item text) RETU end; $get_header$ LANGUAGE plpgsql; -create or replace function admin_api_v1_0_0_functions.get_api_key_uuid() returns TEXT +create or replace function admin_api_v1_1_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; + select admin_api_v1_1_0_functions.get_header('x-api-user-id') into uuid; return uuid; end; $gaku$ LANGUAGE plpgsql; @@ -37,13 +37,13 @@ $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) +create or replace function admin_api_v1_1_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; + SELECT admin_api_v1_1_0_functions.get_api_key_uuid() INTO uuid_header; INSERT INTO public.support_adminapievent (api_key_uuid, event, event_data, "timestamp") @@ -59,14 +59,14 @@ $log_admin_api_event$ LANGUAGE plpgsql; -- 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 +create or replace function admin_api_v1_1_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 admin_api_v1_1_0_functions.get_api_key_uuid() INTO uuid_header; SELECT CASE WHEN EXISTS ( @@ -105,7 +105,7 @@ $has_admin_data_access$ LANGUAGE plpgsql; -- ### 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-profile: admin_api_v1_1_0 -- content-type: application/json -- Prefer: params=single-object -- // Not actually a key UUID. @@ -113,7 +113,7 @@ $has_admin_data_access$ LANGUAGE plpgsql; -- { -- "email": "darth.vader@deathstar.org" -- } -create or replace function admin_api_v1_0_0.add_tribal_access_email(params JSON) +create or replace function admin_api_v1_1_0.add_tribal_access_email(params JSON) returns BOOLEAN as $add_tribal_access_email$ DECLARE @@ -121,7 +121,7 @@ DECLARE 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') + IF admin_api_v1_1_0_functions.has_admin_data_access('CREATE') THEN -- Are they already in the table? SELECT count(up.email) @@ -147,7 +147,7 @@ BEGIN 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', + RETURN admin_api_v1_1_0_functions.log_admin_api_event('tribal-access-email-added', json_build_object('email', params->>'email')); END IF; ELSE @@ -161,7 +161,7 @@ $add_tribal_access_email$ LANGUAGE plpgsql; -- ### 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-profile: admin_api_v1_1_0 -- content-type: application/json -- Prefer: params=single-object -- // Not actually a key UUID. @@ -174,21 +174,21 @@ $add_tribal_access_email$ LANGUAGE plpgsql; -- "bob@deathstar.org" -- ] -- } -CREATE OR REPLACE FUNCTION admin_api_v1_0_0.add_tribal_access_emails(params JSON) +CREATE OR REPLACE FUNCTION admin_api_v1_1_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') + IF admin_api_v1_1_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); + PERFORM admin_api_v1_1_0.add_tribal_access_email(json_build_object('email', em.ele)::JSON); END LOOP; RETURN 1; END IF; @@ -201,7 +201,7 @@ $add_tribal_access_emails$ LANGUAGE plpgsql; -- ### 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-profile: admin_api_v1_1_0 -- content-type: application/json -- Prefer: params=single-object -- // Not actually a key UUID. @@ -209,14 +209,14 @@ $add_tribal_access_emails$ LANGUAGE plpgsql; -- { -- "email": "darth.vader@deathstar.org" -- } -CREATE OR REPLACE FUNCTION admin_api_v1_0_0.remove_tribal_access_email(params JSON) +CREATE OR REPLACE FUNCTION admin_api_v1_1_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') + IF admin_api_v1_1_0_functions.has_admin_data_access('DELETE') THEN -- Delete rows where the email address matches DELETE FROM public.users_userpermission as up @@ -227,7 +227,7 @@ BEGIN -- 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', + RETURN admin_api_v1_1_0_functions.log_admin_api_event('tribal-access-email-removed', json_build_object('email', params->>'email')); ELSE RETURN 0; @@ -244,7 +244,7 @@ $remove_tribal_access_email$ LANGUAGE plpgsql; -- ### 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-profile: admin_api_v1_1_0 -- content-type: application/json -- Prefer: params=single-object -- // Not actually a key UUID. @@ -257,18 +257,18 @@ $remove_tribal_access_email$ LANGUAGE plpgsql; -- "bob@deathstar.org" -- ] -- } -CREATE OR REPLACE FUNCTION admin_api_v1_0_0.remove_tribal_access_emails(params JSON) +CREATE OR REPLACE FUNCTION admin_api_v1_1_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') + IF admin_api_v1_1_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); + PERFORM admin_api_v1_1_0.remove_tribal_access_email(json_build_object('email', em.ele)::JSON); END LOOP; RETURN 1; END IF; @@ -276,6 +276,130 @@ BEGIN END; $remove_tribal_access_emails$ LANGUAGE plpgsql; + + + +--The function below add_tribal_api_key_access adds read access to a tribal API for a specified email. +--It checks if the API user has read permissions. +--If the email already exists in the database, the function returns false. +--Otherwise, it adds the email with 'read-tribal' permission, logs the event, and returns true. + +CREATE OR REPLACE FUNCTION admin_api_v1_1_0.add_tribal_api_key_access(params JSON) +RETURNS BOOLEAN +AS $add_tribal_api_key_access$ +DECLARE + user_exists BOOLEAN; +BEGIN + -- If the API user has read permissions, give it a go + IF admin_api_v1_1_0_functions.has_admin_data_access('CREATE') THEN + -- Check if the user with the given email + SELECT EXISTS ( + SELECT 1 + FROM public.dissemination_TribalApiAccessKeyIds + WHERE email = params->>'email' + ) + INTO user_exists; + + -- If the user exists, return false (indicating failure) + IF user_exists THEN + RETURN false; + END IF; + + -- If the user does not exist, add a new record + INSERT INTO public.dissemination_TribalApiAccessKeyIds (email, key_id, date_added) + VALUES (params->>'email', params->>'key_id', CURRENT_TIMESTAMP); + + END IF; + + RETURN true; -- Return true to indicate success +END; +$add_tribal_api_key_access$ LANGUAGE plpgsql; + +-- The function below removes tribal API key access for a specified email. +-- It checks if the API user has read permissions. +-- If the email exists in the database with 'read-tribal' permission, it removes the entry, logs the removal event, and returns true. +-- If the email doesn't exist or the user lacks proper permissions, the function returns false. + +CREATE OR REPLACE FUNCTION admin_api_v1_1_0.remove_tribal_api_key_access(params JSON) +RETURNS BOOLEAN +AS $remove_tribal_api_key_access$ +DECLARE + user_exists BOOLEAN; +BEGIN + -- If the API user has read permissions, give it a go + IF admin_api_v1_1_0_functions.has_admin_data_access('DELETE') THEN + -- Check if the user with the given email exists + SELECT EXISTS ( + SELECT 1 + FROM public.dissemination_TribalApiAccessKeyIds + WHERE email = params->>'email' + ) + INTO user_exists; + + -- If the user exists, remove the record + IF user_exists THEN + DELETE FROM public.dissemination_TribalApiAccessKeyIds + WHERE email = params->>'email'; + RETURN true; -- Return true to indicate success + ELSE + RETURN false; -- Return false to indicate failure + END IF; + ELSE + RETURN false; -- Return false if the API user doesn't have read permissions + END IF; +END; +$remove_tribal_api_key_access$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION admin_api_v1_1_0.request_file_access( + report_id TEXT +) RETURNS JSON LANGUAGE plpgsql AS +$$ +DECLARE + v_uuid_header TEXT; + v_access_uuid VARCHAR(200); + v_key_exists BOOLEAN; + v_key_added_date DATE; +BEGIN + + SELECT admin_api_v1_1_0_functions.get_api_key_uuid() INTO v_uuid_header; + + -- Check if the provided API key exists in public.dissemination_TribalApiAccessKeyIds + SELECT + EXISTS( + SELECT 1 + FROM public.dissemination_TribalApiAccessKeyIds + WHERE key_id = v_uuid_header + ) INTO v_key_exists; + + + -- Get the added date of the key from public.dissemination_TribalApiAccessKeyIds + SELECT date_added + INTO v_key_added_date + FROM public.dissemination_TribalApiAccessKeyIds + WHERE key_id = v_uuid_header; + + + -- Check if the key is less than 6 months old + IF v_uuid_header IS NOT NULL AND v_key_exists AND v_key_added_date >= CURRENT_DATE - INTERVAL '6 months' THEN + -- Generate UUID (using PostgreSQL's gen_random_uuid function) + SELECT gen_random_uuid() INTO v_access_uuid; + + -- Inserting data into the one_time_access table + INSERT INTO public.dissemination_onetimeaccess (uuid, api_key_id, timestamp, report_id) + VALUES (v_access_uuid::UUID, v_uuid_header, CURRENT_TIMESTAMP, report_id); + + -- Return the UUID to the user + RETURN json_build_object('access_uuid', v_access_uuid); + ELSE + -- Return an error for unauthorized access + RETURN json_build_object('error', 'Unauthorized access or key older than 6 months')::JSON; + END IF; +END; +$$; + + + 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_1_0/create_schema.sql similarity index 67% rename from backend/support/api/admin_api_v1_0_0/create_schema.sql rename to backend/support/api/admin_api_v1_1_0/create_schema.sql index 325d868bb8..25f913689d 100644 --- a/backend/support/api/admin_api_v1_0_0/create_schema.sql +++ b/backend/support/api/admin_api_v1_1_0/create_schema.sql @@ -3,28 +3,28 @@ begin; do $$ begin - DROP SCHEMA IF EXISTS admin_api_v1_0_0 CASCADE; - DROP SCHEMA IF EXISTS admin_api_v1_0_0_functions CASCADE; + DROP SCHEMA IF EXISTS admin_api_v1_1_0 CASCADE; + DROP SCHEMA IF EXISTS admin_api_v1_1_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; + if not exists (select schema_name from information_schema.schemata where schema_name = 'admin_api_v1_1_0') then + create schema admin_api_v1_1_0; + create schema admin_api_v1_1_0_functions; - grant usage on schema admin_api_v1_0_0_functions to api_fac_gov; + grant usage on schema admin_api_v1_1_0_functions to api_fac_gov; -- Grant access to tables and views alter default privileges - in schema admin_api_v1_0_0 + in schema admin_api_v1_1_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; + grant usage on schema admin_api_v1_1_0 to api_fac_gov; + grant select, usage on all sequences in schema admin_api_v1_1_0 to api_fac_gov; alter default privileges - in schema admin_api_v1_0_0 + in schema admin_api_v1_1_0 grant select, usage on sequences to api_fac_gov; @@ -41,6 +41,9 @@ begin 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; + + GRANT INSERT, SELECT, DELETE on public.dissemination_tribalapiaccesskeyids to api_fac_gov; + GRANT INSERT on public.dissemination_onetimeaccess to api_fac_gov; end if; end $$ diff --git a/backend/support/api/admin_api_v1_0_0/create_views.sql b/backend/support/api/admin_api_v1_1_0/create_views.sql similarity index 76% rename from backend/support/api/admin_api_v1_0_0/create_views.sql rename to backend/support/api/admin_api_v1_1_0/create_views.sql index bed57b4ad6..04b747662f 100644 --- a/backend/support/api/admin_api_v1_0_0/create_views.sql +++ b/backend/support/api/admin_api_v1_1_0/create_views.sql @@ -11,7 +11,7 @@ begin; -- DROP TABLE public.audit_access; -CREATE OR REPLACE VIEW admin_api_v1_0_0.audit_access AS +CREATE OR REPLACE VIEW admin_api_v1_1_0.audit_access AS SELECT aa.role, aa.fullname, @@ -21,11 +21,11 @@ CREATE OR REPLACE VIEW admin_api_v1_0_0.audit_access AS FROM public.audit_access aa WHERE - admin_api_v1_0_0_functions.has_admin_data_access('READ') + admin_api_v1_1_0_functions.has_admin_data_access('READ') ORDER BY aa.id ; -CREATE OR REPLACE VIEW admin_api_v1_0_0.singleauditchecklist AS +CREATE OR REPLACE VIEW admin_api_v1_1_0.singleauditchecklist AS SELECT sac.id, sac.date_created, @@ -54,11 +54,11 @@ CREATE OR REPLACE VIEW admin_api_v1_0_0.singleauditchecklist AS from public.audit_singleauditchecklist sac where - admin_api_v1_0_0_functions.has_admin_data_access('READ') + admin_api_v1_1_0_functions.has_admin_data_access('READ') order by sac.id ; -CREATE OR REPLACE VIEW admin_api_v1_0_0.tribal_access AS +CREATE OR REPLACE VIEW admin_api_v1_1_0.tribal_access AS SELECT uup.email, up.slug as permission @@ -68,11 +68,11 @@ CREATE OR REPLACE VIEW admin_api_v1_0_0.tribal_access AS WHERE (uup.permission_id = up.id) AND (up.slug = 'read-tribal') - AND admin_api_v1_0_0_functions.has_admin_data_access('READ') + AND admin_api_v1_1_0_functions.has_admin_data_access('READ') ORDER BY uup.id ; -CREATE OR REPLACE VIEW admin_api_v1_0_0.admin_api_events AS +CREATE OR REPLACE VIEW admin_api_v1_1_0.admin_api_events AS SELECT ae.timestamp, ae.api_key_uuid, @@ -81,7 +81,7 @@ CREATE OR REPLACE VIEW admin_api_v1_0_0.admin_api_events AS FROM public.support_adminapievent ae WHERE - admin_api_v1_0_0_functions.has_admin_data_access('READ') + admin_api_v1_1_0_functions.has_admin_data_access('READ') ORDER BY ae.id ; diff --git a/backend/support/api/admin_api_v1_0_0/drop_schema.sql b/backend/support/api/admin_api_v1_1_0/drop_schema.sql similarity index 54% rename from backend/support/api/admin_api_v1_0_0/drop_schema.sql rename to backend/support/api/admin_api_v1_1_0/drop_schema.sql index 1b45ddc3df..b0d4cc1109 100644 --- a/backend/support/api/admin_api_v1_0_0/drop_schema.sql +++ b/backend/support/api/admin_api_v1_1_0/drop_schema.sql @@ -1,7 +1,7 @@ begin; -DROP SCHEMA IF EXISTS admin_api_v1_0_0 CASCADE; +DROP SCHEMA IF EXISTS admin_api_v1_1_0 CASCADE; commit; diff --git a/backend/support/api/admin_api_v1_0_0/drop_views.sql b/backend/support/api/admin_api_v1_1_0/drop_views.sql similarity index 51% rename from backend/support/api/admin_api_v1_0_0/drop_views.sql rename to backend/support/api/admin_api_v1_1_0/drop_views.sql index a49a02cb79..8e8e9b55ab 100644 --- a/backend/support/api/admin_api_v1_0_0/drop_views.sql +++ b/backend/support/api/admin_api_v1_1_0/drop_views.sql @@ -1,6 +1,6 @@ begin; - drop table if exists admin_api_v1_0_0.audit_access; + drop table if exists admin_api_v1_1_0.audit_access; commit; diff --git a/backend/support/api/admin_api_v1_0_0/test.rest b/backend/support/api/admin_api_v1_1_0/test.rest similarity index 91% rename from backend/support/api/admin_api_v1_0_0/test.rest rename to backend/support/api/admin_api_v1_1_0/test.rest index d80c517f37..16e6ab054c 100644 --- a/backend/support/api/admin_api_v1_0_0/test.rest +++ b/backend/support/api/admin_api_v1_1_0/test.rest @@ -18,13 +18,13 @@ GET {{scheme}}://{{api_url}}/audit_access 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 +accept-profile: admin_api_v1_1_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 +accept-profile: admin_api_v1_1_0 x-api-key: {{$processEnv API_GOV_KEY}} ### @@ -32,7 +32,7 @@ x-api-key: {{$processEnv API_GOV_KEY}} 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 +accept-profile: admin_api_v1_1_0 x-api-key: {{$processEnv API_GOV_KEY}} @@ -41,7 +41,7 @@ x-api-key: {{$processEnv API_GOV_KEY}} 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-profile: admin_api_v1_1_0 content-type: application/json Prefer: params=single-object x-api-key: {{$processEnv API_GOV_KEY}} @@ -55,7 +55,7 @@ x-api-key: {{$processEnv API_GOV_KEY}} 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-profile: admin_api_v1_1_0 content-type: application/json Prefer: params=single-object x-api-key: {{$processEnv API_GOV_KEY}} @@ -74,7 +74,7 @@ x-api-key: {{$processEnv API_GOV_KEY}} 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-profile: admin_api_v1_1_0 content-type: application/json Prefer: params=single-object x-api-key: {{$processEnv API_GOV_KEY}} @@ -89,7 +89,7 @@ x-api-key: {{$processEnv API_GOV_KEY}} 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-profile: admin_api_v1_1_0 content-type: application/json Prefer: params=single-object x-api-key: {{$processEnv API_GOV_KEY}} @@ -109,6 +109,6 @@ x-api-key: {{$processEnv API_GOV_KEY}} 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 +accept-profile: admin_api_v1_1_0 x-api-key: {{$processEnv API_GOV_KEY}} diff --git a/backend/support/test_admin_api.py b/backend/support/test_admin_api.py index f54c790a05..f13a5d1e03 100644 --- a/backend/support/test_admin_api.py +++ b/backend/support/test_admin_api.py @@ -12,7 +12,7 @@ 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" + admin_api_version = "admin_api_v1_1_0" def get_connection(self): cloudgov = ["DEVELOPMENT", "PREVIEW", "STAGING", "PRODUCTION"] diff --git a/docs/testing.md b/docs/testing.md index 2718acc770..7848a68b28 100644 --- a/docs/testing.md +++ b/docs/testing.md @@ -11,9 +11,12 @@ We use [Django's test execution framework](https://docs.djangoproject.com/en/4.0 - [Writing new tests](#writing-new-tests) - [Testing Actions Locally](#testing-actions-locally) - [Accessibility](#accessibility) - - [Security Scans](#security-scans) + - [Security scans](#security-scans) + - [OWASP ZAP](#owasp-zap) + - [Bandit](#bandit) - [Linting](#linting) - [End-to-end testing](#end-to-end-testing) + - [Testing behind Login.gov](#testing-behind-logingov) ## Packages - [model_bakery](https://model-bakery.readthedocs.io/en/latest/), to help create data and instances within our tests @@ -125,9 +128,11 @@ in files in [backend/cypress/e2e/](/backend/cypress/e2e). To run these tests: - [Create a testing login.gov account](https://github.com/GSA-TTS/FAC/blob/main/docs/testing.md#testing-behind-logingov) - [Set up the fac() alias](https://github.com/GSA-TTS/FAC/blob/main/docs/development.md?plain=1#L125) - [Generate a new JWT](https://github.com/GSA-TTS/FAC/blob/main/backend/dissemination/README.md#creating-a-jwt-secret) -- `CYPRESS_LOGIN_TEST_EMAIL='' CYPRESS_LOGIN_TEST_PASSWORD='' CYPRESS_LOGIN_TEST_OTP_SECRET='' CYPRESS_LOGIN_TEST_EMAIL_AUDITEE='' CYPRESS_LOGIN_TEST_PASSWORD_AUDITEE='' CYPRESS_LOGIN_TEST_OTP_SECRET_AUDITEE='' CYPRESS_API_GOV_JWT='' CYPRESS_API_GOV_URL='localhost:3000' npx cypress open` +- `CYPRESS_LOGIN_TEST_EMAIL='' CYPRESS_LOGIN_TEST_PASSWORD='' CYPRESS_LOGIN_TEST_OTP_SECRET='' CYPRESS_LOGIN_TEST_EMAIL_AUDITEE='' CYPRESS_LOGIN_TEST_PASSWORD_AUDITEE='' CYPRESS_LOGIN_TEST_OTP_SECRET_AUDITEE='' CYPRESS_API_GOV_JWT='' CYPRESS_API_GOV_URL='localhost:3000' CYPRESS_API_GOV_USER_ID_ADMIN='' CYPRESS_ADMIN_API_VERSION='' npx cypress open` - Note: All of this goes on one line - *: These fields can be found in the [FAC dev keys Google doc](https://docs.google.com/spreadsheets/d/1byrBp16jufbiEY_GP5MyR0Uqf6WvB_5tubSXN_mYyJY/edit#gid=0) + - **: This field can be the UUID associated with any of the [users with administrative privileges](https://github.com/GSA-TTS/FAC/blob/main/backend/support/api/admin_api_v1_0_0/create_access_tables.sql) + - ***: This current value for this field can be found [here](https://github.com/GSA-TTS/FAC/blob/1af236093cab16beb783eec4021b162f04c90840/backend/docker-compose.yml#L112) - Click `E2E Testing` - Select `Chrome` and click `Start E2E Testing in Chrome` diff --git a/terraform/shared/modules/env/postgrest.tf b/terraform/shared/modules/env/postgrest.tf index 30c37a9532..c01436e510 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,admin_api_v1_0_0" + PGRST_DB_SCHEMAS : "api_v1_0_3,api_v1_1_0,admin_api_v1_1_0" PGRST_DB_ANON_ROLE : "anon" PGRST_JWT_SECRET : var.pgrst_jwt_secret PGRST_DB_MAX_ROWS : 20000