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
|
-- ==============================================================
-- GNUmed database schema change script
--
-- License: GPL v2 or later
-- Author: karsten.hilbert@gmx.net
--
-- ==============================================================
\set ON_ERROR_STOP 1
--set default_transaction_read_only to off;
-- --------------------------------------------------------------
\unset ON_ERROR_STOP
drop index dem.idx_msg_inbox_fk_staff cascade;
drop index dem.idx_msg_inbox_fk_patient cascade;
\set ON_ERROR_STOP 1
create index idx_msg_inbox_fk_staff on dem.message_inbox(fk_staff);
create index idx_msg_inbox_fk_patient on dem.message_inbox(fk_patient);
-- --------------------------------------------------------------
\unset ON_ERROR_STOP
drop view dem.v_message_inbox cascade;
\set ON_ERROR_STOP 1
create view dem.v_message_inbox as
select
mi.modified_when
as received_when,
coalesce (
(select short_alias from dem.staff where db_user = mi.modified_by),
'<' || mi.modified_by || '>'
)
as modified_by,
(select short_alias from dem.staff where dem.staff.pk = mi.fk_staff)
as provider,
mi.importance,
vit.category,
vit.l10n_category,
vit.type,
vit.l10n_type,
mi.comment,
mi.ufk_context
as pk_context,
mi.data
as data,
mi.pk
as pk_inbox_message,
mi.fk_staff
as pk_staff,
vit.pk_category,
mi.fk_inbox_item_type
as pk_type,
mi.fk_patient
as pk_patient,
false
as is_virtual,
mi.due_date
as due_date,
mi.expiry_date
as expiry_date,
case
when due_date is null then false
when due_date > now() then false
when expiry_date is null then true
when expiry_date < now() then false
else true
end
as is_overdue,
case
when expiry_date is null then false
when expiry_date > now() then false
else true
end
as is_expired,
case
when due_date is null then null
when due_date > now() then due_date - now()
else now() - due_date
end
as interval_due,
gm.xid2int(mi.xmin)
as xmin_message_inbox
from
dem.message_inbox mi,
dem.v_inbox_item_type vit
where
mi.fk_inbox_item_type = vit.pk_type
union
select
now() as received_when,
'<system>' as modified_by,
(select short_alias from dem.staff where dem.staff.pk = vo4dnd.pk_intended_reviewer)
as provider,
0 as importance,
'clinical'
as category,
_('clinical')
as l10n_category,
'review docs'
as type,
_('review docs')
as l10n_type,
(select _('unreviewed documents for patient') || ' ['
|| dn.lastnames || ', '
|| dn.firstnames || ']'
from dem.names dn
where
dn.id_identity = vo4dnd.pk_patient
and
dn.active is True
)
as comment,
NULL::integer[]
as pk_context,
NULL::text
as data,
NULL::integer
as pk_inbox_message,
vo4dnd.pk_intended_reviewer
as pk_staff,
(select pk_category from dem.v_inbox_item_type where type = 'review docs')
as pk_category,
(select pk_type from dem.v_inbox_item_type where type = 'review docs')
as pk_type,
vo4dnd.pk_patient as pk_patient,
true
as is_virtual,
now()::date - '1 hour'::interval
as due_date,
NULL::date
as expiry_date,
TRUE::boolean
as is_overdue,
FALSE::boolean
as is_expired,
'1 hour'::interval
as interval_due,
NULL::integer
as xmin_message_inbox
from
blobs.v_obj4doc_no_data vo4dnd
where
reviewed is False
union
select
now() as received_when,
vtr.modified_by as modified_by,
(select short_alias from dem.staff where dem.staff.pk = vtr.pk_intended_reviewer)
as provider,
0 as importance,
'clinical'
as category,
_('clinical')
as l10n_category,
'review results'
as type,
_('review results')
as l10n_type,
(select _('unreviewed (normal) results for patient') || ' ['
|| dn.lastnames || ', '
|| dn.firstnames || ']'
from dem.names dn
where
dn.id_identity = vtr.pk_patient
and
dn.active is True
)
as comment,
NULL::integer[]
as pk_context,
NULL::text
as data,
NULL::integer
as pk_inbox_message,
vtr.pk_intended_reviewer
as pk_staff,
(select pk_category from dem.v_inbox_item_type where type = 'review results')
as pk_category,
(select pk_type from dem.v_inbox_item_type where type = 'review results')
as pk_type,
vtr.pk_patient as pk_patient,
true
as is_virtual,
now()::date - '1 hour'::interval
as due_date,
NULL::date
as expiry_date,
TRUE::boolean
as is_overdue,
FALSE::boolean
as is_expired,
'1 hour'::interval
as interval_due,
NULL::integer
as xmin_message_inbox
from
clin.v_test_results vtr
where
reviewed is false
and
(
(is_technically_abnormal is false)
or
((is_technically_abnormal is null) and (abnormality_indicator is null))
)
union
select
now() as received_when,
vtr.modified_by as modified_by,
(select short_alias from dem.staff where dem.staff.pk = vtr.pk_intended_reviewer)
as provider,
1 as importance,
'clinical'
as category,
_('clinical')
as l10n_category,
'review results'
as type,
_('review results')
as l10n_type,
(select _('unreviewed (abnormal) results for patient') || ' ['
|| dn.lastnames || ', '
|| dn.firstnames || ']'
from dem.names dn
where
dn.id_identity = vtr.pk_patient
and
dn.active is True
)
as comment,
NULL::integer[]
as pk_context,
NULL::text
as data,
NULL::integer
as pk_inbox_message,
vtr.pk_intended_reviewer
as pk_staff,
(select pk_category from dem.v_inbox_item_type where type = 'review results')
as pk_category,
(select pk_type from dem.v_inbox_item_type where type = 'review results')
as pk_type,
vtr.pk_patient as pk_patient,
true
as is_virtual,
now()::date - '1 hour'::interval
as due_date,
NULL::date
as expiry_date,
TRUE::boolean
as is_overdue,
FALSE::boolean
as is_expired,
'1 hour'::interval
as interval_due,
NULL::integer
as xmin_message_inbox
from
clin.v_test_results vtr
where
reviewed is false
and
(
(is_technically_abnormal is true)
or
((is_technically_abnormal is null) and (abnormality_indicator is not null))
)
;
comment on view dem.v_message_inbox is
'Denormalized messages for the providers and/or patients.
Using UNION makes sure we get the right level of uniqueness.';
grant select on dem.v_message_inbox to group "gm-doctors";
-- ==============================================================
select gm.log_script_insertion('v18-dem-v_message_inbox.sql', '18.0');
|