Skip to content

Commit

Permalink
[US_IX] Ingest multiple violation types from violation survey (Recidi…
Browse files Browse the repository at this point in the history
…viz/recidiviz-data#29380)

## Description of the change

Revise supervision violation ingest to ingest multiple violation types
when somebody checked multiple violation types on the violation survey

Testing:
- [x] run mappings script to make sure everything parses
- [x] run sandbox to check numbers

## Type of change

> All pull requests must have at least one of the following labels
applied (otherwise the PR will fail):

| Label | Description |
|-----------------------------
|-----------------------------------------------------------------------------------------------------------
|
| Type: Bug | non-breaking change that fixes an issue |
| Type: Feature | non-breaking change that adds functionality |
| Type: Breaking Change | fix or feature that would cause existing
functionality to not work as expected |
| Type: Non-breaking refactor | change addresses some tech debt item or
prepares for a later change, but does not change functionality |
| Type: Configuration Change | adjusts configuration to achieve some end
related to functionality, development, performance, or security |
| Type: Dependency Upgrade | upgrades a project dependency - these
changes are not included in release notes |

## Related issues

Closes #XXXX

## Checklists

### Development

**This box MUST be checked by the submitter prior to merging**:
- [x] **Double- and triple-checked that there is no Personally
Identifiable Information (PII) being mistakenly added in this pull
request**

These boxes should be checked by the submitter prior to merging:
- [x] Tests have been written to cover the code changed/added as part of
this pull request

### Code review

These boxes should be checked by reviewers prior to merging:

- [ ] This pull request has a descriptive title and information useful
to a reviewer
- [ ] Potential security implications or infrastructural changes have
been considered, if relevant

GitOrigin-RevId: 8518ea893ba9fd9b2fd608d0a4af509947813117
  • Loading branch information
brendali121 authored and Helper Bot committed May 14, 2024
1 parent 29250a2 commit d553b25
Show file tree
Hide file tree
Showing 2 changed files with 58 additions and 33 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -8,7 +8,7 @@ input_columns:
- CompletedDate
- OffenderQuestionnaireTemplateId
- violation_date
- violation_type
- violation_types
unused_columns: []
output:
StatePerson:
Expand All @@ -26,26 +26,29 @@ output:
- $literal("SUPPLEMENTAL")
violation_date: violation_date
supervision_violation_types:
- StateSupervisionViolationTypeEntry:
violation_type:
$enum_mapping:
$raw_text: violation_type
$mappings:
StateSupervisionViolationType.ABSCONDED:
- Absconding
StateSupervisionViolationType.TECHNICAL:
- Technical (enter details below)
StateSupervisionViolationType.FELONY:
- Non-Violent Felony
- Violent Felony
- New Felony
StateSupervisionViolationType.MISDEMEANOR:
- Violent Misdemeanor
- Non-Violent Misdemeanor
- New Misdemeanor
StateSupervisionViolationType.LAW:
- Violent Sex Offense
- Non-Violent Sex Offense
- $foreach:
$iterable: violation_types
$result:
StateSupervisionViolationTypeEntry:
violation_type:
$enum_mapping:
$raw_text: $iter_item
$mappings:
StateSupervisionViolationType.ABSCONDED:
- Absconding
StateSupervisionViolationType.TECHNICAL:
- Technical (enter details below)
StateSupervisionViolationType.FELONY:
- Non-Violent Felony
- Violent Felony
- New Felony
StateSupervisionViolationType.MISDEMEANOR:
- Violent Misdemeanor
- Non-Violent Misdemeanor
- New Misdemeanor
StateSupervisionViolationType.LAW:
- Violent Sex Offense
- Non-Violent Sex Offense
supervision_violation_responses:
- StateSupervisionViolationResponse:
external_id:
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -25,7 +25,10 @@
from recidiviz.utils.metadata import local_project_id_override

VIEW_QUERY_TEMPLATE = """
WITH survey_template AS (
WITH
-- The violation survey responses are coded in Atlas using a series of SectionIds, QuestionIds, and AnswerIds.
-- This CTE compiles a mapping of all those Section, Question, and Answer Ids to their respective descriptions for easier readability later on
survey_template AS (
SELECT DISTINCT
JSON_EXTRACT_SCALAR(sections, "$.questionnaireId") AS QuestionnaireTemplateId,
JSON_EXTRACT_SCALAR(sections, "$.sectionId") AS sectionId,
Expand All @@ -39,6 +42,10 @@
UNNEST(JSON_EXTRACT_ARRAY(questions, "$.answers")) AS answers
WHERE UPPER(QuestionnaireDefinition) LIKE '%VIOLATION SURVEY%'
),
-- This CTE pulls together all the survey responses (with their QuestionnaireTemplateId, QuestionIds, AnswerIds, and answer values)
-- for all survey templates that correspond with the violation survey. We also pull in an external id for the
-- violation survey itself (OffenderQuestionnaireTemplateId), the JII associated with the survey, and the employee information
-- for the employee that entered the survey. The result of this CTE is one row per survey-section-question-answer combination.
survey_responses AS (
SELECT
OffenderQuestionnaireTemplateId,
Expand All @@ -59,6 +66,9 @@
"1030"
)
),
-- This CTE filters down to relevant sections/questions and then joins on the survey_template CTE
-- to get the survey answers in a more readable format. This CTE also filters out survey-section-question-answer rows where the
-- question or answer was NULL.
survey_answer_per_question AS (
SELECT DISTINCT *
FROM (
Expand Down Expand Up @@ -86,23 +96,35 @@
WHERE answer IS NOT NULL AND question_title IS NOT NULL
ORDER BY OffenderQuestionnaireTemplateId, SectionId)
-- This CTE aggregates all the results into one row pers survey.
-- For violation type (which is a "check all that apply" question), we string agg
-- all distinct violation type values.
-- We also take the MIN of violation date across all survey-section-question-answer rows,
-- but we only expect one non-null value for violation date per survey anyways.
SELECT
CompletedByEmployeeId,
CompletedDate,
OffenderQuestionnaireTemplateId,
OffenderId,
MAX(
CompletedByEmployeeId,
CompletedDate,
OffenderQuestionnaireTemplateId,
OffenderId,
MIN(violation_date) as violation_date,
STRING_AGG(DISTINCT violation_type, "," ORDER BY violation_type) AS violation_types
FROM (
SELECT
DISTINCT
CompletedByEmployeeId,
CompletedDate,
OffenderQuestionnaireTemplateId,
OffenderId,
CASE
WHEN question_title = "Report of Violation Date"
OR question_title = "Violation Date"
THEN answer END) AS violation_date,
MAX(
THEN answer END AS violation_date,
CASE
WHEN question_title = "New Crime Type (check all that apply)"
OR question_title = "Violation Type"
WHEN question_title = "Violation Type"
OR question_title = "Violation Type (check all that apply)"
THEN answer END) AS violation_type,
FROM survey_answer_per_question
THEN answer END AS violation_type,
FROM survey_answer_per_question
)
GROUP BY CompletedByEmployeeId,CompletedDate,OffenderQuestionnaireTemplateId,OffenderId
"""
Expand Down

0 comments on commit d553b25

Please sign in to comment.