]> Git — Sourcephile - gargantext.git/blob - src/Gargantext/Database/Schema/schema.sql
[PHYLO.API] REST GET.
[gargantext.git] / src / Gargantext / Database / Schema / schema.sql
1 CREATE EXTENSION IF NOT EXISTS plpgsql WITH SCHEMA pg_catalog;
2 CREATE EXTENSION IF NOT EXISTS tsm_system_rows;
3
4 COMMENT ON EXTENSION plpgsql IS 'PL/pgSQL procedural language';
5
6 -- CREATE USER WITH ...
7 -- createdb "gargandb"
8
9 CREATE TABLE public.auth_user (
10 id SERIAL,
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,
21 PRIMARY KEY (id)
22 );
23
24 ALTER TABLE public.auth_user OWNER TO gargantua;
25
26
27 -- TODO add publication_date
28 -- TODO typename -> type_id
29 CREATE TABLE public.nodes (
30 id SERIAL,
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,
37 search tsvector,
38 PRIMARY KEY (id),
39 FOREIGN KEY (user_id) REFERENCES public.auth_user(id) ON DELETE CASCADE
40 );
41 ALTER TABLE public.nodes OWNER TO gargantua;
42
43
44 CREATE TABLE public.ngrams (
45 id SERIAL,
46 terms character varying(255),
47 n integer,
48 PRIMARY KEY (id)
49 );
50 ALTER TABLE public.ngrams OWNER TO gargantua;
51
52 --------------------------------------------------------------
53 --------------------------------------------------------------
54 -- TODO: delete delete this table
55 CREATE TABLE public.nodes_ngrams (
56 id SERIAL,
57 node_id integer NOT NULL,
58 ngrams_id integer NOT NULL,
59 parent_id integer REFERENCES public.nodes_ngrams(id) ON DELETE SET NULL,
60 ngrams_type integer,
61 list_type integer,
62 weight double precision,
63 FOREIGN KEY (node_id) REFERENCES public.nodes(id) ON DELETE CASCADE,
64 FOREIGN KEY (ngrams_id) REFERENCES public.ngrams(id) ON DELETE CASCADE,
65 PRIMARY KEY (id)
66 -- PRIMARY KEY (node_id,ngrams_id)
67 );
68 ALTER TABLE public.nodes_ngrams OWNER TO gargantua;
69 --------------------------------------------------------------
70
71 CREATE TABLE public.nodes_ngrams_repo (
72 version integer NOT NULL,
73 patches jsonb DEFAULT '{}'::jsonb NOT NULL,
74 PRIMARY KEY (version)
75 );
76 ALTER TABLE public.nodes_ngrams_repo OWNER TO gargantua;
77
78 --------------------------------------------------------------
79 --
80 --
81 -- TODO: delete delete this table
82 --CREATE TABLE public.nodes_ngrams_ngrams (
83 -- node_id integer NOT NULL REFERENCES public.nodes(id) ON DELETE CASCADE,
84 -- ngram1_id integer NOT NULL REFERENCES public.ngrams(id) ON DELETE CASCADE,
85 -- ngram2_id integer NOT NULL REFERENCES public.ngrams(id) ON DELETE CASCADE,
86 -- weight double precision,
87 -- PRIMARY KEY (node_id,ngram1_id,ngram2_id)
88 --);
89 --
90 --ALTER TABLE public.nodes_ngrams_ngrams OWNER TO gargantua;
91
92 ---------------------------------------------------------
93 CREATE TABLE public.nodes_nodes (
94 node1_id integer NOT NULL REFERENCES public.nodes(id) ON DELETE CASCADE,
95 node2_id integer NOT NULL REFERENCES public.nodes(id) ON DELETE CASCADE,
96 score real,
97 favorite boolean,
98 delete boolean,
99 PRIMARY KEY (node1_id, node2_id)
100 );
101 ALTER TABLE public.nodes_nodes OWNER TO gargantua;
102 ---------------------------------------------------------
103
104 -- If needed for rights management at row level
105 -- CREATE EXTENSION IF NOT EXISTS acl WITH SCHEMA public;
106
107 CREATE TABLE public.rights (
108 user_id INTEGER NOT NULL REFERENCES public.auth_user(id) ON DELETE CASCADE,
109 node_id INTEGER NOT NULL REFERENCES public.nodes(id) ON DELETE CASCADE,
110 rights INTEGER NOT NULL,
111 PRIMARY KEY (user_id, node_id)
112 );
113 ALTER TABLE public.rights OWNER TO gargantua;
114
115
116
117 ------------------------------------------------------------
118 -- INDEXES
119
120 CREATE INDEX ON public.auth_user USING btree (username varchar_pattern_ops);
121 CREATE UNIQUE INDEX ON public.auth_user USING btree (username);
122
123 CREATE INDEX ON public.rights USING btree (user_id,node_id);
124
125 CREATE INDEX ON public.nodes USING gin (hyperdata);
126 CREATE INDEX ON public.nodes USING btree (user_id, typename, parent_id);
127 CREATE UNIQUE INDEX ON public.nodes USING btree (((hyperdata ->> 'uniqId'::text)));
128 CREATE UNIQUE INDEX ON public.nodes USING btree (((hyperdata ->> 'uniqIdBdd'::text)));
129 CREATE UNIQUE INDEX ON public.nodes USING btree (typename, parent_id, ((hyperdata ->> 'uniqId'::text)));
130
131 CREATE UNIQUE INDEX ON public.ngrams (terms); -- TEST GIN
132
133 CREATE INDEX ON public.nodes_ngrams USING btree (ngrams_id);
134 CREATE UNIQUE INDEX ON public.nodes_ngrams USING btree (node_id,ngrams_id);
135 CREATE UNIQUE INDEX ON public.nodes_ngrams USING btree (node_id,ngrams_id,ngrams_type);
136
137 CREATE INDEX ON public.nodes_nodes USING btree (node1_id, node2_id, delete);
138 CREATE UNIQUE INDEX ON public.nodes_nodes USING btree (node1_id, node2_id);
139
140 --CREATE INDEX ON public.nodes_nodes_ngrams USING btree (node1_id,nod2_id);
141
142 -- TRIGGERS
143 -- TODO user haskell-postgresql-simple to create this function
144 -- with rights typename
145 CREATE OR REPLACE FUNCTION public.search_update()
146 RETURNS trigger AS $$
147 begin
148 IF new.typename = 4 AND new.hyperdata @> '{"language_iso2":"EN"}' THEN
149 new.search := to_tsvector( 'english' , (new.hyperdata ->> 'title') || ' ' || (new.hyperdata ->> 'abstract'));
150
151 ELSIF new.typename = 4 AND new.hyperdata @> '{"language_iso2":"FR"}' THEN
152 new.search := to_tsvector( 'french' , (new.hyperdata ->> 'title') || ' ' || (new.hyperdata ->> 'abstract'));
153
154 ELSIF new.typename = 41 THEN
155 new.search := to_tsvector( 'french' , (new.hyperdata ->> 'prenom')
156 || ' ' || (new.hyperdata ->> 'nom')
157 || ' ' || (new.hyperdata ->> 'fonction')
158 );
159 ELSE
160 new.search := to_tsvector( 'english' , new.name);
161 END IF;
162 return new;
163 end
164 $$ LANGUAGE plpgsql;
165
166 ALTER FUNCTION public.search_update() OWNER TO gargantua;
167
168 CREATE TRIGGER search_update_trigger BEFORE INSERT OR UPDATE ON nodes FOR EACH ROW EXECUTE PROCEDURE search_update();
169
170 -- Ngrams Full DB Extraction Optim
171 -- TODO remove hard parameter
172 CREATE OR REPLACE function node_pos(int, int) returns bigint
173 AS 'SELECT count(id) from nodes
174 WHERE id < $1
175 AND typename = $2
176 '
177 LANGUAGE SQL immutable;
178
179 --drop index node_by_pos;
180 create index node_by_pos on nodes using btree(node_pos(id,typename));
181
182 -- Initialize index with already existing data
183 UPDATE nodes SET hyperdata = hyperdata;
184
185
186
187
188
189