File: v12-clin-substance_intake-dynamic.sql

package info (click to toggle)
gnumed-server 16.17-1
  • links: PTS, VCS
  • area: main
  • in suites: wheezy
  • size: 42,064 kB
  • sloc: sql: 1,190,603; python: 11,850; sh: 1,082; makefile: 19
file content (341 lines) | stat: -rw-r--r-- 9,172 bytes parent folder | download | duplicates (7)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
-- ==============================================================
-- GNUmed database schema change script
--
-- License: GPL v2 or later
-- Author: karsten.hilbert@gmx.net
--
-- ==============================================================
-- $Id: v12-clin-substance_intake-dynamic.sql,v 1.8 2009-12-03 17:52:12 ncq Exp $
-- $Revision: 1.8 $

-- --------------------------------------------------------------
\set ON_ERROR_STOP 1

set check_function_bodies to 1;
--set default_transaction_read_only to off;

-- --------------------------------------------------------------
-- .soap_cat
alter table clin.substance_intake
	alter column soap_cat
		set default 'p';

\unset ON_ERROR_STOP
alter table clin.substance_intake drop constraint medication_is_plan cascade;
\set ON_ERROR_STOP 1

alter table clin.substance_intake
	add constraint medication_is_plan
		check (soap_cat='p');

-- --------------------------------------------------------------
-- .is_long_term
comment on column clin.substance_intake.is_long_term is
	'whether this is expected to be a regular/ongoing/chronic/long-term/repeat/permament/perpetual/life-long substance intake';


alter table clin.substance_intake
	alter column is_long_term
		set default null;

-- --------------------------------------------------------------
-- .fk_episode
alter table clin.substance_intake
	alter column fk_episode
		drop not null;


\unset ON_ERROR_STOP
alter table clin.substance_intake drop constraint sane_fk_episode cascade;
\set ON_ERROR_STOP 1


alter table clin.substance_intake
	add constraint sane_fk_episode
		check (
			(intake_is_approved_of is False)
				OR
			((intake_is_approved_of is TRUE) AND (fk_episode is not NULL))
		);


\unset ON_ERROR_STOP
drop function clin.trf_sanity_check_substance_episode() cascade;
\set ON_ERROR_STOP 1


create or replace function clin.trf_sanity_check_substance_episode()
	returns trigger
	language plpgsql
	as '
declare
	_identity_from_encounter integer;
	_identity_from_episode integer;
begin
	-- episode can only be NULL if intake is not approved of,
	-- IOW, if clinician approves of intake she better know why
	if NEW.intake_is_approved_of is True then
		if NEW.fk_episode is NULL then
			raise exception ''clin.trf_sanity_check_substance_episode(): substance intake is approved of but .fk_episode is NULL'';
			return NULL;
		end if;
	end if;

	-- .fk_episode can be NULL (except in the above case)
	if NEW.fk_episode is NULL then
		return NEW;
	end if;

	-- .fk_episode must belong to the same patient as .fk_encounter
	select fk_patient into _identity_from_encounter from clin.encounter where pk = NEW.fk_encounter;

	select fk_patient into _identity_from_episode from clin.encounter where pk = (
		select fk_encounter from clin.episode where pk = NEW.fk_episode
	);

	if _identity_from_encounter <> _identity_from_episode then
		raise exception ''INSERT/UPDATE into %.%: Sanity check failed. Encounter % patient = %. Episode % patient = %.'',
			TG_TABLE_SCHEMA,
			TG_TABLE_NAME,
			NEW.fk_encounter,
			_identity_from_encounter,
			NEW.fk_episode,
			_identity_from_episode
		;
		return NULL;
	end if;

	return NEW;

end;';


create trigger tr_sanity_check_substance_episode
	before insert or update
	on clin.substance_intake
	for each row
		execute procedure clin.trf_sanity_check_substance_episode();

-- --------------------------------------------------------------
-- .fk_brand
alter table clin.substance_intake
	alter column fk_brand
		drop not null;

-- --------------------------------------------------------------
-- .fk_substance

-- drop old foreign key on consumed substance
\unset ON_ERROR_STOP
alter table clin.substance_intake drop constraint substance_intake_fk_substance_fkey cascade;
\set ON_ERROR_STOP 1

-- re-adjust foreign key data
update clin.substance_intake csi set
	fk_substance = (
		select ccs.pk
		from clin.consumed_substance ccs
		where
			ccs.description = (
				select cas.description
				from clin.active_substance cas
				where cas.pk = csi.fk_substance
			)
	);

-- re-add new foreign key
alter table clin.substance_intake
	add foreign key (fk_substance)
		references clin.consumed_substance(pk)
			on update cascade
			on delete restrict;

-- --------------------------------------------------------------
\unset ON_ERROR_STOP
drop view clin.v_pat_substance_intake cascade;
\set ON_ERROR_STOP 1

