1 CREATE EXTENSION
IF NOT EXISTS plpgsql
WITH SCHEMA pg_catalog
;
2 COMMENT ON EXTENSION plpgsql
IS 'PL/pgSQL procedural language';
4 CREATE EXTENSION
IF NOT EXISTS tsm_system_rows
;
5 CREATE EXTENSION pgcrypto
;
7 -----------------------------------------------------------------
8 CREATE TABLE public.
auth_user (
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 forgot_password_uuid
TEXT,
23 ALTER TABLE public.auth_user
OWNER TO gargantua
;
24 -----------------------------------------------------------------
26 -- TODO add publication_date
27 -- TODO typename -> type_id
28 CREATE TABLE public.
nodes (
30 hash_id
CHARACTER varying(66) DEFAULT ''::character varying NOT NULL,
31 typename
INTEGER NOT NULL,
32 user_id
INTEGER NOT NULL,
33 parent_id
INTEGER REFERENCES public.
nodes(id) ON DELETE CASCADE ,
34 name CHARACTER varying(255) DEFAULT ''::character varying NOT NULL,
35 date TIMESTAMP with time zone DEFAULT now() NOT NULL,
36 hyperdata jsonb
DEFAULT '{}'::jsonb NOT NULL,
39 FOREIGN KEY (user_id
) REFERENCES public.
auth_user(id) ON DELETE CASCADE
41 ALTER TABLE public.nodes
OWNER TO gargantua
;
42 --------------------------------------------------------------
44 -- TODO add publication_date
45 -- TODO typename -> type_id
46 CREATE TABLE public.
contexts (
48 hash_id
CHARACTER varying(66) DEFAULT ''::character varying NOT NULL,
49 typename
INTEGER NOT NULL,
50 user_id
INTEGER NOT NULL,
51 parent_id
INTEGER REFERENCES public.
contexts(id) ON DELETE CASCADE ,
52 name CHARACTER varying(255) DEFAULT ''::character varying NOT NULL,
53 date TIMESTAMP with time zone DEFAULT now() NOT NULL,
54 hyperdata jsonb
DEFAULT '{}'::jsonb NOT NULL,
57 FOREIGN KEY (user_id
) REFERENCES public.
auth_user(id) ON DELETE CASCADE
59 ALTER TABLE public.contexts
OWNER TO gargantua
;
61 --------------------------------------------------------------
63 CREATE TABLE public.
ngrams (
65 terms
CHARACTER varying(255),
69 ALTER TABLE public.ngrams
OWNER TO gargantua
;
72 CREATE TABLE public.
ngrams_postag (
76 postag
CHARACTER varying(5) ,
77 ngrams_id
INTEGER NOT NULL ,
78 lemm_id
INTEGER NOT NULL ,
79 score
INTEGER DEFAULT 1 ::integer NOT NULL ,
80 FOREIGN KEY (ngrams_id
) REFERENCES public.
ngrams(id) ON DELETE CASCADE,
81 FOREIGN KEY (lemm_id
) REFERENCES public.
ngrams(id) ON DELETE CASCADE
83 ALTER TABLE public.ngrams_postag
OWNER TO gargantua
;
85 --------------------------------------------------------------
86 -- Node here should have type NodeList
87 CREATE TABLE public.
node_ngrams (
89 node_id
INTEGER NOT NULL ,
90 node_subtype
INTEGER ,
91 ngrams_id
INTEGER NOT NULL ,
92 ngrams_type
INTEGER , -- change to ngrams_field? (no for pedagogic reason)
93 ngrams_field
INTEGER ,
95 ngrams_class
INTEGER ,
96 weight
double precision ,
98 FOREIGN KEY (node_id
) REFERENCES public.
nodes(id) ON DELETE CASCADE ,
99 FOREIGN KEY (ngrams_id
) REFERENCES public.
ngrams(id) ON DELETE CASCADE
101 ALTER TABLE public.node_ngrams
OWNER TO gargantua
;
103 --CREATE TABLE public.context_nodengrams_nodengrams (
104 -- context_id INTEGER NOT NULL ,
105 -- node_ngrams1_id INTEGER NOT NULL ,
106 -- node_ngrams2_id INTEGER NOT NULL ,
107 -- weight double precision ,
108 -- FOREIGN KEY (node_id) REFERENCES public.contexts(id) ON DELETE CASCADE ,
109 -- FOREIGN KEY (node_ngrams1_id) REFERENCES public.node_ngrams(id) ON DELETE CASCADE,
110 -- FOREIGN KEY (node_ngrams2_id) REFERENCES public.node_ngrams(id) ON DELETE CASCADE,
111 -- PRIMARY KEY (node_id, node_ngrams1_id, node_ngrams2_id)
113 --ALTER TABLE public.context_nodengrams_nodengrams OWNER TO gargantua;
115 --------------------------------------------------------------
116 --------------------------------------------------------------
118 --CREATE TABLE public.nodes_ngrams_ngrams (
119 -- node_id integer NOT NULL REFERENCES public.nodes(id) ON DELETE CASCADE,
120 -- ngram1_id integer NOT NULL REFERENCES public.ngrams(id) ON DELETE CASCADE,
121 -- ngram2_id integer NOT NULL REFERENCES public.ngrams(id) ON DELETE CASCADE,
122 -- weight double precision,
123 -- PRIMARY KEY (node_id,ngram1_id,ngram2_id)
126 --ALTER TABLE public.nodes_ngrams_ngrams OWNER TO gargantua;
127 ---------------------------------------------------------------
128 -- TODO nodes_nodes(node1_id int, node2_id int, edge_type int , weight real)
129 CREATE TABLE public.
nodes_nodes (
130 node1_id
INTEGER NOT NULL REFERENCES public.
nodes(id) ON DELETE CASCADE,
131 node2_id
INTEGER NOT NULL REFERENCES public.
nodes(id) ON DELETE CASCADE,
134 PRIMARY KEY (node1_id
, node2_id
)
136 ALTER TABLE public.nodes_nodes
OWNER TO gargantua
;
140 -- To attach contexts to a Corpus
141 CREATE TABLE public.
nodes_contexts (
143 node_id
INTEGER NOT NULL REFERENCES public.
nodes(id) ON DELETE CASCADE,
144 context_id
INTEGER NOT NULL REFERENCES public.
contexts(id) ON DELETE CASCADE,
149 ALTER TABLE public.nodes_contexts
OWNER TO gargantua
;
151 CREATE TABLE public.
nodescontexts_nodescontexts (
152 nodescontexts1
INTEGER NOT NULL REFERENCES public.
nodes_contexts(id) ON DELETE CASCADE,
153 nodescontexts2
INTEGER NOT NULL REFERENCES public.
nodes_contexts(id) ON DELETE CASCADE,
155 PRIMARY KEY (nodescontexts1
, nodescontexts2
)
157 ALTER TABLE public.nodescontexts_nodescontexts
OWNER TO gargantua
;
160 ---------------------------------------------------------------
161 CREATE TABLE public.
context_node_ngrams (
162 context_id
INTEGER NOT NULL REFERENCES public.
contexts (id) ON DELETE CASCADE,
163 node_id
INTEGER NOT NULL REFERENCES public.
nodes (id) ON DELETE CASCADE,
164 ngrams_id
INTEGER NOT NULL REFERENCES public.
ngrams (id) ON DELETE CASCADE,
165 ngrams_type
INTEGER ,
166 weight
double precision,
167 PRIMARY KEY (context_id
, node_id
, ngrams_id
, ngrams_type
)
169 ALTER TABLE public.context_node_ngrams
OWNER TO gargantua
;
171 CREATE TABLE public.
context_node_ngrams2 (
172 context_id
INTEGER NOT NULL REFERENCES public.
contexts (id) ON DELETE CASCADE,
173 nodengrams_id
INTEGER NOT NULL REFERENCES public.
node_ngrams (id) ON DELETE CASCADE,
174 weight
double precision,
175 PRIMARY KEY (context_id
, nodengrams_id
)
177 ALTER TABLE public.context_node_ngrams2
OWNER TO gargantua
;
180 --------------------------------------------------------------------
181 CREATE TABLE public.
node_node_ngrams (
182 node1_id
INTEGER NOT NULL REFERENCES public.
nodes (id) ON DELETE CASCADE,
183 node2_id
INTEGER NOT NULL REFERENCES public.
nodes (id) ON DELETE CASCADE,
184 ngrams_id
INTEGER NOT NULL REFERENCES public.
ngrams (id) ON DELETE CASCADE,
186 weight
double precision,
187 PRIMARY KEY (node1_id
, node2_id
, ngrams_id
, ngrams_type
)
189 ALTER TABLE public.node_node_ngrams
OWNER TO gargantua
;
191 CREATE TABLE public.
node_node_ngrams2 (
192 node_id
INTEGER NOT NULL REFERENCES public.
nodes (id) ON DELETE CASCADE,
193 nodengrams_id
INTEGER NOT NULL REFERENCES public.
node_ngrams (id) ON DELETE CASCADE,
194 weight
double precision,
195 PRIMARY KEY (node_id
, nodengrams_id
)
197 ALTER TABLE public.node_node_ngrams2
OWNER TO gargantua
;
200 --------------------------------------------------------------
202 --CREATE TABLE public.nodes_ngrams_repo (
203 -- version integer NOT NULL,
204 -- patches jsonb DEFAULT '{}'::jsonb NOT NULL,
205 -- PRIMARY KEY (version)
207 --ALTER TABLE public.nodes_ngrams_repo OWNER TO gargantua;
209 ---------------------------------------------------------
211 -- If needed for rights management at row level
212 -- CREATE EXTENSION IF NOT EXISTS acl WITH SCHEMA public;
213 CREATE TABLE public.
rights (
214 user_id
INTEGER NOT NULL REFERENCES public.
auth_user(id) ON DELETE CASCADE,
215 node_id
INTEGER NOT NULL REFERENCES public.
nodes(id) ON DELETE CASCADE,
216 rights
INTEGER NOT NULL,
217 PRIMARY KEY (user_id
, node_id
)
219 ALTER TABLE public.rights
OWNER TO gargantua
;
221 ------------------------------------------------------------
224 create table public.
node_stories (
226 node_id
INTEGER NOT NULL,
227 archive jsonb
DEFAULT '{}'::jsonb NOT NULL,
229 FOREIGN KEY (node_id
) REFERENCES public.
nodes(id) ON DELETE CASCADE
231 ALTER TABLE public.node_stories
OWNER TO gargantua
;
233 CREATE UNIQUE INDEX ON public.node_stories
USING btree (node_id
);
236 create table public.
node_story_archive_history (
238 node_id
INTEGER NOT NULL,
239 ngrams_type_id
INTEGER NOT NULL,
240 ngrams_id
INTEGER NOT NULL,
241 patch jsonb
DEFAULT '{}'::jsonb NOT NULL,
243 FOREIGN KEY (node_id
) REFERENCES public.
nodes(id) ON DELETE CASCADE,
244 FOREIGN KEY (ngrams_id
) REFERENCES public.
ngrams(id) ON DELETE CASCADE
246 ALTER TABLE public.node_story_archive_history
OWNER TO gargantua
;
249 ------------------------------------------------------------
251 CREATE INDEX ON public.auth_user
USING btree (username varchar_pattern_ops
);
252 CREATE UNIQUE INDEX ON public.auth_user
USING btree (username
);
254 CREATE INDEX ON public.rights
USING btree (user_id
,node_id
);
256 CREATE INDEX ON public.nodes
USING gin (hyperdata
);
257 CREATE INDEX ON public.nodes
USING btree (user_id
, typename
, parent_id
);
258 CREATE INDEX ON public.nodes
USING btree (id, typename
, date ASC);
259 CREATE INDEX ON public.nodes
USING btree (id, typename
, date DESC);
260 CREATE INDEX ON public.nodes
USING btree (typename
, id);
261 CREATE UNIQUE INDEX ON public.nodes
USING btree (hash_id
);
263 CREATE INDEX ON public.contexts
USING gin (hyperdata
);
264 CREATE INDEX ON public.contexts
USING btree (user_id
, typename
, parent_id
);
265 CREATE INDEX ON public.contexts
USING btree (id, typename
, date ASC);
266 CREATE INDEX ON public.contexts
USING btree (id, typename
, date DESC);
267 CREATE INDEX ON public.contexts
USING btree (typename
, id);
268 CREATE UNIQUE INDEX ON public.contexts
USING btree (hash_id
);
270 CREATE INDEX ON public.nodescontexts_nodescontexts
USING btree (nodescontexts1
, nodescontexts2
);
271 -- CREATE UNIQUE INDEX ON public.nodes USING btree (((hyperdata ->> 'uniqId'::text)));
272 -- CREATE UNIQUE INDEX ON public.nodes USING btree (((hyperdata ->> 'uniqIdBdd'::text)));
273 -- CREATE UNIQUE INDEX ON public.nodes USING btree (typename, parent_id, ((hyperdata ->> 'uniqId'::text)));
275 CREATE UNIQUE INDEX ON public.
ngrams (terms
); -- TEST GIN
276 CREATE INDEX ON public.ngrams
USING btree (id, terms
);
277 CREATE UNIQUE INDEX ON public.
ngrams_postag (lang_id
,algo_id
,postag
,ngrams_id
,lemm_id
);
279 -- To save the Node Ngrams Repo
280 CREATE INDEX ON public.node_ngrams
USING btree (node_id
,node_subtype
);
281 CREATE UNIQUE INDEX ON public.node_ngrams
USING btree (node_id
,node_subtype
, ngrams_id
);
285 -- To make the links between Nodes in Tree/Forest
286 CREATE UNIQUE INDEX ON public.nodes_nodes
USING btree (node1_id
, node2_id
);
287 CREATE INDEX ON public.nodes_nodes
USING btree (node1_id
, node2_id
, category
);
290 -- To make the links between Corpus Node and its contexts
291 CREATE UNIQUE INDEX ON public.nodes_contexts
USING btree (node_id
, context_id
);
292 CREATE INDEX ON public.nodes_contexts
USING btree (node_id
, context_id
, category
);
295 ------------------------------------------------------------------------
296 CREATE UNIQUE INDEX ON public.context_node_ngrams
USING btree (context_id
, node_id
, ngrams_id
, ngrams_type
);
297 CREATE INDEX ON public.context_node_ngrams
USING btree (context_id
, node_id
);
298 CREATE INDEX ON public.context_node_ngrams
USING btree (ngrams_id
, node_id
);
299 CREATE INDEX ON public.context_node_ngrams
USING btree (ngrams_type
);
301 CREATE INDEX ON public.context_node_ngrams2
USING btree (context_id
);
302 CREATE INDEX ON public.context_node_ngrams2
USING btree (nodengrams_id
);
303 CREATE INDEX ON public.context_node_ngrams2
USING btree (context_id
, nodengrams_id
);
306 CREATE UNIQUE INDEX ON public.node_node_ngrams
USING btree (node1_id
, node2_id
, ngrams_id
, ngrams_type
);
307 CREATE INDEX ON public.node_node_ngrams
USING btree (node1_id
, node2_id
);
308 CREATE INDEX ON public.node_node_ngrams
USING btree (ngrams_id
, node2_id
);
309 CREATE INDEX ON public.node_node_ngrams
USING btree (ngrams_type
);
310 CREATE INDEX ON public.node_node_ngrams2
USING btree (node_id
);
311 CREATE INDEX ON public.node_node_ngrams2
USING btree (nodengrams_id
);
312 CREATE INDEX ON public.node_node_ngrams2
USING btree (node_id
, nodengrams_id
);
314 -- CREATE INDEX ON public.context_nodengrams_nodengrams USING btree (context_id, node_ngrams1_id, node_ngrams2_id);
315 -- CREATE INDEX ON public.context_nodengrams_nodengrams USING btree (node_ngrams1_id);
316 -- CREATE INDEX ON public.context_nodengrams_nodengrams USING btree (node_ngrams2_id);
319 ------------------------------------------------------------------------
320 -- Ngrams Full DB Extraction Optim
321 -- TODO remove hard parameter and move elsewhere
322 CREATE OR REPLACE function node_pos(int, int) returns bigint
323 AS 'SELECT count(id) from nodes
327 LANGUAGE SQL immutable;
329 --drop index node_by_pos;
330 --create index node_by_pos on nodes using btree(node_pos(id,typename));