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
|
-- ==============================================================
-- GNUmed database schema change script
--
-- License: GPL v2 or later
-- Author: karsten.hilbert@gmx.net
--
-- ==============================================================
\set ON_ERROR_STOP 1
-- --------------------------------------------------------------
-- remove those which have been orphaned by the old
-- LOINC updater w/ respect to .fk_data_source
delete from ref.loinc r_l where not exists (
select 1 from ref.data_source r_ds
where
r_ds.pk = r_l.fk_data_source
and
r_ds.name_short like '%LOINC%'
);
-- make sure we've got a LOINC data source
insert into ref.data_source (
name_long,
name_short,
version,
source
) select
'LOINC® (Logical Observation Identifiers Names and Codes)',
'LOINC',
'2.26',
'http://loinc.org'
where not exists (
select 1 from ref.data_source where
name_long = 'LOINC® (Logical Observation Identifiers Names and Codes)'
and
name_short = 'LOINC'
and
version = '2.26'
);
-- remove dupes
delete from ref.loinc
where ref.loinc.pk not in (
select max(rl2.pk)
from ref.loinc rl2
group by
-- rl2.fk_data_source,
rl2.code,
rl2.term
);
-- ensure fk_data_source points to a LOINC entry
update ref.loinc set
fk_data_source = (
select ref.data_source.pk
from ref.data_source
where
name_long = 'LOINC® (Logical Observation Identifiers Names and Codes)'
and
name_short = 'LOINC'
and
version = '2.26'
limit 1
)
where
fk_data_source not in (
select pk
from ref.data_source
where
name_short like '%LOINC%'
)
;
-- --------------------------------------------------------------
\unset ON_ERROR_STOP
drop trigger tr_upd_ref_code_tbl_check_backlink on ref.loinc;
drop trigger tr_del_ref_code_tbl_check_backlink on ref.loinc;
\set ON_ERROR_STOP 1
-- UPDATE
create trigger tr_upd_ref_code_tbl_check_backlink
before update on ref.loinc
for each row execute procedure ref.trf_upd_ref_code_tbl_check_backlink();
-- DELETE
create trigger tr_del_ref_code_tbl_check_backlink
before update on ref.loinc
for each row execute procedure ref.trf_del_ref_code_tbl_check_backlink();
-- --------------------------------------------------------------
\unset ON_ERROR_STOP
drop index idx_ref_loinc_fk_data_src cascade;
drop index idx_ref_loinc_code_unique_per_system cascade;
drop index idx_ref_loinc_term_unique_per_system cascade;
\set ON_ERROR_STOP 1
create index idx_ref_loinc_fk_data_src on ref.loinc(fk_data_source);
create unique index idx_ref_loinc_code_unique_per_system on ref.loinc(fk_data_source, lower(code));
create unique index idx_ref_loinc_term_unique_per_system on ref.loinc(fk_data_source, lower(code), lower(term));
-- --------------------------------------------------------------
\unset ON_ERROR_STOP
alter table ref.loinc drop constraint loinc_fk_data_source_fkey cascade;
\set ON_ERROR_STOP 1
alter table ref.loinc
add foreign key (fk_data_source)
references ref.data_source(pk)
on update cascade
on delete restrict;
-- --------------------------------------------------------------
select gm.log_script_insertion('v16-ref-loinc-dynamic.sql', '16.0');
|