diff --git a/.github/workflows/add-bpmn-renders.yml b/.github/workflows/add-bpmn-renders.yml index 10b879535e..14aee9ab2e 100644 --- a/.github/workflows/add-bpmn-renders.yml +++ b/.github/workflows/add-bpmn-renders.yml @@ -50,7 +50,7 @@ jobs: - name: Create Pull Request with Changes if: steps.vars.outputs.imagesupdated != 0 - uses: peter-evans/create-pull-request@v6 + uses: peter-evans/create-pull-request@v7 with: commit-message: Update BPMN images for ${{ env.BRANCH_NAME }} title: Update BPMN images for ${{ env.BRANCH_NAME }} diff --git a/.github/workflows/new-relic-deployment.yml b/.github/workflows/new-relic-deployment.yml index 61977f0ec0..f3f347f88a 100644 --- a/.github/workflows/new-relic-deployment.yml +++ b/.github/workflows/new-relic-deployment.yml @@ -16,7 +16,7 @@ jobs: run: echo "RELEASE_VERSION=${{ github.ref_name }}" >> $GITHUB_ENV - name: Add New Relic Application Deployment Marker - uses: newrelic/deployment-marker-action@v2.5.0 + uses: newrelic/deployment-marker-action@v2.5.1 with: apiKey: ${{ secrets.NEW_RELIC_API_KEY }} guid: ${{ secrets.NEW_RELIC_DEV_DEPLOYMENT_ENTITY_GUID }} @@ -32,7 +32,7 @@ jobs: run: echo "RELEASE_VERSION=${{ github.ref_name }}" >> $GITHUB_ENV - name: Add New Relic Application Deployment Marker - uses: newrelic/deployment-marker-action@v2.5.0 + uses: newrelic/deployment-marker-action@v2.5.1 with: apiKey: ${{ secrets.NEW_RELIC_API_KEY }} guid: ${{ secrets.NEW_RELIC_STAGING_DEPLOYMENT_ENTITY_GUID }} @@ -48,7 +48,7 @@ jobs: run: echo "RELEASE_VERSION=${{ github.ref_name }}" >> $GITHUB_ENV - name: Add New Relic Application Deployment Marker - uses: newrelic/deployment-marker-action@v2.5.0 + uses: newrelic/deployment-marker-action@v2.5.1 with: apiKey: ${{ secrets.NEW_RELIC_API_KEY }} guid: ${{ secrets.NEW_RELIC_PRODUCTION_DEPLOYMENT_ENTITY_GUID }} diff --git a/backend/dissemination/README.md b/backend/dissemination/README.md index 7e9186949b..2b6aedd4dd 100644 --- a/backend/dissemination/README.md +++ b/backend/dissemination/README.md @@ -96,6 +96,50 @@ When adding a new API version: - This is likely true of TESTED patch version bumps (v1_0_0 to v1_0_1), and *maybe* minor version bumps (v1_0_0 to v1_1_0). MAJOR bumps require change management messaging. 5. If previous versions of the API are needed, `APIViewTests` will need to be updated. At the time of writing this, it only tests the default API. +# Using VS Code REST Client Plugin to Test API + +## Installation: +1. In your Visual Studio Code, go to the Extensions Marketplace and search for **REST Client**. +4. Click **Install** and follow the steps to install one of the "REST Client". + +## How to Use: +Once the REST Client extension is installed, you can create a `.http` or `.rest` file in your project and write your API queries directly within that file. + +## Sample API Request: + +Here’s an example of how to query your API using the REST Client: + +```http +GET {{scheme}}://{{api_url}}/function_name_or_view_name_plus_params_if_any +authorization: Bearer {{YOUR_JWT_TOKEN}} +x-api-user-id: {{your_api_user_id}} +accept-profile: target_api_profile +x-api-key: {{YOUR_API_GOV_KEY}} +``` + +## Key Details: +- **`authorization`**: The `Bearer {{YOUR_JWT_TOKEN}}` token is mandatory. Use the same JWT token used in Cypress tests from the code base. Without this token, the request will be flagged as anonymous and require extra steps to create an anonymous role in the local environment. + +- **`x-api-user-id`**: Mandatory in some cases, depending on the API function. Search for the function in the code base to find where to get the correct value for `x-api-user-id`. Check keys like `support_administrative_key_uuids` and `dissemination_tribalapiaccesskeyids` for reference. + +- **`accept-profile`**: Specifies the API version/profile. The current default is `api_v1_0_3`. You can check available profiles and deprecated versions in `backend/dissemination/api_versions.py`. + +- **`x-api-key`**: An API key can be requested by following the steps described [here](https://www.fac.gov/api/). + +## Example: + +```http +GET http://localhost:3000/general?limit=1&is_public=eq.false +authorization: Bearer {{CYPRESS_API_GOV_JWT}} +x-api-user-id: 00112233-4455-6677-8899-aabbccddeeff +accept-profile: admin_api_v1_1_0 +x-api-key: abcdefghijklmnop +``` + +This will send a request to `http://localhost:3000/general` with the provided headers and params. +Check `backend/support/api/admin_api_v1_1_0/` for more examples. + + # End-to-end workbook testing ### How to run the end-to-end test data generator: diff --git a/backend/dissemination/api/api_v1_1_1/create_functions.sql b/backend/dissemination/api/api_v1_1_1/create_functions.sql index a3e772cec6..87114cd660 100644 --- a/backend/dissemination/api/api_v1_1_1/create_functions.sql +++ b/backend/dissemination/api/api_v1_1_1/create_functions.sql @@ -56,4 +56,51 @@ END; $has_tribal_data_access$ LANGUAGE plpgsql; +CREATE OR REPLACE FUNCTION api_v1_1_1.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 api_v1_1_1_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; +$$; + NOTIFY pgrst, 'reload schema'; diff --git a/backend/package-lock.json b/backend/package-lock.json index 0cbbdf11ac..e04aff51b0 100644 --- a/backend/package-lock.json +++ b/backend/package-lock.json @@ -15,19 +15,19 @@ "esbuild-sass-plugin": "3.3.1", "glob": "11.0.0", "npm-run-all": "^4.1.5", - "postcss": "^8.4.41", + "postcss": "^8.4.45", "postcss-cli": "^11.0.0" }, "devDependencies": { "@4tw/cypress-drag-drop": "^2.2.5", "@babel/eslint-parser": "^7.25.1", - "@eslint/js": "^9.9.1", - "cypress": "^13.14.0", + "@eslint/js": "^9.10.0", + "cypress": "^13.14.2", "cypress-axe": "^1.5.0", "cypress-downloadfile": "^1.2.4", "cypress-file-upload": "^5.0.8", "cypress-otp": "^1.0.3", - "eslint": "^9.9.1", + "eslint": "^9.10.0", "eslint-config-prettier": "^9.1.0", "eslint-plugin-cypress": "^3.5.0", "eslint-plugin-prettier": "^5.2.1", @@ -990,9 +990,9 @@ } }, "node_modules/@eslint/js": { - "version": "9.9.1", - "resolved": "https://registry.npmjs.org/@eslint/js/-/js-9.9.1.tgz", - "integrity": "sha512-xIDQRsfg5hNBqHz04H1R3scSVwmI+KUbqjsQKHKQ1DAUSaUjYPReZZmS/5PNiKu1fUvzDd6H7DEDKACSEhu+TQ==", + "version": "9.10.0", + "resolved": "https://registry.npmjs.org/@eslint/js/-/js-9.10.0.tgz", + "integrity": "sha512-fuXtbiP5GWIn8Fz+LWoOMVf/Jxm+aajZYkhi6CuEm4SxymFM+eUWzbO9qXT+L0iCkL5+KGYMCSGxo686H19S1g==", "dev": true, "engines": { "node": "^18.18.0 || ^20.9.0 || >=21.1.0" @@ -1007,6 +1007,18 @@ "node": "^18.18.0 || ^20.9.0 || >=21.1.0" } }, + "node_modules/@eslint/plugin-kit": { + "version": "0.1.0", + "resolved": "https://registry.npmjs.org/@eslint/plugin-kit/-/plugin-kit-0.1.0.tgz", + "integrity": "sha512-autAXT203ixhqei9xt+qkYOvY8l6LAFIdT2UXc/RPNeUVfqRF1BV94GTJyVPFKT8nFM6MyVJhjLj9E8JWvf5zQ==", + "dev": true, + "dependencies": { + "levn": "^0.4.1" + }, + "engines": { + "node": "^18.18.0 || ^20.9.0 || >=21.1.0" + } + }, "node_modules/@humanwhocodes/module-importer": { "version": "1.0.1", "resolved": "https://registry.npmjs.org/@humanwhocodes/module-importer/-/module-importer-1.0.1.tgz", @@ -2248,9 +2260,9 @@ } }, "node_modules/cypress": { - "version": "13.14.0", - "resolved": "https://registry.npmjs.org/cypress/-/cypress-13.14.0.tgz", - "integrity": "sha512-r0+nhd033x883YL6068futewUsl02Q7rWiinyAAIBDW/OOTn+UMILWgNuCiY3vtJjd53efOqq5R9dctQk/rKiw==", + "version": "13.14.2", + "resolved": "https://registry.npmjs.org/cypress/-/cypress-13.14.2.tgz", + "integrity": "sha512-lsiQrN17vHMB2fnvxIrKLAjOr9bPwsNbPZNrWf99s4u+DVmCY6U+w7O3GGG9FvP4EUVYaDu+guWeNLiUzBrqvA==", "dev": true, "hasInstallScript": true, "dependencies": { @@ -2914,16 +2926,17 @@ } }, "node_modules/eslint": { - "version": "9.9.1", - "resolved": "https://registry.npmjs.org/eslint/-/eslint-9.9.1.tgz", - "integrity": "sha512-dHvhrbfr4xFQ9/dq+jcVneZMyRYLjggWjk6RVsIiHsP8Rz6yZ8LvZ//iU4TrZF+SXWG+JkNF2OyiZRvzgRDqMg==", + "version": "9.10.0", + "resolved": "https://registry.npmjs.org/eslint/-/eslint-9.10.0.tgz", + "integrity": "sha512-Y4D0IgtBZfOcOUAIQTSXBKoNGfY0REGqHJG6+Q81vNippW5YlKjHFj4soMxamKK1NXHUWuBZTLdU3Km+L/pcHw==", "dev": true, "dependencies": { "@eslint-community/eslint-utils": "^4.2.0", "@eslint-community/regexpp": "^4.11.0", "@eslint/config-array": "^0.18.0", "@eslint/eslintrc": "^3.1.0", - "@eslint/js": "9.9.1", + "@eslint/js": "9.10.0", + "@eslint/plugin-kit": "^0.1.0", "@humanwhocodes/module-importer": "^1.0.1", "@humanwhocodes/retry": "^0.3.0", "@nodelib/fs.walk": "^1.2.8", @@ -2946,7 +2959,6 @@ "is-glob": "^4.0.0", "is-path-inside": "^3.0.3", "json-stable-stringify-without-jsonify": "^1.0.1", - "levn": "^0.4.1", "lodash.merge": "^4.6.2", "minimatch": "^3.1.2", "natural-compare": "^1.4.0", @@ -5755,9 +5767,9 @@ } }, "node_modules/postcss": { - "version": "8.4.41", - "resolved": "https://registry.npmjs.org/postcss/-/postcss-8.4.41.tgz", - "integrity": "sha512-TesUflQ0WKZqAvg52PWL6kHgLKP6xB6heTOdoYM0Wt2UHyxNa4K25EZZMgKns3BH1RLVbZCREPpLY0rhnNoHVQ==", + "version": "8.4.45", + "resolved": "https://registry.npmjs.org/postcss/-/postcss-8.4.45.tgz", + "integrity": "sha512-7KTLTdzdZZYscUc65XmjFiB73vBhBfbPztCYdUNvlaso9PrzjzcmjqBPR0lNGkcVlcO4BjiO5rK/qNz+XAen1Q==", "funding": [ { "type": "opencollective", diff --git a/backend/package.json b/backend/package.json index 32798c5b92..8221e4fa53 100644 --- a/backend/package.json +++ b/backend/package.json @@ -25,13 +25,13 @@ "devDependencies": { "@4tw/cypress-drag-drop": "^2.2.5", "@babel/eslint-parser": "^7.25.1", - "@eslint/js": "^9.9.1", - "cypress": "^13.14.0", + "@eslint/js": "^9.10.0", + "cypress": "^13.14.2", "cypress-axe": "^1.5.0", "cypress-downloadfile": "^1.2.4", "cypress-file-upload": "^5.0.8", "cypress-otp": "^1.0.3", - "eslint": "^9.9.1", + "eslint": "^9.10.0", "eslint-config-prettier": "^9.1.0", "eslint-plugin-cypress": "^3.5.0", "eslint-plugin-prettier": "^5.2.1", @@ -48,7 +48,7 @@ "esbuild-sass-plugin": "3.3.1", "glob": "11.0.0", "npm-run-all": "^4.1.5", - "postcss": "^8.4.41", + "postcss": "^8.4.45", "postcss-cli": "^11.0.0" } } diff --git a/backend/support/api/admin_api_v1_1_1/base.sql b/backend/support/api/admin_api_v1_1_1/base.sql new file mode 100644 index 0000000000..dedabe0cb7 --- /dev/null +++ b/backend/support/api/admin_api_v1_1_1/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_1_1/create_access_tables.sql b/backend/support/api/admin_api_v1_1_1/create_access_tables.sql new file mode 100644 index 0000000000..18db91956d --- /dev/null +++ b/backend/support/api/admin_api_v1_1_1/create_access_tables.sql @@ -0,0 +1,43 @@ +-- 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' + ), + ( + 'daniel.swick@gsa.gov', + 'b6e08808-ecb2-4b6a-b928-46d4205497ff', + 'CREATE,READ,DELETE', + '2023-12-08' + ), + ( + 'fac-gov-test-users+api-tester-admin@gsa.gov', + 'dd60c3f9-053d-4d82-a309-c89da53559f4', + 'CREATE,READ,DELETE', + '2024-07-10' + ) + ; + diff --git a/backend/support/api/admin_api_v1_1_1/create_functions.sql b/backend/support/api/admin_api_v1_1_1/create_functions.sql new file mode 100644 index 0000000000..77b2b2a303 --- /dev/null +++ b/backend/support/api/admin_api_v1_1_1/create_functions.sql @@ -0,0 +1,389 @@ +-- 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_1_1_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_1_1_functions.get_api_key_uuid() returns TEXT +as $gaku$ +declare uuid text; +begin + select admin_api_v1_1_1_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_1_1_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_1_1_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_1_1_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_1_1_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_1_1 +-- 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_1_1.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_1_1_functions.has_admin_data_access('CREATE') + THEN + -- Are they already in the table? + SELECT count(up.email) + FROM public.users_userpermission as up + WHERE LOWER(email) = LOWER(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 (LOWER(params->>'email'), read_tribal_id, null); + + RAISE INFO 'ADMIN_API add_tribal_access_email OK %', LOWER(params->>'email'); + RETURN admin_api_v1_1_1_functions.log_admin_api_event('tribal-access-email-added', + json_build_object('email', LOWER(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_1_1 +-- 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_1_1.add_tribal_access_emails(params JSON) +returns BOOLEAN +as $add_tribal_access_emails$ +DECLARE + ele TEXT; + em record; +BEGIN + IF admin_api_v1_1_1_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_1_1.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_1_1 +-- 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_1_1.remove_tribal_access_email(params JSON) +returns BOOLEAN +as $remove_tribal_access_email$ +DECLARE + affected_rows INTEGER; +BEGIN + + IF admin_api_v1_1_1_functions.has_admin_data_access('DELETE') + THEN + -- Delete rows where the email address matches + DELETE FROM public.users_userpermission as up + WHERE LOWER(up.email) = LOWER(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_1_1_functions.log_admin_api_event('tribal-access-email-removed', + json_build_object('email', LOWER(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_1_1 +-- 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_1_1.remove_tribal_access_emails(params JSON) +returns BOOLEAN +as $remove_tribal_access_emails$ +DECLARE + ele TEXT; + em record; +BEGIN + IF admin_api_v1_1_1_functions.has_admin_data_access('DELETE') + THEN + FOR em IN (SELECT json_array_elements_text((params->>'emails')::JSON) ele) + LOOP + PERFORM admin_api_v1_1_1.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; + + + + +--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. +--Otherwise, it adds the email with 'read-tribal' permission, logs the event, and returns true. + +CREATE OR REPLACE FUNCTION admin_api_v1_1_1.add_tribal_api_key_access(params JSON) +RETURNS JSON +AS $add_tribal_api_key_access$ +DECLARE + user_exists BOOLEAN; +BEGIN + -- If the API user has create permissions, we can proceed + IF admin_api_v1_1_1_functions.has_admin_data_access('CREATE') THEN + -- Check if the user with the given email + SELECT EXISTS ( + SELECT 1 + FROM public.dissemination_TribalApiAccessKeyIds + WHERE LOWER(email) = LOWER(params->>'email') + ) + INTO user_exists; + + -- If the user already exists, it means they have access. + -- For purposes of this function, lets call that "succses", and return true. + IF user_exists THEN + RAISE INFO 'ADMIN_API add_tribal_api_key_access ALREADY_EXISTS %', LOWER(params->>'email'); + RETURN json_build_object( + 'result', 'success', + 'message', 'User with this key already exists')::JSON; + + END IF; + + -- If the user does not exist, add a new record + INSERT INTO public.dissemination_TribalApiAccessKeyIds (email, key_id, date_added) + VALUES (LOWER(params->>'email'), params->>'key_id', CURRENT_TIMESTAMP); + RAISE INFO 'ADMIN_API add_tribal_api_key_access ACCESS_GRANTED % %', LOWER(params->>'email'), params->>'key_id'; + RETURN json_build_object( + 'result', 'success', + 'message', 'User access granted')::JSON; + ELSE + -- If the user does not have CREATE permissions, then we should return a message to that effect. + -- It is a permissions error, but still, we need to know this failed. + RAISE INFO 'ADMIN_API add_tribal_api_key_access ADMIN_LACKS_CREATE'; + RETURN json_build_object( + 'result', 'failure', + 'message', 'Admin user lacks CREATE permissions')::JSON; + END IF; + + -- Return false by default. + RAISE INFO 'ADMIN_API add_tribal_api_key_access WAT %', LOWER(params->>'email'); + RETURN json_build_object( + 'result', 'failure', + 'message', 'Unknown error in access addition')::JSON; +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_1.remove_tribal_api_key_access(params JSON) +RETURNS JSON +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_1_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 LOWER(email) = LOWER(params->>'email') + ) + INTO user_exists; + + -- If the user exists, remove the record + IF user_exists THEN + DELETE FROM public.dissemination_TribalApiAccessKeyIds + WHERE LOWER(email) = LOWER(params->>'email'); + RAISE INFO 'ADMIN_API remove_tribal_api_key_access ACCESS_REMOVED %', LOWER(params->>'email'); + RETURN json_build_object( + 'result', 'success', + 'message', 'Removed record')::JSON; + ELSE + RAISE INFO 'ADMIN_API remove_tribal_api_key_access DID_NOT_EXIST %', LOWER(params->>'email'); + RETURN json_build_object( + 'result', 'failure', + 'message', 'User did not exist in table')::JSON; + END IF; + ELSE + RAISE INFO 'ADMIN_API remove_tribal_api_key_access ADMIN_LACKS_DELETE'; + RETURN json_build_object( + 'result', 'failure', + 'message', 'Admin user lacks DELETE permissions')::JSON; -- Return false if the API user doesn't have read permissions + END IF; + RAISE INFO 'ADMIN_API add_tribal_api_key_access WAT %', LOWER(params->>'email'); + RETURN json_build_object( + 'result', 'failure', + 'message', 'Uknown error in access removal')::JSON; +END; +$remove_tribal_api_key_access$ LANGUAGE plpgsql; + + +commit; + +NOTIFY pgrst, 'reload schema'; diff --git a/backend/support/api/admin_api_v1_1_1/create_schema.sql b/backend/support/api/admin_api_v1_1_1/create_schema.sql new file mode 100644 index 0000000000..9eff082bfe --- /dev/null +++ b/backend/support/api/admin_api_v1_1_1/create_schema.sql @@ -0,0 +1,56 @@ +begin; + +do +$$ +begin + DROP SCHEMA IF EXISTS admin_api_v1_1_1 CASCADE; + DROP SCHEMA IF EXISTS admin_api_v1_1_1_functions CASCADE; + + if not exists (select schema_name from information_schema.schemata where schema_name = 'admin_api_v1_1_1') then + create schema admin_api_v1_1_1; + create schema admin_api_v1_1_1_functions; + + grant usage on schema admin_api_v1_1_1_functions to api_fac_gov; + + -- Grant access to tables and views + alter default privileges + in schema admin_api_v1_1_1 + 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_1_1 to api_fac_gov; + grant select, usage on all sequences in schema admin_api_v1_1_1 to api_fac_gov; + alter default privileges + in schema admin_api_v1_1_1 + 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; + + 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 +$$ +; + +commit; + +notify pgrst, + 'reload schema'; + diff --git a/backend/support/api/admin_api_v1_1_1/create_views.sql b/backend/support/api/admin_api_v1_1_1/create_views.sql new file mode 100644 index 0000000000..6c84abf4d8 --- /dev/null +++ b/backend/support/api/admin_api_v1_1_1/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_1_1.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_1_1_functions.has_admin_data_access('READ') + ORDER BY aa.id +; + +CREATE OR REPLACE VIEW admin_api_v1_1_1.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_1_1_functions.has_admin_data_access('READ') + order by sac.id +; + +CREATE OR REPLACE VIEW admin_api_v1_1_1.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_1_1_functions.has_admin_data_access('READ') + ORDER BY uup.id +; + +CREATE OR REPLACE VIEW admin_api_v1_1_1.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_1_1_functions.has_admin_data_access('READ') + ORDER BY ae.id +; + + +commit; + +notify pgrst, + 'reload schema'; diff --git a/backend/support/api/admin_api_v1_1_1/drop_schema.sql b/backend/support/api/admin_api_v1_1_1/drop_schema.sql new file mode 100644 index 0000000000..0f53c84a81 --- /dev/null +++ b/backend/support/api/admin_api_v1_1_1/drop_schema.sql @@ -0,0 +1,9 @@ + +begin; + +DROP SCHEMA IF EXISTS admin_api_v1_1_1 CASCADE; + +commit; + +notify pgrst, + 'reload schema'; diff --git a/backend/support/api/admin_api_v1_1_1/drop_views.sql b/backend/support/api/admin_api_v1_1_1/drop_views.sql new file mode 100644 index 0000000000..6185d9b83d --- /dev/null +++ b/backend/support/api/admin_api_v1_1_1/drop_views.sql @@ -0,0 +1,8 @@ +begin; + + drop view if exists admin_api_v1_1_1.audit_access; + +commit; + +notify pgrst, + 'reload schema';