create view clin.v_pat_substance_intake as
select
	csi.pk
		as pk_substance_intake,
	(select fk_patient from clin.encounter where pk = csi.fk_encounter)
		as pk_patient,
	csi.soap_cat,
	rbd.description
		as brand,
	csi.preparation,
	rbd.atc_code
		as atc_brand,
	rbd.external_code
		as external_code_brand,

	ccs.description
		as substance,
	csi.strength,
	ccs.atc_code
		as atc_substance,

	csi.clin_when
		as started,
	csi.intake_is_approved_of,
	csi.schedule,
	csi.duration,
	csi.is_long_term,
	csi.aim,
	cep.description
		as episode,
	csi.narrative
		as notes,
	rbd.is_fake
		as fake_brand,

	case
		when csi.clin_when is null then false
		-- from here on csi.clin_when cannot be null
		when (csi.clin_when > current_timestamp) is true then false
		-- from here on csi.clin_when must be < current_timestamp and not null
		when is_long_term is true then true
		-- from here on csi.is_long_term must be false or null
		when (csi.clin_when + csi.duration > current_timestamp) is true then true
		when (csi.clin_when + csi.duration < current_timestamp) is true then false
		-- from here on csi.duration must be null
		else null
	end::boolean
		as is_currently_active,

	csi.fk_brand
		as pk_brand,
	ccs.pk
		as pk_substance,
	csi.fk_encounter
		as pk_encounter,
	csi.fk_episode
		as pk_episode,
	cep.fk_health_issue
		as pk_health_issue,
	csi.modified_when,
	csi.modified_by,
	csi.xmin
		as xmin_substance_intake
from
	clin.substance_intake csi
		left join ref.branded_drug rbd on (csi.fk_brand = rbd.pk)
			left join clin.consumed_substance ccs on (csi.fk_substance = ccs.pk)
				left join clin.episode cep on (csi.fk_episode = cep.pk)
;

grant select on clin.v_pat_substance_intake to group "gm-doctors";

-- --------------------------------------------------------------
\unset ON_ERROR_STOP
drop view clin.v_pat_substance_intake_journal cascade;
\set ON_ERROR_STOP 1

create view clin.v_pat_substance_intake_journal as
select
	(select fk_patient from clin.encounter where pk = csi.fk_encounter)
		as pk_patient,
	csi.modified_when
		as modified_when,
	csi.clin_when
		as clin_when,
	coalesce (
		(select short_alias from dem.staff where db_user = csi.modified_by),
		'<' || csi.modified_by || '>'
	)
		as modified_by,
	csi.soap_cat
		as soap_cat,

	(case
		when is_long_term is true then _('long-term') || ' '
		else ''
	 end
	)
		|| _('substance intake') || ' '
		|| (case
				when intake_is_approved_of is true then _('(approved of)')
				when intake_is_approved_of is false then _('(not approved of)')
				else _('(of unknown approval)')
			end)
		|| E':\n'

		|| ' ' || ccs.description								-- Metoprolol
		|| coalesce(' [' || ccs.atc_code || '] ', ' ')			-- [ATC]
		|| csi.strength || ' '									-- 100mg
		|| csi.preparation										-- tab
		|| coalesce(' ' || csi.schedule, '')					-- 1-0-0
		|| ', ' || to_char(csi.clin_when, 'YYYY-MM-DD')			-- 2009-03-01
		|| coalesce(' -> ' || csi.duration, '')					-- -> 6 months
		|| E'\n'

		|| coalesce (
			nullif (
				(coalesce(' ' || csi.aim, '')						-- lower RR
				 || coalesce(' (' || csi.narrative || ')', '')		-- report if unwell
				 || E'\n'
				),
				E'\n'
			),
			''
		)

		|| coalesce (' "' || rbd.description || ' ' || rbd.preparation || '"'		-- "MetoPharm tablets"
			|| coalesce(' [' || rbd.atc_code || ']', '')							-- [ATC code]
			|| coalesce(' (' || rbd.external_code || ')', ''),						-- (external code)
			'')

	as narrative,

	csi.fk_encounter
		as pk_encounter,
	csi.fk_episode
		as pk_episode,
	(select fk_health_issue from clin.episode where pk = csi.fk_episode)
		as pk_health_issue,
	csi.pk
		as src_pk,
	'clin.substance_intake'::text
		as src_table,
	csi.row_version
		as row_version
from
	clin.substance_intake csi
		left join ref.branded_drug rbd on (csi.fk_brand = rbd.pk)
			left join clin.consumed_substance ccs on (csi.fk_substance = ccs.pk)
;

-- --------------------------------------------------------------
select gm.log_script_insertion('$RCSfile: v12-clin-substance_intake-dynamic.sql,v $', '$Revision: 1.8 $');

-- ==============================================================
-- $Log: v12-clin-substance_intake-dynamic.sql,v $
-- Revision 1.8  2009-12-03 17:52:12  ncq
-- - improved constraints
--
-- Revision 1.7  2009/11/24 21:08:49  ncq
-- - adjust to new drug tables
--
-- Revision 1.6  2009/11/06 15:34:44  ncq
-- - .is_currently_active and .pk_health_issue in view
--
-- Revision 1.5  2009/10/29 17:27:56  ncq
-- - .is_long_term
-- - sanity check on fk_episode
-- - view adjusted
--
-- Revision 1.4  2009/10/28 21:49:27  ncq
-- - need episode name in view, too :-)
--
-- Revision 1.3  2009/10/28 16:45:32  ncq
-- - slightly better comment
--
-- Revision 1.2  2009/10/27 11:03:37  ncq
-- - better comment
--
-- Revision 1.1  2009/10/21 08:54:32  ncq
-- - foreign key to consumed_substances
-- - rework views
--
--