File: v12-ref-substance_in_brand-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 (126 lines) | stat: -rw-r--r-- 3,290 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
-- ==============================================================
-- GNUmed database schema change script
--
-- License: GPL v2 or later
-- Author: karsten.hilbert@gmx.net
--
-- ==============================================================
-- $Id: v12-ref-substance_in_brand-dynamic.sql,v 1.2 2009-11-28 18:33:39 ncq Exp $
-- $Revision: 1.2 $

-- --------------------------------------------------------------
\set ON_ERROR_STOP 1
--set default_transaction_read_only to off;

-- --------------------------------------------------------------
select audit.add_table_for_audit('ref', 'substance_in_brand');
select gm.add_table_for_notifies('ref', 'substance_in_brand');


comment on table ref.substance_in_brand is
	'lists substances being part of branded drugs';


-- .fk_brand
comment on column ref.substance_in_brand.fk_brand is
	'The drug brand this substance belongs to.';

\unset ON_ERROR_STOP
drop index ref.idx_subst_fk_brand cascade;
\set ON_ERROR_STOP 1

create index idx_subst_fk_brand on ref.substance_in_brand(fk_brand);


-- .description
comment on column ref.substance_in_brand.description is
	'The substance name.';

\unset ON_ERROR_STOP
alter table ref.substance_in_brand drop constraint subst_sane_desc cascade;
drop index ref.idx_subst_description cascade;
\set ON_ERROR_STOP 1

alter table ref.substance_in_brand
	add constraint subst_sane_desc
		check (gm.is_null_or_blank_string(description) is False);

create index idx_subst_description on ref.substance_in_brand(description);


-- .atc_code
comment on column ref.substance_in_brand.atc_code is
	'the Anatomic Therapeutic Chemical code for this substance';

\unset ON_ERROR_STOP
alter table ref.substance_in_brand drop constraint subst_sane_atc cascade;
\set ON_ERROR_STOP 1

alter table ref.substance_in_brand
	add constraint subst_sane_atc
		check (gm.is_null_or_non_empty_string(atc_code) is True);


-- .table constraints
alter table ref.substance_in_brand
	add constraint subst_unique_per_brand
		unique (fk_brand, description);


-- grants
grant select, insert, update, delete on
	ref.substance_in_brand,
	ref.substance_in_brand_pk_seq
to group "gm-doctors";

-- --------------------------------------------------------------
\unset ON_ERROR_STOP
drop view ref.v_substance_in_brand cascade;
\set ON_ERROR_STOP 1

create view ref.v_substance_in_brand as

select
	rsib.pk
		as pk_substance_in_brand,
	rsib.description
		as substance,
	rsib.atc_code
		as atc_substance,
	rbd.description
		as brand,
	rbd.preparation
		as preparation,
	rbd.atc_code
		as atc_brand,
	rbd.external_code
		as external_code_brand,
	rbd.is_fake
		as is_fake_brand,

	rbd.fk_data_source
		as pk_data_source,
	rsib.fk_brand
		as pk_brand
from
	ref.substance_in_brand rsib
		left join ref.branded_drug rbd on (rsib.fk_brand = rbd.pk)
;


grant select on
	ref.v_substance_in_brand
to group "gm-doctors";

-- --------------------------------------------------------------
select gm.log_script_insertion('$RCSfile: v12-ref-substance_in_brand-dynamic.sql,v $', '$Revision: 1.2 $');

-- ==============================================================
-- $Log: v12-ref-substance_in_brand-dynamic.sql,v $
-- Revision 1.2  2009-11-28 18:33:39  ncq
-- - ref.v_substance_in_brand
--
-- Revision 1.1  2009/11/24 21:11:39  ncq
-- - new drug tables
--
--