rev |
line source |
jbe@0
|
1
|
jbe@92
|
2 -- Execute the following command manually for PostgreSQL prior version 9.0:
|
jbe@92
|
3 -- CREATE LANGUAGE plpgsql;
|
jbe@0
|
4
|
jbe@0
|
5 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
|
jbe@0
|
6
|
jbe@0
|
7 BEGIN;
|
jbe@0
|
8
|
jbe@5
|
9 CREATE VIEW "liquid_feedback_version" AS
|
jbe@460
|
10 SELECT * FROM (VALUES ('3.2.0', 3, 2, 0))
|
jbe@5
|
11 AS "subquery"("string", "major", "minor", "revision");
|
jbe@5
|
12
|
jbe@0
|
13
|
jbe@0
|
14
|
jbe@7
|
15 ----------------------
|
jbe@7
|
16 -- Full text search --
|
jbe@7
|
17 ----------------------
|
jbe@7
|
18
|
jbe@7
|
19
|
jbe@7
|
20 CREATE FUNCTION "text_search_query"("query_text_p" TEXT)
|
jbe@7
|
21 RETURNS TSQUERY
|
jbe@7
|
22 LANGUAGE 'plpgsql' IMMUTABLE AS $$
|
jbe@7
|
23 BEGIN
|
jbe@7
|
24 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p");
|
jbe@7
|
25 END;
|
jbe@7
|
26 $$;
|
jbe@7
|
27
|
jbe@7
|
28 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')';
|
jbe@7
|
29
|
jbe@7
|
30
|
jbe@7
|
31 CREATE FUNCTION "highlight"
|
jbe@7
|
32 ( "body_p" TEXT,
|
jbe@7
|
33 "query_text_p" TEXT )
|
jbe@7
|
34 RETURNS TEXT
|
jbe@7
|
35 LANGUAGE 'plpgsql' IMMUTABLE AS $$
|
jbe@7
|
36 BEGIN
|
jbe@7
|
37 RETURN ts_headline(
|
jbe@7
|
38 'pg_catalog.simple',
|
jbe@8
|
39 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
|
jbe@7
|
40 "text_search_query"("query_text_p"),
|
jbe@7
|
41 'StartSel=* StopSel=* HighlightAll=TRUE' );
|
jbe@7
|
42 END;
|
jbe@7
|
43 $$;
|
jbe@7
|
44
|
jbe@7
|
45 COMMENT ON FUNCTION "highlight"
|
jbe@7
|
46 ( "body_p" TEXT,
|
jbe@7
|
47 "query_text_p" TEXT )
|
jbe@7
|
48 IS 'For a given a user query this function encapsulates all matches with asterisks. Asterisks and backslashes being already present are preceeded with one extra backslash.';
|
jbe@7
|
49
|
jbe@7
|
50
|
jbe@7
|
51
|
jbe@0
|
52 -------------------------
|
jbe@0
|
53 -- Tables and indicies --
|
jbe@0
|
54 -------------------------
|
jbe@0
|
55
|
jbe@8
|
56
|
jbe@385
|
57 CREATE TABLE "temporary_transaction_data" (
|
jbe@385
|
58 PRIMARY KEY ("txid", "key"),
|
jbe@385
|
59 "txid" INT8 DEFAULT txid_current(),
|
jbe@383
|
60 "key" TEXT,
|
jbe@383
|
61 "value" TEXT NOT NULL );
|
jbe@383
|
62
|
jbe@385
|
63 COMMENT ON TABLE "temporary_transaction_data" IS 'Table to store temporary transaction data; shall be emptied before a transaction is committed';
|
jbe@385
|
64
|
jbe@385
|
65 COMMENT ON COLUMN "temporary_transaction_data"."txid" IS 'Value returned by function txid_current(); should be added to WHERE clause, when doing SELECT on this table, but ignored when doing DELETE on this table';
|
jbe@383
|
66
|
jbe@383
|
67
|
jbe@104
|
68 CREATE TABLE "system_setting" (
|
jbe@104
|
69 "member_ttl" INTERVAL );
|
jbe@104
|
70 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
|
jbe@104
|
71
|
jbe@104
|
72 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
|
jbe@104
|
73 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
|
jbe@104
|
74
|
jbe@184
|
75 COMMENT ON COLUMN "system_setting"."member_ttl" IS 'Time after members get their "active" flag set to FALSE, if they do not show any activity.';
|
jbe@104
|
76
|
jbe@104
|
77
|
jbe@111
|
78 CREATE TABLE "contingent" (
|
jbe@293
|
79 PRIMARY KEY ("polling", "time_frame"),
|
jbe@293
|
80 "polling" BOOLEAN,
|
jbe@293
|
81 "time_frame" INTERVAL,
|
jbe@111
|
82 "text_entry_limit" INT4,
|
jbe@111
|
83 "initiative_limit" INT4 );
|
jbe@111
|
84
|
jbe@111
|
85 COMMENT ON TABLE "contingent" IS 'Amount of text entries or initiatives a user may create within a given time frame. Only one row needs to be fulfilled for a member to be allowed to post. This table must not be empty.';
|
jbe@111
|
86
|
jbe@293
|
87 COMMENT ON COLUMN "contingent"."polling" IS 'Determines if settings are for creating initiatives and new drafts of initiatives with "polling" flag set';
|
jbe@111
|
88 COMMENT ON COLUMN "contingent"."text_entry_limit" IS 'Number of new drafts or suggestions to be submitted by each member within the given time frame';
|
jbe@111
|
89 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
|
jbe@111
|
90
|
jbe@111
|
91
|
jbe@0
|
92 CREATE TABLE "member" (
|
jbe@0
|
93 "id" SERIAL4 PRIMARY KEY,
|
jbe@13
|
94 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
jbe@181
|
95 "invite_code" TEXT UNIQUE,
|
jbe@232
|
96 "invite_code_expiry" TIMESTAMPTZ,
|
jbe@182
|
97 "admin_comment" TEXT,
|
jbe@181
|
98 "activated" TIMESTAMPTZ,
|
jbe@184
|
99 "last_activity" DATE,
|
jbe@42
|
100 "last_login" TIMESTAMPTZ,
|
jbe@387
|
101 "last_delegation_check" TIMESTAMPTZ,
|
jbe@45
|
102 "login" TEXT UNIQUE,
|
jbe@0
|
103 "password" TEXT,
|
jbe@440
|
104 "authority" TEXT,
|
jbe@440
|
105 "authority_uid" TEXT,
|
jbe@440
|
106 "authority_login" TEXT,
|
jbe@99
|
107 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@181
|
108 "active" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@0
|
109 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@221
|
110 "lang" TEXT,
|
jbe@7
|
111 "notify_email" TEXT,
|
jbe@11
|
112 "notify_email_unconfirmed" TEXT,
|
jbe@11
|
113 "notify_email_secret" TEXT UNIQUE,
|
jbe@11
|
114 "notify_email_secret_expiry" TIMESTAMPTZ,
|
jbe@55
|
115 "notify_email_lock_expiry" TIMESTAMPTZ,
|
jbe@486
|
116 "disable_notifications" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@486
|
117 "notification_counter" INT4 NOT NULL DEFAULT 1,
|
jbe@486
|
118 "notification_sample_size" INT4 NOT NULL DEFAULT 3,
|
jbe@486
|
119 "notification_dow" INT4 CHECK ("notification_dow" BETWEEN 0 AND 6),
|
jbe@486
|
120 "notification_hour" INT4 CHECK ("notification_hour" BETWEEN 0 AND 23),
|
jbe@387
|
121 "login_recovery_expiry" TIMESTAMPTZ,
|
jbe@11
|
122 "password_reset_secret" TEXT UNIQUE,
|
jbe@11
|
123 "password_reset_secret_expiry" TIMESTAMPTZ,
|
jbe@225
|
124 "name" TEXT UNIQUE,
|
jbe@7
|
125 "identification" TEXT UNIQUE,
|
jbe@214
|
126 "authentication" TEXT,
|
jbe@7
|
127 "organizational_unit" TEXT,
|
jbe@7
|
128 "internal_posts" TEXT,
|
jbe@7
|
129 "realname" TEXT,
|
jbe@7
|
130 "birthday" DATE,
|
jbe@7
|
131 "address" TEXT,
|
jbe@7
|
132 "email" TEXT,
|
jbe@7
|
133 "xmpp_address" TEXT,
|
jbe@7
|
134 "website" TEXT,
|
jbe@7
|
135 "phone" TEXT,
|
jbe@7
|
136 "mobile_phone" TEXT,
|
jbe@7
|
137 "profession" TEXT,
|
jbe@7
|
138 "external_memberships" TEXT,
|
jbe@7
|
139 "external_posts" TEXT,
|
jbe@159
|
140 "formatting_engine" TEXT,
|
jbe@7
|
141 "statement" TEXT,
|
jbe@181
|
142 "text_search_data" TSVECTOR,
|
jbe@184
|
143 CONSTRAINT "active_requires_activated_and_last_activity"
|
jbe@225
|
144 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)),
|
jbe@440
|
145 CONSTRAINT "authority_requires_uid_and_vice_versa"
|
jbe@447
|
146 CHECK (("authority" NOTNULL) = ("authority_uid" NOTNULL)),
|
jbe@440
|
147 CONSTRAINT "authority_uid_unique_per_authority"
|
jbe@440
|
148 UNIQUE ("authority", "authority_uid"),
|
jbe@440
|
149 CONSTRAINT "authority_login_requires_authority"
|
jbe@440
|
150 CHECK ("authority" NOTNULL OR "authority_login" ISNULL),
|
jbe@225
|
151 CONSTRAINT "name_not_null_if_activated"
|
jbe@225
|
152 CHECK ("activated" ISNULL OR "name" NOTNULL) );
|
jbe@440
|
153 CREATE INDEX "member_authority_login_idx" ON "member" ("authority_login");
|
jbe@0
|
154 CREATE INDEX "member_active_idx" ON "member" ("active");
|
jbe@8
|
155 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
|
jbe@7
|
156 CREATE TRIGGER "update_text_search_data"
|
jbe@7
|
157 BEFORE INSERT OR UPDATE ON "member"
|
jbe@7
|
158 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@7
|
159 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
|
jbe@7
|
160 "name", "identification", "organizational_unit", "internal_posts",
|
jbe@7
|
161 "realname", "external_memberships", "external_posts", "statement" );
|
jbe@0
|
162
|
jbe@0
|
163 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
|
jbe@0
|
164
|
jbe@181
|
165 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
|
jbe@181
|
166 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
|
jbe@232
|
167 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"';
|
jbe@182
|
168 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
|
jbe@207
|
169 COMMENT ON COLUMN "member"."activated" IS 'Timestamp of first activation of account (i.e. usage of "invite_code"); required to be set for "active" members';
|
jbe@184
|
170 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
|
jbe@103
|
171 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
|
jbe@387
|
172 COMMENT ON COLUMN "member"."last_delegation_check" IS 'Timestamp of last delegation check (i.e. confirmation of all unit and area delegations)';
|
jbe@10
|
173 COMMENT ON COLUMN "member"."login" IS 'Login name';
|
jbe@10
|
174 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
|
jbe@440
|
175 COMMENT ON COLUMN "member"."authority" IS 'NULL if LiquidFeedback Core is authoritative for the member account; otherwise a string that indicates the source/authority of the external account (e.g. ''LDAP'' for an LDAP account)';
|
jbe@440
|
176 COMMENT ON COLUMN "member"."authority_uid" IS 'Unique identifier (unique per "authority") that allows to identify an external account (e.g. even if the login name changes)';
|
jbe@440
|
177 COMMENT ON COLUMN "member"."authority_login" IS 'Login name for external accounts (field is not unique!)';
|
jbe@99
|
178 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
|
jbe@184
|
179 COMMENT ON COLUMN "member"."active" IS 'Memberships, support and votes are taken into account when corresponding members are marked as active. Automatically set to FALSE, if "last_activity" is older than "system_setting"."member_ttl".';
|
jbe@10
|
180 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
|
jbe@221
|
181 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
|
jbe@10
|
182 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
|
jbe@10
|
183 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
|
jbe@10
|
184 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
|
jbe@10
|
185 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
|
jbe@55
|
186 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
|
jbe@460
|
187 COMMENT ON COLUMN "member"."disable_notifications" IS 'TRUE if member does not want to receive notifications';
|
jbe@387
|
188 COMMENT ON COLUMN "member"."login_recovery_expiry" IS 'Date/time after which another login recovery attempt is allowed';
|
jbe@387
|
189 COMMENT ON COLUMN "member"."password_reset_secret" IS 'Secret string sent via e-mail for password recovery';
|
jbe@387
|
190 COMMENT ON COLUMN "member"."password_reset_secret_expiry" IS 'Date/time until the password recovery secret is valid, and date/time after which another password recovery attempt is allowed';
|
jbe@225
|
191 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet';
|
jbe@10
|
192 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
|
jbe@214
|
193 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
|
jbe@10
|
194 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to';
|
jbe@10
|
195 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization';
|
jbe@10
|
196 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"';
|
jbe@10
|
197 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications';
|
jbe@10
|
198 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in';
|
jbe@10
|
199 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization';
|
jbe@159
|
200 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
|
jbe@207
|
201 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his/her profile';
|
jbe@7
|
202
|
jbe@7
|
203
|
jbe@13
|
204 CREATE TABLE "member_history" (
|
jbe@13
|
205 "id" SERIAL8 PRIMARY KEY,
|
jbe@13
|
206 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@13
|
207 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
jbe@42
|
208 "active" BOOLEAN NOT NULL,
|
jbe@13
|
209 "name" TEXT NOT NULL );
|
jbe@45
|
210 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
|
jbe@13
|
211
|
jbe@57
|
212 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
|
jbe@13
|
213
|
jbe@13
|
214 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
|
jbe@57
|
215 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
|
jbe@13
|
216
|
jbe@13
|
217
|
jbe@159
|
218 CREATE TABLE "rendered_member_statement" (
|
jbe@159
|
219 PRIMARY KEY ("member_id", "format"),
|
jbe@461
|
220 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@159
|
221 "format" TEXT,
|
jbe@159
|
222 "content" TEXT NOT NULL );
|
jbe@159
|
223
|
jbe@159
|
224 COMMENT ON TABLE "rendered_member_statement" IS 'This table may be used by frontends to cache "rendered" member statements (e.g. HTML output generated from wiki text)';
|
jbe@9
|
225
|
jbe@9
|
226
|
jbe@9
|
227 CREATE TABLE "setting" (
|
jbe@9
|
228 PRIMARY KEY ("member_id", "key"),
|
jbe@9
|
229 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@9
|
230 "key" TEXT NOT NULL,
|
jbe@9
|
231 "value" TEXT NOT NULL );
|
jbe@9
|
232 CREATE INDEX "setting_key_idx" ON "setting" ("key");
|
jbe@9
|
233
|
jbe@38
|
234 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string';
|
jbe@9
|
235
|
jbe@9
|
236 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
|
jbe@9
|
237
|
jbe@9
|
238
|
jbe@16
|
239 CREATE TABLE "setting_map" (
|
jbe@16
|
240 PRIMARY KEY ("member_id", "key", "subkey"),
|
jbe@16
|
241 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@16
|
242 "key" TEXT NOT NULL,
|
jbe@16
|
243 "subkey" TEXT NOT NULL,
|
jbe@16
|
244 "value" TEXT NOT NULL );
|
jbe@16
|
245 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key");
|
jbe@16
|
246
|
jbe@23
|
247 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs';
|
jbe@16
|
248
|
jbe@16
|
249 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix';
|
jbe@16
|
250 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry';
|
jbe@16
|
251 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry';
|
jbe@16
|
252
|
jbe@16
|
253
|
jbe@23
|
254 CREATE TABLE "member_relation_setting" (
|
jbe@23
|
255 PRIMARY KEY ("member_id", "key", "other_member_id"),
|
jbe@23
|
256 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
257 "key" TEXT NOT NULL,
|
jbe@23
|
258 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
259 "value" TEXT NOT NULL );
|
jbe@23
|
260
|
jbe@38
|
261 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string';
|
jbe@23
|
262
|
jbe@23
|
263
|
jbe@7
|
264 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
|
jbe@7
|
265
|
jbe@7
|
266 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
|
jbe@7
|
267
|
jbe@7
|
268
|
jbe@7
|
269 CREATE TABLE "member_image" (
|
jbe@7
|
270 PRIMARY KEY ("member_id", "image_type", "scaled"),
|
jbe@7
|
271 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@7
|
272 "image_type" "member_image_type",
|
jbe@7
|
273 "scaled" BOOLEAN,
|
jbe@7
|
274 "content_type" TEXT,
|
jbe@7
|
275 "data" BYTEA NOT NULL );
|
jbe@7
|
276
|
jbe@7
|
277 COMMENT ON TABLE "member_image" IS 'Images of members';
|
jbe@7
|
278
|
jbe@7
|
279 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
|
jbe@0
|
280
|
jbe@0
|
281
|
jbe@4
|
282 CREATE TABLE "member_count" (
|
jbe@341
|
283 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
jbe@5
|
284 "total_count" INT4 NOT NULL );
|
jbe@4
|
285
|
jbe@5
|
286 COMMENT ON TABLE "member_count" IS 'Contains one row which contains the total count of active(!) members and a timestamp indicating when the total member count and area member counts were calculated';
|
jbe@4
|
287
|
jbe@5
|
288 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
|
jbe@5
|
289 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
|
jbe@4
|
290
|
jbe@4
|
291
|
jbe@0
|
292 CREATE TABLE "contact" (
|
jbe@0
|
293 PRIMARY KEY ("member_id", "other_member_id"),
|
jbe@0
|
294 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
295 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@11
|
296 "public" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@11
|
297 CONSTRAINT "cant_save_yourself_as_contact"
|
jbe@11
|
298 CHECK ("member_id" != "other_member_id") );
|
jbe@113
|
299 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
|
jbe@0
|
300
|
jbe@0
|
301 COMMENT ON TABLE "contact" IS 'Contact lists';
|
jbe@0
|
302
|
jbe@0
|
303 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
|
jbe@0
|
304 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
|
jbe@0
|
305 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
|
jbe@0
|
306
|
jbe@0
|
307
|
jbe@113
|
308 CREATE TABLE "ignored_member" (
|
jbe@113
|
309 PRIMARY KEY ("member_id", "other_member_id"),
|
jbe@113
|
310 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@113
|
311 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
|
jbe@113
|
312 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
|
jbe@113
|
313
|
jbe@113
|
314 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
|
jbe@113
|
315
|
jbe@113
|
316 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
|
jbe@113
|
317 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
|
jbe@113
|
318
|
jbe@113
|
319
|
jbe@220
|
320 CREATE TABLE "session" (
|
jbe@220
|
321 "ident" TEXT PRIMARY KEY,
|
jbe@220
|
322 "additional_secret" TEXT,
|
jbe@220
|
323 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
|
jbe@461
|
324 "member_id" INT4 REFERENCES "member" ("id") ON DELETE SET NULL,
|
jbe@440
|
325 "authority" TEXT,
|
jbe@440
|
326 "authority_uid" TEXT,
|
jbe@440
|
327 "authority_login" TEXT,
|
jbe@387
|
328 "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@220
|
329 "lang" TEXT );
|
jbe@220
|
330 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
|
jbe@220
|
331
|
jbe@220
|
332 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
|
jbe@220
|
333
|
jbe@220
|
334 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
|
jbe@220
|
335 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
|
jbe@220
|
336 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
|
jbe@440
|
337 COMMENT ON COLUMN "session"."authority" IS 'Temporary store for "member"."authority" during member account creation';
|
jbe@440
|
338 COMMENT ON COLUMN "session"."authority_uid" IS 'Temporary store for "member"."authority_uid" during member account creation';
|
jbe@440
|
339 COMMENT ON COLUMN "session"."authority_login" IS 'Temporary store for "member"."authority_login" during member account creation';
|
jbe@387
|
340 COMMENT ON COLUMN "session"."needs_delegation_check" IS 'Set to TRUE, if member must perform a delegation check to proceed with login; see column "last_delegation_check" in "member" table';
|
jbe@220
|
341 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
|
jbe@220
|
342
|
jbe@220
|
343
|
jbe@424
|
344 CREATE TYPE "defeat_strength" AS ENUM ('simple', 'tuple');
|
jbe@424
|
345
|
jbe@424
|
346 COMMENT ON TYPE "defeat_strength" IS 'How pairwise defeats are measured for the Schulze method: ''simple'' = only the number of winning votes, ''tuple'' = primarily the number of winning votes, secondarily the number of losing votes';
|
jbe@424
|
347
|
jbe@424
|
348
|
jbe@424
|
349 CREATE TYPE "tie_breaking" AS ENUM ('simple', 'variant1', 'variant2');
|
jbe@424
|
350
|
jbe@424
|
351 COMMENT ON TYPE "tie_breaking" IS 'Tie-breaker for the Schulze method: ''simple'' = only initiative ids are used, ''variant1'' = use initiative ids in variant 1 for tie breaking of the links (TBRL) and sequentially forbid shared links, ''variant2'' = use initiative ids in variant 2 for tie breaking of the links (TBRL) and sequentially forbid shared links';
|
jbe@424
|
352
|
jbe@424
|
353
|
jbe@0
|
354 CREATE TABLE "policy" (
|
jbe@0
|
355 "id" SERIAL4 PRIMARY KEY,
|
jbe@9
|
356 "index" INT4 NOT NULL,
|
jbe@0
|
357 "active" BOOLEAN NOT NULL DEFAULT TRUE,
|
jbe@0
|
358 "name" TEXT NOT NULL UNIQUE,
|
jbe@0
|
359 "description" TEXT NOT NULL DEFAULT '',
|
jbe@261
|
360 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@447
|
361 "min_admission_time" INTERVAL,
|
jbe@447
|
362 "max_admission_time" INTERVAL,
|
jbe@261
|
363 "discussion_time" INTERVAL,
|
jbe@261
|
364 "verification_time" INTERVAL,
|
jbe@261
|
365 "voting_time" INTERVAL,
|
jbe@292
|
366 "issue_quorum_num" INT4,
|
jbe@292
|
367 "issue_quorum_den" INT4,
|
jbe@0
|
368 "initiative_quorum_num" INT4 NOT NULL,
|
jbe@10
|
369 "initiative_quorum_den" INT4 NOT NULL,
|
jbe@424
|
370 "defeat_strength" "defeat_strength" NOT NULL DEFAULT 'tuple',
|
jbe@424
|
371 "tie_breaking" "tie_breaking" NOT NULL DEFAULT 'variant1',
|
jbe@167
|
372 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
|
jbe@167
|
373 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
|
jbe@167
|
374 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
|
jbe@167
|
375 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
|
jbe@167
|
376 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
|
jbe@167
|
377 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
|
jbe@167
|
378 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
|
jbe@167
|
379 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
|
jbe@167
|
380 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
|
jbe@167
|
381 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
|
jbe@429
|
382 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@260
|
383 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@260
|
384 CONSTRAINT "timing" CHECK (
|
jbe@261
|
385 ( "polling" = FALSE AND
|
jbe@447
|
386 "min_admission_time" NOTNULL AND "max_admission_time" NOTNULL AND
|
jbe@454
|
387 "min_admission_time" <= "max_admission_time" AND
|
jbe@447
|
388 "discussion_time" NOTNULL AND
|
jbe@447
|
389 "verification_time" NOTNULL AND
|
jbe@447
|
390 "voting_time" NOTNULL ) OR
|
jbe@261
|
391 ( "polling" = TRUE AND
|
jbe@447
|
392 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
|
jbe@447
|
393 "discussion_time" NOTNULL AND
|
jbe@447
|
394 "verification_time" NOTNULL AND
|
jbe@447
|
395 "voting_time" NOTNULL ) OR
|
jbe@447
|
396 ( "polling" = TRUE AND
|
jbe@447
|
397 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
|
jbe@447
|
398 "discussion_time" ISNULL AND
|
jbe@447
|
399 "verification_time" ISNULL AND
|
jbe@447
|
400 "voting_time" ISNULL ) ),
|
jbe@292
|
401 CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK (
|
jbe@447
|
402 "polling" = ("issue_quorum_num" ISNULL) AND
|
jbe@447
|
403 "polling" = ("issue_quorum_den" ISNULL) ),
|
jbe@429
|
404 CONSTRAINT "no_reverse_beat_path_requires_tuple_defeat_strength" CHECK (
|
jbe@429
|
405 "defeat_strength" = 'tuple'::"defeat_strength" OR
|
jbe@429
|
406 "no_reverse_beat_path" = FALSE ) );
|
jbe@0
|
407 CREATE INDEX "policy_active_idx" ON "policy" ("active");
|
jbe@0
|
408
|
jbe@0
|
409 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
|
jbe@0
|
410
|
jbe@9
|
411 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
|
jbe@0
|
412 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
|
jbe@447
|
413 COMMENT ON COLUMN "policy"."polling" IS 'TRUE = special policy for non-user-generated issues without issue quorum, where certain initiatives (those having the "polling" flag set) do not need to pass the initiative quorum; "min_admission_time" and "max_admission_time" MUST be set to NULL, the other timings may be set to NULL altogether, allowing individual timing for those issues';
|
jbe@447
|
414 COMMENT ON COLUMN "policy"."min_admission_time" IS 'Minimum duration of issue state ''admission''; Minimum time an issue stays open';
|
jbe@447
|
415 COMMENT ON COLUMN "policy"."max_admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
|
jbe@207
|
416 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
|
jbe@207
|
417 COMMENT ON COLUMN "policy"."verification_time" IS 'Duration of issue state ''verification''; Regular time until an issue is "fully_frozen" (e.g. entering issue state ''voting'') after being "half_frozen"';
|
jbe@207
|
418 COMMENT ON COLUMN "policy"."voting_time" IS 'Duration of issue state ''voting''; Time after an issue is "fully_frozen" but not "closed" (duration of issue state ''voting'')';
|
jbe@207
|
419 COMMENT ON COLUMN "policy"."issue_quorum_num" IS 'Numerator of potential supporter quorum to be reached by one initiative of an issue to be "accepted" and enter issue state ''discussion''';
|
jbe@207
|
420 COMMENT ON COLUMN "policy"."issue_quorum_den" IS 'Denominator of potential supporter quorum to be reached by one initiative of an issue to be "accepted" and enter issue state ''discussion''';
|
jbe@10
|
421 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
|
jbe@10
|
422 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
|
jbe@428
|
423 COMMENT ON COLUMN "policy"."defeat_strength" IS 'How pairwise defeats are measured for the Schulze method; see type "defeat_strength"; ''tuple'' is the recommended setting';
|
jbe@428
|
424 COMMENT ON COLUMN "policy"."tie_breaking" IS 'Tie-breaker for the Schulze method; see type "tie_breaking"; ''variant1'' or ''variant2'' are recommended';
|
jbe@167
|
425 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
|
jbe@167
|
426 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
|
jbe@167
|
427 COMMENT ON COLUMN "policy"."direct_majority_strict" IS 'If TRUE, then the direct majority must be strictly greater than "direct_majority_num"/"direct_majority_den", otherwise it may also be equal.';
|
jbe@167
|
428 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
|
jbe@167
|
429 COMMENT ON COLUMN "policy"."direct_majority_non_negative" IS 'Absolute number of sum of "positive_votes" and abstentions neccessary for an initiative to be attainable as winner';
|
jbe@167
|
430 COMMENT ON COLUMN "policy"."indirect_majority_num" IS 'Numerator of fraction of neccessary indirect majority (through beat path) for initiatives to be attainable as winner';
|
jbe@167
|
431 COMMENT ON COLUMN "policy"."indirect_majority_den" IS 'Denominator of fraction of neccessary indirect majority (through beat path) for initiatives to be attainable as winner';
|
jbe@167
|
432 COMMENT ON COLUMN "policy"."indirect_majority_strict" IS 'If TRUE, then the indirect majority must be strictly greater than "indirect_majority_num"/"indirect_majority_den", otherwise it may also be equal.';
|
jbe@167
|
433 COMMENT ON COLUMN "policy"."indirect_majority_positive" IS 'Absolute number of votes in favor of the winner neccessary in a beat path to the status quo for an initaitive to be attainable as winner';
|
jbe@167
|
434 COMMENT ON COLUMN "policy"."indirect_majority_non_negative" IS 'Absolute number of sum of votes in favor and abstentions in a beat path to the status quo for an initiative to be attainable as winner';
|
jbe@429
|
435 COMMENT ON COLUMN "policy"."no_reverse_beat_path" IS 'EXPERIMENTAL FEATURE: Causes initiatives with "reverse_beat_path" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."reverse_beat_path". This option ensures both that a winning initiative is never tied in a (weak) condorcet paradox with the status quo and a winning initiative always beats the status quo directly with a simple majority.';
|
jbe@429
|
436 COMMENT ON COLUMN "policy"."no_multistage_majority" IS 'EXPERIMENTAL FEATURE: Causes initiatives with "multistage_majority" flag to not be "eligible", thus disallowing them to be winner. See comment on column "initiative"."multistage_majority". This disqualifies initiatives which could cause an instable result. An instable result in this meaning is a result such that repeating the ballot with same preferences but with the winner of the first ballot as status quo would lead to a different winner in the second ballot. If there are no direct majorities required for the winner, or if in direct comparison only simple majorities are required and "no_reverse_beat_path" is true, then results are always stable and this flag does not have any effect on the winner (but still affects the "eligible" flag of an "initiative").';
|
jbe@0
|
437
|
jbe@0
|
438
|
jbe@97
|
439 CREATE TABLE "unit" (
|
jbe@97
|
440 "id" SERIAL4 PRIMARY KEY,
|
jbe@97
|
441 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@97
|
442 "active" BOOLEAN NOT NULL DEFAULT TRUE,
|
jbe@97
|
443 "name" TEXT NOT NULL,
|
jbe@97
|
444 "description" TEXT NOT NULL DEFAULT '',
|
jbe@444
|
445 "external_reference" TEXT,
|
jbe@97
|
446 "member_count" INT4,
|
jbe@97
|
447 "text_search_data" TSVECTOR );
|
jbe@97
|
448 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
|
jbe@97
|
449 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
|
jbe@97
|
450 CREATE INDEX "unit_active_idx" ON "unit" ("active");
|
jbe@97
|
451 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
|
jbe@97
|
452 CREATE TRIGGER "update_text_search_data"
|
jbe@97
|
453 BEFORE INSERT OR UPDATE ON "unit"
|
jbe@97
|
454 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@97
|
455 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
|
jbe@97
|
456 "name", "description" );
|
jbe@97
|
457
|
jbe@97
|
458 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
|
jbe@97
|
459
|
jbe@444
|
460 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
|
jbe@444
|
461 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
|
jbe@444
|
462 COMMENT ON COLUMN "unit"."external_reference" IS 'Opaque data field to store an external reference';
|
jbe@444
|
463 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
|
jbe@97
|
464
|
jbe@97
|
465
|
jbe@465
|
466 CREATE TABLE "subscription" (
|
jbe@465
|
467 PRIMARY KEY ("member_id", "unit_id"),
|
jbe@465
|
468 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@465
|
469 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
|
jbe@465
|
470 CREATE INDEX "subscription_unit_id_idx" ON "subscription" ("unit_id");
|
jbe@465
|
471
|
jbe@465
|
472 COMMENT ON TABLE "subscription" IS 'An entry in this table denotes that the member wishes to receive notifications regardless of his/her privileges in the given unit';
|
jbe@465
|
473
|
jbe@465
|
474
|
jbe@203
|
475 CREATE TABLE "unit_setting" (
|
jbe@203
|
476 PRIMARY KEY ("member_id", "key", "unit_id"),
|
jbe@203
|
477 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@203
|
478 "key" TEXT NOT NULL,
|
jbe@203
|
479 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@203
|
480 "value" TEXT NOT NULL );
|
jbe@203
|
481
|
jbe@203
|
482 COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings';
|
jbe@203
|
483
|
jbe@203
|
484
|
jbe@0
|
485 CREATE TABLE "area" (
|
jbe@0
|
486 "id" SERIAL4 PRIMARY KEY,
|
jbe@97
|
487 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
488 "active" BOOLEAN NOT NULL DEFAULT TRUE,
|
jbe@0
|
489 "name" TEXT NOT NULL,
|
jbe@4
|
490 "description" TEXT NOT NULL DEFAULT '',
|
jbe@444
|
491 "external_reference" TEXT,
|
jbe@5
|
492 "direct_member_count" INT4,
|
jbe@5
|
493 "member_weight" INT4,
|
jbe@7
|
494 "text_search_data" TSVECTOR );
|
jbe@97
|
495 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
|
jbe@0
|
496 CREATE INDEX "area_active_idx" ON "area" ("active");
|
jbe@8
|
497 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
|
jbe@7
|
498 CREATE TRIGGER "update_text_search_data"
|
jbe@7
|
499 BEFORE INSERT OR UPDATE ON "area"
|
jbe@7
|
500 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@7
|
501 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
|
jbe@7
|
502 "name", "description" );
|
jbe@0
|
503
|
jbe@0
|
504 COMMENT ON TABLE "area" IS 'Subject areas';
|
jbe@0
|
505
|
jbe@5
|
506 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
|
jbe@444
|
507 COMMENT ON COLUMN "area"."external_reference" IS 'Opaque data field to store an external reference';
|
jbe@5
|
508 COMMENT ON COLUMN "area"."direct_member_count" IS 'Number of active members of that area (ignoring their weight), as calculated from view "area_member_count"';
|
jbe@5
|
509 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations';
|
jbe@0
|
510
|
jbe@0
|
511
|
jbe@465
|
512 CREATE TABLE "ignored_area" (
|
jbe@465
|
513 PRIMARY KEY ("member_id", "area_id"),
|
jbe@465
|
514 "member_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@465
|
515 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
|
jbe@465
|
516 CREATE INDEX "ignored_area_area_id_idx" ON "ignored_area" ("area_id");
|
jbe@465
|
517
|
jbe@465
|
518 COMMENT ON TABLE "ignored_area" IS 'An entry in this table denotes that the member does not wish to receive notifications for the given subject area unless he/she declared interested in a particular issue';
|
jbe@465
|
519
|
jbe@465
|
520
|
jbe@23
|
521 CREATE TABLE "area_setting" (
|
jbe@23
|
522 PRIMARY KEY ("member_id", "key", "area_id"),
|
jbe@23
|
523 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
524 "key" TEXT NOT NULL,
|
jbe@23
|
525 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
526 "value" TEXT NOT NULL );
|
jbe@23
|
527
|
jbe@23
|
528 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings';
|
jbe@23
|
529
|
jbe@23
|
530
|
jbe@9
|
531 CREATE TABLE "allowed_policy" (
|
jbe@9
|
532 PRIMARY KEY ("area_id", "policy_id"),
|
jbe@9
|
533 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@9
|
534 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@9
|
535 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
|
jbe@9
|
536 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
|
jbe@9
|
537
|
jbe@9
|
538 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
|
jbe@9
|
539
|
jbe@9
|
540 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
|
jbe@9
|
541
|
jbe@9
|
542
|
jbe@21
|
543 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze');
|
jbe@21
|
544
|
jbe@21
|
545 COMMENT ON TYPE "snapshot_event" IS 'Reason for snapshots: ''periodic'' = due to periodic recalculation, ''end_of_admission'' = saved state at end of admission period, ''half_freeze'' = saved state at end of discussion period, ''full_freeze'' = saved state at end of verification period';
|
jbe@8
|
546
|
jbe@8
|
547
|
jbe@112
|
548 CREATE TYPE "issue_state" AS ENUM (
|
jbe@112
|
549 'admission', 'discussion', 'verification', 'voting',
|
jbe@389
|
550 'canceled_by_admin',
|
jbe@113
|
551 'canceled_revoked_before_accepted',
|
jbe@113
|
552 'canceled_issue_not_accepted',
|
jbe@113
|
553 'canceled_after_revocation_during_discussion',
|
jbe@113
|
554 'canceled_after_revocation_during_verification',
|
jbe@113
|
555 'canceled_no_initiative_admitted',
|
jbe@112
|
556 'finished_without_winner', 'finished_with_winner');
|
jbe@111
|
557
|
jbe@111
|
558 COMMENT ON TYPE "issue_state" IS 'State of issues';
|
jbe@111
|
559
|
jbe@111
|
560
|
jbe@0
|
561 CREATE TABLE "issue" (
|
jbe@0
|
562 "id" SERIAL4 PRIMARY KEY,
|
jbe@0
|
563 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
564 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
|
jbe@389
|
565 "admin_notice" TEXT,
|
jbe@444
|
566 "external_reference" TEXT,
|
jbe@111
|
567 "state" "issue_state" NOT NULL DEFAULT 'admission',
|
jbe@328
|
568 "phase_finished" TIMESTAMPTZ,
|
jbe@0
|
569 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
jbe@0
|
570 "accepted" TIMESTAMPTZ,
|
jbe@3
|
571 "half_frozen" TIMESTAMPTZ,
|
jbe@3
|
572 "fully_frozen" TIMESTAMPTZ,
|
jbe@0
|
573 "closed" TIMESTAMPTZ,
|
jbe@59
|
574 "cleaned" TIMESTAMPTZ,
|
jbe@447
|
575 "min_admission_time" INTERVAL,
|
jbe@447
|
576 "max_admission_time" INTERVAL,
|
jbe@22
|
577 "discussion_time" INTERVAL NOT NULL,
|
jbe@22
|
578 "verification_time" INTERVAL NOT NULL,
|
jbe@22
|
579 "voting_time" INTERVAL NOT NULL,
|
jbe@0
|
580 "snapshot" TIMESTAMPTZ,
|
jbe@8
|
581 "latest_snapshot_event" "snapshot_event",
|
jbe@0
|
582 "population" INT4,
|
jbe@4
|
583 "voter_count" INT4,
|
jbe@170
|
584 "status_quo_schulze_rank" INT4,
|
jbe@291
|
585 CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK (
|
jbe@447
|
586 ("min_admission_time" NOTNULL) = ("max_admission_time" NOTNULL) AND
|
jbe@452
|
587 ("min_admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created")) ),
|
jbe@340
|
588 CONSTRAINT "valid_state" CHECK (
|
jbe@340
|
589 (
|
jbe@340
|
590 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
|
jbe@340
|
591 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
|
jbe@340
|
592 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL ) OR
|
jbe@340
|
593 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL)
|
jbe@340
|
594 ) AND (
|
jbe@340
|
595 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
|
jbe@340
|
596 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
|
jbe@340
|
597 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
|
jbe@340
|
598 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
|
jbe@389
|
599 ("state" = 'canceled_by_admin' AND "closed" NOTNULL) OR
|
jbe@340
|
600 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
|
jbe@340
|
601 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
|
jbe@340
|
602 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
|
jbe@340
|
603 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
|
jbe@340
|
604 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" = "fully_frozen") OR
|
jbe@340
|
605 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") OR
|
jbe@340
|
606 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen")
|
jbe@111
|
607 )),
|
jbe@328
|
608 CONSTRAINT "phase_finished_only_when_not_closed" CHECK (
|
jbe@328
|
609 "phase_finished" ISNULL OR "closed" ISNULL ),
|
jbe@3
|
610 CONSTRAINT "state_change_order" CHECK (
|
jbe@10
|
611 "created" <= "accepted" AND
|
jbe@10
|
612 "accepted" <= "half_frozen" AND
|
jbe@10
|
613 "half_frozen" <= "fully_frozen" AND
|
jbe@3
|
614 "fully_frozen" <= "closed" ),
|
jbe@61
|
615 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
|
jbe@61
|
616 "cleaned" ISNULL OR "closed" NOTNULL ),
|
jbe@10
|
617 CONSTRAINT "last_snapshot_on_full_freeze"
|
jbe@10
|
618 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet
|
jbe@10
|
619 CONSTRAINT "freeze_requires_snapshot"
|
jbe@10
|
620 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL),
|
jbe@10
|
621 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event"
|
jbe@447
|
622 CHECK (("snapshot" NOTNULL) = ("latest_snapshot_event" NOTNULL)) );
|
jbe@0
|
623 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id");
|
jbe@0
|
624 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id");
|
jbe@16
|
625 CREATE INDEX "issue_created_idx" ON "issue" ("created");
|
jbe@16
|
626 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
|
jbe@16
|
627 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
|
jbe@16
|
628 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
|
jbe@16
|
629 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
|
jbe@0
|
630 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
|
jbe@16
|
631 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
|
jbe@0
|
632
|
jbe@0
|
633 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
|
jbe@0
|
634
|
jbe@389
|
635 COMMENT ON COLUMN "issue"."admin_notice" IS 'Public notice by admin to explain manual interventions, or to announce corrections';
|
jbe@444
|
636 COMMENT ON COLUMN "issue"."external_reference" IS 'Opaque data field to store an external reference';
|
jbe@328
|
637 COMMENT ON COLUMN "issue"."phase_finished" IS 'Set to a value NOTNULL, if the current phase has finished, but calculations are pending; No changes in this issue shall be made by the frontend or API when this value is set';
|
jbe@170
|
638 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"';
|
jbe@170
|
639 COMMENT ON COLUMN "issue"."half_frozen" IS 'Point in time, when "discussion_time" has elapsed; Frontends must ensure that for half_frozen issues a) initiatives are not revoked, b) no new drafts are created, c) no initiators are added or removed.';
|
jbe@170
|
640 COMMENT ON COLUMN "issue"."fully_frozen" IS 'Point in time, when "verification_time" has elapsed and voting has started; Frontends must ensure that for fully_frozen issues additionally to the restrictions for half_frozen issues a) initiatives are not created, b) no interest is created or removed, c) no supporters are added or removed, d) no opinions are created, changed or deleted.';
|
jbe@447
|
641 COMMENT ON COLUMN "issue"."closed" IS 'Point in time, when "max_admission_time" or "voting_time" have elapsed, and issue is no longer active; Frontends must ensure that for closed issues additionally to the restrictions for half_frozen and fully_frozen issues a) no voter is added or removed to/from the direct_voter table, b) no votes are added, modified or removed.';
|
jbe@170
|
642 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
|
jbe@447
|
643 COMMENT ON COLUMN "issue"."min_admission_time" IS 'Copied from "policy" table at creation of issue';
|
jbe@447
|
644 COMMENT ON COLUMN "issue"."max_admission_time" IS 'Copied from "policy" table at creation of issue';
|
jbe@170
|
645 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
|
jbe@170
|
646 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
|
jbe@170
|
647 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
|
jbe@170
|
648 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
|
jbe@170
|
649 COMMENT ON COLUMN "issue"."latest_snapshot_event" IS 'Event type of latest snapshot for issue; Can be used to select the latest snapshot data in the snapshot tables';
|
jbe@170
|
650 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"';
|
jbe@170
|
651 COMMENT ON COLUMN "issue"."voter_count" IS 'Total number of direct and delegating voters; This value is related to the final voting, while "population" is related to snapshots before the final voting';
|
jbe@170
|
652 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
|
jbe@0
|
653
|
jbe@0
|
654
|
jbe@410
|
655 CREATE TABLE "issue_order_in_admission_state" (
|
jbe@400
|
656 "id" INT8 PRIMARY KEY, --REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@410
|
657 "order_in_area" INT4,
|
jbe@410
|
658 "order_in_unit" INT4 );
|
jbe@410
|
659
|
jbe@410
|
660 COMMENT ON TABLE "issue_order_in_admission_state" IS 'Ordering information for issues that are not stored in the "issue" table to avoid locking of multiple issues at once; Filled/updated by "lf_update_issue_order"';
|
jbe@410
|
661
|
jbe@410
|
662 COMMENT ON COLUMN "issue_order_in_admission_state"."id" IS 'References "issue" ("id") but has no referential integrity trigger associated, due to performance/locking issues';
|
jbe@410
|
663 COMMENT ON COLUMN "issue_order_in_admission_state"."order_in_area" IS 'Order of issues in admission state within a single area; NULL values sort last';
|
jbe@410
|
664 COMMENT ON COLUMN "issue_order_in_admission_state"."order_in_unit" IS 'Order of issues in admission state within all areas of a unit; NULL values sort last';
|
jbe@0
|
665
|
jbe@0
|
666
|
jbe@23
|
667 CREATE TABLE "issue_setting" (
|
jbe@23
|
668 PRIMARY KEY ("member_id", "key", "issue_id"),
|
jbe@23
|
669 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
670 "key" TEXT NOT NULL,
|
jbe@23
|
671 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
672 "value" TEXT NOT NULL );
|
jbe@23
|
673
|
jbe@23
|
674 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings';
|
jbe@23
|
675
|
jbe@23
|
676
|
jbe@0
|
677 CREATE TABLE "initiative" (
|
jbe@0
|
678 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
|
jbe@0
|
679 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
680 "id" SERIAL4 PRIMARY KEY,
|
jbe@0
|
681 "name" TEXT NOT NULL,
|
jbe@261
|
682 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@0
|
683 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
jbe@0
|
684 "revoked" TIMESTAMPTZ,
|
jbe@112
|
685 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
|
jbe@14
|
686 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@444
|
687 "external_reference" TEXT,
|
jbe@0
|
688 "admitted" BOOLEAN,
|
jbe@0
|
689 "supporter_count" INT4,
|
jbe@0
|
690 "informed_supporter_count" INT4,
|
jbe@0
|
691 "satisfied_supporter_count" INT4,
|
jbe@0
|
692 "satisfied_informed_supporter_count" INT4,
|
jbe@313
|
693 "harmonic_weight" NUMERIC(12, 3),
|
jbe@352
|
694 "final_suggestion_order_calculated" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@414
|
695 "first_preference_votes" INT4,
|
jbe@0
|
696 "positive_votes" INT4,
|
jbe@0
|
697 "negative_votes" INT4,
|
jbe@167
|
698 "direct_majority" BOOLEAN,
|
jbe@167
|
699 "indirect_majority" BOOLEAN,
|
jbe@170
|
700 "schulze_rank" INT4,
|
jbe@167
|
701 "better_than_status_quo" BOOLEAN,
|
jbe@167
|
702 "worse_than_status_quo" BOOLEAN,
|
jbe@429
|
703 "reverse_beat_path" BOOLEAN,
|
jbe@154
|
704 "multistage_majority" BOOLEAN,
|
jbe@154
|
705 "eligible" BOOLEAN,
|
jbe@126
|
706 "winner" BOOLEAN,
|
jbe@0
|
707 "rank" INT4,
|
jbe@7
|
708 "text_search_data" TSVECTOR,
|
jbe@112
|
709 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
|
jbe@447
|
710 CHECK (("revoked" NOTNULL) = ("revoked_by_member_id" NOTNULL)),
|
jbe@14
|
711 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
|
jbe@14
|
712 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
|
jbe@0
|
713 CONSTRAINT "revoked_initiatives_cant_be_admitted"
|
jbe@0
|
714 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
|
jbe@128
|
715 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
|
jbe@128
|
716 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
|
jbe@414
|
717 ( "first_preference_votes" ISNULL AND
|
jbe@414
|
718 "positive_votes" ISNULL AND "negative_votes" ISNULL AND
|
jbe@167
|
719 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
|
jbe@173
|
720 "schulze_rank" ISNULL AND
|
jbe@167
|
721 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
|
jbe@429
|
722 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
|
jbe@173
|
723 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
|
jbe@173
|
724 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
|
jbe@175
|
725 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
|
jbe@175
|
726 "eligible" = FALSE OR
|
jbe@175
|
727 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
|
jbe@175
|
728 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
|
jbe@175
|
729 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
|
jbe@176
|
730 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
|
jbe@173
|
731 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
|
jbe@16
|
732 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
|
jbe@16
|
733 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
|
jbe@8
|
734 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
|
jbe@7
|
735 CREATE TRIGGER "update_text_search_data"
|
jbe@7
|
736 BEFORE INSERT OR UPDATE ON "initiative"
|
jbe@7
|
737 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@450
|
738 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "name");
|
jbe@0
|
739
|
jbe@10
|
740 COMMENT ON TABLE "initiative" IS 'Group of members publishing drafts for resolutions to be passed; Frontends must ensure that initiatives of half_frozen issues are not revoked, and that initiatives of fully_frozen or closed issues are neither revoked nor created.';
|
jbe@0
|
741
|
jbe@289
|
742 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
|
jbe@210
|
743 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
|
jbe@210
|
744 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
|
jbe@444
|
745 COMMENT ON COLUMN "initiative"."external_reference" IS 'Opaque data field to store an external reference';
|
jbe@210
|
746 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
|
jbe@0
|
747 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
|
jbe@0
|
748 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
|
jbe@0
|
749 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
|
jbe@0
|
750 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
|
jbe@320
|
751 COMMENT ON COLUMN "initiative"."harmonic_weight" IS 'Indicates the relevancy of the initiative, calculated from the potential supporters weighted with the harmonic series to avoid a large number of clones affecting other initiative''s sorting positions too much; shall be used as secondary sorting key after "admitted" as primary sorting key';
|
jbe@352
|
752 COMMENT ON COLUMN "initiative"."final_suggestion_order_calculated" IS 'Set to TRUE, when "proportional_order" of suggestions has been calculated the last time';
|
jbe@414
|
753 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
|
jbe@414
|
754 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
|
jbe@414
|
755 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
|
jbe@210
|
756 COMMENT ON COLUMN "initiative"."direct_majority" IS 'TRUE, if "positive_votes"/("positive_votes"+"negative_votes") is strictly greater or greater-equal than "direct_majority_num"/"direct_majority_den", and "positive_votes" is greater-equal than "direct_majority_positive", and ("positive_votes"+abstentions) is greater-equal than "direct_majority_non_negative"';
|
jbe@210
|
757 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
|
jbe@411
|
758 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking';
|
jbe@411
|
759 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo';
|
jbe@411
|
760 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (DEPRECATED, since schulze-ranking is unique per issue; use "better_than_status_quo"=FALSE)';
|
jbe@429
|
761 COMMENT ON COLUMN "initiative"."reverse_beat_path" IS 'TRUE, if there is a beat path (may include ties) from this initiative to the status quo; set to NULL if "policy"."defeat_strength" is set to ''simple''';
|
jbe@210
|
762 COMMENT ON COLUMN "initiative"."multistage_majority" IS 'TRUE, if either (a) this initiative has no better rank than the status quo, or (b) there exists a better ranked initiative X, which directly beats this initiative, and either more voters prefer X to this initiative than voters preferring X to the status quo or less voters prefer this initiative to X than voters preferring the status quo to X';
|
jbe@429
|
763 COMMENT ON COLUMN "initiative"."eligible" IS 'Initiative has a "direct_majority" and an "indirect_majority", is "better_than_status_quo" and depending on selected policy the initiative has no "reverse_beat_path" or "multistage_majority"';
|
jbe@411
|
764 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"';
|
jbe@210
|
765 COMMENT ON COLUMN "initiative"."rank" IS 'Unique ranking for all "admitted" initiatives per issue; lower rank is better; a winner always has rank 1, but rank 1 does not imply that an initiative is winner; initiatives with "direct_majority" AND "indirect_majority" always have a better (lower) rank than other initiatives';
|
jbe@0
|
766
|
jbe@0
|
767
|
jbe@61
|
768 CREATE TABLE "battle" (
|
jbe@126
|
769 "issue_id" INT4 NOT NULL,
|
jbe@61
|
770 "winning_initiative_id" INT4,
|
jbe@61
|
771 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@61
|
772 "losing_initiative_id" INT4,
|
jbe@61
|
773 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@126
|
774 "count" INT4 NOT NULL,
|
jbe@126
|
775 CONSTRAINT "initiative_ids_not_equal" CHECK (
|
jbe@126
|
776 "winning_initiative_id" != "losing_initiative_id" OR
|
jbe@126
|
777 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
|
jbe@126
|
778 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
|
jbe@126
|
779 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
|
jbe@126
|
780 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
|
jbe@126
|
781 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
|
jbe@126
|
782
|
jbe@126
|
783 COMMENT ON TABLE "battle" IS 'Number of members preferring one initiative to another; Filled by "battle_view" when closing an issue; NULL as initiative_id denotes virtual "status-quo" initiative';
|
jbe@61
|
784
|
jbe@61
|
785
|
jbe@113
|
786 CREATE TABLE "ignored_initiative" (
|
jbe@465
|
787 PRIMARY KEY ("member_id", "initiative_id"),
|
jbe@465
|
788 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@465
|
789 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
|
jbe@465
|
790 CREATE INDEX "ignored_initiative_initiative_id_idx" ON "ignored_initiative" ("initiative_id");
|
jbe@113
|
791
|
jbe@113
|
792 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
|
jbe@113
|
793
|
jbe@113
|
794
|
jbe@23
|
795 CREATE TABLE "initiative_setting" (
|
jbe@23
|
796 PRIMARY KEY ("member_id", "key", "initiative_id"),
|
jbe@23
|
797 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
798 "key" TEXT NOT NULL,
|
jbe@23
|
799 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
800 "value" TEXT NOT NULL );
|
jbe@23
|
801
|
jbe@23
|
802 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings';
|
jbe@23
|
803
|
jbe@23
|
804
|
jbe@0
|
805 CREATE TABLE "draft" (
|
jbe@0
|
806 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
|
jbe@0
|
807 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
808 "id" SERIAL8 PRIMARY KEY,
|
jbe@0
|
809 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
jbe@0
|
810 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
|
jbe@9
|
811 "formatting_engine" TEXT,
|
jbe@7
|
812 "content" TEXT NOT NULL,
|
jbe@444
|
813 "external_reference" TEXT,
|
jbe@7
|
814 "text_search_data" TSVECTOR );
|
jbe@16
|
815 CREATE INDEX "draft_created_idx" ON "draft" ("created");
|
jbe@9
|
816 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
|
jbe@8
|
817 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
|
jbe@7
|
818 CREATE TRIGGER "update_text_search_data"
|
jbe@7
|
819 BEFORE INSERT OR UPDATE ON "draft"
|
jbe@7
|
820 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@7
|
821 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
|
jbe@0
|
822
|
jbe@10
|
823 COMMENT ON TABLE "draft" IS 'Drafts of initiatives to solve issues; Frontends must ensure that new drafts for initiatives of half_frozen, fully_frozen or closed issues can''t be created.';
|
jbe@0
|
824
|
jbe@444
|
825 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
|
jbe@444
|
826 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
|
jbe@444
|
827 COMMENT ON COLUMN "draft"."external_reference" IS 'Opaque data field to store an external reference';
|
jbe@9
|
828
|
jbe@0
|
829
|
jbe@63
|
830 CREATE TABLE "rendered_draft" (
|
jbe@63
|
831 PRIMARY KEY ("draft_id", "format"),
|
jbe@63
|
832 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@63
|
833 "format" TEXT,
|
jbe@63
|
834 "content" TEXT NOT NULL );
|
jbe@63
|
835
|
jbe@63
|
836 COMMENT ON TABLE "rendered_draft" IS 'This table may be used by frontends to cache "rendered" drafts (e.g. HTML output generated from wiki text)';
|
jbe@63
|
837
|
jbe@63
|
838
|
jbe@0
|
839 CREATE TABLE "suggestion" (
|
jbe@0
|
840 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
|
jbe@0
|
841 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
842 "id" SERIAL8 PRIMARY KEY,
|
jbe@160
|
843 "draft_id" INT8 NOT NULL,
|
jbe@160
|
844 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
|
jbe@0
|
845 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
jbe@0
|
846 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
|
jbe@0
|
847 "name" TEXT NOT NULL,
|
jbe@159
|
848 "formatting_engine" TEXT,
|
jbe@159
|
849 "content" TEXT NOT NULL DEFAULT '',
|
jbe@444
|
850 "external_reference" TEXT,
|
jbe@7
|
851 "text_search_data" TSVECTOR,
|
jbe@0
|
852 "minus2_unfulfilled_count" INT4,
|
jbe@0
|
853 "minus2_fulfilled_count" INT4,
|
jbe@0
|
854 "minus1_unfulfilled_count" INT4,
|
jbe@0
|
855 "minus1_fulfilled_count" INT4,
|
jbe@0
|
856 "plus1_unfulfilled_count" INT4,
|
jbe@0
|
857 "plus1_fulfilled_count" INT4,
|
jbe@0
|
858 "plus2_unfulfilled_count" INT4,
|
jbe@352
|
859 "plus2_fulfilled_count" INT4,
|
jbe@352
|
860 "proportional_order" INT4 );
|
jbe@16
|
861 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
|
jbe@9
|
862 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
|
jbe@8
|
863 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
|
jbe@7
|
864 CREATE TRIGGER "update_text_search_data"
|
jbe@7
|
865 BEFORE INSERT OR UPDATE ON "suggestion"
|
jbe@7
|
866 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@7
|
867 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
|
jbe@159
|
868 "name", "content");
|
jbe@0
|
869
|
jbe@10
|
870 COMMENT ON TABLE "suggestion" IS 'Suggestions to initiators, to change the current draft; must not be deleted explicitly, as they vanish automatically if the last opinion is deleted';
|
jbe@0
|
871
|
jbe@160
|
872 COMMENT ON COLUMN "suggestion"."draft_id" IS 'Draft, which the author has seen when composing the suggestion; should always be set by a frontend, but defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
|
jbe@444
|
873 COMMENT ON COLUMN "suggestion"."external_reference" IS 'Opaque data field to store an external reference';
|
jbe@0
|
874 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
|
jbe@0
|
875 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
|
jbe@0
|
876 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
|
jbe@0
|
877 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
|
jbe@0
|
878 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
|
jbe@0
|
879 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
|
jbe@0
|
880 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
|
jbe@0
|
881 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
|
jbe@378
|
882 COMMENT ON COLUMN "suggestion"."proportional_order" IS 'To be used for sorting suggestions within an initiative; NULL values sort last; updated by "lf_update_suggestion_order"';
|
jbe@0
|
883
|
jbe@0
|
884
|
jbe@159
|
885 CREATE TABLE "rendered_suggestion" (
|
jbe@159
|
886 PRIMARY KEY ("suggestion_id", "format"),
|
jbe@159
|
887 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@159
|
888 "format" TEXT,
|
jbe@159
|
889 "content" TEXT NOT NULL );
|
jbe@159
|
890
|
jbe@159
|
891 COMMENT ON TABLE "rendered_suggestion" IS 'This table may be used by frontends to cache "rendered" drafts (e.g. HTML output generated from wiki text)';
|
jbe@159
|
892
|
jbe@159
|
893
|
jbe@23
|
894 CREATE TABLE "suggestion_setting" (
|
jbe@23
|
895 PRIMARY KEY ("member_id", "key", "suggestion_id"),
|
jbe@23
|
896 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
897 "key" TEXT NOT NULL,
|
jbe@23
|
898 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@23
|
899 "value" TEXT NOT NULL );
|
jbe@23
|
900
|
jbe@23
|
901 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings';
|
jbe@23
|
902
|
jbe@23
|
903
|
jbe@97
|
904 CREATE TABLE "privilege" (
|
jbe@97
|
905 PRIMARY KEY ("unit_id", "member_id"),
|
jbe@97
|
906 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@97
|
907 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@97
|
908 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@97
|
909 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@97
|
910 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@261
|
911 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@261
|
912 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
|
jbe@261
|
913 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
|
jbe@261
|
914 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
|
jbe@97
|
915
|
jbe@97
|
916 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
|
jbe@97
|
917
|
jbe@289
|
918 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
|
jbe@289
|
919 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
|
jbe@289
|
920 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
|
jbe@289
|
921 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
|
jbe@289
|
922 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
|
jbe@289
|
923 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
|
jbe@289
|
924 COMMENT ON COLUMN "privilege"."polling_right" IS 'Right to create issues with policies having the "policy"."polling" flag set, and to add initiatives having the "initiative"."polling" flag set to those issues';
|
jbe@97
|
925
|
jbe@97
|
926
|
jbe@0
|
927 CREATE TABLE "membership" (
|
jbe@0
|
928 PRIMARY KEY ("area_id", "member_id"),
|
jbe@0
|
929 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@169
|
930 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
|
jbe@0
|
931 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id");
|
jbe@0
|
932
|
jbe@0
|
933 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas';
|
jbe@0
|
934
|
jbe@0
|
935
|
jbe@0
|
936 CREATE TABLE "interest" (
|
jbe@0
|
937 PRIMARY KEY ("issue_id", "member_id"),
|
jbe@0
|
938 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@148
|
939 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
|
jbe@0
|
940 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
|
jbe@0
|
941
|
jbe@10
|
942 COMMENT ON TABLE "interest" IS 'Interest of members in a particular issue; Frontends must ensure that interest for fully_frozen or closed issues is not added or removed.';
|
jbe@0
|
943
|
jbe@0
|
944
|
jbe@0
|
945 CREATE TABLE "initiator" (
|
jbe@0
|
946 PRIMARY KEY ("initiative_id", "member_id"),
|
jbe@0
|
947 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
948 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@14
|
949 "accepted" BOOLEAN );
|
jbe@0
|
950 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
|
jbe@0
|
951
|
jbe@10
|
952 COMMENT ON TABLE "initiator" IS 'Members who are allowed to post new drafts; Frontends must ensure that initiators are not added or removed from half_frozen, fully_frozen or closed initiatives.';
|
jbe@0
|
953
|
jbe@14
|
954 COMMENT ON COLUMN "initiator"."accepted" IS 'If "accepted" is NULL, then the member was invited to be a co-initiator, but has not answered yet. If it is TRUE, the member has accepted the invitation, if it is FALSE, the member has rejected the invitation.';
|
jbe@0
|
955
|
jbe@0
|
956
|
jbe@0
|
957 CREATE TABLE "supporter" (
|
jbe@0
|
958 "issue_id" INT4 NOT NULL,
|
jbe@0
|
959 PRIMARY KEY ("initiative_id", "member_id"),
|
jbe@0
|
960 "initiative_id" INT4,
|
jbe@0
|
961 "member_id" INT4,
|
jbe@0
|
962 "draft_id" INT8 NOT NULL,
|
jbe@10
|
963 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@160
|
964 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
|
jbe@0
|
965 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
|
jbe@0
|
966
|
jbe@10
|
967 COMMENT ON TABLE "supporter" IS 'Members who support an initiative (conditionally); Frontends must ensure that supporters are not added or removed from fully_frozen or closed initiatives.';
|
jbe@0
|
968
|
jbe@207
|
969 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
|
jbe@160
|
970 COMMENT ON COLUMN "supporter"."draft_id" IS 'Latest seen draft; should always be set by a frontend, but defaults to current draft of the initiative (implemented by trigger "default_for_draft_id")';
|
jbe@84
|
971
|
jbe@0
|
972
|
jbe@0
|
973 CREATE TABLE "opinion" (
|
jbe@0
|
974 "initiative_id" INT4 NOT NULL,
|
jbe@0
|
975 PRIMARY KEY ("suggestion_id", "member_id"),
|
jbe@0
|
976 "suggestion_id" INT8,
|
jbe@0
|
977 "member_id" INT4,
|
jbe@0
|
978 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
|
jbe@0
|
979 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
|
jbe@42
|
980 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
981 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
|
jbe@10
|
982 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
|
jbe@0
|
983
|
jbe@10
|
984 COMMENT ON TABLE "opinion" IS 'Opinion on suggestions (criticism related to initiatives); Frontends must ensure that opinions are not created modified or deleted when related to fully_frozen or closed issues.';
|
jbe@0
|
985
|
jbe@0
|
986 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
|
jbe@0
|
987
|
jbe@0
|
988
|
jbe@97
|
989 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
|
jbe@97
|
990
|
jbe@97
|
991 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
|
jbe@10
|
992
|
jbe@10
|
993
|
jbe@0
|
994 CREATE TABLE "delegation" (
|
jbe@0
|
995 "id" SERIAL8 PRIMARY KEY,
|
jbe@0
|
996 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@86
|
997 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@10
|
998 "scope" "delegation_scope" NOT NULL,
|
jbe@97
|
999 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
1000 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
1001 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
1002 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
|
jbe@97
|
1003 CONSTRAINT "no_unit_delegation_to_null"
|
jbe@97
|
1004 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
|
jbe@10
|
1005 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
|
jbe@97
|
1006 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
|
jbe@97
|
1007 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
|
jbe@97
|
1008 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
|
jbe@97
|
1009 UNIQUE ("unit_id", "truster_id"),
|
jbe@74
|
1010 UNIQUE ("area_id", "truster_id"),
|
jbe@74
|
1011 UNIQUE ("issue_id", "truster_id") );
|
jbe@0
|
1012 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
|
jbe@0
|
1013 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
|
jbe@0
|
1014
|
jbe@0
|
1015 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
|
jbe@0
|
1016
|
jbe@97
|
1017 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
|
jbe@0
|
1018 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
|
jbe@0
|
1019 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
|
jbe@0
|
1020
|
jbe@0
|
1021
|
jbe@0
|
1022 CREATE TABLE "direct_population_snapshot" (
|
jbe@0
|
1023 PRIMARY KEY ("issue_id", "event", "member_id"),
|
jbe@0
|
1024 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
1025 "event" "snapshot_event",
|
jbe@45
|
1026 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
|
jbe@54
|
1027 "weight" INT4 );
|
jbe@0
|
1028 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id");
|
jbe@0
|
1029
|
jbe@389
|
1030 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"; for corrections refer to column "issue_notice" of "issue" table';
|
jbe@0
|
1031
|
jbe@148
|
1032 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
|
jbe@148
|
1033 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"';
|
jbe@0
|
1034
|
jbe@0
|
1035
|
jbe@0
|
1036 CREATE TABLE "delegating_population_snapshot" (
|
jbe@0
|
1037 PRIMARY KEY ("issue_id", "event", "member_id"),
|
jbe@0
|
1038 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
1039 "event" "snapshot_event",
|
jbe@45
|
1040 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
|
jbe@8
|
1041 "weight" INT4,
|
jbe@10
|
1042 "scope" "delegation_scope" NOT NULL,
|
jbe@0
|
1043 "delegate_member_ids" INT4[] NOT NULL );
|
jbe@0
|
1044 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id");
|
jbe@0
|
1045
|
jbe@389
|
1046 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table; for corrections refer to column "issue_notice" of "issue" table';
|
jbe@0
|
1047
|
jbe@0
|
1048 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
|
jbe@0
|
1049 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member';
|
jbe@8
|
1050 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight';
|
jbe@0
|
1051 COMMENT ON COLUMN "delegating_population_snapshot"."delegate_member_ids" IS 'Chain of members who act as delegates; last entry referes to "member_id" column of table "direct_population_snapshot"';
|
jbe@0
|
1052
|
jbe@0
|
1053
|
jbe@0
|
1054 CREATE TABLE "direct_interest_snapshot" (
|
jbe@0
|
1055 PRIMARY KEY ("issue_id", "event", "member_id"),
|
jbe@0
|
1056 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
1057 "event" "snapshot_event",
|
jbe@45
|
1058 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
|
jbe@144
|
1059 "weight" INT4 );
|
jbe@0
|
1060 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
|
jbe@0
|
1061
|
jbe@389
|
1062 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"; for corrections refer to column "issue_notice" of "issue" table';
|
jbe@0
|
1063
|
jbe@0
|
1064 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
|
jbe@0
|
1065 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
|
jbe@0
|
1066
|
jbe@0
|
1067
|
jbe@0
|
1068 CREATE TABLE "delegating_interest_snapshot" (
|
jbe@0
|
1069 PRIMARY KEY ("issue_id", "event", "member_id"),
|
jbe@0
|
1070 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@0
|
1071 "event" "snapshot_event",
|
jbe@45
|
1072 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
|
jbe@8
|
1073 "weight" INT4,
|
jbe@10
|
1074 "scope" "delegation_scope" NOT NULL,
|
jbe@0
|
1075 "delegate_member_ids" INT4[] NOT NULL );
|
jbe@0
|
1076 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
|
jbe@0
|
1077
|
jbe@389
|
1078 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table; for corrections refer to column "issue_notice" of "issue" table';
|
jbe@0
|
1079
|
jbe@0
|
1080 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
|
jbe@0
|
1081 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
|
jbe@8
|
1082 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
|
jbe@0
|
1083 COMMENT ON COLUMN "delegating_interest_snapshot"."delegate_member_ids" IS 'Chain of members who act as delegates; last entry referes to "member_id" column of table "direct_interest_snapshot"';
|
jbe@0
|
1084
|
jbe@0
|
1085
|
jbe@0
|
1086 CREATE TABLE "direct_supporter_snapshot" (
|
jbe@0
|
1087 "issue_id" INT4 NOT NULL,
|
jbe@0
|
1088 PRIMARY KEY ("initiative_id", "event", "member_id"),
|
jbe@0
|
1089 "initiative_id" INT4,
|
jbe@0
|
1090 "event" "snapshot_event",
|
jbe@45
|
1091 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
|
jbe@204
|
1092 "draft_id" INT8 NOT NULL,
|
jbe@0
|
1093 "informed" BOOLEAN NOT NULL,
|
jbe@0
|
1094 "satisfied" BOOLEAN NOT NULL,
|
jbe@0
|
1095 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@204
|
1096 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
|
jbe@0
|
1097 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
|
jbe@0
|
1098 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
|
jbe@0
|
1099
|
jbe@389
|
1100 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot"); for corrections refer to column "issue_notice" of "issue" table';
|
jbe@0
|
1101
|
jbe@207
|
1102 COMMENT ON COLUMN "direct_supporter_snapshot"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
|
jbe@0
|
1103 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details';
|
jbe@0
|
1104 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
|
jbe@0
|
1105 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
|
jbe@0
|
1106
|
jbe@0
|
1107
|
jbe@113
|
1108 CREATE TABLE "non_voter" (
|
jbe@113
|
1109 PRIMARY KEY ("issue_id", "member_id"),
|
jbe@113
|
1110 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@113
|
1111 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
|
jbe@113
|
1112 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
|
jbe@113
|
1113
|
jbe@113
|
1114 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
|
jbe@113
|
1115
|
jbe@113
|
1116
|
jbe@0
|
1117 CREATE TABLE "direct_voter" (
|
jbe@0
|
1118 PRIMARY KEY ("issue_id", "member_id"),
|
jbe@0
|
1119 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@45
|
1120 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
|
jbe@285
|
1121 "weight" INT4,
|
jbe@285
|
1122 "comment_changed" TIMESTAMPTZ,
|
jbe@285
|
1123 "formatting_engine" TEXT,
|
jbe@285
|
1124 "comment" TEXT,
|
jbe@285
|
1125 "text_search_data" TSVECTOR );
|
jbe@0
|
1126 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
|
jbe@285
|
1127 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
|
jbe@285
|
1128 CREATE TRIGGER "update_text_search_data"
|
jbe@285
|
1129 BEFORE INSERT OR UPDATE ON "direct_voter"
|
jbe@285
|
1130 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@285
|
1131 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
|
jbe@0
|
1132
|
jbe@389
|
1133 COMMENT ON TABLE "direct_voter" IS 'Members having directly voted for/against initiatives of an issue; frontends must ensure that no voters are added or removed to/from this table when the issue has been closed; for corrections refer to column "issue_notice" of "issue" table';
|
jbe@0
|
1134
|
jbe@285
|
1135 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
|
jbe@285
|
1136 COMMENT ON COLUMN "direct_voter"."comment_changed" IS 'Shall be set on comment change, to indicate a comment being modified after voting has been finished; Automatically set to NULL after voting phase; Automatically set to NULL by trigger, if "comment" is set to NULL';
|
jbe@285
|
1137 COMMENT ON COLUMN "direct_voter"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "direct_voter"."comment"; Automatically set to NULL by trigger, if "comment" is set to NULL';
|
jbe@285
|
1138 COMMENT ON COLUMN "direct_voter"."comment" IS 'Is to be set or updated by the frontend, if comment was inserted or updated AFTER the issue has been closed. Otherwise it shall be set to NULL.';
|
jbe@285
|
1139
|
jbe@285
|
1140
|
jbe@285
|
1141 CREATE TABLE "rendered_voter_comment" (
|
jbe@285
|
1142 PRIMARY KEY ("issue_id", "member_id", "format"),
|
jbe@285
|
1143 FOREIGN KEY ("issue_id", "member_id")
|
jbe@285
|
1144 REFERENCES "direct_voter" ("issue_id", "member_id")
|
jbe@285
|
1145 ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@285
|
1146 "issue_id" INT4,
|
jbe@285
|
1147 "member_id" INT4,
|
jbe@285
|
1148 "format" TEXT,
|
jbe@285
|
1149 "content" TEXT NOT NULL );
|
jbe@285
|
1150
|
jbe@285
|
1151 COMMENT ON TABLE "rendered_voter_comment" IS 'This table may be used by frontends to cache "rendered" voter comments (e.g. HTML output generated from wiki text)';
|
jbe@0
|
1152
|
jbe@0
|
1153
|
jbe@0
|
1154 CREATE TABLE "delegating_voter" (
|
jbe@0
|
1155 PRIMARY KEY ("issue_id", "member_id"),
|
jbe@0
|
1156 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@45
|
1157 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
|
jbe@8
|
1158 "weight" INT4,
|
jbe@10
|
1159 "scope" "delegation_scope" NOT NULL,
|
jbe@0
|
1160 "delegate_member_ids" INT4[] NOT NULL );
|
jbe@52
|
1161 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
|
jbe@0
|
1162
|
jbe@389
|
1163 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table; for corrections refer to column "issue_notice" of "issue" table';
|
jbe@0
|
1164
|
jbe@0
|
1165 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
|
jbe@8
|
1166 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
|
jbe@0
|
1167 COMMENT ON COLUMN "delegating_voter"."delegate_member_ids" IS 'Chain of members who act as delegates; last entry referes to "member_id" column of table "direct_voter"';
|
jbe@0
|
1168
|
jbe@0
|
1169
|
jbe@0
|
1170 CREATE TABLE "vote" (
|
jbe@0
|
1171 "issue_id" INT4 NOT NULL,
|
jbe@0
|
1172 PRIMARY KEY ("initiative_id", "member_id"),
|
jbe@0
|
1173 "initiative_id" INT4,
|
jbe@0
|
1174 "member_id" INT4,
|
jbe@414
|
1175 "grade" INT4 NOT NULL,
|
jbe@414
|
1176 "first_preference" BOOLEAN,
|
jbe@0
|
1177 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@414
|
1178 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@414
|
1179 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
|
jbe@414
|
1180 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
|
jbe@0
|
1181 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
|
jbe@0
|
1182
|
jbe@389
|
1183 COMMENT ON TABLE "vote" IS 'Manual and delegated votes without abstentions; frontends must ensure that no votes are added modified or removed when the issue has been closed; for corrections refer to column "issue_notice" of "issue" table';
|
jbe@0
|
1184
|
jbe@414
|
1185 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
|
jbe@414
|
1186 COMMENT ON COLUMN "vote"."grade" IS 'Values smaller than zero mean reject, values greater than zero mean acceptance, zero or missing row means abstention. Preferences are expressed by different positive or negative numbers.';
|
jbe@414
|
1187 COMMENT ON COLUMN "vote"."first_preference" IS 'Value is automatically set after voting is finished. For positive grades, this value is set to true for the highest (i.e. best) grade.';
|
jbe@0
|
1188
|
jbe@0
|
1189
|
jbe@112
|
1190 CREATE TYPE "event_type" AS ENUM (
|
jbe@112
|
1191 'issue_state_changed',
|
jbe@112
|
1192 'initiative_created_in_new_issue',
|
jbe@112
|
1193 'initiative_created_in_existing_issue',
|
jbe@112
|
1194 'initiative_revoked',
|
jbe@112
|
1195 'new_draft_created',
|
jbe@112
|
1196 'suggestion_created');
|
jbe@112
|
1197
|
jbe@112
|
1198 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
|
jbe@112
|
1199
|
jbe@112
|
1200
|
jbe@112
|
1201 CREATE TABLE "event" (
|
jbe@112
|
1202 "id" SERIAL8 PRIMARY KEY,
|
jbe@112
|
1203 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
jbe@112
|
1204 "event" "event_type" NOT NULL,
|
jbe@112
|
1205 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
|
jbe@112
|
1206 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@328
|
1207 "state" "issue_state",
|
jbe@112
|
1208 "initiative_id" INT4,
|
jbe@112
|
1209 "draft_id" INT8,
|
jbe@112
|
1210 "suggestion_id" INT8,
|
jbe@112
|
1211 FOREIGN KEY ("issue_id", "initiative_id")
|
jbe@112
|
1212 REFERENCES "initiative" ("issue_id", "id")
|
jbe@112
|
1213 ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@112
|
1214 FOREIGN KEY ("initiative_id", "draft_id")
|
jbe@112
|
1215 REFERENCES "draft" ("initiative_id", "id")
|
jbe@112
|
1216 ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@112
|
1217 FOREIGN KEY ("initiative_id", "suggestion_id")
|
jbe@112
|
1218 REFERENCES "suggestion" ("initiative_id", "id")
|
jbe@112
|
1219 ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@451
|
1220 CONSTRAINT "null_constr_for_issue_state_changed" CHECK (
|
jbe@112
|
1221 "event" != 'issue_state_changed' OR (
|
jbe@112
|
1222 "member_id" ISNULL AND
|
jbe@112
|
1223 "issue_id" NOTNULL AND
|
jbe@113
|
1224 "state" NOTNULL AND
|
jbe@112
|
1225 "initiative_id" ISNULL AND
|
jbe@112
|
1226 "draft_id" ISNULL AND
|
jbe@112
|
1227 "suggestion_id" ISNULL )),
|
jbe@451
|
1228 CONSTRAINT "null_constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
|
jbe@112
|
1229 "event" NOT IN (
|
jbe@112
|
1230 'initiative_created_in_new_issue',
|
jbe@112
|
1231 'initiative_created_in_existing_issue',
|
jbe@112
|
1232 'initiative_revoked',
|
jbe@112
|
1233 'new_draft_created'
|
jbe@112
|
1234 ) OR (
|
jbe@112
|
1235 "member_id" NOTNULL AND
|
jbe@112
|
1236 "issue_id" NOTNULL AND
|
jbe@113
|
1237 "state" NOTNULL AND
|
jbe@112
|
1238 "initiative_id" NOTNULL AND
|
jbe@112
|
1239 "draft_id" NOTNULL AND
|
jbe@112
|
1240 "suggestion_id" ISNULL )),
|
jbe@451
|
1241 CONSTRAINT "null_constr_for_suggestion_creation" CHECK (
|
jbe@112
|
1242 "event" != 'suggestion_created' OR (
|
jbe@112
|
1243 "member_id" NOTNULL AND
|
jbe@112
|
1244 "issue_id" NOTNULL AND
|
jbe@113
|
1245 "state" NOTNULL AND
|
jbe@112
|
1246 "initiative_id" NOTNULL AND
|
jbe@112
|
1247 "draft_id" ISNULL AND
|
jbe@112
|
1248 "suggestion_id" NOTNULL )) );
|
jbe@223
|
1249 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
|
jbe@112
|
1250
|
jbe@112
|
1251 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
|
jbe@112
|
1252
|
jbe@114
|
1253 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
|
jbe@114
|
1254 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
|
jbe@114
|
1255 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
|
jbe@114
|
1256 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
|
jbe@114
|
1257
|
jbe@112
|
1258
|
jbe@222
|
1259 CREATE TABLE "notification_sent" (
|
jbe@222
|
1260 "event_id" INT8 NOT NULL );
|
jbe@222
|
1261 CREATE UNIQUE INDEX "notification_sent_singleton_idx" ON "notification_sent" ((1));
|
jbe@222
|
1262
|
jbe@222
|
1263 COMMENT ON TABLE "notification_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out';
|
jbe@222
|
1264 COMMENT ON INDEX "notification_sent_singleton_idx" IS 'This index ensures that "notification_sent" only contains one row maximum.';
|
jbe@222
|
1265
|
jbe@222
|
1266
|
jbe@486
|
1267 CREATE TABLE "initiative_notification_sent" (
|
jbe@486
|
1268 PRIMARY KEY ("member_id", "initiative_id"),
|
jbe@486
|
1269 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@486
|
1270 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@486
|
1271 "last_draft_id" INT8 NOT NULL,
|
jbe@495
|
1272 "last_suggestion_id" INT8 );
|
jbe@486
|
1273 CREATE INDEX "initiative_notification_sent_initiative_idx" ON "initiative_notification_sent" ("initiative_id");
|
jbe@486
|
1274
|
jbe@486
|
1275
|
jbe@496
|
1276 CREATE TABLE "newsletter" (
|
jbe@496
|
1277 "id" SERIAL4 PRIMARY KEY,
|
jbe@496
|
1278 "published" TIMESTAMPTZ NOT NULL,
|
jbe@496
|
1279 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
jbe@496
|
1280 "include_all_members" BOOLEAN NOT NULL,
|
jbe@496
|
1281 "sent" TIMESTAMPTZ,
|
jbe@496
|
1282 "subject" TEXT NOT NULL,
|
jbe@496
|
1283 "content" TEXT NOT NULL );
|
jbe@496
|
1284 CREATE INDEX "newsletter_unit_id_idx" ON "newsletter" ("unit_id", "published");
|
jbe@496
|
1285 CREATE INDEX "newsletter_all_units_published_idx" ON "newsletter" ("published") WHERE "unit_id" ISNULL;
|
jbe@496
|
1286 CREATE INDEX "newsletter_published_idx" ON "newsletter" ("published");
|
jbe@496
|
1287
|
jbe@496
|
1288
|
jbe@112
|
1289
|
jbe@112
|
1290 ----------------------------------------------
|
jbe@112
|
1291 -- Writing of history entries and event log --
|
jbe@112
|
1292 ----------------------------------------------
|
jbe@13
|
1293
|
jbe@181
|
1294
|
jbe@13
|
1295 CREATE FUNCTION "write_member_history_trigger"()
|
jbe@13
|
1296 RETURNS TRIGGER
|
jbe@13
|
1297 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@13
|
1298 BEGIN
|
jbe@42
|
1299 IF
|
jbe@230
|
1300 ( NEW."active" != OLD."active" OR
|
jbe@230
|
1301 NEW."name" != OLD."name" ) AND
|
jbe@230
|
1302 OLD."activated" NOTNULL
|
jbe@42
|
1303 THEN
|
jbe@42
|
1304 INSERT INTO "member_history"
|
jbe@57
|
1305 ("member_id", "active", "name")
|
jbe@57
|
1306 VALUES (NEW."id", OLD."active", OLD."name");
|
jbe@13
|
1307 END IF;
|
jbe@13
|
1308 RETURN NULL;
|
jbe@13
|
1309 END;
|
jbe@13
|
1310 $$;
|
jbe@13
|
1311
|
jbe@13
|
1312 CREATE TRIGGER "write_member_history"
|
jbe@13
|
1313 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
|
jbe@13
|
1314 "write_member_history_trigger"();
|
jbe@13
|
1315
|
jbe@13
|
1316 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
|
jbe@57
|
1317 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
|
jbe@13
|
1318
|
jbe@13
|
1319
|
jbe@112
|
1320 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
|
jbe@112
|
1321 RETURNS TRIGGER
|
jbe@112
|
1322 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@112
|
1323 BEGIN
|
jbe@328
|
1324 IF NEW."state" != OLD."state" THEN
|
jbe@112
|
1325 INSERT INTO "event" ("event", "issue_id", "state")
|
jbe@112
|
1326 VALUES ('issue_state_changed', NEW."id", NEW."state");
|
jbe@112
|
1327 END IF;
|
jbe@112
|
1328 RETURN NULL;
|
jbe@112
|
1329 END;
|
jbe@112
|
1330 $$;
|
jbe@112
|
1331
|
jbe@112
|
1332 CREATE TRIGGER "write_event_issue_state_changed"
|
jbe@112
|
1333 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
|
jbe@112
|
1334 "write_event_issue_state_changed_trigger"();
|
jbe@112
|
1335
|
jbe@112
|
1336 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
|
jbe@112
|
1337 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
|
jbe@112
|
1338
|
jbe@112
|
1339
|
jbe@112
|
1340 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
|
jbe@112
|
1341 RETURNS TRIGGER
|
jbe@112
|
1342 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@112
|
1343 DECLARE
|
jbe@112
|
1344 "initiative_row" "initiative"%ROWTYPE;
|
jbe@113
|
1345 "issue_row" "issue"%ROWTYPE;
|
jbe@112
|
1346 "event_v" "event_type";
|
jbe@112
|
1347 BEGIN
|
jbe@112
|
1348 SELECT * INTO "initiative_row" FROM "initiative"
|
jbe@112
|
1349 WHERE "id" = NEW."initiative_id";
|
jbe@113
|
1350 SELECT * INTO "issue_row" FROM "issue"
|
jbe@113
|
1351 WHERE "id" = "initiative_row"."issue_id";
|
jbe@112
|
1352 IF EXISTS (
|
jbe@112
|
1353 SELECT NULL FROM "draft"
|
jbe@112
|
1354 WHERE "initiative_id" = NEW."initiative_id"
|
jbe@112
|
1355 AND "id" != NEW."id"
|
jbe@112
|
1356 ) THEN
|
jbe@112
|
1357 "event_v" := 'new_draft_created';
|
jbe@112
|
1358 ELSE
|
jbe@112
|
1359 IF EXISTS (
|
jbe@112
|
1360 SELECT NULL FROM "initiative"
|
jbe@112
|
1361 WHERE "issue_id" = "initiative_row"."issue_id"
|
jbe@112
|
1362 AND "id" != "initiative_row"."id"
|
jbe@112
|
1363 ) THEN
|
jbe@112
|
1364 "event_v" := 'initiative_created_in_existing_issue';
|
jbe@112
|
1365 ELSE
|
jbe@112
|
1366 "event_v" := 'initiative_created_in_new_issue';
|
jbe@112
|
1367 END IF;
|
jbe@112
|
1368 END IF;
|
jbe@112
|
1369 INSERT INTO "event" (
|
jbe@112
|
1370 "event", "member_id",
|
jbe@113
|
1371 "issue_id", "state", "initiative_id", "draft_id"
|
jbe@112
|
1372 ) VALUES (
|
jbe@112
|
1373 "event_v",
|
jbe@112
|
1374 NEW."author_id",
|
jbe@112
|
1375 "initiative_row"."issue_id",
|
jbe@113
|
1376 "issue_row"."state",
|
jbe@112
|
1377 "initiative_row"."id",
|
jbe@112
|
1378 NEW."id" );
|
jbe@112
|
1379 RETURN NULL;
|
jbe@112
|
1380 END;
|
jbe@112
|
1381 $$;
|
jbe@112
|
1382
|
jbe@112
|
1383 CREATE TRIGGER "write_event_initiative_or_draft_created"
|
jbe@112
|
1384 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
|
jbe@112
|
1385 "write_event_initiative_or_draft_created_trigger"();
|
jbe@112
|
1386
|
jbe@112
|
1387 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
|
jbe@112
|
1388 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
|
jbe@112
|
1389
|
jbe@112
|
1390
|
jbe@112
|
1391 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
|
jbe@112
|
1392 RETURNS TRIGGER
|
jbe@112
|
1393 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@113
|
1394 DECLARE
|
jbe@231
|
1395 "issue_row" "issue"%ROWTYPE;
|
jbe@231
|
1396 "draft_id_v" "draft"."id"%TYPE;
|
jbe@112
|
1397 BEGIN
|
jbe@112
|
1398 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
|
jbe@231
|
1399 SELECT * INTO "issue_row" FROM "issue"
|
jbe@231
|
1400 WHERE "id" = NEW."issue_id";
|
jbe@231
|
1401 SELECT "id" INTO "draft_id_v" FROM "current_draft"
|
jbe@231
|
1402 WHERE "initiative_id" = NEW."id";
|
jbe@112
|
1403 INSERT INTO "event" (
|
jbe@231
|
1404 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id"
|
jbe@112
|
1405 ) VALUES (
|
jbe@112
|
1406 'initiative_revoked',
|
jbe@112
|
1407 NEW."revoked_by_member_id",
|
jbe@112
|
1408 NEW."issue_id",
|
jbe@113
|
1409 "issue_row"."state",
|
jbe@231
|
1410 NEW."id",
|
jbe@231
|
1411 "draft_id_v");
|
jbe@112
|
1412 END IF;
|
jbe@112
|
1413 RETURN NULL;
|
jbe@112
|
1414 END;
|
jbe@112
|
1415 $$;
|
jbe@112
|
1416
|
jbe@112
|
1417 CREATE TRIGGER "write_event_initiative_revoked"
|
jbe@112
|
1418 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
|
jbe@112
|
1419 "write_event_initiative_revoked_trigger"();
|
jbe@112
|
1420
|
jbe@112
|
1421 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
|
jbe@112
|
1422 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
|
jbe@112
|
1423
|
jbe@112
|
1424
|
jbe@112
|
1425 CREATE FUNCTION "write_event_suggestion_created_trigger"()
|
jbe@112
|
1426 RETURNS TRIGGER
|
jbe@112
|
1427 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@112
|
1428 DECLARE
|
jbe@112
|
1429 "initiative_row" "initiative"%ROWTYPE;
|
jbe@113
|
1430 "issue_row" "issue"%ROWTYPE;
|
jbe@112
|
1431 BEGIN
|
jbe@112
|
1432 SELECT * INTO "initiative_row" FROM "initiative"
|
jbe@112
|
1433 WHERE "id" = NEW."initiative_id";
|
jbe@113
|
1434 SELECT * INTO "issue_row" FROM "issue"
|
jbe@113
|
1435 WHERE "id" = "initiative_row"."issue_id";
|
jbe@112
|
1436 INSERT INTO "event" (
|
jbe@112
|
1437 "event", "member_id",
|
jbe@113
|
1438 "issue_id", "state", "initiative_id", "suggestion_id"
|
jbe@112
|
1439 ) VALUES (
|
jbe@112
|
1440 'suggestion_created',
|
jbe@112
|
1441 NEW."author_id",
|
jbe@112
|
1442 "initiative_row"."issue_id",
|
jbe@113
|
1443 "issue_row"."state",
|
jbe@112
|
1444 "initiative_row"."id",
|
jbe@112
|
1445 NEW."id" );
|
jbe@112
|
1446 RETURN NULL;
|
jbe@112
|
1447 END;
|
jbe@112
|
1448 $$;
|
jbe@112
|
1449
|
jbe@112
|
1450 CREATE TRIGGER "write_event_suggestion_created"
|
jbe@112
|
1451 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
|
jbe@112
|
1452 "write_event_suggestion_created_trigger"();
|
jbe@112
|
1453
|
jbe@112
|
1454 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
|
jbe@112
|
1455 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
|
jbe@112
|
1456
|
jbe@112
|
1457
|
jbe@13
|
1458
|
jbe@0
|
1459 ----------------------------
|
jbe@0
|
1460 -- Additional constraints --
|
jbe@0
|
1461 ----------------------------
|
jbe@0
|
1462
|
jbe@0
|
1463
|
jbe@0
|
1464 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
|
jbe@0
|
1465 RETURNS TRIGGER
|
jbe@0
|
1466 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1467 BEGIN
|
jbe@0
|
1468 IF NOT EXISTS (
|
jbe@0
|
1469 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
|
jbe@0
|
1470 ) THEN
|
jbe@463
|
1471 RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING
|
jbe@463
|
1472 ERRCODE = 'integrity_constraint_violation',
|
jbe@463
|
1473 HINT = 'Create issue, initiative, and draft within the same transaction.';
|
jbe@0
|
1474 END IF;
|
jbe@0
|
1475 RETURN NULL;
|
jbe@0
|
1476 END;
|
jbe@0
|
1477 $$;
|
jbe@0
|
1478
|
jbe@0
|
1479 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
|
jbe@0
|
1480 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
|
jbe@0
|
1481 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@0
|
1482 "issue_requires_first_initiative_trigger"();
|
jbe@0
|
1483
|
jbe@0
|
1484 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
|
jbe@0
|
1485 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
|
jbe@0
|
1486
|
jbe@0
|
1487
|
jbe@0
|
1488 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
|
jbe@0
|
1489 RETURNS TRIGGER
|
jbe@0
|
1490 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1491 DECLARE
|
jbe@0
|
1492 "reference_lost" BOOLEAN;
|
jbe@0
|
1493 BEGIN
|
jbe@0
|
1494 IF TG_OP = 'DELETE' THEN
|
jbe@0
|
1495 "reference_lost" := TRUE;
|
jbe@0
|
1496 ELSE
|
jbe@0
|
1497 "reference_lost" := NEW."issue_id" != OLD."issue_id";
|
jbe@0
|
1498 END IF;
|
jbe@0
|
1499 IF
|
jbe@0
|
1500 "reference_lost" AND NOT EXISTS (
|
jbe@0
|
1501 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
|
jbe@0
|
1502 )
|
jbe@0
|
1503 THEN
|
jbe@0
|
1504 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
|
jbe@0
|
1505 END IF;
|
jbe@0
|
1506 RETURN NULL;
|
jbe@0
|
1507 END;
|
jbe@0
|
1508 $$;
|
jbe@0
|
1509
|
jbe@0
|
1510 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
|
jbe@0
|
1511 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
|
jbe@0
|
1512 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@0
|
1513 "last_initiative_deletes_issue_trigger"();
|
jbe@0
|
1514
|
jbe@0
|
1515 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
|
jbe@0
|
1516 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
|
jbe@0
|
1517
|
jbe@0
|
1518
|
jbe@0
|
1519 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
|
jbe@0
|
1520 RETURNS TRIGGER
|
jbe@0
|
1521 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1522 BEGIN
|
jbe@0
|
1523 IF NOT EXISTS (
|
jbe@0
|
1524 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
|
jbe@0
|
1525 ) THEN
|
jbe@463
|
1526 RAISE EXCEPTION 'Cannot create initiative without an initial draft.' USING
|
jbe@463
|
1527 ERRCODE = 'integrity_constraint_violation',
|
jbe@463
|
1528 HINT = 'Create issue, initiative and draft within the same transaction.';
|
jbe@0
|
1529 END IF;
|
jbe@0
|
1530 RETURN NULL;
|
jbe@0
|
1531 END;
|
jbe@0
|
1532 $$;
|
jbe@0
|
1533
|
jbe@0
|
1534 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
|
jbe@0
|
1535 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
|
jbe@0
|
1536 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@0
|
1537 "initiative_requires_first_draft_trigger"();
|
jbe@0
|
1538
|
jbe@0
|
1539 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
|
jbe@0
|
1540 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
|
jbe@0
|
1541
|
jbe@0
|
1542
|
jbe@0
|
1543 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
|
jbe@0
|
1544 RETURNS TRIGGER
|
jbe@0
|
1545 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1546 DECLARE
|
jbe@0
|
1547 "reference_lost" BOOLEAN;
|
jbe@0
|
1548 BEGIN
|
jbe@0
|
1549 IF TG_OP = 'DELETE' THEN
|
jbe@0
|
1550 "reference_lost" := TRUE;
|
jbe@0
|
1551 ELSE
|
jbe@0
|
1552 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
|
jbe@0
|
1553 END IF;
|
jbe@0
|
1554 IF
|
jbe@0
|
1555 "reference_lost" AND NOT EXISTS (
|
jbe@0
|
1556 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
|
jbe@0
|
1557 )
|
jbe@0
|
1558 THEN
|
jbe@0
|
1559 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
|
jbe@0
|
1560 END IF;
|
jbe@0
|
1561 RETURN NULL;
|
jbe@0
|
1562 END;
|
jbe@0
|
1563 $$;
|
jbe@0
|
1564
|
jbe@0
|
1565 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
|
jbe@0
|
1566 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
|
jbe@0
|
1567 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@0
|
1568 "last_draft_deletes_initiative_trigger"();
|
jbe@0
|
1569
|
jbe@0
|
1570 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
|
jbe@0
|
1571 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
|
jbe@0
|
1572
|
jbe@0
|
1573
|
jbe@0
|
1574 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
|
jbe@0
|
1575 RETURNS TRIGGER
|
jbe@0
|
1576 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1577 BEGIN
|
jbe@0
|
1578 IF NOT EXISTS (
|
jbe@0
|
1579 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
|
jbe@0
|
1580 ) THEN
|
jbe@463
|
1581 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING
|
jbe@463
|
1582 ERRCODE = 'integrity_constraint_violation',
|
jbe@463
|
1583 HINT = 'Create suggestion and opinion within the same transaction.';
|
jbe@0
|
1584 END IF;
|
jbe@0
|
1585 RETURN NULL;
|
jbe@0
|
1586 END;
|
jbe@0
|
1587 $$;
|
jbe@0
|
1588
|
jbe@0
|
1589 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
|
jbe@0
|
1590 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
|
jbe@0
|
1591 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@0
|
1592 "suggestion_requires_first_opinion_trigger"();
|
jbe@0
|
1593
|
jbe@0
|
1594 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
|
jbe@0
|
1595 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
|
jbe@0
|
1596
|
jbe@0
|
1597
|
jbe@0
|
1598 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
|
jbe@0
|
1599 RETURNS TRIGGER
|
jbe@0
|
1600 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1601 DECLARE
|
jbe@0
|
1602 "reference_lost" BOOLEAN;
|
jbe@0
|
1603 BEGIN
|
jbe@0
|
1604 IF TG_OP = 'DELETE' THEN
|
jbe@0
|
1605 "reference_lost" := TRUE;
|
jbe@0
|
1606 ELSE
|
jbe@0
|
1607 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
|
jbe@0
|
1608 END IF;
|
jbe@0
|
1609 IF
|
jbe@0
|
1610 "reference_lost" AND NOT EXISTS (
|
jbe@0
|
1611 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
|
jbe@0
|
1612 )
|
jbe@0
|
1613 THEN
|
jbe@0
|
1614 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
|
jbe@0
|
1615 END IF;
|
jbe@0
|
1616 RETURN NULL;
|
jbe@0
|
1617 END;
|
jbe@0
|
1618 $$;
|
jbe@0
|
1619
|
jbe@0
|
1620 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
|
jbe@0
|
1621 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
|
jbe@0
|
1622 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@0
|
1623 "last_opinion_deletes_suggestion_trigger"();
|
jbe@0
|
1624
|
jbe@0
|
1625 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
|
jbe@0
|
1626 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
|
jbe@0
|
1627
|
jbe@0
|
1628
|
jbe@284
|
1629 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
|
jbe@284
|
1630 RETURNS TRIGGER
|
jbe@284
|
1631 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@284
|
1632 BEGIN
|
jbe@284
|
1633 DELETE FROM "direct_voter"
|
jbe@284
|
1634 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
|
jbe@284
|
1635 RETURN NULL;
|
jbe@284
|
1636 END;
|
jbe@284
|
1637 $$;
|
jbe@284
|
1638
|
jbe@284
|
1639 CREATE TRIGGER "non_voter_deletes_direct_voter"
|
jbe@284
|
1640 AFTER INSERT OR UPDATE ON "non_voter"
|
jbe@284
|
1641 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@284
|
1642 "non_voter_deletes_direct_voter_trigger"();
|
jbe@284
|
1643
|
jbe@284
|
1644 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
|
jbe@284
|
1645 COMMENT ON TRIGGER "non_voter_deletes_direct_voter" ON "non_voter" IS 'An entry in the "non_voter" table deletes an entry in the "direct_voter" table (and vice versa due to trigger "direct_voter_deletes_non_voter" on table "direct_voter")';
|
jbe@284
|
1646
|
jbe@284
|
1647
|
jbe@284
|
1648 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
|
jbe@284
|
1649 RETURNS TRIGGER
|
jbe@284
|
1650 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@284
|
1651 BEGIN
|
jbe@284
|
1652 DELETE FROM "non_voter"
|
jbe@284
|
1653 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
|
jbe@284
|
1654 RETURN NULL;
|
jbe@284
|
1655 END;
|
jbe@284
|
1656 $$;
|
jbe@284
|
1657
|
jbe@284
|
1658 CREATE TRIGGER "direct_voter_deletes_non_voter"
|
jbe@284
|
1659 AFTER INSERT OR UPDATE ON "direct_voter"
|
jbe@284
|
1660 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@284
|
1661 "direct_voter_deletes_non_voter_trigger"();
|
jbe@284
|
1662
|
jbe@284
|
1663 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
|
jbe@284
|
1664 COMMENT ON TRIGGER "direct_voter_deletes_non_voter" ON "direct_voter" IS 'An entry in the "direct_voter" table deletes an entry in the "non_voter" table (and vice versa due to trigger "non_voter_deletes_direct_voter" on table "non_voter")';
|
jbe@284
|
1665
|
jbe@284
|
1666
|
jbe@285
|
1667 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
|
jbe@285
|
1668 RETURNS TRIGGER
|
jbe@285
|
1669 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@285
|
1670 BEGIN
|
jbe@285
|
1671 IF NEW."comment" ISNULL THEN
|
jbe@285
|
1672 NEW."comment_changed" := NULL;
|
jbe@285
|
1673 NEW."formatting_engine" := NULL;
|
jbe@285
|
1674 END IF;
|
jbe@285
|
1675 RETURN NEW;
|
jbe@285
|
1676 END;
|
jbe@285
|
1677 $$;
|
jbe@285
|
1678
|
jbe@285
|
1679 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
|
jbe@285
|
1680 BEFORE INSERT OR UPDATE ON "direct_voter"
|
jbe@285
|
1681 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@285
|
1682 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
|
jbe@285
|
1683
|
jbe@285
|
1684 COMMENT ON FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"() IS 'Implementation of trigger "voter_comment_fields_only_set_when_voter_comment_is_set" ON table "direct_voter"';
|
jbe@285
|
1685 COMMENT ON TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set" ON "direct_voter" IS 'If "comment" is set to NULL, then other comment related fields are also set to NULL.';
|
jbe@285
|
1686
|
jbe@0
|
1687
|
jbe@20
|
1688 ---------------------------------------------------------------
|
jbe@333
|
1689 -- Ensure that votes are not modified when issues are closed --
|
jbe@20
|
1690 ---------------------------------------------------------------
|
jbe@20
|
1691
|
jbe@20
|
1692 -- NOTE: Frontends should ensure this anyway, but in case of programming
|
jbe@20
|
1693 -- errors the following triggers ensure data integrity.
|
jbe@20
|
1694
|
jbe@20
|
1695
|
jbe@20
|
1696 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
|
jbe@20
|
1697 RETURNS TRIGGER
|
jbe@20
|
1698 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@20
|
1699 DECLARE
|
jbe@336
|
1700 "issue_id_v" "issue"."id"%TYPE;
|
jbe@336
|
1701 "issue_row" "issue"%ROWTYPE;
|
jbe@20
|
1702 BEGIN
|
jbe@383
|
1703 IF EXISTS (
|
jbe@385
|
1704 SELECT NULL FROM "temporary_transaction_data"
|
jbe@385
|
1705 WHERE "txid" = txid_current()
|
jbe@383
|
1706 AND "key" = 'override_protection_triggers'
|
jbe@383
|
1707 AND "value" = TRUE::TEXT
|
jbe@383
|
1708 ) THEN
|
jbe@383
|
1709 RETURN NULL;
|
jbe@383
|
1710 END IF;
|
jbe@32
|
1711 IF TG_OP = 'DELETE' THEN
|
jbe@32
|
1712 "issue_id_v" := OLD."issue_id";
|
jbe@32
|
1713 ELSE
|
jbe@32
|
1714 "issue_id_v" := NEW."issue_id";
|
jbe@32
|
1715 END IF;
|
jbe@20
|
1716 SELECT INTO "issue_row" * FROM "issue"
|
jbe@32
|
1717 WHERE "id" = "issue_id_v" FOR SHARE;
|
jbe@383
|
1718 IF (
|
jbe@383
|
1719 "issue_row"."closed" NOTNULL OR (
|
jbe@383
|
1720 "issue_row"."state" = 'voting' AND
|
jbe@383
|
1721 "issue_row"."phase_finished" NOTNULL
|
jbe@383
|
1722 )
|
jbe@383
|
1723 ) THEN
|
jbe@332
|
1724 IF
|
jbe@332
|
1725 TG_RELID = 'direct_voter'::regclass AND
|
jbe@332
|
1726 TG_OP = 'UPDATE'
|
jbe@332
|
1727 THEN
|
jbe@332
|
1728 IF
|
jbe@332
|
1729 OLD."issue_id" = NEW."issue_id" AND
|
jbe@332
|
1730 OLD."member_id" = NEW."member_id" AND
|
jbe@332
|
1731 OLD."weight" = NEW."weight"
|
jbe@332
|
1732 THEN
|
jbe@332
|
1733 RETURN NULL; -- allows changing of voter comment
|
jbe@332
|
1734 END IF;
|
jbe@332
|
1735 END IF;
|
jbe@463
|
1736 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
|
jbe@463
|
1737 ERRCODE = 'integrity_constraint_violation';
|
jbe@20
|
1738 END IF;
|
jbe@20
|
1739 RETURN NULL;
|
jbe@20
|
1740 END;
|
jbe@20
|
1741 $$;
|
jbe@20
|
1742
|
jbe@20
|
1743 CREATE TRIGGER "forbid_changes_on_closed_issue"
|
jbe@20
|
1744 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
|
jbe@20
|
1745 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@20
|
1746 "forbid_changes_on_closed_issue_trigger"();
|
jbe@20
|
1747
|
jbe@20
|
1748 CREATE TRIGGER "forbid_changes_on_closed_issue"
|
jbe@20
|
1749 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
|
jbe@20
|
1750 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@20
|
1751 "forbid_changes_on_closed_issue_trigger"();
|
jbe@20
|
1752
|
jbe@20
|
1753 CREATE TRIGGER "forbid_changes_on_closed_issue"
|
jbe@20
|
1754 AFTER INSERT OR UPDATE OR DELETE ON "vote"
|
jbe@20
|
1755 FOR EACH ROW EXECUTE PROCEDURE
|
jbe@20
|
1756 "forbid_changes_on_closed_issue_trigger"();
|
jbe@20
|
1757
|
jbe@20
|
1758 COMMENT ON FUNCTION "forbid_changes_on_closed_issue_trigger"() IS 'Implementation of triggers "forbid_changes_on_closed_issue" on tables "direct_voter", "delegating_voter" and "vote"';
|
jbe@20
|
1759 COMMENT ON TRIGGER "forbid_changes_on_closed_issue" ON "direct_voter" IS 'Ensures that frontends can''t tamper with votings of closed issues, in case of programming errors';
|
jbe@20
|
1760 COMMENT ON TRIGGER "forbid_changes_on_closed_issue" ON "delegating_voter" IS 'Ensures that frontends can''t tamper with votings of closed issues, in case of programming errors';
|
jbe@20
|
1761 COMMENT ON TRIGGER "forbid_changes_on_closed_issue" ON "vote" IS 'Ensures that frontends can''t tamper with votings of closed issues, in case of programming errors';
|
jbe@20
|
1762
|
jbe@20
|
1763
|
jbe@20
|
1764
|
jbe@0
|
1765 --------------------------------------------------------------------
|
jbe@0
|
1766 -- Auto-retrieval of fields only needed for referential integrity --
|
jbe@0
|
1767 --------------------------------------------------------------------
|
jbe@0
|
1768
|
jbe@20
|
1769
|
jbe@0
|
1770 CREATE FUNCTION "autofill_issue_id_trigger"()
|
jbe@0
|
1771 RETURNS TRIGGER
|
jbe@0
|
1772 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1773 BEGIN
|
jbe@0
|
1774 IF NEW."issue_id" ISNULL THEN
|
jbe@0
|
1775 SELECT "issue_id" INTO NEW."issue_id"
|
jbe@0
|
1776 FROM "initiative" WHERE "id" = NEW."initiative_id";
|
jbe@0
|
1777 END IF;
|
jbe@0
|
1778 RETURN NEW;
|
jbe@0
|
1779 END;
|
jbe@0
|
1780 $$;
|
jbe@0
|
1781
|
jbe@0
|
1782 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
|
jbe@0
|
1783 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
|
jbe@0
|
1784
|
jbe@0
|
1785 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
|
jbe@0
|
1786 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
|
jbe@0
|
1787
|
jbe@0
|
1788 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
|
jbe@0
|
1789 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
|
jbe@0
|
1790 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
|
jbe@0
|
1791
|
jbe@0
|
1792
|
jbe@0
|
1793 CREATE FUNCTION "autofill_initiative_id_trigger"()
|
jbe@0
|
1794 RETURNS TRIGGER
|
jbe@0
|
1795 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1796 BEGIN
|
jbe@0
|
1797 IF NEW."initiative_id" ISNULL THEN
|
jbe@0
|
1798 SELECT "initiative_id" INTO NEW."initiative_id"
|
jbe@0
|
1799 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
|
jbe@0
|
1800 END IF;
|
jbe@0
|
1801 RETURN NEW;
|
jbe@0
|
1802 END;
|
jbe@0
|
1803 $$;
|
jbe@0
|
1804
|
jbe@0
|
1805 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
|
jbe@0
|
1806 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
|
jbe@0
|
1807
|
jbe@0
|
1808 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
|
jbe@0
|
1809 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
|
jbe@0
|
1810
|
jbe@0
|
1811
|
jbe@0
|
1812
|
jbe@4
|
1813 -----------------------------------------------------
|
jbe@4
|
1814 -- Automatic calculation of certain default values --
|
jbe@4
|
1815 -----------------------------------------------------
|
jbe@0
|
1816
|
jbe@22
|
1817
|
jbe@22
|
1818 CREATE FUNCTION "copy_timings_trigger"()
|
jbe@22
|
1819 RETURNS TRIGGER
|
jbe@22
|
1820 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@22
|
1821 DECLARE
|
jbe@22
|
1822 "policy_row" "policy"%ROWTYPE;
|
jbe@22
|
1823 BEGIN
|
jbe@22
|
1824 SELECT * INTO "policy_row" FROM "policy"
|
jbe@22
|
1825 WHERE "id" = NEW."policy_id";
|
jbe@447
|
1826 IF NEW."min_admission_time" ISNULL THEN
|
jbe@447
|
1827 NEW."min_admission_time" := "policy_row"."min_admission_time";
|
jbe@447
|
1828 END IF;
|
jbe@447
|
1829 IF NEW."max_admission_time" ISNULL THEN
|
jbe@447
|
1830 NEW."max_admission_time" := "policy_row"."max_admission_time";
|
jbe@22
|
1831 END IF;
|
jbe@22
|
1832 IF NEW."discussion_time" ISNULL THEN
|
jbe@22
|
1833 NEW."discussion_time" := "policy_row"."discussion_time";
|
jbe@22
|
1834 END IF;
|
jbe@22
|
1835 IF NEW."verification_time" ISNULL THEN
|
jbe@22
|
1836 NEW."verification_time" := "policy_row"."verification_time";
|
jbe@22
|
1837 END IF;
|
jbe@22
|
1838 IF NEW."voting_time" ISNULL THEN
|
jbe@22
|
1839 NEW."voting_time" := "policy_row"."voting_time";
|
jbe@22
|
1840 END IF;
|
jbe@22
|
1841 RETURN NEW;
|
jbe@22
|
1842 END;
|
jbe@22
|
1843 $$;
|
jbe@22
|
1844
|
jbe@22
|
1845 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
|
jbe@22
|
1846 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
|
jbe@22
|
1847
|
jbe@22
|
1848 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
|
jbe@22
|
1849 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
|
jbe@22
|
1850
|
jbe@22
|
1851
|
jbe@160
|
1852 CREATE FUNCTION "default_for_draft_id_trigger"()
|
jbe@2
|
1853 RETURNS TRIGGER
|
jbe@2
|
1854 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@2
|
1855 BEGIN
|
jbe@2
|
1856 IF NEW."draft_id" ISNULL THEN
|
jbe@2
|
1857 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
|
jbe@2
|
1858 WHERE "initiative_id" = NEW."initiative_id";
|
jbe@2
|
1859 END IF;
|
jbe@2
|
1860 RETURN NEW;
|
jbe@2
|
1861 END;
|
jbe@2
|
1862 $$;
|
jbe@2
|
1863
|
jbe@160
|
1864 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
|
jbe@160
|
1865 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
|
jbe@2
|
1866 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
|
jbe@160
|
1867 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
|
jbe@160
|
1868
|
jbe@160
|
1869 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
|
jbe@160
|
1870 COMMENT ON TRIGGER "default_for_draft_id" ON "suggestion" IS 'If "draft_id" is NULL, then use the current draft of the initiative as default';
|
jbe@160
|
1871 COMMENT ON TRIGGER "default_for_draft_id" ON "supporter" IS 'If "draft_id" is NULL, then use the current draft of the initiative as default';
|
jbe@2
|
1872
|
jbe@2
|
1873
|
jbe@0
|
1874
|
jbe@0
|
1875 ----------------------------------------
|
jbe@0
|
1876 -- Automatic creation of dependencies --
|
jbe@0
|
1877 ----------------------------------------
|
jbe@0
|
1878
|
jbe@22
|
1879
|
jbe@0
|
1880 CREATE FUNCTION "autocreate_interest_trigger"()
|
jbe@0
|
1881 RETURNS TRIGGER
|
jbe@0
|
1882 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1883 BEGIN
|
jbe@0
|
1884 IF NOT EXISTS (
|
jbe@0
|
1885 SELECT NULL FROM "initiative" JOIN "interest"
|
jbe@0
|
1886 ON "initiative"."issue_id" = "interest"."issue_id"
|
jbe@0
|
1887 WHERE "initiative"."id" = NEW."initiative_id"
|
jbe@0
|
1888 AND "interest"."member_id" = NEW."member_id"
|
jbe@0
|
1889 ) THEN
|
jbe@0
|
1890 BEGIN
|
jbe@0
|
1891 INSERT INTO "interest" ("issue_id", "member_id")
|
jbe@0
|
1892 SELECT "issue_id", NEW."member_id"
|
jbe@0
|
1893 FROM "initiative" WHERE "id" = NEW."initiative_id";
|
jbe@0
|
1894 EXCEPTION WHEN unique_violation THEN END;
|
jbe@0
|
1895 END IF;
|
jbe@0
|
1896 RETURN NEW;
|
jbe@0
|
1897 END;
|
jbe@0
|
1898 $$;
|
jbe@0
|
1899
|
jbe@0
|
1900 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
|
jbe@0
|
1901 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
|
jbe@0
|
1902
|
jbe@0
|
1903 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
|
jbe@0
|
1904 COMMENT ON TRIGGER "autocreate_interest" ON "supporter" IS 'Supporting an initiative implies interest in the issue, thus automatically creates an entry in the "interest" table';
|
jbe@0
|
1905
|
jbe@0
|
1906
|
jbe@0
|
1907 CREATE FUNCTION "autocreate_supporter_trigger"()
|
jbe@0
|
1908 RETURNS TRIGGER
|
jbe@0
|
1909 LANGUAGE 'plpgsql' VOLATILE AS $$
|
jbe@0
|
1910 BEGIN
|
jbe@0
|
1911 IF NOT EXISTS (
|
jbe@0
|
1912 SELECT NULL FROM "suggestion" JOIN "supporter"
|
jbe@0
|
1913 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
|
jbe@0
|
1914 WHERE "suggestion"."id" = NEW."suggestion_id"
|
jbe@0
|
1915 AND "supporter"."member_id" = NEW."member_id"
|
jbe@0
|
1916 ) THEN
|
jbe@0
|
1917 BEGIN
|
jbe@0
|
1918 INSERT INTO "supporter" ("initiative_id", "member_id")
|
jbe@0
|
1919 SELECT "initiative_id", NEW."member_id"
|
jbe@0
|
1920 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
|
jbe@0
|
1921 EXCEPTION WHEN unique_violation THEN END;
|
jbe@0
|
1922 END IF;
|
jbe@0
|
1923 RETURN NEW;
|
jbe@0
|
1924 END;
|
jbe@0
|
1925 $$;
|
jbe@0
|
1926
|
jbe@0
|
1927 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
|
jbe@0
|
1928 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
|
jbe@0
|
1929
|
jbe@0
|
1930 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
|
jbe@0
|
1931 COMMENT ON TRIGGER "autocreate_supporter" ON "opinion" IS 'Opinions can only be added for supported initiatives. This trigger automatrically creates an entry in the "supporter" table, if not existent yet.';
|
jbe@0
|
1932
|
jbe@0
|
1933
|
jbe@0
|
1934
|
jbe@0
|
1935 ------------------------------------------
|
jbe@0
|
1936 -- Views and helper functions for views --
|
jbe@0
|
1937 ------------------------------------------
|
jbe@0
|
1938
|
jbe@5
|
1939
|
jbe@97
|
1940 CREATE VIEW "unit_delegation" AS
|
jbe@97
|
1941 SELECT
|
jbe@97
|
1942 "unit"."id" AS "unit_id",
|
jbe@97
|
1943 "delegation"."id",
|
jbe@97
|
1944 "delegation"."truster_id",
|
jbe@97
|
1945 "delegation"."trustee_id",
|
jbe@97
|
1946 "delegation"."scope"
|
jbe@97
|
1947 FROM "unit"
|
jbe@97
|
1948 JOIN "delegation"
|
jbe@97
|
1949 ON "delegation"."unit_id" = "unit"."id"
|
jbe@97
|
1950 JOIN "member"
|
jbe@97
|
1951 ON "delegation"."truster_id" = "member"."id"
|
jbe@97
|
1952 JOIN "privilege"
|
jbe@97
|
1953 ON "delegation"."unit_id" = "privilege"."unit_id"
|
jbe@97
|
1954 AND "delegation"."truster_id" = "privilege"."member_id"
|
jbe@97
|
1955 WHERE "member"."active" AND "privilege"."voting_right";
|
jbe@97
|
1956
|
jbe@97
|
1957 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
|
jbe@5
|
1958
|
jbe@5
|
1959
|
jbe@5
|
1960 CREATE VIEW "area_delegation" AS
|
jbe@70
|
1961 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
|
jbe@70
|
1962 "area"."id" AS "area_id",
|
jbe@70
|
1963 "delegation"."id",
|
jbe@70
|
1964 "delegation"."truster_id",
|
jbe@70
|
1965 "delegation"."trustee_id",
|
jbe@70
|
1966 "delegation"."scope"
|
jbe@97
|
1967 FROM "area"
|
jbe@97
|
1968 JOIN "delegation"
|
jbe@97
|
1969 ON "delegation"."unit_id" = "area"."unit_id"
|
jbe@97
|
1970 OR "delegation"."area_id" = "area"."id"
|
jbe@97
|
1971 JOIN "member"
|
jbe@97
|
1972 ON "delegation"."truster_id" = "member"."id"
|
jbe@97
|
1973 JOIN "privilege"
|
jbe@97
|
1974 ON "area"."unit_id" = "privilege"."unit_id"
|
jbe@97
|
1975 AND "delegation"."truster_id" = "privilege"."member_id"
|
jbe@97
|
1976 WHERE "member"."active" AND "privilege"."voting_right"
|
jbe@70
|
1977 ORDER BY
|
jbe@70
|
1978 "area"."id",
|
jbe@70
|
1979 "delegation"."truster_id",
|
jbe@70
|
1980 "delegation"."scope" DESC;
|
jbe@70
|
1981
|
jbe@97
|
1982 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
|
jbe@5
|
1983
|
jbe@5
|
1984
|
jbe@5
|
1985 CREATE VIEW "issue_delegation" AS
|
jbe@70
|
1986 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
|
jbe@70
|
1987 "issue"."id" AS "issue_id",
|
jbe@70
|
1988 "delegation"."id",
|
jbe@70
|
1989 "delegation"."truster_id",
|
jbe@70
|
1990 "delegation"."trustee_id",
|
jbe@70
|
1991 "delegation"."scope"
|
jbe@97
|
1992 FROM "issue"
|
jbe@97
|
1993 JOIN "area"
|
jbe@97
|
1994 ON "area"."id" = "issue"."area_id"
|
jbe@97
|
1995 JOIN "delegation"
|
jbe@97
|
1996 ON "delegation"."unit_id" = "area"."unit_id"
|
jbe@97
|
1997 OR "delegation"."area_id" = "area"."id"
|
jbe@97
|
1998 OR "delegation"."issue_id" = "issue"."id"
|
jbe@97
|
1999 JOIN "member"
|
jbe@97
|
2000 ON "delegation"."truster_id" = "member"."id"
|
jbe@97
|
2001 JOIN "privilege"
|
jbe@97
|
2002 ON "area"."unit_id" = "privilege"."unit_id"
|
jbe@97
|
2003 AND "delegation"."truster_id" = "privilege"."member_id"
|
jbe@97
|
2004 WHERE "member"."active" AND "privilege"."voting_right"
|
jbe@70
|
2005 ORDER BY
|
jbe@70
|
2006 "issue"."id",
|
jbe@70
|
2007 "delegation"."truster_id",
|
jbe@70
|
2008 "delegation"."scope" DESC;
|
jbe@70
|
2009
|
jbe@97
|
2010 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
|
jbe@5
|
2011
|
jbe@5
|
2012
|
jbe@5
|
2013 CREATE FUNCTION "membership_weight_with_skipping"
|
jbe@5
|
2014 ( "area_id_p" "area"."id"%TYPE,
|
jbe@5
|
2015 "member_id_p" "member"."id"%TYPE,
|
jbe@5
|
2016 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[]
|
jbe@5
|
2017 RETURNS INT4
|
jbe@5
|
2018 LANGUAGE 'plpgsql' STABLE AS $$
|
jbe@5
|
2019 DECLARE
|
jbe@5
|
2020 "sum_v" INT4;
|
jbe@5
|
2021 "delegation_row" "area_delegation"%ROWTYPE;
|
jbe@5
|
2022 BEGIN
|
jbe@5
|
2023 "sum_v" := 1;
|
jbe@5
|
2024 FOR "delegation_row" IN
|
jbe@5
|
2025 SELECT "area_delegation".*
|
jbe@5
|
2026 FROM "area_delegation" LEFT JOIN "membership"
|
jbe@5
|
2027 ON "membership"."area_id" = "area_id_p"
|
jbe@5
|
2028 AND "membership"."member_id" = "area_delegation"."truster_id"
|
jbe@5
|
2029 WHERE "area_delegation"."area_id" = "area_id_p"
|
jbe@5
|
2030 AND "area_delegation"."trustee_id" = "member_id_p"
|
jbe@5
|
2031 AND "membership"."member_id" ISNULL
|
jbe@5
|
2032 LOOP
|
jbe@5
|
2033 IF NOT
|
jbe@5
|
2034 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"]
|
jbe@5
|
2035 THEN
|
jbe@5
|
2036 "sum_v" := "sum_v" + "membership_weight_with_skipping"(
|
jbe@5
|
2037 "area_id_p",
|
jbe@5
|
2038 "delegation_row"."truster_id",
|
jbe@5
|
2039 "skip_member_ids_p" || "delegation_row"."truster_id"
|
jbe@5
|
2040 );
|
jbe@5
|
2041 END IF;
|
jbe@5
|
2042 END LOOP;
|
jbe@5
|
2043 RETURN "sum_v";
|
jbe@5
|
2044 END;
|
jbe@5
|
2045 $$;
|
jbe@5
|
2046
|
jbe@8
|
2047 COMMENT ON FUNCTION "membership_weight_with_skipping"
|
jbe@8
|
2048 ( "area"."id"%TYPE,
|
jbe@8
|
2049 "member"."id"%TYPE,
|
jbe@8
|
2050 INT4[] )
|
jbe@8
|
2051 IS 'Helper function for "membership_weight" function';
|
jbe@8
|
2052
|
jbe@8
|
2053
|
jbe@5
|
2054 CREATE FUNCTION "membership_weight"
|
jbe@5
|
2055 ( "area_id_p" "area"."id"%TYPE,
|
jbe@5
|
2056 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[]
|
jbe@5
|
2057 RETURNS INT4
|
jbe@5
|
2058 LANGUAGE 'plpgsql' STABLE AS $$
|
jbe@5
|
2059 BEGIN
|
jbe@5
|
2060 RETURN "membership_weight_with_skipping"(
|
jbe@5
|
2061 "area_id_p",
|
jbe@5
|
2062 "member_id_p",
|
jbe@5
|
2063 ARRAY["member_id_p"]
|
jbe@5
|
2064 );
|
jbe@5
|
2065 END;
|
jbe@5
|
2066 $$;
|
jbe@5
|
2067
|
jbe@8
|
2068 COMMENT ON FUNCTION "membership_weight"
|
jbe@8
|
2069 ( "area"."id"%TYPE,
|
jbe@8
|
2070 "member"."id"%TYPE )
|
jbe@8
|
2071 IS 'Calculates the potential voting weight of a member in a given area';
|
jbe@8
|
2072
|
jbe@5
|
2073
|
jbe@4
|
2074 CREATE VIEW "member_count_view" AS
|
jbe@5
|
2075 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
|
jbe@4
|
2076
|
jbe@4
|
2077 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
|
jbe@4
|
2078
|
jbe@4
|
2079
|
jbe@97
|
2080 CREATE VIEW "unit_member_count" AS
|
jbe@97
|
2081 SELECT
|
jbe@97
|
2082 "unit"."id" AS "unit_id",
|
jbe@248
|
2083 count("member"."id") AS "member_count"
|
jbe@97
|
2084 FROM "unit"
|
jbe@97
|
2085 LEFT JOIN "privilege"
|
jbe@97
|
2086 ON "privilege"."unit_id" = "unit"."id"
|
jbe@97
|
2087 AND "privilege"."voting_right"
|
jbe@97
|
2088 LEFT JOIN "member"
|
jbe@97
|
2089 ON "member"."id" = "privilege"."member_id"
|
jbe@97
|
2090 AND "member"."active"
|
jbe@97
|
2091 GROUP BY "unit"."id";
|
jbe@97
|
2092
|
jbe@97
|
2093 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
|
jbe@97
|
2094
|
jbe@97
|
2095
|
jbe@4
|
2096 CREATE VIEW "area_member_count" AS
|
jbe@5
|
2097 SELECT
|
jbe@5
|
2098 "area"."id" AS "area_id",
|
jbe@5
|
2099 count("member"."id") AS "direct_member_count",
|
jbe@5
|
2100 coalesce(
|
jbe@5
|
2101 sum(
|
jbe@5
|
2102 CASE WHEN "member"."id" NOTNULL THEN
|
jbe@5
|
2103 "membership_weight"("area"."id", "member"."id")
|
jbe@5
|
2104 ELSE 0 END
|
jbe@5
|
2105 )
|
jbe@169
|
2106 ) AS "member_weight"
|
jbe@4
|
2107 FROM "area"
|
jbe@4
|
2108 LEFT JOIN "membership"
|
jbe@4
|
2109 ON "area"."id" = "membership"."area_id"
|
jbe@97
|
2110 LEFT JOIN "privilege"
|
jbe@97
|
2111 ON "privilege"."unit_id" = "area"."unit_id"
|
jbe@97
|
2112 AND "privilege"."member_id" = "membership"."member_id"
|
jbe@97
|
2113 AND "privilege"."voting_right"
|
jbe@4
|
2114 LEFT JOIN "member"
|
jbe@97
|
2115 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here!
|
jbe@4
|
2116 AND "member"."active"
|
jbe@4
|
2117 GROUP BY "area"."id";
|
jbe@4
|
2118
|
jbe@169
|
2119 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
|
jbe@4
|
2120
|
jbe@4
|
2121
|
jbe@9
|
2122 CREATE VIEW "opening_draft" AS
|
jbe@9
|
2123 SELECT "draft".* FROM (
|
jbe@9
|
2124 SELECT
|
jbe@9
|
2125 "initiative"."id" AS "initiative_id",
|
jbe@9
|
2126 min("draft"."id") AS "draft_id"
|
jbe@9
|
2127 FROM "initiative" JOIN "draft"
|
jbe@9
|
2128 ON "initiative"."id" = "draft"."initiative_id"
|
jbe@9
|
2129 GROUP BY "initiative"."id"
|
jbe@9
|
2130 ) AS "subquery"
|
jbe@9
|
2131 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
|
jbe@9
|
2132
|
jbe@9
|
2133 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
|
jbe@9
|
2134
|
jbe@9
|
2135
|
jbe@0
|
2136 CREATE VIEW "current_draft" AS
|
jbe@0
|
2137 SELECT "draft".* FROM (
|
jbe@0
|
2138 SELECT
|
jbe@0
|
2139 "initiative"."id" AS "initiative_id",
|
jbe@0
|
2140 max("draft"."id") AS "draft_id"
|
jbe@0
|
2141 FROM "initiative" JOIN "draft"
|
jbe@0
|
2142 ON "initiative"."id" = "draft"."initiative_id"
|
jbe@0
|
2143 GROUP BY "initiative"."id"
|
jbe@0
|
2144 ) AS "subquery"
|
jbe@0
|
2145 JOIN "draft" ON "subquery"."draft_id" = "draft"."id";
|
jbe@0
|
2146
|
jbe@0
|
2147 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
|
jbe@0
|
2148
|
jbe@0
|
2149
|
jbe@0
|
2150 CREATE VIEW "critical_opinion" AS
|
jbe@0
|
2151 SELECT * FROM "opinion"
|
jbe@0
|
2152 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
|
jbe@0
|
2153 OR ("degree" = -2 AND "fulfilled" = TRUE);
|
jbe@0
|
2154
|
jbe@0
|
2155 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
|
jbe@0
|
2156
|
jbe@0
|
2157
|
jbe@392
|
2158 CREATE VIEW "issue_supporter_in_admission_state" AS
|
jbe@466
|
2159 SELECT DISTINCT -- TODO: DISTINCT needed?
|
jbe@410
|
2160 "area"."unit_id",
|
jbe@392
|
2161 "issue"."area_id",
|
jbe@392
|
2162 "issue"."id" AS "issue_id",
|
jbe@392
|
2163 "supporter"."member_id",
|
jbe@392
|
2164 "direct_interest_snapshot"."weight"
|
jbe@392
|
2165 FROM "issue"
|
jbe@410
|
2166 JOIN "area" ON "area"."id" = "issue"."area_id"
|
jbe@392
|
2167 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
|
jbe@392
|
2168 JOIN "direct_interest_snapshot"
|
jbe@392
|
2169 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
|
jbe@392
|
2170 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@392
|
2171 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
|
jbe@392
|
2172 WHERE "issue"."state" = 'admission'::"issue_state";
|
jbe@392
|
2173
|
jbe@392
|
2174 COMMENT ON VIEW "issue_supporter_in_admission_state" IS 'Helper view for "lf_update_issue_order" to allow a (proportional) ordering of issues within an area';
|
jbe@392
|
2175
|
jbe@392
|
2176
|
jbe@352
|
2177 CREATE VIEW "initiative_suggestion_order_calculation" AS
|
jbe@352
|
2178 SELECT
|
jbe@352
|
2179 "initiative"."id" AS "initiative_id",
|
jbe@352
|
2180 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
|
jbe@352
|
2181 FROM "initiative" JOIN "issue"
|
jbe@352
|
2182 ON "initiative"."issue_id" = "issue"."id"
|
jbe@352
|
2183 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
|
jbe@352
|
2184 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
|
jbe@352
|
2185
|
jbe@352
|
2186 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
|
jbe@352
|
2187
|
jbe@360
|
2188 COMMENT ON COLUMN "initiative_suggestion_order_calculation"."final" IS 'Set to TRUE, if the issue is fully frozen or closed, and the calculation has to be done only once for one last time';
|
jbe@352
|
2189
|
jbe@352
|
2190
|
jbe@352
|
2191 CREATE VIEW "individual_suggestion_ranking" AS
|
jbe@352
|
2192 SELECT
|
jbe@352
|
2193 "opinion"."initiative_id",
|
jbe@352
|
2194 "opinion"."member_id",
|
jbe@352
|
2195 "direct_interest_snapshot"."weight",
|
jbe@352
|
2196 CASE WHEN
|
jbe@352
|
2197 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
|
jbe@352
|
2198 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
|
jbe@352
|
2199 THEN 1 ELSE
|
jbe@352
|
2200 CASE WHEN
|
jbe@352
|
2201 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
|
jbe@352
|
2202 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
|
jbe@352
|
2203 THEN 2 ELSE
|
jbe@352
|
2204 CASE WHEN
|
jbe@352
|
2205 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
|
jbe@352
|
2206 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
|
jbe@352
|
2207 THEN 3 ELSE 4 END
|
jbe@352
|
2208 END
|
jbe@352
|
2209 END AS "preference",
|
jbe@352
|
2210 "opinion"."suggestion_id"
|
jbe@352
|
2211 FROM "opinion"
|
jbe@352
|
2212 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
|
jbe@352
|
2213 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
|
jbe@352
|
2214 JOIN "direct_interest_snapshot"
|
jbe@352
|
2215 ON "direct_interest_snapshot"."issue_id" = "issue"."id"
|
jbe@352
|
2216 AND "direct_interest_snapshot"."event" = "issue"."latest_snapshot_event"
|
jbe@352
|
2217 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
|
jbe@352
|
2218
|
jbe@352
|
2219 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
|
jbe@352
|
2220
|
jbe@352
|
2221
|
jbe@126
|
2222 CREATE VIEW "battle_participant" AS
|
jbe@126
|
2223 SELECT "initiative"."id", "initiative"."issue_id"
|
jbe@126
|
2224 FROM "issue" JOIN "initiative"
|
jbe@126
|
2225 ON "issue"."id" = "initiative"."issue_id"
|
jbe@126
|
2226 WHERE "initiative"."admitted"
|
jbe@126
|
2227 UNION ALL
|
jbe@126
|
2228 SELECT NULL, "id" AS "issue_id"
|
jbe@126
|
2229 FROM "issue";
|
jbe@126
|
2230
|
jbe@126
|
2231 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
|
jbe@126
|
2232
|
jbe@126
|
2233
|
jbe@61
|
2234 CREATE VIEW "battle_view" AS
|
jbe@0
|
2235 SELECT
|
jbe@0
|
2236 "issue"."id" AS "issue_id",
|
jbe@10
|
2237 "winning_initiative"."id" AS "winning_initiative_id",
|
jbe@10
|
2238 "losing_initiative"."id" AS "losing_initiative_id",
|
jbe@0
|
2239 sum(
|
jbe@0
|
2240 CASE WHEN
|
jbe@0
|
2241 coalesce("better_vote"."grade", 0) >
|
jbe@0
|
2242 coalesce("worse_vote"."grade", 0)
|
jbe@0
|
2243 THEN "direct_voter"."weight" ELSE 0 END
|
jbe@0
|
2244 ) AS "count"
|
jbe@0
|
2245 FROM "issue"
|
jbe@0
|
2246 LEFT JOIN "direct_voter"
|
jbe@0
|
2247 ON "issue"."id" = "direct_voter"."issue_id"
|
jbe@126
|
2248 JOIN "battle_participant" AS "winning_initiative"
|
jbe@10
|
2249 ON "issue"."id" = "winning_initiative"."issue_id"
|
jbe@126
|
2250 JOIN "battle_participant" AS "losing_initiative"
|
jbe@10
|
2251 ON "issue"."id" = "losing_initiative"."issue_id"
|
jbe@0
|
2252 LEFT JOIN "vote" AS "better_vote"
|
jbe@10
|
2253 ON "direct_voter"."member_id" = "better_vote"."member_id"
|
jbe@10
|
2254 AND "winning_initiative"."id" = "better_vote"."initiative_id"
|
jbe@0
|
2255 LEFT JOIN "vote" AS "worse_vote"
|
jbe@10
|
2256 ON "direct_voter"."member_id" = "worse_vote"."member_id"
|
jbe@10
|
2257 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
|
jbe@328
|
2258 WHERE "issue"."state" = 'voting'
|
jbe@328
|
2259 AND "issue"."phase_finished" NOTNULL
|
jbe@126
|
2260 AND (
|
jbe@126
|
2261 "winning_initiative"."id" != "losing_initiative"."id" OR
|
jbe@126
|
2262 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
|
jbe@126
|
2263 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
|
jbe@0
|
2264 GROUP BY
|
jbe@0
|
2265 "issue"."id",
|
jbe@10
|
2266 "winning_initiative"."id",
|
jbe@10
|
2267 "losing_initiative"."id";
|
jbe@0
|
2268
|
jbe@126
|
2269 COMMENT ON VIEW "battle_view" IS 'Number of members preferring one initiative (or status-quo) to another initiative (or status-quo); Used to fill "battle" table';
|
jbe@1
|
2270
|
jbe@1
|
2271
|
jbe@235
|
2272 CREATE VIEW "expired_session" AS
|
jbe@235
|
2273 SELECT * FROM "session" WHERE now() > "expiry";
|
jbe@235
|
2274
|
jbe@235
|
2275 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
|
jbe@235
|
2276 DELETE FROM "session" WHERE "ident" = OLD."ident";
|
jbe@235
|
2277
|
jbe@235
|
2278 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
|
jbe@235
|
2279 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
|
jbe@235
|
2280
|
jbe@235
|
2281
|
jbe@0
|
2282 CREATE VIEW "open_issue" AS
|
jbe@0
|
2283 SELECT * FROM "issue" WHERE "closed" ISNULL;
|
jbe@0
|
2284
|
jbe@0
|
2285 COMMENT ON VIEW "open_issue" IS 'All open issues';
|
jbe@0
|
2286
|
jbe@0
|
2287
|
jbe@9
|
2288 CREATE VIEW "member_contingent" AS
|
jbe@9
|
2289 SELECT
|
jbe@9
|
2290 "member"."id" AS "member_id",
|
jbe@293
|
2291 "contingent"."polling",
|
jbe@9
|
2292 "contingent"."time_frame",
|
jbe@9
|
2293 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
|
jbe@9
|
2294 (
|
jbe@9
|
2295 SELECT count(1) FROM "draft"
|
jbe@293
|
2296 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
|
jbe@9
|
2297 WHERE "draft"."author_id" = "member"."id"
|
jbe@293
|
2298 AND "initiative"."polling" = "contingent"."polling"
|
jbe@9
|
2299 AND "draft"."created" > now() - "contingent"."time_frame"
|
jbe@9
|
2300 ) + (
|
jbe@9
|
2301 SELECT count(1) FROM "suggestion"
|
jbe@293
|
2302 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
|
jbe@9
|
2303 WHERE "suggestion"."author_id" = "member"."id"
|
jbe@293
|
2304 AND "contingent"."polling" = FALSE
|
jbe@9
|
2305 AND "suggestion"."created" > now() - "contingent"."time_frame"
|
jbe@9
|
2306 )
|
jbe@9
|
2307 ELSE NULL END AS "text_entry_count",
|
jbe@9
|
2308 "contingent"."text_entry_limit",
|
jbe@9
|
2309 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
|
jbe@293
|
2310 SELECT count(1) FROM "opening_draft" AS "draft"
|
jbe@293
|
2311 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
|
jbe@293
|
2312 WHERE "draft"."author_id" = "member"."id"
|
jbe@293
|
2313 AND "initiative"."polling" = "contingent"."polling"
|
jbe@293
|
2314 AND "draft"."created" > now() - "contingent"."time_frame"
|
jbe@9
|
2315 ) ELSE NULL END AS "initiative_count",
|
jbe@9
|
2316 "contingent"."initiative_limit"
|
jbe@9
|
2317 FROM "member" CROSS JOIN "contingent";
|
jbe@9
|
2318
|
jbe@9
|
2319 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
|
jbe@9
|
2320
|
jbe@9
|
2321 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
|
jbe@9
|
2322 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
|
jbe@9
|
2323
|
jbe@9
|
2324
|
jbe@9
|
2325 CREATE VIEW "member_contingent_left" AS
|
jbe@9
|
2326 SELECT
|
jbe@9
|
2327 "member_id",
|
jbe@293
|
2328 "polling",
|
jbe@9
|
2329 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
|
jbe@9
|
2330 max("initiative_limit" - "initiative_count") AS "initiatives_left"
|
jbe@293
|
2331 FROM "member_contingent" GROUP BY "member_id", "polling";
|
jbe@9
|
2332
|
jbe@9
|
2333 COMMENT ON VIEW "member_contingent_left" IS 'Amount of text entries or initiatives which can be posted now instantly by a member. This view should be used by a frontend to determine, if the contingent for posting is exhausted.';
|
jbe@9
|
2334
|
jbe@9
|
2335
|
jbe@499
|
2336 CREATE VIEW "event_for_notification" AS
|
jbe@113
|
2337 SELECT
|
jbe@499
|
2338 "member"."id" AS "recipient_id",
|
jbe@113
|
2339 "event".*
|
jbe@113
|
2340 FROM "member" CROSS JOIN "event"
|
jbe@499
|
2341 JOIN "issue" ON "issue"."id" = "event"."issue_id"
|
jbe@499
|
2342 JOIN "area" ON "area"."id" = "issue"."area_id"
|
jbe@499
|
2343 LEFT JOIN "privilege" ON
|
jbe@499
|
2344 "privilege"."member_id" = "member"."id" AND
|
jbe@499
|
2345 "privilege"."unit_id" = "area"."unit_id" AND
|
jbe@499
|
2346 "privilege"."voting_right" = TRUE
|
jbe@499
|
2347 LEFT JOIN "subscription" ON
|
jbe@499
|
2348 "subscription"."member_id" = "member"."id" AND
|
jbe@499
|
2349 "subscription"."unit_id" = "area"."unit_id"
|
jbe@499
|
2350 LEFT JOIN "ignored_area" ON
|
jbe@499
|
2351 "ignored_area"."member_id" = "member"."id" AND
|
jbe@499
|
2352 "ignored_area"."area_id" = "issue"."area_id"
|
jbe@499
|
2353 LEFT JOIN "interest" ON
|
jbe@499
|
2354 "interest"."member_id" = "member"."id" AND
|
jbe@499
|
2355 "interest"."issue_id" = "event"."issue_id"
|
jbe@499
|
2356 LEFT JOIN "supporter" ON
|
jbe@499
|
2357 "supporter"."member_id" = "member"."id" AND
|
jbe@499
|
2358 "supporter"."initiative_id" = "event"."initiative_id"
|
jbe@499
|
2359 WHERE ("privilege"."member_id" NOTNULL OR "subscription"."member_id" NOTNULL)
|
jbe@499
|
2360 AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
|
jbe@499
|
2361 AND (
|
jbe@499
|
2362 "event"."event" = 'issue_state_changed'::"event_type" OR
|
jbe@499
|
2363 ( "event"."event" = 'initiative_revoked'::"event_type" AND
|
jbe@499
|
2364 "supporter"."member_id" NOTNULL ) );
|
jbe@499
|
2365
|
jbe@499
|
2366 COMMENT ON VIEW "event_for_notification" IS 'TODO: documentation';
|
jbe@222
|
2367
|
jbe@222
|
2368
|
jbe@473
|
2369 CREATE VIEW "updated_initiative" AS
|
jbe@473
|
2370 SELECT
|
jbe@499
|
2371 "supporter"."member_id" AS "recipient_id",
|
jbe@477
|
2372 FALSE AS "featured",
|
jbe@499
|
2373 "supporter"."initiative_id"
|
jbe@499
|
2374 FROM "supporter"
|
jbe@499
|
2375 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
|
jbe@473
|
2376 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
|
jbe@499
|
2377 LEFT JOIN "initiative_notification_sent" AS "sent" ON
|
jbe@499
|
2378 "sent"."member_id" = "supporter"."member_id" AND
|
jbe@499
|
2379 "sent"."initiative_id" = "supporter"."initiative_id"
|
jbe@499
|
2380 LEFT JOIN "ignored_initiative" ON
|
jbe@499
|
2381 "ignored_initiative"."member_id" = "supporter"."member_id" AND
|
jbe@499
|
2382 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
|
jbe@480
|
2383 WHERE "issue"."state" IN ('admission', 'discussion')
|
jbe@499
|
2384 AND "ignored_initiative"."member_id" ISNULL
|
jbe@473
|
2385 AND (
|
jbe@473
|
2386 EXISTS (
|
jbe@473
|
2387 SELECT NULL FROM "draft"
|
jbe@499
|
2388 LEFT JOIN "ignored_member" ON
|
jbe@499
|
2389 "ignored_member"."member_id" = "supporter"."member_id" AND
|
jbe@499
|
2390 "ignored_member"."other_member_id" = "draft"."author_id"
|
jbe@499
|
2391 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
|
jbe@473
|
2392 AND "draft"."id" > "supporter"."draft_id"
|
jbe@499
|
2393 AND "ignored_member"."member_id" ISNULL
|
jbe@473
|
2394 ) OR EXISTS (
|
jbe@473
|
2395 SELECT NULL FROM "suggestion"
|
jbe@487
|
2396 LEFT JOIN "opinion" ON
|
jbe@487
|
2397 "opinion"."member_id" = "supporter"."member_id" AND
|
jbe@487
|
2398 "opinion"."suggestion_id" = "suggestion"."id"
|
jbe@499
|
2399 LEFT JOIN "ignored_member" ON
|
jbe@499
|
2400 "ignored_member"."member_id" = "supporter"."member_id" AND
|
jbe@499
|
2401 "ignored_member"."other_member_id" = "suggestion"."author_id"
|
jbe@499
|
2402 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
|
jbe@487
|
2403 AND "opinion"."member_id" ISNULL
|
jbe@499
|
2404 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
|
jbe@499
|
2405 AND "ignored_member"."member_id" ISNULL
|
jbe@473
|
2406 )
|
jbe@473
|
2407 );
|
jbe@473
|
2408
|
jbe@474
|
2409 CREATE FUNCTION "featured_initiative"
|
jbe@499
|
2410 ( "recipient_id_p" "member"."id"%TYPE,
|
jbe@499
|
2411 "area_id_p" "area"."id"%TYPE )
|
jbe@499
|
2412 RETURNS SETOF "initiative"."id"%TYPE
|
jbe@474
|
2413 LANGUAGE 'plpgsql' STABLE AS $$
|
jbe@474
|
2414 DECLARE
|
jbe@499
|
2415 "counter_v" "member"."notification_counter"%TYPE;
|
jbe@499
|
2416 "sample_size_v" "member"."notification_sample_size"%TYPE;
|
jbe@499
|
2417 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
|
jbe@499
|
2418 "match_v" BOOLEAN;
|
jbe@474
|
2419 "member_id_v" "member"."id"%TYPE;
|
jbe@474
|
2420 "seed_v" TEXT;
|
jbe@499
|
2421 "initiative_id_v" "initiative"."id"%TYPE;
|
jbe@474
|
2422 BEGIN
|
jbe@499
|
2423 SELECT "notification_counter", "notification_sample_size"
|
jbe@499
|
2424 INTO "counter_v", "sample_size_v"
|
jbe@499
|
2425 FROM "member" WHERE "id" = "recipient_id_p";
|
jbe@474
|
2426 "initiative_id_ary" := '{}';
|
jbe@474
|
2427 LOOP
|
jbe@474
|
2428 "match_v" := FALSE;
|
jbe@474
|
2429 FOR "member_id_v", "seed_v" IN
|
jbe@474
|
2430 SELECT * FROM (
|
jbe@474
|
2431 SELECT DISTINCT
|
jbe@474
|
2432 "supporter"."member_id",
|
jbe@499
|
2433 md5(
|
jbe@499
|
2434 "recipient_id_p" || '-' ||
|
jbe@499
|
2435 "counter_v" || '-' ||
|
jbe@499
|
2436 "area_id_p" || '-' ||
|
jbe@499
|
2437 "supporter"."member_id"
|
jbe@499
|
2438 ) AS "seed"
|
jbe@474
|
2439 FROM "supporter"
|
jbe@474
|
2440 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
|
jbe@474
|
2441 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
|
jbe@499
|
2442 WHERE "supporter"."member_id" != "recipient_id_p"
|
jbe@474
|
2443 AND "issue"."area_id" = "area_id_p"
|
jbe@474
|
2444 AND "issue"."state" IN ('admission', 'discussion', 'verification')
|
jbe@474
|
2445 ) AS "subquery"
|
jbe@474
|
2446 ORDER BY "seed"
|
jbe@474
|
2447 LOOP
|
jbe@499
|
2448 SELECT "initiative"."id" INTO "initiative_id_v"
|
jbe@476
|
2449 FROM "initiative"
|
jbe@474
|
2450 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
|
jbe@499
|
2451 JOIN "area" ON "area"."id" = "issue"."area_id"
|
jbe@474
|
2452 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
|
jbe@474
|
2453 LEFT JOIN "supporter" AS "self_support" ON
|
jbe@474
|
2454 "self_support"."initiative_id" = "initiative"."id" AND
|
jbe@499
|
2455 "self_support"."member_id" = "recipient_id_p"
|
jbe@499
|
2456 LEFT JOIN "privilege" ON
|
jbe@499
|
2457 "privilege"."member_id" = "recipient_id_p" AND
|
jbe@499
|
2458 "privilege"."unit_id" = "area"."unit_id" AND
|
jbe@499
|
2459 "privilege"."voting_right" = TRUE
|
jbe@499
|
2460 LEFT JOIN "subscription" ON
|
jbe@499
|
2461 "subscription"."member_id" = "recipient_id_p" AND
|
jbe@499
|
2462 "subscription"."unit_id" = "area"."unit_id"
|
jbe@499
|
2463 LEFT JOIN "ignored_initiative" ON
|
jbe@499
|
2464 "ignored_initiative"."member_id" = "recipient_id_p" AND
|
jbe@499
|
2465 "ignored_initiative"."initiative_id" = "initiative"."id"
|
jbe@474
|
2466 WHERE "supporter"."member_id" = "member_id_v"
|
jbe@474
|
2467 AND "issue"."area_id" = "area_id_p"
|
jbe@474
|
2468 AND "issue"."state" IN ('admission', 'discussion', 'verification')
|
jbe@474
|
2469 AND "self_support"."member_id" ISNULL
|
jbe@476
|
2470 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
|
jbe@499
|
2471 AND (
|
jbe@499
|
2472 "privilege"."member_id" NOTNULL OR
|
jbe@499
|
2473 "subscription"."member_id" NOTNULL )
|
jbe@499
|
2474 AND "ignored_initiative"."member_id" ISNULL
|
jbe@499
|
2475 AND NOT EXISTS (
|
jbe@499
|
2476 SELECT NULL FROM "draft"
|
jbe@499
|
2477 JOIN "ignored_member" ON
|
jbe@499
|
2478 "ignored_member"."member_id" = "recipient_id_p" AND
|
jbe@499
|
2479 "ignored_member"."other_member_id" = "draft"."author_id"
|
jbe@499
|
2480 WHERE "draft"."initiative_id" = "initiative"."id"
|
jbe@499
|
2481 )
|
jbe@474
|
2482 ORDER BY md5("seed_v" || '-' || "initiative"."id")
|
jbe@476
|
2483 LIMIT 1;
|
jbe@476
|
2484 IF FOUND THEN
|
jbe@476
|
2485 "match_v" := TRUE;
|
jbe@499
|
2486 RETURN NEXT "initiative_id_v";
|
jbe@499
|
2487 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
|
jbe@476
|
2488 RETURN;
|
jbe@474
|
2489 END IF;
|
jbe@499
|
2490 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
|
jbe@476
|
2491 END IF;
|
jbe@474
|
2492 END LOOP;
|
jbe@474
|
2493 EXIT WHEN NOT "match_v";
|
jbe@474
|
2494 END LOOP;
|
jbe@474
|
2495 RETURN;
|
jbe@474
|
2496 END;
|
jbe@474
|
2497 $$;
|
jbe@474
|
2498
|
jbe@474
|
2499 CREATE VIEW "updated_or_featured_initiative" AS
|
jbe@474
|
2500 SELECT
|
jbe@499
|
2501 "subquery".*,
|
jbe@477
|
2502 NOT EXISTS (
|
jbe@477
|
2503 SELECT NULL FROM "initiative" AS "better_initiative"
|
jbe@499
|
2504 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
|
jbe@484
|
2505 AND
|
jbe@484
|
2506 ( COALESCE("better_initiative"."harmonic_weight", -1),
|
jbe@484
|
2507 -"better_initiative"."id" ) >
|
jbe@484
|
2508 ( COALESCE("initiative"."harmonic_weight", -1),
|
jbe@485
|
2509 -"initiative"."id" )
|
jbe@499
|
2510 ) AS "leading"
|
jbe@499
|
2511 FROM (
|
jbe@499
|
2512 SELECT * FROM "updated_initiative"
|
jbe@499
|
2513 UNION ALL
|
jbe@499
|
2514 SELECT
|
jbe@499
|
2515 "member"."id" AS "recipient_id",
|
jbe@499
|
2516 TRUE AS "featured",
|
jbe@499
|
2517 "featured_initiative_id" AS "initiative_id"
|
jbe@499
|
2518 FROM "member" CROSS JOIN "area"
|
jbe@499
|
2519 CROSS JOIN LATERAL
|
jbe@499
|
2520 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
|
jbe@499
|
2521 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
|
jbe@499
|
2522 ) AS "subquery"
|
jbe@499
|
2523 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
|
jbe@474
|
2524
|
jbe@474
|
2525 CREATE VIEW "leading_complement_initiative" AS
|
jbe@477
|
2526 SELECT * FROM (
|
jbe@499
|
2527 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
|
jbe@499
|
2528 "uf_initiative"."recipient_id",
|
jbe@477
|
2529 FALSE AS "featured",
|
jbe@499
|
2530 "uf_initiative"."initiative_id",
|
jbe@499
|
2531 TRUE AS "leading"
|
jbe@489
|
2532 FROM "updated_or_featured_initiative" AS "uf_initiative"
|
jbe@499
|
2533 JOIN "initiative" AS "uf_initiative_full" ON
|
jbe@499
|
2534 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
|
jbe@489
|
2535 JOIN "initiative" ON
|
jbe@499
|
2536 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
|
jbe@477
|
2537 ORDER BY
|
jbe@499
|
2538 "uf_initiative"."recipient_id",
|
jbe@477
|
2539 "initiative"."issue_id",
|
jbe@477
|
2540 "initiative"."harmonic_weight" DESC,
|
jbe@477
|
2541 "initiative"."id"
|
jbe@477
|
2542 ) AS "subquery"
|
jbe@477
|
2543 WHERE NOT EXISTS (
|
jbe@477
|
2544 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
|
jbe@499
|
2545 WHERE "other"."recipient_id" = "subquery"."recipient_id"
|
jbe@499
|
2546 AND "other"."initiative_id" = "subquery"."initiative_id"
|
jbe@477
|
2547 );
|
jbe@474
|
2548
|
jbe@490
|
2549 CREATE VIEW "unfiltered_initiative_for_notification" AS
|
jbe@499
|
2550 SELECT
|
jbe@499
|
2551 "subquery".*,
|
jbe@499
|
2552 "supporter"."member_id" NOTNULL AS "supported",
|
jbe@499
|
2553 CASE WHEN "supporter"."member_id" NOTNULL THEN
|
jbe@499
|
2554 EXISTS (
|
jbe@499
|
2555 SELECT NULL FROM "draft"
|
jbe@499
|
2556 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
|
jbe@499
|
2557 AND "draft"."id" > "supporter"."draft_id"
|
jbe@499
|
2558 )
|
jbe@499
|
2559 ELSE
|
jbe@499
|
2560 EXISTS (
|
jbe@499
|
2561 SELECT NULL FROM "draft"
|
jbe@499
|
2562 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
|
jbe@499
|
2563 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
|
jbe@499
|
2564 )
|
jbe@499
|
2565 END AS "new_draft",
|
jbe@499
|
2566 CASE WHEN "supporter"."member_id" NOTNULL THEN
|
jbe@499
|
2567 ( SELECT count(1) FROM "suggestion"
|
jbe@499
|
2568 LEFT JOIN "opinion" ON
|
jbe@499
|
2569 "opinion"."member_id" = "supporter"."member_id" AND
|
jbe@499
|
2570 "opinion"."suggestion_id" = "suggestion"."id"
|
jbe@499
|
2571 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
|
jbe@499
|
2572 AND "opinion"."member_id" ISNULL
|
jbe@499
|
2573 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
|
jbe@499
|
2574 )
|
jbe@499
|
2575 ELSE
|
jbe@499
|
2576 ( SELECT count(1) FROM "suggestion"
|
jbe@499
|
2577 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
|
jbe@499
|
2578 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
|
jbe@499
|
2579 )
|
jbe@499
|
2580 END AS "new_suggestion_count"
|
jbe@499
|
2581 FROM (
|
jbe@499
|
2582 SELECT * FROM "updated_or_featured_initiative"
|
jbe@499
|
2583 UNION ALL
|
jbe@499
|
2584 SELECT * FROM "leading_complement_initiative"
|
jbe@499
|
2585 ) AS "subquery"
|
jbe@499
|
2586 LEFT JOIN "supporter" ON
|
jbe@499
|
2587 "supporter"."member_id" = "subquery"."recipient_id" AND
|
jbe@499
|
2588 "supporter"."initiative_id" = "subquery"."initiative_id"
|
jbe@499
|
2589 LEFT JOIN "initiative_notification_sent" AS "sent" ON
|
jbe@499
|
2590 "sent"."member_id" = "subquery"."recipient_id" AND
|
jbe@499
|
2591 "sent"."initiative_id" = "subquery"."initiative_id";
|
jbe@474
|
2592
|
jbe@490
|
2593 CREATE VIEW "initiative_for_notification" AS
|
jbe@499
|
2594 SELECT "unfiltered1".*
|
jbe@499
|
2595 FROM "unfiltered_initiative_for_notification" "unfiltered1"
|
jbe@499
|
2596 JOIN "initiative" AS "initiative1" ON
|
jbe@499
|
2597 "initiative1"."id" = "unfiltered1"."initiative_id"
|
jbe@499
|
2598 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
|
jbe@490
|
2599 WHERE EXISTS (
|
jbe@490
|
2600 SELECT NULL
|
jbe@499
|
2601 FROM "unfiltered_initiative_for_notification" "unfiltered2"
|
jbe@499
|
2602 JOIN "initiative" AS "initiative2" ON
|
jbe@499
|
2603 "initiative2"."id" = "unfiltered2"."initiative_id"
|
jbe@499
|
2604 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
|
jbe@499
|
2605 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
|
jbe@490
|
2606 AND "issue1"."area_id" = "issue2"."area_id"
|
jbe@499
|
2607 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
|
jbe@490
|
2608 );
|
jbe@490
|
2609
|
jbe@497
|
2610 CREATE VIEW "newsletter_to_send" AS
|
jbe@497
|
2611 SELECT
|
jbe@499
|
2612 "member"."id" AS "recipient_id",
|
jbe@499
|
2613 "newsletter"."id" AS "newsletter_id"
|
jbe@497
|
2614 FROM "newsletter" CROSS JOIN "member"
|
jbe@497
|
2615 LEFT JOIN "privilege" ON
|
jbe@497
|
2616 "privilege"."member_id" = "member"."id" AND
|
jbe@497
|
2617 "privilege"."unit_id" = "newsletter"."unit_id" AND
|
jbe@497
|
2618 "privilege"."voting_right" = TRUE
|
jbe@497
|
2619 LEFT JOIN "subscription" ON
|
jbe@497
|
2620 "subscription"."member_id" = "member"."id" AND
|
jbe@497
|
2621 "subscription"."unit_id" = "newsletter"."unit_id"
|
jbe@498
|
2622 WHERE "newsletter"."published" <= now()
|
jbe@497
|
2623 AND "newsletter"."sent" ISNULL
|
jbe@497
|
2624 AND "member"."locked" = FALSE
|
jbe@497
|
2625 AND (
|
jbe@497
|
2626 "member"."disable_notifications" = FALSE OR
|
jbe@497
|
2627 "newsletter"."include_all_members" = TRUE )
|
jbe@497
|
2628 AND (
|
jbe@497
|
2629 "newsletter"."unit_id" ISNULL OR
|
jbe@497
|
2630 "privilege"."member_id" NOTNULL OR
|
jbe@497
|
2631 "subscription"."member_id" NOTNULL );
|
jbe@497
|
2632
|
jbe@473
|
2633
|
jbe@0
|
2634
|
jbe@242
|
2635 ------------------------------------------------------
|
jbe@242
|
2636 -- Row set returning function for delegation chains --
|
jbe@242
|
2637 ------------------------------------------------------
|
jbe@5
|
2638
|
jbe@5
|
2639
|
jbe@5
|
2640 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
|
jbe@5
|
2641 ('first', 'intermediate', 'last', 'repetition');
|
jbe@5
|
2642
|
jbe@5
|
2643 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
|
jbe@5
|
2644
|
jbe@5
|
2645
|
jbe@5
|
2646 CREATE TYPE "delegation_chain_row" AS (
|
jbe@5
|
2647 "index" INT4,
|
jbe@5
|
2648 "member_id" INT4,
|
jbe@97
|
2649 "member_valid" BOOLEAN,
|
jbe@5
|
2650 "participation" BOOLEAN,
|
jbe@5
|
2651 "overridden" BOOLEAN,
|
jbe@5
|
2652 "scope_in" "delegation_scope",
|
jbe@5
|
2653 "scope_out" "delegation_scope",
|
jbe@86
|
2654 "disabled_out" BOOLEAN,
|
jbe@5
|
2655 "loop" "delegation_chain_loop_tag" );
|
jbe@5
|
2656
|
jbe@243
|
2657 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
|
jbe@5
|
2658
|
jbe@5
|
2659 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
|
jbe@5
|
2660 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest, for areas: membership, for global delegation chains: always null';
|
jbe@5
|
2661 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
|
jbe@5
|
2662 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
|
jbe@5
|
2663 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
|
jbe@86
|
2664 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
|
jbe@5
|
2665 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
|
jbe@5
|
2666
|
jbe@5
|
2667
|
jbe@242
|
2668 CREATE FUNCTION "delegation_chain_for_closed_issue"
|
jbe@242
|
2669 ( "member_id_p" "member"."id"%TYPE,
|
jbe@242
|
2670 "issue_id_p" "issue"."id"%TYPE )
|
jbe@242
|
2671 RETURNS SETOF "delegation_chain_row"
|
jbe@242
|
2672 LANGUAGE 'plpgsql' STABLE AS $$
|
jbe@242
|
2673 DECLARE
|
jbe@242
|
2674 "output_row" "delegation_chain_row";
|
jbe@242
|
2675 "direct_voter_row" "direct_voter"%ROWTYPE;
|
jbe@242
|
2676 "delegating_voter_row" "delegating_voter"%ROWTYPE;
|
jbe@242
|
2677 BEGIN
|
jbe@242
|
2678 "output_row"."index" := 0;
|
jbe@242
|
2679 "output_row"."member_id" := "member_id_p";
|
jbe@242
|
2680 "output_row"."member_valid" := TRUE;
|
jbe@242
|
2681 "output_row"."participation" := FALSE;
|
jbe@242
|
2682 "output_row"."overridden" := FALSE;
|
jbe@242
|
2683 "output_row"."disabled_out" := FALSE;
|
jbe@242
|
2684 LOOP
|
jbe@242
|
2685 SELECT INTO "direct_voter_row" * FROM "direct_voter"
|
jbe@242
|
2686 WHERE "issue_id" = "issue_id_p"
|
jbe@242
|
2687 AND "member_id" = "output_row"."member_id";
|
jbe@242
|
2688 IF "direct_voter_row"."member_id" NOTNULL THEN
|
jbe@242
|
2689 "output_row"."participation" := TRUE;
|
jbe@242
|
2690 "output_row"."scope_out" := NULL;
|
jbe@242
|
2691 "output_row"."disabled_out" := NULL;
|
jbe@242
|
2692 RETURN NEXT "output_row";
|
jbe@242
|
2693 RETURN;
|
jbe@242
|
2694 END IF;
|
jbe@242
|
2695 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
|
jbe@242
|
2696 WHERE "issue_id" = "issue_id_p"
|
jbe@242
|
2697 AND "member_id" = "output_row"."member_id";
|
jbe@242
|
2698 IF "delegating_voter_row"."member_id" ISNULL THEN
|
jbe@242
|
2699 RETURN;
|
jbe@242
|
2700 END IF;
|
jbe@242
|
2701 "output_row"."scope_out" := "delegating_voter_row"."scope";
|
jbe@242
|
2702 RETURN NEXT "output_row";
|
jbe@242
|
2703 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
|
jbe@242
|
2704 "output_row"."scope_in" := "output_row"."scope_out";
|
jbe@242
|
2705 END LOOP;
|
jbe@242
|
2706 END;
|
jbe@242
|
2707 $$;
|
jbe@242
|
2708
|
jbe@242
|
2709 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
|
jbe@242
|
2710 ( "member"."id"%TYPE,
|
jbe@242
|
2711 "member"."id"%TYPE )
|
jbe@242
|
2712 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
|
jbe@242
|
2713
|
jbe@242
|
2714
|
jbe@5
|
2715 CREATE FUNCTION "delegation_chain"
|
jbe@5
|
2716 ( "member_id_p" "member"."id"%TYPE,
|
jbe@97
|
2717 "unit_id_p" "unit"."id"%TYPE,
|
jbe@5
|
2718 "area_id_p" "area"."id"%TYPE,
|
jbe@5
|
2719 "issue_id_p" "issue"."id"%TYPE,
|
jbe@255
|
2720 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
|
jbe@255
|
2721 "simulate_default_p" BOOLEAN DEFAULT FALSE )
|
jbe@5
|
2722 RETURNS SETOF "delegation_chain_row"
|
jbe@5
|
2723 LANGUAGE 'plpgsql' STABLE AS $$
|
jbe@5
|
2724 DECLARE
|
jbe@97
|
2725 "scope_v" "delegation_scope";
|
jbe@97
|
2726 "unit_id_v" "unit"."id"%TYPE;
|
jbe@97
|
2727 "area_id_v" "area"."id"%TYPE;
|
jbe@241
|
2728 "issue_row" "issue"%ROWTYPE;
|
jbe@5
|
2729 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
|
jbe@5
|
2730 "loop_member_id_v" "member"."id"%TYPE;
|
jbe@5
|
2731 "output_row" "delegation_chain_row";
|
jbe@5
|
2732 "output_rows" "delegation_chain_row"[];
|
jbe@255
|
2733 "simulate_v" BOOLEAN;
|
jbe@255
|
2734 "simulate_here_v" BOOLEAN;
|
jbe@5
|
2735 "delegation_row" "delegation"%ROWTYPE;
|
jbe@5
|
2736 "row_count" INT4;
|
jbe@5
|
2737 "i" INT4;
|
jbe@5
|
2738 "loop_v" BOOLEAN;
|
jbe@5
|
2739 BEGIN
|
jbe@255
|
2740 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
|
jbe@255
|
2741 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
|
jbe@255
|
2742 END IF;
|
jbe@255
|
2743 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
|
jbe@255
|
2744 "simulate_v" := TRUE;
|
jbe@255
|
2745 ELSE
|
jbe@255
|
2746 "simulate_v" := FALSE;
|
jbe@255
|
2747 END IF;
|
jbe@97
|
2748 IF
|
jbe@97
|
2749 "unit_id_p" NOTNULL AND
|
jbe@97
|
2750 "area_id_p" ISNULL AND
|
jbe@97
|
2751 "issue_id_p" ISNULL
|
jbe@97
|
2752 THEN
|
jbe@97
|
2753 "scope_v" := 'unit';
|
jbe@97
|
2754 "unit_id_v" := "unit_id_p";
|
jbe@97
|
2755 ELSIF
|
jbe@97
|
2756 "unit_id_p" ISNULL AND
|
jbe@97
|
2757 "area_id_p" NOTNULL AND
|
jbe@97
|
2758 "issue_id_p" ISNULL
|
jbe@97
|
2759 THEN
|
jbe@97
|
2760 "scope_v" := 'area';
|
jbe@97
|
2761 "area_id_v" := "area_id_p";
|
jbe@97
|
2762 SELECT "unit_id" INTO "unit_id_v"
|
jbe@97
|
2763 FROM "area" WHERE "id" = "area_id_v";
|
jbe@97
|
2764 ELSIF
|
jbe@97
|
2765 "unit_id_p" ISNULL AND
|
jbe@97
|
2766 "area_id_p" ISNULL AND
|
jbe@97
|
2767 "issue_id_p" NOTNULL
|
jbe@97
|
2768 THEN
|
jbe@242
|
2769 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
|
jbe@242
|
2770 IF "issue_row"."id" ISNULL THEN
|
jbe@242
|
2771 RETURN;
|
jbe@242
|
2772 END IF;
|
jbe@242
|
2773 IF "issue_row"."closed" NOTNULL THEN
|
jbe@255
|
2774 IF "simulate_v" THEN
|
jbe@242
|
2775 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
|
jbe@242
|
2776 END IF;
|
jbe@242
|
2777 FOR "output_row" IN
|
jbe@242
|
2778 SELECT * FROM
|
jbe@242
|
2779 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
|
jbe@242
|
2780 LOOP
|
jbe@242
|
2781 RETURN NEXT "output_row";
|
jbe@242
|
2782 END LOOP;
|
jbe@242
|
2783 RETURN;
|
jbe@242
|
2784 END IF;
|
jbe@97
|
2785 "scope_v" := 'issue';
|
jbe@97
|
2786 SELECT "area_id" INTO "area_id_v"
|
jbe@97
|
2787 FROM "issue" WHERE "id" = "issue_id_p";
|
jbe@97
|
2788 SELECT "unit_id" INTO "unit_id_v"
|
jbe@97
|
2789 FROM "area" WHERE "id" = "area_id_v";
|
jbe@97
|
2790 ELSE
|
jbe@97
|
2791 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
|
jbe@97
|
2792 END IF;
|
jbe@5
|
2793 "visited_member_ids" := '{}';
|
jbe@5
|
2794 "loop_member_id_v" := NULL;
|
jbe@5
|
2795 "output_rows" := '{}';
|
jbe@5
|
2796 "output_row"."index" := 0;
|
jbe@5
|
2797 "output_row"."member_id" := "member_id_p";
|
jbe@97
|
2798 "output_row"."member_valid" := TRUE;
|
jbe@5
|
2799 "output_row"."participation" := FALSE;
|
jbe@5
|
2800 "output_row"."overridden" := FALSE;
|
jbe@86
|
2801 "output_row"."disabled_out" := FALSE;
|
jbe@5
|
2802 "output_row"."scope_out" := NULL;
|
jbe@5
|
2803 LOOP
|
jbe@5
|
2804 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
|
jbe@5
|
2805 "loop_member_id_v" := "output_row"."member_id";
|
jbe@5
|
2806 ELSE
|
jbe@5
|
2807 "visited_member_ids" :=
|
jbe@5
|
2808 "visited_member_ids" || "output_row"."member_id";
|
jbe@5
|
2809 END IF;
|
jbe@241
|
2810 IF "output_row"."participation" ISNULL THEN
|
jbe@241
|
2811 "output_row"."overridden" := NULL;
|
jbe@241
|
2812 ELSIF "output_row"."participation" THEN
|
jbe@5
|
2813 "output_row"."overridden" := TRUE;
|
jbe@5
|
2814 END IF;
|
jbe@5
|
2815 "output_row"."scope_in" := "output_row"."scope_out";
|
jbe@255
|
2816 "output_row"."member_valid" := EXISTS (
|
jbe@97
|
2817 SELECT NULL FROM "member" JOIN "privilege"
|
jbe@97
|
2818 ON "privilege"."member_id" = "member"."id"
|
jbe@97
|
2819 AND "privilege"."unit_id" = "unit_id_v"
|
jbe@97
|
2820 WHERE "id" = "output_row"."member_id"
|
jbe@97
|
2821 AND "member"."active" AND "privilege"."voting_right"
|
jbe@255
|
2822 );
|
jbe@255
|
2823 "simulate_here_v" := (
|
jbe@255
|
2824 "simulate_v" AND
|
jbe@255
|
2825 "output_row"."member_id" = "member_id_p"
|
jbe@255
|
2826 );
|
jbe@255
|
2827 "delegation_row" := ROW(NULL);
|
jbe@255
|
2828 IF "output_row"."member_valid" OR "simulate_here_v" THEN
|
jbe@97
|
2829 IF "scope_v" = 'unit' THEN
|
jbe@255
|
2830 IF NOT "simulate_here_v" THEN
|
jbe@255
|
2831 SELECT * INTO "delegation_row" FROM "delegation"
|
jbe@255
|
2832 WHERE "truster_id" = "output_row"."member_id"
|
jbe@255
|
2833 AND "unit_id" = "unit_id_v";
|
jbe@255
|
2834 END IF;
|
jbe@97
|
2835 ELSIF "scope_v" = 'area' THEN
|
jbe@5
|
2836 "output_row"."participation" := EXISTS (
|
jbe@5
|
2837 SELECT NULL FROM "membership"
|
jbe@5
|
2838 WHERE "area_id" = "area_id_p"
|
jbe@5
|
2839 AND "member_id" = "output_row"."member_id"
|
jbe@5
|
2840 );
|
jbe@255
|
2841 IF "simulate_here_v" THEN
|
jbe@255
|
2842 IF "simulate_trustee_id_p" ISNULL THEN
|
jbe@255
|
2843 SELECT * INTO "delegation_row" FROM "delegation"
|
jbe@255
|
2844 WHERE "truster_id" = "output_row"."member_id"
|
jbe@255
|
2845 AND "unit_id" = "unit_id_v";
|
jbe@255
|
2846 END IF;
|
jbe@255
|
2847 ELSE
|
jbe@255
|
2848 SELECT * INTO "delegation_row" FROM "delegation"
|
jbe@255
|
2849 WHERE "truster_id" = "output_row"."member_id"
|
jbe@255
|
2850 AND (
|
jbe@255
|
2851 "unit_id" = "unit_id_v" OR
|
jbe@255
|
2852 "area_id" = "area_id_v"
|
jbe@255
|
2853 )
|
jbe@255
|
2854 ORDER BY "scope" DESC;
|
jbe@255
|
2855 END IF;
|
jbe@97
|
2856 ELSIF "scope_v" = 'issue' THEN
|
jbe@241
|
2857 IF "issue_row"."fully_frozen" ISNULL THEN
|
jbe@241
|
2858 "output_row"."participation" := EXISTS (
|
jbe@241
|
2859 SELECT NULL FROM "interest"
|
jbe@241
|
2860 WHERE "issue_id" = "issue_id_p"
|
jbe@241
|
2861 AND "member_id" = "output_row"."member_id"
|
jbe@241
|
2862 );
|
jbe@241
|
2863 ELSE
|
jbe@241
|
2864 IF "output_row"."member_id" = "member_id_p" THEN
|
jbe@241
|
2865 "output_row"."participation" := EXISTS (
|
jbe@241
|
2866 SELECT NULL FROM "direct_voter"
|
jbe@241
|
2867 WHERE "issue_id" = "issue_id_p"
|
jbe@241
|
2868 AND "member_id" = "output_row"."member_id"
|
jbe@241
|
2869 );
|
jbe@241
|
2870 ELSE
|
jbe@241
|
2871 "output_row"."participation" := NULL;
|
jbe@241
|
2872 END IF;
|
jbe@241
|
2873 END IF;
|
jbe@255
|
2874 IF "simulate_here_v" THEN
|
jbe@255
|
2875 IF "simulate_trustee_id_p" ISNULL THEN
|
jbe@255
|
2876 SELECT * INTO "delegation_row" FROM "delegation"
|
jbe@255
|
2877 WHERE "truster_id" = "output_row"."member_id"
|
jbe@255
|
2878 AND (
|
jbe@255
|
2879 "unit_id" = "unit_id_v" OR
|
jbe@255
|
2880 "area_id" = "area_id_v"
|
jbe@255
|
2881 )
|
jbe@255
|
2882 ORDER BY "scope" DESC;
|
jbe@255
|
2883 END IF;
|
jbe@255
|
2884 ELSE
|
jbe@255
|
2885 SELECT * INTO "delegation_row" FROM "delegation"
|
jbe@255
|
2886 WHERE "truster_id" = "output_row"."member_id"
|
jbe@255
|
2887 AND (
|
jbe@255
|
2888 "unit_id" = "unit_id_v" OR
|
jbe@255
|
2889 "area_id" = "area_id_v" OR
|
jbe@255
|
2890 "issue_id" = "issue_id_p"
|
jbe@255
|
2891 )
|
jbe@255
|
2892 ORDER BY "scope" DESC;
|
jbe@255
|
2893 END IF;
|
jbe@5
|
2894 END IF;
|
jbe@5
|
2895 ELSE
|
jbe@5
|
2896 "output_row"."participation" := FALSE;
|
jbe@5
|
2897 END IF;
|
jbe@255
|
2898 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
|
jbe@97
|
2899 "output_row"."scope_out" := "scope_v";
|
jbe@5
|
2900 "output_rows" := "output_rows" || "output_row";
|
jbe@5
|
2901 "output_row"."member_id" := "simulate_trustee_id_p";
|
jbe@5
|
2902 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
|
jbe@10
|
2903 "output_row"."scope_out" := "delegation_row"."scope";
|
jbe@5
|
2904 "output_rows" := "output_rows" || "output_row";
|
jbe@5
|
2905 "output_row"."member_id" := "delegation_row"."trustee_id";
|
jbe@86
|
2906 ELSIF "delegation_row"."scope" NOTNULL THEN
|
jbe@86
|
2907 "output_row"."scope_out" := "delegation_row"."scope";
|
jbe@86
|
2908 "output_row"."disabled_out" := TRUE;
|
jbe@86
|
2909 "output_rows" := "output_rows" || "output_row";
|
jbe@86
|
2910 EXIT;
|
jbe@5
|
2911 ELSE
|
jbe@5
|
2912 "output_row"."scope_out" := NULL;
|
jbe@5
|
2913 "output_rows" := "output_rows" || "output_row";
|
jbe@5
|
2914 EXIT;
|
jbe@5
|
2915 END IF;
|
jbe@5
|
2916 EXIT WHEN "loop_member_id_v" NOTNULL;
|
jbe@5
|
2917 "output_row"."index" := "output_row"."index" + 1;
|
jbe@5
|
2918 END LOOP;
|
jbe@5
|
2919 "row_count" := array_upper("output_rows", 1);
|
jbe@5
|
2920 "i" := 1;
|
jbe@5
|
2921 "loop_v" := FALSE;
|
jbe@5
|
2922 LOOP
|
jbe@5
|
2923 "output_row" := "output_rows"["i"];
|
jbe@98
|
2924 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
|
jbe@5
|
2925 IF "loop_v" THEN
|
jbe@5
|
2926 IF "i" + 1 = "row_count" THEN
|
jbe@5
|
2927 "output_row"."loop" := 'last';
|
jbe@5
|
2928 ELSIF "i" = "row_count" THEN
|
jbe@5
|
2929 "output_row"."loop" := 'repetition';
|
jbe@5
|
2930 ELSE
|
jbe@5
|
2931 "output_row"."loop" := 'intermediate';
|
jbe@5
|
2932 END IF;
|
jbe@5
|
2933 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
|
jbe@5
|
2934 "output_row"."loop" := 'first';
|
jbe@5
|
2935 "loop_v" := TRUE;
|
jbe@5
|
2936 END IF;
|
jbe@97
|
2937 IF "scope_v" = 'unit' THEN
|
jbe@5
|
2938 "output_row"."participation" := NULL;
|
jbe@5
|
2939 END IF;
|
|