File: v16-ref-atc-dynamic.sql

package info (click to toggle)
gnumed-server 22.31-1
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid, trixie
  • size: 46,268 kB
  • sloc: sql: 1,217,633; python: 15,878; sh: 1,590; makefile: 20
file content (114 lines) | stat: -rw-r--r-- 3,132 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
-- ==============================================================
-- GNUmed database schema change script
--
-- License: GPL v2 or later
-- Author: karsten.hilbert@gmx.net
--
-- ==============================================================
\set ON_ERROR_STOP 1

-- --------------------------------------------------------------
\unset ON_ERROR_STOP
drop trigger tr_upd_ref_code_tbl_check_backlink on ref.atc;
drop trigger tr_del_ref_code_tbl_check_backlink on ref.atc;
\set ON_ERROR_STOP 1


-- UPDATE
create trigger tr_upd_ref_code_tbl_check_backlink
	before update on ref.atc
		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.atc
		for each row execute procedure ref.trf_del_ref_code_tbl_check_backlink();

-- --------------------------------------------------------------
-- remove those which have been orphaned by the old
-- ATC updater w/ respect to .fk_data_source
delete from ref.atc r_a where not exists (
	select 1 from ref.data_source r_ds
	where
		r_ds.pk = r_a.fk_data_source
			and
		r_ds.name_short like '%ATC%'
);

-- make sure we've got an ATC data source
insert into ref.data_source (
	name_long,
	name_short,
	version,
	source
) select
	'Anatomical Therapeutic Chemical Classification 1/2009 Deutschland',
	'ATC',
	'2009-01-DE',
	'http://www.dimdi.de'
 where not exists (
	select 1 from ref.data_source where
		name_long = 'Anatomical Therapeutic Chemical Classification 1/2009 Deutschland'
			and
		name_short = 'ATC'
			and
		version = '2009-01-DE'
);

-- remove dupes
delete from ref.atc
where pk not in (
	select max(ra2.pk)
	from ref.atc ra2
	group by
--		ra2.fk_data_source,
		ra2.code,
		lower(ra2.term)
);

-- ensure fk_data_source points to an ATC entry
update ref.atc set
	fk_data_source = (
		select ref.data_source.pk
		from ref.data_source
		where
			name_long = 'Anatomical Therapeutic Chemical Classification 1/2009 Deutschland'
				and
			name_short = 'ATC'
				and
			version = '2009-01-DE'
		limit 1
	)
where
	fk_data_source not in (
		select pk
		from ref.data_source
		where
			name_short like '%ATC%'
	)
;

-- --------------------------------------------------------------
\unset ON_ERROR_STOP
drop index idx_ref_atc_fk_data_src cascade;
drop index idx_ref_atc_code_unique_per_system cascade;
drop index idx_ref_atc_term_unique_per_system cascade;
\set ON_ERROR_STOP 1

create index idx_ref_atc_fk_data_src on ref.atc(fk_data_source);
create unique index idx_ref_atc_code_unique_per_system on ref.atc(fk_data_source, lower(code));
create unique index idx_ref_atc_term_unique_per_system on ref.atc(fk_data_source, lower(code), lower(term));

-- --------------------------------------------------------------
\unset ON_ERROR_STOP
alter table ref.atc drop constraint atc_fk_data_source_fkey cascade;
\set ON_ERROR_STOP 1

alter table ref.atc
	add foreign key (fk_data_source)
		references ref.data_source(pk)
		on update cascade
		on delete restrict;

-- --------------------------------------------------------------
select gm.log_script_insertion('v16-ref-atc-dynamic.sql', '16.0');