schema.sql 6.87 KB
Newer Older
1
CREATE EXTENSION IF NOT EXISTS plpgsql WITH SCHEMA pg_catalog;
2 3
CREATE EXTENSION IF NOT EXISTS tsm_system_rows;

4 5 6 7 8 9 10
COMMENT ON EXTENSION plpgsql IS 'PL/pgSQL procedural language';

-- CREATE USER WITH ...
-- createdb "gargandb"

CREATE TABLE public.auth_user (
    id SERIAL,
11 12
    password     character varying(128) NOT NULL,
    last_login   timestamp with time zone,
13
    is_superuser boolean NOT NULL,
14 15 16 17 18 19
    username     character varying(150) NOT NULL,
    first_name   character varying(30) NOT NULL,
    last_name    character varying(30) NOT NULL,
    email        character varying(254) NOT NULL,
    is_staff     boolean NOT NULL,
    is_active    boolean NOT NULL,
20 21 22 23 24 25
    date_joined timestamp with time zone DEFAULT now() NOT NULL,
    PRIMARY KEY (id)
);

ALTER TABLE public.auth_user OWNER TO gargantua;

26

27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51
-- TODO add publication_date
-- TODO typename -> type_id
CREATE TABLE public.nodes (
    id        SERIAL,
    typename  integer NOT NULL,
    user_id   integer NOT NULL,
    parent_id integer REFERENCES public.nodes(id) ON DELETE CASCADE ,
    name      character varying(255) DEFAULT ''::character varying NOT NULL,
    date      timestamp with time zone DEFAULT now() NOT NULL,
    hyperdata jsonb DEFAULT '{}'::jsonb NOT NULL,
    search tsvector,
    PRIMARY KEY (id),
    FOREIGN KEY (user_id)  REFERENCES public.auth_user(id) ON DELETE CASCADE
);
ALTER TABLE public.nodes OWNER TO gargantua;


CREATE TABLE public.ngrams (
    id SERIAL,
    terms character varying(255),
    n integer,
    PRIMARY KEY (id)
);
ALTER TABLE public.ngrams OWNER TO gargantua;

52 53
--------------------------------------------------------------
-- TODO: delete delete this table
54 55 56 57 58 59 60 61 62 63 64 65 66
--CREATE TABLE public.nodes_ngrams (
--    id SERIAL,
--    node_id integer NOT NULL,
--    ngrams_id integer NOT NULL,
--    parent_id integer REFERENCES public.nodes_ngrams(id) ON DELETE SET NULL,
--    ngrams_type integer,
--    list_type integer,
--    weight double precision,
--    FOREIGN KEY (node_id) REFERENCES public.nodes(id) ON DELETE CASCADE,
--    FOREIGN KEY (ngrams_id) REFERENCES public.ngrams(id) ON DELETE CASCADE,
--    PRIMARY KEY (id)
--);
--ALTER TABLE public.nodes_ngrams OWNER TO gargantua;
67
--------------------------------------------------------------
68

69
--------------------------------------------------------------
70 71
--
--
72 73 74 75 76 77 78 79 80
--CREATE TABLE public.nodes_ngrams_ngrams (
--    node_id   integer NOT NULL REFERENCES public.nodes(id)  ON DELETE CASCADE,
--    ngram1_id integer NOT NULL REFERENCES public.ngrams(id) ON DELETE CASCADE,
--    ngram2_id integer NOT NULL REFERENCES public.ngrams(id) ON DELETE CASCADE,
--    weight double precision,
--    PRIMARY KEY (node_id,ngram1_id,ngram2_id)
--);
--
--ALTER TABLE public.nodes_ngrams_ngrams OWNER TO gargantua;
81

82
---------------------------------------------------------------
83
CREATE TABLE public.nodes_nodes (
84 85
    node1_id integer NOT NULL REFERENCES public.nodes(id) ON DELETE CASCADE,
    node2_id integer NOT NULL REFERENCES public.nodes(id) ON DELETE CASCADE,
86 87 88
    score real,
    favorite boolean,
    delete boolean,
89
    PRIMARY KEY (node1_id,node2_id)
90 91
);
ALTER TABLE public.nodes_nodes OWNER TO gargantua;
92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113

