Skip to content

Commit dc46de8

Browse files
author
matthias_schaub
committed
refactor init scripts for db
1 parent 967891b commit dc46de8

File tree

4 files changed

+128
-98
lines changed

4 files changed

+128
-98
lines changed

postgres/Dockerfile

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1,7 +1,7 @@
11
FROM mdillon/postgis
22

3-
COPY initdb.sql docker-entrypoint-initdb.d/
4-
COPY serviceAccountKey.json serviceAccountKey.json
3+
COPY initdb/* docker-entrypoint-initdb.d/
4+
#COPY serviceAccountKey.json serviceAccountKey.json
55

66
# Copy backup scripts and make them executable
77
COPY backup/make_basebackup.sh make_basebackup.sh
Lines changed: 41 additions & 35 deletions
Original file line numberDiff line numberDiff line change
@@ -1,15 +1,11 @@
11
-- noinspection SqlNoDataSourceInspectionForFile
2-
3-
42
CREATE EXTENSION postgis;
5-
--
6-
-- TABLES
7-
--
3+
84
CREATE TABLE IF NOT EXISTS projects (
95
archive boolean,
106
created timestamp,
117
created_by varchar,
12-
geom geometry(MULTIPOLYGON,4326),
8+
geom geometry(MULTIPOLYGON, 4326),
139
image varchar,
1410
is_featured boolean,
1511
look_for varchar,
@@ -23,45 +19,53 @@ CREATE TABLE IF NOT EXISTS projects (
2319
status varchar,
2420
verification_number int,
2521
project_type_specifics json,
26-
PRIMARY KEY(project_id)
27-
);
22+
PRIMARY KEY (project_id)
23+
);
2824

29-
CREATE TABLE IF NOT EXISTS groups (
25+
CREATE TABLE IF NOT EXISTS GROUPS (
3026
project_id varchar,
3127
group_id varchar,
3228
number_of_tasks int,
3329
finished_count int,
3430
required_count int,
3531
progress int,
3632
project_type_specifics json,
37-
PRIMARY KEY(project_id, group_id),
33+
PRIMARY KEY (project_id, group_id),
3834
FOREIGN KEY (project_id) REFERENCES projects (project_id)
39-
);
35+
);
4036

41-
CREATE INDEX IF NOT EXISTS groups_projectid ON public.groups USING btree (group_id);
42-
CREATE INDEX IF NOT EXISTS groups_goupid ON public.groups USING btree (project_id);
37+
CREATE INDEX IF NOT EXISTS groups_projectid ON public.groups
38+
USING btree (group_id);
39+
40+
CREATE INDEX IF NOT EXISTS groups_goupid ON public.groups
41+
USING btree (project_id);
4342

4443
CREATE TABLE IF NOT EXISTS tasks (
4544
project_id varchar,
4645
group_id varchar,
4746
task_id varchar,
48-
geom geometry(MULTIPOLYGON,4326),
47+
geom geometry(MULTIPOLYGON, 4326),
4948
project_type_specifics json,
50-
PRIMARY KEY(project_id, group_id, task_id),
49+
PRIMARY KEY (project_id, group_id, task_id),
5150
FOREIGN KEY (project_id) REFERENCES projects (project_id),
52-
FOREIGN KEY (project_id, group_id) REFERENCES groups (project_id, group_id)
53-
);
51+
FOREIGN KEY (project_id, group_id) REFERENCES GROUPS (project_id, group_id)
52+
);
53+
54+
CREATE INDEX IF NOT EXISTS tasks_task_id ON public.tasks
55+
USING btree (task_id);
5456

55-
CREATE INDEX IF NOT EXISTS tasks_task_id ON public.tasks USING btree (task_id);
56-
CREATE INDEX IF NOT EXISTS tasks_groupid ON public.tasks USING btree (group_id);
57-
CREATE INDEX IF NOT EXISTS tasks_projectid ON public.tasks USING btree (project_id);
57+
CREATE INDEX IF NOT EXISTS tasks_groupid ON public.tasks
58+
USING btree (group_id);
59+
60+
CREATE INDEX IF NOT EXISTS tasks_projectid ON public.tasks
61+
USING btree (project_id);
5862

5963
CREATE TABLE IF NOT EXISTS users (
6064
user_id varchar,
6165
username varchar,
6266
created timestamp,
63-
PRIMARY KEY(user_id)
64-
);
67+
PRIMARY KEY (user_id)
68+
);
6569

6670
CREATE TABLE IF NOT EXISTS results (
6771
project_id varchar,
@@ -74,15 +78,22 @@ CREATE TABLE IF NOT EXISTS results (
7478
result int,
7579
PRIMARY KEY (project_id, group_id, task_id, user_id),
7680
FOREIGN KEY (project_id) REFERENCES projects (project_id),
77-
FOREIGN KEY (project_id, group_id) REFERENCES groups (project_id, group_id),
81+
FOREIGN KEY (project_id, group_id) REFERENCES GROUPS (project_id, group_id),
7882
FOREIGN KEY (project_id, group_id, task_id) REFERENCES tasks (project_id, group_id, task_id),
7983
FOREIGN KEY (user_id) REFERENCES users (user_id)
80-
);
84+
);
85+
86+
CREATE INDEX IF NOT EXISTS results_projectid ON public.results
87+
USING btree (project_id);
88+
89+
CREATE INDEX IF NOT EXISTS results_groupid ON public.results
90+
USING btree (group_id);
91+
92+
CREATE INDEX IF NOT EXISTS results_taskid ON public.results
93+
USING btree (task_id);
8194

82-
CREATE INDEX IF NOT EXISTS results_projectid ON public.results USING btree (project_id);
83-
CREATE INDEX IF NOT EXISTS results_groupid ON public.results USING btree (group_id);
84-
CREATE INDEX IF NOT EXISTS results_taskid ON public.results USING btree (task_id);
85-
CREATE INDEX IF NOT EXISTS results_userid ON public.results USING btree (user_id);
95+
CREATE INDEX IF NOT EXISTS results_userid ON public.results
96+
USING btree (user_id);
8697

8798
-- create table for results import through csv
8899
CREATE TABLE IF NOT EXISTS results_temp (
@@ -96,13 +107,8 @@ CREATE TABLE IF NOT EXISTS results_temp (
96107
result int,
97108
PRIMARY KEY (project_id, group_id, task_id, user_id),
98109
FOREIGN KEY (project_id) REFERENCES projects (project_id),
99-
FOREIGN KEY (project_id, group_id) REFERENCES groups (project_id, group_id),
110+
FOREIGN KEY (project_id, group_id) REFERENCES GROUPS (project_id, group_id),
100111
FOREIGN KEY (project_id, group_id, task_id) REFERENCES tasks (project_id, group_id, task_id),
101112
FOREIGN KEY (user_id) REFERENCES users (user_id)
102-
);
113+
);
103114

104-
--
105-
-- VIEWS
106-
--
107-
-- create views for statistics
108-
\i /docker-entrypoint-initdb.d/stat_views.sql

postgres/initdb/2-row-count.sql

Lines changed: 85 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,85 @@
1+
/* http://www.varlena.com/GeneralBits/120.php */
2+
CREATE TABLE row_counts (
3+
relname text PRIMARY KEY,
4+
reltuples numeric
5+
);
6+
7+
CREATE OR REPLACE FUNCTION count_trig ()
8+
RETURNS TRIGGER
9+
AS $$
10+
DECLARE
11+
BEGIN
12+
IF TG_OP = 'INSERT' THEN
13+
EXECUTE 'UPDATE row_counts set reltuples=reltuples +1 where relname = ''' || TG_RELNAME || '''';
14+
RETURN NEW;
15+
ELSIF TG_OP = 'DELETE' THEN
16+
EXECUTE 'UPDATE row_counts set reltuples=reltuples -1 where relname = ''' || TG_RELNAME || '''';
17+
RETURN OLD;
18+
END IF;
19+
END;
20+
$$
21+
LANGUAGE 'plpgsql';
22+
23+
24+
/* add triggers to all tables in public schema */
25+
CREATE OR REPLACE FUNCTION add_count_trigs ()
26+
RETURNS void
27+
AS $$
28+
DECLARE
29+
rec RECORD;
30+
q text;
31+
BEGIN
32+
FOR rec IN
33+
SELECT
34+
relname
35+
FROM
36+
pg_class r
37+
JOIN pg_namespace n ON (relnamespace = n.oid)
38+
WHERE
39+
relkind = 'r'
40+
AND n.nspname = 'public' LOOP
41+
q := 'CREATE TRIGGER ' || rec.relname || '_count BEFORE INSERT OR DELETE ON ';
42+
q := q || rec.relname || ' FOR EACH ROW EXECUTE PROCEDURE count_trig()';
43+
EXECUTE q;
44+
END LOOP;
45+
RETURN;
46+
END;
47+
$$
48+
LANGUAGE 'plpgsql';
49+
50+
CREATE OR REPLACE FUNCTION init_row_counts ()
51+
RETURNS void
52+
AS $$
53+
DECLARE
54+
rec RECORD;
55+
crec RECORD;
56+
BEGIN
57+
FOR rec IN
58+
SELECT
59+
relname
60+
FROM
61+
pg_class r
62+
JOIN pg_namespace n ON (relnamespace = n.oid)
63+
WHERE
64+
relkind = 'r'
65+
AND n.nspname = 'public' LOOP
66+
FOR crec IN EXECUTE 'SELECT count(*) as rows from ' || rec.relname LOOP
67+
-- nothing here, move along
68+
END LOOP;
69+
INSERT INTO row_counts
70+
VALUES (rec.relname, crec.rows);
71+
END LOOP;
72+
RETURN;
73+
END;
74+
$$
75+
LANGUAGE 'plpgsql';
76+
77+
VACUUM;
78+
79+
BEGIN;
80+
SELECT
81+
add_count_trigs ();
82+
SELECT
83+
init_row_counts ();
84+
COMMIT;
85+

postgres/triggers.sql

Lines changed: 0 additions & 61 deletions
This file was deleted.

0 commit comments

Comments
 (0)