Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

APPEALS-59239: Update of the national_hearing_queue_entries View Definition to Include Legacy Appeal Information #23335

Open
wants to merge 22 commits into
base: feature/APPEALS-57706
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
22 commits
Select commit Hold shift + click to select a range
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
54 changes: 34 additions & 20 deletions .github/workflows/workflow.yml
Original file line number Diff line number Diff line change
Expand Up @@ -21,15 +21,16 @@ jobs:
timeout-minutes: 45
services:
postgres:
image: postgres:14.8
image: 065403089830.dkr.ecr.us-gov-west-1.amazonaws.com/caseflow-postgres-ci:14.9
credentials:
username: AWS
password: ${{ secrets.VAEC_ECR_PASSWORD }}
env:
POSTGRES_USER: root
POSTGRES_PASSWORD: password
POSTGRES_USER: postgres
POSTGRES_PASSWORD: postgres
POSTGRES_DB: caseflow_certification_test

ports:
- 5432:5432

options: --health-cmd pg_isready --health-interval 10s --health-timeout 5s --health-retries 5

redis:
Expand Down Expand Up @@ -74,8 +75,8 @@ jobs:
BUNDLE_PATH: vendor/bundle
COVERAGE_DIR: /home/circleci/coverage-${{matrix.ci_node_index}} #circleci is the USER
POSTGRES_HOST: postgres
POSTGRES_USER: root
POSTGRES_PASSWORD: password
POSTGRES_USER: postgres
POSTGRES_PASSWORD: postgres
KNAPSACK_PRO_RSPEC_SPLIT_BY_TEST_EXAMPLES: true
KNAPSACK_PRO_TEST_SUITE_TOKEN_RSPEC: ${{ secrets.KNAPSACK_PRO_TEST_SUITE_TOKEN_RSPEC }}
KNAPSACK_PRO_CI_NODE_TOTAL: ${{ matrix.ci_node_total }}
Expand Down Expand Up @@ -194,31 +195,44 @@ jobs:
&& sudo tar -C /usr/local/bin -xzvf dockerize-linux-amd64-${DOCKERIZE_VERSION}.tar.gz \
&& rm dockerize-linux-amd64-${DOCKERIZE_VERSION}.tar.gz

- name: "Wait for database"
- name: Wait for the Postgres Database to Boot
run: dockerize -wait tcp://postgres:5432 -timeout 1m

- name: "Wait for localstack"
run: dockerize -wait tcp://localstack:4566 -timeout 30s

- name: "Wait for FACOLS"
run: ./ci-bin/capture-log "bundle exec rake local:vacols:wait_for_connection"
run: bundle exec rake local:vacols:wait_for_connection

- name: "Install psql"
run: sudo apt-get install -y postgresql-client

- name: Database setup
- name: Postgres Database Creation
run: |
./ci-bin/capture-log "bundle exec rake db:create:etl db:schema:load:etl"
./ci-bin/capture-log "bundle exec rake db:create:primary db:schema:load:primary"
./ci-bin/capture-log "make -f Makefile.example external-db-create"
bundle exec rake db:create:etl
bundle exec rake db:create:primary
# added line to create external table(s) that are needed for tests

- name: Install Postgres Extensions
run: psql -h postgres -U postgres -d caseflow_certification_test -a -f docker-bin/pg/setup_extensions_test.sql

# We don't want to seed DBs here because DatabaseCleaner just truncates it anyway. The setup_vacols
# rake task needs to be run because it adds data to two tables that are ignored by DBCleaner
- name: Seed databases
- name: Seed the VACOLS database
run: bundle exec rake spec:setup_vacols

- name: Set Up Foreign Tables
run: psql -h postgres -U postgres -d caseflow_certification_test -a -f local/sql/create_foreign_tables_for_vacols_test.sql

- name: Postgres Database Schema Setup
run: |
./ci-bin/capture-log "bundle exec rake spec:setup_vacols"
bundle exec rake db:schema:load:etl
bundle exec rake db:schema:load:primary
make -f Makefile.example external-db-create
# added line to create external table(s) that are needed for tests

- name: "Wait for localstack"
run: dockerize -wait tcp://localstack:4566 -timeout 30s

- name: Assets Precompile
run: |
./ci-bin/capture-log "bundle exec rake assets:precompile"
run: bundle exec rake assets:precompile

