liquid_feedback_core
view core.sql @ 592:332a2177e208
Reduced indices on "issue" table
| author | jbe |
|---|---|
| date | Sat Dec 08 01:26:25 2018 +0100 (2018-12-08) |
| parents | d955519f7471 |
| children | e7f772ca0621 |
line source
2 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
4 BEGIN;
6 CREATE EXTENSION IF NOT EXISTS btree_gist;
7 CREATE EXTENSION IF NOT EXISTS latlon;
8 CREATE EXTENSION IF NOT EXISTS conflux;
10 CREATE VIEW "liquid_feedback_version" AS
11 SELECT * FROM (VALUES ('4.1.0', 4, 1, 0))
12 AS "subquery"("string", "major", "minor", "revision");
16 ----------------------
17 -- Full text search --
18 ----------------------
21 CREATE FUNCTION "text_search_query"("query_text_p" TEXT)
22 RETURNS TSQUERY
23 LANGUAGE 'plpgsql' IMMUTABLE AS $$
24 BEGIN
25 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p");
26 END;
27 $$;
29 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')';
32 CREATE FUNCTION "highlight"
33 ( "body_p" TEXT,
34 "query_text_p" TEXT )
35 RETURNS TEXT
36 LANGUAGE 'plpgsql' IMMUTABLE AS $$
37 BEGIN
38 RETURN ts_headline(
39 'pg_catalog.simple',
40 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
41 "text_search_query"("query_text_p"),
42 'StartSel=* StopSel=* HighlightAll=TRUE' );
43 END;
44 $$;
46 COMMENT ON FUNCTION "highlight"
47 ( "body_p" TEXT,
48 "query_text_p" TEXT )
49 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.';
53 -------------------------
54 -- Tables and indicies --
55 -------------------------
58 CREATE TABLE "temporary_transaction_data" (
59 PRIMARY KEY ("txid", "key"),
60 "txid" INT8 DEFAULT txid_current(),
61 "key" TEXT,
62 "value" TEXT NOT NULL );
64 COMMENT ON TABLE "temporary_transaction_data" IS 'Table to store temporary transaction data; shall be emptied before a transaction is committed';
66 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';
69 CREATE TABLE "system_setting" (
70 "member_ttl" INTERVAL );
71 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
73 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
74 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
76 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.';
79 CREATE TABLE "contingent" (
80 PRIMARY KEY ("polling", "time_frame"),
81 "polling" BOOLEAN,
82 "time_frame" INTERVAL,
83 "text_entry_limit" INT4,
84 "initiative_limit" INT4 );
86 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.';
88 COMMENT ON COLUMN "contingent"."polling" IS 'Determines if settings are for creating initiatives and new drafts of initiatives with "polling" flag set';
89 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';
90 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame';
93 CREATE TABLE "member" (
94 "id" SERIAL4 PRIMARY KEY,
95 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
96 "deleted" TIMESTAMPTZ,
97 "invite_code" TEXT UNIQUE,
98 "invite_code_expiry" TIMESTAMPTZ,
99 "admin_comment" TEXT,
100 "activated" TIMESTAMPTZ,
101 "last_activity" DATE,
102 "last_login" TIMESTAMPTZ,
103 "last_delegation_check" TIMESTAMPTZ,
104 "login" TEXT UNIQUE,
105 "password" TEXT,
106 "authority" TEXT,
107 "authority_uid" TEXT,
108 "authority_login" TEXT,
109 "locked" BOOLEAN NOT NULL DEFAULT FALSE,
110 "active" BOOLEAN NOT NULL DEFAULT FALSE,
111 "admin" BOOLEAN NOT NULL DEFAULT FALSE,
112 "lang" TEXT,
113 "notify_email" TEXT,
114 "notify_email_unconfirmed" TEXT,
115 "notify_email_secret" TEXT UNIQUE,
116 "notify_email_secret_expiry" TIMESTAMPTZ,
117 "notify_email_lock_expiry" TIMESTAMPTZ,
118 "unsubscribe_secret" TEXT,
119 "disable_notifications" BOOLEAN NOT NULL DEFAULT FALSE,
120 "notification_counter" INT4 NOT NULL DEFAULT 1,
121 "notification_sample_size" INT4 NOT NULL DEFAULT 3,
122 "notification_dow" INT4 CHECK ("notification_dow" BETWEEN 0 AND 6),
123 "notification_hour" INT4 DEFAULT floor(random() * 24) CHECK ("notification_hour" BETWEEN 0 AND 23),
124 "notification_sent" TIMESTAMP,
125 "login_recovery_expiry" TIMESTAMPTZ,
126 "password_reset_secret" TEXT UNIQUE,
127 "password_reset_secret_expiry" TIMESTAMPTZ,
128 "name" TEXT UNIQUE,
129 "identification" TEXT UNIQUE,
130 "authentication" TEXT,
131 "role" BOOLEAN NOT NULL DEFAULT FALSE,
132 "location" JSONB,
133 "text_search_data" TSVECTOR,
134 CONSTRAINT "deleted_requires_locked"
135 CHECK ("deleted" ISNULL OR "locked" = TRUE),
136 CONSTRAINT "active_requires_activated_and_last_activity"
137 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)),
138 CONSTRAINT "authority_requires_uid_and_vice_versa"
139 CHECK (("authority" NOTNULL) = ("authority_uid" NOTNULL)),
140 CONSTRAINT "authority_uid_unique_per_authority"
141 UNIQUE ("authority", "authority_uid"),
142 CONSTRAINT "authority_login_requires_authority"
143 CHECK ("authority" NOTNULL OR "authority_login" ISNULL),
144 CONSTRAINT "notification_dow_requires_notification_hour"
145 CHECK ("notification_dow" ISNULL OR "notification_hour" NOTNULL),
146 CONSTRAINT "name_not_null_if_activated"
147 CHECK ("activated" ISNULL OR "name" NOTNULL) );
148 CREATE INDEX "member_authority_login_idx" ON "member" ("authority_login");
149 CREATE INDEX "member_active_idx" ON "member" ("active");
150 CREATE INDEX "member_location_idx" ON "member" USING gist ((GeoJSON_to_ecluster("location")));
151 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
152 CREATE TRIGGER "update_text_search_data"
153 BEFORE INSERT OR UPDATE ON "member"
154 FOR EACH ROW EXECUTE PROCEDURE
155 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
156 "name", "identification");
158 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
160 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
161 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
162 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"';
163 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
164 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';
165 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
166 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
167 COMMENT ON COLUMN "member"."last_delegation_check" IS 'Timestamp of last delegation check (i.e. confirmation of all unit and area delegations)';
168 COMMENT ON COLUMN "member"."login" IS 'Login name';
169 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
170 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)';
171 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)';
172 COMMENT ON COLUMN "member"."authority_login" IS 'Login name for external accounts (field is not unique!)';
173 COMMENT ON COLUMN "member"."deleted" IS 'Timestamp of deletion (set by "delete_member" function)';
174 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
175 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".';
176 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
177 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
178 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
179 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
180 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
181 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
182 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
183 COMMENT ON COLUMN "member"."unsubscribe_secret" IS 'Secret string to be used for a List-Unsubscribe mail header';
184 COMMENT ON COLUMN "member"."disable_notifications" IS 'TRUE if member does not want to receive notifications';
185 COMMENT ON COLUMN "member"."notification_counter" IS 'Sequential number of next scheduled notification message (used as a seed for pseudo-random initiative selection algorithm)';
186 COMMENT ON COLUMN "member"."notification_sample_size" IS 'Number of featured initiatives per issue in scheduled notification messages';
187 COMMENT ON COLUMN "member"."notification_dow" IS 'Day of week for scheduled notifications (NULL to receive a daily digest)';
188 COMMENT ON COLUMN "member"."notification_hour" IS 'Time of day when scheduled notifications are sent out';
189 COMMENT ON COLUMN "member"."notification_sent" IS 'Timestamp of last scheduled notification mail that has been sent out';
190 COMMENT ON COLUMN "member"."login_recovery_expiry" IS 'Date/time after which another login recovery attempt is allowed';
191 COMMENT ON COLUMN "member"."password_reset_secret" IS 'Secret string sent via e-mail for password recovery';
192 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';
193 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet';
194 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
195 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
196 COMMENT ON COLUMN "member"."location" IS 'Geographic location on earth as GeoJSON object';
199 CREATE TABLE "member_history" ( -- TODO: redundancy with new "event" table
200 "id" SERIAL8 PRIMARY KEY,
201 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
202 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
203 "active" BOOLEAN NOT NULL,
204 "name" TEXT NOT NULL );
205 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
207 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
209 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
210 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
213 CREATE TABLE "agent" (
214 PRIMARY KEY ("controlled_id", "controller_id"),
215 "controlled_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
216 "controller_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
217 "accepted" BOOLEAN,
218 CONSTRAINT "controlled_id_and_controller_id_differ" CHECK (
219 "controlled_id" != "controller_id" ) );
220 CREATE INDEX "agent_controller_id_idx" ON "agent" ("controller_id");
222 COMMENT ON TABLE "agent" IS 'Privileges for role accounts';
224 COMMENT ON COLUMN "agent"."accepted" IS 'If "accepted" is NULL, then the member was invited to be an agent, but has not reacted yet. If it is TRUE, the member has accepted the invitation, if it is FALSE, the member has rejected the invitation.';
227 CREATE TABLE "verification" (
228 "id" SERIAL8 PRIMARY KEY,
229 "requested" TIMESTAMPTZ,
230 "request_origin" JSONB,
231 "request_data" JSONB,
232 "requesting_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
233 "verifying_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
234 "verified_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
235 "verified" TIMESTAMPTZ,
236 "verification_data" JSONB,
237 "denied" TIMESTAMPTZ,
238 "comment" TEXT,
239 CONSTRAINT "verified_and_denied_conflict" CHECK (
240 "verified" ISNULL OR "denied" ISNULL ) );
241 CREATE INDEX "verification_requested_idx" ON "verification" ("requested");
242 CREATE INDEX "verification_open_request_idx" ON "verification" ("requested") WHERE "verified" ISNULL AND "denied" ISNULL;
243 CREATE INDEX "verification_requesting_member_id_idx" ON "verification" ("requesting_member_id");
244 CREATE INDEX "verification_verified_member_id_idx" ON "verification" ("verified_member_id");
245 CREATE INDEX "verification_verified_idx" ON "verification" ("verified");
246 CREATE INDEX "verification_denied_idx" ON "verification" ("denied");
248 COMMENT ON TABLE "verification" IS 'Request to verify a participant';
250 COMMENT ON COLUMN "verification"."requested" IS 'Timestamp when request for verification has been submitted';
251 COMMENT ON COLUMN "verification"."request_origin" IS 'JSON data containing information about the origin of the request (e.g. IP address or hostname)';
252 COMMENT ON COLUMN "verification"."request_data" IS 'JSON data containing information about the entity to be verified (e.g. real name, address, etc.)';
253 COMMENT ON COLUMN "verification"."requesting_member_id" IS 'Member who requested verification';
254 COMMENT ON COLUMN "verification"."verifying_member_id" IS 'Member who processed the verification request (i.e. who accepted or denied the request)';
255 COMMENT ON COLUMN "verification"."verified_member_id" IS 'Member entry containing verified information (not necessarily equal to "requesting_member_id" but may be merged with requesting member later)';
256 COMMENT ON COLUMN "verification"."verified" IS 'Timestamp when request for verification has been accepted by authority';
257 COMMENT ON COLUMN "verification"."verification_data" IS 'JSON data containing additional verified data or information about the authority or operator who accepted or denied the request, but all public information shall be copied to "member"."identification", "member"."verification" and/or "member"."name" if applicable for setup';
258 COMMENT ON COLUMN "verification"."denied" IS 'Timestamp when request for verification has been denied by authority';
259 COMMENT ON COLUMN "verification"."comment" IS 'Administrative comment';
262 -- TODO: merge tables "verification" and "role_verification"
264 CREATE TABLE "role_verification" (
265 "id" SERIAL8 PRIMARY KEY,
266 "requested" TIMESTAMPTZ,
267 "request_origin" JSONB,
268 "request_data" JSONB,
269 "requesting_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
270 "requesting_real_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
271 "verifying_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
272 "verified_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
273 "verified" TIMESTAMPTZ,
274 "verification_data" JSONB,
275 "denied" TIMESTAMPTZ,
276 "comment" TEXT,
277 CONSTRAINT "verified_and_denied_conflict" CHECK (
278 "verified" ISNULL OR "denied" ISNULL ) );
279 CREATE INDEX "role_verification_requested_idx" ON "role_verification" ("requested");
280 CREATE INDEX "role_verification_open_request_idx" ON "role_verification" ("requested") WHERE "verified" ISNULL AND "denied" ISNULL;
281 CREATE INDEX "role_verification_requesting_member_id_idx" ON "role_verification" ("requesting_member_id");
282 CREATE INDEX "role_verification_verified_member_id_idx" ON "role_verification" ("verified_member_id");
283 CREATE INDEX "role_verification_verified_idx" ON "role_verification" ("verified");
284 CREATE INDEX "role_verification_denied_idx" ON "role_verification" ("denied");
286 COMMENT ON TABLE "role_verification" IS 'Request to verify a role account (see table "verification" for documentation of columns not documented for this table)';
288 COMMENT ON COLUMN "role_verification"."requesting_member_id" IS 'Member role account to verify';
289 COMMENT ON COLUMN "role_verification"."requesting_real_member_id" IS 'Member account of real person who requested verification';
292 CREATE TABLE "member_settings" (
293 "member_id" INT4 PRIMARY KEY REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
294 "settings" JSONB NOT NULL CHECK (jsonb_typeof("settings") = 'object') );
296 COMMENT ON TABLE "member_settings" IS 'Stores a JSON document for each member containing optional (additional) settings for the respective member';
299 CREATE TABLE "member_useterms" (
300 "id" SERIAL8 PRIMARY KEY,
301 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
302 "accepted" TIMESTAMPTZ NOT NULL DEFAULT now(),
303 "contract_identifier" TEXT NOT NULL );
304 CREATE INDEX "member_useterms_member_id_contract_identifier" ON "member_useterms" ("member_id", "contract_identifier");
306 COMMENT ON TABLE "member_useterms" IS 'Keeps record of accepted terms of use; may contain multiple rows per member';
308 COMMENT ON COLUMN "member_useterms"."accepted" IS 'Point in time when user accepted the terms of use';
309 COMMENT ON COLUMN "member_useterms"."contract_identifier" IS 'String identifier to denote the accepted terms of use, including their version or revision';
312 CREATE TABLE "member_profile" (
313 "member_id" INT4 PRIMARY KEY REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
314 "formatting_engine" TEXT,
315 "statement" TEXT,
316 "profile" JSONB NOT NULL DEFAULT '{}' CHECK (jsonb_typeof("profile") = 'object'),
317 "profile_text_data" TEXT,
318 "text_search_data" TSVECTOR );
319 CREATE INDEX "member_profile_text_search_data_idx" ON "member_profile" USING gin ("text_search_data");
320 CREATE TRIGGER "update_text_search_data"
321 BEFORE INSERT OR UPDATE ON "member_profile"
322 FOR EACH ROW EXECUTE PROCEDURE
323 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
324 'statement', 'profile_text_data');
326 COMMENT ON COLUMN "member_profile"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member_profile"."statement"';
327 COMMENT ON COLUMN "member_profile"."statement" IS 'Freely chosen text of the member for his/her profile';
328 COMMENT ON COLUMN "member_profile"."profile" IS 'Additional profile data as JSON document';
329 COMMENT ON COLUMN "member_profile"."profile_text_data" IS 'Text data from "profile" field for full text search';
332 CREATE TABLE "rendered_member_statement" (
333 PRIMARY KEY ("member_id", "format"),
334 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
335 "format" TEXT,
336 "content" TEXT NOT NULL );
338 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)';
341 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
343 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
346 CREATE TABLE "member_image" (
347 PRIMARY KEY ("member_id", "image_type", "scaled"),
348 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
349 "image_type" "member_image_type",
350 "scaled" BOOLEAN,
351 "content_type" TEXT,
352 "data" BYTEA NOT NULL );
354 COMMENT ON TABLE "member_image" IS 'Images of members';
356 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
359 CREATE TABLE "member_count" (
360 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
361 "total_count" INT4 NOT NULL );
363 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';
365 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
366 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
369 CREATE TABLE "contact" (
370 PRIMARY KEY ("member_id", "other_member_id"),
371 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
372 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
373 "public" BOOLEAN NOT NULL DEFAULT FALSE,
374 "following" BOOLEAN NOT NULL DEFAULT TRUE,
375 CONSTRAINT "cant_save_yourself_as_contact"
376 CHECK ("member_id" != "other_member_id") );
377 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
379 COMMENT ON TABLE "contact" IS 'Contact lists';
381 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
382 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
383 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
384 COMMENT ON COLUMN "contact"."following" IS 'TRUE = actions of contact are shown in personal timeline';
387 CREATE TABLE "ignored_member" (
388 PRIMARY KEY ("member_id", "other_member_id"),
389 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
390 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
391 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
393 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
395 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
396 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
399 CREATE TABLE "session" (
400 UNIQUE ("member_id", "id"), -- index needed for foreign-key on table "token"
401 "id" SERIAL8 PRIMARY KEY,
402 "ident" TEXT NOT NULL UNIQUE,
403 "additional_secret" TEXT,
404 "logout_token" TEXT,
405 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
406 "member_id" INT4 REFERENCES "member" ("id") ON DELETE SET NULL,
407 "real_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
408 "authority" TEXT,
409 "authority_uid" TEXT,
410 "authority_login" TEXT,
411 "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE,
412 "lang" TEXT );
413 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
415 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
417 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
418 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
419 COMMENT ON COLUMN "session"."logout_token" IS 'Optional token to authorize logout through external component';
420 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in, or role account in use';
421 COMMENT ON COLUMN "session"."real_member_id" IS 'Reference to member, who is really logged in (real person rather than role account)';
422 COMMENT ON COLUMN "session"."authority" IS 'Temporary store for "member"."authority" during member account creation';
423 COMMENT ON COLUMN "session"."authority_uid" IS 'Temporary store for "member"."authority_uid" during member account creation';
424 COMMENT ON COLUMN "session"."authority_login" IS 'Temporary store for "member"."authority_login" during member account creation';
425 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';
426 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
429 CREATE TYPE "authflow" AS ENUM ('code', 'token');
431 COMMENT ON TYPE "authflow" IS 'OAuth 2.0 flows: ''code'' = Authorization Code flow, ''token'' = Implicit flow';
434 CREATE TABLE "system_application" (
435 "id" SERIAL4 PRIMARY KEY,
436 "name" TEXT NOT NULL,
437 "base_url" TEXT,
438 "manifest_url" TEXT,
439 "client_id" TEXT NOT NULL UNIQUE,
440 "default_redirect_uri" TEXT NOT NULL,
441 "cert_common_name" TEXT,
442 "client_cred_scope" TEXT,
443 "flow" "authflow",
444 "automatic_scope" TEXT,
445 "permitted_scope" TEXT,
446 "forbidden_scope" TEXT );
448 COMMENT ON TABLE "system_application" IS 'OAuth 2.0 clients that are registered by the system administrator';
450 COMMENT ON COLUMN "system_application"."name" IS 'Human readable name of application';
451 COMMENT ON COLUMN "system_application"."base_url" IS 'Base URL for users';
452 COMMENT ON COLUMN "system_application"."manifest_url" IS 'URL referring to a manifest that can be used for application (type/version) discovery';
453 COMMENT ON COLUMN "system_application"."client_id" IS 'OAuth 2.0 "client_id"';
454 COMMENT ON COLUMN "system_application"."cert_common_name" IS 'Value for CN field of TLS client certificate';
455 COMMENT ON COLUMN "system_application"."client_cred_scope" IS 'Space-separated list of scopes; If set, Client Credentials Grant is allowed; value determines scope';
456 COMMENT ON COLUMN "system_application"."flow" IS 'If set to ''code'' or ''token'', then Authorization Code or Implicit flow is allowed respectively';
457 COMMENT ON COLUMN "system_application"."automatic_scope" IS 'Space-separated list of scopes; Automatically granted scope for Authorization Code or Implicit flow';
458 COMMENT ON COLUMN "system_application"."permitted_scope" IS 'Space-separated list of scopes; If set, scope that members may grant to the application is limited to the given value';
459 COMMENT ON COLUMN "system_application"."forbidden_scope" IS 'Space-separated list of scopes that may not be granted to the application by a member';
462 CREATE TABLE "system_application_redirect_uri" (
463 PRIMARY KEY ("system_application_id", "redirect_uri"),
464 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
465 "redirect_uri" TEXT );
467 COMMENT ON TABLE "system_application_redirect_uri" IS 'Additional OAuth 2.0 redirection endpoints, which may be selected through the "redirect_uri" GET parameter';
470 CREATE TABLE "dynamic_application_scope" (
471 PRIMARY KEY ("redirect_uri", "flow", "scope"),
472 "redirect_uri" TEXT,
473 "flow" TEXT,
474 "scope" TEXT,
475 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours' );
476 CREATE INDEX "dynamic_application_scope_redirect_uri_scope_idx" ON "dynamic_application_scope" ("redirect_uri", "flow", "scope");
477 CREATE INDEX "dynamic_application_scope_expiry_idx" ON "dynamic_application_scope" ("expiry");
479 COMMENT ON TABLE "dynamic_application_scope" IS 'Dynamic OAuth 2.0 client registration data';
481 COMMENT ON COLUMN "dynamic_application_scope"."redirect_uri" IS 'Redirection endpoint for which the registration has been done';
482 COMMENT ON COLUMN "dynamic_application_scope"."flow" IS 'OAuth 2.0 flow for which the registration has been done (see also "system_application"."flow")';
483 COMMENT ON COLUMN "dynamic_application_scope"."scope" IS 'Single scope without space characters (use multiple rows for more scopes)';
484 COMMENT ON COLUMN "dynamic_application_scope"."expiry" IS 'Expiry unless renewed';
487 CREATE TABLE "member_application" (
488 "id" SERIAL4 PRIMARY KEY,
489 UNIQUE ("system_application_id", "member_id"),
490 UNIQUE ("domain", "member_id"),
491 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
492 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
493 "domain" TEXT,
494 "session_id" INT8,
495 FOREIGN KEY ("member_id", "session_id") REFERENCES "session" ("member_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
496 "scope" TEXT NOT NULL,
497 CONSTRAINT "system_application_or_domain_but_not_both" CHECK (
498 ("system_application_id" NOTNULL AND "domain" ISNULL) OR
499 ("system_application_id" ISNULL AND "domain" NOTNULL) ) );
500 CREATE INDEX "member_application_member_id_idx" ON "member_application" ("member_id");
502 COMMENT ON TABLE "member_application" IS 'Application authorized by a member';
504 COMMENT ON COLUMN "member_application"."system_application_id" IS 'If set, then application is a system application';
505 COMMENT ON COLUMN "member_application"."domain" IS 'If set, then application is a dynamically registered OAuth 2.0 client; value is set to client''s domain';
506 COMMENT ON COLUMN "member_application"."session_id" IS 'If set, registration ends with session';
507 COMMENT ON COLUMN "member_application"."scope" IS 'Granted scope as space-separated list of strings';
510 CREATE TYPE "token_type" AS ENUM ('authorization', 'refresh', 'access');
512 COMMENT ON TYPE "token_type" IS 'Types for entries in "token" table';
515 CREATE TABLE "token" (
516 "id" SERIAL8 PRIMARY KEY,
517 "token" TEXT NOT NULL UNIQUE,
518 "token_type" "token_type" NOT NULL,
519 "authorization_token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
520 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
521 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
522 "domain" TEXT,
523 FOREIGN KEY ("member_id", "domain") REFERENCES "member_application" ("member_id", "domain") ON DELETE CASCADE ON UPDATE CASCADE,
524 "session_id" INT8,
525 FOREIGN KEY ("member_id", "session_id") REFERENCES "session" ("member_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE, -- NOTE: deletion through "detach_token_from_session" trigger on table "session"
526 "redirect_uri" TEXT,
527 "redirect_uri_explicit" BOOLEAN,
528 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
529 "expiry" TIMESTAMPTZ DEFAULT now() + '1 hour',
530 "used" BOOLEAN NOT NULL DEFAULT FALSE,
531 "scope" TEXT NOT NULL,
532 CONSTRAINT "access_token_needs_expiry"
533 CHECK ("token_type" != 'access'::"token_type" OR "expiry" NOTNULL),
534 CONSTRAINT "authorization_token_needs_redirect_uri"
535 CHECK ("token_type" != 'authorization'::"token_type" OR ("redirect_uri" NOTNULL AND "redirect_uri_explicit" NOTNULL) ) );
536 CREATE INDEX "token_member_id_idx" ON "token" ("member_id");
537 CREATE INDEX "token_authorization_token_id_idx" ON "token" ("authorization_token_id");
538 CREATE INDEX "token_expiry_idx" ON "token" ("expiry");
540 COMMENT ON TABLE "token" IS 'Issued OAuth 2.0 authorization codes and access/refresh tokens';
542 COMMENT ON COLUMN "token"."token" IS 'String secret (the actual token)';
543 COMMENT ON COLUMN "token"."authorization_token_id" IS 'Reference to authorization token if tokens were originally created by Authorization Code flow (allows deletion if code is used twice)';
544 COMMENT ON COLUMN "token"."system_application_id" IS 'If set, then application is a system application';
545 COMMENT ON COLUMN "token"."domain" IS 'If set, then application is a dynamically registered OAuth 2.0 client; value is set to client''s domain';
546 COMMENT ON COLUMN "token"."session_id" IS 'If set, then token is tied to a session; Deletion of session sets value to NULL (via trigger) and removes all scopes without suffix ''_detached''';
547 COMMENT ON COLUMN "token"."redirect_uri" IS 'Authorization codes must be bound to a specific redirect URI';
548 COMMENT ON COLUMN "token"."redirect_uri_explicit" IS 'True if ''redirect_uri'' parameter was explicitly specified during authorization request of the Authorization Code flow (since RFC 6749 requires it to be included in the access token request in this case)';
549 COMMENT ON COLUMN "token"."expiry" IS 'Point in time when code or token expired; In case of "used" authorization codes, authorization code must not be deleted as long as tokens exist which refer to the authorization code';
550 COMMENT ON COLUMN "token"."used" IS 'Can be set to TRUE for authorization codes that have been used (enables deletion of authorization codes that were used twice)';
551 COMMENT ON COLUMN "token"."scope" IS 'Scope as space-separated list of strings (detached scopes are marked with ''_detached'' suffix)';
554 CREATE TABLE "token_scope" (
555 PRIMARY KEY ("token_id", "index"),
556 "token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
557 "index" INT4,
558 "scope" TEXT NOT NULL );
560 COMMENT ON TABLE "token_scope" IS 'Additional scopes for an authorization code if ''scope1'', ''scope2'', etc. parameters were used during Authorization Code flow to request several access and refresh tokens at once';
563 CREATE TYPE "defeat_strength" AS ENUM ('simple', 'tuple');
565 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';
568 CREATE TYPE "tie_breaking" AS ENUM ('simple', 'variant1', 'variant2');
570 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';
573 CREATE TABLE "policy" (
574 "id" SERIAL4 PRIMARY KEY,
575 "index" INT4 NOT NULL,
576 "active" BOOLEAN NOT NULL DEFAULT TRUE,
577 "name" TEXT NOT NULL UNIQUE,
578 "description" TEXT NOT NULL DEFAULT '',
579 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
580 "min_admission_time" INTERVAL,
581 "max_admission_time" INTERVAL,
582 "discussion_time" INTERVAL,
583 "verification_time" INTERVAL,
584 "voting_time" INTERVAL,
585 "issue_quorum" INT4 CHECK ("issue_quorum" >= 1),
586 "issue_quorum_num" INT4,
587 "issue_quorum_den" INT4,
588 "initiative_quorum" INT4 NOT NULL CHECK ("initiative_quorum" >= 1),
589 "initiative_quorum_num" INT4 NOT NULL,
590 "initiative_quorum_den" INT4 NOT NULL,
591 "defeat_strength" "defeat_strength" NOT NULL DEFAULT 'tuple',
592 "tie_breaking" "tie_breaking" NOT NULL DEFAULT 'variant1',
593 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
594 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
595 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
596 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
597 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
598 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
599 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
600 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
601 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
602 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
603 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT FALSE,
604 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
605 CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK (
606 "polling" = ("issue_quorum" ISNULL) AND
607 "polling" = ("issue_quorum_num" ISNULL) AND
608 "polling" = ("issue_quorum_den" ISNULL) ),
609 CONSTRAINT "min_admission_time_smaller_than_max_admission_time" CHECK (
610 "min_admission_time" < "max_admission_time" ),
611 CONSTRAINT "timing_null_or_not_null_constraints" CHECK (
612 ( "polling" = FALSE AND
613 "min_admission_time" NOTNULL AND "max_admission_time" NOTNULL AND
614 "discussion_time" NOTNULL AND
615 "verification_time" NOTNULL AND
616 "voting_time" NOTNULL ) OR
617 ( "polling" = TRUE AND
618 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
619 "discussion_time" NOTNULL AND
620 "verification_time" NOTNULL AND
621 "voting_time" NOTNULL ) OR
622 ( "polling" = TRUE AND
623 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
624 "discussion_time" ISNULL AND
625 "verification_time" ISNULL AND
626 "voting_time" ISNULL ) ),
627 CONSTRAINT "no_reverse_beat_path_requires_tuple_defeat_strength" CHECK (
628 "defeat_strength" = 'tuple'::"defeat_strength" OR
629 "no_reverse_beat_path" = FALSE ) );
630 CREATE INDEX "policy_active_idx" ON "policy" ("active");
632 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
634 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
635 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
636 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';
637 COMMENT ON COLUMN "policy"."min_admission_time" IS 'Minimum duration of issue state ''admission''; Minimum time an issue stays open; Note: should be considerably smaller than "max_admission_time"';
638 COMMENT ON COLUMN "policy"."max_admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
639 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
640 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"';
641 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'')';
642 COMMENT ON COLUMN "policy"."issue_quorum" IS 'Absolute number of supporters needed by an initiative to be "accepted", i.e. pass from ''admission'' to ''discussion'' state';
643 COMMENT ON COLUMN "policy"."issue_quorum_num" IS 'Numerator of supporter quorum to be reached by an initiative to be "accepted", i.e. pass from ''admission'' to ''discussion'' state (Note: further requirements apply, see quorum columns of "area" table)';
644 COMMENT ON COLUMN "policy"."issue_quorum_den" IS 'Denominator of supporter quorum to be reached by an initiative to be "accepted", i.e. pass from ''admission'' to ''discussion'' state (Note: further requirements apply, see quorum columns of "area" table)';
645 COMMENT ON COLUMN "policy"."initiative_quorum" IS 'Absolute number of satisfied supporters to be reached by an initiative to be "admitted" for voting';
646 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
647 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
648 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';
649 COMMENT ON COLUMN "policy"."tie_breaking" IS 'Tie-breaker for the Schulze method; see type "tie_breaking"; ''variant1'' or ''variant2'' are recommended';
650 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
651 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
652 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.';
653 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
654 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';
655 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';
656 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';
657 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.';
658 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';
659 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';
660 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.';
661 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").';
664 CREATE TABLE "unit" (
665 "id" SERIAL4 PRIMARY KEY,
666 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
667 "active" BOOLEAN NOT NULL DEFAULT TRUE,
668 "name" TEXT NOT NULL,
669 "description" TEXT NOT NULL DEFAULT '',
670 "external_reference" TEXT,
671 "member_count" INT4,
672 "location" JSONB,
673 "text_search_data" TSVECTOR );
674 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
675 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
676 CREATE INDEX "unit_active_idx" ON "unit" ("active");
677 CREATE INDEX "unit_location_idx" ON "unit" USING gist ((GeoJSON_to_ecluster("location")));
678 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
679 CREATE TRIGGER "update_text_search_data"
680 BEFORE INSERT OR UPDATE ON "unit"
681 FOR EACH ROW EXECUTE PROCEDURE
682 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
683 "name", "description" );
685 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
687 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
688 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
689 COMMENT ON COLUMN "unit"."external_reference" IS 'Opaque data field to store an external reference';
690 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege" (only active members counted)';
691 COMMENT ON COLUMN "unit"."location" IS 'Geographic location on earth as GeoJSON object indicating valid coordinates for initiatives of issues with this policy';
694 CREATE TABLE "subscription" (
695 PRIMARY KEY ("member_id", "unit_id"),
696 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
697 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
698 CREATE INDEX "subscription_unit_id_idx" ON "subscription" ("unit_id");
700 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';
703 CREATE TABLE "area" (
704 UNIQUE ("unit_id", "id"), -- index needed for foreign-key on table "event"
705 "id" SERIAL4 PRIMARY KEY,
706 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
707 "active" BOOLEAN NOT NULL DEFAULT TRUE,
708 "name" TEXT NOT NULL,
709 "description" TEXT NOT NULL DEFAULT '',
710 "quorum_standard" NUMERIC NOT NULL DEFAULT 2 CHECK ("quorum_standard" >= 0),
711 "quorum_issues" NUMERIC NOT NULL DEFAULT 1 CHECK ("quorum_issues" > 0),
712 "quorum_time" INTERVAL NOT NULL DEFAULT '1 day' CHECK ("quorum_time" > '0'::INTERVAL),
713 "quorum_exponent" NUMERIC NOT NULL DEFAULT 0.5 CHECK ("quorum_exponent" BETWEEN 0 AND 1),
714 "quorum_factor" NUMERIC NOT NULL DEFAULT 2 CHECK ("quorum_factor" >= 1),
715 "quorum_den" INT4 CHECK ("quorum_den" > 0),
716 "issue_quorum" INT4,
717 "external_reference" TEXT,
718 "location" JSONB,
719 "text_search_data" TSVECTOR );
720 CREATE INDEX "area_active_idx" ON "area" ("active");
721 CREATE INDEX "area_location_idx" ON "area" USING gist ((GeoJSON_to_ecluster("location")));
722 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
723 CREATE TRIGGER "update_text_search_data"
724 BEFORE INSERT OR UPDATE ON "area"
725 FOR EACH ROW EXECUTE PROCEDURE
726 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
727 "name", "description" );
729 COMMENT ON TABLE "area" IS 'Subject areas';
731 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
732 COMMENT ON COLUMN "area"."quorum_standard" IS 'Parameter for dynamic issue quorum: default quorum';
733 COMMENT ON COLUMN "area"."quorum_issues" IS 'Parameter for dynamic issue quorum: number of open issues for default quorum';
734 COMMENT ON COLUMN "area"."quorum_time" IS 'Parameter for dynamic issue quorum: discussion, verification, and voting time of open issues to result in the given default quorum (open issues with shorter time will increase quorum and open issues with longer time will reduce quorum if "quorum_exponent" is greater than zero)';
735 COMMENT ON COLUMN "area"."quorum_exponent" IS 'Parameter for dynamic issue quorum: set to zero to ignore duration of open issues, set to one to fully take duration of open issues into account; defaults to 0.5';
736 COMMENT ON COLUMN "area"."quorum_factor" IS 'Parameter for dynamic issue quorum: factor to increase dynamic quorum when a number of "quorum_issues" issues with "quorum_time" duration of discussion, verification, and voting phase are added to the number of open admitted issues';
737 COMMENT ON COLUMN "area"."quorum_den" IS 'Parameter for dynamic issue quorum: when set, dynamic quorum is multiplied with "issue"."population" and divided by "quorum_den" (and then rounded up)';
738 COMMENT ON COLUMN "area"."issue_quorum" IS 'Additional dynamic issue quorum based on the number of open accepted issues; automatically calculated by function "issue_admission"';
739 COMMENT ON COLUMN "area"."external_reference" IS 'Opaque data field to store an external reference';
740 COMMENT ON COLUMN "area"."location" IS 'Geographic location on earth as GeoJSON object indicating valid coordinates for initiatives of issues with this policy';
743 CREATE TABLE "ignored_area" (
744 PRIMARY KEY ("member_id", "area_id"),
745 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
746 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
747 CREATE INDEX "ignored_area_area_id_idx" ON "ignored_area" ("area_id");
749 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';
752 CREATE TABLE "allowed_policy" (
753 PRIMARY KEY ("area_id", "policy_id"),
754 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
755 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
756 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
757 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
759 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
761 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
764 CREATE TABLE "snapshot" (
765 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "issue"
766 "id" SERIAL8 PRIMARY KEY,
767 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
768 "population" INT4,
769 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
770 "issue_id" INT4 ); -- NOTE: following (cyclic) reference is added later through ALTER command: REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE
772 COMMENT ON TABLE "snapshot" IS 'Point in time when a snapshot of one or more issues (see table "snapshot_issue") and their supporter situation is taken';
775 CREATE TABLE "snapshot_population" (
776 PRIMARY KEY ("snapshot_id", "member_id"),
777 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
778 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE );
780 COMMENT ON TABLE "snapshot_population" IS 'Members with voting right relevant for a snapshot';
783 CREATE TYPE "issue_state" AS ENUM (
784 'admission', 'discussion', 'verification', 'voting',
785 'canceled_by_admin',
786 'canceled_revoked_before_accepted',
787 'canceled_issue_not_accepted',
788 'canceled_after_revocation_during_discussion',
789 'canceled_after_revocation_during_verification',
790 'canceled_no_initiative_admitted',
791 'finished_without_winner', 'finished_with_winner');
793 COMMENT ON TYPE "issue_state" IS 'State of issues';
796 CREATE TABLE "issue" (
797 UNIQUE ("area_id", "id"), -- index needed for foreign-key on table "event"
798 UNIQUE ("policy_id", "id"), -- index needed for foreign-key on table "event"
799 "id" SERIAL4 PRIMARY KEY,
800 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
801 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
802 "admin_notice" TEXT,
803 "external_reference" TEXT,
804 "state" "issue_state" NOT NULL DEFAULT 'admission',
805 "phase_finished" TIMESTAMPTZ,
806 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
807 "accepted" TIMESTAMPTZ,
808 "half_frozen" TIMESTAMPTZ,
809 "fully_frozen" TIMESTAMPTZ,
810 "closed" TIMESTAMPTZ,
811 "cleaned" TIMESTAMPTZ,
812 "min_admission_time" INTERVAL,
813 "max_admission_time" INTERVAL,
814 "discussion_time" INTERVAL NOT NULL,
815 "verification_time" INTERVAL NOT NULL,
816 "voting_time" INTERVAL NOT NULL,
817 "calculated" TIMESTAMPTZ, -- NOTE: copy of "calculated" column of latest snapshot, but no referential integrity to avoid overhead
818 "latest_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
819 "admission_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
820 "half_freeze_snapshot_id" INT8,
821 FOREIGN KEY ("id", "half_freeze_snapshot_id")
822 REFERENCES "snapshot" ("issue_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE,
823 "full_freeze_snapshot_id" INT8,
824 FOREIGN KEY ("id", "full_freeze_snapshot_id")
825 REFERENCES "snapshot" ("issue_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE,
826 "issue_quorum" INT4,
827 "initiative_quorum" INT4,
828 "population" INT4,
829 "voter_count" INT4,
830 "status_quo_schulze_rank" INT4,
831 CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK (
832 ("min_admission_time" NOTNULL) = ("max_admission_time" NOTNULL) AND
833 ("min_admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created")) ),
834 CONSTRAINT "valid_state" CHECK (
835 (
836 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
837 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
838 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL ) OR
839 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL)
840 ) AND (
841 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
842 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
843 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
844 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
845 ("state" = 'canceled_by_admin' AND "closed" NOTNULL) OR
846 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
847 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
848 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
849 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
850 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" = "fully_frozen") OR
851 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") OR
852 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen")
853 )),
854 CONSTRAINT "phase_finished_only_when_not_closed" CHECK (
855 "phase_finished" ISNULL OR "closed" ISNULL ),
856 CONSTRAINT "state_change_order" CHECK (
857 "created" <= "accepted" AND
858 "accepted" <= "half_frozen" AND
859 "half_frozen" <= "fully_frozen" AND
860 "fully_frozen" <= "closed" ),
861 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
862 "cleaned" ISNULL OR "closed" NOTNULL ),
863 CONSTRAINT "snapshot_required" CHECK (
864 --("accepted" ISNULL OR "admission_snapshot_id" NOTNULL) AND
865 ("half_frozen" ISNULL OR "half_freeze_snapshot_id" NOTNULL) AND
866 ("fully_frozen" ISNULL OR "full_freeze_snapshot_id" NOTNULL) ) );
867 CREATE INDEX "issue_state_idx" ON "issue" ("state");
868 CREATE INDEX "issue_created_idx" ON "issue" ("created");
869 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
870 CREATE INDEX "issue_open_created_idx" ON "issue" ("created") WHERE "closed" ISNULL;
871 CREATE INDEX "issue_latest_snapshot_id_idx" ON "issue" ("latest_snapshot_id");
872 CREATE INDEX "issue_admission_snapshot_id_idx" ON "issue" ("admission_snapshot_id");
873 CREATE INDEX "issue_half_freeze_snapshot_id_idx" ON "issue" ("half_freeze_snapshot_id");
874 CREATE INDEX "issue_full_freeze_snapshot_id_idx" ON "issue" ("full_freeze_snapshot_id");
876 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
878 COMMENT ON COLUMN "issue"."admin_notice" IS 'Public notice by admin to explain manual interventions, or to announce corrections';
879 COMMENT ON COLUMN "issue"."external_reference" IS 'Opaque data field to store an external reference';
880 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';
881 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when the issue was accepted for further discussion (see columns "issue_quorum_num" and "issue_quorum_den" of table "policy" and quorum columns of table "area")';
882 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.';
883 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.';
884 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.';
885 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
886 COMMENT ON COLUMN "issue"."min_admission_time" IS 'Copied from "policy" table at creation of issue';
887 COMMENT ON COLUMN "issue"."max_admission_time" IS 'Copied from "policy" table at creation of issue';
888 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
889 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
890 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
891 COMMENT ON COLUMN "issue"."calculated" IS 'Point in time, when most recent snapshot and "population" and *_count values were calculated (NOTE: value is equal to "snapshot"."calculated" of snapshot with "id"="issue"."latest_snapshot_id")';
892 COMMENT ON COLUMN "issue"."latest_snapshot_id" IS 'Snapshot id of most recent snapshot';
893 COMMENT ON COLUMN "issue"."admission_snapshot_id" IS 'Snapshot id when issue as accepted or canceled in admission phase';
894 COMMENT ON COLUMN "issue"."half_freeze_snapshot_id" IS 'Snapshot id at end of discussion phase';
895 COMMENT ON COLUMN "issue"."full_freeze_snapshot_id" IS 'Snapshot id at end of verification phase';
896 COMMENT ON COLUMN "issue"."issue_quorum" IS 'Calculated number of supporters needed by an initiative of the issue to be "accepted", i.e. pass from ''admission'' to ''discussion'' state';
897 COMMENT ON COLUMN "issue"."initiative_quorum" IS 'Calculated number of satisfied supporters to be reached by an initiative to be "admitted" for voting';
898 COMMENT ON COLUMN "issue"."population" IS 'Count of members in "snapshot_population" table with "snapshot_id" equal to "issue"."latest_snapshot_id"';
899 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';
900 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
903 ALTER TABLE "snapshot" ADD FOREIGN KEY ("issue_id") REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE;
906 CREATE TABLE "issue_order_in_admission_state" (
907 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performans/locking issues; REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
908 "order_in_area" INT4,
909 "order_in_unit" INT4 );
911 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"';
913 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';
914 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';
915 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';
918 CREATE TABLE "initiative" (
919 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
920 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
921 "id" SERIAL4 PRIMARY KEY,
922 "name" TEXT NOT NULL,
923 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
924 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
925 "revoked" TIMESTAMPTZ,
926 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
927 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
928 "location" JSONB,
929 "external_reference" TEXT,
930 "admitted" BOOLEAN,
931 "supporter_count" INT4,
932 "informed_supporter_count" INT4,
933 "satisfied_supporter_count" INT4,
934 "satisfied_informed_supporter_count" INT4,
935 "harmonic_weight" NUMERIC(12, 3),
936 "final_suggestion_order_calculated" BOOLEAN NOT NULL DEFAULT FALSE,
937 "first_preference_votes" INT4,
938 "positive_votes" INT4,
939 "negative_votes" INT4,
940 "direct_majority" BOOLEAN,
941 "indirect_majority" BOOLEAN,
942 "schulze_rank" INT4,
943 "better_than_status_quo" BOOLEAN,
944 "worse_than_status_quo" BOOLEAN,
945 "reverse_beat_path" BOOLEAN,
946 "multistage_majority" BOOLEAN,
947 "eligible" BOOLEAN,
948 "winner" BOOLEAN,
949 "rank" INT4,
950 "text_search_data" TSVECTOR,
951 "draft_text_search_data" TSVECTOR,
952 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
953 CHECK (("revoked" NOTNULL) = ("revoked_by_member_id" NOTNULL)),
954 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
955 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
956 CONSTRAINT "revoked_initiatives_cant_be_admitted"
957 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
958 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
959 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
960 ( "first_preference_votes" ISNULL AND
961 "positive_votes" ISNULL AND "negative_votes" ISNULL AND
962 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
963 "schulze_rank" ISNULL AND
964 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
965 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
966 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
967 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
968 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
969 "eligible" = FALSE OR
970 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
971 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
972 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
973 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
974 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
975 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
976 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
977 CREATE INDEX "initiative_location_idx" ON "initiative" USING gist ((GeoJSON_to_ecluster("location")));
978 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
979 CREATE INDEX "initiative_draft_text_search_data_idx" ON "initiative" USING gin ("draft_text_search_data");
980 CREATE TRIGGER "update_text_search_data"
981 BEFORE INSERT OR UPDATE ON "initiative"
982 FOR EACH ROW EXECUTE PROCEDURE
983 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "name");
985 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.';
987 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
988 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
989 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
990 COMMENT ON COLUMN "initiative"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied from most recent draft)';
991 COMMENT ON COLUMN "initiative"."external_reference" IS 'Opaque data field to store an external reference';
992 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
993 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
994 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
995 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
996 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
997 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';
998 COMMENT ON COLUMN "initiative"."final_suggestion_order_calculated" IS 'Set to TRUE, when "proportional_order" of suggestions has been calculated the last time';
999 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
1000 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
1001 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
1002 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"';
1003 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
1004 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking';
1005 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo';
1006 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)';
1007 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''';
1008 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';
1009 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"';
1010 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"';
1011 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';
1014 CREATE TABLE "battle" (
1015 "issue_id" INT4 NOT NULL,
1016 "winning_initiative_id" INT4,
1017 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1018 "losing_initiative_id" INT4,
1019 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1020 "count" INT4 NOT NULL,
1021 CONSTRAINT "initiative_ids_not_equal" CHECK (
1022 "winning_initiative_id" != "losing_initiative_id" OR
1023 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
1024 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
1025 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
1026 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
1027 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
1029 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';
1032 CREATE TABLE "ignored_initiative" (
1033 PRIMARY KEY ("member_id", "initiative_id"),
1034 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1035 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1036 CREATE INDEX "ignored_initiative_initiative_id_idx" ON "ignored_initiative" ("initiative_id");
1038 COMMENT ON TABLE "ignored_initiative" IS 'An entry in this table denotes that the member does not wish to receive notifications for the given initiative';
1041 CREATE TABLE "draft" (
1042 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
1043 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1044 "id" SERIAL8 PRIMARY KEY,
1045 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1046 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1047 "formatting_engine" TEXT,
1048 "content" TEXT NOT NULL,
1049 "location" JSONB,
1050 "external_reference" TEXT,
1051 "text_search_data" TSVECTOR );
1052 CREATE INDEX "draft_created_idx" ON "draft" ("created");
1053 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
1054 CREATE INDEX "draft_location_idx" ON "draft" USING gist ((GeoJSON_to_ecluster("location")));
1055 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
1056 CREATE TRIGGER "update_text_search_data"
1057 BEFORE INSERT OR UPDATE ON "draft"
1058 FOR EACH ROW EXECUTE PROCEDURE
1059 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1061 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.';
1063 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
1064 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
1065 COMMENT ON COLUMN "draft"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied to "initiative" table if draft is most recent)';
1066 COMMENT ON COLUMN "draft"."external_reference" IS 'Opaque data field to store an external reference';
1069 CREATE TABLE "rendered_draft" (
1070 PRIMARY KEY ("draft_id", "format"),
1071 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1072 "format" TEXT,
1073 "content" TEXT NOT NULL );
1075 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)';
1078 CREATE TABLE "suggestion" (
1079 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
1080 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1081 "id" SERIAL8 PRIMARY KEY,
1082 "draft_id" INT8 NOT NULL,
1083 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1084 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1085 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1086 "name" TEXT NOT NULL,
1087 "formatting_engine" TEXT,
1088 "content" TEXT NOT NULL DEFAULT '',
1089 "location" JSONB,
1090 "external_reference" TEXT,
1091 "text_search_data" TSVECTOR,
1092 "minus2_unfulfilled_count" INT4,
1093 "minus2_fulfilled_count" INT4,
1094 "minus1_unfulfilled_count" INT4,
1095 "minus1_fulfilled_count" INT4,
1096 "plus1_unfulfilled_count" INT4,
1097 "plus1_fulfilled_count" INT4,
1098 "plus2_unfulfilled_count" INT4,
1099 "plus2_fulfilled_count" INT4,
1100 "proportional_order" INT4 );
1101 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
1102 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
1103 CREATE INDEX "suggestion_location_idx" ON "suggestion" USING gist ((GeoJSON_to_ecluster("location")));
1104 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
1105 CREATE TRIGGER "update_text_search_data"
1106 BEFORE INSERT OR UPDATE ON "suggestion"
1107 FOR EACH ROW EXECUTE PROCEDURE
1108 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
1109 "name", "content");
1111 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';
1113 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")';
1114 COMMENT ON COLUMN "suggestion"."location" IS 'Geographic location of suggestion as GeoJSON object';
1115 COMMENT ON COLUMN "suggestion"."external_reference" IS 'Opaque data field to store an external reference';
1116 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1117 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1118 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1119 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1120 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1121 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1122 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1123 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1124 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"';
1127 CREATE TABLE "rendered_suggestion" (
1128 PRIMARY KEY ("suggestion_id", "format"),
1129 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1130 "format" TEXT,
1131 "content" TEXT NOT NULL );
1133 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)';
1136 CREATE TABLE "temporary_suggestion_counts" (
1137 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performance/locking issues; REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1138 "minus2_unfulfilled_count" INT4 NOT NULL,
1139 "minus2_fulfilled_count" INT4 NOT NULL,
1140 "minus1_unfulfilled_count" INT4 NOT NULL,
1141 "minus1_fulfilled_count" INT4 NOT NULL,
1142 "plus1_unfulfilled_count" INT4 NOT NULL,
1143 "plus1_fulfilled_count" INT4 NOT NULL,
1144 "plus2_unfulfilled_count" INT4 NOT NULL,
1145 "plus2_fulfilled_count" INT4 NOT NULL );
1147 COMMENT ON TABLE "temporary_suggestion_counts" IS 'Holds certain calculated values (suggestion counts) temporarily until they can be copied into table "suggestion"';
1149 COMMENT ON COLUMN "temporary_suggestion_counts"."id" IS 'References "suggestion" ("id") but has no referential integrity trigger associated, due to performance/locking issues';
1152 CREATE TABLE "privilege" (
1153 PRIMARY KEY ("unit_id", "member_id"),
1154 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1155 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1156 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1157 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1158 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1159 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1160 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
1161 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
1162 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
1164 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
1166 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
1167 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
1168 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
1169 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
1170 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
1171 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
1172 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';
1175 CREATE TABLE "interest" (
1176 PRIMARY KEY ("issue_id", "member_id"),
1177 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1178 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE );
1179 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
1181 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.';
1184 CREATE TABLE "initiator" (
1185 PRIMARY KEY ("initiative_id", "member_id"),
1186 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1187 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1188 "accepted" BOOLEAN );
1189 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
1191 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.';
1193 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.';
1196 CREATE TABLE "supporter" (
1197 "issue_id" INT4 NOT NULL,
1198 PRIMARY KEY ("initiative_id", "member_id"),
1199 "initiative_id" INT4,
1200 "member_id" INT4,
1201 "draft_id" INT8 NOT NULL,
1202 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1203 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
1204 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
1206 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.';
1208 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1209 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")';
1212 CREATE TABLE "opinion" (
1213 "initiative_id" INT4 NOT NULL,
1214 PRIMARY KEY ("suggestion_id", "member_id"),
1215 "suggestion_id" INT8,
1216 "member_id" INT4,
1217 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
1218 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
1219 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1220 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1221 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
1223 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.';
1225 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
1228 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
1230 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
1233 CREATE TABLE "delegation" (
1234 "id" SERIAL8 PRIMARY KEY,
1235 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1236 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1237 "scope" "delegation_scope" NOT NULL,
1238 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1239 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1240 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1241 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
1242 CONSTRAINT "no_unit_delegation_to_null"
1243 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
1244 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
1245 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
1246 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
1247 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
1248 UNIQUE ("unit_id", "truster_id"),
1249 UNIQUE ("area_id", "truster_id"),
1250 UNIQUE ("issue_id", "truster_id") );
1251 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
1252 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
1254 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
1256 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
1257 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
1258 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
1261 CREATE TABLE "snapshot_issue" (
1262 PRIMARY KEY ("snapshot_id", "issue_id"),
1263 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1264 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); -- NOTE: trigger "delete_snapshot_on_partial_delete" will delete whole "snapshot"
1265 CREATE INDEX "snapshot_issue_issue_id_idx" ON "snapshot_issue" ("issue_id");
1267 COMMENT ON TABLE "snapshot_issue" IS 'List of issues included in a snapshot';
1269 COMMENT ON COLUMN "snapshot_issue"."issue_id" IS 'Issue being part of the snapshot; Trigger "delete_snapshot_on_partial_delete" on "snapshot_issue" table will delete snapshot if an issue of the snapshot is deleted.';
1272 CREATE TABLE "direct_interest_snapshot" (
1273 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1274 "snapshot_id" INT8,
1275 "issue_id" INT4,
1276 FOREIGN KEY ("snapshot_id", "issue_id")
1277 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1278 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1279 "weight" INT4 );
1280 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
1282 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';
1284 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
1287 CREATE TABLE "delegating_interest_snapshot" (
1288 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1289 "snapshot_id" INT8,
1290 "issue_id" INT4,
1291 FOREIGN KEY ("snapshot_id", "issue_id")
1292 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1293 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1294 "weight" INT4,
1295 "scope" "delegation_scope" NOT NULL,
1296 "delegate_member_ids" INT4[] NOT NULL );
1297 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
1299 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';
1301 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
1302 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
1303 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"';
1306 CREATE TABLE "direct_supporter_snapshot" (
1307 PRIMARY KEY ("snapshot_id", "initiative_id", "member_id"),
1308 "snapshot_id" INT8,
1309 "issue_id" INT4 NOT NULL,
1310 FOREIGN KEY ("snapshot_id", "issue_id")
1311 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1312 "initiative_id" INT4,
1313 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1314 "draft_id" INT8 NOT NULL,
1315 "informed" BOOLEAN NOT NULL,
1316 "satisfied" BOOLEAN NOT NULL,
1317 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1318 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1319 FOREIGN KEY ("snapshot_id", "issue_id", "member_id") REFERENCES "direct_interest_snapshot" ("snapshot_id", "issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1320 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1322 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';
1324 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';
1325 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1326 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1329 CREATE TABLE "non_voter" (
1330 PRIMARY KEY ("member_id", "issue_id"),
1331 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1332 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1333 CREATE INDEX "non_voter_issue_id_idx" ON "non_voter" ("issue_id");
1335 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1338 CREATE TABLE "direct_voter" (
1339 PRIMARY KEY ("issue_id", "member_id"),
1340 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1341 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1342 "weight" INT4,
1343 "comment_changed" TIMESTAMPTZ,
1344 "formatting_engine" TEXT,
1345 "comment" TEXT,
1346 "text_search_data" TSVECTOR );
1347 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1348 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
1349 CREATE TRIGGER "update_text_search_data"
1350 BEFORE INSERT OR UPDATE ON "direct_voter"
1351 FOR EACH ROW EXECUTE PROCEDURE
1352 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
1354 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';
1356 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1357 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';
1358 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';
1359 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.';
1362 CREATE TABLE "rendered_voter_comment" (
1363 PRIMARY KEY ("issue_id", "member_id", "format"),
1364 FOREIGN KEY ("issue_id", "member_id")
1365 REFERENCES "direct_voter" ("issue_id", "member_id")
1366 ON DELETE CASCADE ON UPDATE CASCADE,
1367 "issue_id" INT4,
1368 "member_id" INT4,
1369 "format" TEXT,
1370 "content" TEXT NOT NULL );
1372 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)';
1375 CREATE TABLE "delegating_voter" (
1376 PRIMARY KEY ("issue_id", "member_id"),
1377 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1378 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1379 "weight" INT4,
1380 "scope" "delegation_scope" NOT NULL,
1381 "delegate_member_ids" INT4[] NOT NULL );
1382 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1384 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';
1386 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1387 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1388 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"';
1391 CREATE TABLE "vote" (
1392 "issue_id" INT4 NOT NULL,
1393 PRIMARY KEY ("initiative_id", "member_id"),
1394 "initiative_id" INT4,
1395 "member_id" INT4,
1396 "grade" INT4 NOT NULL,
1397 "first_preference" BOOLEAN,
1398 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1399 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1400 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
1401 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
1402 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1404 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';
1406 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1407 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.';
1408 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.';
1411 CREATE TABLE "posting" (
1412 "id" SERIAL8 PRIMARY KEY,
1413 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1414 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1415 "message" TEXT NOT NULL,
1416 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1417 "area_id" INT4,
1418 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1419 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1420 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1421 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1422 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1423 "initiative_id" INT4,
1424 "suggestion_id" INT8,
1425 -- NOTE: no referential integrity for suggestions because those are
1426 -- actually deleted
1427 -- FOREIGN KEY ("initiative_id", "suggestion_id")
1428 -- REFERENCES "suggestion" ("initiative_id", "id")
1429 -- ON DELETE CASCADE ON UPDATE CASCADE,
1430 CONSTRAINT "area_requires_unit" CHECK (
1431 "area_id" ISNULL OR "unit_id" NOTNULL ),
1432 CONSTRAINT "policy_set_when_issue_set" CHECK (
1433 ("policy_id" NOTNULL) = ("issue_id" NOTNULL) ),
1434 CONSTRAINT "issue_requires_area" CHECK (
1435 "issue_id" ISNULL OR "area_id" NOTNULL ),
1436 CONSTRAINT "initiative_requires_issue" CHECK (
1437 "initiative_id" ISNULL OR "issue_id" NOTNULL ),
1438 CONSTRAINT "suggestion_requires_initiative" CHECK (
1439 "suggestion_id" ISNULL OR "initiative_id" NOTNULL ) );
1440 CREATE INDEX "posting_global_idx" ON "posting" USING gist ((pstamp("author_id", "id")));
1441 CREATE INDEX "posting_unit_idx" ON "posting" USING gist ("unit_id", (pstamp("author_id", "id"))) WHERE "unit_id" NOTNULL;
1442 CREATE INDEX "posting_area_idx" ON "posting" USING gist ("area_id", (pstamp("author_id", "id"))) WHERE "area_id" NOTNULL;
1443 CREATE INDEX "posting_policy_idx" ON "posting" USING gist ("policy_id", (pstamp("author_id", "id"))) WHERE "policy_id" NOTNULL;
1444 CREATE INDEX "posting_issue_idx" ON "posting" USING gist ("issue_id", (pstamp("author_id", "id"))) WHERE "issue_id" NOTNULL;
1445 CREATE INDEX "posting_initiative_idx" ON "posting" USING gist ("initiative_id", (pstamp("author_id", "id"))) WHERE "initiative_id" NOTNULL;
1446 CREATE INDEX "posting_suggestion_idx" ON "posting" USING gist ("suggestion_id", (pstamp("author_id", "id"))) WHERE "suggestion_id" NOTNULL;
1448 COMMENT ON TABLE "posting" IS 'Text postings of members; a text posting may optionally be associated to a unit, area, policy, issue, initiative, or suggestion';
1451 CREATE TYPE "event_type" AS ENUM (
1452 'unit_created',
1453 'unit_updated',
1454 'area_created',
1455 'area_updated',
1456 'policy_created',
1457 'policy_updated',
1458 'issue_state_changed',
1459 'initiative_created_in_new_issue',
1460 'initiative_created_in_existing_issue',
1461 'initiative_revoked',
1462 'new_draft_created',
1463 'suggestion_created',
1464 'suggestion_deleted',
1465 'member_activated',
1466 'member_deleted',
1467 'member_active',
1468 'member_name_updated',
1469 'member_profile_updated',
1470 'member_image_updated',
1471 'interest',
1472 'initiator',
1473 'support',
1474 'support_updated',
1475 'suggestion_rated',
1476 'delegation',
1477 'contact',
1478 'posting_created' );
1480 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1483 CREATE TABLE "event" (
1484 "id" SERIAL8 PRIMARY KEY,
1485 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1486 "event" "event_type" NOT NULL,
1487 "posting_id" INT8 REFERENCES "posting" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1488 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1489 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1490 "scope" "delegation_scope",
1491 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1492 "area_id" INT4,
1493 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1494 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1495 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1496 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1497 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1498 "state" "issue_state",
1499 "initiative_id" INT4,
1500 "draft_id" INT8,
1501 "suggestion_id" INT8,
1502 "boolean_value" BOOLEAN,
1503 "numeric_value" INT4,
1504 "text_value" TEXT,
1505 "old_text_value" TEXT,
1506 FOREIGN KEY ("issue_id", "initiative_id")
1507 REFERENCES "initiative" ("issue_id", "id")
1508 ON DELETE CASCADE ON UPDATE CASCADE,
1509 FOREIGN KEY ("initiative_id", "draft_id")
1510 REFERENCES "draft" ("initiative_id", "id")
1511 ON DELETE CASCADE ON UPDATE CASCADE,
1512 -- NOTE: no referential integrity for suggestions because those are
1513 -- actually deleted
1514 -- FOREIGN KEY ("initiative_id", "suggestion_id")
1515 -- REFERENCES "suggestion" ("initiative_id", "id")
1516 -- ON DELETE CASCADE ON UPDATE CASCADE,
1517 CONSTRAINT "constr_for_issue_state_changed" CHECK (
1518 "event" != 'issue_state_changed' OR (
1519 "posting_id" ISNULL AND
1520 "member_id" ISNULL AND
1521 "other_member_id" ISNULL AND
1522 "scope" ISNULL AND
1523 "unit_id" NOTNULL AND
1524 "area_id" NOTNULL AND
1525 "policy_id" NOTNULL AND
1526 "issue_id" NOTNULL AND
1527 "state" NOTNULL AND
1528 "initiative_id" ISNULL AND
1529 "draft_id" ISNULL AND
1530 "suggestion_id" ISNULL AND
1531 "boolean_value" ISNULL AND
1532 "numeric_value" ISNULL AND
1533 "text_value" ISNULL AND
1534 "old_text_value" ISNULL )),
1535 CONSTRAINT "constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1536 "event" NOT IN (
1537 'initiative_created_in_new_issue',
1538 'initiative_created_in_existing_issue',
1539 'initiative_revoked',
1540 'new_draft_created'
1541 ) OR (
1542 "posting_id" ISNULL AND
1543 "member_id" NOTNULL AND
1544 "other_member_id" ISNULL AND
1545 "scope" ISNULL AND
1546 "unit_id" NOTNULL AND
1547 "area_id" NOTNULL AND
1548 "policy_id" NOTNULL AND
1549 "issue_id" NOTNULL AND
1550 "state" NOTNULL AND
1551 "initiative_id" NOTNULL AND
1552 "draft_id" NOTNULL AND
1553 "suggestion_id" ISNULL AND
1554 "boolean_value" ISNULL AND
1555 "numeric_value" ISNULL AND
1556 "text_value" ISNULL AND
1557 "old_text_value" ISNULL )),
1558 CONSTRAINT "constr_for_suggestion_creation" CHECK (
1559 "event" != 'suggestion_created' OR (
1560 "posting_id" ISNULL AND
1561 "member_id" NOTNULL AND
1562 "other_member_id" ISNULL AND
1563 "scope" ISNULL AND
1564 "unit_id" NOTNULL AND
1565 "area_id" NOTNULL AND
1566 "policy_id" NOTNULL AND
1567 "issue_id" NOTNULL AND
1568 "state" NOTNULL AND
1569 "initiative_id" NOTNULL AND
1570 "draft_id" ISNULL AND
1571 "suggestion_id" NOTNULL AND
1572 "boolean_value" ISNULL AND
1573 "numeric_value" ISNULL AND
1574 "text_value" ISNULL AND
1575 "old_text_value" ISNULL )),
1576 CONSTRAINT "constr_for_suggestion_removal" CHECK (
1577 "event" != 'suggestion_deleted' OR (
1578 "posting_id" ISNULL AND
1579 "member_id" ISNULL AND
1580 "other_member_id" ISNULL AND
1581 "scope" ISNULL AND
1582 "unit_id" NOTNULL AND
1583 "area_id" NOTNULL AND
1584 "policy_id" NOTNULL AND
1585 "issue_id" NOTNULL AND
1586 "state" NOTNULL AND
1587 "initiative_id" NOTNULL AND
1588 "draft_id" ISNULL AND
1589 "suggestion_id" NOTNULL AND
1590 "boolean_value" ISNULL AND
1591 "numeric_value" ISNULL AND
1592 "text_value" ISNULL AND
1593 "old_text_value" ISNULL )),
1594 CONSTRAINT "constr_for_value_less_member_event" CHECK (
1595 "event" NOT IN (
1596 'member_activated',
1597 'member_deleted',
1598 'member_profile_updated',
1599 'member_image_updated'
1600 ) OR (
1601 "posting_id" ISNULL AND
1602 "member_id" NOTNULL AND
1603 "other_member_id" ISNULL AND
1604 "scope" ISNULL AND
1605 "unit_id" ISNULL AND
1606 "area_id" ISNULL AND
1607 "policy_id" ISNULL AND
1608 "issue_id" ISNULL AND
1609 "state" ISNULL AND
1610 "initiative_id" ISNULL AND
1611 "draft_id" ISNULL AND
1612 "suggestion_id" ISNULL AND
1613 "boolean_value" ISNULL AND
1614 "numeric_value" ISNULL AND
1615 "text_value" ISNULL AND
1616 "old_text_value" ISNULL )),
1617 CONSTRAINT "constr_for_member_active" CHECK (
1618 "event" != 'member_active' OR (
1619 "posting_id" ISNULL AND
1620 "member_id" NOTNULL AND
1621 "other_member_id" ISNULL AND
1622 "scope" ISNULL AND
1623 "unit_id" ISNULL AND
1624 "area_id" ISNULL AND
1625 "policy_id" ISNULL AND
1626 "issue_id" ISNULL AND
1627 "state" ISNULL AND
1628 "initiative_id" ISNULL AND
1629 "draft_id" ISNULL AND
1630 "suggestion_id" ISNULL AND
1631 "boolean_value" NOTNULL AND
1632 "numeric_value" ISNULL AND
1633 "text_value" ISNULL AND
1634 "old_text_value" ISNULL )),
1635 CONSTRAINT "constr_for_member_name_updated" CHECK (
1636 "event" != 'member_name_updated' OR (
1637 "posting_id" ISNULL AND
1638 "member_id" NOTNULL AND
1639 "other_member_id" ISNULL AND
1640 "scope" ISNULL AND
1641 "unit_id" ISNULL AND
1642 "area_id" ISNULL AND
1643 "policy_id" ISNULL AND
1644 "issue_id" ISNULL AND
1645 "state" ISNULL AND
1646 "initiative_id" ISNULL AND
1647 "draft_id" ISNULL AND
1648 "suggestion_id" ISNULL AND
1649 "boolean_value" ISNULL AND
1650 "numeric_value" ISNULL AND
1651 "text_value" NOTNULL AND
1652 "old_text_value" NOTNULL )),
1653 CONSTRAINT "constr_for_interest" CHECK (
1654 "event" != 'interest' OR (
1655 "posting_id" ISNULL AND
1656 "member_id" NOTNULL AND
1657 "other_member_id" ISNULL AND
1658 "scope" ISNULL AND
1659 "unit_id" NOTNULL AND
1660 "area_id" NOTNULL AND
1661 "policy_id" NOTNULL AND
1662 "issue_id" NOTNULL AND
1663 "state" NOTNULL AND
1664 "initiative_id" ISNULL AND
1665 "draft_id" ISNULL AND
1666 "suggestion_id" ISNULL AND
1667 "boolean_value" NOTNULL AND
1668 "numeric_value" ISNULL AND
1669 "text_value" ISNULL AND
1670 "old_text_value" ISNULL )),
1671 CONSTRAINT "constr_for_initiator" CHECK (
1672 "event" != 'initiator' OR (
1673 "posting_id" ISNULL AND
1674 "member_id" NOTNULL AND
1675 "other_member_id" ISNULL AND
1676 "scope" ISNULL AND
1677 "unit_id" NOTNULL AND
1678 "area_id" NOTNULL AND
1679 "policy_id" NOTNULL AND
1680 "issue_id" NOTNULL AND
1681 "state" NOTNULL AND
1682 "initiative_id" NOTNULL AND
1683 "draft_id" ISNULL AND
1684 "suggestion_id" ISNULL AND
1685 "boolean_value" NOTNULL AND
1686 "numeric_value" ISNULL AND
1687 "text_value" ISNULL AND
1688 "old_text_value" ISNULL )),
1689 CONSTRAINT "constr_for_support" CHECK (
1690 "event" != 'support' OR (
1691 "posting_id" ISNULL AND
1692 "member_id" NOTNULL AND
1693 "other_member_id" ISNULL AND
1694 "scope" ISNULL AND
1695 "unit_id" NOTNULL AND
1696 "area_id" NOTNULL AND
1697 "policy_id" NOTNULL AND
1698 "issue_id" NOTNULL AND
1699 "state" NOTNULL AND
1700 "initiative_id" NOTNULL AND
1701 ("draft_id" NOTNULL) = ("boolean_value" = TRUE) AND
1702 "suggestion_id" ISNULL AND
1703 "boolean_value" NOTNULL AND
1704 "numeric_value" ISNULL AND
1705 "text_value" ISNULL AND
1706 "old_text_value" ISNULL )),
1707 CONSTRAINT "constr_for_support_updated" CHECK (
1708 "event" != 'support_updated' OR (
1709 "posting_id" ISNULL AND
1710 "member_id" NOTNULL AND
1711 "other_member_id" ISNULL AND
1712 "scope" ISNULL AND
1713 "unit_id" NOTNULL AND
1714 "area_id" NOTNULL AND
1715 "policy_id" NOTNULL AND
1716 "issue_id" NOTNULL AND
1717 "state" NOTNULL AND
1718 "initiative_id" NOTNULL AND
1719 "draft_id" NOTNULL AND
1720 "suggestion_id" ISNULL AND
1721 "boolean_value" ISNULL AND
1722 "numeric_value" ISNULL AND
1723 "text_value" ISNULL AND
1724 "old_text_value" ISNULL )),
1725 CONSTRAINT "constr_for_suggestion_rated" CHECK (
1726 "event" != 'suggestion_rated' OR (
1727 "posting_id" ISNULL AND
1728 "member_id" NOTNULL AND
1729 "other_member_id" ISNULL AND
1730 "scope" ISNULL AND
1731 "unit_id" NOTNULL AND
1732 "area_id" NOTNULL AND
1733 "policy_id" NOTNULL AND
1734 "issue_id" NOTNULL AND
1735 "state" NOTNULL AND
1736 "initiative_id" NOTNULL AND
1737 "draft_id" ISNULL AND
1738 "suggestion_id" NOTNULL AND
1739 ("boolean_value" NOTNULL) = ("numeric_value" != 0) AND
1740 "numeric_value" NOTNULL AND
1741 "numeric_value" IN (-2, -1, 0, 1, 2) AND
1742 "text_value" ISNULL AND
1743 "old_text_value" ISNULL )),
1744 CONSTRAINT "constr_for_delegation" CHECK (
1745 "event" != 'delegation' OR (
1746 "posting_id" ISNULL AND
1747 "member_id" NOTNULL AND
1748 (("other_member_id" ISNULL) OR ("boolean_value" = TRUE)) AND
1749 "scope" NOTNULL AND
1750 "unit_id" NOTNULL AND
1751 ("area_id" NOTNULL) = ("scope" != 'unit'::"delegation_scope") AND
1752 "policy_id" ISNULL AND
1753 ("issue_id" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1754 ("state" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1755 "initiative_id" ISNULL AND
1756 "draft_id" ISNULL AND
1757 "suggestion_id" ISNULL AND
1758 "boolean_value" NOTNULL AND
1759 "numeric_value" ISNULL AND
1760 "text_value" ISNULL AND
1761 "old_text_value" ISNULL )),
1762 CONSTRAINT "constr_for_contact" CHECK (
1763 "event" != 'contact' OR (
1764 "posting_id" ISNULL AND
1765 "member_id" NOTNULL AND
1766 "other_member_id" NOTNULL AND
1767 "scope" ISNULL AND
1768 "unit_id" ISNULL AND
1769 "area_id" ISNULL AND
1770 "policy_id" ISNULL AND
1771 "issue_id" ISNULL AND
1772 "state" ISNULL AND
1773 "initiative_id" ISNULL AND
1774 "draft_id" ISNULL AND
1775 "suggestion_id" ISNULL AND
1776 "boolean_value" NOTNULL AND
1777 "numeric_value" ISNULL AND
1778 "text_value" ISNULL AND
1779 "old_text_value" ISNULL )),
1780 CONSTRAINT "constr_for_posting_created" CHECK (
1781 "event" != 'posting_created' OR (
1782 "posting_id" NOTNULL AND
1783 "member_id" NOTNULL AND
1784 "other_member_id" ISNULL AND
1785 "scope" ISNULL AND
1786 "state" ISNULL AND
1787 ("area_id" ISNULL OR "unit_id" NOTNULL) AND
1788 ("policy_id" NOTNULL) = ("issue_id" NOTNULL) AND
1789 ("issue_id" ISNULL OR "area_id" NOTNULL) AND
1790 ("state" NOTNULL) = ("issue_id" NOTNULL) AND
1791 ("initiative_id" ISNULL OR "issue_id" NOTNULL) AND
1792 "draft_id" ISNULL AND
1793 ("suggestion_id" ISNULL OR "initiative_id" NOTNULL) AND
1794 "boolean_value" ISNULL AND
1795 "numeric_value" ISNULL AND
1796 "text_value" ISNULL AND
1797 "old_text_value" ISNULL )) );
1798 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1799 CREATE INDEX "event_tl_global_idx" ON "event" USING gist ((pstamp("member_id", "id")));
1800 CREATE INDEX "event_tl_unit_idx" ON "event" USING gist ("unit_id", (pstamp("member_id", "id"))) WHERE "unit_id" NOTNULL;
1801 CREATE INDEX "event_tl_area_idx" ON "event" USING gist ("area_id", (pstamp("member_id", "id"))) WHERE "area_id" NOTNULL;
1802 CREATE INDEX "event_tl_policy_idx" ON "event" USING gist ("policy_id", (pstamp("member_id", "id"))) WHERE "policy_id" NOTNULL;
1803 CREATE INDEX "event_tl_issue_idx" ON "event" USING gist ("issue_id", (pstamp("member_id", "id"))) WHERE "issue_id" NOTNULL;
1804 CREATE INDEX "event_tl_initiative_idx" ON "event" USING gist ("initiative_id", (pstamp("member_id", "id"))) WHERE "initiative_id" NOTNULL;
1805 CREATE INDEX "event_tl_suggestion_idx" ON "event" USING gist ("suggestion_id", (pstamp("member_id", "id"))) WHERE "suggestion_id" NOTNULL;
1808 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1810 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1811 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1812 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1813 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1816 CREATE TABLE "event_processed" (
1817 "event_id" INT8 NOT NULL );
1818 CREATE UNIQUE INDEX "event_processed_singleton_idx" ON "event_processed" ((1));
1820 COMMENT ON TABLE "event_processed" IS 'This table stores one row with the last event_id, for which event handlers have been executed (e.g. notifications having been sent out)';
1821 COMMENT ON INDEX "event_processed_singleton_idx" IS 'This index ensures that "event_processed" only contains one row maximum.';
1824 CREATE TABLE "notification_initiative_sent" (
1825 PRIMARY KEY ("member_id", "initiative_id"),
1826 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1827 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1828 "last_draft_id" INT8 NOT NULL,
1829 "last_suggestion_id" INT8 );
1830 CREATE INDEX "notification_initiative_sent_initiative_idx" ON "notification_initiative_sent" ("initiative_id");
1832 COMMENT ON TABLE "notification_initiative_sent" IS 'Information which initiatives have been promoted to a member in a scheduled notification mail';
1834 COMMENT ON COLUMN "notification_initiative_sent"."last_draft_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1835 COMMENT ON COLUMN "notification_initiative_sent"."last_suggestion_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1838 CREATE TABLE "newsletter" (
1839 "id" SERIAL4 PRIMARY KEY,
1840 "published" TIMESTAMPTZ NOT NULL,
1841 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1842 "include_all_members" BOOLEAN NOT NULL,
1843 "sent" TIMESTAMPTZ,
1844 "subject" TEXT NOT NULL,
1845 "content" TEXT NOT NULL );
1846 CREATE INDEX "newsletter_unit_id_idx" ON "newsletter" ("unit_id", "published");
1847 CREATE INDEX "newsletter_all_units_published_idx" ON "newsletter" ("published") WHERE "unit_id" ISNULL;
1848 CREATE INDEX "newsletter_published_idx" ON "newsletter" ("published");
1850 COMMENT ON TABLE "newsletter" IS 'Contains newsletters created by administrators to be sent out and for further reference';
1852 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter is to be sent out (and made available in the frontend)';
1853 COMMENT ON COLUMN "newsletter"."unit_id" IS 'If set, only members with voting right in the given unit are considered to be recipients';
1854 COMMENT ON COLUMN "newsletter"."include_all_members" IS 'TRUE = include all members regardless of their ''disable_notifications'' setting';
1855 COMMENT ON COLUMN "newsletter"."sent" IS 'Timestamp when the newsletter has been mailed out';
1856 COMMENT ON COLUMN "newsletter"."subject" IS 'Subject line (e.g. to be used for the email)';
1857 COMMENT ON COLUMN "newsletter"."content" IS 'Plain text content of the newsletter';
1861 ----------------------------------------------
1862 -- Writing of history entries and event log --
1863 ----------------------------------------------
1866 CREATE FUNCTION "write_member_history_trigger"()
1867 RETURNS TRIGGER
1868 LANGUAGE 'plpgsql' VOLATILE AS $$
1869 BEGIN
1870 IF
1871 ( NEW."active" != OLD."active" OR
1872 NEW."name" != OLD."name" ) AND
1873 OLD."activated" NOTNULL
1874 THEN
1875 INSERT INTO "member_history"
1876 ("member_id", "active", "name")
1877 VALUES (NEW."id", OLD."active", OLD."name");
1878 END IF;
1879 RETURN NULL;
1880 END;
1881 $$;
1883 CREATE TRIGGER "write_member_history"
1884 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1885 "write_member_history_trigger"();
1887 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1888 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1891 CREATE FUNCTION "write_event_unit_trigger"()
1892 RETURNS TRIGGER
1893 LANGUAGE 'plpgsql' VOLATILE AS $$
1894 DECLARE
1895 "event_v" "event_type";
1896 BEGIN
1897 IF TG_OP = 'UPDATE' THEN
1898 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1899 RETURN NULL;
1900 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1901 -- "event_v" := 'unit_created';
1902 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1903 -- "event_v" := 'unit_deleted';
1904 ELSIF OLD != NEW THEN
1905 "event_v" := 'unit_updated';
1906 ELSE
1907 RETURN NULL;
1908 END IF;
1909 ELSE
1910 "event_v" := 'unit_created';
1911 END IF;
1912 INSERT INTO "event" ("event", "unit_id") VALUES ("event_v", NEW."id");
1913 RETURN NULL;
1914 END;
1915 $$;
1917 CREATE TRIGGER "write_event_unit" AFTER INSERT OR UPDATE ON "unit"
1918 FOR EACH ROW EXECUTE PROCEDURE "write_event_unit_trigger"();
1920 COMMENT ON FUNCTION "write_event_unit_trigger"() IS 'Implementation of trigger "write_event_unit" on table "unit"';
1921 COMMENT ON TRIGGER "write_event_unit" ON "unit" IS 'Create entry in "event" table on new or changed/disabled units';
1924 CREATE FUNCTION "write_event_area_trigger"()
1925 RETURNS TRIGGER
1926 LANGUAGE 'plpgsql' VOLATILE AS $$
1927 DECLARE
1928 "event_v" "event_type";
1929 BEGIN
1930 IF TG_OP = 'UPDATE' THEN
1931 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1932 RETURN NULL;
1933 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1934 -- "event_v" := 'area_created';
1935 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1936 -- "event_v" := 'area_deleted';
1937 ELSIF OLD != NEW THEN
1938 "event_v" := 'area_updated';
1939 ELSE
1940 RETURN NULL;
1941 END IF;
1942 ELSE
1943 "event_v" := 'area_created';
1944 END IF;
1945 INSERT INTO "event" ("event", "area_id") VALUES ("event_v", NEW."id");
1946 RETURN NULL;
1947 END;
1948 $$;
1950 CREATE TRIGGER "write_event_area" AFTER INSERT OR UPDATE ON "area"
1951 FOR EACH ROW EXECUTE PROCEDURE "write_event_area_trigger"();
1953 COMMENT ON FUNCTION "write_event_area_trigger"() IS 'Implementation of trigger "write_event_area" on table "area"';
1954 COMMENT ON TRIGGER "write_event_area" ON "area" IS 'Create entry in "event" table on new or changed/disabled areas';
1957 CREATE FUNCTION "write_event_policy_trigger"()
1958 RETURNS TRIGGER
1959 LANGUAGE 'plpgsql' VOLATILE AS $$
1960 DECLARE
1961 "event_v" "event_type";
1962 BEGIN
1963 IF TG_OP = 'UPDATE' THEN
1964 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1965 RETURN NULL;
1966 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1967 -- "event_v" := 'policy_created';
1968 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1969 -- "event_v" := 'policy_deleted';
1970 ELSIF OLD != NEW THEN
1971 "event_v" := 'policy_updated';
1972 ELSE
1973 RETURN NULL;
1974 END IF;
1975 ELSE
1976 "event_v" := 'policy_created';
1977 END IF;
1978 INSERT INTO "event" ("event", "policy_id") VALUES ("event_v", NEW."id");
1979 RETURN NULL;
1980 END;
1981 $$;
1983 CREATE TRIGGER "write_event_policy" AFTER INSERT OR UPDATE ON "policy"
1984 FOR EACH ROW EXECUTE PROCEDURE "write_event_policy_trigger"();
1986 COMMENT ON FUNCTION "write_event_policy_trigger"() IS 'Implementation of trigger "write_event_policy" on table "policy"';
1987 COMMENT ON TRIGGER "write_event_policy" ON "policy" IS 'Create entry in "event" table on new or changed/disabled policies';
1990 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1991 RETURNS TRIGGER
1992 LANGUAGE 'plpgsql' VOLATILE AS $$
1993 DECLARE
1994 "area_row" "area"%ROWTYPE;
1995 BEGIN
1996 IF NEW."state" != OLD."state" THEN
1997 SELECT * INTO "area_row" FROM "area" WHERE "id" = NEW."area_id"
1998 FOR SHARE;
1999 INSERT INTO "event" (
2000 "event",
2001 "unit_id", "area_id", "policy_id", "issue_id", "state"
2002 ) VALUES (
2003 'issue_state_changed',
2004 "area_row"."unit_id", NEW."area_id", NEW."policy_id",
2005 NEW."id", NEW."state"
2006 );
2007 END IF;
2008 RETURN NULL;
2009 END;
2010 $$;
2012 CREATE TRIGGER "write_event_issue_state_changed"
2013 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
2014 "write_event_issue_state_changed_trigger"();
2016 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
2017 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
2020 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
2021 RETURNS TRIGGER
2022 LANGUAGE 'plpgsql' VOLATILE AS $$
2023 DECLARE
2024 "initiative_row" "initiative"%ROWTYPE;
2025 "issue_row" "issue"%ROWTYPE;
2026 "area_row" "area"%ROWTYPE;
2027 "event_v" "event_type";
2028 BEGIN
2029 SELECT * INTO "initiative_row" FROM "initiative"
2030 WHERE "id" = NEW."initiative_id" FOR SHARE;
2031 SELECT * INTO "issue_row" FROM "issue"
2032 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2033 SELECT * INTO "area_row" FROM "area"
2034 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2035 IF EXISTS (
2036 SELECT NULL FROM "draft"
2037 WHERE "initiative_id" = NEW."initiative_id" AND "id" != NEW."id"
2038 FOR SHARE
2039 ) THEN
2040 "event_v" := 'new_draft_created';
2041 ELSE
2042 IF EXISTS (
2043 SELECT NULL FROM "initiative"
2044 WHERE "issue_id" = "initiative_row"."issue_id"
2045 AND "id" != "initiative_row"."id"
2046 FOR SHARE
2047 ) THEN
2048 "event_v" := 'initiative_created_in_existing_issue';
2049 ELSE
2050 "event_v" := 'initiative_created_in_new_issue';
2051 END IF;
2052 END IF;
2053 INSERT INTO "event" (
2054 "event", "member_id",
2055 "unit_id", "area_id", "policy_id", "issue_id", "state",
2056 "initiative_id", "draft_id"
2057 ) VALUES (
2058 "event_v", NEW."author_id",
2059 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
2060 "initiative_row"."issue_id", "issue_row"."state",
2061 NEW."initiative_id", NEW."id"
2062 );
2063 RETURN NULL;
2064 END;
2065 $$;
2067 CREATE TRIGGER "write_event_initiative_or_draft_created"
2068 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
2069 "write_event_initiative_or_draft_created_trigger"();
2071 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
2072 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
2075 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
2076 RETURNS TRIGGER
2077 LANGUAGE 'plpgsql' VOLATILE AS $$
2078 DECLARE
2079 "issue_row" "issue"%ROWTYPE;
2080 "area_row" "area"%ROWTYPE;
2081 "draft_id_v" "draft"."id"%TYPE;
2082 BEGIN
2083 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
2084 -- NOTE: lock for primary key update to avoid new drafts
2085 PERFORM NULL FROM "initiative" WHERE "id" = NEW."id" FOR UPDATE;
2086 SELECT * INTO "issue_row" FROM "issue"
2087 WHERE "id" = NEW."issue_id" FOR SHARE;
2088 SELECT * INTO "area_row" FROM "area"
2089 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2090 -- NOTE: FOR SHARE cannot be used with DISTINCT in view "current_draft"
2091 PERFORM NULL FROM "draft" WHERE "initiative_id" = NEW."id" FOR SHARE;
2092 SELECT "id" INTO "draft_id_v" FROM "current_draft"
2093 WHERE "initiative_id" = NEW."id";
2094 INSERT INTO "event" (
2095 "event", "member_id",
2096 "unit_id", "area_id", "policy_id", "issue_id", "state",
2097 "initiative_id", "draft_id"
2098 ) VALUES (
2099 'initiative_revoked', NEW."revoked_by_member_id",
2100 "area_row"."unit_id", "issue_row"."area_id",
2101 "issue_row"."policy_id",
2102 NEW."issue_id", "issue_row"."state",
2103 NEW."id", "draft_id_v"
2104 );
2105 END IF;
2106 RETURN NULL;
2107 END;
2108 $$;
2110 CREATE TRIGGER "write_event_initiative_revoked"
2111 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
2112 "write_event_initiative_revoked_trigger"();
2114 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
2115 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
2118 CREATE FUNCTION "write_event_suggestion_created_trigger"()
2119 RETURNS TRIGGER
2120 LANGUAGE 'plpgsql' VOLATILE AS $$
2121 DECLARE
2122 "initiative_row" "initiative"%ROWTYPE;
2123 "issue_row" "issue"%ROWTYPE;
2124 "area_row" "area"%ROWTYPE;
2125 BEGIN
2126 SELECT * INTO "initiative_row" FROM "initiative"
2127 WHERE "id" = NEW."initiative_id" FOR SHARE;
2128 SELECT * INTO "issue_row" FROM "issue"
2129 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2130 SELECT * INTO "area_row" FROM "area"
2131 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2132 INSERT INTO "event" (
2133 "event", "member_id",
2134 "unit_id", "area_id", "policy_id", "issue_id", "state",
2135 "initiative_id", "suggestion_id"
2136 ) VALUES (
2137 'suggestion_created', NEW."author_id",
2138 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
2139 "initiative_row"."issue_id", "issue_row"."state",
2140 NEW."initiative_id", NEW."id"
2141 );
2142 RETURN NULL;
2143 END;
2144 $$;
2146 CREATE TRIGGER "write_event_suggestion_created"
2147 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2148 "write_event_suggestion_created_trigger"();
2150 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
2151 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2154 CREATE FUNCTION "write_event_suggestion_removed_trigger"()
2155 RETURNS TRIGGER
2156 LANGUAGE 'plpgsql' VOLATILE AS $$
2157 DECLARE
2158 "initiative_row" "initiative"%ROWTYPE;
2159 "issue_row" "issue"%ROWTYPE;
2160 "area_row" "area"%ROWTYPE;
2161 BEGIN
2162 SELECT * INTO "initiative_row" FROM "initiative"
2163 WHERE "id" = OLD."initiative_id" FOR SHARE;
2164 IF "initiative_row"."id" NOTNULL THEN
2165 SELECT * INTO "issue_row" FROM "issue"
2166 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2167 SELECT * INTO "area_row" FROM "area"
2168 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2169 INSERT INTO "event" (
2170 "event",
2171 "unit_id", "area_id", "policy_id", "issue_id", "state",
2172 "initiative_id", "suggestion_id"
2173 ) VALUES (
2174 'suggestion_deleted',
2175 "area_row"."unit_id", "issue_row"."area_id",
2176 "issue_row"."policy_id",
2177 "initiative_row"."issue_id", "issue_row"."state",
2178 OLD."initiative_id", OLD."id"
2179 );
2180 END IF;
2181 RETURN NULL;
2182 END;
2183 $$;
2185 CREATE TRIGGER "write_event_suggestion_removed"
2186 AFTER DELETE ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2187 "write_event_suggestion_removed_trigger"();
2189 COMMENT ON FUNCTION "write_event_suggestion_removed_trigger"() IS 'Implementation of trigger "write_event_suggestion_removed" on table "issue"';
2190 COMMENT ON TRIGGER "write_event_suggestion_removed" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2193 CREATE FUNCTION "write_event_member_trigger"()
2194 RETURNS TRIGGER
2195 LANGUAGE 'plpgsql' VOLATILE AS $$
2196 BEGIN
2197 IF TG_OP = 'INSERT' THEN
2198 IF NEW."activated" NOTNULL AND NEW."deleted" ISNULL THEN
2199 INSERT INTO "event" ("event", "member_id")
2200 VALUES ('member_activated', NEW."id");
2201 END IF;
2202 IF NEW."active" THEN
2203 INSERT INTO "event" ("event", "member_id", "boolean_value")
2204 VALUES ('member_active', NEW."id", TRUE);
2205 END IF;
2206 ELSIF TG_OP = 'UPDATE' THEN
2207 IF OLD."id" != NEW."id" THEN
2208 RAISE EXCEPTION 'Cannot change member ID';
2209 END IF;
2210 IF
2211 (OLD."activated" ISNULL OR OLD."deleted" NOTNULL) AND
2212 NEW."activated" NOTNULL AND NEW."deleted" ISNULL
2213 THEN
2214 INSERT INTO "event" ("event", "member_id")
2215 VALUES ('member_activated', NEW."id");
2216 END IF;
2217 IF OLD."active" != NEW."active" THEN
2218 INSERT INTO "event" ("event", "member_id", "boolean_value") VALUES (
2219 'member_active', NEW."id", NEW."active"
2220 );
2221 END IF;
2222 IF OLD."name" != NEW."name" THEN
2223 INSERT INTO "event" (
2224 "event", "member_id", "text_value", "old_text_value"
2225 ) VALUES (
2226 'member_name_updated', NEW."id", NEW."name", OLD."name"
2227 );
2228 END IF;
2229 IF
2230 OLD."activated" NOTNULL AND OLD."deleted" ISNULL AND
2231 (NEW."activated" ISNULL OR NEW."deleted" NOTNULL)
2232 THEN
2233 INSERT INTO "event" ("event", "member_id")
2234 VALUES ('member_deleted', NEW."id");
2235 END IF;
2236 END IF;
2237 RETURN NULL;
2238 END;
2239 $$;
2241 CREATE TRIGGER "write_event_member"
2242 AFTER INSERT OR UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
2243 "write_event_member_trigger"();
2245 COMMENT ON FUNCTION "write_event_member_trigger"() IS 'Implementation of trigger "write_event_member" on table "member"';
2246 COMMENT ON TRIGGER "write_event_member" ON "member" IS 'Create entries in "event" table on insertion to member table';
2249 CREATE FUNCTION "write_event_member_profile_updated_trigger"()
2250 RETURNS TRIGGER
2251 LANGUAGE 'plpgsql' VOLATILE AS $$
2252 BEGIN
2253 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2254 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2255 INSERT INTO "event" ("event", "member_id") VALUES (
2256 'member_profile_updated', OLD."member_id"
2257 );
2258 END IF;
2259 END IF;
2260 IF TG_OP = 'UPDATE' THEN
2261 IF OLD."member_id" = NEW."member_id" THEN
2262 RETURN NULL;
2263 END IF;
2264 END IF;
2265 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2266 INSERT INTO "event" ("event", "member_id") VALUES (
2267 'member_profile_updated', NEW."member_id"
2268 );
2269 END IF;
2270 RETURN NULL;
2271 END;
2272 $$;
2274 CREATE TRIGGER "write_event_member_profile_updated"
2275 AFTER INSERT OR UPDATE OR DELETE ON "member_profile"
2276 FOR EACH ROW EXECUTE PROCEDURE
2277 "write_event_member_profile_updated_trigger"();
2279 COMMENT ON FUNCTION "write_event_member_profile_updated_trigger"() IS 'Implementation of trigger "write_event_member_profile_updated" on table "member_profile"';
2280 COMMENT ON TRIGGER "write_event_member_profile_updated" ON "member_profile" IS 'Creates entries in "event" table on member profile update';
2283 CREATE FUNCTION "write_event_member_image_updated_trigger"()
2284 RETURNS TRIGGER
2285 LANGUAGE 'plpgsql' VOLATILE AS $$
2286 BEGIN
2287 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2288 IF NOT OLD."scaled" THEN
2289 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2290 INSERT INTO "event" ("event", "member_id") VALUES (
2291 'member_image_updated', OLD."member_id"
2292 );
2293 END IF;
2294 END IF;
2295 END IF;
2296 IF TG_OP = 'UPDATE' THEN
2297 IF
2298 OLD."member_id" = NEW."member_id" AND
2299 OLD."scaled" = NEW."scaled"
2300 THEN
2301 RETURN NULL;
2302 END IF;
2303 END IF;
2304 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2305 IF NOT NEW."scaled" THEN
2306 INSERT INTO "event" ("event", "member_id") VALUES (
2307 'member_image_updated', NEW."member_id"
2308 );
2309 END IF;
2310 END IF;
2311 RETURN NULL;
2312 END;
2313 $$;
2315 CREATE TRIGGER "write_event_member_image_updated"
2316 AFTER INSERT OR UPDATE OR DELETE ON "member_image"
2317 FOR EACH ROW EXECUTE PROCEDURE
2318 "write_event_member_image_updated_trigger"();
2320 COMMENT ON FUNCTION "write_event_member_image_updated_trigger"() IS 'Implementation of trigger "write_event_member_image_updated" on table "member_image"';
2321 COMMENT ON TRIGGER "write_event_member_image_updated" ON "member_image" IS 'Creates entries in "event" table on member image update';
2324 CREATE FUNCTION "write_event_interest_trigger"()
2325 RETURNS TRIGGER
2326 LANGUAGE 'plpgsql' VOLATILE AS $$
2327 DECLARE
2328 "issue_row" "issue"%ROWTYPE;
2329 "area_row" "area"%ROWTYPE;
2330 BEGIN
2331 IF TG_OP = 'UPDATE' THEN
2332 IF OLD = NEW THEN
2333 RETURN NULL;
2334 END IF;
2335 END IF;
2336 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2337 SELECT * INTO "issue_row" FROM "issue"
2338 WHERE "id" = OLD."issue_id" FOR SHARE;
2339 SELECT * INTO "area_row" FROM "area"
2340 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2341 IF "issue_row"."id" NOTNULL THEN
2342 INSERT INTO "event" (
2343 "event", "member_id",
2344 "unit_id", "area_id", "policy_id", "issue_id", "state",
2345 "boolean_value"
2346 ) VALUES (
2347 'interest', OLD."member_id",
2348 "area_row"."unit_id", "issue_row"."area_id",
2349 "issue_row"."policy_id",
2350 OLD."issue_id", "issue_row"."state",
2351 FALSE
2352 );
2353 END IF;
2354 END IF;
2355 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2356 SELECT * INTO "issue_row" FROM "issue"
2357 WHERE "id" = NEW."issue_id" FOR SHARE;
2358 SELECT * INTO "area_row" FROM "area"
2359 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2360 INSERT INTO "event" (
2361 "event", "member_id",
2362 "unit_id", "area_id", "policy_id", "issue_id", "state",
2363 "boolean_value"
2364 ) VALUES (
2365 'interest', NEW."member_id",
2366 "area_row"."unit_id", "issue_row"."area_id",
2367 "issue_row"."policy_id",
2368 NEW."issue_id", "issue_row"."state",
2369 TRUE
2370 );
2371 END IF;
2372 RETURN NULL;
2373 END;
2374 $$;
2376 CREATE TRIGGER "write_event_interest"
2377 AFTER INSERT OR UPDATE OR DELETE ON "interest" FOR EACH ROW EXECUTE PROCEDURE
2378 "write_event_interest_trigger"();
2380 COMMENT ON FUNCTION "write_event_interest_trigger"() IS 'Implementation of trigger "write_event_interest_inserted" on table "interest"';
2381 COMMENT ON TRIGGER "write_event_interest" ON "interest" IS 'Create entry in "event" table on adding or removing interest';
2384 CREATE FUNCTION "write_event_initiator_trigger"()
2385 RETURNS TRIGGER
2386 LANGUAGE 'plpgsql' VOLATILE AS $$
2387 DECLARE
2388 "initiative_row" "initiative"%ROWTYPE;
2389 "issue_row" "issue"%ROWTYPE;
2390 "area_row" "area"%ROWTYPE;
2391 "accepted_v" BOOLEAN = FALSE;
2392 "rejected_v" BOOLEAN = FALSE;
2393 BEGIN
2394 IF TG_OP = 'UPDATE' THEN
2395 IF
2396 OLD."initiative_id" = NEW."initiative_id" AND
2397 OLD."member_id" = NEW."member_id"
2398 THEN
2399 IF
2400 coalesce(OLD."accepted", FALSE) = coalesce(NEW."accepted", FALSE)
2401 THEN
2402 RETURN NULL;
2403 END IF;
2404 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2405 "accepted_v" := TRUE;
2406 ELSE
2407 "rejected_v" := TRUE;
2408 END IF;
2409 END IF;
2410 END IF;
2411 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "accepted_v" THEN
2412 IF coalesce(OLD."accepted", FALSE) = TRUE THEN
2413 SELECT * INTO "initiative_row" FROM "initiative"
2414 WHERE "id" = OLD."initiative_id" FOR SHARE;
2415 IF "initiative_row"."id" NOTNULL THEN
2416 SELECT * INTO "issue_row" FROM "issue"
2417 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2418 SELECT * INTO "area_row" FROM "area"
2419 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2420 INSERT INTO "event" (
2421 "event", "member_id",
2422 "unit_id", "area_id", "policy_id", "issue_id", "state",
2423 "initiative_id", "boolean_value"
2424 ) VALUES (
2425 'initiator', OLD."member_id",
2426 "area_row"."unit_id", "issue_row"."area_id",
2427 "issue_row"."policy_id",
2428 "issue_row"."id", "issue_row"."state",
2429 OLD."initiative_id", FALSE
2430 );
2431 END IF;
2432 END IF;
2433 END IF;
2434 IF TG_OP = 'UPDATE' AND NOT "rejected_v" THEN
2435 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2436 SELECT * INTO "initiative_row" FROM "initiative"
2437 WHERE "id" = NEW."initiative_id" FOR SHARE;
2438 SELECT * INTO "issue_row" FROM "issue"
2439 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2440 SELECT * INTO "area_row" FROM "area"
2441 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2442 INSERT INTO "event" (
2443 "event", "member_id",
2444 "unit_id", "area_id", "policy_id", "issue_id", "state",
2445 "initiative_id", "boolean_value"
2446 ) VALUES (
2447 'initiator', NEW."member_id",
2448 "area_row"."unit_id", "issue_row"."area_id",
2449 "issue_row"."policy_id",
2450 "issue_row"."id", "issue_row"."state",
2451 NEW."initiative_id", TRUE
2452 );
2453 END IF;
2454 END IF;
2455 RETURN NULL;
2456 END;
2457 $$;
2459 CREATE TRIGGER "write_event_initiator"
2460 AFTER UPDATE OR DELETE ON "initiator" FOR EACH ROW EXECUTE PROCEDURE
2461 "write_event_initiator_trigger"();
2463 COMMENT ON FUNCTION "write_event_initiator_trigger"() IS 'Implementation of trigger "write_event_initiator" on table "initiator"';
2464 COMMENT ON TRIGGER "write_event_initiator" ON "initiator" IS 'Create entry in "event" table when accepting or removing initiatorship (NOTE: trigger does not fire on INSERT to avoid events on initiative creation)';
2467 CREATE FUNCTION "write_event_support_trigger"()
2468 RETURNS TRIGGER
2469 LANGUAGE 'plpgsql' VOLATILE AS $$
2470 DECLARE
2471 "issue_row" "issue"%ROWTYPE;
2472 "area_row" "area"%ROWTYPE;
2473 BEGIN
2474 IF TG_OP = 'UPDATE' THEN
2475 IF
2476 OLD."initiative_id" = NEW."initiative_id" AND
2477 OLD."member_id" = NEW."member_id"
2478 THEN
2479 IF OLD."draft_id" != NEW."draft_id" THEN
2480 SELECT * INTO "issue_row" FROM "issue"
2481 WHERE "id" = NEW."issue_id" FOR SHARE;
2482 SELECT * INTO "area_row" FROM "area"
2483 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2484 INSERT INTO "event" (
2485 "event", "member_id",
2486 "unit_id", "area_id", "policy_id", "issue_id", "state",
2487 "initiative_id", "draft_id"
2488 ) VALUES (
2489 'support_updated', NEW."member_id",
2490 "area_row"."unit_id", "issue_row"."area_id",
2491 "issue_row"."policy_id",
2492 "issue_row"."id", "issue_row"."state",
2493 NEW."initiative_id", NEW."draft_id"
2494 );
2495 END IF;
2496 RETURN NULL;
2497 END IF;
2498 END IF;
2499 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2500 IF EXISTS (
2501 SELECT NULL FROM "initiative" WHERE "id" = OLD."initiative_id"
2502 FOR SHARE
2503 ) THEN
2504 SELECT * INTO "issue_row" FROM "issue"
2505 WHERE "id" = OLD."issue_id" FOR SHARE;
2506 SELECT * INTO "area_row" FROM "area"
2507 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2508 INSERT INTO "event" (
2509 "event", "member_id",
2510 "unit_id", "area_id", "policy_id", "issue_id", "state",
2511 "initiative_id", "boolean_value"
2512 ) VALUES (
2513 'support', OLD."member_id",
2514 "area_row"."unit_id", "issue_row"."area_id",
2515 "issue_row"."policy_id",
2516 "issue_row"."id", "issue_row"."state",
2517 OLD."initiative_id", FALSE
2518 );
2519 END IF;
2520 END IF;
2521 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2522 SELECT * INTO "issue_row" FROM "issue"
2523 WHERE "id" = NEW."issue_id" FOR SHARE;
2524 SELECT * INTO "area_row" FROM "area"
2525 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2526 INSERT INTO "event" (
2527 "event", "member_id",
2528 "unit_id", "area_id", "policy_id", "issue_id", "state",
2529 "initiative_id", "draft_id", "boolean_value"
2530 ) VALUES (
2531 'support', NEW."member_id",
2532 "area_row"."unit_id", "issue_row"."area_id",
2533 "issue_row"."policy_id",
2534 "issue_row"."id", "issue_row"."state",
2535 NEW."initiative_id", NEW."draft_id", TRUE
2536 );
2537 END IF;
2538 RETURN NULL;
2539 END;
2540 $$;
2542 CREATE TRIGGER "write_event_support"
2543 AFTER INSERT OR UPDATE OR DELETE ON "supporter" FOR EACH ROW EXECUTE PROCEDURE
2544 "write_event_support_trigger"();
2546 COMMENT ON FUNCTION "write_event_support_trigger"() IS 'Implementation of trigger "write_event_support" on table "supporter"';
2547 COMMENT ON TRIGGER "write_event_support" ON "supporter" IS 'Create entry in "event" table when adding, updating, or removing support';
2550 CREATE FUNCTION "write_event_suggestion_rated_trigger"()
2551 RETURNS TRIGGER
2552 LANGUAGE 'plpgsql' VOLATILE AS $$
2553 DECLARE
2554 "same_pkey_v" BOOLEAN = FALSE;
2555 "initiative_row" "initiative"%ROWTYPE;
2556 "issue_row" "issue"%ROWTYPE;
2557 "area_row" "area"%ROWTYPE;
2558 BEGIN
2559 IF TG_OP = 'UPDATE' THEN
2560 IF
2561 OLD."suggestion_id" = NEW."suggestion_id" AND
2562 OLD."member_id" = NEW."member_id"
2563 THEN
2564 IF
2565 OLD."degree" = NEW."degree" AND
2566 OLD."fulfilled" = NEW."fulfilled"
2567 THEN
2568 RETURN NULL;
2569 END IF;
2570 "same_pkey_v" := TRUE;
2571 END IF;
2572 END IF;
2573 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "same_pkey_v" THEN
2574 IF EXISTS (
2575 SELECT NULL FROM "suggestion" WHERE "id" = OLD."suggestion_id"
2576 FOR SHARE
2577 ) THEN
2578 SELECT * INTO "initiative_row" FROM "initiative"
2579 WHERE "id" = OLD."initiative_id" FOR SHARE;
2580 SELECT * INTO "issue_row" FROM "issue"
2581 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2582 SELECT * INTO "area_row" FROM "area"
2583 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2584 INSERT INTO "event" (
2585 "event", "member_id",
2586 "unit_id", "area_id", "policy_id", "issue_id", "state",
2587 "initiative_id", "suggestion_id",
2588 "boolean_value", "numeric_value"
2589 ) VALUES (
2590 'suggestion_rated', OLD."member_id",
2591 "area_row"."unit_id", "issue_row"."area_id",
2592 "issue_row"."policy_id",
2593 "initiative_row"."issue_id", "issue_row"."state",
2594 OLD."initiative_id", OLD."suggestion_id",
2595 NULL, 0
2596 );
2597 END IF;
2598 END IF;
2599 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2600 SELECT * INTO "initiative_row" FROM "initiative"
2601 WHERE "id" = NEW."initiative_id" FOR SHARE;
2602 SELECT * INTO "issue_row" FROM "issue"
2603 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2604 SELECT * INTO "area_row" FROM "area"
2605 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2606 INSERT INTO "event" (
2607 "event", "member_id",
2608 "unit_id", "area_id", "policy_id", "issue_id", "state",
2609 "initiative_id", "suggestion_id",
2610 "boolean_value", "numeric_value"
2611 ) VALUES (
2612 'suggestion_rated', NEW."member_id",
2613 "area_row"."unit_id", "issue_row"."area_id",
2614 "issue_row"."policy_id",
2615 "initiative_row"."issue_id", "issue_row"."state",
2616 NEW."initiative_id", NEW."suggestion_id",
2617 NEW."fulfilled", NEW."degree"
2618 );
2619 END IF;
2620 RETURN NULL;
2621 END;
2622 $$;
2624 CREATE TRIGGER "write_event_suggestion_rated"
2625 AFTER INSERT OR UPDATE OR DELETE ON "opinion" FOR EACH ROW EXECUTE PROCEDURE
2626 "write_event_suggestion_rated_trigger"();
2628 COMMENT ON FUNCTION "write_event_suggestion_rated_trigger"() IS 'Implementation of trigger "write_event_suggestion_rated" on table "opinion"';
2629 COMMENT ON TRIGGER "write_event_suggestion_rated" ON "opinion" IS 'Create entry in "event" table when adding, updating, or removing support';
2632 CREATE FUNCTION "write_event_delegation_trigger"()
2633 RETURNS TRIGGER
2634 LANGUAGE 'plpgsql' VOLATILE AS $$
2635 DECLARE
2636 "issue_row" "issue"%ROWTYPE;
2637 "area_row" "area"%ROWTYPE;
2638 BEGIN
2639 IF TG_OP = 'DELETE' THEN
2640 IF EXISTS (
2641 SELECT NULL FROM "member" WHERE "id" = OLD."truster_id"
2642 ) AND (CASE OLD."scope"
2643 WHEN 'unit'::"delegation_scope" THEN EXISTS (
2644 SELECT NULL FROM "unit" WHERE "id" = OLD."unit_id"
2645 )
2646 WHEN 'area'::"delegation_scope" THEN EXISTS (
2647 SELECT NULL FROM "area" WHERE "id" = OLD."area_id"
2648 )
2649 WHEN 'issue'::"delegation_scope" THEN EXISTS (
2650 SELECT NULL FROM "issue" WHERE "id" = OLD."issue_id"
2651 )
2652 END) THEN
2653 SELECT * INTO "issue_row" FROM "issue"
2654 WHERE "id" = OLD."issue_id" FOR SHARE;
2655 SELECT * INTO "area_row" FROM "area"
2656 WHERE "id" = COALESCE(OLD."area_id", "issue_row"."area_id")
2657 FOR SHARE;
2658 INSERT INTO "event" (
2659 "event", "member_id", "scope",
2660 "unit_id", "area_id", "issue_id", "state",
2661 "boolean_value"
2662 ) VALUES (
2663 'delegation', OLD."truster_id", OLD."scope",
2664 COALESCE(OLD."unit_id", "area_row"."unit_id"), "area_row"."id",
2665 OLD."issue_id", "issue_row"."state",
2666 FALSE
2667 );
2668 END IF;
2669 ELSE
2670 SELECT * INTO "issue_row" FROM "issue"
2671 WHERE "id" = NEW."issue_id" FOR SHARE;
2672 SELECT * INTO "area_row" FROM "area"
2673 WHERE "id" = COALESCE(NEW."area_id", "issue_row"."area_id")
2674 FOR SHARE;
2675 INSERT INTO "event" (
2676 "event", "member_id", "other_member_id", "scope",
2677 "unit_id", "area_id", "issue_id", "state",
2678 "boolean_value"
2679 ) VALUES (
2680 'delegation', NEW."truster_id", NEW."trustee_id", NEW."scope",
2681 COALESCE(NEW."unit_id", "area_row"."unit_id"), "area_row"."id",
2682 NEW."issue_id", "issue_row"."state",
2683 TRUE
2684 );
2685 END IF;
2686 RETURN NULL;
2687 END;
2688 $$;
2690 CREATE TRIGGER "write_event_delegation"
2691 AFTER INSERT OR UPDATE OR DELETE ON "delegation" FOR EACH ROW EXECUTE PROCEDURE
2692 "write_event_delegation_trigger"();
2694 COMMENT ON FUNCTION "write_event_delegation_trigger"() IS 'Implementation of trigger "write_event_delegation" on table "delegation"';
2695 COMMENT ON TRIGGER "write_event_delegation" ON "delegation" IS 'Create entry in "event" table when adding, updating, or removing a delegation';
2698 CREATE FUNCTION "write_event_contact_trigger"()
2699 RETURNS TRIGGER
2700 LANGUAGE 'plpgsql' VOLATILE AS $$
2701 BEGIN
2702 IF TG_OP = 'UPDATE' THEN
2703 IF
2704 OLD."member_id" = NEW."member_id" AND
2705 OLD."other_member_id" = NEW."other_member_id" AND
2706 OLD."public" = NEW."public"
2707 THEN
2708 RETURN NULL;
2709 END IF;
2710 END IF;
2711 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2712 IF OLD."public" THEN
2713 IF EXISTS (
2714 SELECT NULL FROM "member" WHERE "id" = OLD."member_id"
2715 FOR SHARE
2716 ) AND EXISTS (
2717 SELECT NULL FROM "member" WHERE "id" = OLD."other_member_id"
2718 FOR SHARE
2719 ) THEN
2720 INSERT INTO "event" (
2721 "event", "member_id", "other_member_id", "boolean_value"
2722 ) VALUES (
2723 'contact', OLD."member_id", OLD."other_member_id", FALSE
2724 );
2725 END IF;
2726 END IF;
2727 END IF;
2728 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2729 IF NEW."public" THEN
2730 INSERT INTO "event" (
2731 "event", "member_id", "other_member_id", "boolean_value"
2732 ) VALUES (
2733 'contact', NEW."member_id", NEW."other_member_id", TRUE
2734 );
2735 END IF;
2736 END IF;
2737 RETURN NULL;
2738 END;
2739 $$;
2741 CREATE TRIGGER "write_event_contact"
2742 AFTER INSERT OR UPDATE OR DELETE ON "contact" FOR EACH ROW EXECUTE PROCEDURE
2743 "write_event_contact_trigger"();
2745 COMMENT ON FUNCTION "write_event_contact_trigger"() IS 'Implementation of trigger "write_event_contact" on table "contact"';
2746 COMMENT ON TRIGGER "write_event_contact" ON "contact" IS 'Create entry in "event" table when adding or removing public contacts';
2749 CREATE FUNCTION "write_event_posting_trigger"()
2750 RETURNS TRIGGER
2751 LANGUAGE 'plpgsql' VOLATILE AS $$
2752 BEGIN
2753 INSERT INTO "event" (
2754 "event", "posting_id", "member_id",
2755 "unit_id", "area_id", "policy_id",
2756 "issue_id", "initiative_id", "suggestion_id"
2757 ) VALUES (
2758 'posting_created', NEW."id", NEW."author_id",
2759 NEW."unit_id", NEW."area_id", NEW."policy_id",
2760 NEW."issue_id", NEW."initiative_id", NEW."suggestion_id"
2761 );
2762 RETURN NULL;
2763 END;
2764 $$;
2766 CREATE TRIGGER "write_event_posting"
2767 AFTER INSERT ON "posting" FOR EACH ROW EXECUTE PROCEDURE
2768 "write_event_posting_trigger"();
2770 COMMENT ON FUNCTION "write_event_posting_trigger"() IS 'Implementation of trigger "write_event_posting" on table "posting"';
2771 COMMENT ON TRIGGER "write_event_posting" ON "posting" IS 'Create entry in "event" table when creating a new posting';
2774 CREATE FUNCTION "send_event_notify_trigger"()
2775 RETURNS TRIGGER
2776 LANGUAGE 'plpgsql' VOLATILE AS $$
2777 BEGIN
2778 EXECUTE 'NOTIFY "event", ''' || NEW."event" || '''';
2779 RETURN NULL;
2780 END;
2781 $$;
2783 CREATE TRIGGER "send_notify"
2784 AFTER INSERT OR UPDATE ON "event" FOR EACH ROW EXECUTE PROCEDURE
2785 "send_event_notify_trigger"();
2789 ----------------------------
2790 -- Additional constraints --
2791 ----------------------------
2794 CREATE FUNCTION "delete_extended_scope_tokens_trigger"()
2795 RETURNS TRIGGER
2796 LANGUAGE 'plpgsql' VOLATILE AS $$
2797 DECLARE
2798 "system_application_row" "system_application"%ROWTYPE;
2799 BEGIN
2800 IF OLD."system_application_id" NOTNULL THEN
2801 SELECT * FROM "system_application" INTO "system_application_row"
2802 WHERE "id" = OLD."system_application_id";
2803 DELETE FROM "token"
2804 WHERE "member_id" = OLD."member_id"
2805 AND "system_application_id" = OLD."system_application_id"
2806 AND NOT COALESCE(
2807 regexp_split_to_array("scope", E'\\s+') <@
2808 regexp_split_to_array(
2809 "system_application_row"."automatic_scope", E'\\s+'
2810 ),
2811 FALSE
2812 );
2813 END IF;
2814 RETURN OLD;
2815 END;
2816 $$;
2818 CREATE TRIGGER "delete_extended_scope_tokens"
2819 BEFORE DELETE ON "member_application" FOR EACH ROW EXECUTE PROCEDURE
2820 "delete_extended_scope_tokens_trigger"();
2823 CREATE FUNCTION "detach_token_from_session_trigger"()
2824 RETURNS TRIGGER
2825 LANGUAGE 'plpgsql' VOLATILE AS $$
2826 BEGIN
2827 UPDATE "token" SET "session_id" = NULL
2828 WHERE "session_id" = OLD."id";
2829 RETURN OLD;
2830 END;
2831 $$;
2833 CREATE TRIGGER "detach_token_from_session"
2834 BEFORE DELETE ON "session" FOR EACH ROW EXECUTE PROCEDURE
2835 "detach_token_from_session_trigger"();
2838 CREATE FUNCTION "delete_non_detached_scope_with_session_trigger"()
2839 RETURNS TRIGGER
2840 LANGUAGE 'plpgsql' VOLATILE AS $$
2841 BEGIN
2842 IF NEW."session_id" ISNULL THEN
2843 SELECT coalesce(string_agg("element", ' '), '') INTO NEW."scope"
2844 FROM unnest(regexp_split_to_array(NEW."scope", E'\\s+')) AS "element"
2845 WHERE "element" LIKE '%_detached';
2846 END IF;
2847 RETURN NEW;
2848 END;
2849 $$;
2851 CREATE TRIGGER "delete_non_detached_scope_with_session"
2852 BEFORE INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2853 "delete_non_detached_scope_with_session_trigger"();
2856 CREATE FUNCTION "delete_token_with_empty_scope_trigger"()
2857 RETURNS TRIGGER
2858 LANGUAGE 'plpgsql' VOLATILE AS $$
2859 BEGIN
2860 IF NEW."scope" = '' THEN
2861 DELETE FROM "token" WHERE "id" = NEW."id";
2862 END IF;
2863 RETURN NULL;
2864 END;
2865 $$;
2867 CREATE TRIGGER "delete_token_with_empty_scope"
2868 AFTER INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2869 "delete_token_with_empty_scope_trigger"();
2872 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
2873 RETURNS TRIGGER
2874 LANGUAGE 'plpgsql' VOLATILE AS $$
2875 BEGIN
2876 IF NOT EXISTS (
2877 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
2878 ) THEN
2879 RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING
2880 ERRCODE = 'integrity_constraint_violation',
2881 HINT = 'Create issue, initiative, and draft within the same transaction.';
2882 END IF;
2883 RETURN NULL;
2884 END;
2885 $$;
2887 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
2888 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
2889 FOR EACH ROW EXECUTE PROCEDURE
2890 "issue_requires_first_initiative_trigger"();
2892 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
2893 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
2896 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
2897 RETURNS TRIGGER
2898 LANGUAGE 'plpgsql' VOLATILE AS $$
2899 DECLARE
2900 "reference_lost" BOOLEAN;
2901 BEGIN
2902 IF TG_OP = 'DELETE' THEN
2903 "reference_lost" := TRUE;
2904 ELSE
2905 "reference_lost" := NEW."issue_id" != OLD."issue_id";
2906 END IF;
2907 IF
2908 "reference_lost" AND NOT EXISTS (
2909 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
2910 )
2911 THEN
2912 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
2913 END IF;
2914 RETURN NULL;
2915 END;
2916 $$;
2918 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
2919 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
2920 FOR EACH ROW EXECUTE PROCEDURE
2921 "last_initiative_deletes_issue_trigger"();
2923 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
2924 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
2927 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
2928 RETURNS TRIGGER
2929 LANGUAGE 'plpgsql' VOLATILE AS $$
2930 BEGIN
2931 IF NOT EXISTS (
2932 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
2933 ) THEN
2934 RAISE EXCEPTION 'Cannot create initiative without an initial draft.' USING
2935 ERRCODE = 'integrity_constraint_violation',
2936 HINT = 'Create issue, initiative and draft within the same transaction.';
2937 END IF;
2938 RETURN NULL;
2939 END;
2940 $$;
2942 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
2943 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
2944 FOR EACH ROW EXECUTE PROCEDURE
2945 "initiative_requires_first_draft_trigger"();
2947 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
2948 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
2951 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
2952 RETURNS TRIGGER
2953 LANGUAGE 'plpgsql' VOLATILE AS $$
2954 DECLARE
2955 "reference_lost" BOOLEAN;
2956 BEGIN
2957 IF TG_OP = 'DELETE' THEN
2958 "reference_lost" := TRUE;
2959 ELSE
2960 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
2961 END IF;
2962 IF
2963 "reference_lost" AND NOT EXISTS (
2964 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
2965 )
2966 THEN
2967 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
2968 END IF;
2969 RETURN NULL;
2970 END;
2971 $$;
2973 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
2974 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
2975 FOR EACH ROW EXECUTE PROCEDURE
2976 "last_draft_deletes_initiative_trigger"();
2978 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
2979 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
2982 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
2983 RETURNS TRIGGER
2984 LANGUAGE 'plpgsql' VOLATILE AS $$
2985 BEGIN
2986 IF NOT EXISTS (
2987 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
2988 ) THEN
2989 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING
2990 ERRCODE = 'integrity_constraint_violation',
2991 HINT = 'Create suggestion and opinion within the same transaction.';
2992 END IF;
2993 RETURN NULL;
2994 END;
2995 $$;
2997 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
2998 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
2999 FOR EACH ROW EXECUTE PROCEDURE
3000 "suggestion_requires_first_opinion_trigger"();
3002 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
3003 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
3006 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
3007 RETURNS TRIGGER
3008 LANGUAGE 'plpgsql' VOLATILE AS $$
3009 DECLARE
3010 "reference_lost" BOOLEAN;
3011 BEGIN
3012 IF TG_OP = 'DELETE' THEN
3013 "reference_lost" := TRUE;
3014 ELSE
3015 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
3016 END IF;
3017 IF
3018 "reference_lost" AND NOT EXISTS (
3019 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
3020 )
3021 THEN
3022 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
3023 END IF;
3024 RETURN NULL;
3025 END;
3026 $$;
3028 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
3029 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
3030 FOR EACH ROW EXECUTE PROCEDURE
3031 "last_opinion_deletes_suggestion_trigger"();
3033 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
3034 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
3037 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
3038 RETURNS TRIGGER
3039 LANGUAGE 'plpgsql' VOLATILE AS $$
3040 BEGIN
3041 DELETE FROM "direct_voter"
3042 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
3043 RETURN NULL;
3044 END;
3045 $$;
3047 CREATE TRIGGER "non_voter_deletes_direct_voter"
3048 AFTER INSERT OR UPDATE ON "non_voter"
3049 FOR EACH ROW EXECUTE PROCEDURE
3050 "non_voter_deletes_direct_voter_trigger"();
3052 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
3053 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")';
3056 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
3057 RETURNS TRIGGER
3058 LANGUAGE 'plpgsql' VOLATILE AS $$
3059 BEGIN
3060 DELETE FROM "non_voter"
3061 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
3062 RETURN NULL;
3063 END;
3064 $$;
3066 CREATE TRIGGER "direct_voter_deletes_non_voter"
3067 AFTER INSERT OR UPDATE ON "direct_voter"
3068 FOR EACH ROW EXECUTE PROCEDURE
3069 "direct_voter_deletes_non_voter_trigger"();
3071 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
3072 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")';
3075 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
3076 RETURNS TRIGGER
3077 LANGUAGE 'plpgsql' VOLATILE AS $$
3078 BEGIN
3079 IF NEW."comment" ISNULL THEN
3080 NEW."comment_changed" := NULL;
3081 NEW."formatting_engine" := NULL;
3082 END IF;
3083 RETURN NEW;
3084 END;
3085 $$;
3087 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
3088 BEFORE INSERT OR UPDATE ON "direct_voter"
3089 FOR EACH ROW EXECUTE PROCEDURE
3090 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
3092 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"';
3093 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.';
3097 ---------------------------------
3098 -- Delete incomplete snapshots --
3099 ---------------------------------
3102 CREATE FUNCTION "delete_snapshot_on_partial_delete_trigger"()
3103 RETURNS TRIGGER
3104 LANGUAGE 'plpgsql' VOLATILE AS $$
3105 BEGIN
3106 IF TG_OP = 'UPDATE' THEN
3107 IF
3108 OLD."snapshot_id" = NEW."snapshot_id" AND
3109 OLD."issue_id" = NEW."issue_id"
3110 THEN
3111 RETURN NULL;
3112 END IF;
3113 END IF;
3114 DELETE FROM "snapshot" WHERE "id" = OLD."snapshot_id";
3115 RETURN NULL;
3116 END;
3117 $$;
3119 CREATE TRIGGER "delete_snapshot_on_partial_delete"
3120 AFTER UPDATE OR DELETE ON "snapshot_issue"
3121 FOR EACH ROW EXECUTE PROCEDURE
3122 "delete_snapshot_on_partial_delete_trigger"();
3124 COMMENT ON FUNCTION "delete_snapshot_on_partial_delete_trigger"() IS 'Implementation of trigger "delete_snapshot_on_partial_delete" on table "snapshot_issue"';
3125 COMMENT ON TRIGGER "delete_snapshot_on_partial_delete" ON "snapshot_issue" IS 'Deletes whole snapshot if one issue is deleted from the snapshot';
3129 ---------------------------------------------------------------
3130 -- Ensure that votes are not modified when issues are closed --
3131 ---------------------------------------------------------------
3133 -- NOTE: Frontends should ensure this anyway, but in case of programming
3134 -- errors the following triggers ensure data integrity.
3137 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
3138 RETURNS TRIGGER
3139 LANGUAGE 'plpgsql' VOLATILE AS $$
3140 DECLARE
3141 "issue_id_v" "issue"."id"%TYPE;
3142 "issue_row" "issue"%ROWTYPE;
3143 BEGIN
3144 IF EXISTS (
3145 SELECT NULL FROM "temporary_transaction_data"
3146 WHERE "txid" = txid_current()
3147 AND "key" = 'override_protection_triggers'
3148 AND "value" = TRUE::TEXT
3149 ) THEN
3150 RETURN NULL;
3151 END IF;
3152 IF TG_OP = 'DELETE' THEN
3153 "issue_id_v" := OLD."issue_id";
3154 ELSE
3155 "issue_id_v" := NEW."issue_id";
3156 END IF;
3157 SELECT INTO "issue_row" * FROM "issue"
3158 WHERE "id" = "issue_id_v" FOR SHARE;
3159 IF (
3160 "issue_row"."closed" NOTNULL OR (
3161 "issue_row"."state" = 'voting' AND
3162 "issue_row"."phase_finished" NOTNULL
3163 )
3164 ) THEN
3165 IF
3166 TG_RELID = 'direct_voter'::regclass AND
3167 TG_OP = 'UPDATE'
3168 THEN
3169 IF
3170 OLD."issue_id" = NEW."issue_id" AND
3171 OLD."member_id" = NEW."member_id" AND
3172 OLD."weight" = NEW."weight"
3173 THEN
3174 RETURN NULL; -- allows changing of voter comment
3175 END IF;
3176 END IF;
3177 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
3178 ERRCODE = 'integrity_constraint_violation';
3179 END IF;
3180 RETURN NULL;
3181 END;
3182 $$;
3184 CREATE TRIGGER "forbid_changes_on_closed_issue"
3185 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
3186 FOR EACH ROW EXECUTE PROCEDURE
3187 "forbid_changes_on_closed_issue_trigger"();
3189 CREATE TRIGGER "forbid_changes_on_closed_issue"
3190 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
3191 FOR EACH ROW EXECUTE PROCEDURE
3192 "forbid_changes_on_closed_issue_trigger"();
3194 CREATE TRIGGER "forbid_changes_on_closed_issue"
3195 AFTER INSERT OR UPDATE OR DELETE ON "vote"
3196 FOR EACH ROW EXECUTE PROCEDURE
3197 "forbid_changes_on_closed_issue_trigger"();
3199 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"';
3200 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';
3201 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';
3202 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';
3206 --------------------------------------------------------------------
3207 -- Auto-retrieval of fields only needed for referential integrity --
3208 --------------------------------------------------------------------
3211 CREATE FUNCTION "autofill_issue_id_trigger"()
3212 RETURNS TRIGGER
3213 LANGUAGE 'plpgsql' VOLATILE AS $$
3214 BEGIN
3215 IF NEW."issue_id" ISNULL THEN
3216 SELECT "issue_id" INTO NEW."issue_id"
3217 FROM "initiative" WHERE "id" = NEW."initiative_id";
3218 END IF;
3219 RETURN NEW;
3220 END;
3221 $$;
3223 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
3224 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3226 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
3227 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3229 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
3230 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
3231 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
3234 CREATE FUNCTION "autofill_initiative_id_trigger"()
3235 RETURNS TRIGGER
3236 LANGUAGE 'plpgsql' VOLATILE AS $$
3237 BEGIN
3238 IF NEW."initiative_id" ISNULL THEN
3239 SELECT "initiative_id" INTO NEW."initiative_id"
3240 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3241 END IF;
3242 RETURN NEW;
3243 END;
3244 $$;
3246 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
3247 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
3249 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
3250 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
3254 -------------------------------------------------------
3255 -- Automatic copying of values for indexing purposes --
3256 -------------------------------------------------------
3259 CREATE FUNCTION "copy_current_draft_data"
3260 ("initiative_id_p" "initiative"."id"%TYPE )
3261 RETURNS VOID
3262 LANGUAGE 'plpgsql' VOLATILE AS $$
3263 BEGIN
3264 PERFORM NULL FROM "initiative" WHERE "id" = "initiative_id_p"
3265 FOR UPDATE;
3266 UPDATE "initiative" SET
3267 "location" = "draft"."location",
3268 "draft_text_search_data" = "draft"."text_search_data"
3269 FROM "current_draft" AS "draft"
3270 WHERE "initiative"."id" = "initiative_id_p"
3271 AND "draft"."initiative_id" = "initiative_id_p";
3272 END;
3273 $$;
3275 COMMENT ON FUNCTION "copy_current_draft_data"
3276 ( "initiative"."id"%TYPE )
3277 IS 'Helper function for function "copy_current_draft_data_trigger"';
3280 CREATE FUNCTION "copy_current_draft_data_trigger"()
3281 RETURNS TRIGGER
3282 LANGUAGE 'plpgsql' VOLATILE AS $$
3283 BEGIN
3284 IF TG_OP='DELETE' THEN
3285 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3286 ELSE
3287 IF TG_OP='UPDATE' THEN
3288 IF COALESCE(OLD."inititiave_id" != NEW."initiative_id", TRUE) THEN
3289 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3290 END IF;
3291 END IF;
3292 PERFORM "copy_current_draft_data"(NEW."initiative_id");
3293 END IF;
3294 RETURN NULL;
3295 END;
3296 $$;
3298 CREATE TRIGGER "copy_current_draft_data"
3299 AFTER INSERT OR UPDATE OR DELETE ON "draft"
3300 FOR EACH ROW EXECUTE PROCEDURE
3301 "copy_current_draft_data_trigger"();
3303 COMMENT ON FUNCTION "copy_current_draft_data_trigger"() IS 'Implementation of trigger "copy_current_draft_data" on table "draft"';
3304 COMMENT ON TRIGGER "copy_current_draft_data" ON "draft" IS 'Copy certain fields from most recent "draft" to "initiative"';
3308 -----------------------------------------------------
3309 -- Automatic calculation of certain default values --
3310 -----------------------------------------------------
3313 CREATE FUNCTION "copy_timings_trigger"()
3314 RETURNS TRIGGER
3315 LANGUAGE 'plpgsql' VOLATILE AS $$
3316 DECLARE
3317 "policy_row" "policy"%ROWTYPE;
3318 BEGIN
3319 SELECT * INTO "policy_row" FROM "policy"
3320 WHERE "id" = NEW."policy_id";
3321 IF NEW."min_admission_time" ISNULL THEN
3322 NEW."min_admission_time" := "policy_row"."min_admission_time";
3323 END IF;
3324 IF NEW."max_admission_time" ISNULL THEN
3325 NEW."max_admission_time" := "policy_row"."max_admission_time";
3326 END IF;
3327 IF NEW."discussion_time" ISNULL THEN
3328 NEW."discussion_time" := "policy_row"."discussion_time";
3329 END IF;
3330 IF NEW."verification_time" ISNULL THEN
3331 NEW."verification_time" := "policy_row"."verification_time";
3332 END IF;
3333 IF NEW."voting_time" ISNULL THEN
3334 NEW."voting_time" := "policy_row"."voting_time";
3335 END IF;
3336 RETURN NEW;
3337 END;
3338 $$;
3340 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
3341 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
3343 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
3344 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
3347 CREATE FUNCTION "default_for_draft_id_trigger"()
3348 RETURNS TRIGGER
3349 LANGUAGE 'plpgsql' VOLATILE AS $$
3350 BEGIN
3351 IF NEW."draft_id" ISNULL THEN
3352 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
3353 WHERE "initiative_id" = NEW."initiative_id";
3354 END IF;
3355 RETURN NEW;
3356 END;
3357 $$;
3359 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
3360 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3361 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
3362 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3364 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
3365 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';
3366 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';
3370 ----------------------------------------
3371 -- Automatic creation of dependencies --
3372 ----------------------------------------
3375 CREATE FUNCTION "autocreate_interest_trigger"()
3376 RETURNS TRIGGER
3377 LANGUAGE 'plpgsql' VOLATILE AS $$
3378 BEGIN
3379 IF NOT EXISTS (
3380 SELECT NULL FROM "initiative" JOIN "interest"
3381 ON "initiative"."issue_id" = "interest"."issue_id"
3382 WHERE "initiative"."id" = NEW."initiative_id"
3383 AND "interest"."member_id" = NEW."member_id"
3384 ) THEN
3385 BEGIN
3386 INSERT INTO "interest" ("issue_id", "member_id")
3387 SELECT "issue_id", NEW."member_id"
3388 FROM "initiative" WHERE "id" = NEW."initiative_id";
3389 EXCEPTION WHEN unique_violation THEN END;
3390 END IF;
3391 RETURN NEW;
3392 END;
3393 $$;
3395 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
3396 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
3398 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
3399 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';
3402 CREATE FUNCTION "autocreate_supporter_trigger"()
3403 RETURNS TRIGGER
3404 LANGUAGE 'plpgsql' VOLATILE AS $$
3405 BEGIN
3406 IF NOT EXISTS (
3407 SELECT NULL FROM "suggestion" JOIN "supporter"
3408 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
3409 WHERE "suggestion"."id" = NEW."suggestion_id"
3410 AND "supporter"."member_id" = NEW."member_id"
3411 ) THEN
3412 BEGIN
3413 INSERT INTO "supporter" ("initiative_id", "member_id")
3414 SELECT "initiative_id", NEW."member_id"
3415 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3416 EXCEPTION WHEN unique_violation THEN END;
3417 END IF;
3418 RETURN NEW;
3419 END;
3420 $$;
3422 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
3423 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
3425 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
3426 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.';
3430 ------------------------------------------
3431 -- Views and helper functions for views --
3432 ------------------------------------------
3435 CREATE VIEW "member_eligible_to_be_notified" AS
3436 SELECT * FROM "member"
3437 WHERE "activated" NOTNULL AND "locked" = FALSE;
3439 COMMENT ON VIEW "member_eligible_to_be_notified" IS 'Filtered "member" table containing only activated and non-locked members (used as helper view for "member_to_notify" and "newsletter_to_send")';
3442 CREATE VIEW "member_to_notify" AS
3443 SELECT * FROM "member_eligible_to_be_notified"
3444 WHERE "disable_notifications" = FALSE;
3446 COMMENT ON VIEW "member_to_notify" IS 'Filtered "member" table containing only members that are eligible to and wish to receive notifications; NOTE: "notify_email" may still be NULL and might need to be checked by frontend (this allows other means of messaging)';
3449 CREATE VIEW "follower" AS
3450 SELECT
3451 "id" AS "follower_id",
3452 ( SELECT ARRAY["member"."id"] || array_agg("contact"."other_member_id")
3453 FROM "contact"
3454 WHERE "contact"."member_id" = "member"."id" AND "contact"."following" )
3455 AS "following_ids"
3456 FROM "member";
3458 COMMENT ON VIEW "follower" IS 'Provides the contacts of each member that are being followed (including the member itself) as an array of IDs';
3461 CREATE VIEW "area_quorum" AS
3462 SELECT
3463 "area"."id" AS "area_id",
3464 ceil(
3465 "area"."quorum_standard"::FLOAT8 * "quorum_factor"::FLOAT8 ^ (
3466 coalesce(
3467 ( SELECT sum(
3468 ( extract(epoch from "area"."quorum_time")::FLOAT8 /
3469 extract(epoch from
3470 ("issue"."accepted"-"issue"."created") +
3471 "issue"."discussion_time" +
3472 "issue"."verification_time" +
3473 "issue"."voting_time"
3474 )::FLOAT8
3475 ) ^ "area"."quorum_exponent"::FLOAT8
3476 )
3477 FROM "issue" JOIN "policy"
3478 ON "issue"."policy_id" = "policy"."id"
3479 WHERE "issue"."area_id" = "area"."id"
3480 AND "issue"."accepted" NOTNULL
3481 AND "issue"."closed" ISNULL
3482 AND "policy"."polling" = FALSE
3483 )::FLOAT8, 0::FLOAT8
3484 ) / "area"."quorum_issues"::FLOAT8 - 1::FLOAT8
3485 ) * CASE WHEN "area"."quorum_den" ISNULL THEN 1 ELSE (
3486 SELECT "snapshot"."population"
3487 FROM "snapshot"
3488 WHERE "snapshot"."area_id" = "area"."id"
3489 AND "snapshot"."issue_id" ISNULL
3490 ORDER BY "snapshot"."id" DESC
3491 LIMIT 1
3492 ) END / coalesce("area"."quorum_den", 1)
3494 )::INT4 AS "issue_quorum"
3495 FROM "area";
3497 COMMENT ON VIEW "area_quorum" IS 'Area-based quorum considering number of open (accepted) issues';
3500 CREATE VIEW "issue_quorum" AS
3501 SELECT DISTINCT ON ("issue_id")
3502 "issue"."id" AS "issue_id",
3503 "subquery"."issue_quorum"
3504 FROM "issue"
3505 CROSS JOIN LATERAL (
3506 SELECT "area_quorum"."issue_quorum"
3507 FROM "area_quorum" WHERE "area_quorum"."area_id" = "issue"."area_id"
3508 UNION ALL
3509 SELECT "policy"."issue_quorum"
3510 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3511 UNION ALL
3512 SELECT
3513 ceil(
3514 ("issue"."population"::INT8 * "policy"."issue_quorum_num"::INT8) /
3515 "policy"."issue_quorum_den"::FLOAT8
3516 )::INT4
3517 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3518 ) AS "subquery"
3519 ORDER BY "issue_id", "issue_quorum" DESC;
3521 COMMENT ON VIEW "issue_quorum" IS 'Effective quorum for issue admission';
3524 CREATE VIEW "area_with_unaccepted_issues" AS
3525 SELECT DISTINCT ON ("area"."id") "area".*
3526 FROM "area" JOIN "issue" ON "area"."id" = "issue"."area_id"
3527 WHERE "issue"."state" = 'admission';
3529 COMMENT ON VIEW "area_with_unaccepted_issues" IS 'All areas with unaccepted open issues (needed for issue admission system)';
3532 CREATE VIEW "issue_for_admission" AS
3533 SELECT DISTINCT ON ("issue"."area_id")
3534 "issue".*,
3535 max("initiative"."supporter_count") AS "max_supporter_count"
3536 FROM "issue"
3537 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
3538 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
3539 JOIN "area" ON "issue"."area_id" = "area"."id"
3540 WHERE "issue"."state" = 'admission'::"issue_state"
3541 AND now() >= "issue"."created" + "issue"."min_admission_time"
3542 AND "initiative"."supporter_count" >= "policy"."issue_quorum"
3543 AND "initiative"."supporter_count" * "policy"."issue_quorum_den" >=
3544 "issue"."population" * "policy"."issue_quorum_num"
3545 AND "initiative"."supporter_count" >= "area"."issue_quorum"
3546 AND "initiative"."revoked" ISNULL
3547 GROUP BY "issue"."id"
3548 ORDER BY "issue"."area_id", "max_supporter_count" DESC, "issue"."id";
3550 COMMENT ON VIEW "issue_for_admission" IS 'Contains up to 1 issue per area eligible to pass from ''admission'' to ''discussion'' state; needs to be recalculated after admitting the issue in this view';
3553 CREATE VIEW "unit_delegation" AS
3554 SELECT
3555 "unit"."id" AS "unit_id",
3556 "delegation"."id",
3557 "delegation"."truster_id",
3558 "delegation"."trustee_id",
3559 "delegation"."scope"
3560 FROM "unit"
3561 JOIN "delegation"
3562 ON "delegation"."unit_id" = "unit"."id"
3563 JOIN "member"
3564 ON "delegation"."truster_id" = "member"."id"
3565 JOIN "privilege"
3566 ON "delegation"."unit_id" = "privilege"."unit_id"
3567 AND "delegation"."truster_id" = "privilege"."member_id"
3568 WHERE "member"."active" AND "privilege"."voting_right";
3570 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
3573 CREATE VIEW "area_delegation" AS
3574 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
3575 "area"."id" AS "area_id",
3576 "delegation"."id",
3577 "delegation"."truster_id",
3578 "delegation"."trustee_id",
3579 "delegation"."scope"
3580 FROM "area"
3581 JOIN "delegation"
3582 ON "delegation"."unit_id" = "area"."unit_id"
3583 OR "delegation"."area_id" = "area"."id"
3584 JOIN "member"
3585 ON "delegation"."truster_id" = "member"."id"
3586 JOIN "privilege"
3587 ON "area"."unit_id" = "privilege"."unit_id"
3588 AND "delegation"."truster_id" = "privilege"."member_id"
3589 WHERE "member"."active" AND "privilege"."voting_right"
3590 ORDER BY
3591 "area"."id",
3592 "delegation"."truster_id",
3593 "delegation"."scope" DESC;
3595 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
3598 CREATE VIEW "issue_delegation" AS
3599 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
3600 "issue"."id" AS "issue_id",
3601 "delegation"."id",
3602 "delegation"."truster_id",
3603 "delegation"."trustee_id",
3604 "delegation"."scope"
3605 FROM "issue"
3606 JOIN "area"
3607 ON "area"."id" = "issue"."area_id"
3608 JOIN "delegation"
3609 ON "delegation"."unit_id" = "area"."unit_id"
3610 OR "delegation"."area_id" = "area"."id"
3611 OR "delegation"."issue_id" = "issue"."id"
3612 JOIN "member"
3613 ON "delegation"."truster_id" = "member"."id"
3614 JOIN "privilege"
3615 ON "area"."unit_id" = "privilege"."unit_id"
3616 AND "delegation"."truster_id" = "privilege"."member_id"
3617 WHERE "member"."active" AND "privilege"."voting_right"
3618 ORDER BY
3619 "issue"."id",
3620 "delegation"."truster_id",
3621 "delegation"."scope" DESC;
3623 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
3626 CREATE VIEW "member_count_view" AS
3627 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
3629 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
3632 CREATE VIEW "unit_member" AS
3633 SELECT
3634 "unit"."id" AS "unit_id",
3635 "member"."id" AS "member_id"
3636 FROM "privilege"
3637 JOIN "unit" ON "unit"."id" = "privilege"."unit_id"
3638 JOIN "member" ON "member"."id" = "privilege"."member_id"
3639 WHERE "privilege"."voting_right" AND "member"."active";
3641 COMMENT ON VIEW "unit_member" IS 'Active members with voting right in a unit';
3644 CREATE VIEW "unit_member_count" AS
3645 SELECT
3646 "unit"."id" AS "unit_id",
3647 count("unit_member"."member_id") AS "member_count"
3648 FROM "unit" LEFT JOIN "unit_member"
3649 ON "unit"."id" = "unit_member"."unit_id"
3650 GROUP BY "unit"."id";
3652 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
3655 CREATE VIEW "opening_draft" AS
3656 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3657 ORDER BY "initiative_id", "id";
3659 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
3662 CREATE VIEW "current_draft" AS
3663 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3664 ORDER BY "initiative_id", "id" DESC;
3666 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
3669 CREATE VIEW "critical_opinion" AS
3670 SELECT * FROM "opinion"
3671 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
3672 OR ("degree" = -2 AND "fulfilled" = TRUE);
3674 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
3677 CREATE VIEW "issue_supporter_in_admission_state" AS
3678 SELECT
3679 "area"."unit_id",
3680 "issue"."area_id",
3681 "issue"."id" AS "issue_id",
3682 "supporter"."member_id",
3683 "direct_interest_snapshot"."weight"
3684 FROM "issue"
3685 JOIN "area" ON "area"."id" = "issue"."area_id"
3686 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
3687 JOIN "direct_interest_snapshot"
3688 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3689 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3690 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
3691 WHERE "issue"."state" = 'admission'::"issue_state";
3693 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';
3696 CREATE VIEW "initiative_suggestion_order_calculation" AS
3697 SELECT
3698 "initiative"."id" AS "initiative_id",
3699 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
3700 FROM "initiative" JOIN "issue"
3701 ON "initiative"."issue_id" = "issue"."id"
3702 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
3703 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
3705 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
3707 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';
3710 CREATE VIEW "individual_suggestion_ranking" AS
3711 SELECT
3712 "opinion"."initiative_id",
3713 "opinion"."member_id",
3714 "direct_interest_snapshot"."weight",
3715 CASE WHEN
3716 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
3717 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
3718 THEN 1 ELSE
3719 CASE WHEN
3720 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
3721 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
3722 THEN 2 ELSE
3723 CASE WHEN
3724 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
3725 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
3726 THEN 3 ELSE 4 END
3727 END
3728 END AS "preference",
3729 "opinion"."suggestion_id"
3730 FROM "opinion"
3731 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
3732 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3733 JOIN "direct_interest_snapshot"
3734 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3735 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3736 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
3738 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
3741 CREATE VIEW "battle_participant" AS
3742 SELECT "initiative"."id", "initiative"."issue_id"
3743 FROM "issue" JOIN "initiative"
3744 ON "issue"."id" = "initiative"."issue_id"
3745 WHERE "initiative"."admitted"
3746 UNION ALL
3747 SELECT NULL, "id" AS "issue_id"
3748 FROM "issue";
3750 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
3753 CREATE VIEW "battle_view" AS
3754 SELECT
3755 "issue"."id" AS "issue_id",
3756 "winning_initiative"."id" AS "winning_initiative_id",
3757 "losing_initiative"."id" AS "losing_initiative_id",
3758 sum(
3759 CASE WHEN
3760 coalesce("better_vote"."grade", 0) >
3761 coalesce("worse_vote"."grade", 0)
3762 THEN "direct_voter"."weight" ELSE 0 END
3763 ) AS "count"
3764 FROM "issue"
3765 LEFT JOIN "direct_voter"
3766 ON "issue"."id" = "direct_voter"."issue_id"
3767 JOIN "battle_participant" AS "winning_initiative"
3768 ON "issue"."id" = "winning_initiative"."issue_id"
3769 JOIN "battle_participant" AS "losing_initiative"
3770 ON "issue"."id" = "losing_initiative"."issue_id"
3771 LEFT JOIN "vote" AS "better_vote"
3772 ON "direct_voter"."member_id" = "better_vote"."member_id"
3773 AND "winning_initiative"."id" = "better_vote"."initiative_id"
3774 LEFT JOIN "vote" AS "worse_vote"
3775 ON "direct_voter"."member_id" = "worse_vote"."member_id"
3776 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
3777 WHERE "issue"."state" = 'voting'
3778 AND "issue"."phase_finished" NOTNULL
3779 AND (
3780 "winning_initiative"."id" != "losing_initiative"."id" OR
3781 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
3782 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
3783 GROUP BY
3784 "issue"."id",
3785 "winning_initiative"."id",
3786 "losing_initiative"."id";
3788 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';
3791 CREATE VIEW "expired_session" AS
3792 SELECT * FROM "session" WHERE now() > "expiry";
3794 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
3795 DELETE FROM "session" WHERE "id" = OLD."id";
3797 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
3798 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
3801 CREATE VIEW "expired_token" AS
3802 SELECT * FROM "token" WHERE now() > "expiry" AND NOT (
3803 "token_type" = 'authorization' AND "used" AND EXISTS (
3804 SELECT NULL FROM "token" AS "other"
3805 WHERE "other"."authorization_token_id" = "token"."id" ) );
3807 CREATE RULE "delete" AS ON DELETE TO "expired_token" DO INSTEAD
3808 DELETE FROM "token" WHERE "id" = OLD."id";
3810 COMMENT ON VIEW "expired_token" IS 'View containing all expired tokens where DELETE is possible; Note that used authorization codes must not be deleted if still referred to by other tokens';
3813 CREATE VIEW "unused_snapshot" AS
3814 SELECT "snapshot".* FROM "snapshot"
3815 LEFT JOIN "issue"
3816 ON "snapshot"."id" = "issue"."latest_snapshot_id"
3817 OR "snapshot"."id" = "issue"."admission_snapshot_id"
3818 OR "snapshot"."id" = "issue"."half_freeze_snapshot_id"
3819 OR "snapshot"."id" = "issue"."full_freeze_snapshot_id"
3820 WHERE "issue"."id" ISNULL;
3822 CREATE RULE "delete" AS ON DELETE TO "unused_snapshot" DO INSTEAD
3823 DELETE FROM "snapshot" WHERE "id" = OLD."id";
3825 COMMENT ON VIEW "unused_snapshot" IS 'Snapshots that are not referenced by any issue (either as latest snapshot or as snapshot at phase/state change)';
3828 CREATE VIEW "open_issue" AS
3829 SELECT * FROM "issue" WHERE "closed" ISNULL;
3831 COMMENT ON VIEW "open_issue" IS 'All open issues';
3834 CREATE VIEW "member_contingent" AS
3835 SELECT
3836 "member"."id" AS "member_id",
3837 "contingent"."polling",
3838 "contingent"."time_frame",
3839 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
3840 (
3841 SELECT count(1) FROM "draft"
3842 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3843 WHERE "draft"."author_id" = "member"."id"
3844 AND "initiative"."polling" = "contingent"."polling"
3845 AND "draft"."created" > now() - "contingent"."time_frame"
3846 ) + (
3847 SELECT count(1) FROM "suggestion"
3848 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
3849 WHERE "suggestion"."author_id" = "member"."id"
3850 AND "contingent"."polling" = FALSE
3851 AND "suggestion"."created" > now() - "contingent"."time_frame"
3852 )
3853 ELSE NULL END AS "text_entry_count",
3854 "contingent"."text_entry_limit",
3855 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
3856 SELECT count(1) FROM "opening_draft" AS "draft"
3857 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3858 WHERE "draft"."author_id" = "member"."id"
3859 AND "initiative"."polling" = "contingent"."polling"
3860 AND "draft"."created" > now() - "contingent"."time_frame"
3861 ) ELSE NULL END AS "initiative_count",
3862 "contingent"."initiative_limit"
3863 FROM "member" CROSS JOIN "contingent";
3865 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
3867 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
3868 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
3871 CREATE VIEW "member_contingent_left" AS
3872 SELECT
3873 "member_id",
3874 "polling",
3875 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
3876 max("initiative_limit" - "initiative_count") AS "initiatives_left"
3877 FROM "member_contingent" GROUP BY "member_id", "polling";
3879 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.';
3882 CREATE VIEW "event_for_notification" AS
3883 SELECT
3884 "member"."id" AS "recipient_id",
3885 "event".*
3886 FROM "member" CROSS JOIN "event"
3887 JOIN "issue" ON "issue"."id" = "event"."issue_id"
3888 JOIN "area" ON "area"."id" = "issue"."area_id"
3889 LEFT JOIN "privilege" ON
3890 "privilege"."member_id" = "member"."id" AND
3891 "privilege"."unit_id" = "area"."unit_id" AND
3892 "privilege"."voting_right" = TRUE
3893 LEFT JOIN "subscription" ON
3894 "subscription"."member_id" = "member"."id" AND
3895 "subscription"."unit_id" = "area"."unit_id"
3896 LEFT JOIN "ignored_area" ON
3897 "ignored_area"."member_id" = "member"."id" AND
3898 "ignored_area"."area_id" = "issue"."area_id"
3899 LEFT JOIN "interest" ON
3900 "interest"."member_id" = "member"."id" AND
3901 "interest"."issue_id" = "event"."issue_id"
3902 LEFT JOIN "supporter" ON
3903 "supporter"."member_id" = "member"."id" AND
3904 "supporter"."initiative_id" = "event"."initiative_id"
3905 WHERE ("privilege"."member_id" NOTNULL OR "subscription"."member_id" NOTNULL)
3906 AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
3907 AND (
3908 "event"."event" = 'issue_state_changed'::"event_type" OR
3909 ( "event"."event" = 'initiative_revoked'::"event_type" AND
3910 "supporter"."member_id" NOTNULL ) );
3912 COMMENT ON VIEW "event_for_notification" IS 'Entries of the "event" table which are of interest for a particular notification mail recipient';
3914 COMMENT ON COLUMN "event_for_notification"."recipient_id" IS 'member_id of the recipient of a notification mail';
3917 CREATE VIEW "updated_initiative" AS
3918 SELECT
3919 "supporter"."member_id" AS "recipient_id",
3920 FALSE AS "featured",
3921 "supporter"."initiative_id"
3922 FROM "supporter"
3923 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
3924 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3925 LEFT JOIN "notification_initiative_sent" AS "sent" ON
3926 "sent"."member_id" = "supporter"."member_id" AND
3927 "sent"."initiative_id" = "supporter"."initiative_id"
3928 LEFT JOIN "ignored_initiative" ON
3929 "ignored_initiative"."member_id" = "supporter"."member_id" AND
3930 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
3931 WHERE "issue"."state" IN ('admission', 'discussion')
3932 AND "initiative"."revoked" ISNULL
3933 AND "ignored_initiative"."member_id" ISNULL
3934 AND (
3935 EXISTS (
3936 SELECT NULL FROM "draft"
3937 LEFT JOIN "ignored_member" ON
3938 "ignored_member"."member_id" = "supporter"."member_id" AND
3939 "ignored_member"."other_member_id" = "draft"."author_id"
3940 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
3941 AND "draft"."id" > "supporter"."draft_id"
3942 AND "ignored_member"."member_id" ISNULL
3943 ) OR EXISTS (
3944 SELECT NULL FROM "suggestion"
3945 LEFT JOIN "opinion" ON
3946 "opinion"."member_id" = "supporter"."member_id" AND
3947 "opinion"."suggestion_id" = "suggestion"."id"
3948 LEFT JOIN "ignored_member" ON
3949 "ignored_member"."member_id" = "supporter"."member_id" AND
3950 "ignored_member"."other_member_id" = "suggestion"."author_id"
3951 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
3952 AND "opinion"."member_id" ISNULL
3953 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
3954 AND "ignored_member"."member_id" ISNULL
3955 )
3956 );
3958 COMMENT ON VIEW "updated_initiative" IS 'Helper view for view "updated_or_featured_initiative"';
3961 CREATE FUNCTION "featured_initiative"
3962 ( "recipient_id_p" "member"."id"%TYPE,
3963 "area_id_p" "area"."id"%TYPE )
3964 RETURNS SETOF "initiative"."id"%TYPE
3965 LANGUAGE 'plpgsql' STABLE AS $$
3966 DECLARE
3967 "counter_v" "member"."notification_counter"%TYPE;
3968 "sample_size_v" "member"."notification_sample_size"%TYPE;
3969 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
3970 "match_v" BOOLEAN;
3971 "member_id_v" "member"."id"%TYPE;
3972 "seed_v" TEXT;
3973 "initiative_id_v" "initiative"."id"%TYPE;
3974 BEGIN
3975 SELECT "notification_counter", "notification_sample_size"
3976 INTO "counter_v", "sample_size_v"
3977 FROM "member" WHERE "id" = "recipient_id_p";
3978 IF COALESCE("sample_size_v" <= 0, TRUE) THEN
3979 RETURN;
3980 END IF;
3981 "initiative_id_ary" := '{}';
3982 LOOP
3983 "match_v" := FALSE;
3984 FOR "member_id_v", "seed_v" IN
3985 SELECT * FROM (
3986 SELECT DISTINCT
3987 "supporter"."member_id",
3988 md5(
3989 "recipient_id_p" || '-' ||
3990 "counter_v" || '-' ||
3991 "area_id_p" || '-' ||
3992 "supporter"."member_id"
3993 ) AS "seed"
3994 FROM "supporter"
3995 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
3996 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3997 WHERE "supporter"."member_id" != "recipient_id_p"
3998 AND "issue"."area_id" = "area_id_p"
3999 AND "issue"."state" IN ('admission', 'discussion', 'verification')
4000 ) AS "subquery"
4001 ORDER BY "seed"
4002 LOOP
4003 SELECT "initiative"."id" INTO "initiative_id_v"
4004 FROM "initiative"
4005 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4006 JOIN "area" ON "area"."id" = "issue"."area_id"
4007 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
4008 LEFT JOIN "supporter" AS "self_support" ON
4009 "self_support"."initiative_id" = "initiative"."id" AND
4010 "self_support"."member_id" = "recipient_id_p"
4011 LEFT JOIN "privilege" ON
4012 "privilege"."member_id" = "recipient_id_p" AND
4013 "privilege"."unit_id" = "area"."unit_id" AND
4014 "privilege"."voting_right" = TRUE
4015 LEFT JOIN "subscription" ON
4016 "subscription"."member_id" = "recipient_id_p" AND
4017 "subscription"."unit_id" = "area"."unit_id"
4018 LEFT JOIN "ignored_initiative" ON
4019 "ignored_initiative"."member_id" = "recipient_id_p" AND
4020 "ignored_initiative"."initiative_id" = "initiative"."id"
4021 WHERE "supporter"."member_id" = "member_id_v"
4022 AND "issue"."area_id" = "area_id_p"
4023 AND "issue"."state" IN ('admission', 'discussion', 'verification')
4024 AND "initiative"."revoked" ISNULL
4025 AND "self_support"."member_id" ISNULL
4026 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
4027 AND (
4028 "privilege"."member_id" NOTNULL OR
4029 "subscription"."member_id" NOTNULL )
4030 AND "ignored_initiative"."member_id" ISNULL
4031 AND NOT EXISTS (
4032 SELECT NULL FROM "draft"
4033 JOIN "ignored_member" ON
4034 "ignored_member"."member_id" = "recipient_id_p" AND
4035 "ignored_member"."other_member_id" = "draft"."author_id"
4036 WHERE "draft"."initiative_id" = "initiative"."id"
4037 )
4038 ORDER BY md5("seed_v" || '-' || "initiative"."id")
4039 LIMIT 1;
4040 IF FOUND THEN
4041 "match_v" := TRUE;
4042 RETURN NEXT "initiative_id_v";
4043 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
4044 RETURN;
4045 END IF;
4046 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
4047 END IF;
4048 END LOOP;
4049 EXIT WHEN NOT "match_v";
4050 END LOOP;
4051 RETURN;
4052 END;
4053 $$;
4055 COMMENT ON FUNCTION "featured_initiative"
4056 ( "recipient_id_p" "member"."id"%TYPE,
4057 "area_id_p" "area"."id"%TYPE )
4058 IS 'Helper function for view "updated_or_featured_initiative"';
4061 CREATE VIEW "updated_or_featured_initiative" AS
4062 SELECT
4063 "subquery".*,
4064 NOT EXISTS (
4065 SELECT NULL FROM "initiative" AS "better_initiative"
4066 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
4067 AND
4068 ( COALESCE("better_initiative"."supporter_count", -1),
4069 -"better_initiative"."id" ) >
4070 ( COALESCE("initiative"."supporter_count", -1),
4071 -"initiative"."id" )
4072 ) AS "leading"
4073 FROM (
4074 SELECT * FROM "updated_initiative"
4075 UNION ALL
4076 SELECT
4077 "member"."id" AS "recipient_id",
4078 TRUE AS "featured",
4079 "featured_initiative_id" AS "initiative_id"
4080 FROM "member" CROSS JOIN "area"
4081 CROSS JOIN LATERAL
4082 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
4083 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
4084 ) AS "subquery"
4085 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
4087 COMMENT ON VIEW "updated_or_featured_initiative" IS 'Initiatives to be included in a scheduled notification mail because (a) they have been updated or (b) they are featured';
4089 COMMENT ON COLUMN "updated_or_featured_initiative"."recipient_id" IS '"id" of the member who receives the notification mail';
4090 COMMENT ON COLUMN "updated_or_featured_initiative"."featured" IS 'TRUE if the initiative has been included because it was selected by the "featured_initiative" algorithm (see source of function "featured_initiative")';
4091 COMMENT ON COLUMN "updated_or_featured_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4092 COMMENT ON COLUMN "updated_or_featured_initiative"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4095 CREATE VIEW "leading_complement_initiative" AS
4096 SELECT * FROM (
4097 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
4098 "uf_initiative"."recipient_id",
4099 FALSE AS "featured",
4100 "uf_initiative"."initiative_id",
4101 TRUE AS "leading"
4102 FROM "updated_or_featured_initiative" AS "uf_initiative"
4103 JOIN "initiative" AS "uf_initiative_full" ON
4104 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
4105 JOIN "initiative" ON
4106 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
4107 WHERE "initiative"."revoked" ISNULL
4108 ORDER BY
4109 "uf_initiative"."recipient_id",
4110 "initiative"."issue_id",
4111 "initiative"."supporter_count" DESC,
4112 "initiative"."id"
4113 ) AS "subquery"
4114 WHERE NOT EXISTS (
4115 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
4116 WHERE "other"."recipient_id" = "subquery"."recipient_id"
4117 AND "other"."initiative_id" = "subquery"."initiative_id"
4118 );
4120 COMMENT ON VIEW "leading_complement_initiative" IS 'Helper view for view "unfiltered_initiative_for_notification" in order to always include the most supported initiative of an issue';
4121 COMMENT ON COLUMN "leading_complement_initiative"."featured" IS 'Always FALSE in this view';
4122 COMMENT ON COLUMN "leading_complement_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4123 COMMENT ON COLUMN "leading_complement_initiative"."leading" IS 'Always TRUE in this view';
4126 CREATE VIEW "unfiltered_initiative_for_notification" AS
4127 SELECT
4128 "subquery".*,
4129 "supporter"."member_id" NOTNULL AS "supported",
4130 CASE WHEN "supporter"."member_id" NOTNULL THEN
4131 EXISTS (
4132 SELECT NULL FROM "draft"
4133 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4134 AND "draft"."id" > "supporter"."draft_id"
4135 )
4136 ELSE
4137 EXISTS (
4138 SELECT NULL FROM "draft"
4139 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4140 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
4141 )
4142 END AS "new_draft",
4143 CASE WHEN "supporter"."member_id" NOTNULL THEN
4144 ( SELECT count(1) FROM "suggestion"
4145 LEFT JOIN "opinion" ON
4146 "opinion"."member_id" = "supporter"."member_id" AND
4147 "opinion"."suggestion_id" = "suggestion"."id"
4148 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4149 AND "opinion"."member_id" ISNULL
4150 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4151 )
4152 ELSE
4153 ( SELECT count(1) FROM "suggestion"
4154 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4155 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4156 )
4157 END AS "new_suggestion_count"
4158 FROM (
4159 SELECT * FROM "updated_or_featured_initiative"
4160 UNION ALL
4161 SELECT * FROM "leading_complement_initiative"
4162 ) AS "subquery"
4163 LEFT JOIN "supporter" ON
4164 "supporter"."member_id" = "subquery"."recipient_id" AND
4165 "supporter"."initiative_id" = "subquery"."initiative_id"
4166 LEFT JOIN "notification_initiative_sent" AS "sent" ON
4167 "sent"."member_id" = "subquery"."recipient_id" AND
4168 "sent"."initiative_id" = "subquery"."initiative_id";
4170 COMMENT ON VIEW "unfiltered_initiative_for_notification" IS 'Helper view which simply combines the views "updated_or_featured_initiative" and "leading_complement_initiative" and adds columns "supported", "new_draft", and "new_suggestion_count';
4172 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4173 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."new_draft" IS 'TRUE if a new draft exists (using the "draft_id" column of the "supporter" table in case of "supported" initiatives and the "last_draft_id" column of the "notification_initiative_sent" table in all other cases)';
4174 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."new_suggestion_count" IS 'Number of new suggestions (using the "last_suggestion_id" column of the "notification_initiative_sent" table while ignoring suggestions with an "opinion")';
4177 CREATE VIEW "initiative_for_notification" AS
4178 SELECT "unfiltered1".*
4179 FROM "unfiltered_initiative_for_notification" "unfiltered1"
4180 JOIN "initiative" AS "initiative1" ON
4181 "initiative1"."id" = "unfiltered1"."initiative_id"
4182 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
4183 WHERE EXISTS (
4184 SELECT NULL
4185 FROM "unfiltered_initiative_for_notification" "unfiltered2"
4186 JOIN "initiative" AS "initiative2" ON
4187 "initiative2"."id" = "unfiltered2"."initiative_id"
4188 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
4189 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
4190 AND "issue1"."area_id" = "issue2"."area_id"
4191 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
4192 );
4194 COMMENT ON VIEW "initiative_for_notification" IS 'Initiatives to be included in a scheduled notification mail';
4196 COMMENT ON COLUMN "initiative_for_notification"."recipient_id" IS '"id" of the member who receives the notification mail';
4197 COMMENT ON COLUMN "initiative_for_notification"."featured" IS 'TRUE if the initiative has been included because it was selected by the "featured_initiative" algorithm (see source of function "featured_initiative")';
4198 COMMENT ON COLUMN "initiative_for_notification"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4199 COMMENT ON COLUMN "initiative_for_notification"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4200 COMMENT ON COLUMN "initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4201 COMMENT ON COLUMN "initiative_for_notification"."new_draft" IS 'TRUE if a new draft exists (using the "draft_id" column of the "supporter" table in case of "supported" initiatives and the "last_draft_id" column of the "notification_initiative_sent" table in all other cases)';
4202 COMMENT ON COLUMN "initiative_for_notification"."new_suggestion_count" IS 'Number of new suggestions (using the "last_suggestion_id" column of the "notification_initiative_sent" table while ignoring suggestions with an "opinion")';
4205 CREATE VIEW "scheduled_notification_to_send" AS
4206 SELECT * FROM (
4207 SELECT
4208 "id" AS "recipient_id",
4209 now() - CASE WHEN "notification_dow" ISNULL THEN
4210 ( "notification_sent"::DATE + CASE
4211 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4212 THEN 0 ELSE 1 END
4213 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4214 ELSE
4215 ( "notification_sent"::DATE +
4216 ( 7 + "notification_dow" -
4217 EXTRACT(DOW FROM
4218 ( "notification_sent"::DATE + CASE
4219 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4220 THEN 0 ELSE 1 END
4221 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4222 )::INTEGER
4223 ) % 7 +
4224 CASE
4225 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4226 THEN 0 ELSE 1
4227 END
4228 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4229 END AS "pending"
4230 FROM (
4231 SELECT
4232 "id",
4233 COALESCE("notification_sent", "activated") AS "notification_sent",
4234 "notification_dow",
4235 "notification_hour"
4236 FROM "member_to_notify"
4237 WHERE "notification_hour" NOTNULL
4238 ) AS "subquery1"
4239 ) AS "subquery2"
4240 WHERE "pending" > '0'::INTERVAL;
4242 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
4244 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
4245 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
4248 CREATE VIEW "newsletter_to_send" AS
4249 SELECT
4250 "member"."id" AS "recipient_id",
4251 "newsletter"."id" AS "newsletter_id",
4252 "newsletter"."published"
4253 FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member"
4254 LEFT JOIN "privilege" ON
4255 "privilege"."member_id" = "member"."id" AND
4256 "privilege"."unit_id" = "newsletter"."unit_id" AND
4257 "privilege"."voting_right" = TRUE
4258 LEFT JOIN "subscription" ON
4259 "subscription"."member_id" = "member"."id" AND
4260 "subscription"."unit_id" = "newsletter"."unit_id"
4261 WHERE "newsletter"."published" <= now()
4262 AND "newsletter"."sent" ISNULL
4263 AND (
4264 "member"."disable_notifications" = FALSE OR
4265 "newsletter"."include_all_members" = TRUE )
4266 AND (
4267 "newsletter"."unit_id" ISNULL OR
4268 "privilege"."member_id" NOTNULL OR
4269 "subscription"."member_id" NOTNULL );
4271 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
4273 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
4277 ------------------------------------------------------
4278 -- Row set returning function for delegation chains --
4279 ------------------------------------------------------
4282 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
4283 ('first', 'intermediate', 'last', 'repetition');
4285 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
4288 CREATE TYPE "delegation_chain_row" AS (
4289 "index" INT4,
4290 "member_id" INT4,
4291 "member_valid" BOOLEAN,
4292 "participation" BOOLEAN,
4293 "overridden" BOOLEAN,
4294 "scope_in" "delegation_scope",
4295 "scope_out" "delegation_scope",
4296 "disabled_out" BOOLEAN,
4297 "loop" "delegation_chain_loop_tag" );
4299 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
4301 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
4302 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest; for area and global delegation chains: always null';
4303 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
4304 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
4305 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
4306 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
4307 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
4310 CREATE FUNCTION "delegation_chain_for_closed_issue"
4311 ( "member_id_p" "member"."id"%TYPE,
4312 "issue_id_p" "issue"."id"%TYPE )
4313 RETURNS SETOF "delegation_chain_row"
4314 LANGUAGE 'plpgsql' STABLE AS $$
4315 DECLARE
4316 "output_row" "delegation_chain_row";
4317 "direct_voter_row" "direct_voter"%ROWTYPE;
4318 "delegating_voter_row" "delegating_voter"%ROWTYPE;
4319 BEGIN
4320 "output_row"."index" := 0;
4321 "output_row"."member_id" := "member_id_p";
4322 "output_row"."member_valid" := TRUE;
4323 "output_row"."participation" := FALSE;
4324 "output_row"."overridden" := FALSE;
4325 "output_row"."disabled_out" := FALSE;
4326 LOOP
4327 SELECT INTO "direct_voter_row" * FROM "direct_voter"
4328 WHERE "issue_id" = "issue_id_p"
4329 AND "member_id" = "output_row"."member_id";
4330 IF "direct_voter_row"."member_id" NOTNULL THEN
4331 "output_row"."participation" := TRUE;
4332 "output_row"."scope_out" := NULL;
4333 "output_row"."disabled_out" := NULL;
4334 RETURN NEXT "output_row";
4335 RETURN;
4336 END IF;
4337 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
4338 WHERE "issue_id" = "issue_id_p"
4339 AND "member_id" = "output_row"."member_id";
4340 IF "delegating_voter_row"."member_id" ISNULL THEN
4341 RETURN;
4342 END IF;
4343 "output_row"."scope_out" := "delegating_voter_row"."scope";
4344 RETURN NEXT "output_row";
4345 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
4346 "output_row"."scope_in" := "output_row"."scope_out";
4347 END LOOP;
4348 END;
4349 $$;
4351 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
4352 ( "member"."id"%TYPE,
4353 "member"."id"%TYPE )
4354 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
4357 CREATE FUNCTION "delegation_chain"
4358 ( "member_id_p" "member"."id"%TYPE,
4359 "unit_id_p" "unit"."id"%TYPE,
4360 "area_id_p" "area"."id"%TYPE,
4361 "issue_id_p" "issue"."id"%TYPE,
4362 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4363 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4364 RETURNS SETOF "delegation_chain_row"
4365 LANGUAGE 'plpgsql' STABLE AS $$
4366 DECLARE
4367 "scope_v" "delegation_scope";
4368 "unit_id_v" "unit"."id"%TYPE;
4369 "area_id_v" "area"."id"%TYPE;
4370 "issue_row" "issue"%ROWTYPE;
4371 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
4372 "loop_member_id_v" "member"."id"%TYPE;
4373 "output_row" "delegation_chain_row";
4374 "output_rows" "delegation_chain_row"[];
4375 "simulate_v" BOOLEAN;
4376 "simulate_here_v" BOOLEAN;
4377 "delegation_row" "delegation"%ROWTYPE;
4378 "row_count" INT4;
4379 "i" INT4;
4380 "loop_v" BOOLEAN;
4381 BEGIN
4382 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
4383 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
4384 END IF;
4385 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
4386 "simulate_v" := TRUE;
4387 ELSE
4388 "simulate_v" := FALSE;
4389 END IF;
4390 IF
4391 "unit_id_p" NOTNULL AND
4392 "area_id_p" ISNULL AND
4393 "issue_id_p" ISNULL
4394 THEN
4395 "scope_v" := 'unit';
4396 "unit_id_v" := "unit_id_p";
4397 ELSIF
4398 "unit_id_p" ISNULL AND
4399 "area_id_p" NOTNULL AND
4400 "issue_id_p" ISNULL
4401 THEN
4402 "scope_v" := 'area';
4403 "area_id_v" := "area_id_p";
4404 SELECT "unit_id" INTO "unit_id_v"
4405 FROM "area" WHERE "id" = "area_id_v";
4406 ELSIF
4407 "unit_id_p" ISNULL AND
4408 "area_id_p" ISNULL AND
4409 "issue_id_p" NOTNULL
4410 THEN
4411 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
4412 IF "issue_row"."id" ISNULL THEN
4413 RETURN;
4414 END IF;
4415 IF "issue_row"."closed" NOTNULL THEN
4416 IF "simulate_v" THEN
4417 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
4418 END IF;
4419 FOR "output_row" IN
4420 SELECT * FROM
4421 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
4422 LOOP
4423 RETURN NEXT "output_row";
4424 END LOOP;
4425 RETURN;
4426 END IF;
4427 "scope_v" := 'issue';
4428 SELECT "area_id" INTO "area_id_v"
4429 FROM "issue" WHERE "id" = "issue_id_p";
4430 SELECT "unit_id" INTO "unit_id_v"
4431 FROM "area" WHERE "id" = "area_id_v";
4432 ELSE
4433 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
4434 END IF;
4435 "visited_member_ids" := '{}';
4436 "loop_member_id_v" := NULL;
4437 "output_rows" := '{}';
4438 "output_row"."index" := 0;
4439 "output_row"."member_id" := "member_id_p";
4440 "output_row"."member_valid" := TRUE;
4441 "output_row"."participation" := FALSE;
4442 "output_row"."overridden" := FALSE;
4443 "output_row"."disabled_out" := FALSE;
4444 "output_row"."scope_out" := NULL;
4445 LOOP
4446 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
4447 "loop_member_id_v" := "output_row"."member_id";
4448 ELSE
4449 "visited_member_ids" :=
4450 "visited_member_ids" || "output_row"."member_id";
4451 END IF;
4452 IF "output_row"."participation" ISNULL THEN
4453 "output_row"."overridden" := NULL;
4454 ELSIF "output_row"."participation" THEN
4455 "output_row"."overridden" := TRUE;
4456 END IF;
4457 "output_row"."scope_in" := "output_row"."scope_out";
4458 "output_row"."member_valid" := EXISTS (
4459 SELECT NULL FROM "member" JOIN "privilege"
4460 ON "privilege"."member_id" = "member"."id"
4461 AND "privilege"."unit_id" = "unit_id_v"
4462 WHERE "id" = "output_row"."member_id"
4463 AND "member"."active" AND "privilege"."voting_right"
4464 );
4465 "simulate_here_v" := (
4466 "simulate_v" AND
4467 "output_row"."member_id" = "member_id_p"
4468 );
4469 "delegation_row" := ROW(NULL);
4470 IF "output_row"."member_valid" OR "simulate_here_v" THEN
4471 IF "scope_v" = 'unit' THEN
4472 IF NOT "simulate_here_v" THEN
4473 SELECT * INTO "delegation_row" FROM "delegation"
4474 WHERE "truster_id" = "output_row"."member_id"
4475 AND "unit_id" = "unit_id_v";
4476 END IF;
4477 ELSIF "scope_v" = 'area' THEN
4478 IF "simulate_here_v" THEN
4479 IF "simulate_trustee_id_p" ISNULL THEN
4480 SELECT * INTO "delegation_row" FROM "delegation"
4481 WHERE "truster_id" = "output_row"."member_id"
4482 AND "unit_id" = "unit_id_v";
4483 END IF;
4484 ELSE
4485 SELECT * INTO "delegation_row" FROM "delegation"
4486 WHERE "truster_id" = "output_row"."member_id"
4487 AND (
4488 "unit_id" = "unit_id_v" OR
4489 "area_id" = "area_id_v"
4490 )
4491 ORDER BY "scope" DESC;
4492 END IF;
4493 ELSIF "scope_v" = 'issue' THEN
4494 IF "issue_row"."fully_frozen" ISNULL THEN
4495 "output_row"."participation" := EXISTS (
4496 SELECT NULL FROM "interest"
4497 WHERE "issue_id" = "issue_id_p"
4498 AND "member_id" = "output_row"."member_id"
4499 );
4500 ELSE
4501 IF "output_row"."member_id" = "member_id_p" THEN
4502 "output_row"."participation" := EXISTS (
4503 SELECT NULL FROM "direct_voter"
4504 WHERE "issue_id" = "issue_id_p"
4505 AND "member_id" = "output_row"."member_id"
4506 );
4507 ELSE
4508 "output_row"."participation" := NULL;
4509 END IF;
4510 END IF;
4511 IF "simulate_here_v" THEN
4512 IF "simulate_trustee_id_p" ISNULL THEN
4513 SELECT * INTO "delegation_row" FROM "delegation"
4514 WHERE "truster_id" = "output_row"."member_id"
4515 AND (
4516 "unit_id" = "unit_id_v" OR
4517 "area_id" = "area_id_v"
4518 )
4519 ORDER BY "scope" DESC;
4520 END IF;
4521 ELSE
4522 SELECT * INTO "delegation_row" FROM "delegation"
4523 WHERE "truster_id" = "output_row"."member_id"
4524 AND (
4525 "unit_id" = "unit_id_v" OR
4526 "area_id" = "area_id_v" OR
4527 "issue_id" = "issue_id_p"
4528 )
4529 ORDER BY "scope" DESC;
4530 END IF;
4531 END IF;
4532 ELSE
4533 "output_row"."participation" := FALSE;
4534 END IF;
4535 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
4536 "output_row"."scope_out" := "scope_v";
4537 "output_rows" := "output_rows" || "output_row";
4538 "output_row"."member_id" := "simulate_trustee_id_p";
4539 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
4540 "output_row"."scope_out" := "delegation_row"."scope";
4541 "output_rows" := "output_rows" || "output_row";
4542 "output_row"."member_id" := "delegation_row"."trustee_id";
4543 ELSIF "delegation_row"."scope" NOTNULL THEN
4544 "output_row"."scope_out" := "delegation_row"."scope";
4545 "output_row"."disabled_out" := TRUE;
4546 "output_rows" := "output_rows" || "output_row";
4547 EXIT;
4548 ELSE
4549 "output_row"."scope_out" := NULL;
4550 "output_rows" := "output_rows" || "output_row";
4551 EXIT;
4552 END IF;
4553 EXIT WHEN "loop_member_id_v" NOTNULL;
4554 "output_row"."index" := "output_row"."index" + 1;
4555 END LOOP;
4556 "row_count" := array_upper("output_rows", 1);
4557 "i" := 1;
4558 "loop_v" := FALSE;
4559 LOOP
4560 "output_row" := "output_rows"["i"];
4561 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
4562 IF "loop_v" THEN
4563 IF "i" + 1 = "row_count" THEN
4564 "output_row"."loop" := 'last';
4565 ELSIF "i" = "row_count" THEN
4566 "output_row"."loop" := 'repetition';
4567 ELSE
4568 "output_row"."loop" := 'intermediate';
4569 END IF;
4570 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
4571 "output_row"."loop" := 'first';
4572 "loop_v" := TRUE;
4573 END IF;
4574 IF "scope_v" = 'unit' THEN
4575 "output_row"."participation" := NULL;
4576 END IF;
4577 RETURN NEXT "output_row";
4578 "i" := "i" + 1;
4579 END LOOP;
4580 RETURN;
4581 END;
4582 $$;
4584 COMMENT ON FUNCTION "delegation_chain"
4585 ( "member"."id"%TYPE,
4586 "unit"."id"%TYPE,
4587 "area"."id"%TYPE,
4588 "issue"."id"%TYPE,
4589 "member"."id"%TYPE,
4590 BOOLEAN )
4591 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
4595 ---------------------------------------------------------
4596 -- Single row returning function for delegation chains --
4597 ---------------------------------------------------------
4600 CREATE TYPE "delegation_info_loop_type" AS ENUM
4601 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
4603 COMMENT ON TYPE "delegation_info_loop_type" IS 'Type of "delegation_loop" in "delegation_info_type"; ''own'' means loop to self, ''first'' means loop to first trustee, ''first_ellipsis'' means loop to ellipsis after first trustee, ''other'' means loop to other trustee, ''other_ellipsis'' means loop to ellipsis after other trustee''';
4606 CREATE TYPE "delegation_info_type" AS (
4607 "own_participation" BOOLEAN,
4608 "own_delegation_scope" "delegation_scope",
4609 "first_trustee_id" INT4,
4610 "first_trustee_participation" BOOLEAN,
4611 "first_trustee_ellipsis" BOOLEAN,
4612 "other_trustee_id" INT4,
4613 "other_trustee_participation" BOOLEAN,
4614 "other_trustee_ellipsis" BOOLEAN,
4615 "delegation_loop" "delegation_info_loop_type",
4616 "participating_member_id" INT4 );
4618 COMMENT ON TYPE "delegation_info_type" IS 'Type of result returned by "delegation_info" function; For meaning of "participation" check comment on "delegation_chain_row" type';
4620 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
4621 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
4622 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
4623 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
4624 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
4625 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
4626 COMMENT ON COLUMN "delegation_info_type"."other_trustee_participation" IS 'Another trustee is participating (redundant field: if "other_trustee_id" is set, then "other_trustee_participation" is always TRUE, else "other_trustee_participation" is NULL)';
4627 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
4628 COMMENT ON COLUMN "delegation_info_type"."delegation_loop" IS 'Non-NULL value, if delegation chain contains a circle; See comment on "delegation_info_loop_type" for details';
4629 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
4632 CREATE FUNCTION "delegation_info"
4633 ( "member_id_p" "member"."id"%TYPE,
4634 "unit_id_p" "unit"."id"%TYPE,
4635 "area_id_p" "area"."id"%TYPE,
4636 "issue_id_p" "issue"."id"%TYPE,
4637 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4638 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4639 RETURNS "delegation_info_type"
4640 LANGUAGE 'plpgsql' STABLE AS $$
4641 DECLARE
4642 "current_row" "delegation_chain_row";
4643 "result" "delegation_info_type";
4644 BEGIN
4645 "result"."own_participation" := FALSE;
4646 FOR "current_row" IN
4647 SELECT * FROM "delegation_chain"(
4648 "member_id_p",
4649 "unit_id_p", "area_id_p", "issue_id_p",
4650 "simulate_trustee_id_p", "simulate_default_p")
4651 LOOP
4652 IF
4653 "result"."participating_member_id" ISNULL AND
4654 "current_row"."participation"
4655 THEN
4656 "result"."participating_member_id" := "current_row"."member_id";
4657 END IF;
4658 IF "current_row"."member_id" = "member_id_p" THEN
4659 "result"."own_participation" := "current_row"."participation";
4660 "result"."own_delegation_scope" := "current_row"."scope_out";
4661 IF "current_row"."loop" = 'first' THEN
4662 "result"."delegation_loop" := 'own';
4663 END IF;
4664 ELSIF
4665 "current_row"."member_valid" AND
4666 ( "current_row"."loop" ISNULL OR
4667 "current_row"."loop" != 'repetition' )
4668 THEN
4669 IF "result"."first_trustee_id" ISNULL THEN
4670 "result"."first_trustee_id" := "current_row"."member_id";
4671 "result"."first_trustee_participation" := "current_row"."participation";
4672 "result"."first_trustee_ellipsis" := FALSE;
4673 IF "current_row"."loop" = 'first' THEN
4674 "result"."delegation_loop" := 'first';
4675 END IF;
4676 ELSIF "result"."other_trustee_id" ISNULL THEN
4677 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
4678 "result"."other_trustee_id" := "current_row"."member_id";
4679 "result"."other_trustee_participation" := TRUE;
4680 "result"."other_trustee_ellipsis" := FALSE;
4681 IF "current_row"."loop" = 'first' THEN
4682 "result"."delegation_loop" := 'other';
4683 END IF;
4684 ELSE
4685 "result"."first_trustee_ellipsis" := TRUE;
4686 IF "current_row"."loop" = 'first' THEN
4687 "result"."delegation_loop" := 'first_ellipsis';
4688 END IF;
4689 END IF;
4690 ELSE
4691 "result"."other_trustee_ellipsis" := TRUE;
4692 IF "current_row"."loop" = 'first' THEN
4693 "result"."delegation_loop" := 'other_ellipsis';
4694 END IF;
4695 END IF;
4696 END IF;
4697 END LOOP;
4698 RETURN "result";
4699 END;
4700 $$;
4702 COMMENT ON FUNCTION "delegation_info"
4703 ( "member"."id"%TYPE,
4704 "unit"."id"%TYPE,
4705 "area"."id"%TYPE,
4706 "issue"."id"%TYPE,
4707 "member"."id"%TYPE,
4708 BOOLEAN )
4709 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
4713 ------------------------
4714 -- Geospatial lookups --
4715 ------------------------
4717 /*
4718 CREATE FUNCTION "closed_initiatives_in_bounding_box"
4719 ( "bounding_box_p" EBOX,
4720 "limit_p" INT4 )
4721 RETURNS SETOF "initiative"
4722 LANGUAGE 'plpgsql' STABLE AS $$
4723 DECLARE
4724 "limit_v" INT4;
4725 "count_v" INT4;
4726 BEGIN
4727 "limit_v" := "limit_p" + 1;
4728 LOOP
4729 SELECT count(1) INTO "count_v"
4730 FROM "initiative"
4731 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4732 WHERE "issue"."closed" NOTNULL
4733 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4734 LIMIT "limit_v";
4735 IF "count_v" < "limit_v" THEN
4736 RETURN QUERY SELECT "initiative".*
4737 FROM (
4738 SELECT
4739 "initiative"."id" AS "initiative_id",
4740 "issue"."closed"
4741 FROM "initiative"
4742 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4743 WHERE "issue"."closed" NOTNULL
4744 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4745 ) AS "subquery"
4746 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4747 ORDER BY "subquery"."closed" DESC
4748 LIMIT "limit_p";
4749 RETURN;
4750 END IF;
4751 SELECT count(1) INTO "count_v"
4752 FROM (
4753 SELECT "initiative"."id" AS "initiative_id"
4754 FROM "initiative"
4755 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4756 WHERE "issue"."closed" NOTNULL
4757 ORDER BY "closed" DESC
4758 LIMIT "limit_v"
4759 ) AS "subquery"
4760 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4761 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4762 LIMIT "limit_p";
4763 IF "count_v" >= "limit_p" THEN
4764 RETURN QUERY SELECT "initiative".*
4765 FROM (
4766 SELECT
4767 "initiative"."id" AS "initiative_id",
4768 "issue"."closed"
4769 FROM "initiative"
4770 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4771 WHERE "issue"."closed" NOTNULL
4772 ORDER BY "closed" DESC
4773 LIMIT "limit_v"
4774 ) AS "subquery"
4775 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4776 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4777 ORDER BY "subquery"."closed" DESC
4778 LIMIT "limit_p";
4779 RETURN;
4780 END IF;
4781 "limit_v" := "limit_v" * 2;
4782 END LOOP;
4783 END;
4784 $$;
4786 COMMENT ON FUNCTION "closed_initiatives_in_bounding_box"
4787 ( EBOX, INT4 )
4788 IS 'TODO';
4789 */
4793 ---------------------------
4794 -- Transaction isolation --
4795 ---------------------------
4798 CREATE FUNCTION "require_transaction_isolation"()
4799 RETURNS VOID
4800 LANGUAGE 'plpgsql' VOLATILE AS $$
4801 BEGIN
4802 IF
4803 current_setting('transaction_isolation') NOT IN
4804 ('repeatable read', 'serializable')
4805 THEN
4806 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
4807 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
4808 END IF;
4809 RETURN;
4810 END;
4811 $$;
4813 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
4816 CREATE FUNCTION "dont_require_transaction_isolation"()
4817 RETURNS VOID
4818 LANGUAGE 'plpgsql' VOLATILE AS $$
4819 BEGIN
4820 IF
4821 current_setting('transaction_isolation') IN
4822 ('repeatable read', 'serializable')
4823 THEN
4824 RAISE WARNING 'Unneccessary transaction isolation level: %',
4825 current_setting('transaction_isolation');
4826 END IF;
4827 RETURN;
4828 END;
4829 $$;
4831 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
4835 -------------------------
4836 -- Notification system --
4837 -------------------------
4839 CREATE FUNCTION "get_initiatives_for_notification"
4840 ( "recipient_id_p" "member"."id"%TYPE )
4841 RETURNS SETOF "initiative_for_notification"
4842 LANGUAGE 'plpgsql' VOLATILE AS $$
4843 DECLARE
4844 "result_row" "initiative_for_notification"%ROWTYPE;
4845 "last_draft_id_v" "draft"."id"%TYPE;
4846 "last_suggestion_id_v" "suggestion"."id"%TYPE;
4847 BEGIN
4848 PERFORM "require_transaction_isolation"();
4849 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
4850 FOR "result_row" IN
4851 SELECT * FROM "initiative_for_notification"
4852 WHERE "recipient_id" = "recipient_id_p"
4853 LOOP
4854 SELECT "id" INTO "last_draft_id_v" FROM "draft"
4855 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
4856 ORDER BY "id" DESC LIMIT 1;
4857 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
4858 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
4859 ORDER BY "id" DESC LIMIT 1;
4860 INSERT INTO "notification_initiative_sent"
4861 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
4862 VALUES (
4863 "recipient_id_p",
4864 "result_row"."initiative_id",
4865 "last_draft_id_v",
4866 "last_suggestion_id_v" )
4867 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
4868 "last_draft_id" = "last_draft_id_v",
4869 "last_suggestion_id" = "last_suggestion_id_v";
4870 RETURN NEXT "result_row";
4871 END LOOP;
4872 DELETE FROM "notification_initiative_sent"
4873 USING "initiative", "issue"
4874 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
4875 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
4876 AND "issue"."id" = "initiative"."issue_id"
4877 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
4878 UPDATE "member" SET
4879 "notification_counter" = "notification_counter" + 1,
4880 "notification_sent" = now()
4881 WHERE "id" = "recipient_id_p";
4882 RETURN;
4883 END;
4884 $$;
4886 COMMENT ON FUNCTION "get_initiatives_for_notification"
4887 ( "member"."id"%TYPE )
4888 IS 'Returns rows from view "initiative_for_notification" for a given recipient while updating table "notification_initiative_sent" and columns "notification_counter" and "notification_sent" of "member" table';
4892 ------------------------------------------------------------------------
4893 -- Regular tasks, except calculcation of snapshots and voting results --
4894 ------------------------------------------------------------------------
4897 CREATE FUNCTION "check_activity"()
4898 RETURNS VOID
4899 LANGUAGE 'plpgsql' VOLATILE AS $$
4900 DECLARE
4901 "system_setting_row" "system_setting"%ROWTYPE;
4902 BEGIN
4903 PERFORM "dont_require_transaction_isolation"();
4904 SELECT * INTO "system_setting_row" FROM "system_setting";
4905 IF "system_setting_row"."member_ttl" NOTNULL THEN
4906 UPDATE "member" SET "active" = FALSE
4907 WHERE "active" = TRUE
4908 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
4909 END IF;
4910 RETURN;
4911 END;
4912 $$;
4914 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
4917 CREATE FUNCTION "calculate_member_counts"()
4918 RETURNS VOID
4919 LANGUAGE 'plpgsql' VOLATILE AS $$
4920 BEGIN
4921 PERFORM "require_transaction_isolation"();
4922 DELETE FROM "member_count";
4923 INSERT INTO "member_count" ("total_count")
4924 SELECT "total_count" FROM "member_count_view";
4925 UPDATE "unit" SET "member_count" = "view"."member_count"
4926 FROM "unit_member_count" AS "view"
4927 WHERE "view"."unit_id" = "unit"."id";
4928 RETURN;
4929 END;
4930 $$;
4932 COMMENT ON FUNCTION "calculate_member_counts"() IS 'Updates "member_count" table and "member_count" column of table "area" by materializing data from views "member_count_view" and "unit_member_count"';
4936 ------------------------------------
4937 -- Calculation of harmonic weight --
4938 ------------------------------------
4941 CREATE VIEW "remaining_harmonic_supporter_weight" AS
4942 SELECT
4943 "direct_interest_snapshot"."snapshot_id",
4944 "direct_interest_snapshot"."issue_id",
4945 "direct_interest_snapshot"."member_id",
4946 "direct_interest_snapshot"."weight" AS "weight_num",
4947 count("initiative"."id") AS "weight_den"
4948 FROM "issue"
4949 JOIN "direct_interest_snapshot"
4950 ON "issue"."latest_snapshot_id" = "direct_interest_snapshot"."snapshot_id"
4951 AND "issue"."id" = "direct_interest_snapshot"."issue_id"
4952 JOIN "initiative"
4953 ON "issue"."id" = "initiative"."issue_id"
4954 AND "initiative"."harmonic_weight" ISNULL
4955 JOIN "direct_supporter_snapshot"
4956 ON "issue"."latest_snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
4957 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
4958 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
4959 AND (
4960 "direct_supporter_snapshot"."satisfied" = TRUE OR
4961 coalesce("initiative"."admitted", FALSE) = FALSE
4962 )
4963 GROUP BY
4964 "direct_interest_snapshot"."snapshot_id",
4965 "direct_interest_snapshot"."issue_id",
4966 "direct_interest_snapshot"."member_id",
4967 "direct_interest_snapshot"."weight";
4969 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
4972 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
4973 SELECT
4974 "initiative"."issue_id",
4975 "initiative"."id" AS "initiative_id",
4976 "initiative"."admitted",
4977 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
4978 "remaining_harmonic_supporter_weight"."weight_den"
4979 FROM "remaining_harmonic_supporter_weight"
4980 JOIN "initiative"
4981 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
4982 AND "initiative"."harmonic_weight" ISNULL
4983 JOIN "direct_supporter_snapshot"
4984 ON "remaining_harmonic_supporter_weight"."snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
4985 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
4986 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
4987 AND (
4988 "direct_supporter_snapshot"."satisfied" = TRUE OR
4989 coalesce("initiative"."admitted", FALSE) = FALSE
4990 )
4991 GROUP BY
4992 "initiative"."issue_id",
4993 "initiative"."id",
4994 "initiative"."admitted",
4995 "remaining_harmonic_supporter_weight"."weight_den";
4997 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
5000 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
5001 SELECT
5002 "issue_id",
5003 "id" AS "initiative_id",
5004 "admitted",
5005 0 AS "weight_num",
5006 1 AS "weight_den"
5007 FROM "initiative"
5008 WHERE "harmonic_weight" ISNULL;
5010 COMMENT ON VIEW "remaining_harmonic_initiative_weight_dummies" IS 'Helper view for function "set_harmonic_initiative_weights" providing dummy weights of zero value, which are needed for corner cases where there are no supporters for an initiative at all';
5013 CREATE FUNCTION "set_harmonic_initiative_weights"
5014 ( "issue_id_p" "issue"."id"%TYPE )
5015 RETURNS VOID
5016 LANGUAGE 'plpgsql' VOLATILE AS $$
5017 DECLARE
5018 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
5019 "i" INT4;
5020 "count_v" INT4;
5021 "summand_v" FLOAT;
5022 "id_ary" INT4[];
5023 "weight_ary" FLOAT[];
5024 "min_weight_v" FLOAT;
5025 BEGIN
5026 PERFORM "require_transaction_isolation"();
5027 UPDATE "initiative" SET "harmonic_weight" = NULL
5028 WHERE "issue_id" = "issue_id_p";
5029 LOOP
5030 "min_weight_v" := NULL;
5031 "i" := 0;
5032 "count_v" := 0;
5033 FOR "weight_row" IN
5034 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
5035 WHERE "issue_id" = "issue_id_p"
5036 AND (
5037 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
5038 SELECT NULL FROM "initiative"
5039 WHERE "issue_id" = "issue_id_p"
5040 AND "harmonic_weight" ISNULL
5041 AND coalesce("admitted", FALSE) = FALSE
5042 )
5043 )
5044 UNION ALL -- needed for corner cases
5045 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
5046 WHERE "issue_id" = "issue_id_p"
5047 AND (
5048 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
5049 SELECT NULL FROM "initiative"
5050 WHERE "issue_id" = "issue_id_p"
5051 AND "harmonic_weight" ISNULL
5052 AND coalesce("admitted", FALSE) = FALSE
5053 )
5054 )
5055 ORDER BY "initiative_id" DESC, "weight_den" DESC
5056 -- NOTE: non-admitted initiatives placed first (at last positions),
5057 -- latest initiatives treated worse in case of tie
5058 LOOP
5059 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
5060 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
5061 "i" := "i" + 1;
5062 "count_v" := "i";
5063 "id_ary"["i"] := "weight_row"."initiative_id";
5064 "weight_ary"["i"] := "summand_v";
5065 ELSE
5066 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
5067 END IF;
5068 END LOOP;
5069 EXIT WHEN "count_v" = 0;
5070 "i" := 1;
5071 LOOP
5072 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
5073 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
5074 "min_weight_v" := "weight_ary"["i"];
5075 END IF;
5076 "i" := "i" + 1;
5077 EXIT WHEN "i" > "count_v";
5078 END LOOP;
5079 "i" := 1;
5080 LOOP
5081 IF "weight_ary"["i"] = "min_weight_v" THEN
5082 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
5083 WHERE "id" = "id_ary"["i"];
5084 EXIT;
5085 END IF;
5086 "i" := "i" + 1;
5087 END LOOP;
5088 END LOOP;
5089 UPDATE "initiative" SET "harmonic_weight" = 0
5090 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
5091 END;
5092 $$;
5094 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
5095 ( "issue"."id"%TYPE )
5096 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
5100 ------------------------------
5101 -- Calculation of snapshots --
5102 ------------------------------
5105 CREATE FUNCTION "weight_of_added_delegations_for_snapshot"
5106 ( "snapshot_id_p" "snapshot"."id"%TYPE,
5107 "issue_id_p" "issue"."id"%TYPE,
5108 "member_id_p" "member"."id"%TYPE,
5109 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
5110 RETURNS "direct_interest_snapshot"."weight"%TYPE
5111 LANGUAGE 'plpgsql' VOLATILE AS $$
5112 DECLARE
5113 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5114 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
5115 "weight_v" INT4;
5116 "sub_weight_v" INT4;
5117 BEGIN
5118 PERFORM "require_transaction_isolation"();
5119 "weight_v" := 0;
5120 FOR "issue_delegation_row" IN
5121 SELECT * FROM "issue_delegation"
5122 WHERE "trustee_id" = "member_id_p"
5123 AND "issue_id" = "issue_id_p"
5124 LOOP
5125 IF NOT EXISTS (
5126 SELECT NULL FROM "direct_interest_snapshot"
5127 WHERE "snapshot_id" = "snapshot_id_p"
5128 AND "issue_id" = "issue_id_p"
5129 AND "member_id" = "issue_delegation_row"."truster_id"
5130 ) AND NOT EXISTS (
5131 SELECT NULL FROM "delegating_interest_snapshot"
5132 WHERE "snapshot_id" = "snapshot_id_p"
5133 AND "issue_id" = "issue_id_p"
5134 AND "member_id" = "issue_delegation_row"."truster_id"
5135 ) THEN
5136 "delegate_member_ids_v" :=
5137 "member_id_p" || "delegate_member_ids_p";
5138 INSERT INTO "delegating_interest_snapshot" (
5139 "snapshot_id",
5140 "issue_id",
5141 "member_id",
5142 "scope",
5143 "delegate_member_ids"
5144 ) VALUES (
5145 "snapshot_id_p",
5146 "issue_id_p",
5147 "issue_delegation_row"."truster_id",
5148 "issue_delegation_row"."scope",
5149 "delegate_member_ids_v"
5150 );
5151 "sub_weight_v" := 1 +
5152 "weight_of_added_delegations_for_snapshot"(
5153 "snapshot_id_p",
5154 "issue_id_p",
5155 "issue_delegation_row"."truster_id",
5156 "delegate_member_ids_v"
5157 );
5158 UPDATE "delegating_interest_snapshot"
5159 SET "weight" = "sub_weight_v"
5160 WHERE "snapshot_id" = "snapshot_id_p"
5161 AND "issue_id" = "issue_id_p"
5162 AND "member_id" = "issue_delegation_row"."truster_id";
5163 "weight_v" := "weight_v" + "sub_weight_v";
5164 END IF;
5165 END LOOP;
5166 RETURN "weight_v";
5167 END;
5168 $$;
5170 COMMENT ON FUNCTION "weight_of_added_delegations_for_snapshot"
5171 ( "snapshot"."id"%TYPE,
5172 "issue"."id"%TYPE,
5173 "member"."id"%TYPE,
5174 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
5175 IS 'Helper function for "fill_snapshot" function';
5178 CREATE FUNCTION "take_snapshot"
5179 ( "issue_id_p" "issue"."id"%TYPE,
5180 "area_id_p" "area"."id"%TYPE = NULL )
5181 RETURNS "snapshot"."id"%TYPE
5182 LANGUAGE 'plpgsql' VOLATILE AS $$
5183 DECLARE
5184 "area_id_v" "area"."id"%TYPE;
5185 "unit_id_v" "unit"."id"%TYPE;
5186 "snapshot_id_v" "snapshot"."id"%TYPE;
5187 "issue_id_v" "issue"."id"%TYPE;
5188 "member_id_v" "member"."id"%TYPE;
5189 BEGIN
5190 IF "issue_id_p" NOTNULL AND "area_id_p" NOTNULL THEN
5191 RAISE EXCEPTION 'One of "issue_id_p" and "area_id_p" must be NULL';
5192 END IF;
5193 PERFORM "require_transaction_isolation"();
5194 IF "issue_id_p" ISNULL THEN
5195 "area_id_v" := "area_id_p";
5196 ELSE
5197 SELECT "area_id" INTO "area_id_v"
5198 FROM "issue" WHERE "id" = "issue_id_p";
5199 END IF;
5200 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5201 INSERT INTO "snapshot" ("area_id", "issue_id")
5202 VALUES ("area_id_v", "issue_id_p")
5203 RETURNING "id" INTO "snapshot_id_v";
5204 INSERT INTO "snapshot_population" ("snapshot_id", "member_id")
5205 SELECT "snapshot_id_v", "member_id"
5206 FROM "unit_member" WHERE "unit_id" = "unit_id_v";
5207 UPDATE "snapshot" SET
5208 "population" = (
5209 SELECT count(1) FROM "snapshot_population"
5210 WHERE "snapshot_id" = "snapshot_id_v"
5211 ) WHERE "id" = "snapshot_id_v";
5212 FOR "issue_id_v" IN
5213 SELECT "id" FROM "issue"
5214 WHERE CASE WHEN "issue_id_p" ISNULL THEN
5215 "area_id" = "area_id_p" AND
5216 "state" = 'admission'
5217 ELSE
5218 "id" = "issue_id_p"
5219 END
5220 LOOP
5221 INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id")
5222 VALUES ("snapshot_id_v", "issue_id_v");
5223 INSERT INTO "direct_interest_snapshot"
5224 ("snapshot_id", "issue_id", "member_id")
5225 SELECT
5226 "snapshot_id_v" AS "snapshot_id",
5227 "issue_id_v" AS "issue_id",
5228 "member"."id" AS "member_id"
5229 FROM "issue"
5230 JOIN "area" ON "issue"."area_id" = "area"."id"
5231 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
5232 JOIN "member" ON "interest"."member_id" = "member"."id"
5233 JOIN "privilege"
5234 ON "privilege"."unit_id" = "area"."unit_id"
5235 AND "privilege"."member_id" = "member"."id"
5236 WHERE "issue"."id" = "issue_id_v"
5237 AND "member"."active" AND "privilege"."voting_right";
5238 FOR "member_id_v" IN
5239 SELECT "member_id" FROM "direct_interest_snapshot"
5240 WHERE "snapshot_id" = "snapshot_id_v"
5241 AND "issue_id" = "issue_id_v"
5242 LOOP
5243 UPDATE "direct_interest_snapshot" SET
5244 "weight" = 1 +
5245 "weight_of_added_delegations_for_snapshot"(
5246 "snapshot_id_v",
5247 "issue_id_v",
5248 "member_id_v",
5249 '{}'
5250 )
5251 WHERE "snapshot_id" = "snapshot_id_v"
5252 AND "issue_id" = "issue_id_v"
5253 AND "member_id" = "member_id_v";
5254 END LOOP;
5255 INSERT INTO "direct_supporter_snapshot"
5256 ( "snapshot_id", "issue_id", "initiative_id", "member_id",
5257 "draft_id", "informed", "satisfied" )
5258 SELECT
5259 "snapshot_id_v" AS "snapshot_id",
5260 "issue_id_v" AS "issue_id",
5261 "initiative"."id" AS "initiative_id",
5262 "supporter"."member_id" AS "member_id",
5263 "supporter"."draft_id" AS "draft_id",
5264 "supporter"."draft_id" = "current_draft"."id" AS "informed",
5265 NOT EXISTS (
5266 SELECT NULL FROM "critical_opinion"
5267 WHERE "initiative_id" = "initiative"."id"
5268 AND "member_id" = "supporter"."member_id"
5269 ) AS "satisfied"
5270 FROM "initiative"
5271 JOIN "supporter"
5272 ON "supporter"."initiative_id" = "initiative"."id"
5273 JOIN "current_draft"
5274 ON "initiative"."id" = "current_draft"."initiative_id"
5275 JOIN "direct_interest_snapshot"
5276 ON "snapshot_id_v" = "direct_interest_snapshot"."snapshot_id"
5277 AND "supporter"."member_id" = "direct_interest_snapshot"."member_id"
5278 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
5279 WHERE "initiative"."issue_id" = "issue_id_v";
5280 DELETE FROM "temporary_suggestion_counts";
5281 INSERT INTO "temporary_suggestion_counts"
5282 ( "id",
5283 "minus2_unfulfilled_count", "minus2_fulfilled_count",
5284 "minus1_unfulfilled_count", "minus1_fulfilled_count",
5285 "plus1_unfulfilled_count", "plus1_fulfilled_count",
5286 "plus2_unfulfilled_count", "plus2_fulfilled_count" )
5287 SELECT
5288 "suggestion"."id",
5289 ( SELECT coalesce(sum("di"."weight"), 0)
5290 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5291 ON "di"."snapshot_id" = "snapshot_id_v"
5292 AND "di"."issue_id" = "issue_id_v"
5293 AND "di"."member_id" = "opinion"."member_id"
5294 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5295 AND "opinion"."degree" = -2
5296 AND "opinion"."fulfilled" = FALSE
5297 ) AS "minus2_unfulfilled_count",
5298 ( SELECT coalesce(sum("di"."weight"), 0)
5299 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5300 ON "di"."snapshot_id" = "snapshot_id_v"
5301 AND "di"."issue_id" = "issue_id_v"
5302 AND "di"."member_id" = "opinion"."member_id"
5303 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5304 AND "opinion"."degree" = -2
5305 AND "opinion"."fulfilled" = TRUE
5306 ) AS "minus2_fulfilled_count",
5307 ( SELECT coalesce(sum("di"."weight"), 0)
5308 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5309 ON "di"."snapshot_id" = "snapshot_id_v"
5310 AND "di"."issue_id" = "issue_id_v"
5311 AND "di"."member_id" = "opinion"."member_id"
5312 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5313 AND "opinion"."degree" = -1
5314 AND "opinion"."fulfilled" = FALSE
5315 ) AS "minus1_unfulfilled_count",
5316 ( SELECT coalesce(sum("di"."weight"), 0)
5317 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5318 ON "di"."snapshot_id" = "snapshot_id_v"
5319 AND "di"."issue_id" = "issue_id_v"
5320 AND "di"."member_id" = "opinion"."member_id"
5321 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5322 AND "opinion"."degree" = -1
5323 AND "opinion"."fulfilled" = TRUE
5324 ) AS "minus1_fulfilled_count",
5325 ( SELECT coalesce(sum("di"."weight"), 0)
5326 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5327 ON "di"."snapshot_id" = "snapshot_id_v"
5328 AND "di"."issue_id" = "issue_id_v"
5329 AND "di"."member_id" = "opinion"."member_id"
5330 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5331 AND "opinion"."degree" = 1
5332 AND "opinion"."fulfilled" = FALSE
5333 ) AS "plus1_unfulfilled_count",
5334 ( SELECT coalesce(sum("di"."weight"), 0)
5335 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5336 ON "di"."snapshot_id" = "snapshot_id_v"
5337 AND "di"."issue_id" = "issue_id_v"
5338 AND "di"."member_id" = "opinion"."member_id"
5339 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5340 AND "opinion"."degree" = 1
5341 AND "opinion"."fulfilled" = TRUE
5342 ) AS "plus1_fulfilled_count",
5343 ( SELECT coalesce(sum("di"."weight"), 0)
5344 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5345 ON "di"."snapshot_id" = "snapshot_id_v"
5346 AND "di"."issue_id" = "issue_id_v"
5347 AND "di"."member_id" = "opinion"."member_id"
5348 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5349 AND "opinion"."degree" = 2
5350 AND "opinion"."fulfilled" = FALSE
5351 ) AS "plus2_unfulfilled_count",
5352 ( SELECT coalesce(sum("di"."weight"), 0)
5353 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5354 ON "di"."snapshot_id" = "snapshot_id_v"
5355 AND "di"."issue_id" = "issue_id_v"
5356 AND "di"."member_id" = "opinion"."member_id"
5357 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5358 AND "opinion"."degree" = 2
5359 AND "opinion"."fulfilled" = TRUE
5360 ) AS "plus2_fulfilled_count"
5361 FROM "suggestion" JOIN "initiative"
5362 ON "suggestion"."initiative_id" = "initiative"."id"
5363 WHERE "initiative"."issue_id" = "issue_id_v";
5364 END LOOP;
5365 RETURN "snapshot_id_v";
5366 END;
5367 $$;
5369 COMMENT ON FUNCTION "take_snapshot"
5370 ( "issue"."id"%TYPE,
5371 "area"."id"%TYPE )
5372 IS 'This function creates a new interest/supporter snapshot of a particular issue, or, if the first argument is NULL, for all issues in ''admission'' phase of the area given as second argument. It must be executed with TRANSACTION ISOLATION LEVEL REPEATABLE READ. The snapshot must later be finished by calling "finish_snapshot" for every issue.';
5375 CREATE FUNCTION "finish_snapshot"
5376 ( "issue_id_p" "issue"."id"%TYPE )
5377 RETURNS VOID
5378 LANGUAGE 'plpgsql' VOLATILE AS $$
5379 DECLARE
5380 "snapshot_id_v" "snapshot"."id"%TYPE;
5381 BEGIN
5382 -- NOTE: function does not require snapshot isolation but we don't call
5383 -- "dont_require_snapshot_isolation" here because this function is
5384 -- also invoked by "check_issue"
5385 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
5386 SELECT "id" INTO "snapshot_id_v" FROM "snapshot"
5387 ORDER BY "id" DESC LIMIT 1;
5388 UPDATE "issue" SET
5389 "calculated" = "snapshot"."calculated",
5390 "latest_snapshot_id" = "snapshot_id_v",
5391 "population" = "snapshot"."population",
5392 "initiative_quorum" = CASE WHEN
5393 "policy"."initiative_quorum" > ceil(
5394 ( "issue"."population"::INT8 *
5395 "policy"."initiative_quorum_num"::INT8 ) /
5396 "policy"."initiative_quorum_den"::FLOAT8
5397 )::INT4
5398 THEN
5399 "policy"."initiative_quorum"
5400 ELSE
5401 ceil(
5402 ( "issue"."population"::INT8 *
5403 "policy"."initiative_quorum_num"::INT8 ) /
5404 "policy"."initiative_quorum_den"::FLOAT8
5405 )::INT4
5406 END
5407 FROM "snapshot", "policy"
5408 WHERE "issue"."id" = "issue_id_p"
5409 AND "snapshot"."id" = "snapshot_id_v"
5410 AND "policy"."id" = "issue"."policy_id";
5411 UPDATE "initiative" SET
5412 "supporter_count" = (
5413 SELECT coalesce(sum("di"."weight"), 0)
5414 FROM "direct_interest_snapshot" AS "di"
5415 JOIN "direct_supporter_snapshot" AS "ds"
5416 ON "di"."member_id" = "ds"."member_id"
5417 WHERE "di"."snapshot_id" = "snapshot_id_v"
5418 AND "di"."issue_id" = "issue_id_p"
5419 AND "ds"."snapshot_id" = "snapshot_id_v"
5420 AND "ds"."initiative_id" = "initiative"."id"
5421 ),
5422 "informed_supporter_count" = (
5423 SELECT coalesce(sum("di"."weight"), 0)
5424 FROM "direct_interest_snapshot" AS "di"
5425 JOIN "direct_supporter_snapshot" AS "ds"
5426 ON "di"."member_id" = "ds"."member_id"
5427 WHERE "di"."snapshot_id" = "snapshot_id_v"
5428 AND "di"."issue_id" = "issue_id_p"
5429 AND "ds"."snapshot_id" = "snapshot_id_v"
5430 AND "ds"."initiative_id" = "initiative"."id"
5431 AND "ds"."informed"
5432 ),
5433 "satisfied_supporter_count" = (
5434 SELECT coalesce(sum("di"."weight"), 0)
5435 FROM "direct_interest_snapshot" AS "di"
5436 JOIN "direct_supporter_snapshot" AS "ds"
5437 ON "di"."member_id" = "ds"."member_id"
5438 WHERE "di"."snapshot_id" = "snapshot_id_v"
5439 AND "di"."issue_id" = "issue_id_p"
5440 AND "ds"."snapshot_id" = "snapshot_id_v"
5441 AND "ds"."initiative_id" = "initiative"."id"
5442 AND "ds"."satisfied"
5443 ),
5444 "satisfied_informed_supporter_count" = (
5445 SELECT coalesce(sum("di"."weight"), 0)
5446 FROM "direct_interest_snapshot" AS "di"
5447 JOIN "direct_supporter_snapshot" AS "ds"
5448 ON "di"."member_id" = "ds"."member_id"
5449 WHERE "di"."snapshot_id" = "snapshot_id_v"
5450 AND "di"."issue_id" = "issue_id_p"
5451 AND "ds"."snapshot_id" = "snapshot_id_v"
5452 AND "ds"."initiative_id" = "initiative"."id"
5453 AND "ds"."informed"
5454 AND "ds"."satisfied"
5455 )
5456 WHERE "issue_id" = "issue_id_p";
5457 UPDATE "suggestion" SET
5458 "minus2_unfulfilled_count" = "temp"."minus2_unfulfilled_count",
5459 "minus2_fulfilled_count" = "temp"."minus2_fulfilled_count",
5460 "minus1_unfulfilled_count" = "temp"."minus1_unfulfilled_count",
5461 "minus1_fulfilled_count" = "temp"."minus1_fulfilled_count",
5462 "plus1_unfulfilled_count" = "temp"."plus1_unfulfilled_count",
5463 "plus1_fulfilled_count" = "temp"."plus1_fulfilled_count",
5464 "plus2_unfulfilled_count" = "temp"."plus2_unfulfilled_count",
5465 "plus2_fulfilled_count" = "temp"."plus2_fulfilled_count"
5466 FROM "temporary_suggestion_counts" AS "temp", "initiative"
5467 WHERE "temp"."id" = "suggestion"."id"
5468 AND "initiative"."issue_id" = "issue_id_p"
5469 AND "suggestion"."initiative_id" = "initiative"."id";
5470 DELETE FROM "temporary_suggestion_counts";
5471 RETURN;
5472 END;
5473 $$;
5475 COMMENT ON FUNCTION "finish_snapshot"
5476 ( "issue"."id"%TYPE )
5477 IS 'After calling "take_snapshot", this function "finish_snapshot" needs to be called for every issue in the snapshot (separate function calls keep locking time minimal)';
5481 -----------------------
5482 -- Counting of votes --
5483 -----------------------
5486 CREATE FUNCTION "weight_of_added_vote_delegations"
5487 ( "issue_id_p" "issue"."id"%TYPE,
5488 "member_id_p" "member"."id"%TYPE,
5489 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
5490 RETURNS "direct_voter"."weight"%TYPE
5491 LANGUAGE 'plpgsql' VOLATILE AS $$
5492 DECLARE
5493 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5494 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
5495 "weight_v" INT4;
5496 "sub_weight_v" INT4;
5497 BEGIN
5498 PERFORM "require_transaction_isolation"();
5499 "weight_v" := 0;
5500 FOR "issue_delegation_row" IN
5501 SELECT * FROM "issue_delegation"
5502 WHERE "trustee_id" = "member_id_p"
5503 AND "issue_id" = "issue_id_p"
5504 LOOP
5505 IF NOT EXISTS (
5506 SELECT NULL FROM "direct_voter"
5507 WHERE "member_id" = "issue_delegation_row"."truster_id"
5508 AND "issue_id" = "issue_id_p"
5509 ) AND NOT EXISTS (
5510 SELECT NULL FROM "delegating_voter"
5511 WHERE "member_id" = "issue_delegation_row"."truster_id"
5512 AND "issue_id" = "issue_id_p"
5513 ) THEN
5514 "delegate_member_ids_v" :=
5515 "member_id_p" || "delegate_member_ids_p";
5516 INSERT INTO "delegating_voter" (
5517 "issue_id",
5518 "member_id",
5519 "scope",
5520 "delegate_member_ids"
5521 ) VALUES (
5522 "issue_id_p",
5523 "issue_delegation_row"."truster_id",
5524 "issue_delegation_row"."scope",
5525 "delegate_member_ids_v"
5526 );
5527 "sub_weight_v" := 1 +
5528 "weight_of_added_vote_delegations"(
5529 "issue_id_p",
5530 "issue_delegation_row"."truster_id",
5531 "delegate_member_ids_v"
5532 );
5533 UPDATE "delegating_voter"
5534 SET "weight" = "sub_weight_v"
5535 WHERE "issue_id" = "issue_id_p"
5536 AND "member_id" = "issue_delegation_row"."truster_id";
5537 "weight_v" := "weight_v" + "sub_weight_v";
5538 END IF;
5539 END LOOP;
5540 RETURN "weight_v";
5541 END;
5542 $$;
5544 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
5545 ( "issue"."id"%TYPE,
5546 "member"."id"%TYPE,
5547 "delegating_voter"."delegate_member_ids"%TYPE )
5548 IS 'Helper function for "add_vote_delegations" function';
5551 CREATE FUNCTION "add_vote_delegations"
5552 ( "issue_id_p" "issue"."id"%TYPE )
5553 RETURNS VOID
5554 LANGUAGE 'plpgsql' VOLATILE AS $$
5555 DECLARE
5556 "member_id_v" "member"."id"%TYPE;
5557 BEGIN
5558 PERFORM "require_transaction_isolation"();
5559 FOR "member_id_v" IN
5560 SELECT "member_id" FROM "direct_voter"
5561 WHERE "issue_id" = "issue_id_p"
5562 LOOP
5563 UPDATE "direct_voter" SET
5564 "weight" = "weight" + "weight_of_added_vote_delegations"(
5565 "issue_id_p",
5566 "member_id_v",
5567 '{}'
5568 )
5569 WHERE "member_id" = "member_id_v"
5570 AND "issue_id" = "issue_id_p";
5571 END LOOP;
5572 RETURN;
5573 END;
5574 $$;
5576 COMMENT ON FUNCTION "add_vote_delegations"
5577 ( "issue_id_p" "issue"."id"%TYPE )
5578 IS 'Helper function for "close_voting" function';
5581 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
5582 RETURNS VOID
5583 LANGUAGE 'plpgsql' VOLATILE AS $$
5584 DECLARE
5585 "area_id_v" "area"."id"%TYPE;
5586 "unit_id_v" "unit"."id"%TYPE;
5587 "member_id_v" "member"."id"%TYPE;
5588 BEGIN
5589 PERFORM "require_transaction_isolation"();
5590 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
5591 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5592 -- override protection triggers:
5593 INSERT INTO "temporary_transaction_data" ("key", "value")
5594 VALUES ('override_protection_triggers', TRUE::TEXT);
5595 -- delete timestamp of voting comment:
5596 UPDATE "direct_voter" SET "comment_changed" = NULL
5597 WHERE "issue_id" = "issue_id_p";
5598 -- delete delegating votes (in cases of manual reset of issue state):
5599 DELETE FROM "delegating_voter"
5600 WHERE "issue_id" = "issue_id_p";
5601 -- delete votes from non-privileged voters:
5602 DELETE FROM "direct_voter"
5603 USING (
5604 SELECT
5605 "direct_voter"."member_id"
5606 FROM "direct_voter"
5607 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
5608 LEFT JOIN "privilege"
5609 ON "privilege"."unit_id" = "unit_id_v"
5610 AND "privilege"."member_id" = "direct_voter"."member_id"
5611 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
5612 "member"."active" = FALSE OR
5613 "privilege"."voting_right" ISNULL OR
5614 "privilege"."voting_right" = FALSE
5615 )
5616 ) AS "subquery"
5617 WHERE "direct_voter"."issue_id" = "issue_id_p"
5618 AND "direct_voter"."member_id" = "subquery"."member_id";
5619 -- consider delegations:
5620 UPDATE "direct_voter" SET "weight" = 1
5621 WHERE "issue_id" = "issue_id_p";
5622 PERFORM "add_vote_delegations"("issue_id_p");
5623 -- mark first preferences:
5624 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
5625 FROM (
5626 SELECT
5627 "vote"."initiative_id",
5628 "vote"."member_id",
5629 CASE WHEN "vote"."grade" > 0 THEN
5630 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
5631 ELSE NULL
5632 END AS "first_preference"
5633 FROM "vote"
5634 JOIN "initiative" -- NOTE: due to missing index on issue_id
5635 ON "vote"."issue_id" = "initiative"."issue_id"
5636 JOIN "vote" AS "agg"
5637 ON "initiative"."id" = "agg"."initiative_id"
5638 AND "vote"."member_id" = "agg"."member_id"
5639 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
5640 ) AS "subquery"
5641 WHERE "vote"."issue_id" = "issue_id_p"
5642 AND "vote"."initiative_id" = "subquery"."initiative_id"
5643 AND "vote"."member_id" = "subquery"."member_id";
5644 -- finish overriding protection triggers (avoids garbage):
5645 DELETE FROM "temporary_transaction_data"
5646 WHERE "key" = 'override_protection_triggers';
5647 -- materialize battle_view:
5648 -- NOTE: "closed" column of issue must be set at this point
5649 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
5650 INSERT INTO "battle" (
5651 "issue_id",
5652 "winning_initiative_id", "losing_initiative_id",
5653 "count"
5654 ) SELECT
5655 "issue_id",
5656 "winning_initiative_id", "losing_initiative_id",
5657 "count"
5658 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
5659 -- set voter count:
5660 UPDATE "issue" SET
5661 "voter_count" = (
5662 SELECT coalesce(sum("weight"), 0)
5663 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
5664 )
5665 WHERE "id" = "issue_id_p";
5666 -- copy "positive_votes" and "negative_votes" from "battle" table:
5667 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
5668 UPDATE "initiative" SET
5669 "first_preference_votes" = 0,
5670 "positive_votes" = "battle_win"."count",
5671 "negative_votes" = "battle_lose"."count"
5672 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
5673 WHERE
5674 "battle_win"."issue_id" = "issue_id_p" AND
5675 "battle_win"."winning_initiative_id" = "initiative"."id" AND
5676 "battle_win"."losing_initiative_id" ISNULL AND
5677 "battle_lose"."issue_id" = "issue_id_p" AND
5678 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
5679 "battle_lose"."winning_initiative_id" ISNULL;
5680 -- calculate "first_preference_votes":
5681 -- NOTE: will only set values not equal to zero
5682 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
5683 FROM (
5684 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
5685 FROM "vote" JOIN "direct_voter"
5686 ON "vote"."issue_id" = "direct_voter"."issue_id"
5687 AND "vote"."member_id" = "direct_voter"."member_id"
5688 WHERE "vote"."first_preference"
5689 GROUP BY "vote"."initiative_id"
5690 ) AS "subquery"
5691 WHERE "initiative"."issue_id" = "issue_id_p"
5692 AND "initiative"."admitted"
5693 AND "initiative"."id" = "subquery"."initiative_id";
5694 END;
5695 $$;
5697 COMMENT ON FUNCTION "close_voting"
5698 ( "issue"."id"%TYPE )
5699 IS 'Closes the voting on an issue, and calculates positive and negative votes for each initiative; The ranking is not calculated yet, to keep the (locking) transaction short.';
5702 CREATE FUNCTION "defeat_strength"
5703 ( "positive_votes_p" INT4,
5704 "negative_votes_p" INT4,
5705 "defeat_strength_p" "defeat_strength" )
5706 RETURNS INT8
5707 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5708 BEGIN
5709 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
5710 IF "positive_votes_p" > "negative_votes_p" THEN
5711 RETURN "positive_votes_p";
5712 ELSE
5713 RETURN 0;
5714 END IF;
5715 ELSE
5716 IF "positive_votes_p" > "negative_votes_p" THEN
5717 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
5718 ELSIF "positive_votes_p" = "negative_votes_p" THEN
5719 RETURN 0;
5720 ELSE
5721 RETURN -1;
5722 END IF;
5723 END IF;
5724 END;
5725 $$;
5727 COMMENT ON FUNCTION "defeat_strength"(INT4, INT4, "defeat_strength") IS 'Calculates defeat strength (INT8!) according to the "defeat_strength" option (see comment on type "defeat_strength")';
5730 CREATE FUNCTION "secondary_link_strength"
5731 ( "initiative1_ord_p" INT4,
5732 "initiative2_ord_p" INT4,
5733 "tie_breaking_p" "tie_breaking" )
5734 RETURNS INT8
5735 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5736 BEGIN
5737 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
5738 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
5739 END IF;
5740 RETURN (
5741 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
5742 0
5743 ELSE
5744 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
5745 1::INT8 << 62
5746 ELSE 0 END
5747 +
5748 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
5749 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
5750 ELSE
5751 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
5752 END
5753 END
5754 );
5755 END;
5756 $$;
5758 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
5761 CREATE TYPE "link_strength" AS (
5762 "primary" INT8,
5763 "secondary" INT8 );
5765 COMMENT ON TYPE "link_strength" IS 'Type to store the defeat strength of a link between two candidates plus a secondary criterion to create unique link strengths between the candidates (needed for tie-breaking ''variant1'' and ''variant2'')';
5768 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
5769 RETURNS "link_strength"[][]
5770 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5771 DECLARE
5772 "dimension_v" INT4;
5773 "matrix_p" "link_strength"[][];
5774 "i" INT4;
5775 "j" INT4;
5776 "k" INT4;
5777 BEGIN
5778 "dimension_v" := array_upper("matrix_d", 1);
5779 "matrix_p" := "matrix_d";
5780 "i" := 1;
5781 LOOP
5782 "j" := 1;
5783 LOOP
5784 IF "i" != "j" THEN
5785 "k" := 1;
5786 LOOP
5787 IF "i" != "k" AND "j" != "k" THEN
5788 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
5789 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
5790 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
5791 END IF;
5792 ELSE
5793 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
5794 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
5795 END IF;
5796 END IF;
5797 END IF;
5798 EXIT WHEN "k" = "dimension_v";
5799 "k" := "k" + 1;
5800 END LOOP;
5801 END IF;
5802 EXIT WHEN "j" = "dimension_v";
5803 "j" := "j" + 1;
5804 END LOOP;
5805 EXIT WHEN "i" = "dimension_v";
5806 "i" := "i" + 1;
5807 END LOOP;
5808 RETURN "matrix_p";
5809 END;
5810 $$;
5812 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
5815 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
5816 RETURNS VOID
5817 LANGUAGE 'plpgsql' VOLATILE AS $$
5818 DECLARE
5819 "issue_row" "issue"%ROWTYPE;
5820 "policy_row" "policy"%ROWTYPE;
5821 "dimension_v" INT4;
5822 "matrix_a" INT4[][]; -- absolute votes
5823 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
5824 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
5825 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
5826 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
5827 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
5828 "i" INT4;
5829 "j" INT4;
5830 "m" INT4;
5831 "n" INT4;
5832 "battle_row" "battle"%ROWTYPE;
5833 "rank_ary" INT4[];
5834 "rank_v" INT4;
5835 "initiative_id_v" "initiative"."id"%TYPE;
5836 BEGIN
5837 PERFORM "require_transaction_isolation"();
5838 SELECT * INTO "issue_row"
5839 FROM "issue" WHERE "id" = "issue_id_p";
5840 SELECT * INTO "policy_row"
5841 FROM "policy" WHERE "id" = "issue_row"."policy_id";
5842 SELECT count(1) INTO "dimension_v"
5843 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
5844 -- create "matrix_a" with absolute number of votes in pairwise
5845 -- comparison:
5846 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
5847 "i" := 1;
5848 "j" := 2;
5849 FOR "battle_row" IN
5850 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
5851 ORDER BY
5852 "winning_initiative_id" NULLS FIRST,
5853 "losing_initiative_id" NULLS FIRST
5854 LOOP
5855 "matrix_a"["i"]["j"] := "battle_row"."count";
5856 IF "j" = "dimension_v" THEN
5857 "i" := "i" + 1;
5858 "j" := 1;
5859 ELSE
5860 "j" := "j" + 1;
5861 IF "j" = "i" THEN
5862 "j" := "j" + 1;
5863 END IF;
5864 END IF;
5865 END LOOP;
5866 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
5867 RAISE EXCEPTION 'Wrong battle count (should not happen)';
5868 END IF;
5869 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
5870 -- and "secondary_link_strength" functions:
5871 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
5872 "i" := 1;
5873 LOOP
5874 "j" := 1;
5875 LOOP
5876 IF "i" != "j" THEN
5877 "matrix_d"["i"]["j"] := (
5878 "defeat_strength"(
5879 "matrix_a"["i"]["j"],
5880 "matrix_a"["j"]["i"],
5881 "policy_row"."defeat_strength"
5882 ),
5883 "secondary_link_strength"(
5884 "i",
5885 "j",
5886 "policy_row"."tie_breaking"
5887 )
5888 )::"link_strength";
5889 END IF;
5890 EXIT WHEN "j" = "dimension_v";
5891 "j" := "j" + 1;
5892 END LOOP;
5893 EXIT WHEN "i" = "dimension_v";
5894 "i" := "i" + 1;
5895 END LOOP;
5896 -- find best paths:
5897 "matrix_p" := "find_best_paths"("matrix_d");
5898 -- create partial order:
5899 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
5900 "i" := 1;
5901 LOOP
5902 "j" := "i" + 1;
5903 LOOP
5904 IF "i" != "j" THEN
5905 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
5906 "matrix_b"["i"]["j"] := TRUE;
5907 "matrix_b"["j"]["i"] := FALSE;
5908 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
5909 "matrix_b"["i"]["j"] := FALSE;
5910 "matrix_b"["j"]["i"] := TRUE;
5911 END IF;
5912 END IF;
5913 EXIT WHEN "j" = "dimension_v";
5914 "j" := "j" + 1;
5915 END LOOP;
5916 EXIT WHEN "i" = "dimension_v" - 1;
5917 "i" := "i" + 1;
5918 END LOOP;
5919 -- tie-breaking by forbidding shared weakest links in beat-paths
5920 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
5921 -- is performed later by initiative id):
5922 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
5923 "m" := 1;
5924 LOOP
5925 "n" := "m" + 1;
5926 LOOP
5927 -- only process those candidates m and n, which are tied:
5928 IF "matrix_b"["m"]["n"] ISNULL THEN
5929 -- start with beat-paths prior tie-breaking:
5930 "matrix_t" := "matrix_p";
5931 -- start with all links allowed:
5932 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
5933 LOOP
5934 -- determine (and forbid) that link that is the weakest link
5935 -- in both the best path from candidate m to candidate n and
5936 -- from candidate n to candidate m:
5937 "i" := 1;
5938 <<forbid_one_link>>
5939 LOOP
5940 "j" := 1;
5941 LOOP
5942 IF "i" != "j" THEN
5943 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
5944 "matrix_f"["i"]["j"] := TRUE;
5945 -- exit for performance reasons,
5946 -- as exactly one link will be found:
5947 EXIT forbid_one_link;
5948 END IF;
5949 END IF;
5950 EXIT WHEN "j" = "dimension_v";
5951 "j" := "j" + 1;
5952 END LOOP;
5953 IF "i" = "dimension_v" THEN
5954 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
5955 END IF;
5956 "i" := "i" + 1;
5957 END LOOP;
5958 -- calculate best beat-paths while ignoring forbidden links:
5959 "i" := 1;
5960 LOOP
5961 "j" := 1;
5962 LOOP
5963 IF "i" != "j" THEN
5964 "matrix_t"["i"]["j"] := CASE
5965 WHEN "matrix_f"["i"]["j"]
5966 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
5967 ELSE "matrix_d"["i"]["j"] END;
5968 END IF;
5969 EXIT WHEN "j" = "dimension_v";
5970 "j" := "j" + 1;
5971 END LOOP;
5972 EXIT WHEN "i" = "dimension_v";
5973 "i" := "i" + 1;
5974 END LOOP;
5975 "matrix_t" := "find_best_paths"("matrix_t");
5976 -- extend partial order, if tie-breaking was successful:
5977 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
5978 "matrix_b"["m"]["n"] := TRUE;
5979 "matrix_b"["n"]["m"] := FALSE;
5980 EXIT;
5981 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
5982 "matrix_b"["m"]["n"] := FALSE;
5983 "matrix_b"["n"]["m"] := TRUE;
5984 EXIT;
5985 END IF;
5986 END LOOP;
5987 END IF;
5988 EXIT WHEN "n" = "dimension_v";
5989 "n" := "n" + 1;
5990 END LOOP;
5991 EXIT WHEN "m" = "dimension_v" - 1;
5992 "m" := "m" + 1;
5993 END LOOP;
5994 END IF;
5995 -- store a unique ranking in "rank_ary":
5996 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
5997 "rank_v" := 1;
5998 LOOP
5999 "i" := 1;
6000 <<assign_next_rank>>
6001 LOOP
6002 IF "rank_ary"["i"] ISNULL THEN
6003 "j" := 1;
6004 LOOP
6005 IF
6006 "i" != "j" AND
6007 "rank_ary"["j"] ISNULL AND
6008 ( "matrix_b"["j"]["i"] OR
6009 -- tie-breaking by "id"
6010 ( "matrix_b"["j"]["i"] ISNULL AND
6011 "j" < "i" ) )
6012 THEN
6013 -- someone else is better
6014 EXIT;
6015 END IF;
6016 IF "j" = "dimension_v" THEN
6017 -- noone is better
6018 "rank_ary"["i"] := "rank_v";
6019 EXIT assign_next_rank;
6020 END IF;
6021 "j" := "j" + 1;
6022 END LOOP;
6023 END IF;
6024 "i" := "i" + 1;
6025 IF "i" > "dimension_v" THEN
6026 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
6027 END IF;
6028 END LOOP;
6029 EXIT WHEN "rank_v" = "dimension_v";
6030 "rank_v" := "rank_v" + 1;
6031 END LOOP;
6032 -- write preliminary results:
6033 "i" := 2; -- omit status quo with "i" = 1
6034 FOR "initiative_id_v" IN
6035 SELECT "id" FROM "initiative"
6036 WHERE "issue_id" = "issue_id_p" AND "admitted"
6037 ORDER BY "id"
6038 LOOP
6039 UPDATE "initiative" SET
6040 "direct_majority" =
6041 CASE WHEN "policy_row"."direct_majority_strict" THEN
6042 "positive_votes" * "policy_row"."direct_majority_den" >
6043 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
6044 ELSE
6045 "positive_votes" * "policy_row"."direct_majority_den" >=
6046 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
6047 END
6048 AND "positive_votes" >= "policy_row"."direct_majority_positive"
6049 AND "issue_row"."voter_count"-"negative_votes" >=
6050 "policy_row"."direct_majority_non_negative",
6051 "indirect_majority" =
6052 CASE WHEN "policy_row"."indirect_majority_strict" THEN
6053 "positive_votes" * "policy_row"."indirect_majority_den" >
6054 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
6055 ELSE
6056 "positive_votes" * "policy_row"."indirect_majority_den" >=
6057 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
6058 END
6059 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
6060 AND "issue_row"."voter_count"-"negative_votes" >=
6061 "policy_row"."indirect_majority_non_negative",
6062 "schulze_rank" = "rank_ary"["i"],
6063 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
6064 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
6065 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
6066 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
6067 THEN NULL
6068 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
6069 "eligible" = FALSE,
6070 "winner" = FALSE,
6071 "rank" = NULL -- NOTE: in cases of manual reset of issue state
6072 WHERE "id" = "initiative_id_v";
6073 "i" := "i" + 1;
6074 END LOOP;
6075 IF "i" != "dimension_v" + 1 THEN
6076 RAISE EXCEPTION 'Wrong winner count (should not happen)';
6077 END IF;
6078 -- take indirect majorities into account:
6079 LOOP
6080 UPDATE "initiative" SET "indirect_majority" = TRUE
6081 FROM (
6082 SELECT "new_initiative"."id" AS "initiative_id"
6083 FROM "initiative" "old_initiative"
6084 JOIN "initiative" "new_initiative"
6085 ON "new_initiative"."issue_id" = "issue_id_p"
6086 AND "new_initiative"."indirect_majority" = FALSE
6087 JOIN "battle" "battle_win"
6088 ON "battle_win"."issue_id" = "issue_id_p"
6089 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
6090 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
6091 JOIN "battle" "battle_lose"
6092 ON "battle_lose"."issue_id" = "issue_id_p"
6093 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
6094 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
6095 WHERE "old_initiative"."issue_id" = "issue_id_p"
6096 AND "old_initiative"."indirect_majority" = TRUE
6097 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
6098 "battle_win"."count" * "policy_row"."indirect_majority_den" >
6099 "policy_row"."indirect_majority_num" *
6100 ("battle_win"."count"+"battle_lose"."count")
6101 ELSE
6102 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
6103 "policy_row"."indirect_majority_num" *
6104 ("battle_win"."count"+"battle_lose"."count")
6105 END
6106 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
6107 AND "issue_row"."voter_count"-"battle_lose"."count" >=
6108 "policy_row"."indirect_majority_non_negative"
6109 ) AS "subquery"
6110 WHERE "id" = "subquery"."initiative_id";
6111 EXIT WHEN NOT FOUND;
6112 END LOOP;
6113 -- set "multistage_majority" for remaining matching initiatives:
6114 UPDATE "initiative" SET "multistage_majority" = TRUE
6115 FROM (
6116 SELECT "losing_initiative"."id" AS "initiative_id"
6117 FROM "initiative" "losing_initiative"
6118 JOIN "initiative" "winning_initiative"
6119 ON "winning_initiative"."issue_id" = "issue_id_p"
6120 AND "winning_initiative"."admitted"
6121 JOIN "battle" "battle_win"
6122 ON "battle_win"."issue_id" = "issue_id_p"
6123 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
6124 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
6125 JOIN "battle" "battle_lose"
6126 ON "battle_lose"."issue_id" = "issue_id_p"
6127 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
6128 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
6129 WHERE "losing_initiative"."issue_id" = "issue_id_p"
6130 AND "losing_initiative"."admitted"
6131 AND "winning_initiative"."schulze_rank" <
6132 "losing_initiative"."schulze_rank"
6133 AND "battle_win"."count" > "battle_lose"."count"
6134 AND (
6135 "battle_win"."count" > "winning_initiative"."positive_votes" OR
6136 "battle_lose"."count" < "losing_initiative"."negative_votes" )
6137 ) AS "subquery"
6138 WHERE "id" = "subquery"."initiative_id";
6139 -- mark eligible initiatives:
6140 UPDATE "initiative" SET "eligible" = TRUE
6141 WHERE "issue_id" = "issue_id_p"
6142 AND "initiative"."direct_majority"
6143 AND "initiative"."indirect_majority"
6144 AND "initiative"."better_than_status_quo"
6145 AND (
6146 "policy_row"."no_multistage_majority" = FALSE OR
6147 "initiative"."multistage_majority" = FALSE )
6148 AND (
6149 "policy_row"."no_reverse_beat_path" = FALSE OR
6150 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
6151 -- mark final winner:
6152 UPDATE "initiative" SET "winner" = TRUE
6153 FROM (
6154 SELECT "id" AS "initiative_id"
6155 FROM "initiative"
6156 WHERE "issue_id" = "issue_id_p" AND "eligible"
6157 ORDER BY
6158 "schulze_rank",
6159 "id"
6160 LIMIT 1
6161 ) AS "subquery"
6162 WHERE "id" = "subquery"."initiative_id";
6163 -- write (final) ranks:
6164 "rank_v" := 1;
6165 FOR "initiative_id_v" IN
6166 SELECT "id"
6167 FROM "initiative"
6168 WHERE "issue_id" = "issue_id_p" AND "admitted"
6169 ORDER BY
6170 "winner" DESC,
6171 "eligible" DESC,
6172 "schulze_rank",
6173 "id"
6174 LOOP
6175 UPDATE "initiative" SET "rank" = "rank_v"
6176 WHERE "id" = "initiative_id_v";
6177 "rank_v" := "rank_v" + 1;
6178 END LOOP;
6179 -- set schulze rank of status quo and mark issue as finished:
6180 UPDATE "issue" SET
6181 "status_quo_schulze_rank" = "rank_ary"[1],
6182 "state" =
6183 CASE WHEN EXISTS (
6184 SELECT NULL FROM "initiative"
6185 WHERE "issue_id" = "issue_id_p" AND "winner"
6186 ) THEN
6187 'finished_with_winner'::"issue_state"
6188 ELSE
6189 'finished_without_winner'::"issue_state"
6190 END,
6191 "closed" = "phase_finished",
6192 "phase_finished" = NULL
6193 WHERE "id" = "issue_id_p";
6194 RETURN;
6195 END;
6196 $$;
6198 COMMENT ON FUNCTION "calculate_ranks"
6199 ( "issue"."id"%TYPE )
6200 IS 'Determine ranking (Votes have to be counted first)';
6204 -----------------------------
6205 -- Automatic state changes --
6206 -----------------------------
6209 CREATE FUNCTION "issue_admission"
6210 ( "area_id_p" "area"."id"%TYPE )
6211 RETURNS BOOLEAN
6212 LANGUAGE 'plpgsql' VOLATILE AS $$
6213 DECLARE
6214 "issue_id_v" "issue"."id"%TYPE;
6215 BEGIN
6216 PERFORM "dont_require_transaction_isolation"();
6217 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
6218 UPDATE "area" SET "issue_quorum" = "view"."issue_quorum"
6219 FROM "area_quorum" AS "view"
6220 WHERE "area"."id" = "view"."area_id"
6221 AND "area"."id" = "area_id_p";
6222 SELECT "id" INTO "issue_id_v" FROM "issue_for_admission"
6223 WHERE "area_id" = "area_id_p";
6224 IF "issue_id_v" ISNULL THEN RETURN FALSE; END IF;
6225 UPDATE "issue" SET
6226 "admission_snapshot_id" = "latest_snapshot_id",
6227 "state" = 'discussion',
6228 "accepted" = now(),
6229 "phase_finished" = NULL,
6230 "issue_quorum" = "issue_quorum"."issue_quorum"
6231 FROM "issue_quorum"
6232 WHERE "id" = "issue_id_v"
6233 AND "issue_quorum"."issue_id" = "issue_id_v";
6234 RETURN TRUE;
6235 END;
6236 $$;
6238 COMMENT ON FUNCTION "issue_admission"
6239 ( "area"."id"%TYPE )
6240 IS 'Checks if an issue in the area can be admitted for further discussion; returns TRUE on success in which case the function must be called again until it returns FALSE';
6243 CREATE TYPE "check_issue_persistence" AS (
6244 "state" "issue_state",
6245 "phase_finished" BOOLEAN,
6246 "issue_revoked" BOOLEAN,
6247 "snapshot_created" BOOLEAN,
6248 "harmonic_weights_set" BOOLEAN,
6249 "closed_voting" BOOLEAN );
6251 COMMENT ON TYPE "check_issue_persistence" IS 'Type of data returned by "check_issue" function, to be passed to subsequent calls of the same function';
6254 CREATE FUNCTION "check_issue"
6255 ( "issue_id_p" "issue"."id"%TYPE,
6256 "persist" "check_issue_persistence" )
6257 RETURNS "check_issue_persistence"
6258 LANGUAGE 'plpgsql' VOLATILE AS $$
6259 DECLARE
6260 "issue_row" "issue"%ROWTYPE;
6261 "last_calculated_v" "snapshot"."calculated"%TYPE;
6262 "policy_row" "policy"%ROWTYPE;
6263 "initiative_row" "initiative"%ROWTYPE;
6264 "state_v" "issue_state";
6265 BEGIN
6266 PERFORM "require_transaction_isolation"();
6267 IF "persist" ISNULL THEN
6268 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6269 FOR UPDATE;
6270 SELECT "calculated" INTO "last_calculated_v"
6271 FROM "snapshot" JOIN "snapshot_issue"
6272 ON "snapshot"."id" = "snapshot_issue"."snapshot_id"
6273 WHERE "snapshot_issue"."issue_id" = "issue_id_p"
6274 ORDER BY "snapshot"."id" DESC;
6275 IF "issue_row"."closed" NOTNULL THEN
6276 RETURN NULL;
6277 END IF;
6278 "persist"."state" := "issue_row"."state";
6279 IF
6280 ( "issue_row"."state" = 'admission' AND "last_calculated_v" >=
6281 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
6282 ( "issue_row"."state" = 'discussion' AND now() >=
6283 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
6284 ( "issue_row"."state" = 'verification' AND now() >=
6285 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
6286 ( "issue_row"."state" = 'voting' AND now() >=
6287 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
6288 THEN
6289 "persist"."phase_finished" := TRUE;
6290 ELSE
6291 "persist"."phase_finished" := FALSE;
6292 END IF;
6293 IF
6294 NOT EXISTS (
6295 -- all initiatives are revoked
6296 SELECT NULL FROM "initiative"
6297 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6298 ) AND (
6299 -- and issue has not been accepted yet
6300 "persist"."state" = 'admission' OR
6301 -- or verification time has elapsed
6302 ( "persist"."state" = 'verification' AND
6303 "persist"."phase_finished" ) OR
6304 -- or no initiatives have been revoked lately
6305 NOT EXISTS (
6306 SELECT NULL FROM "initiative"
6307 WHERE "issue_id" = "issue_id_p"
6308 AND now() < "revoked" + "issue_row"."verification_time"
6309 )
6310 )
6311 THEN
6312 "persist"."issue_revoked" := TRUE;
6313 ELSE
6314 "persist"."issue_revoked" := FALSE;
6315 END IF;
6316 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
6317 UPDATE "issue" SET "phase_finished" = now()
6318 WHERE "id" = "issue_row"."id";
6319 RETURN "persist";
6320 ELSIF
6321 "persist"."state" IN ('admission', 'discussion', 'verification')
6322 THEN
6323 RETURN "persist";
6324 ELSE
6325 RETURN NULL;
6326 END IF;
6327 END IF;
6328 IF
6329 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6330 coalesce("persist"."snapshot_created", FALSE) = FALSE
6331 THEN
6332 IF "persist"."state" != 'admission' THEN
6333 PERFORM "take_snapshot"("issue_id_p");
6334 PERFORM "finish_snapshot"("issue_id_p");
6335 ELSE
6336 UPDATE "issue" SET "issue_quorum" = "issue_quorum"."issue_quorum"
6337 FROM "issue_quorum"
6338 WHERE "id" = "issue_id_p"
6339 AND "issue_quorum"."issue_id" = "issue_id_p";
6340 END IF;
6341 "persist"."snapshot_created" = TRUE;
6342 IF "persist"."phase_finished" THEN
6343 IF "persist"."state" = 'admission' THEN
6344 UPDATE "issue" SET "admission_snapshot_id" = "latest_snapshot_id"
6345 WHERE "id" = "issue_id_p";
6346 ELSIF "persist"."state" = 'discussion' THEN
6347 UPDATE "issue" SET "half_freeze_snapshot_id" = "latest_snapshot_id"
6348 WHERE "id" = "issue_id_p";
6349 ELSIF "persist"."state" = 'verification' THEN
6350 UPDATE "issue" SET "full_freeze_snapshot_id" = "latest_snapshot_id"
6351 WHERE "id" = "issue_id_p";
6352 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
6353 FOR "initiative_row" IN
6354 SELECT * FROM "initiative"
6355 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6356 FOR UPDATE
6357 LOOP
6358 IF
6359 "initiative_row"."polling" OR
6360 "initiative_row"."satisfied_supporter_count" >=
6361 "issue_row"."initiative_quorum"
6362 THEN
6363 UPDATE "initiative" SET "admitted" = TRUE
6364 WHERE "id" = "initiative_row"."id";
6365 ELSE
6366 UPDATE "initiative" SET "admitted" = FALSE
6367 WHERE "id" = "initiative_row"."id";
6368 END IF;
6369 END LOOP;
6370 END IF;
6371 END IF;
6372 RETURN "persist";
6373 END IF;
6374 IF
6375 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6376 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
6377 THEN
6378 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
6379 "persist"."harmonic_weights_set" = TRUE;
6380 IF
6381 "persist"."phase_finished" OR
6382 "persist"."issue_revoked" OR
6383 "persist"."state" = 'admission'
6384 THEN
6385 RETURN "persist";
6386 ELSE
6387 RETURN NULL;
6388 END IF;
6389 END IF;
6390 IF "persist"."issue_revoked" THEN
6391 IF "persist"."state" = 'admission' THEN
6392 "state_v" := 'canceled_revoked_before_accepted';
6393 ELSIF "persist"."state" = 'discussion' THEN
6394 "state_v" := 'canceled_after_revocation_during_discussion';
6395 ELSIF "persist"."state" = 'verification' THEN
6396 "state_v" := 'canceled_after_revocation_during_verification';
6397 END IF;
6398 UPDATE "issue" SET
6399 "state" = "state_v",
6400 "closed" = "phase_finished",
6401 "phase_finished" = NULL
6402 WHERE "id" = "issue_id_p";
6403 RETURN NULL;
6404 END IF;
6405 IF "persist"."state" = 'admission' THEN
6406 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6407 FOR UPDATE;
6408 IF "issue_row"."phase_finished" NOTNULL THEN
6409 UPDATE "issue" SET
6410 "state" = 'canceled_issue_not_accepted',
6411 "closed" = "phase_finished",
6412 "phase_finished" = NULL
6413 WHERE "id" = "issue_id_p";
6414 END IF;
6415 RETURN NULL;
6416 END IF;
6417 IF "persist"."phase_finished" THEN
6418 IF "persist"."state" = 'discussion' THEN
6419 UPDATE "issue" SET
6420 "state" = 'verification',
6421 "half_frozen" = "phase_finished",
6422 "phase_finished" = NULL
6423 WHERE "id" = "issue_id_p";
6424 RETURN NULL;
6425 END IF;
6426 IF "persist"."state" = 'verification' THEN
6427 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6428 FOR UPDATE;
6429 SELECT * INTO "policy_row" FROM "policy"
6430 WHERE "id" = "issue_row"."policy_id";
6431 IF EXISTS (
6432 SELECT NULL FROM "initiative"
6433 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
6434 ) THEN
6435 UPDATE "issue" SET
6436 "state" = 'voting',
6437 "fully_frozen" = "phase_finished",
6438 "phase_finished" = NULL
6439 WHERE "id" = "issue_id_p";
6440 ELSE
6441 UPDATE "issue" SET
6442 "state" = 'canceled_no_initiative_admitted',
6443 "fully_frozen" = "phase_finished",
6444 "closed" = "phase_finished",
6445 "phase_finished" = NULL
6446 WHERE "id" = "issue_id_p";
6447 -- NOTE: The following DELETE statements have effect only when
6448 -- issue state has been manipulated
6449 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
6450 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
6451 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
6452 END IF;
6453 RETURN NULL;
6454 END IF;
6455 IF "persist"."state" = 'voting' THEN
6456 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
6457 PERFORM "close_voting"("issue_id_p");
6458 "persist"."closed_voting" = TRUE;
6459 RETURN "persist";
6460 END IF;
6461 PERFORM "calculate_ranks"("issue_id_p");
6462 RETURN NULL;
6463 END IF;
6464 END IF;
6465 RAISE WARNING 'should not happen';
6466 RETURN NULL;
6467 END;
6468 $$;
6470 COMMENT ON FUNCTION "check_issue"
6471 ( "issue"."id"%TYPE,
6472 "check_issue_persistence" )
6473 IS 'Precalculate supporter counts etc. for a given issue, and check, if status change is required, and perform the status change when necessary; Function must be called multiple times with the previous result as second parameter, until the result is NULL (see source code of function "check_everything")';
6476 CREATE FUNCTION "check_everything"()
6477 RETURNS VOID
6478 LANGUAGE 'plpgsql' VOLATILE AS $$
6479 DECLARE
6480 "area_id_v" "area"."id"%TYPE;
6481 "snapshot_id_v" "snapshot"."id"%TYPE;
6482 "issue_id_v" "issue"."id"%TYPE;
6483 "persist_v" "check_issue_persistence";
6484 BEGIN
6485 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
6486 DELETE FROM "expired_session";
6487 DELETE FROM "expired_token";
6488 DELETE FROM "unused_snapshot";
6489 PERFORM "check_activity"();
6490 PERFORM "calculate_member_counts"();
6491 FOR "area_id_v" IN SELECT "id" FROM "area_with_unaccepted_issues" LOOP
6492 SELECT "take_snapshot"(NULL, "area_id_v") INTO "snapshot_id_v";
6493 PERFORM "finish_snapshot"("issue_id") FROM "snapshot_issue"
6494 WHERE "snapshot_id" = "snapshot_id_v";
6495 LOOP
6496 EXIT WHEN "issue_admission"("area_id_v") = FALSE;
6497 END LOOP;
6498 END LOOP;
6499 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
6500 "persist_v" := NULL;
6501 LOOP
6502 "persist_v" := "check_issue"("issue_id_v", "persist_v");
6503 EXIT WHEN "persist_v" ISNULL;
6504 END LOOP;
6505 END LOOP;
6506 DELETE FROM "unused_snapshot";
6507 RETURN;
6508 END;
6509 $$;
6511 COMMENT ON FUNCTION "check_everything"() IS 'Amongst other regular tasks, this function performs "check_issue" for every open issue. Use this function only for development and debugging purposes, as you may run into locking and/or serialization problems in productive environments. For production, use lf_update binary instead';
6515 ----------------------
6516 -- Deletion of data --
6517 ----------------------
6520 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
6521 RETURNS VOID
6522 LANGUAGE 'plpgsql' VOLATILE AS $$
6523 BEGIN
6524 IF EXISTS (
6525 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
6526 ) THEN
6527 -- override protection triggers:
6528 INSERT INTO "temporary_transaction_data" ("key", "value")
6529 VALUES ('override_protection_triggers', TRUE::TEXT);
6530 -- clean data:
6531 DELETE FROM "delegating_voter"
6532 WHERE "issue_id" = "issue_id_p";
6533 DELETE FROM "direct_voter"
6534 WHERE "issue_id" = "issue_id_p";
6535 DELETE FROM "delegating_interest_snapshot"
6536 WHERE "issue_id" = "issue_id_p";
6537 DELETE FROM "direct_interest_snapshot"
6538 WHERE "issue_id" = "issue_id_p";
6539 DELETE FROM "non_voter"
6540 WHERE "issue_id" = "issue_id_p";
6541 DELETE FROM "delegation"
6542 WHERE "issue_id" = "issue_id_p";
6543 DELETE FROM "supporter"
6544 USING "initiative" -- NOTE: due to missing index on issue_id
6545 WHERE "initiative"."issue_id" = "issue_id_p"
6546 AND "supporter"."initiative_id" = "initiative_id";
6547 -- mark issue as cleaned:
6548 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
6549 -- finish overriding protection triggers (avoids garbage):
6550 DELETE FROM "temporary_transaction_data"
6551 WHERE "key" = 'override_protection_triggers';
6552 END IF;
6553 RETURN;
6554 END;
6555 $$;
6557 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
6560 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
6561 RETURNS VOID
6562 LANGUAGE 'plpgsql' VOLATILE AS $$
6563 BEGIN
6564 UPDATE "member" SET
6565 "last_login" = NULL,
6566 "last_delegation_check" = NULL,
6567 "login" = NULL,
6568 "password" = NULL,
6569 "authority" = NULL,
6570 "authority_uid" = NULL,
6571 "authority_login" = NULL,
6572 "deleted" = coalesce("deleted", now()),
6573 "locked" = TRUE,
6574 "active" = FALSE,
6575 "notify_email" = NULL,
6576 "notify_email_unconfirmed" = NULL,
6577 "notify_email_secret" = NULL,
6578 "notify_email_secret_expiry" = NULL,
6579 "notify_email_lock_expiry" = NULL,
6580 "disable_notifications" = TRUE,
6581 "notification_counter" = DEFAULT,
6582 "notification_sample_size" = 0,
6583 "notification_dow" = NULL,
6584 "notification_hour" = NULL,
6585 "notification_sent" = NULL,
6586 "login_recovery_expiry" = NULL,
6587 "password_reset_secret" = NULL,
6588 "password_reset_secret_expiry" = NULL,
6589 "location" = NULL
6590 WHERE "id" = "member_id_p";
6591 -- "text_search_data" is updated by triggers
6592 DELETE FROM "member_settings" WHERE "member_id" = "member_id_p";
6593 DELETE FROM "member_profile" WHERE "member_id" = "member_id_p";
6594 DELETE FROM "rendered_member_statement" WHERE "member_id" = "member_id_p";
6595 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
6596 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
6597 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
6598 DELETE FROM "session" WHERE "member_id" = "member_id_p";
6599 DELETE FROM "member_application" WHERE "member_id" = "member_id_p";
6600 DELETE FROM "token" WHERE "member_id" = "member_id_p";
6601 DELETE FROM "subscription" WHERE "member_id" = "member_id_p";
6602 DELETE FROM "ignored_area" WHERE "member_id" = "member_id_p";
6603 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
6604 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
6605 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
6606 DELETE FROM "direct_voter" USING "issue"
6607 WHERE "direct_voter"."issue_id" = "issue"."id"
6608 AND "issue"."closed" ISNULL
6609 AND "member_id" = "member_id_p";
6610 DELETE FROM "notification_initiative_sent" WHERE "member_id" = "member_id_p";
6611 RETURN;
6612 END;
6613 $$;
6615 COMMENT ON FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE) IS 'Deactivate member and clear certain settings and data of this member (data protection)';
6618 CREATE FUNCTION "delete_private_data"()
6619 RETURNS VOID
6620 LANGUAGE 'plpgsql' VOLATILE AS $$
6621 BEGIN
6622 DELETE FROM "temporary_transaction_data";
6623 DELETE FROM "temporary_suggestion_counts";
6624 DELETE FROM "member" WHERE "activated" ISNULL;
6625 UPDATE "member" SET
6626 "invite_code" = NULL,
6627 "invite_code_expiry" = NULL,
6628 "admin_comment" = NULL,
6629 "last_login" = NULL,
6630 "last_delegation_check" = NULL,
6631 "login" = NULL,
6632 "password" = NULL,
6633 "authority" = NULL,
6634 "authority_uid" = NULL,
6635 "authority_login" = NULL,
6636 "lang" = NULL,
6637 "notify_email" = NULL,
6638 "notify_email_unconfirmed" = NULL,
6639 "notify_email_secret" = NULL,
6640 "notify_email_secret_expiry" = NULL,
6641 "notify_email_lock_expiry" = NULL,
6642 "disable_notifications" = TRUE,
6643 "notification_counter" = DEFAULT,
6644 "notification_sample_size" = 0,
6645 "notification_dow" = NULL,
6646 "notification_hour" = NULL,
6647 "notification_sent" = NULL,
6648 "login_recovery_expiry" = NULL,
6649 "password_reset_secret" = NULL,
6650 "password_reset_secret_expiry" = NULL,
6651 "location" = NULL;
6652 -- "text_search_data" is updated by triggers
6653 DELETE FROM "verification";
6654 DELETE FROM "member_settings";
6655 DELETE FROM "member_useterms";
6656 DELETE FROM "member_profile";
6657 DELETE FROM "rendered_member_statement";
6658 DELETE FROM "member_image";
6659 DELETE FROM "contact";
6660 DELETE FROM "ignored_member";
6661 DELETE FROM "session";
6662 DELETE FROM "system_application";
6663 DELETE FROM "system_application_redirect_uri";
6664 DELETE FROM "dynamic_application_scope";
6665 DELETE FROM "member_application";
6666 DELETE FROM "token";
6667 DELETE FROM "subscription";
6668 DELETE FROM "ignored_area";
6669 DELETE FROM "ignored_initiative";
6670 DELETE FROM "non_voter";
6671 DELETE FROM "direct_voter" USING "issue"
6672 WHERE "direct_voter"."issue_id" = "issue"."id"
6673 AND "issue"."closed" ISNULL;
6674 DELETE FROM "event_processed";
6675 DELETE FROM "notification_initiative_sent";
6676 DELETE FROM "newsletter";
6677 RETURN;
6678 END;
6679 $$;
6681 COMMENT ON FUNCTION "delete_private_data"() IS 'Used by lf_export script. DO NOT USE on productive database, but only on a copy! This function deletes all data which should not be publicly available, and can be used to create a database dump for publication. See source code to see which data is deleted. If you need a different behaviour, copy this function and modify lf_export accordingly, to avoid data-leaks after updating.';
6685 COMMIT;
