Skip to content

Commit

Permalink
KH-532: Orders table to provide more meaningfully flattened data. (#12)
Browse files Browse the repository at this point in the history
  • Loading branch information
Ruhanga authored Jun 13, 2024
1 parent c3ee49c commit d24e7d9
Show file tree
Hide file tree
Showing 6 changed files with 223 additions and 92 deletions.
97 changes: 56 additions & 41 deletions analytics/dsl/export/tables/orders.sql
Original file line number Diff line number Diff line change
@@ -1,43 +1,58 @@
CREATE TABLE `orders` (
`order_id` BIGINT,
`patient_id` BIGINT,
`order_type_id` BIGINT,
`order_type_name` VARCHAR,
`order_type_uuid` VARCHAR,
`order_type_java_class_name` VARCHAR,
`concept_id` BIGINT,
`orderer` BIGINT,
`encounter_id` BIGINT,
`encounter_datetime` TIMESTAMP,
`encounter_type_name` VARCHAR,
`encounter_type_uuid` VARCHAR,
`care_setting` BIGINT,
`care_setting_name` VARCHAR,
`care_setting_type` VARCHAR,
`care_setting_uuid` VARCHAR,
`instructions` VARCHAR,
`date_activated` TIMESTAMP,
`auto_expire_date` TIMESTAMP,
`date_stopped` TIMESTAMP,
`order_reason` BIGINT,
`order_reason_non_coded` VARCHAR,
`date_created` TIMESTAMP,
`creator` BIGINT,
`voided_by` BIGINT,
`date_voided` TIMESTAMP,
`void_reason` VARCHAR,
`accession_number` VARCHAR,
`uuid` VARCHAR,
`order_number` VARCHAR,
`previous_order_id` BIGINT,
`order_action` VARCHAR,
`comment_to_fulfiller` VARCHAR,
`scheduled_date` TIMESTAMP,
`order_group_id` BIGINT,
`sort_weight` DOUBLE,
`encounter_voided` BOOLEAN,
`voided` BOOLEAN,
`order_type_retired` BOOLEAN,
`encounter_type_retired` BOOLEAN,
`care_setting_retired` BOOLEAN
`order_id` int,
`patient_uuid` VARCHAR,
`order_type_name` VARCHAR,
`order_type_uuid` VARCHAR,
`order_type_java_class_name` VARCHAR,
`order_name` VARCHAR,
`concept_uuid` VARCHAR,
`orderer` int,
`encounter_uuid` VARCHAR,
`encounter_datetime` datetime,
`encounter_type_name` VARCHAR,
`encounter_type_uuid` VARCHAR,
`care_setting_name` VARCHAR,
`care_setting_type` VARCHAR,
`care_setting_uuid` VARCHAR,
`instructions` VARCHAR,
`date_activated` TIMESTAMP,
`auto_expire_date` TIMESTAMP,
`date_stopped` TIMESTAMP,
`order_reason` VARCHAR,
`order_reason_uuid` VARCHAR,
`order_reason_non_coded` VARCHAR,
`date_created` datetime,
`creator_uuid` VARCHAR,
`voided_by` int,
`date_voided` TIMESTAMP,
`void_reason` VARCHAR,
`accession_number` VARCHAR,
`uuid` VARCHAR,
`order_number` VARCHAR,
`previous_order_id` int,
`order_action` VARCHAR,
`comment_to_fulfiller` VARCHAR,
`scheduled_date` TIMESTAMP,
`order_group_id` int,
`sort_weight` DOUBLE,
`encounter_voided` BOOLEAN,
`voided` BOOLEAN,
`order_type_retired` BOOLEAN,
`encounter_type_retired` BOOLEAN,
`care_setting_retired` BOOLEAN,
`drug_name` VARCHAR,
`dose` DOUBLE,
`dose_unit_name` VARCHAR,
`frequency` VARCHAR,
`route_name` VARCHAR,
`quantity` DOUBLE,
`quantity_unit_name` VARCHAR,
`duration` int,
`duration_unit_name` VARCHAR,
`drug_uuid` VARCHAR,
`dose_unit_uuid` VARCHAR,
`quantity_unit_uuid` VARCHAR,
`route_uuid` VARCHAR,
`duration_unit_uuid` VARCHAR,
`frequency_uuid` VARCHAR
)
65 changes: 54 additions & 11 deletions analytics/dsl/flattening/queries/orders.sql
Original file line number Diff line number Diff line change
@@ -1,28 +1,28 @@
select
SELECT
orders.order_id AS order_id,
orders.patient_id AS patient_id,
orders.order_type_id AS order_type_id,
person.uuid AS patient_uuid,
order_type.name AS order_type_name,
order_type.uuid AS order_type_uuid,
order_type.java_class_name AS order_type_java_class_name,
orders.concept_id AS concept_id,
concept_concept_name.name AS order_name,
concept.uuid AS concept_uuid,
orders.orderer AS orderer,
orders.encounter_id AS encounter_id,
encounter.uuid AS encounter_uuid,
encounter.encounter_datetime AS encounter_datetime,
encounter_type.name AS encounter_type_name,
encounter_type.uuid AS encounter_type_uuid,
orders.care_setting AS care_setting,
care_setting.name AS care_setting_name,
care_setting.care_setting_type AS care_setting_type,
care_setting.uuid AS care_setting_uuid,
orders.instructions AS instructions,
orders.date_activated AS date_activated,
orders.auto_expire_date AS auto_expire_date,
orders.date_stopped AS date_stopped,
orders.order_reason AS order_reason,
concept_order_reason_name.name AS order_reason,
concept_order_reason_name.uuid AS order_reason_uuid,
orders.order_reason_non_coded AS order_reason_non_coded,
orders.date_created AS date_created,
orders.creator AS creator,
creator.uuid AS creator_uuid,
orders.voided_by AS voided_by,
orders.date_voided AS date_voided,
orders.void_reason AS void_reason,
Expand All @@ -39,10 +39,53 @@ select
orders.voided AS voided,
order_type.retired AS order_type_retired,
encounter_type.retired AS encounter_type_retired,
care_setting.retired AS care_setting_retired
from
care_setting.retired AS care_setting_retired,
drug.name AS drug_name,
drug_order.dose AS dose,
concept_dose_unit_name.name AS dose_unit_name,
concept_frequency_name.name AS frequency,
concept_route_name.name AS route_name,
drug_order.quantity AS quantity,
concept_quantity_unit_name.name AS quantity_unit_name,
drug_order.duration AS duration,
concept_duration_unit_name.name AS duration_unit_name,
drug.uuid AS drug_uuid,
dose_unit.uuid AS dose_unit_uuid,
quantity_unit.uuid AS quantity_unit_uuid,
route.uuid AS route_uuid,
duration_unit.uuid AS duration_unit_uuid,
concept_frequency.uuid AS frequency_uuid
FROM
orders
LEFT JOIN person person ON person.person_id = orders.patient_id
LEFT JOIN person creator ON orders.creator = creator.person_id
LEFT JOIN order_type order_type ON orders.order_type_id = order_type.order_type_id
LEFT JOIN concept concept ON concept.concept_id = orders.concept_id
LEFT JOIN concept_name concept_concept_name ON orders.concept_id = concept_concept_name.concept_id AND concept_concept_name.locale LIKE 'en' AND concept_concept_name.voided = false AND concept_concept_name.locale_preferred = true

LEFT JOIN concept concept_order_reason ON concept_order_reason.concept_id = orders.concept_id
LEFT JOIN concept_name concept_order_reason_name ON orders.order_reason = concept_order_reason_name.concept_id AND concept_concept_name.locale LIKE 'en' AND concept_concept_name.voided = false AND concept_concept_name.locale_preferred = true

LEFT JOIN care_setting care_setting ON orders.care_setting = care_setting.care_setting_id
LEFT JOIN encounter encounter ON encounter.encounter_id = orders.encounter_id
LEFT JOIN encounter_type encounter_type ON encounter.encounter_type = encounter_type.encounter_type_id
LEFT JOIN encounter_type encounter_type ON encounter.encounter_type = encounter_type.encounter_type_id

LEFT JOIN drug_order drug_order ON drug_order.order_id = orders.order_id

LEFT JOIN concept dose_unit ON drug_order.dose_units = dose_unit.concept_id
LEFT JOIN concept_name concept_dose_unit_name ON dose_unit.concept_id= concept_dose_unit_name.concept_id AND concept_dose_unit_name.locale LIKE 'en' AND concept_dose_unit_name.voided = false AND concept_dose_unit_name.locale_preferred = true

LEFT JOIN concept quantity_unit ON drug_order.quantity_units = quantity_unit.concept_id
LEFT JOIN concept_name concept_quantity_unit_name ON quantity_unit.concept_id = concept_quantity_unit_name.concept_id AND concept_quantity_unit_name.locale LIKE 'en' AND concept_quantity_unit_name.voided = false AND concept_quantity_unit_name.locale_preferred = true

LEFT JOIN concept route ON drug_order.route = route.concept_id
LEFT JOIN concept_name concept_route_name ON route.concept_id = concept_route_name.concept_id AND concept_route_name.locale LIKE 'en' AND concept_route_name.voided = false AND concept_route_name.locale_preferred = true

LEFT JOIN concept duration_unit ON drug_order.duration_units = duration_unit.concept_id
LEFT JOIN concept_name concept_duration_unit_name ON duration_unit.concept_id = concept_duration_unit_name.concept_id AND concept_duration_unit_name.locale LIKE 'en' AND concept_duration_unit_name.voided = false AND concept_duration_unit_name.locale_preferred = true

LEFT JOIN order_frequency frequency ON drug_order.frequency = frequency.order_frequency_id
LEFT JOIN concept concept_frequency ON concept_frequency.concept_id = frequency.concept_id
LEFT JOIN concept_name concept_frequency_name ON concept_frequency.concept_id = concept_frequency_name.concept_id AND concept_frequency_name.locale LIKE 'en' AND concept_frequency_name.voided = false AND concept_frequency_name.locale_preferred = true

LEFT JOIN drug drug ON drug_order.drug_inventory_id = drug.drug_id
22 changes: 22 additions & 0 deletions analytics/dsl/flattening/tables/openmrs/drug.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
CREATE TABLE `drug` (
`drug_id` int,
`concept_id` int,
`name` VARCHAR,
`combination` BOOLEAN,
`dosage_form` int,
`maximum_daily_dose` double,
`minimum_daily_dose` double,
`route` int,
`creator` int,
`date_created` TIMESTAMP,
`retired` BOOLEAN,
`changed_by` int,
`date_changed` TIMESTAMP,
`retired_by` int,
`date_retired` TIMESTAMP,
`retire_reason` VARCHAR,
`uuid` VARCHAR,
`strength` VARCHAR,
`dose_limit_units` int,
PRIMARY KEY (`drug_id`) NOT ENFORCED
)
21 changes: 21 additions & 0 deletions analytics/dsl/flattening/tables/openmrs/drug_order.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
CREATE TABLE `drug_order` (
`order_id` int,
`drug_inventory_id` int,
`dose` double,
`as_needed` BOOLEAN,
`dosing_type` VARCHAR,
`quantity` double,
`as_needed_condition` VARCHAR,
`num_refills` int,
`dosing_instructions` VARCHAR,
`duration` int,
`duration_units` int,
`quantity_units` int,
`route` int,
`dose_units` int,
`frequency` int,
`brand_name` VARCHAR,
`dispense_as_written` BOOLEAN,
`drug_non_coded` VARCHAR,
PRIMARY KEY (`order_id`) NOT ENFORCED
)
15 changes: 15 additions & 0 deletions analytics/dsl/flattening/tables/openmrs/order_frequency.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,15 @@
CREATE TABLE `order_frequency` (
`order_frequency_id` int,
`concept_id` int,
`frequency_per_day` double,
`creator` int,
`date_created` TIMESTAMP,
`retired` BOOLEAN,
`retired_by` int,
`date_retired` TIMESTAMP,
`retire_reason` varchar,
`changed_by` int,
`date_changed` TIMESTAMP,
`uuid` VARCHAR,
PRIMARY KEY (`order_frequency_id`) NOT ENFORCED
)
95 changes: 55 additions & 40 deletions analytics/liquibase/analytics/changelogs/0001-init.xml
Original file line number Diff line number Diff line change
Expand Up @@ -142,46 +142,61 @@
<column name="order_id" type="BIGINT">
<constraints nullable="false" primaryKey="true" primaryKeyName="orders_pkey" />
</column>
<column name="patient_id" type="BIGINT" />
<column name="order_type_id" type="BIGINT" />
<column name="order_type_name" type="VARCHAR" />
<column name="order_type_uuid" type="VARCHAR" />
<column name="order_type_java_class_name" type="VARCHAR" />
<column name="concept_id" type="BIGINT" />
<column name="orderer" type="BIGINT" />
<column name="encounter_id" type="BIGINT" />
<column name="encounter_datetime" type="TIMESTAMP" />
<column name="encounter_type_name" type="VARCHAR" />
<column name="encounter_type_uuid" type="VARCHAR" />
<column name="care_setting" type="BIGINT" />
<column name="care_setting_name" type="VARCHAR" />
<column name="care_setting_type" type="VARCHAR" />
<column name="care_setting_uuid" type="VARCHAR" />
<column name="instructions" type="VARCHAR" />
<column name="date_activated" type="TIMESTAMP" />
<column name="auto_expire_date" type="TIMESTAMP" />
<column name="date_stopped" type="TIMESTAMP" />
<column name="order_reason" type="BIGINT" />
<column name="order_reason_non_coded" type="VARCHAR" />
<column name="date_created" type="TIMESTAMP" />
<column name="creator" type="BIGINT" />
<column name="voided_by" type="BIGINT" />
<column name="date_voided" type="TIMESTAMP" />
<column name="void_reason" type="VARCHAR" />
<column name="accession_number" type="VARCHAR" />
<column name="uuid" type="VARCHAR" />
<column name="order_number" type="VARCHAR" />
<column name="previous_order_id" type="BIGINT" />
<column name="order_action" type="VARCHAR" />
<column name="comment_to_fulfiller" type="VARCHAR" />
<column name="scheduled_date" type="TIMESTAMP" />
<column name="order_group_id" type="BIGINT" />
<column name="sort_weight" type="DOUBLE" />
<column name="encounter_voided" type="BOOLEAN" />
<column name="voided" type="BOOLEAN" />
<column name="order_type_retired" type="BOOLEAN" />
<column name="encounter_type_retired" type="BOOLEAN" />
<column name="care_setting_retired" type="BOOLEAN" />
<column name="patient_uuid" type="VARCHAR"/>
<column name="order_type_name" type="VARCHAR"/>
<column name="order_type_uuid" type="VARCHAR"/>
<column name="order_type_java_class_name" type="VARCHAR"/>
<column name="order_name" type="VARCHAR"/>
<column name="concept_uuid" type="VARCHAR"/>
<column name="orderer" type="BIGINT"/>
<column name="encounter_uuid" type="VARCHAR"/>
<column name="encounter_datetime" type="TIMESTAMP"/>
<column name="encounter_type_name" type="VARCHAR"/>
<column name="encounter_type_uuid" type="VARCHAR"/>
<column name="care_setting_name" type="VARCHAR"/>
<column name="care_setting_type" type="VARCHAR"/>
<column name="care_setting_uuid" type="VARCHAR"/>
<column name="instructions" type="VARCHAR"/>
<column name="date_activated" type="TIMESTAMP"/>
<column name="auto_expire_date" type="TIMESTAMP"/>
<column name="date_stopped" type="TIMESTAMP"/>
<column name="order_reason" type="VARCHAR"/>
<column name="order_reason_uuid" type="VARCHAR"/>
<column name="order_reason_non_coded" type="VARCHAR"/>
<column name="date_created" type="TIMESTAMP"/>
<column name="creator_uuid" type="VARCHAR"/>
<column name="voided_by" type="BIGINT"/>
<column name="date_voided" type="TIMESTAMP"/>
<column name="void_reason" type="VARCHAR"/>
<column name="accession_number" type="VARCHAR"/>
<column name="uuid" type="VARCHAR"/>
<column name="order_number" type="VARCHAR"/>
<column name="previous_order_id" type="BIGINT"/>
<column name="order_action" type="VARCHAR"/>
<column name="comment_to_fulfiller" type="VARCHAR"/>
<column name="scheduled_date" type="TIMESTAMP"/>
<column name="order_group_id" type="BIGINT"/>
<column name="sort_weight" type="DOUBLE PRECISION"/>
<column name="encounter_voided" type="BOOLEAN"/>
<column name="voided" type="BOOLEAN"/>
<column name="order_type_retired" type="BOOLEAN"/>
<column name="encounter_type_retired" type="BOOLEAN"/>
<column name="care_setting_retired" type="BOOLEAN"/>
<column name="drug_name" type="VARCHAR"/>
<column name="dose" type="DOUBLE PRECISION"/>
<column name="dose_unit_name" type="VARCHAR"/>
<column name="frequency" type="VARCHAR"/>
<column name="route_name" type="VARCHAR"/>
<column name="quantity" type="DOUBLE PRECISION"/>
<column name="quantity_unit_name" type="VARCHAR"/>
<column name="duration" type="BIGINT"/>
<column name="duration_unit_name" type="VARCHAR"/>
<column name="drug_uuid" type="VARCHAR"/>
<column name="dose_unit_uuid" type="VARCHAR"/>
<column name="quantity_unit_uuid" type="VARCHAR"/>
<column name="route_uuid" type="VARCHAR"/>
<column name="duration_unit_uuid" type="VARCHAR"/>
<column name="frequency_uuid" type="VARCHAR"/>
</createTable>
</changeSet>
<changeSet author="ruhanga" id="1658321685032-8">
Expand Down

0 comments on commit d24e7d9

Please sign in to comment.