1
- WITH CTE_PAIRS AS (
2
- /*
3
- SELECT 1314273 AS INGREDIENT_CONCEPT_ID, 432870 AS CONDITION_CONCEPT_ID --RITUXIMAB / thrombocytopenic disorder
4
- UNION
5
- SELECT 1314273 AS INGREDIENT_CONCEPT_ID, 4029574 AS CONDITION_CONCEPT_ID --RITUXIMAB / Salt-losing congenital adrenal hyperplasia
6
- */
7
- SELECT COUNT(*)
1
+ /*PREP - BUILD CONDITIONS OF INTEREST AND THEIR FAMILY ONCE AND INDEX*/
2
+ /*WITH CTE_PAIRS AS (
3
+ SELECT *
8
4
FROM CEM_V2_0_0_20200226.dbo.nc_matrix_conditions, CEM_V2_0_0_20200226.dbo.nc_matrix_ingredients
9
5
),
10
6
CTE_PAIRS_EXPAND AS (
@@ -17,15 +13,52 @@ CTE_PAIRS_EXPAND AS (
17
13
FROM CTE_PAIRS p
18
14
JOIN CEM_V2_0_0_20200226.dbo.CONCEPT_ANCESTOR ca2
19
15
ON ca2.DESCENDANT_CONCEPT_ID = p.CONDITION_CONCEPT_ID
16
+ )
17
+ SELECT *
18
+ INTO #TEMP_CTE_PAIRS_EXPAND
19
+ FROM CTE_PAIRS_EXPAND*/
20
+
21
+ /*SELECT *
22
+ INTO SCRATCH.dbo.EAV_TEMP_CTE_PAIRS_EXPAND
23
+ FROM #TEMP_CTE_PAIRS_EXPAND
24
+
25
+ CREATE INDEX IXD_TEMP_CTE_PAIRS_EXPANDED ON SCRATCH.dbo.EAV_TEMP_CTE_PAIRS_EXPAND (INGREDIENT_CONCEPT_ID, FAMILY_CONDITION_CONCEPT_ID)
26
+ */
27
+
28
+
29
+
30
+ --COUNT(*) --7305329
31
+
32
+ WITH CTE_PAIRS_EXPAND AS (
33
+ SELECT *
34
+ FROM #TEMP_CTE_PAIRS_EXPAND e
35
+ WHERE e.INGREDIENT_CONCEPT_ID = 1314273
20
36
)
21
37
SELECT p.INGREDIENT_CONCEPT_ID, p.CONDITION_CONCEPT_ID,
22
38
MAX(EVIDENCE_EXISTS) AS EVIDENCE_EXISTS
39
+ INTO #TEMP_SUMMARIZE_EVIDENCE
23
40
FROM (
41
+ /*INDICATIONS*/
42
+ SELECT p.INGREDIENT_CONCEPT_ID, p.CONDITION_CONCEPT_ID,
43
+ MAX(CASE WHEN c1.CONCEPT_ID IS NOT NULL THEN 1 ELSE 0 END) AS EVIDENCE_EXISTS
44
+ FROM CTE_PAIRS_EXPAND p
45
+ JOIN CEM_V2_0_0_20200226.dbo.CONCEPT_ANCESTOR ca
46
+ ON ca.ANCESTOR_CONCEPT_ID = p.INGREDIENT_CONCEPT_ID
47
+ JOIN CEM_V2_0_0_20200226.dbo.CONCEPT_RELATIONSHIP cr
48
+ ON cr.RELATIONSHIP_ID IN ('Is CI of','Is FDA-appr ind of','Is off-label ind of')
49
+ AND cr.CONCEPT_ID_2 = ca.DESCENDANT_CONCEPT_ID
50
+ JOIN CEM_V2_0_0_20200226.dbo.CONCEPT_RELATIONSHIP cr1
51
+ ON cr1.CONCEPT_ID_2 = cr.CONCEPT_ID_1
52
+ AND cr1.CONCEPT_ID_1 = p.FAMILY_CONDITION_CONCEPT_ID
53
+ JOIN CEM_V2_0_0_20200226.dbo.CONCEPT c1
54
+ ON c1.CONCEPT_ID = cr1.CONCEPT_ID_1
55
+ GROUP BY p.INGREDIENT_CONCEPT_ID, p.CONDITION_CONCEPT_ID
56
+ UNION ALL
24
57
/*LITERATURE*/
25
58
SELECT p.INGREDIENT_CONCEPT_ID, p.CONDITION_CONCEPT_ID,
26
59
MAX(CASE WHEN cu.CONCEPT_ID_1 IS NOT NULL THEN 1 ELSE 0 END) AS EVIDENCE_EXISTS
27
60
FROM CTE_PAIRS_EXPAND p
28
- LEFT OUTER JOIN CEM_V2_0_0_20200226.dbo.CEM_UNIFIED cu
61
+ JOIN CEM_V2_0_0_20200226.dbo.CEM_UNIFIED cu
29
62
ON SOURCE_ID IN ('medline_winnenburg')
30
63
AND cu.CONCEPT_ID_1 = p.INGREDIENT_CONCEPT_ID
31
64
AND cu.CONCEPT_ID_2 = p.FAMILY_CONDITION_CONCEPT_ID
35
68
SELECT p.INGREDIENT_CONCEPT_ID, p.CONDITION_CONCEPT_ID,
36
69
MAX(CASE WHEN cu.CONCEPT_ID_1 IS NOT NULL THEN 1 ELSE 0 END) AS EVIDENCE_EXISTS
37
70
FROM CTE_PAIRS_EXPAND p
38
- LEFT OUTER JOIN CEM_V2_0_0_20200226.dbo.CONCEPT_ANCESTOR ca
71
+ JOIN CEM_V2_0_0_20200226.dbo.CONCEPT_ANCESTOR ca
39
72
ON ca.ANCESTOR_CONCEPT_ID = p.INGREDIENT_CONCEPT_ID
40
- LEFT OUTER JOIN CEM_V2_0_0_20200226.dbo.CEM_UNIFIED cu
73
+ JOIN CEM_V2_0_0_20200226.dbo.CEM_UNIFIED cu
41
74
ON SOURCE_ID IN ('splicer', 'eu_pl_adr')
42
75
AND cu.CONCEPT_ID_1 = ca.DESCENDANT_CONCEPT_ID --SPLICER NEEDS TO BE BROUGHT TO INGREDIENT LEVEL
43
76
AND cu.CONCEPT_ID_2 = p.FAMILY_CONDITION_CONCEPT_ID
@@ -47,20 +80,20 @@ FROM (
47
80
SELECT p.INGREDIENT_CONCEPT_ID, p.CONDITION_CONCEPT_ID,
48
81
MAX(CASE WHEN u1.CONCEPT_ID_1 IS NOT NULL THEN 1 ELSE 0 END) AS EVIDENCE_EXISTS
49
82
FROM CTE_PAIRS_EXPAND p
50
- LEFT OUTER JOIN CEM_V2_0_0_20200226.dbo.CEM_UNIFIED u1
83
+ JOIN CEM_V2_0_0_20200226.dbo.CEM_UNIFIED u1
51
84
ON u1.SOURCE_ID = 'aeolus'
52
85
AND u1.CONCEPT_ID_1 = p.INGREDIENT_CONCEPT_ID
53
86
AND u1.CONCEPT_ID_2 = p.FAMILY_CONDITION_CONCEPT_ID
54
87
AND u1.STATISTIC_VALUE_TYPE = 'PRR'
55
88
AND u1.STATISTIC_VALUE >= 2
56
- LEFT OUTER JOIN CEM_V2_0_0_20200226.dbo.CEM_UNIFIED u2
89
+ JOIN CEM_V2_0_0_20200226.dbo.CEM_UNIFIED u2
57
90
ON u2.SOURCE_ID = 'aeolus'
58
91
AND u1.UNIQUE_IDENTIFIER = u2.UNIQUE_IDENTIFIER
59
92
AND u2.CONCEPT_ID_1 = p.INGREDIENT_CONCEPT_ID
60
93
AND u2.CONCEPT_ID_2 = p.FAMILY_CONDITION_CONCEPT_ID
61
94
AND u2.STATISTIC_VALUE_TYPE = 'CASE COUNT'
62
95
AND u2.STATISTIC_VALUE >= 3
63
- LEFT OUTER JOIN CEM_V2_0_0_20200226.dbo.CEM_UNIFIED u3
96
+ JOIN CEM_V2_0_0_20200226.dbo.CEM_UNIFIED u3
64
97
ON u3.SOURCE_ID = 'aeolus'
65
98
AND u1.UNIQUE_IDENTIFIER = u3.UNIQUE_IDENTIFIER
66
99
AND u3.CONCEPT_ID_1 = p.INGREDIENT_CONCEPT_ID
@@ -70,4 +103,17 @@ FROM (
70
103
GROUP BY p.INGREDIENT_CONCEPT_ID, p.CONDITION_CONCEPT_ID
71
104
) p
72
105
GROUP BY p.INGREDIENT_CONCEPT_ID, p.CONDITION_CONCEPT_ID
73
- --INDICATIONS
106
+
107
+
108
+ WITH CTE_UNIVERSE AS (
109
+ SELECT *
110
+ FROM CEM_V2_0_0_20200226.dbo.nc_matrix_conditions, CEM_V2_0_0_20200226.dbo.nc_matrix_ingredients
111
+ WHERE INGREDIENT_CONCEPT_ID = 1314273
112
+ )
113
+ SELECT u.INGREDIENT_CONCEPT_ID, u.CONDITION_CONCEPT_ID,
114
+ MAX(CASE WHEN EVIDENCE_EXISTS IS NULL THEN 0 ELSE EVIDENCE_EXISTS END) AS EVIDENCE_EXISTS
115
+ FROM CTE_UNIVERSE u
116
+ LEFT OUTER JOIN #TEMP_SUMMARIZE_EVIDENCE e
117
+ ON e.INGREDIENT_CONCEPT_ID = u.INGREDIENT_CONCEPT_ID
118
+ AND e.CONDITION_CONCEPT_ID = u.CONDITION_CONCEPT_ID
119
+ GROUP BY u.INGREDIENT_CONCEPT_ID, u.CONDITION_CONCEPT_ID
0 commit comments