---------------------------------------------------------------
-- TODO should reference "id" of nodes_nodes (instead of node1_id, node2_id)
CREATE TABLE public.node_node_ngrams (
id SERIAL,
node1_id   INTEGER NOT NULL REFERENCES public.nodes  (id) ON DELETE CASCADE,
node2_id   INTEGER NOT NULL REFERENCES public.nodes  (id) ON DELETE CASCADE,
ngrams_id  INTEGER NOT NULL REFERENCES public.ngrams (id) ON DELETE CASCADE,
ngrams_type INTEGER,
weight double precision,
PRIMARY KEY (id)
);
ALTER TABLE public.node_node_ngrams OWNER TO gargantua;
--------------------------------------------------------------

--CREATE TABLE public.nodes_ngrams_repo (
--    version integer NOT NULL,
--    patches jsonb DEFAULT '{}'::jsonb NOT NULL,
--    PRIMARY KEY (version)
--);
--ALTER TABLE public.nodes_ngrams_repo OWNER TO gargantua;

114 115 116 117 118 119 120 121 122 123 124 125 126
---------------------------------------------------------

-- If needed for rights management at row level
-- CREATE EXTENSION IF NOT EXISTS acl WITH SCHEMA public;

CREATE TABLE public.rights (
  user_id INTEGER NOT NULL REFERENCES public.auth_user(id) ON DELETE CASCADE,
  node_id INTEGER NOT NULL REFERENCES public.nodes(id)     ON DELETE CASCADE,
  rights  INTEGER NOT NULL,
  PRIMARY KEY (user_id, node_id)
);
ALTER TABLE public.rights OWNER TO gargantua;

127

128
------------------------------------------------------------
129 130
-- INDEXES

131 132
CREATE INDEX        ON public.auth_user USING btree (username varchar_pattern_ops);
CREATE UNIQUE INDEX ON public.auth_user USING btree (username);
133

134
CREATE INDEX        ON public.rights USING btree (user_id,node_id);
135

136 137 138 139 140
CREATE INDEX        ON public.nodes USING gin (hyperdata);
CREATE INDEX        ON public.nodes USING btree (user_id, typename, parent_id);
CREATE UNIQUE INDEX ON public.nodes USING btree (((hyperdata ->> 'uniqId'::text)));
CREATE UNIQUE INDEX ON public.nodes USING btree (((hyperdata ->> 'uniqIdBdd'::text)));
CREATE UNIQUE INDEX ON public.nodes USING btree (typename, parent_id, ((hyperdata ->> 'uniqId'::text)));
141

142
CREATE UNIQUE INDEX ON public.ngrams (terms); -- TEST GIN
143

144 145 146
CREATE INDEX        ON public.nodes_nodes  USING btree (node1_id, node2_id, delete);
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);
148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176

-- TRIGGERS
-- TODO user haskell-postgresql-simple to create this function
-- with rights typename
CREATE OR REPLACE FUNCTION public.search_update()
RETURNS trigger AS $$
begin
  IF new.typename = 4 AND new.hyperdata @> '{"language_iso2":"EN"}' THEN
    new.search := to_tsvector( 'english' , (new.hyperdata ->> 'title') || ' ' || (new.hyperdata ->> 'abstract'));
  
  ELSIF new.typename = 4 AND new.hyperdata @> '{"language_iso2":"FR"}' THEN
    new.search := to_tsvector( 'french' , (new.hyperdata ->> 'title') || ' ' || (new.hyperdata ->> 'abstract'));
  
  ELSIF new.typename = 41 THEN
    new.search := to_tsvector( 'french' , (new.hyperdata ->> 'prenom')
                                 || ' ' || (new.hyperdata ->> 'nom')
                                 || ' ' || (new.hyperdata ->> 'fonction')
                             );
  ELSE
    new.search := to_tsvector( 'english' , new.name);
  END IF;
  return new;
end
$$ LANGUAGE plpgsql;

ALTER FUNCTION public.search_update() OWNER TO gargantua;

CREATE TRIGGER search_update_trigger BEFORE INSERT OR UPDATE ON nodes FOR EACH ROW EXECUTE PROCEDURE search_update();

177 178 179 180 181 182 183 184 185 186 187
-- Ngrams Full DB Extraction Optim
-- TODO remove hard parameter
CREATE OR REPLACE function node_pos(int, int) returns bigint
   AS 'SELECT count(id) from nodes
      WHERE  id < $1
      AND typename = $2
      '
   LANGUAGE SQL immutable;

--drop index node_by_pos;
create index node_by_pos on nodes using btree(node_pos(id,typename));
188 189 190 191

-- Initialize index with already existing data
UPDATE nodes SET hyperdata = hyperdata;

192 193 194 195 196