# Changing the user and permissions as Chrome/Chromedriver can't run as root
- name: RSpec via knapsack_pro Queue Mode
Expand Down
7 changes: 7 additions & 0 deletions app/models/national_hearing_queue_entry.rb
Original file line number Diff line number Diff line change
@@ -1,4 +1,11 @@
# frozen_string_literal: true

class NationalHearingQueueEntry < CaseflowRecord
def self.refresh
Scenic.database.refresh_materialized_view(
"national_hearing_queue_entries",
concurrently: false,
cascade: false
)
end
end
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
class UpdateNationalHearingQueueEntriesToVersion2 < ActiveRecord::Migration[6.1]
def change
update_view :national_hearing_queue_entries,
version: 2,
revert_to_version: 1,
materialized: true
end
end
35 changes: 30 additions & 5 deletions db/schema.rb
Original file line number Diff line number Diff line change
Expand Up @@ -10,9 +10,10 @@
#
# It's strongly recommended that you check this file into your version control system.

ActiveRecord::Schema.define(version: 2024_10_12_181521) do
ActiveRecord::Schema.define(version: 2024_10_21_145753) do

# These are extensions that must be enabled in order to support this database
enable_extension "oracle_fdw"
enable_extension "plpgsql"
enable_extension "uuid-ossp"

Expand Down Expand Up @@ -2500,12 +2501,36 @@
SELECT appeals.id AS appeal_id,
'Appeal'::text AS appeal_type,
COALESCE(appeals.changed_hearing_request_type, appeals.original_hearing_request_type) AS hearing_request_type,
appeals.receipt_date,
appeals.uuid AS external_id,
appeals.stream_type AS appeal_stream,
appeals.stream_docket_number AS docket_number
(appeals.receipt_date)::character(1) AS receipt_date,
(appeals.uuid)::character(1) AS external_id,
(appeals.stream_type)::character(1) AS appeal_stream,
(appeals.stream_docket_number)::character(1) AS docket_number
FROM (appeals
JOIN tasks ON ((((tasks.appeal_type)::text = 'Appeal'::text) AND (tasks.appeal_id = appeals.id))))
WHERE (((tasks.type)::text = 'ScheduleHearingTask'::text) AND ((tasks.status)::text = ANY ((ARRAY['assigned'::character varying, 'in_progress'::character varying, 'on_hold'::character varying])::text[])))
UNION
SELECT legacy_appeals.id AS appeal_id,
'LegacyAppeal'::text AS appeal_type,
f_vacols_brieff.bfhr AS hearing_request_type,
replace(((f_vacols_brieff.bfd19)::character(1))::text, '-'::text, ''::text) AS receipt_date,
f_vacols_brieff.bfkey AS external_id,
CASE
WHEN ((f_vacols_brieff.bfac)::text = '1'::text) THEN 'Original'::text
WHEN ((f_vacols_brieff.bfac)::text = '2'::text) THEN 'Supplemental'::text
WHEN ((f_vacols_brieff.bfac)::text = '3'::text) THEN 'Post Remand'::text
WHEN ((f_vacols_brieff.bfac)::text = '4'::text) THEN 'Reconsideration'::text
WHEN ((f_vacols_brieff.bfac)::text = '5'::text) THEN 'Vacate'::text
WHEN ((f_vacols_brieff.bfac)::text = '6'::text) THEN 'De Novo'::text
WHEN ((f_vacols_brieff.bfac)::text = '7'::text) THEN 'Court Remand'::text
WHEN ((f_vacols_brieff.bfac)::text = '8'::text) THEN 'Designation of Record'::text
WHEN ((f_vacols_brieff.bfac)::text = '9'::text) THEN 'Clear and Unmistakeable Error'::text
ELSE NULL::text
END AS appeal_stream,
f_vacols_folder.tinum AS docket_number
FROM (((legacy_appeals
JOIN tasks ON ((((tasks.appeal_type)::text = 'LegacyAppeal'::text) AND (tasks.appeal_id = legacy_appeals.id))))
JOIN f_vacols_brieff ON (((legacy_appeals.vacols_id)::text = (f_vacols_brieff.bfkey)::text)))
JOIN f_vacols_folder ON (((f_vacols_brieff.bfkey)::text = (f_vacols_folder.ticknum)::text)))
WHERE (((tasks.type)::text = 'ScheduleHearingTask'::text) AND ((tasks.status)::text = ANY ((ARRAY['assigned'::character varying, 'in_progress'::character varying, 'on_hold'::character varying])::text[])));
SQL
end
43 changes: 43 additions & 0 deletions db/views/national_hearing_queue_entries_v02.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,43 @@
--- this view is a way to see both of the appeals and legacy appeals information IN a single table
--- materialized means that this information will be cached IN a temporary table
SELECT
appeals.id AS appeal_id,
'Appeal' AS appeal_type,
-- COALESCE selects the first non-null value
COALESCE(appeals.changed_hearing_request_type, appeals.original_hearing_request_type) AS hearing_request_type,
CAST(appeals.receipt_date AS CHAR) AS receipt_date,
CAST(appeals.uuid AS CHAR) AS external_id,
CAST(appeals.stream_type AS CHAR) AS appeal_stream,
CAST(appeals.stream_docket_number AS CHAR) AS docket_number
FROM appeals
JOIN tasks ON tasks.appeal_type = 'Appeal' and tasks.appeal_id = appeals.id
WHERE tasks.type = 'ScheduleHearingTask'
and tasks.status IN ('assigned', 'in_progress', 'on_hold')

