Skip to content

Commit

Permalink
KH-502: Sets, answers and concept mappings to be properly flattened b…
Browse files Browse the repository at this point in the history
…y the Concepts query (#7)
  • Loading branch information
Ruhanga authored May 14, 2024
1 parent 4dd6c91 commit 7ea0fce
Show file tree
Hide file tree
Showing 4 changed files with 56 additions and 19 deletions.
44 changes: 30 additions & 14 deletions analytics/dsl/flattening/queries/concepts.sql
Original file line number Diff line number Diff line change
@@ -1,14 +1,30 @@
SELECT `concept`.`concept_id` AS `concept_id`,
`concept_reference_source`.`name` AS `Concept Mapping Source`,
`concept_reference_term`.`code` AS `Concept Mapping Code`,
`concept_reference_term`.`name` AS `Concept Mapping Name`,
`concept_name`.`name` AS `name`,
`concept_name`.`locale` AS `locale`,
`concept_name`.`locale_preferred` AS `locale_preferred`,
`concept`.`retired` AS `retired`,
`concept`.`uuid` AS `uuid`
FROM `concept`
LEFT JOIN `concept_reference_map` `concept_reference_map` ON `concept`.`concept_id` = `concept_reference_map`.`concept_id`
LEFT JOIN `concept_reference_term` `concept_reference_term` ON `concept_reference_map`.`concept_reference_term_id` = `concept_reference_term`.`concept_reference_term_id`
LEFT JOIN `concept_reference_source` `concept_reference_source` ON `concept_reference_term`.`concept_source_id` = `concept_reference_source`.`concept_source_id`
LEFT JOIN `concept_name` `concept_name` ON `concept`.`concept_id` = `concept_name`.`concept_id` AND `concept_name`.`locale` LIKE 'en' AND `concept_name`.`voided` = false AND `concept_name`.`locale_preferred` = true
SELECT DISTINCT concept.concept_id AS concept_id,
LISTAGG(
CONCAT_WS(': ', concept_reference_source.name, concept_reference_term.code), ', '
) AS concept_mappings_source_Codes,
concept_name.name AS name,
concept_name.locale AS locale,
concept_name.locale_preferred AS locale_preferred,
concept.retired AS retired,
concept.uuid AS uuid,
(
SELECT LISTAGG(c.uuid, ', ')
FROM concept AS c
INNER JOIN concept_answer AS ca ON c.concept_id = ca.answer_concept
WHERE ca.concept_id = concept.concept_id
) AS question_concepts_uuids,
(
SELECT LISTAGG(c2.uuid, ', ')
FROM concept AS c2
INNER JOIN concept_set AS cs ON c2.concept_id = cs.concept_id
WHERE cs.concept_set = 75
) AS set_concepts_uuids
FROM concept concept
LEFT JOIN concept_reference_map concept_reference_map ON concept.concept_id = concept_reference_map.concept_id
LEFT JOIN concept_reference_term concept_reference_term ON concept_reference_map.concept_reference_term_id = concept_reference_term.concept_reference_term_id
LEFT JOIN concept_reference_source concept_reference_source ON concept_reference_term.concept_source_id = concept_reference_source.concept_source_id
LEFT JOIN concept_name concept_name ON concept.concept_id = concept_name.concept_id AND concept_name.locale LIKE 'en' AND concept_name.voided = false AND concept_name.locale_preferred = true
LEFT JOIN concept_answer concept_answer ON concept.concept_id = concept_answer.answer_concept
LEFT JOIN concept_set concept_set ON concept.concept_id = concept_set.concept_id
GROUP BY
concept.concept_id, concept_name.name, concept_name.locale, concept_name.locale_preferred, concept.retired, concept.uuid;
11 changes: 11 additions & 0 deletions analytics/dsl/flattening/tables/openmrs/concept_answer.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
CREATE TABLE `concept_answer` (
`concept_answer_id` int,
`concept_id` int,
`answer_concept` int,
`answer_drug` int,
`creator` int,
`date_created` TIMESTAMP,
`sort_weight` DOUBLE,
`uuid` VARCHAR,
PRIMARY KEY (`concept_answer_id`) NOT ENFORCED
)
10 changes: 10 additions & 0 deletions analytics/dsl/flattening/tables/openmrs/concept_set.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
CREATE TABLE `concept_set` (
`concept_set_id` int,
`concept_id` int,
`concept_set` int,
`sort_weight` DOUBLE,
`creator` int,
`date_created` TIMESTAMP,
`uuid` VARCHAR,
PRIMARY KEY (`concept_set_id`) NOT ENFORCED
)
10 changes: 5 additions & 5 deletions analytics/liquibase/analytics/changelogs/0001-init.xml
Original file line number Diff line number Diff line change
Expand Up @@ -78,19 +78,19 @@
<column name="question_uuid" type="VARCHAR"/>
</createTable>
</changeSet>
<changeSet author="enyachoke" id="1629094153790-5">
<changeSet author="enyachoke" id="1629094153790-5-test">
<createTable tableName="concepts">
<column name="concept_id" type="BIGINT">
<constraints nullable="false" primaryKey="true" primaryKeyName="concepts_pkey" />
</column>
<column name="concept_mapping_source" type="TEXT" />
<column name="concept_mapping_code" type="TEXT" />
<column name="concept_mapping_name" type="TEXT" />
<column name="concept_mappings_source_Codes" type="TEXT" />
<column name="name" type="TEXT" />
<column name="locale" type="TEXT" />
<column name="locale_preferred" type="BOOLEAN" />
<column name="retired" type="BOOLEAN" />
<column name="uuid" type="TEXT" />
<column name="uuid" type="VARCHAR" />
<column name="question_concepts_uuids" type="TEXT" />
<column name="set_concepts_uuids" type="TEXT" />
</createTable>
</changeSet>
<changeSet author="mksrom" id="1629094153790-6">
Expand Down

0 comments on commit 7ea0fce

Please sign in to comment.