Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Atc update 08 2024 #1099

Open
wants to merge 11 commits into
base: master
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
3 changes: 2 additions & 1 deletion ATC/load_stage.sql
Original file line number Diff line number Diff line change
Expand Up @@ -436,7 +436,8 @@ SELECT concept_code_atc AS concept_code_1,
TO_DATE('20991231', 'yyyymmdd') AS valid_end_date
FROM dev_atc.covid19_atc_rxnorm_manual cov
JOIN devv5.concept c1 ON cov.concept_id = c1.concept_id AND c1.vocabulary_id IN ('RxNorm', 'RxNorm Extension')
AND cov.to_drop IS NULL;
AND cov.to_drop IS NULL
ON CONFLICT DO NOTHING;

--12. Process manual relationships
DO
Expand Down
17 changes: 13 additions & 4 deletions ATC/manual work/class_to_drug.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4,7 +4,7 @@

-- prelim
DROP TABLE IF EXISTS rx;
CREATE TEMP TABLE rx AS
CREATE TABLE rx AS
SELECT c.concept_id,
c.concept_code,
c.concept_name,
Expand Down Expand Up @@ -34,19 +34,24 @@ GROUP BY c.concept_id, c.concept_code, c.concept_name;
-- manual: covid, vaccines, insulin
-- covid 19
DROP TABLE IF EXISTS class_to_drug;
CREATE TEMP TABLE class_to_drug
CREATE TABLE class_to_drug
AS
SELECT cs.concept_code AS class_code,
cs.concept_name AS class_name,
c.concept_id,
c.concept_name,
c.concept_class_id,
1 AS order
1 AS concept_order
FROM dev_atc.covid19_atc_rxnorm_manual cov
JOIN dev_atc.concept_stage cs ON cov.concept_code_atc = cs.concept_code
JOIN devv5.concept c ON cov.concept_id = c.concept_id
WHERE cov.to_drop IS NULL;

--- manual GCS from CR table absent in CA

INSERT INTO class_to_drug
select * from dev_atc.manual_gcs_from_cr;

-- vaccines, insulin
INSERT INTO class_to_drug
SELECT DISTINCT cs.concept_code, cs.concept_name, c.concept_id, c.concept_name, c.concept_class_id, 1 AS order
Expand Down Expand Up @@ -166,4 +171,8 @@ FROM dev_atc.concept_stage cs
AND crs.invalid_reason IS NULL
AND crs.relationship_id = 'ATC - RxNorm'
JOIN rx ON rx.concept_id = crs.concept_id_2
WHERE (cs.concept_code, rx.concept_id) NOT IN (SELECT class_code, concept_id FROM class_to_drug);
WHERE (cs.concept_code, rx.concept_id) NOT IN (SELECT class_code, concept_id FROM class_to_drug);