-- Union for legacy appeals equivalent of above
UNION

SELECT
legacy_appeals.id AS appeal_id,
'LegacyAppeal' AS appeal_type,
f_vacols_brieff.bfhr AS hearing_request_type,
REPLACE(CAST(f_vacols_brieff.bfd19 AS CHAR), '-', '') AS receipt_date,
f_vacols_brieff.bfkey AS external_id,
CASE
WHEN f_vacols_brieff.bfac = '1' THEN 'Original'
WHEN f_vacols_brieff.bfac = '2' THEN 'Supplemental'
WHEN f_vacols_brieff.bfac = '3' THEN 'Post Remand'
WHEN f_vacols_brieff.bfac = '4' THEN 'Reconsideration'
WHEN f_vacols_brieff.bfac = '5' THEN 'Vacate'
WHEN f_vacols_brieff.bfac = '6' THEN 'De Novo'
WHEN f_vacols_brieff.bfac = '7' THEN 'Court Remand'
WHEN f_vacols_brieff.bfac = '8' THEN 'Designation of Record'
WHEN f_vacols_brieff.bfac = '9' THEN 'Clear and Unmistakeable Error'
END AS appeal_stream,
f_vacols_folder.tinum AS docket_number
FROM legacy_appeals
JOIN tasks ON tasks.appeal_type = 'LegacyAppeal' and tasks.appeal_id = legacy_appeals.id
JOIN f_vacols_brieff ON (legacy_appeals.vacols_id = f_vacols_brieff.bfkey)
JOIN f_vacols_folder ON (f_vacols_brieff.bfkey = f_vacols_folder.ticknum)
WHERE tasks.type = 'ScheduleHearingTask'
and tasks.status IN ('assigned', 'in_progress', 'on_hold')
14 changes: 14 additions & 0 deletions docker-bin/pg/setup_extensions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
CREATE EXTENSION oracle_fdw;

CREATE SERVER vacols_sv FOREIGN DATA WRAPPER oracle_fdw OPTIONS (
dbserver 'vacols_db:1521/BVAP'
);

-- Grant permissions to the postgres user for the foreign tables
GRANT USAGE ON FOREIGN SERVER vacols_sv TO postgres;

-- Create a user mapping to the foreign server
CREATE USER MAPPING FOR postgres SERVER vacols_sv OPTIONS (
USER 'VACOLS_DEV',
PASSWORD 'VACOLS_DEV'
);
14 changes: 14 additions & 0 deletions docker-bin/pg/setup_extensions_test.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
CREATE EXTENSION oracle_fdw;

CREATE SERVER vacols_sv FOREIGN DATA WRAPPER oracle_fdw OPTIONS (
dbserver 'facols_db:1521/BVAP'
);

-- Grant permissions to the postgres user for the foreign tables
GRANT USAGE ON FOREIGN SERVER vacols_sv TO postgres;

-- Create a user mapping to the foreign server
CREATE USER MAPPING FOR postgres SERVER vacols_sv OPTIONS (
USER 'VACOLS_TEST',
PASSWORD 'VACOLS_TEST'
);
Loading
Loading