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,
23 ALTER TABLE public.auth_user
OWNER TO gargantua
;
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
;
42 --------------------------------------------------------------
44 CREATE TABLE public.
ngrams (
46 terms
CHARACTER varying(255),
50 ALTER TABLE public.ngrams
OWNER TO gargantua
;
53 CREATE TABLE public.
ngrams_postag (
57 postag
CHARACTER varying(5),
58 ngrams_id
INTEGER NOT NULL,
59 lemm_id
INTEGER NOT NULL,
60 score
INTEGER DEFAULT 1 ::integer NOT NULL,
61 FOREIGN KEY (ngrams_id
) REFERENCES public.
ngrams(id) ON DELETE CASCADE,
62 FOREIGN KEY (lemm_id
) REFERENCES public.
ngrams(id) ON DELETE CASCADE
64 ALTER TABLE public.ngrams_postag
OWNER TO gargantua
;
66 --------------------------------------------------------------
67 CREATE TABLE public.
node_ngrams (
69 node_id
INTEGER NOT NULL,
71 ngrams_id
INTEGER NOT NULL,
72 ngrams_type
INTEGER, -- change to ngrams_field? (no for pedagogic reason)
76 weight
double precision,
78 FOREIGN KEY (node_id
) REFERENCES public.
nodes(id) ON DELETE CASCADE,
79 FOREIGN KEY (ngrams_id
) REFERENCES public.
ngrams(id) ON DELETE CASCADE
81 ALTER TABLE public.node_ngrams
OWNER TO gargantua
;
83 CREATE TABLE public.
node_nodengrams_nodengrams (
84 node_id
INTEGER NOT NULL,
85 node_ngrams1_id
INTEGER NOT NULL,
86 node_ngrams2_id
INTEGER NOT NULL,
87 weight
double precision,
88 FOREIGN KEY (node_id
) REFERENCES public.
nodes(id) ON DELETE CASCADE,
89 FOREIGN KEY (node_ngrams1_id
) REFERENCES public.
node_ngrams(id) ON DELETE CASCADE,
90 FOREIGN KEY (node_ngrams2_id
) REFERENCES public.
node_ngrams(id) ON DELETE CASCADE,
91 PRIMARY KEY (node_id
, node_ngrams1_id
, node_ngrams2_id
)
93 ALTER TABLE public.node_nodengrams_nodengrams
OWNER TO gargantua
;
95 --------------------------------------------------------------
96 --------------------------------------------------------------
99 --CREATE TABLE public.nodes_ngrams_ngrams (
100 -- node_id integer NOT NULL REFERENCES public.nodes(id) ON DELETE CASCADE,
101 -- ngram1_id integer NOT NULL REFERENCES public.ngrams(id) ON DELETE CASCADE,
102 -- ngram2_id integer NOT NULL REFERENCES public.ngrams(id) ON DELETE CASCADE,
103 -- weight double precision,
104 -- PRIMARY KEY (node_id,ngram1_id,ngram2_id)
107 --ALTER TABLE public.nodes_ngrams_ngrams OWNER TO gargantua;
108 ---------------------------------------------------------------
109 -- TODO nodes_nodes(node1_id int, node2_id int, edge_type int , weight real)
110 CREATE TABLE public.
nodes_nodes (
111 node1_id
INTEGER NOT NULL REFERENCES public.
nodes(id) ON DELETE CASCADE,
112 node2_id
INTEGER NOT NULL REFERENCES public.
nodes(id) ON DELETE CASCADE,
115 PRIMARY KEY (node1_id
, node2_id
)
117 ALTER TABLE public.nodes_nodes
OWNER TO gargantua
;
120 ---------------------------------------------------------------
121 CREATE TABLE public.
node_node_ngrams (
122 node1_id
INTEGER NOT NULL REFERENCES public.
nodes (id) ON DELETE CASCADE,
123 node2_id
INTEGER NOT NULL REFERENCES public.
nodes (id) ON DELETE CASCADE,
124 ngrams_id
INTEGER NOT NULL REFERENCES public.
ngrams (id) ON DELETE CASCADE,
126 weight
double precision,
127 PRIMARY KEY (node1_id
, node2_id
, ngrams_id
, ngrams_type
)
129 ALTER TABLE public.node_node_ngrams
OWNER TO gargantua
;
131 CREATE TABLE public.
node_node_ngrams2 (
132 node_id
INTEGER NOT NULL REFERENCES public.
nodes (id) ON DELETE CASCADE,
133 nodengrams_id
INTEGER NOT NULL REFERENCES public.
node_ngrams (id) ON DELETE CASCADE,
134 weight
double precision,
135 PRIMARY KEY (node_id
, nodengrams_id
)
137 ALTER TABLE public.node_node_ngrams2
OWNER TO gargantua
;
139 --------------------------------------------------------------
141 --CREATE TABLE public.nodes_ngrams_repo (
142 -- version integer NOT NULL,
143 -- patches jsonb DEFAULT '{}'::jsonb NOT NULL,
144 -- PRIMARY KEY (version)
146 --ALTER TABLE public.nodes_ngrams_repo OWNER TO gargantua;
148 ---------------------------------------------------------
150 -- If needed for rights management at row level
151 -- CREATE EXTENSION IF NOT EXISTS acl WITH SCHEMA public;
153 CREATE TABLE public.
rights (
154 user_id
INTEGER NOT NULL REFERENCES public.
auth_user(id) ON DELETE CASCADE,
155 node_id
INTEGER NOT NULL REFERENCES public.
nodes(id) ON DELETE CASCADE,
156 rights
INTEGER NOT NULL,
157 PRIMARY KEY (user_id
, node_id
)
159 ALTER TABLE public.rights
OWNER TO gargantua
;
161 ------------------------------------------------------------
162 ------------------------------------------------------------
164 CREATE INDEX ON public.auth_user
USING btree (username varchar_pattern_ops
);
165 CREATE UNIQUE INDEX ON public.auth_user
USING btree (username
);
167 CREATE INDEX ON public.rights
USING btree (user_id
,node_id
);
169 CREATE INDEX ON public.nodes
USING gin (hyperdata
);
170 CREATE INDEX ON public.nodes
USING btree (user_id
, typename
, parent_id
);
171 CREATE INDEX ON public.nodes
USING btree (id, typename
, date ASC);
172 CREATE INDEX ON public.nodes
USING btree (id, typename
, date DESC);
173 CREATE INDEX ON public.nodes
USING btree (typename
, id);
174 CREATE UNIQUE INDEX ON public.nodes
USING btree (hash_id
);
175 -- CREATE UNIQUE INDEX ON public.nodes USING btree (((hyperdata ->> 'uniqId'::text)));
176 -- CREATE UNIQUE INDEX ON public.nodes USING btree (((hyperdata ->> 'uniqIdBdd'::text)));
177 -- CREATE UNIQUE INDEX ON public.nodes USING btree (typename, parent_id, ((hyperdata ->> 'uniqId'::text)));
179 CREATE UNIQUE INDEX ON public.
ngrams (terms
); -- TEST GIN
180 CREATE INDEX ON public.ngrams
USING btree (id, terms
);
181 CREATE UNIQUE INDEX ON public.
ngrams_postag (lang_id
,algo_id
,postag
,ngrams_id
,lemm_id
);
182 CREATE INDEX ON public.node_ngrams
USING btree (node_id
,node_subtype
);
183 CREATE UNIQUE INDEX ON public.node_ngrams
USING btree (node_id
,node_subtype
, ngrams_id
);
185 CREATE UNIQUE INDEX ON public.nodes_nodes
USING btree (node1_id
, node2_id
);
186 CREATE INDEX ON public.nodes_nodes
USING btree (node1_id
, node2_id
, category
);
188 CREATE UNIQUE INDEX ON public.node_node_ngrams
USING btree (node1_id
, node2_id
, ngrams_id
, ngrams_type
);
189 CREATE INDEX ON public.node_node_ngrams
USING btree (node1_id
, node2_id
);
190 CREATE INDEX ON public.node_node_ngrams
USING btree (ngrams_id
, node2_id
);
191 CREATE INDEX ON public.node_node_ngrams
USING btree (ngrams_type
);
192 CREATE INDEX ON public.node_nodengrams_nodengrams
USING btree (node_id
, node_ngrams1_id
, node_ngrams2_id
);
193 CREATE INDEX ON public.node_nodengrams_nodengrams
USING btree (node_ngrams1_id
);
194 CREATE INDEX ON public.node_nodengrams_nodengrams
USING btree (node_ngrams2_id
);
195 CREATE INDEX ON public.node_node_ngrams2
USING btree (node_id
);
196 CREATE INDEX ON public.node_node_ngrams2
USING btree (nodengrams_id
);
197 CREATE INDEX ON public.node_node_ngrams2
USING btree (node_id
, nodengrams_id
);
198 ------------------------------------------------------------
199 ------------------------------------------------------------------------
200 -- Ngrams Full DB Extraction Optim
201 -- TODO remove hard parameter and move elsewhere
202 CREATE OR REPLACE function node_pos(int, int) returns bigint
203 AS 'SELECT count(id) from nodes
207 LANGUAGE SQL immutable;
209 --drop index node_by_pos;
210 create index node_by_pos
on nodes
using btree(node_pos(id,typename
));