From 7cad12c14a9f87e898d62abcae219d504a85eb4a Mon Sep 17 00:00:00 2001
From: Soorya Kumaran C <90232857+SooryaKumaranC-tw@users.noreply.github.com>
Date: Mon, 24 Jan 2022 15:41:54 +0530
Subject: [PATCH 1/3] BAH-1236 | Bug fix. Modified query to display only
 preferred patients in active tab after merging

Co-authored-by: Kavitha S <kavitha.s@thoughtworks.com>
---
 .../main/resources/V1_99_PatientSearchSql.sql | 241 ++++++++++++++++++
 .../src/main/resources/liquibase.xml          |   5 +
 2 files changed, 246 insertions(+)
 create mode 100644 bahmnicore-omod/src/main/resources/V1_99_PatientSearchSql.sql

diff --git a/bahmnicore-omod/src/main/resources/V1_99_PatientSearchSql.sql b/bahmnicore-omod/src/main/resources/V1_99_PatientSearchSql.sql
new file mode 100644
index 0000000000..5f0b66c6d6
--- /dev/null
+++ b/bahmnicore-omod/src/main/resources/V1_99_PatientSearchSql.sql
@@ -0,0 +1,241 @@
+DELETE FROM global_property
+WHERE property IN (
+  'emrapi.sqlSearch.activePatients',
+  'emrapi.sqlSearch.activePatientsByProvider',
+  'emrapi.sqlSearch.patientsToAdmit',
+  'emrapi.sqlSearch.admittedPatients',
+  'emrapi.sqlSearch.patientsToDischarge',
+  'emrapi.sqlSearch.activePatientsByLocation',
+  'emrapi.sqlSearch.highRiskPatients',
+  'emrapi.sqlSearch.patientsHasPendingOrders'
+);
+
+INSERT INTO global_property (`property`, `property_value`, `description`, `uuid`)
+VALUES ('emrapi.sqlSearch.activePatients',
+        'select distinct
+          concat(pn.given_name,\' \', pn.family_name) as name,
+          pi.identifier as identifier,
+          concat("",p.uuid) as uuid,
+          IF(va.value_reference = "Admitted", "true", "false") as hasBeenAdmitted
+        from visit v
+        join person_name pn on v.patient_id = pn.person_id and pn.voided = 0 and pn.preferred = 1
+        join patient_identifier pi on v.patient_id = pi.patient_id and pi.voided=0 and pi.preferred = 1
+        join patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
+        join global_property gp on gp.property="bahmni.primaryIdentifierType" and gp.property_value=pit.uuid
+        join person p on p.person_id = v.patient_id and p.voided = 0
+        join location l on l.uuid = ${visit_location_uuid} and v.location_id = l.location_id
+        left outer join visit_attribute va on va.visit_id = v.visit_id and va.attribute_type_id = (
+          select visit_attribute_type_id from visit_attribute_type where name="Admission Status"
+        ) and va.voided = 0
+        where v.date_stopped is null AND v.voided = 0',
+        'Sql query to get list of active patients',
+        uuid()
+);
+
+insert into global_property (`property`, `property_value`, `description`, `uuid`)
+values ('emrapi.sqlSearch.activePatientsByProvider','
+  select distinct concat(pn.given_name," ", pn.family_name) as name,
+  pi.identifier as identifier,
+  concat("",p.uuid) as uuid,
+  concat("",v.uuid) as activeVisitUuid,
+  IF(va.value_reference = "Admitted", "true", "false") as hasBeenAdmitted
+  from
+    visit v join person_name pn on v.patient_id = pn.person_id and pn.voided = 0 and v.voided=0
+    join patient_identifier pi on v.patient_id = pi.patient_id and pi.voided=0
+    join patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
+    join global_property gp on gp.property="bahmni.primaryIdentifierType" and gp.property_value=pit.uuid
+    join person p on p.person_id = v.patient_id  and p.voided=0
+    join encounter en on en.visit_id = v.visit_id and en.voided=0
+    join encounter_provider ep on ep.encounter_id = en.encounter_id  and ep.voided=0
+    join provider pr on ep.provider_id=pr.provider_id and pr.retired=0
+    join person per on pr.person_id=per.person_id and per.voided=0
+    join location l on l.uuid=${visit_location_uuid} and l.location_id = v.location_id
+    left outer join visit_attribute va on va.visit_id = v.visit_id and va.voided = 0 and va.attribute_type_id = (
+				select visit_attribute_type_id from visit_attribute_type where name="Admission Status"
+			)
+  where
+    v.date_stopped is null and
+    pr.uuid=${provider_uuid}
+    order by en.encounter_datetime desc',
+    'Sql query to get list of active patients by provider uuid',
+  uuid()
+);
+
+INSERT INTO global_property (`property`, `property_value`, `description`, `uuid`)
+VALUES ('emrapi.sqlSearch.patientsToAdmit',
+        'select distinct concat(pn.given_name,\' \', pn.family_name) as name,
+        pi.identifier as identifier,
+        concat("",p.uuid) as uuid,
+        concat("",v.uuid) as activeVisitUuid
+        from visit v
+        join person_name pn on v.patient_id = pn.person_id and pn.voided = 0 AND v.voided = 0
+        join patient_identifier pi on v.patient_id = pi.patient_id
+        join patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
+        join global_property gp on gp.property="bahmni.primaryIdentifierType" and gp.property_value=pit.uuid
+        join person p on v.patient_id = p.person_id
+        join encounter e on v.visit_id = e.visit_id
+        join obs o on e.encounter_id = o.encounter_id and o.voided = 0
+        join concept c on o.value_coded = c.concept_id
+        join concept_name cn on c.concept_id = cn.concept_id
+        join location l on l.uuid=${visit_location_uuid} and v.location_id = l.location_id
+        where v.date_stopped is null and cn.name = \'Admit Patient\' and v.visit_id not in (select visit_id
+        from encounter ie join encounter_type iet
+        on iet.encounter_type_id = ie.encounter_type
+        where iet.name = \'ADMISSION\')',
+        'Sql query to get list of patients to be admitted',
+        uuid()
+);
+
+INSERT INTO global_property (`property`, `property_value`, `description`, `uuid`)
+VALUES ('emrapi.sqlSearch.admittedPatients',
+        'select distinct
+          concat(pn.given_name," ", pn.family_name) as name,
+          pi.identifier as identifier,
+          concat("",p.uuid) as uuid,
+          concat("",v.uuid) as activeVisitUuid,
+          IF(va.value_reference = "Admitted", "true", "false") as hasBeenAdmitted
+        from visit v
+        join person_name pn on v.patient_id = pn.person_id and pn.voided = 0
+        join patient_identifier pi on v.patient_id = pi.patient_id
+        join patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
+        join global_property gp on gp.property="bahmni.primaryIdentifierType" and gp.property_value=pit.uuid
+        join person p on v.patient_id = p.person_id
+        join visit_attribute va on v.visit_id = va.visit_id and va.value_reference = "Admitted" and va.voided = 0
+        join visit_attribute_type vat on vat.visit_attribute_type_id = va.attribute_type_id and vat.name = "Admission Status"
+        join location l on l.uuid=${visit_location_uuid} and v.location_id = l.location_id
+        where v.date_stopped is null AND v.voided = 0',
+        'Sql query to get list of admitted patients',
+        uuid()
+);
+
+INSERT INTO global_property (`property`, `property_value`, `description`, `uuid`)
+VALUES ('emrapi.sqlSearch.patientsToDischarge',
+        'SELECT DISTINCT
+          concat(pn.given_name, \' \', pn.family_name) AS name,
+          pi.identifier AS identifier,
+          concat("", p.uuid) AS uuid,
+          concat("", v.uuid) AS activeVisitUuid,
+          IF(va.value_reference = "Admitted", "true", "false") as hasBeenAdmitted
+        FROM visit v
+        INNER JOIN person_name pn ON v.patient_id = pn.person_id and pn.voided is FALSE
+        INNER JOIN patient_identifier pi ON v.patient_id = pi.patient_id and pi.voided is FALSE
+        INNER JOIN patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
+        INNER JOIN global_property gp on gp.property="bahmni.primaryIdentifierType" and gp.property_value=pit.uuid
+        INNER JOIN person p ON v.patient_id = p.person_id
+        Inner Join (SELECT DISTINCT v.visit_id
+          FROM encounter en
+          INNER JOIN visit v ON v.visit_id = en.visit_id AND en.encounter_type =
+            (SELECT encounter_type_id
+              FROM encounter_type
+            WHERE name = "ADMISSION")) v1 on v1.visit_id = v.visit_id
+        INNER JOIN encounter e ON v.visit_id = e.visit_id
+        INNER JOIN obs o ON e.encounter_id = o.encounter_id
+        INNER JOIN concept_name cn ON o.value_coded = cn.concept_id AND cn.concept_name_type = "FULLY_SPECIFIED" AND cn.voided is FALSE
+        JOIN location l on l.uuid=${visit_location_uuid} and v.location_id = l.location_id
+        left outer join visit_attribute va on va.visit_id = v.visit_id and va.attribute_type_id =
+          (select visit_attribute_type_id from visit_attribute_type where name="Admission Status")
+        LEFT OUTER JOIN encounter e1 ON e1.visit_id = v.visit_id AND e1.encounter_type = (
+          SELECT encounter_type_id
+            FROM encounter_type
+          WHERE name = "DISCHARGE") AND e1.voided is FALSE
+        WHERE v.date_stopped IS NULL AND v.voided = 0 AND o.voided = 0 AND cn.name = "Discharge Patient" AND e1.encounter_id IS NULL',
+        'Sql query to get list of patients to discharge',
+        uuid()
+);
+
+INSERT INTO global_property (`property`, `property_value`, `description`, `uuid`)
+VALUES ('emrapi.sqlSearch.activePatientsByLocation',
+        'select distinct concat(pn.given_name," ", pn.family_name) as name,
+ pi.identifier as identifier,
+ concat("",p.uuid) as uuid,
+ concat("",v.uuid) as activeVisitUuid,
+ IF(va.value_reference = "Admitted", "true", "false") as hasBeenAdmitted
+ from
+   visit v join person_name pn on v.patient_id = pn.person_id and pn.voided = 0 and v.voided=0
+   join patient_identifier pi on v.patient_id = pi.patient_id and pi.voided=0
+   join patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
+   join global_property gp on gp.property="bahmni.primaryIdentifierType" and gp.property_value=pit.uuid
+   join person p on p.person_id = v.patient_id  and p.voided=0
+   join encounter en on en.visit_id = v.visit_id and en.voided=0
+   left outer join location loc on en.location_id = loc.location_id
+   join encounter_provider ep on ep.encounter_id = en.encounter_id  and ep.voided=0
+   join provider pr on ep.provider_id=pr.provider_id and pr.retired=0
+   join person per on pr.person_id=per.person_id and per.voided=0
+   left outer join visit_attribute va on va.visit_id = v.visit_id and va.attribute_type_id = (
+                select visit_attribute_type_id from visit_attribute_type where name="Admission Status"
+            )
+ where
+   v.date_stopped is null and
+   loc.uuid=${location_uuid}
+   order by en.encounter_datetime desc',
+        'SQL query to get list of active patients by location',
+        uuid()
+);
+
+INSERT INTO global_property (`property`, `property_value`, `description`, `uuid`)
+VALUES ('emrapi.sqlSearch.highRiskPatients',
+        'SELECT DISTINCT
+  concat(pn.given_name, " ", pn.family_name)           AS name,
+  pi.identifier                                        AS identifier,
+  concat("", p.uuid)                                   AS uuid,
+  concat("", v.uuid)                                   AS activeVisitUuid,
+  IF(va.value_reference = "Admitted", "true", "false") AS hasBeenAdmitted
+FROM person p
+  INNER JOIN person_name pn ON pn.person_id = p.person_id
+  INNER JOIN patient_identifier pi ON pn.person_id = pi.patient_id
+  INNER JOIN patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
+  INNER JOIN global_property gp on gp.property="bahmni.primaryIdentifierType" and gp.property_value=pit.uuid
+  INNER JOIN visit v ON v.patient_id = p.person_id AND v.date_stopped IS NULL AND v.voided = 0
+  INNER JOIN (SELECT
+                max(test_obs.obs_group_id) AS max_id,
+                test_obs.concept_id,
+                test_obs.person_id
+              FROM obs test_obs
+                INNER JOIN concept c ON c.concept_id = test_obs.concept_id AND test_obs.voided = 0
+                INNER JOIN concept_name cn
+                  ON c.concept_id = cn.concept_id AND cn.concept_name_type = "FULLY_SPECIFIED" AND
+                     cn.name IN (${testName})
+              GROUP BY test_obs.person_id, test_obs.concept_id) AS tests ON tests.person_id = v.patient_id
+  INNER JOIN obs abnormal_obs
+    ON abnormal_obs.obs_group_id = tests.max_id AND abnormal_obs.value_coded = 1 AND abnormal_obs.voided = 0
+  INNER JOIN concept abnormal_concept ON abnormal_concept.concept_id = abnormal_obs.concept_id
+  INNER JOIN concept_name abnormal_concept_name
+    ON abnormal_concept.concept_id = abnormal_concept_name.concept_id AND
+       abnormal_concept_name.concept_name_type = "FULLY_SPECIFIED" AND
+       abnormal_concept_name.name IN ("LAB_ABNORMAL")
+  LEFT OUTER JOIN visit_attribute va ON va.visit_id = v.visit_id AND va.attribute_type_id =
+                                                                     (SELECT visit_attribute_type_id
+                                                                      FROM visit_attribute_type
+                                                                      WHERE name = "Admission Status")',
+        'SQL QUERY TO get LIST of patients with high risk',
+        uuid()
+);
+
+
+INSERT INTO global_property (`property`, `property_value`, `description`, `uuid`)
+VALUES ('emrapi.sqlSearch.patientsHasPendingOrders',
+        'select distinct
+          concat(pn.given_name, " ", pn.family_name) as name,
+          pi.identifier as identifier,
+          concat("",p.uuid) as uuid,
+          concat("",v.uuid) as activeVisitUuid,
+          IF(va.value_reference = "Admitted", "true", "false") as hasBeenAdmitted
+        from visit v
+        join person_name pn on v.patient_id = pn.person_id and pn.voided = 0
+        join patient_identifier pi on v.patient_id = pi.patient_id
+        join patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
+        join global_property gp on gp.property="bahmni.primaryIdentifierType" and gp.property_value=pit.uuid
+        join person p on p.person_id = v.patient_id
+        join orders on orders.patient_id = v.patient_id
+        join order_type on orders.order_type_id = order_type.order_type_id and order_type.name != "Order" and order_type.name != "Drug Order"
+        left outer join visit_attribute va on va.visit_id = v.visit_id and va.voided = 0 and va.attribute_type_id =
+          (select visit_attribute_type_id from visit_attribute_type where name="Admission Status")
+        where v.date_stopped is null AND v.voided = 0 and order_id not in
+          (select obs.order_id
+            from obs
+          where person_id = pn.person_id and order_id = orders.order_id)',
+        'Sql query to get list of patients who has pending orders',
+        uuid()
+);
+
+
diff --git a/bahmnicore-omod/src/main/resources/liquibase.xml b/bahmnicore-omod/src/main/resources/liquibase.xml
index ac47fd82f8..79ca4bc173 100644
--- a/bahmnicore-omod/src/main/resources/liquibase.xml
+++ b/bahmnicore-omod/src/main/resources/liquibase.xml
@@ -3874,6 +3874,11 @@
         <sqlFile path="V1_98_WardsListSql.sql"/>
     </changeSet>
 
+    <changeSet id="bahmni-PatientSearch-Update-202201241152" author="Kavitha S, Soorya Kumaran C">
+        <comment>update the search query to obtain active patients based on preffered and non voided</comment>
+        <sqlFile path="V1_99_PatientSearchSql.sql"/>
+    </changeSet>
+
     <changeSet id="bahmni-201703061748" author="Shruthi P, Pushpa">
         <preConditions onFail="MARK_RAN">
             <sqlCheck expectedResult="1">

From 9bd225173034dc4ff84be74c63c69b61571b5c50 Mon Sep 17 00:00:00 2001
From: Soorya Kumaran C <90232857+SooryaKumaranC-tw@users.noreply.github.com>
Date: Tue, 25 Jan 2022 11:02:55 +0530
Subject: [PATCH 2/3] BAH-1236 | Refactor. Display preferred patients in active
 tabs

Co-authored-by: Kavitha S <kavitha.s@thoughtworks.com>
---
 .../main/resources/V1_99_PatientSearchSql.sql | 239 +-----------------
 .../src/main/resources/liquibase.xml          |   4 +-
 2 files changed, 10 insertions(+), 233 deletions(-)

diff --git a/bahmnicore-omod/src/main/resources/V1_99_PatientSearchSql.sql b/bahmnicore-omod/src/main/resources/V1_99_PatientSearchSql.sql
index 5f0b66c6d6..4482b79396 100644
--- a/bahmnicore-omod/src/main/resources/V1_99_PatientSearchSql.sql
+++ b/bahmnicore-omod/src/main/resources/V1_99_PatientSearchSql.sql
@@ -1,241 +1,18 @@
-DELETE FROM global_property
-WHERE property IN (
-  'emrapi.sqlSearch.activePatients',
-  'emrapi.sqlSearch.activePatientsByProvider',
-  'emrapi.sqlSearch.patientsToAdmit',
-  'emrapi.sqlSearch.admittedPatients',
-  'emrapi.sqlSearch.patientsToDischarge',
-  'emrapi.sqlSearch.activePatientsByLocation',
-  'emrapi.sqlSearch.highRiskPatients',
-  'emrapi.sqlSearch.patientsHasPendingOrders'
-);
-
-INSERT INTO global_property (`property`, `property_value`, `description`, `uuid`)
-VALUES ('emrapi.sqlSearch.activePatients',
-        'select distinct
-          concat(pn.given_name,\' \', pn.family_name) as name,
+UPDATE global_property SET property_value = "select distinct
+          concat(pn.given_name,' ', pn.family_name) as name,
           pi.identifier as identifier,
-          concat("",p.uuid) as uuid,
-          IF(va.value_reference = "Admitted", "true", "false") as hasBeenAdmitted
+          concat('',p.uuid) as uuid,
+          IF(va.value_reference = \"Admitted\", \"true\", \"false\") as hasBeenAdmitted
         from visit v
         join person_name pn on v.patient_id = pn.person_id and pn.voided = 0 and pn.preferred = 1
         join patient_identifier pi on v.patient_id = pi.patient_id and pi.voided=0 and pi.preferred = 1
         join patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
-        join global_property gp on gp.property="bahmni.primaryIdentifierType" and gp.property_value=pit.uuid
+        join global_property gp on gp.property=\"bahmni.primaryIdentifierType\" and gp.property_value=pit.uuid
         join person p on p.person_id = v.patient_id and p.voided = 0
         join location l on l.uuid = ${visit_location_uuid} and v.location_id = l.location_id
         left outer join visit_attribute va on va.visit_id = v.visit_id and va.attribute_type_id = (
-          select visit_attribute_type_id from visit_attribute_type where name="Admission Status"
+          select visit_attribute_type_id from visit_attribute_type where name=\"Admission Status\"
         ) and va.voided = 0
-        where v.date_stopped is null AND v.voided = 0',
-        'Sql query to get list of active patients',
-        uuid()
-);
-
-insert into global_property (`property`, `property_value`, `description`, `uuid`)
-values ('emrapi.sqlSearch.activePatientsByProvider','
-  select distinct concat(pn.given_name," ", pn.family_name) as name,
-  pi.identifier as identifier,
-  concat("",p.uuid) as uuid,
-  concat("",v.uuid) as activeVisitUuid,
-  IF(va.value_reference = "Admitted", "true", "false") as hasBeenAdmitted
-  from
-    visit v join person_name pn on v.patient_id = pn.person_id and pn.voided = 0 and v.voided=0
-    join patient_identifier pi on v.patient_id = pi.patient_id and pi.voided=0
-    join patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
-    join global_property gp on gp.property="bahmni.primaryIdentifierType" and gp.property_value=pit.uuid
-    join person p on p.person_id = v.patient_id  and p.voided=0
-    join encounter en on en.visit_id = v.visit_id and en.voided=0
-    join encounter_provider ep on ep.encounter_id = en.encounter_id  and ep.voided=0
-    join provider pr on ep.provider_id=pr.provider_id and pr.retired=0
-    join person per on pr.person_id=per.person_id and per.voided=0
-    join location l on l.uuid=${visit_location_uuid} and l.location_id = v.location_id
-    left outer join visit_attribute va on va.visit_id = v.visit_id and va.voided = 0 and va.attribute_type_id = (
-				select visit_attribute_type_id from visit_attribute_type where name="Admission Status"
-			)
-  where
-    v.date_stopped is null and
-    pr.uuid=${provider_uuid}
-    order by en.encounter_datetime desc',
-    'Sql query to get list of active patients by provider uuid',
-  uuid()
-);
-
-INSERT INTO global_property (`property`, `property_value`, `description`, `uuid`)
-VALUES ('emrapi.sqlSearch.patientsToAdmit',
-        'select distinct concat(pn.given_name,\' \', pn.family_name) as name,
-        pi.identifier as identifier,
-        concat("",p.uuid) as uuid,
-        concat("",v.uuid) as activeVisitUuid
-        from visit v
-        join person_name pn on v.patient_id = pn.person_id and pn.voided = 0 AND v.voided = 0
-        join patient_identifier pi on v.patient_id = pi.patient_id
-        join patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
-        join global_property gp on gp.property="bahmni.primaryIdentifierType" and gp.property_value=pit.uuid
-        join person p on v.patient_id = p.person_id
-        join encounter e on v.visit_id = e.visit_id
-        join obs o on e.encounter_id = o.encounter_id and o.voided = 0
-        join concept c on o.value_coded = c.concept_id
-        join concept_name cn on c.concept_id = cn.concept_id
-        join location l on l.uuid=${visit_location_uuid} and v.location_id = l.location_id
-        where v.date_stopped is null and cn.name = \'Admit Patient\' and v.visit_id not in (select visit_id
-        from encounter ie join encounter_type iet
-        on iet.encounter_type_id = ie.encounter_type
-        where iet.name = \'ADMISSION\')',
-        'Sql query to get list of patients to be admitted',
-        uuid()
-);
-
-INSERT INTO global_property (`property`, `property_value`, `description`, `uuid`)
-VALUES ('emrapi.sqlSearch.admittedPatients',
-        'select distinct
-          concat(pn.given_name," ", pn.family_name) as name,
-          pi.identifier as identifier,
-          concat("",p.uuid) as uuid,
-          concat("",v.uuid) as activeVisitUuid,
-          IF(va.value_reference = "Admitted", "true", "false") as hasBeenAdmitted
-        from visit v
-        join person_name pn on v.patient_id = pn.person_id and pn.voided = 0
-        join patient_identifier pi on v.patient_id = pi.patient_id
-        join patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
-        join global_property gp on gp.property="bahmni.primaryIdentifierType" and gp.property_value=pit.uuid
-        join person p on v.patient_id = p.person_id
-        join visit_attribute va on v.visit_id = va.visit_id and va.value_reference = "Admitted" and va.voided = 0
-        join visit_attribute_type vat on vat.visit_attribute_type_id = va.attribute_type_id and vat.name = "Admission Status"
-        join location l on l.uuid=${visit_location_uuid} and v.location_id = l.location_id
-        where v.date_stopped is null AND v.voided = 0',
-        'Sql query to get list of admitted patients',
-        uuid()
-);
-
-INSERT INTO global_property (`property`, `property_value`, `description`, `uuid`)
-VALUES ('emrapi.sqlSearch.patientsToDischarge',
-        'SELECT DISTINCT
-          concat(pn.given_name, \' \', pn.family_name) AS name,
-          pi.identifier AS identifier,
-          concat("", p.uuid) AS uuid,
-          concat("", v.uuid) AS activeVisitUuid,
-          IF(va.value_reference = "Admitted", "true", "false") as hasBeenAdmitted
-        FROM visit v
-        INNER JOIN person_name pn ON v.patient_id = pn.person_id and pn.voided is FALSE
-        INNER JOIN patient_identifier pi ON v.patient_id = pi.patient_id and pi.voided is FALSE
-        INNER JOIN patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
-        INNER JOIN global_property gp on gp.property="bahmni.primaryIdentifierType" and gp.property_value=pit.uuid
-        INNER JOIN person p ON v.patient_id = p.person_id
-        Inner Join (SELECT DISTINCT v.visit_id
-          FROM encounter en
-          INNER JOIN visit v ON v.visit_id = en.visit_id AND en.encounter_type =
-            (SELECT encounter_type_id
-              FROM encounter_type
-            WHERE name = "ADMISSION")) v1 on v1.visit_id = v.visit_id
-        INNER JOIN encounter e ON v.visit_id = e.visit_id
-        INNER JOIN obs o ON e.encounter_id = o.encounter_id
-        INNER JOIN concept_name cn ON o.value_coded = cn.concept_id AND cn.concept_name_type = "FULLY_SPECIFIED" AND cn.voided is FALSE
-        JOIN location l on l.uuid=${visit_location_uuid} and v.location_id = l.location_id
-        left outer join visit_attribute va on va.visit_id = v.visit_id and va.attribute_type_id =
-          (select visit_attribute_type_id from visit_attribute_type where name="Admission Status")
-        LEFT OUTER JOIN encounter e1 ON e1.visit_id = v.visit_id AND e1.encounter_type = (
-          SELECT encounter_type_id
-            FROM encounter_type
-          WHERE name = "DISCHARGE") AND e1.voided is FALSE
-        WHERE v.date_stopped IS NULL AND v.voided = 0 AND o.voided = 0 AND cn.name = "Discharge Patient" AND e1.encounter_id IS NULL',
-        'Sql query to get list of patients to discharge',
-        uuid()
-);
-
-INSERT INTO global_property (`property`, `property_value`, `description`, `uuid`)
-VALUES ('emrapi.sqlSearch.activePatientsByLocation',
-        'select distinct concat(pn.given_name," ", pn.family_name) as name,
- pi.identifier as identifier,
- concat("",p.uuid) as uuid,
- concat("",v.uuid) as activeVisitUuid,
- IF(va.value_reference = "Admitted", "true", "false") as hasBeenAdmitted
- from
-   visit v join person_name pn on v.patient_id = pn.person_id and pn.voided = 0 and v.voided=0
-   join patient_identifier pi on v.patient_id = pi.patient_id and pi.voided=0
-   join patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
-   join global_property gp on gp.property="bahmni.primaryIdentifierType" and gp.property_value=pit.uuid
-   join person p on p.person_id = v.patient_id  and p.voided=0
-   join encounter en on en.visit_id = v.visit_id and en.voided=0
-   left outer join location loc on en.location_id = loc.location_id
-   join encounter_provider ep on ep.encounter_id = en.encounter_id  and ep.voided=0
-   join provider pr on ep.provider_id=pr.provider_id and pr.retired=0
-   join person per on pr.person_id=per.person_id and per.voided=0
-   left outer join visit_attribute va on va.visit_id = v.visit_id and va.attribute_type_id = (
-                select visit_attribute_type_id from visit_attribute_type where name="Admission Status"
-            )
- where
-   v.date_stopped is null and
-   loc.uuid=${location_uuid}
-   order by en.encounter_datetime desc',
-        'SQL query to get list of active patients by location',
-        uuid()
-);
-
-INSERT INTO global_property (`property`, `property_value`, `description`, `uuid`)
-VALUES ('emrapi.sqlSearch.highRiskPatients',
-        'SELECT DISTINCT
-  concat(pn.given_name, " ", pn.family_name)           AS name,
-  pi.identifier                                        AS identifier,
-  concat("", p.uuid)                                   AS uuid,
-  concat("", v.uuid)                                   AS activeVisitUuid,
-  IF(va.value_reference = "Admitted", "true", "false") AS hasBeenAdmitted
-FROM person p
-  INNER JOIN person_name pn ON pn.person_id = p.person_id
-  INNER JOIN patient_identifier pi ON pn.person_id = pi.patient_id
-  INNER JOIN patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
-  INNER JOIN global_property gp on gp.property="bahmni.primaryIdentifierType" and gp.property_value=pit.uuid
-  INNER JOIN visit v ON v.patient_id = p.person_id AND v.date_stopped IS NULL AND v.voided = 0
-  INNER JOIN (SELECT
-                max(test_obs.obs_group_id) AS max_id,
-                test_obs.concept_id,
-                test_obs.person_id
-              FROM obs test_obs
-                INNER JOIN concept c ON c.concept_id = test_obs.concept_id AND test_obs.voided = 0
-                INNER JOIN concept_name cn
-                  ON c.concept_id = cn.concept_id AND cn.concept_name_type = "FULLY_SPECIFIED" AND
-                     cn.name IN (${testName})
-              GROUP BY test_obs.person_id, test_obs.concept_id) AS tests ON tests.person_id = v.patient_id
-  INNER JOIN obs abnormal_obs
-    ON abnormal_obs.obs_group_id = tests.max_id AND abnormal_obs.value_coded = 1 AND abnormal_obs.voided = 0
-  INNER JOIN concept abnormal_concept ON abnormal_concept.concept_id = abnormal_obs.concept_id
-  INNER JOIN concept_name abnormal_concept_name
-    ON abnormal_concept.concept_id = abnormal_concept_name.concept_id AND
-       abnormal_concept_name.concept_name_type = "FULLY_SPECIFIED" AND
-       abnormal_concept_name.name IN ("LAB_ABNORMAL")
-  LEFT OUTER JOIN visit_attribute va ON va.visit_id = v.visit_id AND va.attribute_type_id =
-                                                                     (SELECT visit_attribute_type_id
-                                                                      FROM visit_attribute_type
-                                                                      WHERE name = "Admission Status")',
-        'SQL QUERY TO get LIST of patients with high risk',
-        uuid()
-);
-
-
-INSERT INTO global_property (`property`, `property_value`, `description`, `uuid`)
-VALUES ('emrapi.sqlSearch.patientsHasPendingOrders',
-        'select distinct
-          concat(pn.given_name, " ", pn.family_name) as name,
-          pi.identifier as identifier,
-          concat("",p.uuid) as uuid,
-          concat("",v.uuid) as activeVisitUuid,
-          IF(va.value_reference = "Admitted", "true", "false") as hasBeenAdmitted
-        from visit v
-        join person_name pn on v.patient_id = pn.person_id and pn.voided = 0
-        join patient_identifier pi on v.patient_id = pi.patient_id
-        join patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
-        join global_property gp on gp.property="bahmni.primaryIdentifierType" and gp.property_value=pit.uuid
-        join person p on p.person_id = v.patient_id
-        join orders on orders.patient_id = v.patient_id
-        join order_type on orders.order_type_id = order_type.order_type_id and order_type.name != "Order" and order_type.name != "Drug Order"
-        left outer join visit_attribute va on va.visit_id = v.visit_id and va.voided = 0 and va.attribute_type_id =
-          (select visit_attribute_type_id from visit_attribute_type where name="Admission Status")
-        where v.date_stopped is null AND v.voided = 0 and order_id not in
-          (select obs.order_id
-            from obs
-          where person_id = pn.person_id and order_id = orders.order_id)',
-        'Sql query to get list of patients who has pending orders',
-        uuid()
-);
-
+        where v.date_stopped is null AND v.voided = 0;"
+where property = "emrapi.sqlSearch.activePatients";
 
diff --git a/bahmnicore-omod/src/main/resources/liquibase.xml b/bahmnicore-omod/src/main/resources/liquibase.xml
index 79ca4bc173..c18ffbd851 100644
--- a/bahmnicore-omod/src/main/resources/liquibase.xml
+++ b/bahmnicore-omod/src/main/resources/liquibase.xml
@@ -3874,8 +3874,8 @@
         <sqlFile path="V1_98_WardsListSql.sql"/>
     </changeSet>
 
-    <changeSet id="bahmni-PatientSearch-Update-202201241152" author="Kavitha S, Soorya Kumaran C">
-        <comment>update the search query to obtain active patients based on preffered and non voided</comment>
+    <changeSet id="bahmni-PatientSearch-Update-202201250930" author="Kavitha S, Soorya Kumaran C">
+        <comment>update the property value of emrapi.sqlSearch.activePatients search query to obtain active patients based on preferred and non voided</comment>
         <sqlFile path="V1_99_PatientSearchSql.sql"/>
     </changeSet>
 

From 162bd9fb024c1a7ea5a6b3a2049120719b28ed26 Mon Sep 17 00:00:00 2001
From: Kavitha S <kavitha.s@thoughtworks.com>
Date: Tue, 25 Jan 2022 15:58:10 +0530
Subject: [PATCH 3/3] BAH-1374 | Add. Display preferred patients under all
 clinical tabs

Co-authored-by: Soorya Kumaran C <sooryakumaran.c@thoughtworks.com>
---
 .../main/resources/V1_99_PatientSearchSql.sql | 51 ++++++++++++++++++-
 .../src/main/resources/liquibase.xml          |  4 +-
 2 files changed, 52 insertions(+), 3 deletions(-)

diff --git a/bahmnicore-omod/src/main/resources/V1_99_PatientSearchSql.sql b/bahmnicore-omod/src/main/resources/V1_99_PatientSearchSql.sql
index 4482b79396..95313140b7 100644
--- a/bahmnicore-omod/src/main/resources/V1_99_PatientSearchSql.sql
+++ b/bahmnicore-omod/src/main/resources/V1_99_PatientSearchSql.sql
@@ -14,5 +14,54 @@ UPDATE global_property SET property_value = "select distinct
           select visit_attribute_type_id from visit_attribute_type where name=\"Admission Status\"
         ) and va.voided = 0
         where v.date_stopped is null AND v.voided = 0;"
-where property = "emrapi.sqlSearch.activePatients";
+WHERE property = "emrapi.sqlSearch.activePatients";
 
+UPDATE global_property SET property_value =
+  "select distinct concat(pn.given_name,' ', pn.family_name) as name,
+  pi.identifier as identifier,
+  concat('',p.uuid) as uuid,
+  IF(va.value_reference = \"Admitted\", \"true\", \"false\") as hasBeenAdmitted
+  from
+    visit v join person_name pn on v.patient_id = pn.person_id and pn.voided = 0 and v.voided=0 and pn.preferred = 1
+    join patient_identifier pi on v.patient_id = pi.patient_id and pi.voided=0 and pi.preferred = 1
+    join patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
+    join global_property gp on gp.property=\"bahmni.primaryIdentifierType\" and gp.property_value=pit.uuid
+    join person p on p.person_id = v.patient_id  and p.voided=0
+    join encounter en on en.visit_id = v.visit_id and en.voided=0
+    join encounter_provider ep on ep.encounter_id = en.encounter_id  and ep.voided=0
+    join provider pr on ep.provider_id=pr.provider_id and pr.retired=0
+    join person per on pr.person_id=per.person_id and per.voided=0
+    join location l on l.uuid=${visit_location_uuid} and l.location_id = v.location_id
+    left outer join visit_attribute va on va.visit_id = v.visit_id and va.voided = 0 and va.attribute_type_id = (
+				select visit_attribute_type_id from visit_attribute_type where name=\"Admission Status\"
+			)
+  where
+    v.date_stopped is null and
+    pr.uuid=${provider_uuid}
+    order by en.encounter_datetime desc"
+WHERE property = "emrapi.sqlSearch.activePatientsByProvider";
+
+UPDATE global_property SET property_value =
+ "select distinct concat(pn.given_name,' ', pn.family_name) as name,
+ pi.identifier as identifier,
+ concat('',p.uuid) as uuid,
+ IF(va.value_reference = \"Admitted\", \"true\", \"false\") as hasBeenAdmitted
+ from
+   visit v join person_name pn on v.patient_id = pn.person_id and pn.voided = 0 and v.voided=0 and pn.preferred = 1
+   join patient_identifier pi on v.patient_id = pi.patient_id and pi.voided=0 and pi.preferred = 1
+   join patient_identifier_type pit on pi.identifier_type = pit.patient_identifier_type_id
+   join global_property gp on gp.property=\"bahmni.primaryIdentifierType\" and gp.property_value=pit.uuid
+   join person p on p.person_id = v.patient_id  and p.voided=0
+   join encounter en on en.visit_id = v.visit_id and en.voided=0
+   left outer join location loc on en.location_id = loc.location_id
+   join encounter_provider ep on ep.encounter_id = en.encounter_id  and ep.voided=0
+   join provider pr on ep.provider_id=pr.provider_id and pr.retired=0
+   join person per on pr.person_id=per.person_id and per.voided=0
+   left outer join visit_attribute va on va.visit_id = v.visit_id and va.attribute_type_id = (
+                select visit_attribute_type_id from visit_attribute_type where name=\"Admission Status\"
+            )
+ where
+   v.date_stopped is null and
+   loc.uuid=${location_uuid}
+   order by en.encounter_datetime desc"
+WHERE property = "emrapi.sqlSearch.activePatientsByLocation";
\ No newline at end of file
diff --git a/bahmnicore-omod/src/main/resources/liquibase.xml b/bahmnicore-omod/src/main/resources/liquibase.xml
index c18ffbd851..13bdd9fd28 100644
--- a/bahmnicore-omod/src/main/resources/liquibase.xml
+++ b/bahmnicore-omod/src/main/resources/liquibase.xml
@@ -3874,8 +3874,8 @@
         <sqlFile path="V1_98_WardsListSql.sql"/>
     </changeSet>
 
-    <changeSet id="bahmni-PatientSearch-Update-202201250930" author="Kavitha S, Soorya Kumaran C">
-        <comment>update the property value of emrapi.sqlSearch.activePatients search query to obtain active patients based on preferred and non voided</comment>
+    <changeSet id="bahmni-PatientSearch-Update-202201250315" author="Kavitha S, Soorya Kumaran C">
+        <comment>Update the property values for searching active patients based on preferred and non voided</comment>
         <sqlFile path="V1_99_PatientSearchSql.sql"/>
     </changeSet>