1
+ -- ------------------------------
2
+ -- PERSON
3
+ -- ------------------------------
4
+ INSERT INTO {TARGET_SCHEMA}.person (
5
+ person_id ,
6
+ gender_concept_id ,
7
+ year_of_birth ,
8
+ month_of_birth ,
9
+ day_of_birth ,
10
+ birth_datetime ,
11
+ race_concept_id ,
12
+ ethnicity_concept_id ,
13
+ location_id ,
14
+ provider_id ,
15
+ care_site_id ,
16
+ person_source_value ,
17
+ gender_source_value ,
18
+ gender_source_concept_id ,
19
+ race_source_value ,
20
+ race_source_concept_id ,
21
+ ethnicity_source_value ,
22
+ ethnicity_source_concept_id
23
+ )
24
+ WITH cte1 as (
25
+ SELECT DISTINCT e_patid, ethnicityname
26
+ FROM {SOURCE_SCHEMA}.tumour
27
+ )
28
+ SELECT
29
+ t1 .e_patid AS person_id,
30
+ 0 AS gender_concept_id,
31
+ 0 AS year_of_birth,
32
+ NULL ::int AS month_of_birth,
33
+ NULL ::int AS day_of_birth,
34
+ NULL ::timestamp AS birth_datetime,
35
+ CASE WHEN t2 .target_concept_id IS NOT NULL THEN t2 .target_concept_id ELSE 0 END AS race_concept_id,
36
+ 0 AS ethnicity_concept_id,
37
+ NULL ::int AS location_id,
38
+ NULL ::int AS provider_id,
39
+ NULL ::int AS care_site_id,
40
+ t1 .e_patid ::varchar AS person_source_value,
41
+ NULL AS gender_source_value,
42
+ NULL ::int AS gender_source_concept_id,
43
+ t2 .source_code_description AS race_source_value,
44
+ NULL ::int AS race_source_concept_id,
45
+ NULL AS ethnicity_source_value,
46
+ 0 AS ethnicity_source_concept_id
47
+ FROM cte1 as t1
48
+ LEFT JOIN {VOCABULARY_SCHEMA}.source_to_standard_vocab_map as t2 on t1 .ethnicityname = t2 .source_code
49
+ and t2 .source_vocabulary_id = ' NCRAS_ETHNIC_STCM' ;
50
+
51
+ ALTER TABLE {TARGET_SCHEMA}.person ADD CONSTRAINT xpk_person PRIMARY KEY (person_id) USING INDEX TABLESPACE pg_default;
52
+
53
+ CREATE UNIQUE INDEX idx_person_id ON {TARGET_SCHEMA}.person (person_id ASC ) TABLESPACE pg_default;
54
+ CLUSTER {TARGET_SCHEMA}.person USING xpk_person;
55
+
56
+ -- ------------------------------
57
+ -- OBSERVATION_PERIOD --
58
+ -- ------------------------------
59
+ DROP SEQUENCE IF EXISTS {TARGET_SCHEMA}.observation_period_seq;
60
+
61
+ CREATE SEQUENCE {TARGET_SCHEMA}.observation_period_seq;
62
+
63
+ with cte2 as (
64
+ select t1 .e_patid as person_id,
65
+ LEAST(MIN (t1 .diagnosisdatebest ), MIN (t2 .eventdate )) as min_date,
66
+ GREATEST(MAX (t1 .diagnosisdatebest ), MAX (t2 .eventdate )) as max_date
67
+ from {SOURCE_SCHEMA}.tumour as t1
68
+ inner join {SOURCE_SCHEMA}.treatment as t2 on t2 .e_patid = t1 .e_patid
69
+ inner join {TARGET_SCHEMA}.person as t3 on t3 .person_id = t1 .e_patid
70
+ group by t1 .e_patid
71
+ )
72
+ INSERT INTO {TARGET_SCHEMA}.OBSERVATION_PERIOD
73
+ (
74
+ observation_period_id,
75
+ person_id,
76
+ observation_period_start_date,
77
+ observation_period_end_date,
78
+ period_type_concept_id
79
+ )
80
+ select
81
+ nextval(' {TARGET_SCHEMA}.observation_period_seq' ),
82
+ cte2 .person_id ,
83
+ GREATEST(cte2 .min_date , t3 .start ) as observation_period_start_date,
84
+ LEAST(cte2 .max_date ,t3 .end ) as observation_period_end_date,
85
+ 32880
86
+ from cte2, {SOURCE_SCHEMA}.linkage_coverage as t3
87
+ where t3 .data_source = ' ncras_cr' ;
88
+
89
+ DROP SEQUENCE IF EXISTS {TARGET_SCHEMA}.observation_period_seq;
90
+
91
+ ALTER TABLE {TARGET_SCHEMA}.observation_period ADD CONSTRAINT xpk_observation_period PRIMARY KEY (observation_period_id) USING INDEX TABLESPACE pg_default;
92
+ CREATE INDEX idx_observation_period_id ON {TARGET_SCHEMA}.observation_period (person_id ASC ) TABLESPACE pg_default;
93
+ CLUSTER {TARGET_SCHEMA}.observation_period USING idx_observation_period_id;
0 commit comments