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
|
-- ==============================================================
-- GNUmed database schema change script
--
-- License: GPL v2 or later
-- Author: Karsten Hilbert
--
-- ==============================================================
\set ON_ERROR_STOP 1
--set default_transaction_read_only to off;
-- --------------------------------------------------------------
drop view if exists clin.v_procedures_at_hospital_journal cascade;
create view clin.v_procedures_at_hospital_journal as
select
c_enc.fk_patient
as pk_patient,
c_pr.modified_when
as modified_when,
c_pr.clin_when
as clin_when,
coalesce (
(select short_alias from dem.staff where db_user = c_pr.modified_by),
'<' || c_pr.modified_by || '>'
)
as modified_by,
c_pr.soap_cat
as soap_cat,
_('Procedure') || ' "' || c_pr.narrative || '"'
|| ' ('
|| d_ou.description || ' @ ' || d_o.description
|| coalesce (
(', ' || _('until') || ' ' || to_char(c_pr.clin_end, 'YYYY Mon DD')),
case
when (c_pr.is_ongoing is True)
then ', ' || _('ongoing')
else ''
end
)
|| E')'
|| coalesce ((
E'\n' || array_to_string (
(select array_agg(r_csr.code || ' (' || r_ds.name_short || ' - ' || r_ds.version || ' - ' || r_ds.lang || '): ' || r_csr.term)
from
clin.lnk_code2procedure c_lc2p
inner join
ref.coding_system_root r_csr on c_lc2p.fk_generic_code = r_csr.pk_coding_system
inner join
ref.data_source r_ds on r_ds.pk = r_csr.fk_data_source
where
c_lc2p.fk_item = c_pr.pk
),
'; '
) || ';'
),
''
)
as narrative,
c_pr.fk_encounter
as pk_encounter,
c_pr.fk_episode
as pk_episode,
c_epi.fk_health_issue
as pk_health_issue,
c_pr.pk
as src_pk,
'clin.procedure'::text
as src_table,
c_pr.row_version,
-- issue
c_hi.description
as health_issue,
c_hi.laterality
as issue_laterality,
c_hi.is_active
as issue_active,
c_hi.clinically_relevant
as issue_clinically_relevant,
c_hi.is_confidential
as issue_confidential,
-- episode
c_epi.description
as episode,
c_epi.is_open
as episode_open,
-- encounter
c_enc.started
as encounter_started,
c_enc.last_affirmed
as encounter_last_affirmed,
c_ety.description
as encounter_type,
_(c_ety.description)
as encounter_l10n_type
from
clin.procedure c_pr
inner join clin.encounter c_enc on c_pr.fk_encounter = c_enc.pk
inner join clin.encounter_type c_ety on (c_enc.fk_type = c_ety.pk)
inner join clin.episode c_epi on c_pr.fk_episode = c_epi.pk
left join clin.health_issue c_hi on (c_epi.fk_health_issue = c_hi.pk)
left join clin.hospital_stay c_hs on c_pr.fk_hospital_stay = c_hs.pk
left join dem.org_unit d_ou on c_hs.fk_org_unit = d_ou.pk
left join dem.org d_o on d_ou.fk_org = d_o.pk
where
c_pr.fk_hospital_stay is not null
;
grant select on clin.v_procedures_at_hospital_journal TO GROUP "gm-doctors";
-- --------------------------------------------------------------
drop view if exists clin.v_procedures_not_at_hospital_journal cascade;
create view clin.v_procedures_not_at_hospital_journal as
select
c_enc.fk_patient
as pk_patient,
c_pr.modified_when
as modified_when,
c_pr.clin_when
as clin_when,
coalesce (
(select short_alias from dem.staff where db_user = c_pr.modified_by),
'<' || c_pr.modified_by || '>'
)
as modified_by,
c_pr.soap_cat
as soap_cat,
_('Procedure') || ' "' || c_pr.narrative || '"'
|| ' ('
|| d_ou.description || ' @ ' || d_o.description
|| coalesce (
(', ' || _('until') || ' ' || to_char(c_pr.clin_end, 'YYYY Mon DD')),
case
when (c_pr.is_ongoing is True)
then ', ' || _('ongoing')
else ''
end
)
|| E')'
|| coalesce ((
E'\n' || array_to_string (
(select array_agg(r_csr.code || ' (' || r_ds.name_short || ' - ' || r_ds.version || ' - ' || r_ds.lang || '): ' || r_csr.term)
from
clin.lnk_code2procedure c_lc2p
inner join
ref.coding_system_root r_csr on c_lc2p.fk_generic_code = r_csr.pk_coding_system
inner join
ref.data_source r_ds on r_ds.pk = r_csr.fk_data_source
where
c_lc2p.fk_item = c_pr.pk
),
'; '
) || ';'
),
''
)
as narrative,
c_pr.fk_encounter
as pk_encounter,
c_pr.fk_episode
as pk_episode,
c_epi.fk_health_issue
as pk_health_issue,
c_pr.pk
as src_pk,
'clin.procedure'::text
as src_table,
c_pr.row_version,
-- issue
c_hi.description
as health_issue,
c_hi.laterality
as issue_laterality,
c_hi.is_active
as issue_active,
c_hi.clinically_relevant
as issue_clinically_relevant,
c_hi.is_confidential
as issue_confidential,
-- episode
c_epi.description
as episode,
c_epi.is_open
as episode_open,
-- encounter
c_enc.started
as encounter_started,
c_enc.last_affirmed
as encounter_last_affirmed,
c_ety.description
as encounter_type,
_(c_ety.description)
as encounter_l10n_type
from
clin.procedure c_pr
inner join clin.encounter c_enc on c_pr.fk_encounter = c_enc.pk
inner join clin.encounter_type c_ety on (c_enc.fk_type = c_ety.pk)
inner join clin.episode c_epi on c_pr.fk_episode = c_epi.pk
left join clin.health_issue c_hi on (c_epi.fk_health_issue = c_hi.pk)
left join dem.org_unit d_ou on c_pr.fk_org_unit = d_ou.pk
left join dem.org d_o on d_ou.fk_org = d_o.pk
where
c_pr.fk_hospital_stay is null
;
grant select on clin.v_procedures_not_at_hospital_journal TO GROUP "gm-doctors";
-- --------------------------------------------------------------
drop view if exists clin.v_procedures_journal cascade;
create view clin.v_procedures_journal as
select * from clin.v_procedures_at_hospital_journal
union all
select * from clin.v_procedures_not_at_hospital_journal
;
grant select on clin.v_procedures_journal TO GROUP "gm-doctors";
-- --------------------------------------------------------------
select gm.log_script_insertion('v21-clin-v_procedures_journal.sql', '21.0');
|