-- --- In case if you want to turn of connections filtration in postprocessing
-- UPDATE class_to_drug
-- SET concept_order = 1
13 changes: 13 additions & 0 deletions ATC/manual work/load_input.sql
Original file line number Diff line number Diff line change
Expand Up @@ -239,6 +239,19 @@ FROM (SELECT *

UNION

------manual table-----

(

SELECT concept_id,
"5th level code",
'manually added' as source
FROM dev_atc.to_add_new_connections

)

UNION

------DPD------
(SELECT c2.concept_id,
dpd.tc_atc_number,
Expand Down
157 changes: 157 additions & 0 deletions ATC/manual work/tests/comparison_to_z_index.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,157 @@
---- information from z-index
SELECT t3.concept_id,
t3.concept_code,
t3.concept_name,
t2.concept_id,
t2.concept_name,
t2.concept_class_id
FROM dev_atc.zindex_full t1
JOIN devv5.concept t2 on t1.targetid = t2.concept_id and t2.concept_class_id = 'Clinical Drug Form'
JOIN devv5.concept t3 on t1.atc = t3.concept_code AND t3.vocabulary_id = 'ATC';

---- information from devv5.concept_relationship

select c1.concept_id,
c1.concept_code,
c1.concept_name,
c2.concept_id,
c2.concept_name,
c2.concept_class_id
from devv5.concept_relationship cr
join devv5.concept c1 on cr.concept_id_1 = c1.concept_id and cr.relationship_id = 'ATC - RxNorm'
and c1.invalid_reason is NULL
and cr.invalid_reason is NULL
and c1.vocabulary_id = 'ATC'
join devv5.concept c2 on cr.concept_id_2 = c2.concept_id and c2.invalid_reason is NULL
and c2.vocabulary_id in ('RxNorm', 'RxNorm Extension');


--- Codes from Z-Index that do not exist in our system
WITH our_connections as (select c1.concept_id as ATC_id,
c1.concept_code as ATC_code,
c1.concept_name as ATC_name,
c2.concept_id RX_id,
c2.concept_name as RX_name,
c2.concept_class_id as RX_class
from devv5.concept_relationship cr
join devv5.concept c1 on cr.concept_id_1 = c1.concept_id and cr.relationship_id = 'ATC - RxNorm'
and c1.invalid_reason is NULL
and cr.invalid_reason is NULL
and c1.vocabulary_id = 'ATC'
join devv5.concept c2 on cr.concept_id_2 = c2.concept_id and c2.invalid_reason is NULL
and c2.vocabulary_id in ('RxNorm', 'RxNorm Extension'))


SELECT DISTINCT
t2.concept_id,
t2.concept_name,
t2.concept_class_id,
string_agg(DISTINCT t3.concept_code, ', ') as z_index_assign,
string_agg(DISTINCT t4.ATC_CODE, ', ') as our_assign
FROM dev_atc.zindex_full t1
JOIN devv5.concept t2 on t1.targetid = t2.concept_id and t2.concept_class_id = 'Clinical Drug Form'
JOIN devv5.concept t3 on t1.atc = t3.concept_code AND t3.vocabulary_id = 'ATC'
left JOIN OUR_CONNECTIONS t4 on t1.targetid = t4.RX_ID
WHERE (t3.concept_code, t2.concept_id) not in (select
c1.concept_code,
c2.concept_id
from devv5.concept_relationship cr
join devv5.concept c1 on cr.concept_id_1 = c1.concept_id and cr.relationship_id = 'ATC - RxNorm'
and c1.invalid_reason is NULL
and cr.invalid_reason is NULL
and c1.vocabulary_id = 'ATC'
join devv5.concept c2 on cr.concept_id_2 = c2.concept_id and c2.invalid_reason is NULL
and c2.vocabulary_id in ('RxNorm', 'RxNorm Extension'))
AND length (t3.concept_code) = 7
GROUP BY t2.concept_id, t2.concept_name, t2.concept_class_id
ORDER BY t2.concept_id;


----- see 1 to many in previous release, dev_dev, and compare to current state devv5.
create table multiply_rxnorm_per_1_atc as
with old_multiply as (select
c1.concept_code,
string_agg(DISTINCT c2.concept_name, CHR(10) ORDER BY c2.concept_name) as connected_forms,
count(DISTINCT c2.concept_id) as cnt_old
from dev_dev.concept_relationship cr
join dev_dev.concept c1 on cr.concept_id_1 = c1.concept_id and cr.relationship_id = 'ATC - RxNorm'
and c1.invalid_reason is NULL
and cr.invalid_reason is NULL
and c1.vocabulary_id = 'ATC'
join dev_dev.concept c2 on cr.concept_id_2 = c2.concept_id and c2.invalid_reason is NULL
and c2.vocabulary_id in ('RxNorm', 'RxNorm Extension')
and c2.concept_class_id = 'Clinical Drug Form'
GROUP BY c1.concept_code HAVING count(DISTINCT c2.concept_id)>1),
new_multuply as (select
c1.concept_code,
string_agg(DISTINCT c2.concept_name, CHR(10) ORDER BY c2.concept_name) as connected_forms,
count(DISTINCT c2.concept_id) as cnt_new
from devv5.concept_relationship cr
join devv5.concept c1 on cr.concept_id_1 = c1.concept_id and cr.relationship_id = 'ATC - RxNorm'
and c1.invalid_reason is NULL
and cr.invalid_reason is NULL
and c1.vocabulary_id = 'ATC'
join devv5.concept c2 on cr.concept_id_2 = c2.concept_id and c2.invalid_reason is NULL
and c2.vocabulary_id in ('RxNorm', 'RxNorm Extension')
and c2.concept_class_id = 'Clinical Drug Form'
GROUP BY c1.concept_code HAVING count(DISTINCT c2.concept_id)>1)
SELECT t2.concept_code,
t2.connected_forms as connected_forms_old,
t2.CNT_OLD,
t1.cnt_new - t2.cnt_old as cnt_differnce,
t1.cnt_new,
t1.CONNECTED_FORMS as connected_forms_new
FROM
NEW_MULTUPLY t1
JOIN OLD_MULTIPLY t2 on t1.concept_code = t2.concept_code;

select *
from dev_atatur.multiply_rxnorm_per_1_atc;


----- number of different ATC codes per one rxnorm_id
create table rxnorm_w_multiply_atc as
with old_rxn_atc as (select
c2.concept_id,
c2.concept_name,
string_agg(DISTINCT c1.concept_code, CHR(10) ORDER BY c1.concept_code) as connected_ATC_old,
count(DISTINCT c1.concept_code) as cnt_old
from dev_dev.concept_relationship cr
join dev_dev.concept c1 on cr.concept_id_1 = c1.concept_id and cr.relationship_id = 'ATC - RxNorm'
and c1.invalid_reason is NULL
and cr.invalid_reason is NULL
and c1.vocabulary_id = 'ATC'
join dev_dev.concept c2 on cr.concept_id_2 = c2.concept_id and c2.invalid_reason is NULL
and c2.vocabulary_id in ('RxNorm', 'RxNorm Extension')
and c2.concept_class_id = 'Clinical Drug Form'
GROUP BY c2.concept_id,
c2.concept_name HAVING count(DISTINCT c1.concept_code)>1),
new_rxn_atc as (select
c2.concept_id,
c2.concept_name,
string_agg(DISTINCT c1.concept_code, CHR(10) ORDER BY c1.concept_code) as connected_ATC_new,
count(DISTINCT c1.concept_code) as cnt_new
from devv5.concept_relationship cr
join devv5.concept c1 on cr.concept_id_1 = c1.concept_id and cr.relationship_id = 'ATC - RxNorm'
and c1.invalid_reason is NULL
and cr.invalid_reason is NULL
and c1.vocabulary_id = 'ATC'
join devv5.concept c2 on cr.concept_id_2 = c2.concept_id and c2.invalid_reason is NULL
and c2.vocabulary_id in ('RxNorm', 'RxNorm Extension')
and c2.concept_class_id = 'Clinical Drug Form'
GROUP BY c2.concept_id,
c2.concept_name HAVING count(DISTINCT c1.concept_code)>1)
SELECT t1.concept_id,
t1.concept_name,
t1.CNT_NEW,
t1.CNT_NEW - t2.CNT_OLD as cnt_diff,
t2.CNT_OLD,
t1.CONNECTED_ATC_NEW,
t2.CONNECTED_ATC_OLD
FROM NEW_RXN_ATC t1
join OLD_RXN_ATC t2 on t1.concept_id=t2.concept_id;


select sum(cnt_diff)
from rxnorm_w_multiply_atc
where cnt_diff != 0 ;
Loading