From f38059fdf02b320559f03fc7bfe921edcc29b543 Mon Sep 17 00:00:00 2001
From: "Hubbell, Harrison Taylor" <hhubbell@partners.org>
Date: Thu, 23 Jan 2020 12:57:23 -0500
Subject: [PATCH] Add proms_neuro_demographics view module

---
 proms_neuro_demographics/README.md            | 68 +++++++++++++++
 .../proms_neuro_demographics_a.sql            | 64 ++++++++++++++
 .../proms_neuro_demographics_b.sql            | 60 +++++++++++++
 .../tests/test_proms_neuro_demographics_a.py  | 85 +++++++++++++++++++
 .../tests/test_proms_neuro_demographics_b.py  | 83 ++++++++++++++++++
 5 files changed, 360 insertions(+)
 create mode 100644 proms_neuro_demographics/README.md
 create mode 100644 proms_neuro_demographics/proms_neuro_demographics_a.sql
 create mode 100644 proms_neuro_demographics/proms_neuro_demographics_b.sql
 create mode 100644 proms_neuro_demographics/tests/test_proms_neuro_demographics_a.py
 create mode 100644 proms_neuro_demographics/tests/test_proms_neuro_demographics_b.py

diff --git a/proms_neuro_demographics/README.md b/proms_neuro_demographics/README.md
new file mode 100644
index 0000000..b58becb
--- /dev/null
+++ b/proms_neuro_demographics/README.md
@@ -0,0 +1,68 @@
+# PROMs Neurology Demographics
+
+## Table of Contents
+
+1. [Overview](#overview)
+2. [Rules](#rules)
+3. [Columns](#columns)
+
+## Overview
+
+Combine Neurology Demographics A & B questionnaire submissions from different sources and transpose the data so that each record is one submission and each column contains the responses to the individual questions.
+
+
+## Rules
+
+These views combine submissions for Neurology Demographics questionnaires.
+
+
+### Questionnaire records included:
+
+|FormID     |FormNM                     |
+|-----------|---------------------------|
+|14022222270|PROMS MGH NEUROLOGY DEMOGRAPHICS A|
+|14022222271|PROMS MGH NEUROLOGY DEMOGRAPHICS B|
+
+### Link to PatientEncounterID
+
+There are some cases where an `AnswerID` (the primary key of a questionnaire submission) is linked to more than one `PatientEncounterID` (the primary key of a patient encounter). These views do not apply any special logic to determine which `AnswerID` should be linked with which `PatientEncounterID`. At first glance this may appear as if there are duplicate records in these views - however, the views specifically avoid "choosing" a `PatientEncounterID` to mirror business rules that one submission may be used for multiple encounters. After some discussion with business leaders, the conclusion is to leave all `AnswerID`/`PatientEncounterID` pairs. 
+
+Special care should be taken when counting submissions of forms. Please avoid `count(*)` when using this view and instead use `count(distinct AnswerID)` unless you have an explicit use case.
+
+
+## Columns
+
+### Neurology Demographics A
+
+|Column             |Type       |Description                        |Foreign Key    |
+|-------------------|-----------|-----------------------------------|---------------|
+|EDWPatientID `[FK]`|`INTEGER`  |Link to global EDW patient identifier.| |
+|PatientID `[FK]`   |`VARCHAR`  |Link to Epic patient identifier.   |`Epic.Patient.Patient.PatientID`|
+|AnswerID `[FK]`    |`VARCHAR`  |Link to submission identifier.     |`Epic.Reference.QuestionnaireAnswer.AnswerID`|
+|PatientEncounterID `[FK]`|`VARCHAR`|Link to encounter for which the questionnaire is linked.|`Epic.Encounter.PatientEncounter.PatientEncounterID`|
+|SubmissionDTS      |`DATETIME` |Instant at which the questionnaire was submitted.| |
+|QuestionnaireID `[FK]`|`VARCHAR`|Link to questionnaire identifier. |`Epic.Reference.QuestionnaireForm.FormID`|
+|QuestionnaireNM    |`VARCHAR`  |Name of the questionnaire. Mapped from `QuestionnaireID`.| |
+|CompletionStatusDSC|`VARCHAR`  |The completion status of the questionnaire, either "Full" if all questions were answered or "Partial" if otherwise.| |
+|QuestionsAnsweredNBR|`INTEGER` |The number of completed questions.| |
+|Question01VAL      |`VARCHAR`  |Response to question 1: ""| |
+|Question02VAL      |`VARCHAR`  |Response to question 2: ""| |
+|Question03VAL      |`VARCHAR`  |Response to question 3: ""| |
+|Question04VAL      |`VARCHAR`  |Response to question 4: ""| |
+
+### Neurology Demographics B
+
+|Column             |Type       |Description                        |Foreign Key    |
+|-------------------|-----------|-----------------------------------|---------------|
+|EDWPatientID `[FK]`|`INTEGER`  |Link to global EDW patient identifier.| |
+|PatientID `[FK]`   |`VARCHAR`  |Link to Epic patient identifier.   |`Epic.Patient.Patient.PatientID`|
+|AnswerID `[FK]`    |`VARCHAR`  |Link to submission identifier.     |`Epic.Reference.QuestionnaireAnswer.AnswerID`|
+|PatientEncounterID `[FK]`|`VARCHAR`|Link to encounter for which the questionnaire is linked.|`Epic.Encounter.PatientEncounter.PatientEncounterID`|
+|SubmissionDTS      |`DATETIME` |Instant at which the questionnaire was submitted.| |
+|QuestionnaireID `[FK]`|`VARCHAR`|Link to questionnaire identifier. |`Epic.Reference.QuestionnaireForm.FormID`|
+|QuestionnaireNM    |`VARCHAR`  |Name of the questionnaire. Mapped from `QuestionnaireID`.| |
+|CompletionStatusDSC|`VARCHAR`  |The completion status of the questionnaire, either "Full" if all questions were answered or "Partial" if otherwise.| |
+|QuestionsAnsweredNBR|`INTEGER` |The number of completed questions.| |
+|Question01VAL      |`VARCHAR`  |Response to question 1: ""| |
+|Question02VAL      |`VARCHAR`  |Response to question 2: ""| |
+|Question03VAL      |`VARCHAR`  |Response to question 3: ""| |
diff --git a/proms_neuro_demographics/proms_neuro_demographics_a.sql b/proms_neuro_demographics/proms_neuro_demographics_a.sql
new file mode 100644
index 0000000..939470f
--- /dev/null
+++ b/proms_neuro_demographics/proms_neuro_demographics_a.sql
@@ -0,0 +1,64 @@
+--
+-- Author:      Harrison Hubbell <hhubbell@partners.org>
+-- Description: PROMs Neurology Demographics A questionnaire submissions
+--              transposed for quick reference.
+--
+-- Form Records:
+--  PROMS MGH NEUROLOGY DEMOGRAPHICS A (14022222270)
+--
+
+use UserWork;
+go
+
+create view EAViewLibrary.PROMsNeurologyDemographicsA as
+with questionnaire_submissions as (
+    -- Take the minimum `SubmissionDTS` if multiple are linked to an
+    -- `AnswerID`. This can happen if an `AnswerID` is linked to both
+    -- a series and appointment.
+    select
+        AnswerID,
+        PatientID,
+        QuestionnaireID,
+        min(SubmissionDTS) as SubmissionDTS
+    from Epic.Patient.QuestionnaireSubmission_Enterprise
+    where QuestionnaireID = '14022222270'
+    group by
+        AnswerID,
+        PatientID,
+        QuestionnaireID
+)
+select distinct
+    ptn.EDWPatientID,
+    qs.PatientID,
+    qs.AnswerID,
+    qfa.PatientEncounterID,
+    qs.SubmissionDTS,
+    qs.QuestionnaireID,
+    qf.FormNM as QuestionnaireNM,
+    case
+        when qqa_04.AnswerID is not null then 'Full'
+        else 'Partial'
+    end as CompletionStatusDSC,
+    iif(qqa_01.AnswerTXT is not null, 1, 0) + iif(qqa_02.AnswerTXT is not null, 1, 0)
+        + iif(qqa_03.AnswerTXT is not null, 1, 0) + iif(qqa_04.AnswerTXT is not null, 1, 0) as QuestionsAnsweredNBR,
+    qqa_01.AnswerTXT as Question01VAL,
+    qqa_02.AnswerTXT as Question02VAL,
+    qqa_03.AnswerTXT as Question03VAL,
+    qqa_04.AnswerTXT as Question04VAL
+from questionnaire_submissions qs
+    inner join Epic.Patient.Patient_Enterprise ptn on qs.PatientID = ptn.PatientID
+    inner join Epic.Reference.QuestionnaireForm qf on qs.QuestionnaireID = qf.FormID
+    inner join Epic.Reference.QuestionnaireAnswer qa on qs.AnswerID = qa.AnswerID
+    left join Epic.Clinical.QuestionnaireFormAnswer_Enterprise qfa on qs.AnswerID = qfa.AnswerID
+    -- Neurology Demographics A: Q01
+    left join Epic.Reference.QuestionnaireQuestionAnswer qqa_01 on qa.AnswerID = qqa_01.AnswerID
+        and qqa_01.QuestionID in ('132000')
+    -- Neurology Demographics A: Q02
+    left join Epic.Reference.QuestionnaireQuestionAnswer qqa_02 on qa.AnswerID = qqa_02.AnswerID
+        and qqa_02.QuestionID in ('132001')
+    -- Neurology Demographics A: Q03
+    left join Epic.Reference.QuestionnaireQuestionAnswer qqa_03 on qa.AnswerID = qqa_03.AnswerID
+        and qqa_03.QuestionID in ('132002')
+    -- Neurology Demographics A: Q04
+    left join Epic.Reference.QuestionnaireQuestionAnswer qqa_04 on qa.AnswerID = qqa_04.AnswerID
+        and qqa_04.QuestionID in ('132003')
diff --git a/proms_neuro_demographics/proms_neuro_demographics_b.sql b/proms_neuro_demographics/proms_neuro_demographics_b.sql
new file mode 100644
index 0000000..f12b3db
--- /dev/null
+++ b/proms_neuro_demographics/proms_neuro_demographics_b.sql
@@ -0,0 +1,60 @@
+--
+-- Author:      Harrison Hubbell <hhubbell@partners.org>
+-- Description: PROMs Neurology Demographics B questionnaire submissions
+--              transposed for quick reference.
+--
+-- Form Records:
+--  PROMS MGH NEUROLOGY DEMOGRAPHICS B (14022222270)
+--
+
+use UserWork;
+go
+
+create view EAViewLibrary.PROMsNeurologyDemographicsB as
+with questionnaire_submissions as (
+    -- Take the minimum `SubmissionDTS` if multiple are linked to an
+    -- `AnswerID`. This can happen if an `AnswerID` is linked to both
+    -- a series and appointment.
+    select
+        AnswerID,
+        PatientID,
+        QuestionnaireID,
+        min(SubmissionDTS) as SubmissionDTS
+    from Epic.Patient.QuestionnaireSubmission_Enterprise
+    where QuestionnaireID = '14022222271'
+    group by
+        AnswerID,
+        PatientID,
+        QuestionnaireID
+)
+select distinct
+    ptn.EDWPatientID,
+    qs.PatientID,
+    qs.AnswerID,
+    qfa.PatientEncounterID,
+    qs.SubmissionDTS,
+    qs.QuestionnaireID,
+    qf.FormNM as QuestionnaireNM,
+    case
+        when qqa_03.AnswerID is not null then 'Full'
+        else 'Partial'
+    end as CompletionStatusDSC,
+    iif(qqa_01.AnswerTXT is not null, 1, 0) + iif(qqa_02.AnswerTXT is not null, 1, 0)
+        + iif(qqa_03.AnswerTXT is not null, 1, 0) as QuestionsAnsweredNBR,
+    qqa_01.AnswerTXT as Question01VAL,
+    qqa_02.AnswerTXT as Question02VAL,
+    qqa_03.AnswerTXT as Question03VAL
+from questionnaire_submissions qs
+    inner join Epic.Patient.Patient_Enterprise ptn on qs.PatientID = ptn.PatientID
+    inner join Epic.Reference.QuestionnaireForm qf on qs.QuestionnaireID = qf.FormID
+    inner join Epic.Reference.QuestionnaireAnswer qa on qs.AnswerID = qa.AnswerID
+    left join Epic.Clinical.QuestionnaireFormAnswer_Enterprise qfa on qs.AnswerID = qfa.AnswerID
+    -- Neurology Demographics B: Q01
+    left join Epic.Reference.QuestionnaireQuestionAnswer qqa_01 on qa.AnswerID = qqa_01.AnswerID
+        and qqa_01.QuestionID in ('132004')
+    -- Neurology Demographics B: Q02
+    left join Epic.Reference.QuestionnaireQuestionAnswer qqa_02 on qa.AnswerID = qqa_02.AnswerID
+        and qqa_02.QuestionID in ('132005')
+    -- Neurology Demographics B: Q03
+    left join Epic.Reference.QuestionnaireQuestionAnswer qqa_03 on qa.AnswerID = qqa_03.AnswerID
+        and qqa_03.QuestionID in ('132006')
diff --git a/proms_neuro_demographics/tests/test_proms_neuro_demographics_a.py b/proms_neuro_demographics/tests/test_proms_neuro_demographics_a.py
new file mode 100644
index 0000000..73bbcb3
--- /dev/null
+++ b/proms_neuro_demographics/tests/test_proms_neuro_demographics_a.py
@@ -0,0 +1,85 @@
+import pyodbc
+import inspect
+import unittest
+
+
+class TestPROMsNeurologyDemographicsA(unittest.TestCase):
+    @classmethod
+    def setUpClass(cls):
+        cls.conn = pyodbc.connect(driver='{ODBC Driver 17 for SQL Server}',
+            server='PHSEDW',
+            trusted_connection='yes')
+
+        cls.view = 'UserWork.EAViewLibrary.PROMsNeurologyDemographicsA'
+        cls.results = {}
+
+    def retain_result(self, test_data):
+        """
+        Retain any data that caused a test to fail for further inspection. This
+        function will inspect the call stack to identify which test method
+        called it, so the key can be correctly set.
+        :param test_data [list]: List of records from a `pyodbc` call.
+        """
+        caller = inspect.currentframe().f_back.f_code.co_name
+        self.results[caller] = [tuple(x) for x in test_data]
+
+    def test_duplicates(self):
+        """
+        Confirm that there are no duplicate records
+        """
+        with self.conn.cursor() as cur:
+            cur.execute("""
+                select top 1000 src.*
+                from {view} src
+                    inner join (
+                        select AnswerID, PatientEncounterID
+                        from {view}
+                        group by AnswerID, PatientEncounterID
+                        having count(*) > 1
+                    ) dup on src.AnswerID = dup.AnswerID
+                        and src.PatientEncounterID = dup.PatientEncounterID
+            """.format(view=self.view))
+            res = cur.fetchall()
+
+        self.retain_result(res)
+        self.assertEqual(len(res), 0)
+
+    def test_completion_full(self):
+        """
+        Confirm that all responses are populated if
+        CompletionStatusDSC = 'Full'
+        """
+        with self.conn.cursor() as cur:
+            cur.execute("""
+                select top 1000 *
+                from {view}
+                where CompletionStatusDSC = 'Full'
+                    and (Question01VAL is null
+                        or Question02VAL is null
+                        or Question03VAL is null
+                        or Question04VAL is null)
+            """.format(view=self.view))
+            res = cur.fetchall()
+
+        self.retain_result(res)
+        self.assertEqual(len(res), 0)
+
+    def test_completion_partial(self):
+        """
+        Confirm that at least one response is unpopulated if
+        CompletionStatusDSC = 'Partial'
+        """
+        with self.conn.cursor() as cur:
+            cur.execute("""
+                select top 1000 *
+                from {view}
+                where CompletionStatusDSC = 'Partial'
+                    and Question01VAL is not null
+                    and Question02VAL is not null
+                    and Question03VAL is not null
+                    and Question04VAL is not null
+            """.format(view=self.view))
+            res = cur.fetchall()
+
+        self.retain_result(res)
+        self.assertEqual(len(res), 0)
diff --git a/proms_neuro_demographics/tests/test_proms_neuro_demographics_b.py b/proms_neuro_demographics/tests/test_proms_neuro_demographics_b.py
new file mode 100644
index 0000000..67db1c0
--- /dev/null
+++ b/proms_neuro_demographics/tests/test_proms_neuro_demographics_b.py
@@ -0,0 +1,83 @@
+import pyodbc
+import inspect
+import unittest
+
+
+class TestPROMsNeurologyDemographicsB(unittest.TestCase):
+    @classmethod
+    def setUpClass(cls):
+        cls.conn = pyodbc.connect(driver='{ODBC Driver 17 for SQL Server}',
+            server='PHSEDW',
+            trusted_connection='yes')
+
+        cls.view = 'UserWork.EAViewLibrary.PROMsNeurologyDemographicsB'
+        cls.results = {}
+
+    def retain_result(self, test_data):
+        """
+        Retain any data that caused a test to fail for further inspection. This
+        function will inspect the call stack to identify which test method
+        called it, so the key can be correctly set.
+        :param test_data [list]: List of records from a `pyodbc` call.
+        """
+        caller = inspect.currentframe().f_back.f_code.co_name
+        self.results[caller] = [tuple(x) for x in test_data]
+
+    def test_duplicates(self):
+        """
+        Confirm that there are no duplicate records
+        """
+        with self.conn.cursor() as cur:
+            cur.execute("""
+                select top 1000 src.*
+                from {view} src
+                    inner join (
+                        select AnswerID, PatientEncounterID
+                        from {view}
+                        group by AnswerID, PatientEncounterID
+                        having count(*) > 1
+                    ) dup on src.AnswerID = dup.AnswerID
+                        and src.PatientEncounterID = dup.PatientEncounterID
+            """.format(view=self.view))
+            res = cur.fetchall()
+
+        self.retain_result(res)
+        self.assertEqual(len(res), 0)
+
+    def test_completion_full(self):
+        """
+        Confirm that all responses are populated if
+        CompletionStatusDSC = 'Full'
+        """
+        with self.conn.cursor() as cur:
+            cur.execute("""
+                select top 1000 *
+                from {view}
+                where CompletionStatusDSC = 'Full'
+                    and (Question01VAL is null
+                        or Question02VAL is null
+                        or Question03VAL is null)
+            """.format(view=self.view))
+            res = cur.fetchall()
+
+        self.retain_result(res)
+        self.assertEqual(len(res), 0)
+
+    def test_completion_partial(self):
+        """
+        Confirm that at least one response is unpopulated if
+        CompletionStatusDSC = 'Partial'
+        """
+        with self.conn.cursor() as cur:
+            cur.execute("""
+                select top 1000 *
+                from {view}
+                where CompletionStatusDSC = 'Partial'
+                    and Question01VAL is not null
+                    and Question02VAL is not null
+                    and Question03VAL is not null
+            """.format(view=self.view))
+            res = cur.fetchall()
+
+        self.retain_result(res)
+        self.assertEqual(len(res), 0)
-- 
GitLab