Skip to content

Commit ac929cd

Browse files
CNDE-2341: Added sp_nrt_treatment_postprocessing (#223)
1 parent d9b7267 commit ac929cd

File tree

3 files changed

+785
-0
lines changed

3 files changed

+785
-0
lines changed
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,388 @@
1+
CREATE OR ALTER PROCEDURE [dbo].[sp_nrt_treatment_postprocessing] @treatment_uids nvarchar(max),
2+
@debug bit = 'false'
3+
AS
4+
BEGIN
5+
BEGIN TRY
6+
/* Logging variables */
7+
DECLARE @rowcount bigint;
8+
DECLARE @proc_step_no float = 0;
9+
DECLARE @proc_step_name varchar(200) = '';
10+
DECLARE @batch_id bigint;
11+
DECLARE @dataflow_name varchar(200) = 'Treatment POST-Processing';
12+
DECLARE @package_name varchar(200) = 'sp_nrt_treatment_postprocessing';
13+
14+
SET @batch_id = cast((format(getdate(), 'yyMMddHHmmss')) as bigint);
15+
16+
/* Initial logging entry */
17+
INSERT INTO [dbo].[job_flow_log]
18+
( batch_id
19+
, [Dataflow_Name]
20+
, [package_Name]
21+
, [Status_Type]
22+
, [step_number]
23+
, [step_name]
24+
, [msg_description1]
25+
, [row_count])
26+
VALUES ( @batch_id
27+
, @dataflow_name
28+
, @package_name
29+
, 'START'
30+
, 0
31+
, 'SP_Start'
32+
, LEFT(@treatment_uids, 500)
33+
, 0);
34+
35+
SET @proc_step_name = 'Create TREATMENT and TREATMENT_EVENT Temp tables';
36+
SET @proc_step_no = 1;
37+
38+
/* Temp treatment table creation */
39+
SELECT CAST(nrt.treatment_uid AS bigint) AS treatment_uid,
40+
nrt.local_id AS TREATMENT_LOCAL_ID,
41+
nrt.treatment_name AS TREATMENT_NM,
42+
nrt.treatment_drug AS TREATMENT_DRUG,
43+
nrt.treatment_dosage_strength AS TREATMENT_DOSAGE_STRENGTH,
44+
nrt.treatment_dosage_strength_unit AS TREATMENT_DOSAGE_STRENGTH_UNIT,
45+
nrt.treatment_frequency AS TREATMENT_FREQUENCY,
46+
nrt.treatment_duration AS TREATMENT_DURATION,
47+
nrt.treatment_duration_unit AS TREATMENT_DURATION_UNIT,
48+
nrt.treatment_comments AS TREATMENT_COMMENTS,
49+
nrt.treatment_route AS TREATMENT_ROUTE,
50+
CASE WHEN nrt.cd = 'OTH' THEN nrt.treatment_name ELSE '' END AS CUSTOM_TREATMENT,
51+
nrt.treatment_shared_ind AS TREATMENT_SHARED_IND,
52+
nrt.treatment_oid AS TREATMENT_OID,
53+
nrt.record_status_cd AS RECORD_STATUS_CD,
54+
tk.d_treatment_key AS TREATMENT_KEY
55+
INTO #temp_trt_table
56+
FROM dbo.nrt_treatment nrt
57+
LEFT JOIN dbo.nrt_treatment_key tk WITH (NOLOCK)
58+
ON CAST(nrt.treatment_uid AS bigint) = tk.treatment_uid
59+
WHERE nrt.treatment_uid IN (SELECT value FROM STRING_SPLIT(@treatment_uids, ','));
60+
61+
/* Temp treatment_event table creation */
62+
SELECT CAST(nrt.treatment_uid AS bigint) AS treatment_uid,
63+
COALESCE(dtt.DATE_KEY, 1) AS TREATMENT_DT_KEY,
64+
COALESCE(p.PATIENT_KEY, 1) AS PATIENT_KEY,
65+
COALESCE(org.ORGANIZATION_KEY, 1) AS TREATMENT_PROVIDING_ORG_KEY,
66+
COALESCE(prv.PROVIDER_KEY, 1) AS TREATMENT_PHYSICIAN_KEY,
67+
1 AS TREATMENT_COUNT,
68+
trt.TREATMENT_KEY,
69+
COALESCE(mrb.MORB_RPT_KEY, 1) AS MORB_RPT_KEY,
70+
COALESCE(inv.INVESTIGATION_KEY, 1) AS INVESTIGATION_KEY,
71+
COALESCE(cnd.CONDITION_KEY, 1) AS CONDITION_KEY,
72+
COALESCE(ldf.LDF_GROUP_KEY, 1) AS LDF_GROUP_KEY,
73+
nrt.record_status_cd AS RECORD_STATUS_CD
74+
INTO #temp_trt_event_table
75+
FROM dbo.nrt_treatment nrt
76+
LEFT JOIN dbo.nrt_treatment_key tk ON CAST(nrt.treatment_uid AS bigint) = tk.treatment_uid
77+
LEFT JOIN dbo.TREATMENT trt WITH (NOLOCK) ON trt.TREATMENT_KEY = tk.d_treatment_key
78+
LEFT JOIN dbo.INVESTIGATION inv WITH (NOLOCK)
79+
ON CAST(nrt.public_health_case_uid AS bigint) = inv.CASE_UID
80+
LEFT JOIN dbo.nrt_investigation nrt_inv WITH (NOLOCK)
81+
ON CAST(nrt.public_health_case_uid AS bigint) = nrt_inv.public_health_case_uid
82+
LEFT JOIN dbo.CONDITION cnd WITH (NOLOCK) ON nrt_inv.cd = cnd.CONDITION_CD
83+
LEFT JOIN dbo.D_PATIENT p WITH (NOLOCK) ON CAST(nrt.patient_treatment_uid AS bigint) = p.PATIENT_UID
84+
LEFT JOIN dbo.D_ORGANIZATION org WITH (NOLOCK)
85+
ON CAST(nrt.organization_uid AS bigint) = org.ORGANIZATION_UID
86+
LEFT JOIN dbo.D_PROVIDER prv WITH (NOLOCK) ON CAST(nrt.provider_uid AS bigint) = prv.PROVIDER_UID
87+
LEFT JOIN dbo.RDB_DATE dtt WITH (NOLOCK) ON CAST(nrt.treatment_date AS DATE) = dtt.DATE_MM_DD_YYYY
88+
LEFT JOIN dbo.MORBIDITY_REPORT mrb WITH (NOLOCK)
89+
ON CAST(nrt.morbidity_uid AS bigint) = mrb.MORB_RPT_UID
90+
LEFT JOIN dbo.LDF_GROUP ldf WITH (NOLOCK)
91+
ON CAST(nrt.treatment_uid AS bigint) = ldf.business_object_uid
92+
WHERE nrt.treatment_uid IN (SELECT value FROM STRING_SPLIT(@treatment_uids, ','));
93+
94+
/* Logging */
95+
SET @rowcount = @@rowcount;
96+
INSERT INTO [dbo].[job_flow_log]
97+
( batch_id
98+
, [Dataflow_Name]
99+
, [package_Name]
100+
, [Status_Type]
101+
, [step_number]
102+
, [step_name]
103+
, [row_count]
104+
, [msg_description1])
105+
VALUES ( @batch_id
106+
, @dataflow_name
107+
, @package_name
108+
, 'START'
109+
, @proc_step_no
110+
, @proc_step_name
111+
, @rowcount
112+
, LEFT(@treatment_uids, 500));
113+
114+
BEGIN TRANSACTION;
115+
SET @proc_step_name = 'Update TREATMENT Dimension';
116+
SET @proc_step_no = 2;
117+
118+
/* Treatment Update Operation */
119+
UPDATE dbo.TREATMENT
120+
SET TREATMENT_LOCAL_ID = trt.TREATMENT_LOCAL_ID,
121+
TREATMENT_NM = trt.TREATMENT_NM,
122+
TREATMENT_DRUG = trt.TREATMENT_DRUG,
123+
TREATMENT_DOSAGE_STRENGTH = trt.TREATMENT_DOSAGE_STRENGTH,
124+
TREATMENT_DOSAGE_STRENGTH_UNIT = trt.TREATMENT_DOSAGE_STRENGTH_UNIT,
125+
TREATMENT_FREQUENCY = trt.TREATMENT_FREQUENCY,
126+
TREATMENT_DURATION = trt.TREATMENT_DURATION,
127+
TREATMENT_DURATION_UNIT = trt.TREATMENT_DURATION_UNIT,
128+
TREATMENT_COMMENTS = trt.TREATMENT_COMMENTS,
129+
TREATMENT_ROUTE = trt.TREATMENT_ROUTE,
130+
CUSTOM_TREATMENT = trt.CUSTOM_TREATMENT,
131+
TREATMENT_SHARED_IND = trt.TREATMENT_SHARED_IND,
132+
TREATMENT_OID = trt.TREATMENT_OID,
133+
RECORD_STATUS_CD = trt.RECORD_STATUS_CD
134+
FROM #temp_trt_table trt
135+
INNER JOIN dbo.TREATMENT t WITH (NOLOCK)
136+
ON trt.TREATMENT_KEY = t.TREATMENT_KEY
137+
WHERE trt.TREATMENT_KEY IS NOT NULL;
138+
139+
/* Logging */
140+
SET @rowcount = @@rowcount;
141+
INSERT INTO [dbo].[job_flow_log]
142+
( batch_id
143+
, [Dataflow_Name]
144+
, [package_Name]
145+
, [Status_Type]
146+
, [step_number]
147+
, [step_name]
148+
, [row_count]
149+
, [msg_description1])
150+
VALUES ( @batch_id
151+
, @dataflow_name
152+
, @package_name
153+
, 'START'
154+
, @proc_step_no
155+
, @proc_step_name
156+
, @rowcount
157+
, LEFT(@treatment_uids, 500));
158+
159+
SET @proc_step_name = 'Update TREATMENT_EVENT Dimension';
160+
SET @proc_step_no = 3;
161+
162+
/* Treatment_Event Update Operation */
163+
UPDATE dbo.TREATMENT_EVENT
164+
SET TREATMENT_DT_KEY = trte.TREATMENT_DT_KEY,
165+
PATIENT_KEY = trte.PATIENT_KEY,
166+
TREATMENT_PROVIDING_ORG_KEY = trte.TREATMENT_PROVIDING_ORG_KEY,
167+
TREATMENT_PHYSICIAN_KEY = trte.TREATMENT_PHYSICIAN_KEY,
168+
TREATMENT_COUNT = trte.TREATMENT_COUNT,
169+
MORB_RPT_KEY = trte.MORB_RPT_KEY,
170+
INVESTIGATION_KEY = trte.INVESTIGATION_KEY,
171+
CONDITION_KEY = trte.CONDITION_KEY,
172+
LDF_GROUP_KEY = trte.LDF_GROUP_KEY,
173+
RECORD_STATUS_CD = trte.RECORD_STATUS_CD
174+
FROM #temp_trt_event_table trte
175+
INNER JOIN dbo.TREATMENT_EVENT te WITH (NOLOCK)
176+
ON trte.TREATMENT_KEY = te.TREATMENT_KEY
177+
WHERE trte.TREATMENT_KEY IS NOT NULL;
178+
179+
/* Logging */
180+
SET @rowcount = @@rowcount;
181+
INSERT INTO [dbo].[job_flow_log]
182+
( batch_id
183+
, [Dataflow_Name]
184+
, [package_Name]
185+
, [Status_Type]
186+
, [step_number]
187+
, [step_name]
188+
, [row_count]
189+
, [msg_description1])
190+
VALUES ( @batch_id
191+
, @dataflow_name
192+
, @package_name
193+
, 'START'
194+
, @proc_step_no
195+
, @proc_step_name
196+
, @rowcount
197+
, LEFT(@treatment_uids, 500));
198+
199+
SET @proc_step_name = 'Insert into TREATMENT Dimension';
200+
SET @proc_step_no = 4;
201+
202+
/* Treatment Insert Operation - Generate keys first */
203+
INSERT INTO dbo.nrt_treatment_key(treatment_uid)
204+
SELECT treatment_uid
205+
FROM #temp_trt_table
206+
WHERE TREATMENT_KEY IS NULL
207+
ORDER BY treatment_uid;
208+
209+
/* Perform inserts with the new keys */
210+
INSERT INTO dbo.TREATMENT
211+
(TREATMENT_KEY,
212+
TREATMENT_UID,
213+
TREATMENT_LOCAL_ID,
214+
TREATMENT_NM,
215+
TREATMENT_DRUG,
216+
TREATMENT_DOSAGE_STRENGTH,
217+
TREATMENT_DOSAGE_STRENGTH_UNIT,
218+
TREATMENT_FREQUENCY,
219+
TREATMENT_DURATION,
220+
TREATMENT_DURATION_UNIT,
221+
TREATMENT_COMMENTS,
222+
TREATMENT_ROUTE,
223+
CUSTOM_TREATMENT,
224+
TREATMENT_SHARED_IND,
225+
TREATMENT_OID,
226+
RECORD_STATUS_CD)
227+
SELECT k.d_treatment_key,
228+
trt.treatment_uid,
229+
trt.TREATMENT_LOCAL_ID,
230+
trt.TREATMENT_NM,
231+
trt.TREATMENT_DRUG,
232+
trt.TREATMENT_DOSAGE_STRENGTH,
233+
trt.TREATMENT_DOSAGE_STRENGTH_UNIT,
234+
trt.TREATMENT_FREQUENCY,
235+
trt.TREATMENT_DURATION,
236+
trt.TREATMENT_DURATION_UNIT,
237+
trt.TREATMENT_COMMENTS,
238+
trt.TREATMENT_ROUTE,
239+
trt.CUSTOM_TREATMENT,
240+
trt.TREATMENT_SHARED_IND,
241+
trt.TREATMENT_OID,
242+
trt.RECORD_STATUS_CD
243+
FROM #temp_trt_table trt
244+
JOIN dbo.nrt_treatment_key k ON trt.treatment_uid = k.treatment_uid
245+
WHERE trt.TREATMENT_KEY IS NULL;
246+
247+
/* Logging */
248+
SET @rowcount = @@rowcount;
249+
INSERT INTO [dbo].[job_flow_log]
250+
( batch_id
251+
, [Dataflow_Name]
252+
, [package_Name]
253+
, [Status_Type]
254+
, [step_number]
255+
, [step_name]
256+
, [row_count]
257+
, [msg_description1])
258+
VALUES ( @batch_id
259+
, @dataflow_name
260+
, @package_name
261+
, 'START'
262+
, @proc_step_no
263+
, @proc_step_name
264+
, @rowcount
265+
, LEFT(@treatment_uids, 500));
266+
267+
SET @proc_step_name = 'Insert into TREATMENT_EVENT Dimension';
268+
SET @proc_step_no = 5;
269+
270+
INSERT INTO dbo.TREATMENT_EVENT
271+
(TREATMENT_DT_KEY,
272+
TREATMENT_PROVIDING_ORG_KEY,
273+
PATIENT_KEY,
274+
TREATMENT_COUNT,
275+
TREATMENT_KEY,
276+
MORB_RPT_KEY,
277+
TREATMENT_PHYSICIAN_KEY,
278+
INVESTIGATION_KEY,
279+
CONDITION_KEY,
280+
LDF_GROUP_KEY,
281+
RECORD_STATUS_CD)
282+
SELECT trte.TREATMENT_DT_KEY,
283+
trte.TREATMENT_PROVIDING_ORG_KEY,
284+
trte.PATIENT_KEY,
285+
trte.TREATMENT_COUNT,
286+
k.d_treatment_key,
287+
trte.MORB_RPT_KEY,
288+
trte.TREATMENT_PHYSICIAN_KEY,
289+
trte.INVESTIGATION_KEY,
290+
trte.CONDITION_KEY,
291+
trte.LDF_GROUP_KEY,
292+
trte.RECORD_STATUS_CD
293+
FROM #temp_trt_event_table trte
294+
JOIN dbo.nrt_treatment_key k WITH (NOLOCK)
295+
ON trte.treatment_uid = k.treatment_uid
296+
WHERE trte.TREATMENT_KEY IS NULL;
297+
298+
/* Logging */
299+
SET @rowcount = @@rowcount;
300+
INSERT INTO [dbo].[job_flow_log]
301+
( batch_id
302+
, [Dataflow_Name]
303+
, [package_Name]
304+
, [Status_Type]
305+
, [step_number]
306+
, [step_name]
307+
, [row_count]
308+
, [msg_description1])
309+
VALUES ( @batch_id
310+
, @dataflow_name
311+
, @package_name
312+
, 'START'
313+
, @proc_step_no
314+
, @proc_step_name
315+
, @rowcount
316+
, LEFT(@treatment_uids, 500));
317+
318+
COMMIT TRANSACTION;
319+
320+
SET @proc_step_name = 'SP_COMPLETE';
321+
SET @proc_step_no = 6;
322+
323+
INSERT INTO [dbo].[job_flow_log]
324+
( batch_id
325+
, [Dataflow_Name]
326+
, [package_Name]
327+
, [Status_Type]
328+
, [step_number]
329+
, [step_name]
330+
, [row_count]
331+
, [msg_description1])
332+
VALUES ( @batch_id
333+
, @dataflow_name
334+
, @package_name
335+
, 'COMPLETE'
336+
, @proc_step_no
337+
, @proc_step_name
338+
, 0
339+
, LEFT(@treatment_uids, 500));
340+
341+
/* Return any additional data for further processing if needed */
342+
/* SELECT
343+
inv.CASE_UID AS public_health_case_uid,
344+
pat.PATIENT_UID AS patient_uid,
345+
dtm.Datamart AS datamart,
346+
c.CONDITION_CD AS condition_cd,
347+
dtm.Stored_Procedure AS stored_procedure
348+
FROM #temp_trt_event_table trt
349+
LEFT JOIN dbo.INVESTIGATION inv WITH (NOLOCK) ON inv.INVESTIGATION_KEY = trt.INVESTIGATION_KEY
350+
LEFT JOIN dbo.CONDITION c ON c.CONDITION_KEY = trt.CONDITION_KEY
351+
LEFT JOIN dbo.D_PATIENT pat WITH (NOLOCK) ON pat.PATIENT_KEY = trt.PATIENT_KEY
352+
LEFT JOIN dbo.nrt_datamart_metadata dtm WITH (NOLOCK) ON dtm.condition_cd = c.CONDITION_CD;*/
353+
354+
END TRY
355+
BEGIN CATCH
356+
IF @@TRANCOUNT > 0 ROLLBACK TRANSACTION;
357+
358+
DECLARE @FullErrorMessage NVARCHAR(4000) =
359+
'Error Number: ' + CAST(ERROR_NUMBER() AS VARCHAR(10)) + CHAR(13) + CHAR(10) +
360+
'Error Severity: ' + CAST(ERROR_SEVERITY() AS VARCHAR(10)) + CHAR(13) + CHAR(10) +
361+
'Error State: ' + CAST(ERROR_STATE() AS VARCHAR(10)) + CHAR(13) + CHAR(10) +
362+
'Error Line: ' + CAST(ERROR_LINE() AS VARCHAR(10)) + CHAR(13) + CHAR(10) +
363+
'Error Message: ' + ERROR_MESSAGE();
364+
365+
/* Logging */
366+
INSERT INTO [dbo].[job_flow_log]
367+
( batch_id
368+
, [Dataflow_Name]
369+
, [package_Name]
370+
, [Status_Type]
371+
, [step_number]
372+
, [step_name]
373+
, [row_count]
374+
, [msg_description1]
375+
, [Error_Description])
376+
VALUES ( @batch_id
377+
, @dataflow_name
378+
, @package_name
379+
, 'ERROR'
380+
, @Proc_Step_no
381+
, @Proc_Step_Name
382+
, 0
383+
, LEFT(@treatment_uids, 500)
384+
, @FullErrorMessage);
385+
386+
RETURN -1;
387+
END CATCH
388+
END;

0 commit comments

Comments
 (0)