]> Git — Sourcephile - gargantext.git/blob - devops/postgres/schema.sql
Merge branch 'dev' into 74-dev-frame-calc-csv-import
[gargantext.git] / devops / postgres / schema.sql
1 CREATE EXTENSION IF NOT EXISTS plpgsql WITH SCHEMA pg_catalog;
2 COMMENT ON EXTENSION plpgsql IS 'PL/pgSQL procedural language';
3
4 CREATE EXTENSION IF NOT EXISTS tsm_system_rows;
5 CREATE EXTENSION pgcrypto;
6
7 -----------------------------------------------------------------
8 CREATE TABLE public.auth_user (
9 id SERIAL,
10 password CHARACTER varying(128) NOT NULL,
11 last_login TIMESTAMP with time zone,
12 is_superuser BOOLEAN NOT NULL,
13 username CHARACTER varying(150) NOT NULL,
14 first_name CHARACTER varying(30) NOT NULL,
15 last_name CHARACTER varying(30) NOT NULL,
16 email CHARACTER varying(254) NOT NULL,
17 is_staff BOOLEAN NOT NULL,
18 is_active BOOLEAN NOT NULL,
19 date_joined TIMESTAMP with time zone DEFAULT now() NOT NULL,
20 PRIMARY KEY (id)
21 );
22
23 ALTER TABLE public.auth_user OWNER TO gargantua;
24
25 -- TODO add publication_date
26 -- TODO typename -> type_id
27 CREATE TABLE public.nodes (
28 id SERIAL,
29 hash_id CHARACTER varying(66) DEFAULT ''::character varying NOT NULL,
30 typename INTEGER NOT NULL,
31 user_id INTEGER NOT NULL,
32 parent_id INTEGER REFERENCES public.nodes(id) ON DELETE CASCADE ,
33 name CHARACTER varying(255) DEFAULT ''::character varying NOT NULL,
34 date TIMESTAMP with time zone DEFAULT now() NOT NULL,
35 hyperdata jsonb DEFAULT '{}'::jsonb NOT NULL,
36 search tsvector,
37 PRIMARY KEY (id),
38 FOREIGN KEY (user_id) REFERENCES public.auth_user(id) ON DELETE CASCADE
39 );
40 ALTER TABLE public.nodes OWNER TO gargantua;
41 --------------------------------------------------------------
42 -- | Ngrams
43 CREATE TABLE public.ngrams (
44 id SERIAL,
45 terms CHARACTER varying(255),
46 n INTEGER,
47 PRIMARY KEY (id)
48 );
49 ALTER TABLE public.ngrams OWNER TO gargantua;
50
51 -- | Ngrams PosTag
52 CREATE TABLE public.ngrams_postag (
53 id SERIAL,
54 lang_id INTEGER,
55 algo_id INTEGER,
56 postag CHARACTER varying(5),
57 ngrams_id INTEGER NOT NULL,
58 lemm_id INTEGER NOT NULL,
59 score INTEGER DEFAULT 1 ::integer NOT NULL,
60 FOREIGN KEY (ngrams_id) REFERENCES public.ngrams(id) ON DELETE CASCADE,
61 FOREIGN KEY (lemm_id) REFERENCES public.ngrams(id) ON DELETE CASCADE
62 );
63 ALTER TABLE public.ngrams_postag OWNER TO gargantua;
64
65 --------------------------------------------------------------
66 CREATE TABLE public.node_ngrams (
67 id SERIAL,
68 node_id INTEGER NOT NULL,
69 node_subtype INTEGER,
70 ngrams_id INTEGER NOT NULL,
71 ngrams_type INTEGER, -- change to ngrams_field? (no for pedagogic reason)
72 ngrams_field INTEGER,
73 ngrams_tag INTEGER,
74 ngrams_class INTEGER,
75 weight double precision,
76 PRIMARY KEY (id),
77 FOREIGN KEY (node_id) REFERENCES public.nodes(id) ON DELETE CASCADE,
78 FOREIGN KEY (ngrams_id) REFERENCES public.ngrams(id) ON DELETE CASCADE
79 );
80 ALTER TABLE public.node_ngrams OWNER TO gargantua;
81
82 CREATE TABLE public.node_nodengrams_nodengrams (
83 node_id INTEGER NOT NULL,
84 node_ngrams1_id INTEGER NOT NULL,
85 node_ngrams2_id INTEGER NOT NULL,
86 weight double precision,
87 FOREIGN KEY (node_id) REFERENCES public.nodes(id) ON DELETE CASCADE,
88 FOREIGN KEY (node_ngrams1_id) REFERENCES public.node_ngrams(id) ON DELETE CASCADE,
89 FOREIGN KEY (node_ngrams2_id) REFERENCES public.node_ngrams(id) ON DELETE CASCADE,
90 PRIMARY KEY (node_id, node_ngrams1_id, node_ngrams2_id)
91 );
92 ALTER TABLE public.node_nodengrams_nodengrams OWNER TO gargantua;
93
94 --------------------------------------------------------------
95 --------------------------------------------------------------
96 --
97 --
98 --CREATE TABLE public.nodes_ngrams_ngrams (
99 -- node_id integer NOT NULL REFERENCES public.nodes(id) ON DELETE CASCADE,
100 -- ngram1_id integer NOT NULL REFERENCES public.ngrams(id) ON DELETE CASCADE,
101 -- ngram2_id integer NOT NULL REFERENCES public.ngrams(id) ON DELETE CASCADE,
102 -- weight double precision,
103 -- PRIMARY KEY (node_id,ngram1_id,ngram2_id)
104 --);
105 --
106 --ALTER TABLE public.nodes_ngrams_ngrams OWNER TO gargantua;
107 ---------------------------------------------------------------
108 -- TODO nodes_nodes(node1_id int, node2_id int, edge_type int , weight real)
109 CREATE TABLE public.nodes_nodes (
110 node1_id INTEGER NOT NULL REFERENCES public.nodes(id) ON DELETE CASCADE,
111 node2_id INTEGER NOT NULL REFERENCES public.nodes(id) ON DELETE CASCADE,
112 score REAL,
113 category INTEGER,
114 PRIMARY KEY (node1_id, node2_id)
115 );
116 ALTER TABLE public.nodes_nodes OWNER TO gargantua;
117
118
119 ---------------------------------------------------------------
120 CREATE TABLE public.node_node_ngrams (
121 node1_id INTEGER NOT NULL REFERENCES public.nodes (id) ON DELETE CASCADE,
122 node2_id INTEGER NOT NULL REFERENCES public.nodes (id) ON DELETE CASCADE,
123 ngrams_id INTEGER NOT NULL REFERENCES public.ngrams (id) ON DELETE CASCADE,
124 ngrams_type INTEGER,
125 weight double precision,
126 PRIMARY KEY (node1_id, node2_id, ngrams_id, ngrams_type)
127 );
128 ALTER TABLE public.node_node_ngrams OWNER TO gargantua;
129
130 CREATE TABLE public.node_node_ngrams2 (
131 node_id INTEGER NOT NULL REFERENCES public.nodes (id) ON DELETE CASCADE,
132 nodengrams_id INTEGER NOT NULL REFERENCES public.node_ngrams (id) ON DELETE CASCADE,
133 weight double precision,
134 PRIMARY KEY (node_id, nodengrams_id)
135 );
136 ALTER TABLE public.node_node_ngrams2 OWNER TO gargantua;
137
138 --------------------------------------------------------------
139
140 --CREATE TABLE public.nodes_ngrams_repo (
141 -- version integer NOT NULL,
142 -- patches jsonb DEFAULT '{}'::jsonb NOT NULL,
143 -- PRIMARY KEY (version)
144 --);
145 --ALTER TABLE public.nodes_ngrams_repo OWNER TO gargantua;
146
147 ---------------------------------------------------------
148
149 -- If needed for rights management at row level
150 -- CREATE EXTENSION IF NOT EXISTS acl WITH SCHEMA public;
151
152 CREATE TABLE public.rights (
153 user_id INTEGER NOT NULL REFERENCES public.auth_user(id) ON DELETE CASCADE,
154 node_id INTEGER NOT NULL REFERENCES public.nodes(id) ON DELETE CASCADE,
155 rights INTEGER NOT NULL,
156 PRIMARY KEY (user_id, node_id)
157 );
158 ALTER TABLE public.rights OWNER TO gargantua;
159
160 ------------------------------------------------------------
161 ------------------------------------------------------------
162 -- INDEXES
163 CREATE INDEX ON public.auth_user USING btree (username varchar_pattern_ops);
164 CREATE UNIQUE INDEX ON public.auth_user USING btree (username);
165
166 CREATE INDEX ON public.rights USING btree (user_id,node_id);
167
168 CREATE INDEX ON public.nodes USING gin (hyperdata);
169 CREATE INDEX ON public.nodes USING btree (user_id, typename, parent_id);
170 CREATE INDEX ON public.nodes USING btree (id, typename, date ASC);
171 CREATE INDEX ON public.nodes USING btree (id, typename, date DESC);
172 CREATE INDEX ON public.nodes USING btree (typename, id);
173 CREATE UNIQUE INDEX ON public.nodes USING btree (hash_id);
174 -- CREATE UNIQUE INDEX ON public.nodes USING btree (((hyperdata ->> 'uniqId'::text)));
175 -- CREATE UNIQUE INDEX ON public.nodes USING btree (((hyperdata ->> 'uniqIdBdd'::text)));
176 -- CREATE UNIQUE INDEX ON public.nodes USING btree (typename, parent_id, ((hyperdata ->> 'uniqId'::text)));
177
178 CREATE UNIQUE INDEX ON public.ngrams (terms); -- TEST GIN
179 CREATE INDEX ON public.ngrams USING btree (id, terms);
180 CREATE UNIQUE INDEX ON public.ngrams_postag (lang_id,algo_id,postag,ngrams_id,lemm_id);
181 CREATE INDEX ON public.node_ngrams USING btree (node_id,node_subtype);
182 CREATE UNIQUE INDEX ON public.node_ngrams USING btree (node_id,node_subtype, ngrams_id);
183
184 CREATE UNIQUE INDEX ON public.nodes_nodes USING btree (node1_id, node2_id);
185 CREATE INDEX ON public.nodes_nodes USING btree (node1_id, node2_id, category);
186
187 CREATE UNIQUE INDEX ON public.node_node_ngrams USING btree (node1_id, node2_id, ngrams_id, ngrams_type);
188 CREATE INDEX ON public.node_node_ngrams USING btree (node1_id, node2_id);
189 CREATE INDEX ON public.node_node_ngrams USING btree (ngrams_id, node2_id);
190 CREATE INDEX ON public.node_node_ngrams USING btree (ngrams_type);
191 CREATE INDEX ON public.node_nodengrams_nodengrams USING btree (node_id, node_ngrams1_id, node_ngrams2_id);
192 CREATE INDEX ON public.node_nodengrams_nodengrams USING btree (node_ngrams1_id);
193 CREATE INDEX ON public.node_nodengrams_nodengrams USING btree (node_ngrams2_id);
194 CREATE INDEX ON public.node_node_ngrams2 USING btree (node_id);
195 CREATE INDEX ON public.node_node_ngrams2 USING btree (nodengrams_id);
196 CREATE INDEX ON public.node_node_ngrams2 USING btree (node_id, nodengrams_id);
197 ------------------------------------------------------------
198 ------------------------------------------------------------------------
199 -- Ngrams Full DB Extraction Optim
200 -- TODO remove hard parameter and move elsewhere
201 CREATE OR REPLACE function node_pos(int, int) returns bigint
202 AS 'SELECT count(id) from nodes
203 WHERE id < $1
204 AND typename = $2
205 '
206 LANGUAGE SQL immutable;
207
208 --drop index node_by_pos;
209 --create index node_by_pos on nodes using btree(node_pos(id,typename));
210