1 CREATE EXTENSION
IF NOT EXISTS plpgsql
WITH SCHEMA pg_catalog
;
2 CREATE EXTENSION
IF NOT EXISTS tsm_system_rows
;
4 COMMENT ON EXTENSION plpgsql
IS 'PL/pgSQL procedural language';
6 -- CREATE USER WITH ...
9 CREATE TABLE public.
auth_user (
11 password character varying(128) NOT NULL,
12 last_login
timestamp with time zone,
13 is_superuser
boolean NOT NULL,
14 username
character varying(150) NOT NULL,
15 first_name
character varying(30) NOT NULL,
16 last_name
character varying(30) NOT NULL,
17 email
character varying(254) NOT NULL,
18 is_staff
boolean NOT NULL,
19 is_active
boolean NOT NULL,
20 date_joined
timestamp with time zone DEFAULT now() NOT NULL,
24 ALTER TABLE public.auth_user
OWNER TO gargantua
;
27 -- TODO add publication_date
28 -- TODO typename -> type_id
29 CREATE TABLE public.
nodes (
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
;
44 CREATE TABLE public.
ngrams (
46 terms
character varying(255),
50 ALTER TABLE public.ngrams
OWNER TO gargantua
;
52 --------------------------------------------------------------
53 -- TODO: delete delete this table
54 --CREATE TABLE public.nodes_ngrams (
56 -- node_id integer NOT NULL,
57 -- ngrams_id integer NOT NULL,
58 -- parent_id integer REFERENCES public.nodes_ngrams(id) ON DELETE SET NULL,
59 -- ngrams_type integer,
61 -- 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,
66 --ALTER TABLE public.nodes_ngrams OWNER TO gargantua;
67 --------------------------------------------------------------
69 --------------------------------------------------------------
72 --CREATE TABLE public.nodes_ngrams_ngrams (
73 -- node_id integer NOT NULL REFERENCES public.nodes(id) ON DELETE CASCADE,
74 -- ngram1_id integer NOT NULL REFERENCES public.ngrams(id) ON DELETE CASCADE,
75 -- ngram2_id integer NOT NULL REFERENCES public.ngrams(id) ON DELETE CASCADE,
76 -- weight double precision,
77 -- PRIMARY KEY (node_id,ngram1_id,ngram2_id)
80 --ALTER TABLE public.nodes_ngrams_ngrams OWNER TO gargantua;
82 ---------------------------------------------------------------
83 CREATE TABLE public.
nodes_nodes (
84 node1_id
integer NOT NULL REFERENCES public.
nodes(id) ON DELETE CASCADE,
85 node2_id
integer NOT NULL REFERENCES public.
nodes(id) ON DELETE CASCADE,
89 PRIMARY KEY (node1_id
,node2_id
)
91 ALTER TABLE public.nodes_nodes
OWNER TO gargantua
;
93 ---------------------------------------------------------------
94 -- TODO should reference "id" of nodes_nodes (instead of node1_id, node2_id)
95 CREATE TABLE public.
node_node_ngrams (
97 node1_id
INTEGER NOT NULL REFERENCES public.
nodes (id) ON DELETE CASCADE,
98 node2_id
INTEGER NOT NULL REFERENCES public.
nodes (id) ON DELETE CASCADE,
99 ngrams_id
INTEGER NOT NULL REFERENCES public.
ngrams (id) ON DELETE CASCADE,
101 weight
double precision,
104 ALTER TABLE public.node_node_ngrams
OWNER TO gargantua
;
105 --------------------------------------------------------------
107 --CREATE TABLE public.nodes_ngrams_repo (
108 -- version integer NOT NULL,
109 -- patches jsonb DEFAULT '{}'::jsonb NOT NULL,
110 -- PRIMARY KEY (version)
112 --ALTER TABLE public.nodes_ngrams_repo OWNER TO gargantua;
114 ---------------------------------------------------------
116 -- If needed for rights management at row level
117 -- CREATE EXTENSION IF NOT EXISTS acl WITH SCHEMA public;
119 CREATE TABLE public.
rights (
120 user_id
INTEGER NOT NULL REFERENCES public.
auth_user(id) ON DELETE CASCADE,
121 node_id
INTEGER NOT NULL REFERENCES public.
nodes(id) ON DELETE CASCADE,
122 rights
INTEGER NOT NULL,
123 PRIMARY KEY (user_id
, node_id
)
125 ALTER TABLE public.rights
OWNER TO gargantua
;
128 ------------------------------------------------------------
131 CREATE INDEX ON public.auth_user
USING btree (username varchar_pattern_ops
);
132 CREATE UNIQUE INDEX ON public.auth_user
USING btree (username
);
134 CREATE INDEX ON public.rights
USING btree (user_id
,node_id
);
136 CREATE INDEX ON public.nodes
USING gin (hyperdata
);
137 CREATE INDEX ON public.nodes
USING btree (user_id
, typename
, parent_id
);
138 CREATE UNIQUE INDEX ON public.nodes
USING btree (((hyperdata
->> 'uniqId'::text)));
139 CREATE UNIQUE INDEX ON public.nodes
USING btree (((hyperdata
->> 'uniqIdBdd'::text)));
140 CREATE UNIQUE INDEX ON public.nodes
USING btree (typename
, parent_id
, ((hyperdata
->> 'uniqId'::text)));
142 CREATE UNIQUE INDEX ON public.
ngrams (terms
); -- TEST GIN
144 CREATE INDEX ON public.nodes_nodes
USING btree (node1_id
, node2_id
, delete);
145 CREATE UNIQUE INDEX ON public.nodes_nodes
USING btree (node1_id
, node2_id
);
147 CREATE UNIQUE INDEX ON public.node_node_ngrams
USING btree (node1_id
, node2_id
, ngrams_id
, ngrams_type
);
150 -- TODO user haskell-postgresql-simple to create this function
151 -- with rights typename
152 CREATE OR REPLACE FUNCTION public.
search_update()
153 RETURNS trigger AS $$
155 IF new.typename
= 4 AND new.hyperdata @
> '{"language_iso2":"EN"}' THEN
156 new.
search := to_tsvector( 'english' , (new.hyperdata
->> 'title') ||
' ' ||
(new.hyperdata
->> 'abstract'));
158 ELSIF
new.typename
= 4 AND new.hyperdata @
> '{"language_iso2":"FR"}' THEN
159 new.
search := to_tsvector( 'french' , (new.hyperdata
->> 'title') ||
' ' ||
(new.hyperdata
->> 'abstract'));
161 ELSIF
new.typename
= 41 THEN
162 new.
search := to_tsvector( 'french' , (new.hyperdata
->> 'prenom')
163 ||
' ' ||
(new.hyperdata
->> 'nom')
164 ||
' ' ||
(new.hyperdata
->> 'fonction')
167 new.
search := to_tsvector( 'english' , new.
name);
173 ALTER FUNCTION public.
search_update() OWNER TO gargantua
;
175 CREATE TRIGGER search_update_trigger
BEFORE INSERT OR UPDATE ON nodes
FOR EACH ROW EXECUTE PROCEDURE search_update();
177 -- Ngrams Full DB Extraction Optim
178 -- TODO remove hard parameter
179 CREATE OR REPLACE function node_pos(int, int) returns bigint
180 AS 'SELECT count(id) from nodes
184 LANGUAGE SQL immutable;
186 --drop index node_by_pos;
187 create index node_by_pos
on nodes
using btree(node_pos(id,typename
));
189 -- Initialize index with already existing data
190 UPDATE nodes
SET hyperdata
= hyperdata
;