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,
22 ALTER TABLE public.auth_user
OWNER TO gargantua
;
23 -----------------------------------------------------------------
25 -- TODO add publication_date
26 -- TODO typename -> type_id
27 CREATE TABLE public.
nodes (
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,
38 FOREIGN KEY (user_id
) REFERENCES public.
auth_user(id) ON DELETE CASCADE
40 ALTER TABLE public.nodes
OWNER TO gargantua
;
41 --------------------------------------------------------------
43 -- TODO add publication_date
44 -- TODO typename -> type_id
45 CREATE TABLE public.
contexts (
47 hash_id
CHARACTER varying(66) DEFAULT ''::character varying NOT NULL,
48 typename
INTEGER NOT NULL,
49 user_id
INTEGER NOT NULL,
50 parent_id
INTEGER REFERENCES public.
contexts(id) ON DELETE CASCADE ,
51 name CHARACTER varying(255) DEFAULT ''::character varying NOT NULL,
52 date TIMESTAMP with time zone DEFAULT now() NOT NULL,
53 hyperdata jsonb
DEFAULT '{}'::jsonb NOT NULL,
56 FOREIGN KEY (user_id
) REFERENCES public.
auth_user(id) ON DELETE CASCADE
58 ALTER TABLE public.contexts
OWNER TO gargantua
;
60 --------------------------------------------------------------
62 CREATE TABLE public.
ngrams (
64 terms
CHARACTER varying(255),
68 ALTER TABLE public.ngrams
OWNER TO gargantua
;
71 CREATE TABLE public.
ngrams_postag (
75 postag
CHARACTER varying(5) ,
76 ngrams_id
INTEGER NOT NULL ,
77 lemm_id
INTEGER NOT NULL ,
78 score
INTEGER DEFAULT 1 ::integer NOT NULL ,
79 FOREIGN KEY (ngrams_id
) REFERENCES public.
ngrams(id) ON DELETE CASCADE,
80 FOREIGN KEY (lemm_id
) REFERENCES public.
ngrams(id) ON DELETE CASCADE
82 ALTER TABLE public.ngrams_postag
OWNER TO gargantua
;
84 --------------------------------------------------------------
85 -- Node here should have type NodeList
86 CREATE TABLE public.
node_ngrams (
88 node_id
INTEGER NOT NULL ,
89 node_subtype
INTEGER ,
90 ngrams_id
INTEGER NOT NULL ,
91 ngrams_type
INTEGER , -- change to ngrams_field? (no for pedagogic reason)
92 ngrams_field
INTEGER ,
94 ngrams_class
INTEGER ,
95 weight
double precision ,
97 FOREIGN KEY (node_id
) REFERENCES public.
nodes(id) ON DELETE CASCADE ,
98 FOREIGN KEY (ngrams_id
) REFERENCES public.
ngrams(id) ON DELETE CASCADE
100 ALTER TABLE public.node_ngrams
OWNER TO gargantua
;
102 --CREATE TABLE public.context_nodengrams_nodengrams (
103 -- context_id INTEGER NOT NULL ,
104 -- node_ngrams1_id INTEGER NOT NULL ,
105 -- node_ngrams2_id INTEGER NOT NULL ,
106 -- weight double precision ,
107 -- FOREIGN KEY (node_id) REFERENCES public.contexts(id) ON DELETE CASCADE ,
108 -- FOREIGN KEY (node_ngrams1_id) REFERENCES public.node_ngrams(id) ON DELETE CASCADE,
109 -- FOREIGN KEY (node_ngrams2_id) REFERENCES public.node_ngrams(id) ON DELETE CASCADE,
110 -- PRIMARY KEY (node_id, node_ngrams1_id, node_ngrams2_id)
112 --ALTER TABLE public.context_nodengrams_nodengrams OWNER TO gargantua;
114 --------------------------------------------------------------
115 --------------------------------------------------------------
117 --CREATE TABLE public.nodes_ngrams_ngrams (
118 -- node_id integer NOT NULL REFERENCES public.nodes(id) ON DELETE CASCADE,
119 -- ngram1_id integer NOT NULL REFERENCES public.ngrams(id) ON DELETE CASCADE,
120 -- ngram2_id integer NOT NULL REFERENCES public.ngrams(id) ON DELETE CASCADE,
121 -- weight double precision,
122 -- PRIMARY KEY (node_id,ngram1_id,ngram2_id)
125 --ALTER TABLE public.nodes_ngrams_ngrams OWNER TO gargantua;
126 ---------------------------------------------------------------
127 -- TODO nodes_nodes(node1_id int, node2_id int, edge_type int , weight real)
128 CREATE TABLE public.
nodes_nodes (
129 node1_id
INTEGER NOT NULL REFERENCES public.
nodes(id) ON DELETE CASCADE,
130 node2_id
INTEGER NOT NULL REFERENCES public.
nodes(id) ON DELETE CASCADE,
133 PRIMARY KEY (node1_id
, node2_id
)
135 ALTER TABLE public.nodes_nodes
OWNER TO gargantua
;
138 -- To attach contexts to a Corpus
139 CREATE TABLE public.
nodes_contexts (
140 node_id
INTEGER NOT NULL REFERENCES public.
nodes(id) ON DELETE CASCADE,
141 context_id
INTEGER NOT NULL REFERENCES public.
contexts(id) ON DELETE CASCADE,
144 PRIMARY KEY (node_id
, context_id
)
146 ALTER TABLE public.nodes_contexts
OWNER TO gargantua
;
148 ---------------------------------------------------------------
149 CREATE TABLE public.
context_node_ngrams (
150 context_id
INTEGER NOT NULL REFERENCES public.
nodes (id) ON DELETE CASCADE,
151 node_id
INTEGER NOT NULL REFERENCES public.
contexts (id) ON DELETE CASCADE,
152 ngrams_id
INTEGER NOT NULL REFERENCES public.
ngrams (id) ON DELETE CASCADE,
153 ngrams_type
INTEGER ,
154 weight
double precision,
155 PRIMARY KEY (context_id
, node_id
, ngrams_id
, ngrams_type
)
159 ALTER TABLE public.context_node_ngrams
OWNER TO gargantua
;
161 CREATE TABLE public.
context_node_ngrams2 (
162 context_id
INTEGER NOT NULL REFERENCES public.
contexts (id) ON DELETE CASCADE,
163 nodengrams_id
INTEGER NOT NULL REFERENCES public.
node_ngrams (id) ON DELETE CASCADE,
164 weight
double precision,
165 PRIMARY KEY (context_id
, nodengrams_id
)
167 ALTER TABLE public.context_node_ngrams2
OWNER TO gargantua
;
169 --------------------------------------------------------------
171 --CREATE TABLE public.nodes_ngrams_repo (
172 -- version integer NOT NULL,
173 -- patches jsonb DEFAULT '{}'::jsonb NOT NULL,
174 -- PRIMARY KEY (version)
176 --ALTER TABLE public.nodes_ngrams_repo OWNER TO gargantua;
178 ---------------------------------------------------------
180 -- If needed for rights management at row level
181 -- CREATE EXTENSION IF NOT EXISTS acl WITH SCHEMA public;
182 CREATE TABLE public.
rights (
183 user_id
INTEGER NOT NULL REFERENCES public.
auth_user(id) ON DELETE CASCADE,
184 node_id
INTEGER NOT NULL REFERENCES public.
nodes(id) ON DELETE CASCADE,
185 rights
INTEGER NOT NULL,
186 PRIMARY KEY (user_id
, node_id
)
188 ALTER TABLE public.rights
OWNER TO gargantua
;
190 ------------------------------------------------------------
191 ------------------------------------------------------------
193 CREATE INDEX ON public.auth_user
USING btree (username varchar_pattern_ops
);
194 CREATE UNIQUE INDEX ON public.auth_user
USING btree (username
);
196 CREATE INDEX ON public.rights
USING btree (user_id
,node_id
);
198 CREATE INDEX ON public.nodes
USING gin (hyperdata
);
199 CREATE INDEX ON public.nodes
USING btree (user_id
, typename
, parent_id
);
200 CREATE INDEX ON public.nodes
USING btree (id, typename
, date ASC);
201 CREATE INDEX ON public.nodes
USING btree (id, typename
, date DESC);
202 CREATE INDEX ON public.nodes
USING btree (typename
, id);
203 CREATE UNIQUE INDEX ON public.nodes
USING btree (hash_id
);
205 CREATE INDEX ON public.contexts
USING gin (hyperdata
);
206 CREATE INDEX ON public.contexts
USING btree (user_id
, typename
, parent_id
);
207 CREATE INDEX ON public.contexts
USING btree (id, typename
, date ASC);
208 CREATE INDEX ON public.contexts
USING btree (id, typename
, date DESC);
209 CREATE INDEX ON public.contexts
USING btree (typename
, id);
210 CREATE UNIQUE INDEX ON public.contexts
USING btree (hash_id
);
213 -- CREATE UNIQUE INDEX ON public.nodes USING btree (((hyperdata ->> 'uniqId'::text)));
214 -- CREATE UNIQUE INDEX ON public.nodes USING btree (((hyperdata ->> 'uniqIdBdd'::text)));
215 -- CREATE UNIQUE INDEX ON public.nodes USING btree (typename, parent_id, ((hyperdata ->> 'uniqId'::text)));
217 CREATE UNIQUE INDEX ON public.
ngrams (terms
); -- TEST GIN
218 CREATE INDEX ON public.ngrams
USING btree (id, terms
);
219 CREATE UNIQUE INDEX ON public.
ngrams_postag (lang_id
,algo_id
,postag
,ngrams_id
,lemm_id
);
221 -- To save the Node Ngrams Repo
222 CREATE INDEX ON public.node_ngrams
USING btree (node_id
,node_subtype
);
223 CREATE UNIQUE INDEX ON public.node_ngrams
USING btree (node_id
,node_subtype
, ngrams_id
);
227 -- To make the links between Nodes in Tree/Forest
228 CREATE UNIQUE INDEX ON public.nodes_nodes
USING btree (node1_id
, node2_id
);
229 CREATE INDEX ON public.nodes_nodes
USING btree (node1_id
, node2_id
, category
);
231 -- To make the links between Corpus Node and its contexts
232 CREATE UNIQUE INDEX ON public.nodes_contexts
USING btree (node_id
, context_id
);
233 CREATE INDEX ON public.nodes_contexts
USING btree (node_id
, context_id
, category
);
236 ------------------------------------------------------------------------
237 CREATE UNIQUE INDEX ON public.context_node_ngrams
USING btree (context_id
, node_id
, ngrams_id
, ngrams_type
);
238 CREATE INDEX ON public.context_node_ngrams
USING btree (context_id
, node_id
);
239 CREATE INDEX ON public.context_node_ngrams
USING btree (ngrams_id
, node_id
);
240 CREATE INDEX ON public.context_node_ngrams
USING btree (ngrams_type
);
242 CREATE INDEX ON public.context_node_ngrams2
USING btree (context_id
);
243 CREATE INDEX ON public.context_node_ngrams2
USING btree (nodengrams_id
);
244 CREATE INDEX ON public.context_node_ngrams2
USING btree (context_id
, nodengrams_id
);
246 -- CREATE INDEX ON public.context_nodengrams_nodengrams USING btree (context_id, node_ngrams1_id, node_ngrams2_id);
247 -- CREATE INDEX ON public.context_nodengrams_nodengrams USING btree (node_ngrams1_id);
248 -- CREATE INDEX ON public.context_nodengrams_nodengrams USING btree (node_ngrams2_id);
251 ------------------------------------------------------------------------
252 -- Ngrams Full DB Extraction Optim
253 -- TODO remove hard parameter and move elsewhere
254 CREATE OR REPLACE function node_pos(int, int) returns bigint
255 AS 'SELECT count(id) from nodes
259 LANGUAGE SQL immutable;
261 --drop index node_by_pos;
262 --create index node_by_pos on nodes using btree(node_pos(id,typename));