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 CREATE TABLE public.
ngrams (
44 terms
CHARACTER varying(255),
48 ALTER TABLE public.ngrams
OWNER TO gargantua
;
50 --------------------------------------------------------------
51 CREATE TABLE public.
node_ngrams (
53 node_id
INTEGER NOT NULL,
55 ngrams_id
INTEGER NOT NULL,
56 ngrams_type
INTEGER, -- change to ngrams_field? (no for pedagogic reason)
60 weight
double precision,
62 FOREIGN KEY (node_id
) REFERENCES public.
nodes(id) ON DELETE CASCADE,
63 FOREIGN KEY (ngrams_id
) REFERENCES public.
ngrams(id) ON DELETE CASCADE
65 ALTER TABLE public.node_ngrams
OWNER TO gargantua
;
67 CREATE TABLE public.
node_nodengrams_nodengrams (
68 node_id
INTEGER NOT NULL,
69 node_ngrams1_id
INTEGER NOT NULL,
70 node_ngrams2_id
INTEGER NOT NULL,
71 weight
double precision,
72 FOREIGN KEY (node_id
) REFERENCES public.
nodes(id) ON DELETE CASCADE,
73 FOREIGN KEY (node_ngrams1_id
) REFERENCES public.
node_ngrams(id) ON DELETE CASCADE,
74 FOREIGN KEY (node_ngrams2_id
) REFERENCES public.
node_ngrams(id) ON DELETE CASCADE,
75 PRIMARY KEY (node_id
, node_ngrams1_id
, node_ngrams2_id
)
77 ALTER TABLE public.node_nodengrams_nodengrams
OWNER TO gargantua
;
79 --------------------------------------------------------------
80 --------------------------------------------------------------
83 --CREATE TABLE public.nodes_ngrams_ngrams (
84 -- node_id integer NOT NULL REFERENCES public.nodes(id) ON DELETE CASCADE,
85 -- ngram1_id integer NOT NULL REFERENCES public.ngrams(id) ON DELETE CASCADE,
86 -- ngram2_id integer NOT NULL REFERENCES public.ngrams(id) ON DELETE CASCADE,
87 -- weight double precision,
88 -- PRIMARY KEY (node_id,ngram1_id,ngram2_id)
91 --ALTER TABLE public.nodes_ngrams_ngrams OWNER TO gargantua;
92 ---------------------------------------------------------------
93 -- TODO nodes_nodes(node1_id int, node2_id int, edge_type int , weight real)
94 CREATE TABLE public.
nodes_nodes (
95 node1_id
INTEGER NOT NULL REFERENCES public.
nodes(id) ON DELETE CASCADE,
96 node2_id
INTEGER NOT NULL REFERENCES public.
nodes(id) ON DELETE CASCADE,
99 PRIMARY KEY (node1_id
, node2_id
)
101 ALTER TABLE public.nodes_nodes
OWNER TO gargantua
;
104 ---------------------------------------------------------------
105 CREATE TABLE public.
node_node_ngrams (
106 node1_id
INTEGER NOT NULL REFERENCES public.
nodes (id) ON DELETE CASCADE,
107 node2_id
INTEGER NOT NULL REFERENCES public.
nodes (id) ON DELETE CASCADE,
108 ngrams_id
INTEGER NOT NULL REFERENCES public.
ngrams (id) ON DELETE CASCADE,
110 weight
double precision,
111 PRIMARY KEY (node1_id
, node2_id
, ngrams_id
, ngrams_type
)
113 ALTER TABLE public.node_node_ngrams
OWNER TO gargantua
;
115 CREATE TABLE public.
node_node_ngrams2 (
116 node_id
INTEGER NOT NULL REFERENCES public.
nodes (id) ON DELETE CASCADE,
117 nodengrams_id
INTEGER NOT NULL REFERENCES public.
node_ngrams (id) ON DELETE CASCADE,
118 weight
double precision,
119 PRIMARY KEY (node_id
, nodengrams_id
)
121 ALTER TABLE public.node_node_ngrams2
OWNER TO gargantua
;
123 --------------------------------------------------------------
125 --CREATE TABLE public.nodes_ngrams_repo (
126 -- version integer NOT NULL,
127 -- patches jsonb DEFAULT '{}'::jsonb NOT NULL,
128 -- PRIMARY KEY (version)
130 --ALTER TABLE public.nodes_ngrams_repo OWNER TO gargantua;
132 ---------------------------------------------------------
134 -- If needed for rights management at row level
135 -- CREATE EXTENSION IF NOT EXISTS acl WITH SCHEMA public;
137 CREATE TABLE public.
rights (
138 user_id
INTEGER NOT NULL REFERENCES public.
auth_user(id) ON DELETE CASCADE,
139 node_id
INTEGER NOT NULL REFERENCES public.
nodes(id) ON DELETE CASCADE,
140 rights
INTEGER NOT NULL,
141 PRIMARY KEY (user_id
, node_id
)
143 ALTER TABLE public.rights
OWNER TO gargantua
;
145 ------------------------------------------------------------
146 ------------------------------------------------------------
148 CREATE INDEX ON public.auth_user
USING btree (username varchar_pattern_ops
);
149 CREATE UNIQUE INDEX ON public.auth_user
USING btree (username
);
151 CREATE INDEX ON public.rights
USING btree (user_id
,node_id
);
153 CREATE INDEX ON public.nodes
USING gin (hyperdata
);
154 CREATE INDEX ON public.nodes
USING btree (user_id
, typename
, parent_id
);
155 CREATE INDEX ON public.nodes
USING btree (id, typename
, date ASC);
156 CREATE INDEX ON public.nodes
USING btree (id, typename
, date DESC);
157 CREATE INDEX ON public.nodes
USING btree (typename
, id);
158 CREATE UNIQUE INDEX ON public.nodes
USING btree (hash_id
);
159 -- CREATE UNIQUE INDEX ON public.nodes USING btree (((hyperdata ->> 'uniqId'::text)));
160 -- CREATE UNIQUE INDEX ON public.nodes USING btree (((hyperdata ->> 'uniqIdBdd'::text)));
161 -- CREATE UNIQUE INDEX ON public.nodes USING btree (typename, parent_id, ((hyperdata ->> 'uniqId'::text)));
163 CREATE UNIQUE INDEX ON public.
ngrams (terms
); -- TEST GIN
164 CREATE INDEX ON public.ngrams
USING btree (id, terms
);
165 CREATE INDEX ON public.node_ngrams
USING btree (node_id
,node_subtype
);
166 CREATE UNIQUE INDEX ON public.node_ngrams
USING btree (node_id
,node_subtype
, ngrams_id
);
168 CREATE UNIQUE INDEX ON public.nodes_nodes
USING btree (node1_id
, node2_id
);
169 CREATE INDEX ON public.nodes_nodes
USING btree (node1_id
, node2_id
, category
);
171 CREATE UNIQUE INDEX ON public.node_node_ngrams
USING btree (node1_id
, node2_id
, ngrams_id
, ngrams_type
);
172 CREATE INDEX ON public.node_node_ngrams
USING btree (node1_id
, node2_id
);
173 CREATE INDEX ON public.node_node_ngrams
USING btree (ngrams_id
, node2_id
);
174 CREATE INDEX ON public.node_node_ngrams
USING btree (ngrams_type
);
175 CREATE INDEX ON public.node_nodengrams_nodengrams
USING btree (node_id
, node_ngrams1_id
, node_ngrams2_id
);
176 CREATE INDEX ON public.node_nodengrams_nodengrams
USING btree (node_ngrams1_id
);
177 CREATE INDEX ON public.node_nodengrams_nodengrams
USING btree (node_ngrams2_id
);
178 CREATE INDEX ON public.node_node_ngrams2
USING btree (node_id
);
179 CREATE INDEX ON public.node_node_ngrams2
USING btree (nodengrams_id
);
180 CREATE INDEX ON public.node_node_ngrams2
USING btree (node_id
, nodengrams_id
);
181 ------------------------------------------------------------
182 ------------------------------------------------------------------------
183 -- Ngrams Full DB Extraction Optim
184 -- TODO remove hard parameter and move elsewhere
185 CREATE OR REPLACE function node_pos(int, int) returns bigint
186 AS 'SELECT count(id) from nodes
190 LANGUAGE SQL immutable;
192 --drop index node_by_pos;
193 create index node_by_pos
on nodes
using btree(node_pos(id,typename
));