liquid_feedback_core

view core.sql @ 594:a2c156197bc7

Fixed wrong constraint "initiative_ids_not_equal" on "battle" table (due to handling of NULLs in CHECK constraints)
author jbe
date Sat Dec 08 02:05:53 2018 +0100 (2018-12-08)
parents e7f772ca0621
children 87914d1b757f
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_location_idx" ON "initiative" USING gist ((GeoJSON_to_ecluster("location")));
977 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
978 CREATE INDEX "initiative_draft_text_search_data_idx" ON "initiative" USING gin ("draft_text_search_data");
979 CREATE TRIGGER "update_text_search_data"
980 BEFORE INSERT OR UPDATE ON "initiative"
981 FOR EACH ROW EXECUTE PROCEDURE
982 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "name");
984 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.';
986 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
987 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
988 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
989 COMMENT ON COLUMN "initiative"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied from most recent draft)';
990 COMMENT ON COLUMN "initiative"."external_reference" IS 'Opaque data field to store an external reference';
991 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
992 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
993 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
994 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
995 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
996 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';
997 COMMENT ON COLUMN "initiative"."final_suggestion_order_calculated" IS 'Set to TRUE, when "proportional_order" of suggestions has been calculated the last time';
998 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
999 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
1000 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
1001 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"';
1002 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
1003 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking';
1004 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo';
1005 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)';
1006 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''';
1007 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';
1008 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"';
1009 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"';
1010 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';
1013 CREATE TABLE "battle" (
1014 "issue_id" INT4 NOT NULL,
1015 "winning_initiative_id" INT4,
1016 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1017 "losing_initiative_id" INT4,
1018 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1019 "count" INT4 NOT NULL,
1020 CONSTRAINT "initiative_ids_not_equal" CHECK (
1021 "winning_initiative_id" != "losing_initiative_id" AND
1022 ("winning_initiative_id" NOTNULL OR "losing_initiative_id" NOTNULL) ) );
1023 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
1024 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
1025 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
1027 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';
1030 CREATE TABLE "ignored_initiative" (
1031 PRIMARY KEY ("member_id", "initiative_id"),
1032 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1033 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1034 CREATE INDEX "ignored_initiative_initiative_id_idx" ON "ignored_initiative" ("initiative_id");
1036 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';
1039 CREATE TABLE "draft" (
1040 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
1041 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1042 "id" SERIAL8 PRIMARY KEY,
1043 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1044 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1045 "formatting_engine" TEXT,
1046 "content" TEXT NOT NULL,
1047 "location" JSONB,
1048 "external_reference" TEXT,
1049 "text_search_data" TSVECTOR );
1050 CREATE INDEX "draft_created_idx" ON "draft" ("created");
1051 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
1052 CREATE INDEX "draft_location_idx" ON "draft" USING gist ((GeoJSON_to_ecluster("location")));
1053 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
1054 CREATE TRIGGER "update_text_search_data"
1055 BEFORE INSERT OR UPDATE ON "draft"
1056 FOR EACH ROW EXECUTE PROCEDURE
1057 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1059 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.';
1061 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
1062 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
1063 COMMENT ON COLUMN "draft"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied to "initiative" table if draft is most recent)';
1064 COMMENT ON COLUMN "draft"."external_reference" IS 'Opaque data field to store an external reference';
1067 CREATE TABLE "rendered_draft" (
1068 PRIMARY KEY ("draft_id", "format"),
1069 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1070 "format" TEXT,
1071 "content" TEXT NOT NULL );
1073 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)';
1076 CREATE TABLE "suggestion" (
1077 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
1078 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1079 "id" SERIAL8 PRIMARY KEY,
1080 "draft_id" INT8 NOT NULL,
1081 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1082 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1083 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1084 "name" TEXT NOT NULL,
1085 "formatting_engine" TEXT,
1086 "content" TEXT NOT NULL DEFAULT '',
1087 "location" JSONB,
1088 "external_reference" TEXT,
1089 "text_search_data" TSVECTOR,
1090 "minus2_unfulfilled_count" INT4,
1091 "minus2_fulfilled_count" INT4,
1092 "minus1_unfulfilled_count" INT4,
1093 "minus1_fulfilled_count" INT4,
1094 "plus1_unfulfilled_count" INT4,
1095 "plus1_fulfilled_count" INT4,
1096 "plus2_unfulfilled_count" INT4,
1097 "plus2_fulfilled_count" INT4,
1098 "proportional_order" INT4 );
1099 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
1100 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
1101 CREATE INDEX "suggestion_location_idx" ON "suggestion" USING gist ((GeoJSON_to_ecluster("location")));
1102 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
1103 CREATE TRIGGER "update_text_search_data"
1104 BEFORE INSERT OR UPDATE ON "suggestion"
1105 FOR EACH ROW EXECUTE PROCEDURE
1106 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
1107 "name", "content");
1109 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';
1111 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")';
1112 COMMENT ON COLUMN "suggestion"."location" IS 'Geographic location of suggestion as GeoJSON object';
1113 COMMENT ON COLUMN "suggestion"."external_reference" IS 'Opaque data field to store an external reference';
1114 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1115 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1116 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1117 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1118 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1119 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1120 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1121 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1122 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"';
1125 CREATE TABLE "rendered_suggestion" (
1126 PRIMARY KEY ("suggestion_id", "format"),
1127 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1128 "format" TEXT,
1129 "content" TEXT NOT NULL );
1131 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)';
1134 CREATE TABLE "temporary_suggestion_counts" (
1135 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performance/locking issues; REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1136 "minus2_unfulfilled_count" INT4 NOT NULL,
1137 "minus2_fulfilled_count" INT4 NOT NULL,
1138 "minus1_unfulfilled_count" INT4 NOT NULL,
1139 "minus1_fulfilled_count" INT4 NOT NULL,
1140 "plus1_unfulfilled_count" INT4 NOT NULL,
1141 "plus1_fulfilled_count" INT4 NOT NULL,
1142 "plus2_unfulfilled_count" INT4 NOT NULL,
1143 "plus2_fulfilled_count" INT4 NOT NULL );
1145 COMMENT ON TABLE "temporary_suggestion_counts" IS 'Holds certain calculated values (suggestion counts) temporarily until they can be copied into table "suggestion"';
1147 COMMENT ON COLUMN "temporary_suggestion_counts"."id" IS 'References "suggestion" ("id") but has no referential integrity trigger associated, due to performance/locking issues';
1150 CREATE TABLE "privilege" (
1151 PRIMARY KEY ("unit_id", "member_id"),
1152 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1153 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1154 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1155 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1156 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1157 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1158 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
1159 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
1160 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
1162 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
1164 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
1165 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
1166 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
1167 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
1168 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
1169 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
1170 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';
1173 CREATE TABLE "interest" (
1174 PRIMARY KEY ("issue_id", "member_id"),
1175 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1176 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE );
1177 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
1179 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.';
1182 CREATE TABLE "initiator" (
1183 PRIMARY KEY ("initiative_id", "member_id"),
1184 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1185 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1186 "accepted" BOOLEAN );
1187 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
1189 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.';
1191 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.';
1194 CREATE TABLE "supporter" (
1195 "issue_id" INT4 NOT NULL,
1196 PRIMARY KEY ("initiative_id", "member_id"),
1197 "initiative_id" INT4,
1198 "member_id" INT4,
1199 "draft_id" INT8 NOT NULL,
1200 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1201 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
1202 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
1204 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.';
1206 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1207 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")';
1210 CREATE TABLE "opinion" (
1211 "initiative_id" INT4 NOT NULL,
1212 PRIMARY KEY ("suggestion_id", "member_id"),
1213 "suggestion_id" INT8,
1214 "member_id" INT4,
1215 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
1216 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
1217 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1218 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1219 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
1221 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.';
1223 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
1226 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
1228 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
1231 CREATE TABLE "delegation" (
1232 "id" SERIAL8 PRIMARY KEY,
1233 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1234 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1235 "scope" "delegation_scope" NOT NULL,
1236 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1237 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1238 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1239 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
1240 CONSTRAINT "no_unit_delegation_to_null"
1241 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
1242 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
1243 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
1244 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
1245 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
1246 UNIQUE ("unit_id", "truster_id"),
1247 UNIQUE ("area_id", "truster_id"),
1248 UNIQUE ("issue_id", "truster_id") );
1249 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
1250 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
1252 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
1254 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
1255 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
1256 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
1259 CREATE TABLE "snapshot_issue" (
1260 PRIMARY KEY ("snapshot_id", "issue_id"),
1261 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1262 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); -- NOTE: trigger "delete_snapshot_on_partial_delete" will delete whole "snapshot"
1263 CREATE INDEX "snapshot_issue_issue_id_idx" ON "snapshot_issue" ("issue_id");
1265 COMMENT ON TABLE "snapshot_issue" IS 'List of issues included in a snapshot';
1267 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.';
1270 CREATE TABLE "direct_interest_snapshot" (
1271 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1272 "snapshot_id" INT8,
1273 "issue_id" INT4,
1274 FOREIGN KEY ("snapshot_id", "issue_id")
1275 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1276 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1277 "weight" INT4 );
1278 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
1280 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';
1282 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
1285 CREATE TABLE "delegating_interest_snapshot" (
1286 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1287 "snapshot_id" INT8,
1288 "issue_id" INT4,
1289 FOREIGN KEY ("snapshot_id", "issue_id")
1290 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1291 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1292 "weight" INT4,
1293 "scope" "delegation_scope" NOT NULL,
1294 "delegate_member_ids" INT4[] NOT NULL );
1295 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
1297 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';
1299 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
1300 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
1301 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"';
1304 CREATE TABLE "direct_supporter_snapshot" (
1305 PRIMARY KEY ("snapshot_id", "initiative_id", "member_id"),
1306 "snapshot_id" INT8,
1307 "issue_id" INT4 NOT NULL,
1308 FOREIGN KEY ("snapshot_id", "issue_id")
1309 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1310 "initiative_id" INT4,
1311 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1312 "draft_id" INT8 NOT NULL,
1313 "informed" BOOLEAN NOT NULL,
1314 "satisfied" BOOLEAN NOT NULL,
1315 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1316 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1317 FOREIGN KEY ("snapshot_id", "issue_id", "member_id") REFERENCES "direct_interest_snapshot" ("snapshot_id", "issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1318 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1320 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';
1322 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';
1323 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1324 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1327 CREATE TABLE "non_voter" (
1328 PRIMARY KEY ("member_id", "issue_id"),
1329 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1330 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1331 CREATE INDEX "non_voter_issue_id_idx" ON "non_voter" ("issue_id");
1333 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1336 CREATE TABLE "direct_voter" (
1337 PRIMARY KEY ("issue_id", "member_id"),
1338 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1339 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1340 "weight" INT4,
1341 "comment_changed" TIMESTAMPTZ,
1342 "formatting_engine" TEXT,
1343 "comment" TEXT,
1344 "text_search_data" TSVECTOR );
1345 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1346 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
1347 CREATE TRIGGER "update_text_search_data"
1348 BEFORE INSERT OR UPDATE ON "direct_voter"
1349 FOR EACH ROW EXECUTE PROCEDURE
1350 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
1352 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';
1354 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1355 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';
1356 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';
1357 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.';
1360 CREATE TABLE "rendered_voter_comment" (
1361 PRIMARY KEY ("issue_id", "member_id", "format"),
1362 FOREIGN KEY ("issue_id", "member_id")
1363 REFERENCES "direct_voter" ("issue_id", "member_id")
1364 ON DELETE CASCADE ON UPDATE CASCADE,
1365 "issue_id" INT4,
1366 "member_id" INT4,
1367 "format" TEXT,
1368 "content" TEXT NOT NULL );
1370 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)';
1373 CREATE TABLE "delegating_voter" (
1374 PRIMARY KEY ("issue_id", "member_id"),
1375 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1376 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1377 "weight" INT4,
1378 "scope" "delegation_scope" NOT NULL,
1379 "delegate_member_ids" INT4[] NOT NULL );
1380 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1382 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';
1384 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1385 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1386 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"';
1389 CREATE TABLE "vote" (
1390 "issue_id" INT4 NOT NULL,
1391 PRIMARY KEY ("initiative_id", "member_id"),
1392 "initiative_id" INT4,
1393 "member_id" INT4,
1394 "grade" INT4 NOT NULL,
1395 "first_preference" BOOLEAN,
1396 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1397 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1398 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
1399 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
1400 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1402 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';
1404 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1405 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.';
1406 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.';
1409 CREATE TABLE "posting" (
1410 "id" SERIAL8 PRIMARY KEY,
1411 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1412 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1413 "message" TEXT NOT NULL,
1414 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1415 "area_id" INT4,
1416 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1417 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1418 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1419 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1420 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1421 "initiative_id" INT4,
1422 "suggestion_id" INT8,
1423 -- NOTE: no referential integrity for suggestions because those are
1424 -- actually deleted
1425 -- FOREIGN KEY ("initiative_id", "suggestion_id")
1426 -- REFERENCES "suggestion" ("initiative_id", "id")
1427 -- ON DELETE CASCADE ON UPDATE CASCADE,
1428 CONSTRAINT "area_requires_unit" CHECK (
1429 "area_id" ISNULL OR "unit_id" NOTNULL ),
1430 CONSTRAINT "policy_set_when_issue_set" CHECK (
1431 ("policy_id" NOTNULL) = ("issue_id" NOTNULL) ),
1432 CONSTRAINT "issue_requires_area" CHECK (
1433 "issue_id" ISNULL OR "area_id" NOTNULL ),
1434 CONSTRAINT "initiative_requires_issue" CHECK (
1435 "initiative_id" ISNULL OR "issue_id" NOTNULL ),
1436 CONSTRAINT "suggestion_requires_initiative" CHECK (
1437 "suggestion_id" ISNULL OR "initiative_id" NOTNULL ) );
1438 CREATE INDEX "posting_global_idx" ON "posting" USING gist ((pstamp("author_id", "id")));
1439 CREATE INDEX "posting_unit_idx" ON "posting" USING gist ("unit_id", (pstamp("author_id", "id"))) WHERE "unit_id" NOTNULL;
1440 CREATE INDEX "posting_area_idx" ON "posting" USING gist ("area_id", (pstamp("author_id", "id"))) WHERE "area_id" NOTNULL;
1441 CREATE INDEX "posting_policy_idx" ON "posting" USING gist ("policy_id", (pstamp("author_id", "id"))) WHERE "policy_id" NOTNULL;
1442 CREATE INDEX "posting_issue_idx" ON "posting" USING gist ("issue_id", (pstamp("author_id", "id"))) WHERE "issue_id" NOTNULL;
1443 CREATE INDEX "posting_initiative_idx" ON "posting" USING gist ("initiative_id", (pstamp("author_id", "id"))) WHERE "initiative_id" NOTNULL;
1444 CREATE INDEX "posting_suggestion_idx" ON "posting" USING gist ("suggestion_id", (pstamp("author_id", "id"))) WHERE "suggestion_id" NOTNULL;
1446 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';
1449 CREATE TYPE "event_type" AS ENUM (
1450 'unit_created',
1451 'unit_updated',
1452 'area_created',
1453 'area_updated',
1454 'policy_created',
1455 'policy_updated',
1456 'issue_state_changed',
1457 'initiative_created_in_new_issue',
1458 'initiative_created_in_existing_issue',
1459 'initiative_revoked',
1460 'new_draft_created',
1461 'suggestion_created',
1462 'suggestion_deleted',
1463 'member_activated',
1464 'member_deleted',
1465 'member_active',
1466 'member_name_updated',
1467 'member_profile_updated',
1468 'member_image_updated',
1469 'interest',
1470 'initiator',
1471 'support',
1472 'support_updated',
1473 'suggestion_rated',
1474 'delegation',
1475 'contact',
1476 'posting_created' );
1478 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1481 CREATE TABLE "event" (
1482 "id" SERIAL8 PRIMARY KEY,
1483 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1484 "event" "event_type" NOT NULL,
1485 "posting_id" INT8 REFERENCES "posting" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1486 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1487 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1488 "scope" "delegation_scope",
1489 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1490 "area_id" INT4,
1491 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1492 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1493 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1494 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1495 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1496 "state" "issue_state",
1497 "initiative_id" INT4,
1498 "draft_id" INT8,
1499 "suggestion_id" INT8,
1500 "boolean_value" BOOLEAN,
1501 "numeric_value" INT4,
1502 "text_value" TEXT,
1503 "old_text_value" TEXT,
1504 FOREIGN KEY ("issue_id", "initiative_id")
1505 REFERENCES "initiative" ("issue_id", "id")
1506 ON DELETE CASCADE ON UPDATE CASCADE,
1507 FOREIGN KEY ("initiative_id", "draft_id")
1508 REFERENCES "draft" ("initiative_id", "id")
1509 ON DELETE CASCADE ON UPDATE CASCADE,
1510 -- NOTE: no referential integrity for suggestions because those are
1511 -- actually deleted
1512 -- FOREIGN KEY ("initiative_id", "suggestion_id")
1513 -- REFERENCES "suggestion" ("initiative_id", "id")
1514 -- ON DELETE CASCADE ON UPDATE CASCADE,
1515 CONSTRAINT "constr_for_issue_state_changed" CHECK (
1516 "event" != 'issue_state_changed' OR (
1517 "posting_id" ISNULL AND
1518 "member_id" ISNULL AND
1519 "other_member_id" ISNULL AND
1520 "scope" ISNULL AND
1521 "unit_id" NOTNULL AND
1522 "area_id" NOTNULL AND
1523 "policy_id" NOTNULL AND
1524 "issue_id" NOTNULL AND
1525 "state" NOTNULL AND
1526 "initiative_id" ISNULL AND
1527 "draft_id" ISNULL AND
1528 "suggestion_id" ISNULL AND
1529 "boolean_value" ISNULL AND
1530 "numeric_value" ISNULL AND
1531 "text_value" ISNULL AND
1532 "old_text_value" ISNULL )),
1533 CONSTRAINT "constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1534 "event" NOT IN (
1535 'initiative_created_in_new_issue',
1536 'initiative_created_in_existing_issue',
1537 'initiative_revoked',
1538 'new_draft_created'
1539 ) OR (
1540 "posting_id" ISNULL AND
1541 "member_id" NOTNULL AND
1542 "other_member_id" ISNULL AND
1543 "scope" ISNULL AND
1544 "unit_id" NOTNULL AND
1545 "area_id" NOTNULL AND
1546 "policy_id" NOTNULL AND
1547 "issue_id" NOTNULL AND
1548 "state" NOTNULL AND
1549 "initiative_id" NOTNULL AND
1550 "draft_id" NOTNULL AND
1551 "suggestion_id" ISNULL AND
1552 "boolean_value" ISNULL AND
1553 "numeric_value" ISNULL AND
1554 "text_value" ISNULL AND
1555 "old_text_value" ISNULL )),
1556 CONSTRAINT "constr_for_suggestion_creation" CHECK (
1557 "event" != 'suggestion_created' OR (
1558 "posting_id" ISNULL AND
1559 "member_id" NOTNULL AND
1560 "other_member_id" ISNULL AND
1561 "scope" ISNULL AND
1562 "unit_id" NOTNULL AND
1563 "area_id" NOTNULL AND
1564 "policy_id" NOTNULL AND
1565 "issue_id" NOTNULL AND
1566 "state" NOTNULL AND
1567 "initiative_id" NOTNULL AND
1568 "draft_id" ISNULL AND
1569 "suggestion_id" NOTNULL AND
1570 "boolean_value" ISNULL AND
1571 "numeric_value" ISNULL AND
1572 "text_value" ISNULL AND
1573 "old_text_value" ISNULL )),
1574 CONSTRAINT "constr_for_suggestion_removal" CHECK (
1575 "event" != 'suggestion_deleted' OR (
1576 "posting_id" ISNULL AND
1577 "member_id" ISNULL AND
1578 "other_member_id" ISNULL AND
1579 "scope" ISNULL AND
1580 "unit_id" NOTNULL AND
1581 "area_id" NOTNULL AND
1582 "policy_id" NOTNULL AND
1583 "issue_id" NOTNULL AND
1584 "state" NOTNULL AND
1585 "initiative_id" NOTNULL AND
1586 "draft_id" ISNULL AND
1587 "suggestion_id" NOTNULL AND
1588 "boolean_value" ISNULL AND
1589 "numeric_value" ISNULL AND
1590 "text_value" ISNULL AND
1591 "old_text_value" ISNULL )),
1592 CONSTRAINT "constr_for_value_less_member_event" CHECK (
1593 "event" NOT IN (
1594 'member_activated',
1595 'member_deleted',
1596 'member_profile_updated',
1597 'member_image_updated'
1598 ) OR (
1599 "posting_id" ISNULL AND
1600 "member_id" NOTNULL AND
1601 "other_member_id" ISNULL AND
1602 "scope" ISNULL AND
1603 "unit_id" ISNULL AND
1604 "area_id" ISNULL AND
1605 "policy_id" ISNULL AND
1606 "issue_id" ISNULL AND
1607 "state" ISNULL AND
1608 "initiative_id" ISNULL AND
1609 "draft_id" ISNULL AND
1610 "suggestion_id" ISNULL AND
1611 "boolean_value" ISNULL AND
1612 "numeric_value" ISNULL AND
1613 "text_value" ISNULL AND
1614 "old_text_value" ISNULL )),
1615 CONSTRAINT "constr_for_member_active" CHECK (
1616 "event" != 'member_active' OR (
1617 "posting_id" ISNULL AND
1618 "member_id" NOTNULL AND
1619 "other_member_id" ISNULL AND
1620 "scope" ISNULL AND
1621 "unit_id" ISNULL AND
1622 "area_id" ISNULL AND
1623 "policy_id" ISNULL AND
1624 "issue_id" ISNULL AND
1625 "state" ISNULL AND
1626 "initiative_id" ISNULL AND
1627 "draft_id" ISNULL AND
1628 "suggestion_id" ISNULL AND
1629 "boolean_value" NOTNULL AND
1630 "numeric_value" ISNULL AND
1631 "text_value" ISNULL AND
1632 "old_text_value" ISNULL )),
1633 CONSTRAINT "constr_for_member_name_updated" CHECK (
1634 "event" != 'member_name_updated' OR (
1635 "posting_id" ISNULL AND
1636 "member_id" NOTNULL AND
1637 "other_member_id" ISNULL AND
1638 "scope" ISNULL AND
1639 "unit_id" ISNULL AND
1640 "area_id" ISNULL AND
1641 "policy_id" ISNULL AND
1642 "issue_id" ISNULL AND
1643 "state" ISNULL AND
1644 "initiative_id" ISNULL AND
1645 "draft_id" ISNULL AND
1646 "suggestion_id" ISNULL AND
1647 "boolean_value" ISNULL AND
1648 "numeric_value" ISNULL AND
1649 "text_value" NOTNULL AND
1650 "old_text_value" NOTNULL )),
1651 CONSTRAINT "constr_for_interest" CHECK (
1652 "event" != 'interest' OR (
1653 "posting_id" ISNULL AND
1654 "member_id" NOTNULL AND
1655 "other_member_id" ISNULL AND
1656 "scope" ISNULL AND
1657 "unit_id" NOTNULL AND
1658 "area_id" NOTNULL AND
1659 "policy_id" NOTNULL AND
1660 "issue_id" NOTNULL AND
1661 "state" NOTNULL AND
1662 "initiative_id" ISNULL AND
1663 "draft_id" ISNULL AND
1664 "suggestion_id" ISNULL AND
1665 "boolean_value" NOTNULL AND
1666 "numeric_value" ISNULL AND
1667 "text_value" ISNULL AND
1668 "old_text_value" ISNULL )),
1669 CONSTRAINT "constr_for_initiator" CHECK (
1670 "event" != 'initiator' OR (
1671 "posting_id" ISNULL AND
1672 "member_id" NOTNULL AND
1673 "other_member_id" ISNULL AND
1674 "scope" ISNULL AND
1675 "unit_id" NOTNULL AND
1676 "area_id" NOTNULL AND
1677 "policy_id" NOTNULL AND
1678 "issue_id" NOTNULL AND
1679 "state" NOTNULL AND
1680 "initiative_id" NOTNULL AND
1681 "draft_id" ISNULL AND
1682 "suggestion_id" ISNULL AND
1683 "boolean_value" NOTNULL AND
1684 "numeric_value" ISNULL AND
1685 "text_value" ISNULL AND
1686 "old_text_value" ISNULL )),
1687 CONSTRAINT "constr_for_support" CHECK (
1688 "event" != 'support' OR (
1689 "posting_id" ISNULL AND
1690 "member_id" NOTNULL AND
1691 "other_member_id" ISNULL AND
1692 "scope" ISNULL AND
1693 "unit_id" NOTNULL AND
1694 "area_id" NOTNULL AND
1695 "policy_id" NOTNULL AND
1696 "issue_id" NOTNULL AND
1697 "state" NOTNULL AND
1698 "initiative_id" NOTNULL AND
1699 ("draft_id" NOTNULL) = ("boolean_value" = TRUE) AND
1700 "suggestion_id" ISNULL AND
1701 "boolean_value" NOTNULL AND
1702 "numeric_value" ISNULL AND
1703 "text_value" ISNULL AND
1704 "old_text_value" ISNULL )),
1705 CONSTRAINT "constr_for_support_updated" CHECK (
1706 "event" != 'support_updated' OR (
1707 "posting_id" ISNULL AND
1708 "member_id" NOTNULL AND
1709 "other_member_id" ISNULL AND
1710 "scope" ISNULL AND
1711 "unit_id" NOTNULL AND
1712 "area_id" NOTNULL AND
1713 "policy_id" NOTNULL AND
1714 "issue_id" NOTNULL AND
1715 "state" NOTNULL AND
1716 "initiative_id" NOTNULL AND
1717 "draft_id" NOTNULL AND
1718 "suggestion_id" ISNULL AND
1719 "boolean_value" ISNULL AND
1720 "numeric_value" ISNULL AND
1721 "text_value" ISNULL AND
1722 "old_text_value" ISNULL )),
1723 CONSTRAINT "constr_for_suggestion_rated" CHECK (
1724 "event" != 'suggestion_rated' OR (
1725 "posting_id" ISNULL AND
1726 "member_id" NOTNULL AND
1727 "other_member_id" ISNULL AND
1728 "scope" ISNULL AND
1729 "unit_id" NOTNULL AND
1730 "area_id" NOTNULL AND
1731 "policy_id" NOTNULL AND
1732 "issue_id" NOTNULL AND
1733 "state" NOTNULL AND
1734 "initiative_id" NOTNULL AND
1735 "draft_id" ISNULL AND
1736 "suggestion_id" NOTNULL AND
1737 ("boolean_value" NOTNULL) = ("numeric_value" != 0) AND
1738 "numeric_value" NOTNULL AND
1739 "numeric_value" IN (-2, -1, 0, 1, 2) AND
1740 "text_value" ISNULL AND
1741 "old_text_value" ISNULL )),
1742 CONSTRAINT "constr_for_delegation" CHECK (
1743 "event" != 'delegation' OR (
1744 "posting_id" ISNULL AND
1745 "member_id" NOTNULL AND
1746 (("other_member_id" ISNULL) OR ("boolean_value" = TRUE)) AND
1747 "scope" NOTNULL AND
1748 "unit_id" NOTNULL AND
1749 ("area_id" NOTNULL) = ("scope" != 'unit'::"delegation_scope") AND
1750 "policy_id" ISNULL AND
1751 ("issue_id" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1752 ("state" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1753 "initiative_id" ISNULL AND
1754 "draft_id" ISNULL AND
1755 "suggestion_id" ISNULL AND
1756 "boolean_value" NOTNULL AND
1757 "numeric_value" ISNULL AND
1758 "text_value" ISNULL AND
1759 "old_text_value" ISNULL )),
1760 CONSTRAINT "constr_for_contact" CHECK (
1761 "event" != 'contact' OR (
1762 "posting_id" ISNULL AND
1763 "member_id" NOTNULL AND
1764 "other_member_id" NOTNULL AND
1765 "scope" ISNULL AND
1766 "unit_id" ISNULL AND
1767 "area_id" ISNULL AND
1768 "policy_id" ISNULL AND
1769 "issue_id" ISNULL AND
1770 "state" ISNULL AND
1771 "initiative_id" ISNULL AND
1772 "draft_id" ISNULL AND
1773 "suggestion_id" ISNULL AND
1774 "boolean_value" NOTNULL AND
1775 "numeric_value" ISNULL AND
1776 "text_value" ISNULL AND
1777 "old_text_value" ISNULL )),
1778 CONSTRAINT "constr_for_posting_created" CHECK (
1779 "event" != 'posting_created' OR (
1780 "posting_id" NOTNULL AND
1781 "member_id" NOTNULL AND
1782 "other_member_id" ISNULL AND
1783 "scope" ISNULL AND
1784 "state" ISNULL AND
1785 ("area_id" ISNULL OR "unit_id" NOTNULL) AND
1786 ("policy_id" NOTNULL) = ("issue_id" NOTNULL) AND
1787 ("issue_id" ISNULL OR "area_id" NOTNULL) AND
1788 ("state" NOTNULL) = ("issue_id" NOTNULL) AND
1789 ("initiative_id" ISNULL OR "issue_id" NOTNULL) AND
1790 "draft_id" ISNULL AND
1791 ("suggestion_id" ISNULL OR "initiative_id" NOTNULL) AND
1792 "boolean_value" ISNULL AND
1793 "numeric_value" ISNULL AND
1794 "text_value" ISNULL AND
1795 "old_text_value" ISNULL )) );
1796 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1797 CREATE INDEX "event_tl_global_idx" ON "event" USING gist ((pstamp("member_id", "id")));
1798 CREATE INDEX "event_tl_unit_idx" ON "event" USING gist ("unit_id", (pstamp("member_id", "id"))) WHERE "unit_id" NOTNULL;
1799 CREATE INDEX "event_tl_area_idx" ON "event" USING gist ("area_id", (pstamp("member_id", "id"))) WHERE "area_id" NOTNULL;
1800 CREATE INDEX "event_tl_policy_idx" ON "event" USING gist ("policy_id", (pstamp("member_id", "id"))) WHERE "policy_id" NOTNULL;
1801 CREATE INDEX "event_tl_issue_idx" ON "event" USING gist ("issue_id", (pstamp("member_id", "id"))) WHERE "issue_id" NOTNULL;
1802 CREATE INDEX "event_tl_initiative_idx" ON "event" USING gist ("initiative_id", (pstamp("member_id", "id"))) WHERE "initiative_id" NOTNULL;
1803 CREATE INDEX "event_tl_suggestion_idx" ON "event" USING gist ("suggestion_id", (pstamp("member_id", "id"))) WHERE "suggestion_id" NOTNULL;
1806 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1808 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1809 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1810 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1811 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1814 CREATE TABLE "event_processed" (
1815 "event_id" INT8 NOT NULL );
1816 CREATE UNIQUE INDEX "event_processed_singleton_idx" ON "event_processed" ((1));
1818 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)';
1819 COMMENT ON INDEX "event_processed_singleton_idx" IS 'This index ensures that "event_processed" only contains one row maximum.';
1822 CREATE TABLE "notification_initiative_sent" (
1823 PRIMARY KEY ("member_id", "initiative_id"),
1824 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1825 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1826 "last_draft_id" INT8 NOT NULL,
1827 "last_suggestion_id" INT8 );
1828 CREATE INDEX "notification_initiative_sent_initiative_idx" ON "notification_initiative_sent" ("initiative_id");
1830 COMMENT ON TABLE "notification_initiative_sent" IS 'Information which initiatives have been promoted to a member in a scheduled notification mail';
1832 COMMENT ON COLUMN "notification_initiative_sent"."last_draft_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1833 COMMENT ON COLUMN "notification_initiative_sent"."last_suggestion_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1836 CREATE TABLE "newsletter" (
1837 "id" SERIAL4 PRIMARY KEY,
1838 "published" TIMESTAMPTZ NOT NULL,
1839 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1840 "include_all_members" BOOLEAN NOT NULL,
1841 "sent" TIMESTAMPTZ,
1842 "subject" TEXT NOT NULL,
1843 "content" TEXT NOT NULL );
1844 CREATE INDEX "newsletter_unit_id_idx" ON "newsletter" ("unit_id", "published");
1845 CREATE INDEX "newsletter_all_units_published_idx" ON "newsletter" ("published") WHERE "unit_id" ISNULL;
1846 CREATE INDEX "newsletter_published_idx" ON "newsletter" ("published");
1848 COMMENT ON TABLE "newsletter" IS 'Contains newsletters created by administrators to be sent out and for further reference';
1850 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter is to be sent out (and made available in the frontend)';
1851 COMMENT ON COLUMN "newsletter"."unit_id" IS 'If set, only members with voting right in the given unit are considered to be recipients';
1852 COMMENT ON COLUMN "newsletter"."include_all_members" IS 'TRUE = include all members regardless of their ''disable_notifications'' setting';
1853 COMMENT ON COLUMN "newsletter"."sent" IS 'Timestamp when the newsletter has been mailed out';
1854 COMMENT ON COLUMN "newsletter"."subject" IS 'Subject line (e.g. to be used for the email)';
1855 COMMENT ON COLUMN "newsletter"."content" IS 'Plain text content of the newsletter';
1859 ----------------------------------------------
1860 -- Writing of history entries and event log --
1861 ----------------------------------------------
1864 CREATE FUNCTION "write_member_history_trigger"()
1865 RETURNS TRIGGER
1866 LANGUAGE 'plpgsql' VOLATILE AS $$
1867 BEGIN
1868 IF
1869 ( NEW."active" != OLD."active" OR
1870 NEW."name" != OLD."name" ) AND
1871 OLD."activated" NOTNULL
1872 THEN
1873 INSERT INTO "member_history"
1874 ("member_id", "active", "name")
1875 VALUES (NEW."id", OLD."active", OLD."name");
1876 END IF;
1877 RETURN NULL;
1878 END;
1879 $$;
1881 CREATE TRIGGER "write_member_history"
1882 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1883 "write_member_history_trigger"();
1885 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1886 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1889 CREATE FUNCTION "write_event_unit_trigger"()
1890 RETURNS TRIGGER
1891 LANGUAGE 'plpgsql' VOLATILE AS $$
1892 DECLARE
1893 "event_v" "event_type";
1894 BEGIN
1895 IF TG_OP = 'UPDATE' THEN
1896 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1897 RETURN NULL;
1898 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1899 -- "event_v" := 'unit_created';
1900 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1901 -- "event_v" := 'unit_deleted';
1902 ELSIF OLD != NEW THEN
1903 "event_v" := 'unit_updated';
1904 ELSE
1905 RETURN NULL;
1906 END IF;
1907 ELSE
1908 "event_v" := 'unit_created';
1909 END IF;
1910 INSERT INTO "event" ("event", "unit_id") VALUES ("event_v", NEW."id");
1911 RETURN NULL;
1912 END;
1913 $$;
1915 CREATE TRIGGER "write_event_unit" AFTER INSERT OR UPDATE ON "unit"
1916 FOR EACH ROW EXECUTE PROCEDURE "write_event_unit_trigger"();
1918 COMMENT ON FUNCTION "write_event_unit_trigger"() IS 'Implementation of trigger "write_event_unit" on table "unit"';
1919 COMMENT ON TRIGGER "write_event_unit" ON "unit" IS 'Create entry in "event" table on new or changed/disabled units';
1922 CREATE FUNCTION "write_event_area_trigger"()
1923 RETURNS TRIGGER
1924 LANGUAGE 'plpgsql' VOLATILE AS $$
1925 DECLARE
1926 "event_v" "event_type";
1927 BEGIN
1928 IF TG_OP = 'UPDATE' THEN
1929 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1930 RETURN NULL;
1931 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1932 -- "event_v" := 'area_created';
1933 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1934 -- "event_v" := 'area_deleted';
1935 ELSIF OLD != NEW THEN
1936 "event_v" := 'area_updated';
1937 ELSE
1938 RETURN NULL;
1939 END IF;
1940 ELSE
1941 "event_v" := 'area_created';
1942 END IF;
1943 INSERT INTO "event" ("event", "area_id") VALUES ("event_v", NEW."id");
1944 RETURN NULL;
1945 END;
1946 $$;
1948 CREATE TRIGGER "write_event_area" AFTER INSERT OR UPDATE ON "area"
1949 FOR EACH ROW EXECUTE PROCEDURE "write_event_area_trigger"();
1951 COMMENT ON FUNCTION "write_event_area_trigger"() IS 'Implementation of trigger "write_event_area" on table "area"';
1952 COMMENT ON TRIGGER "write_event_area" ON "area" IS 'Create entry in "event" table on new or changed/disabled areas';
1955 CREATE FUNCTION "write_event_policy_trigger"()
1956 RETURNS TRIGGER
1957 LANGUAGE 'plpgsql' VOLATILE AS $$
1958 DECLARE
1959 "event_v" "event_type";
1960 BEGIN
1961 IF TG_OP = 'UPDATE' THEN
1962 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1963 RETURN NULL;
1964 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1965 -- "event_v" := 'policy_created';
1966 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1967 -- "event_v" := 'policy_deleted';
1968 ELSIF OLD != NEW THEN
1969 "event_v" := 'policy_updated';
1970 ELSE
1971 RETURN NULL;
1972 END IF;
1973 ELSE
1974 "event_v" := 'policy_created';
1975 END IF;
1976 INSERT INTO "event" ("event", "policy_id") VALUES ("event_v", NEW."id");
1977 RETURN NULL;
1978 END;
1979 $$;
1981 CREATE TRIGGER "write_event_policy" AFTER INSERT OR UPDATE ON "policy"
1982 FOR EACH ROW EXECUTE PROCEDURE "write_event_policy_trigger"();
1984 COMMENT ON FUNCTION "write_event_policy_trigger"() IS 'Implementation of trigger "write_event_policy" on table "policy"';
1985 COMMENT ON TRIGGER "write_event_policy" ON "policy" IS 'Create entry in "event" table on new or changed/disabled policies';
1988 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1989 RETURNS TRIGGER
1990 LANGUAGE 'plpgsql' VOLATILE AS $$
1991 DECLARE
1992 "area_row" "area"%ROWTYPE;
1993 BEGIN
1994 IF NEW."state" != OLD."state" THEN
1995 SELECT * INTO "area_row" FROM "area" WHERE "id" = NEW."area_id"
1996 FOR SHARE;
1997 INSERT INTO "event" (
1998 "event",
1999 "unit_id", "area_id", "policy_id", "issue_id", "state"
2000 ) VALUES (
2001 'issue_state_changed',
2002 "area_row"."unit_id", NEW."area_id", NEW."policy_id",
2003 NEW."id", NEW."state"
2004 );
2005 END IF;
2006 RETURN NULL;
2007 END;
2008 $$;
2010 CREATE TRIGGER "write_event_issue_state_changed"
2011 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
2012 "write_event_issue_state_changed_trigger"();
2014 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
2015 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
2018 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
2019 RETURNS TRIGGER
2020 LANGUAGE 'plpgsql' VOLATILE AS $$
2021 DECLARE
2022 "initiative_row" "initiative"%ROWTYPE;
2023 "issue_row" "issue"%ROWTYPE;
2024 "area_row" "area"%ROWTYPE;
2025 "event_v" "event_type";
2026 BEGIN
2027 SELECT * INTO "initiative_row" FROM "initiative"
2028 WHERE "id" = NEW."initiative_id" FOR SHARE;
2029 SELECT * INTO "issue_row" FROM "issue"
2030 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2031 SELECT * INTO "area_row" FROM "area"
2032 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2033 IF EXISTS (
2034 SELECT NULL FROM "draft"
2035 WHERE "initiative_id" = NEW."initiative_id" AND "id" != NEW."id"
2036 FOR SHARE
2037 ) THEN
2038 "event_v" := 'new_draft_created';
2039 ELSE
2040 IF EXISTS (
2041 SELECT NULL FROM "initiative"
2042 WHERE "issue_id" = "initiative_row"."issue_id"
2043 AND "id" != "initiative_row"."id"
2044 FOR SHARE
2045 ) THEN
2046 "event_v" := 'initiative_created_in_existing_issue';
2047 ELSE
2048 "event_v" := 'initiative_created_in_new_issue';
2049 END IF;
2050 END IF;
2051 INSERT INTO "event" (
2052 "event", "member_id",
2053 "unit_id", "area_id", "policy_id", "issue_id", "state",
2054 "initiative_id", "draft_id"
2055 ) VALUES (
2056 "event_v", NEW."author_id",
2057 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
2058 "initiative_row"."issue_id", "issue_row"."state",
2059 NEW."initiative_id", NEW."id"
2060 );
2061 RETURN NULL;
2062 END;
2063 $$;
2065 CREATE TRIGGER "write_event_initiative_or_draft_created"
2066 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
2067 "write_event_initiative_or_draft_created_trigger"();
2069 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
2070 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
2073 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
2074 RETURNS TRIGGER
2075 LANGUAGE 'plpgsql' VOLATILE AS $$
2076 DECLARE
2077 "issue_row" "issue"%ROWTYPE;
2078 "area_row" "area"%ROWTYPE;
2079 "draft_id_v" "draft"."id"%TYPE;
2080 BEGIN
2081 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
2082 -- NOTE: lock for primary key update to avoid new drafts
2083 PERFORM NULL FROM "initiative" WHERE "id" = NEW."id" FOR UPDATE;
2084 SELECT * INTO "issue_row" FROM "issue"
2085 WHERE "id" = NEW."issue_id" FOR SHARE;
2086 SELECT * INTO "area_row" FROM "area"
2087 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2088 -- NOTE: FOR SHARE cannot be used with DISTINCT in view "current_draft"
2089 PERFORM NULL FROM "draft" WHERE "initiative_id" = NEW."id" FOR SHARE;
2090 SELECT "id" INTO "draft_id_v" FROM "current_draft"
2091 WHERE "initiative_id" = NEW."id";
2092 INSERT INTO "event" (
2093 "event", "member_id",
2094 "unit_id", "area_id", "policy_id", "issue_id", "state",
2095 "initiative_id", "draft_id"
2096 ) VALUES (
2097 'initiative_revoked', NEW."revoked_by_member_id",
2098 "area_row"."unit_id", "issue_row"."area_id",
2099 "issue_row"."policy_id",
2100 NEW."issue_id", "issue_row"."state",
2101 NEW."id", "draft_id_v"
2102 );
2103 END IF;
2104 RETURN NULL;
2105 END;
2106 $$;
2108 CREATE TRIGGER "write_event_initiative_revoked"
2109 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
2110 "write_event_initiative_revoked_trigger"();
2112 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
2113 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
2116 CREATE FUNCTION "write_event_suggestion_created_trigger"()
2117 RETURNS TRIGGER
2118 LANGUAGE 'plpgsql' VOLATILE AS $$
2119 DECLARE
2120 "initiative_row" "initiative"%ROWTYPE;
2121 "issue_row" "issue"%ROWTYPE;
2122 "area_row" "area"%ROWTYPE;
2123 BEGIN
2124 SELECT * INTO "initiative_row" FROM "initiative"
2125 WHERE "id" = NEW."initiative_id" FOR SHARE;
2126 SELECT * INTO "issue_row" FROM "issue"
2127 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2128 SELECT * INTO "area_row" FROM "area"
2129 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2130 INSERT INTO "event" (
2131 "event", "member_id",
2132 "unit_id", "area_id", "policy_id", "issue_id", "state",
2133 "initiative_id", "suggestion_id"
2134 ) VALUES (
2135 'suggestion_created', NEW."author_id",
2136 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
2137 "initiative_row"."issue_id", "issue_row"."state",
2138 NEW."initiative_id", NEW."id"
2139 );
2140 RETURN NULL;
2141 END;
2142 $$;
2144 CREATE TRIGGER "write_event_suggestion_created"
2145 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2146 "write_event_suggestion_created_trigger"();
2148 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
2149 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2152 CREATE FUNCTION "write_event_suggestion_removed_trigger"()
2153 RETURNS TRIGGER
2154 LANGUAGE 'plpgsql' VOLATILE AS $$
2155 DECLARE
2156 "initiative_row" "initiative"%ROWTYPE;
2157 "issue_row" "issue"%ROWTYPE;
2158 "area_row" "area"%ROWTYPE;
2159 BEGIN
2160 SELECT * INTO "initiative_row" FROM "initiative"
2161 WHERE "id" = OLD."initiative_id" FOR SHARE;
2162 IF "initiative_row"."id" NOTNULL THEN
2163 SELECT * INTO "issue_row" FROM "issue"
2164 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2165 SELECT * INTO "area_row" FROM "area"
2166 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2167 INSERT INTO "event" (
2168 "event",
2169 "unit_id", "area_id", "policy_id", "issue_id", "state",
2170 "initiative_id", "suggestion_id"
2171 ) VALUES (
2172 'suggestion_deleted',
2173 "area_row"."unit_id", "issue_row"."area_id",
2174 "issue_row"."policy_id",
2175 "initiative_row"."issue_id", "issue_row"."state",
2176 OLD."initiative_id", OLD."id"
2177 );
2178 END IF;
2179 RETURN NULL;
2180 END;
2181 $$;
2183 CREATE TRIGGER "write_event_suggestion_removed"
2184 AFTER DELETE ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2185 "write_event_suggestion_removed_trigger"();
2187 COMMENT ON FUNCTION "write_event_suggestion_removed_trigger"() IS 'Implementation of trigger "write_event_suggestion_removed" on table "issue"';
2188 COMMENT ON TRIGGER "write_event_suggestion_removed" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2191 CREATE FUNCTION "write_event_member_trigger"()
2192 RETURNS TRIGGER
2193 LANGUAGE 'plpgsql' VOLATILE AS $$
2194 BEGIN
2195 IF TG_OP = 'INSERT' THEN
2196 IF NEW."activated" NOTNULL AND NEW."deleted" ISNULL THEN
2197 INSERT INTO "event" ("event", "member_id")
2198 VALUES ('member_activated', NEW."id");
2199 END IF;
2200 IF NEW."active" THEN
2201 INSERT INTO "event" ("event", "member_id", "boolean_value")
2202 VALUES ('member_active', NEW."id", TRUE);
2203 END IF;
2204 ELSIF TG_OP = 'UPDATE' THEN
2205 IF OLD."id" != NEW."id" THEN
2206 RAISE EXCEPTION 'Cannot change member ID';
2207 END IF;
2208 IF
2209 (OLD."activated" ISNULL OR OLD."deleted" NOTNULL) AND
2210 NEW."activated" NOTNULL AND NEW."deleted" ISNULL
2211 THEN
2212 INSERT INTO "event" ("event", "member_id")
2213 VALUES ('member_activated', NEW."id");
2214 END IF;
2215 IF OLD."active" != NEW."active" THEN
2216 INSERT INTO "event" ("event", "member_id", "boolean_value") VALUES (
2217 'member_active', NEW."id", NEW."active"
2218 );
2219 END IF;
2220 IF OLD."name" != NEW."name" THEN
2221 INSERT INTO "event" (
2222 "event", "member_id", "text_value", "old_text_value"
2223 ) VALUES (
2224 'member_name_updated', NEW."id", NEW."name", OLD."name"
2225 );
2226 END IF;
2227 IF
2228 OLD."activated" NOTNULL AND OLD."deleted" ISNULL AND
2229 (NEW."activated" ISNULL OR NEW."deleted" NOTNULL)
2230 THEN
2231 INSERT INTO "event" ("event", "member_id")
2232 VALUES ('member_deleted', NEW."id");
2233 END IF;
2234 END IF;
2235 RETURN NULL;
2236 END;
2237 $$;
2239 CREATE TRIGGER "write_event_member"
2240 AFTER INSERT OR UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
2241 "write_event_member_trigger"();
2243 COMMENT ON FUNCTION "write_event_member_trigger"() IS 'Implementation of trigger "write_event_member" on table "member"';
2244 COMMENT ON TRIGGER "write_event_member" ON "member" IS 'Create entries in "event" table on insertion to member table';
2247 CREATE FUNCTION "write_event_member_profile_updated_trigger"()
2248 RETURNS TRIGGER
2249 LANGUAGE 'plpgsql' VOLATILE AS $$
2250 BEGIN
2251 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2252 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2253 INSERT INTO "event" ("event", "member_id") VALUES (
2254 'member_profile_updated', OLD."member_id"
2255 );
2256 END IF;
2257 END IF;
2258 IF TG_OP = 'UPDATE' THEN
2259 IF OLD."member_id" = NEW."member_id" THEN
2260 RETURN NULL;
2261 END IF;
2262 END IF;
2263 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2264 INSERT INTO "event" ("event", "member_id") VALUES (
2265 'member_profile_updated', NEW."member_id"
2266 );
2267 END IF;
2268 RETURN NULL;
2269 END;
2270 $$;
2272 CREATE TRIGGER "write_event_member_profile_updated"
2273 AFTER INSERT OR UPDATE OR DELETE ON "member_profile"
2274 FOR EACH ROW EXECUTE PROCEDURE
2275 "write_event_member_profile_updated_trigger"();
2277 COMMENT ON FUNCTION "write_event_member_profile_updated_trigger"() IS 'Implementation of trigger "write_event_member_profile_updated" on table "member_profile"';
2278 COMMENT ON TRIGGER "write_event_member_profile_updated" ON "member_profile" IS 'Creates entries in "event" table on member profile update';
2281 CREATE FUNCTION "write_event_member_image_updated_trigger"()
2282 RETURNS TRIGGER
2283 LANGUAGE 'plpgsql' VOLATILE AS $$
2284 BEGIN
2285 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2286 IF NOT OLD."scaled" THEN
2287 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2288 INSERT INTO "event" ("event", "member_id") VALUES (
2289 'member_image_updated', OLD."member_id"
2290 );
2291 END IF;
2292 END IF;
2293 END IF;
2294 IF TG_OP = 'UPDATE' THEN
2295 IF
2296 OLD."member_id" = NEW."member_id" AND
2297 OLD."scaled" = NEW."scaled"
2298 THEN
2299 RETURN NULL;
2300 END IF;
2301 END IF;
2302 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2303 IF NOT NEW."scaled" THEN
2304 INSERT INTO "event" ("event", "member_id") VALUES (
2305 'member_image_updated', NEW."member_id"
2306 );
2307 END IF;
2308 END IF;
2309 RETURN NULL;
2310 END;
2311 $$;
2313 CREATE TRIGGER "write_event_member_image_updated"
2314 AFTER INSERT OR UPDATE OR DELETE ON "member_image"
2315 FOR EACH ROW EXECUTE PROCEDURE
2316 "write_event_member_image_updated_trigger"();
2318 COMMENT ON FUNCTION "write_event_member_image_updated_trigger"() IS 'Implementation of trigger "write_event_member_image_updated" on table "member_image"';
2319 COMMENT ON TRIGGER "write_event_member_image_updated" ON "member_image" IS 'Creates entries in "event" table on member image update';
2322 CREATE FUNCTION "write_event_interest_trigger"()
2323 RETURNS TRIGGER
2324 LANGUAGE 'plpgsql' VOLATILE AS $$
2325 DECLARE
2326 "issue_row" "issue"%ROWTYPE;
2327 "area_row" "area"%ROWTYPE;
2328 BEGIN
2329 IF TG_OP = 'UPDATE' THEN
2330 IF OLD = NEW THEN
2331 RETURN NULL;
2332 END IF;
2333 END IF;
2334 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2335 SELECT * INTO "issue_row" FROM "issue"
2336 WHERE "id" = OLD."issue_id" FOR SHARE;
2337 SELECT * INTO "area_row" FROM "area"
2338 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2339 IF "issue_row"."id" NOTNULL THEN
2340 INSERT INTO "event" (
2341 "event", "member_id",
2342 "unit_id", "area_id", "policy_id", "issue_id", "state",
2343 "boolean_value"
2344 ) VALUES (
2345 'interest', OLD."member_id",
2346 "area_row"."unit_id", "issue_row"."area_id",
2347 "issue_row"."policy_id",
2348 OLD."issue_id", "issue_row"."state",
2349 FALSE
2350 );
2351 END IF;
2352 END IF;
2353 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2354 SELECT * INTO "issue_row" FROM "issue"
2355 WHERE "id" = NEW."issue_id" FOR SHARE;
2356 SELECT * INTO "area_row" FROM "area"
2357 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2358 INSERT INTO "event" (
2359 "event", "member_id",
2360 "unit_id", "area_id", "policy_id", "issue_id", "state",
2361 "boolean_value"
2362 ) VALUES (
2363 'interest', NEW."member_id",
2364 "area_row"."unit_id", "issue_row"."area_id",
2365 "issue_row"."policy_id",
2366 NEW."issue_id", "issue_row"."state",
2367 TRUE
2368 );
2369 END IF;
2370 RETURN NULL;
2371 END;
2372 $$;
2374 CREATE TRIGGER "write_event_interest"
2375 AFTER INSERT OR UPDATE OR DELETE ON "interest" FOR EACH ROW EXECUTE PROCEDURE
2376 "write_event_interest_trigger"();
2378 COMMENT ON FUNCTION "write_event_interest_trigger"() IS 'Implementation of trigger "write_event_interest_inserted" on table "interest"';
2379 COMMENT ON TRIGGER "write_event_interest" ON "interest" IS 'Create entry in "event" table on adding or removing interest';
2382 CREATE FUNCTION "write_event_initiator_trigger"()
2383 RETURNS TRIGGER
2384 LANGUAGE 'plpgsql' VOLATILE AS $$
2385 DECLARE
2386 "initiative_row" "initiative"%ROWTYPE;
2387 "issue_row" "issue"%ROWTYPE;
2388 "area_row" "area"%ROWTYPE;
2389 "accepted_v" BOOLEAN = FALSE;
2390 "rejected_v" BOOLEAN = FALSE;
2391 BEGIN
2392 IF TG_OP = 'UPDATE' THEN
2393 IF
2394 OLD."initiative_id" = NEW."initiative_id" AND
2395 OLD."member_id" = NEW."member_id"
2396 THEN
2397 IF
2398 coalesce(OLD."accepted", FALSE) = coalesce(NEW."accepted", FALSE)
2399 THEN
2400 RETURN NULL;
2401 END IF;
2402 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2403 "accepted_v" := TRUE;
2404 ELSE
2405 "rejected_v" := TRUE;
2406 END IF;
2407 END IF;
2408 END IF;
2409 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "accepted_v" THEN
2410 IF coalesce(OLD."accepted", FALSE) = TRUE THEN
2411 SELECT * INTO "initiative_row" FROM "initiative"
2412 WHERE "id" = OLD."initiative_id" FOR SHARE;
2413 IF "initiative_row"."id" NOTNULL THEN
2414 SELECT * INTO "issue_row" FROM "issue"
2415 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2416 SELECT * INTO "area_row" FROM "area"
2417 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2418 INSERT INTO "event" (
2419 "event", "member_id",
2420 "unit_id", "area_id", "policy_id", "issue_id", "state",
2421 "initiative_id", "boolean_value"
2422 ) VALUES (
2423 'initiator', OLD."member_id",
2424 "area_row"."unit_id", "issue_row"."area_id",
2425 "issue_row"."policy_id",
2426 "issue_row"."id", "issue_row"."state",
2427 OLD."initiative_id", FALSE
2428 );
2429 END IF;
2430 END IF;
2431 END IF;
2432 IF TG_OP = 'UPDATE' AND NOT "rejected_v" THEN
2433 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2434 SELECT * INTO "initiative_row" FROM "initiative"
2435 WHERE "id" = NEW."initiative_id" FOR SHARE;
2436 SELECT * INTO "issue_row" FROM "issue"
2437 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2438 SELECT * INTO "area_row" FROM "area"
2439 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2440 INSERT INTO "event" (
2441 "event", "member_id",
2442 "unit_id", "area_id", "policy_id", "issue_id", "state",
2443 "initiative_id", "boolean_value"
2444 ) VALUES (
2445 'initiator', NEW."member_id",
2446 "area_row"."unit_id", "issue_row"."area_id",
2447 "issue_row"."policy_id",
2448 "issue_row"."id", "issue_row"."state",
2449 NEW."initiative_id", TRUE
2450 );
2451 END IF;
2452 END IF;
2453 RETURN NULL;
2454 END;
2455 $$;
2457 CREATE TRIGGER "write_event_initiator"
2458 AFTER UPDATE OR DELETE ON "initiator" FOR EACH ROW EXECUTE PROCEDURE
2459 "write_event_initiator_trigger"();
2461 COMMENT ON FUNCTION "write_event_initiator_trigger"() IS 'Implementation of trigger "write_event_initiator" on table "initiator"';
2462 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)';
2465 CREATE FUNCTION "write_event_support_trigger"()
2466 RETURNS TRIGGER
2467 LANGUAGE 'plpgsql' VOLATILE AS $$
2468 DECLARE
2469 "issue_row" "issue"%ROWTYPE;
2470 "area_row" "area"%ROWTYPE;
2471 BEGIN
2472 IF TG_OP = 'UPDATE' THEN
2473 IF
2474 OLD."initiative_id" = NEW."initiative_id" AND
2475 OLD."member_id" = NEW."member_id"
2476 THEN
2477 IF OLD."draft_id" != NEW."draft_id" THEN
2478 SELECT * INTO "issue_row" FROM "issue"
2479 WHERE "id" = NEW."issue_id" FOR SHARE;
2480 SELECT * INTO "area_row" FROM "area"
2481 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2482 INSERT INTO "event" (
2483 "event", "member_id",
2484 "unit_id", "area_id", "policy_id", "issue_id", "state",
2485 "initiative_id", "draft_id"
2486 ) VALUES (
2487 'support_updated', NEW."member_id",
2488 "area_row"."unit_id", "issue_row"."area_id",
2489 "issue_row"."policy_id",
2490 "issue_row"."id", "issue_row"."state",
2491 NEW."initiative_id", NEW."draft_id"
2492 );
2493 END IF;
2494 RETURN NULL;
2495 END IF;
2496 END IF;
2497 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2498 IF EXISTS (
2499 SELECT NULL FROM "initiative" WHERE "id" = OLD."initiative_id"
2500 FOR SHARE
2501 ) THEN
2502 SELECT * INTO "issue_row" FROM "issue"
2503 WHERE "id" = OLD."issue_id" FOR SHARE;
2504 SELECT * INTO "area_row" FROM "area"
2505 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2506 INSERT INTO "event" (
2507 "event", "member_id",
2508 "unit_id", "area_id", "policy_id", "issue_id", "state",
2509 "initiative_id", "boolean_value"
2510 ) VALUES (
2511 'support', OLD."member_id",
2512 "area_row"."unit_id", "issue_row"."area_id",
2513 "issue_row"."policy_id",
2514 "issue_row"."id", "issue_row"."state",
2515 OLD."initiative_id", FALSE
2516 );
2517 END IF;
2518 END IF;
2519 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2520 SELECT * INTO "issue_row" FROM "issue"
2521 WHERE "id" = NEW."issue_id" FOR SHARE;
2522 SELECT * INTO "area_row" FROM "area"
2523 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2524 INSERT INTO "event" (
2525 "event", "member_id",
2526 "unit_id", "area_id", "policy_id", "issue_id", "state",
2527 "initiative_id", "draft_id", "boolean_value"
2528 ) VALUES (
2529 'support', NEW."member_id",
2530 "area_row"."unit_id", "issue_row"."area_id",
2531 "issue_row"."policy_id",
2532 "issue_row"."id", "issue_row"."state",
2533 NEW."initiative_id", NEW."draft_id", TRUE
2534 );
2535 END IF;
2536 RETURN NULL;
2537 END;
2538 $$;
2540 CREATE TRIGGER "write_event_support"
2541 AFTER INSERT OR UPDATE OR DELETE ON "supporter" FOR EACH ROW EXECUTE PROCEDURE
2542 "write_event_support_trigger"();
2544 COMMENT ON FUNCTION "write_event_support_trigger"() IS 'Implementation of trigger "write_event_support" on table "supporter"';
2545 COMMENT ON TRIGGER "write_event_support" ON "supporter" IS 'Create entry in "event" table when adding, updating, or removing support';
2548 CREATE FUNCTION "write_event_suggestion_rated_trigger"()
2549 RETURNS TRIGGER
2550 LANGUAGE 'plpgsql' VOLATILE AS $$
2551 DECLARE
2552 "same_pkey_v" BOOLEAN = FALSE;
2553 "initiative_row" "initiative"%ROWTYPE;
2554 "issue_row" "issue"%ROWTYPE;
2555 "area_row" "area"%ROWTYPE;
2556 BEGIN
2557 IF TG_OP = 'UPDATE' THEN
2558 IF
2559 OLD."suggestion_id" = NEW."suggestion_id" AND
2560 OLD."member_id" = NEW."member_id"
2561 THEN
2562 IF
2563 OLD."degree" = NEW."degree" AND
2564 OLD."fulfilled" = NEW."fulfilled"
2565 THEN
2566 RETURN NULL;
2567 END IF;
2568 "same_pkey_v" := TRUE;
2569 END IF;
2570 END IF;
2571 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "same_pkey_v" THEN
2572 IF EXISTS (
2573 SELECT NULL FROM "suggestion" WHERE "id" = OLD."suggestion_id"
2574 FOR SHARE
2575 ) THEN
2576 SELECT * INTO "initiative_row" FROM "initiative"
2577 WHERE "id" = OLD."initiative_id" FOR SHARE;
2578 SELECT * INTO "issue_row" FROM "issue"
2579 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2580 SELECT * INTO "area_row" FROM "area"
2581 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2582 INSERT INTO "event" (
2583 "event", "member_id",
2584 "unit_id", "area_id", "policy_id", "issue_id", "state",
2585 "initiative_id", "suggestion_id",
2586 "boolean_value", "numeric_value"
2587 ) VALUES (
2588 'suggestion_rated', OLD."member_id",
2589 "area_row"."unit_id", "issue_row"."area_id",
2590 "issue_row"."policy_id",
2591 "initiative_row"."issue_id", "issue_row"."state",
2592 OLD."initiative_id", OLD."suggestion_id",
2593 NULL, 0
2594 );
2595 END IF;
2596 END IF;
2597 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2598 SELECT * INTO "initiative_row" FROM "initiative"
2599 WHERE "id" = NEW."initiative_id" FOR SHARE;
2600 SELECT * INTO "issue_row" FROM "issue"
2601 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2602 SELECT * INTO "area_row" FROM "area"
2603 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2604 INSERT INTO "event" (
2605 "event", "member_id",
2606 "unit_id", "area_id", "policy_id", "issue_id", "state",
2607 "initiative_id", "suggestion_id",
2608 "boolean_value", "numeric_value"
2609 ) VALUES (
2610 'suggestion_rated', NEW."member_id",
2611 "area_row"."unit_id", "issue_row"."area_id",
2612 "issue_row"."policy_id",
2613 "initiative_row"."issue_id", "issue_row"."state",
2614 NEW."initiative_id", NEW."suggestion_id",
2615 NEW."fulfilled", NEW."degree"
2616 );
2617 END IF;
2618 RETURN NULL;
2619 END;
2620 $$;
2622 CREATE TRIGGER "write_event_suggestion_rated"
2623 AFTER INSERT OR UPDATE OR DELETE ON "opinion" FOR EACH ROW EXECUTE PROCEDURE
2624 "write_event_suggestion_rated_trigger"();
2626 COMMENT ON FUNCTION "write_event_suggestion_rated_trigger"() IS 'Implementation of trigger "write_event_suggestion_rated" on table "opinion"';
2627 COMMENT ON TRIGGER "write_event_suggestion_rated" ON "opinion" IS 'Create entry in "event" table when adding, updating, or removing support';
2630 CREATE FUNCTION "write_event_delegation_trigger"()
2631 RETURNS TRIGGER
2632 LANGUAGE 'plpgsql' VOLATILE AS $$
2633 DECLARE
2634 "issue_row" "issue"%ROWTYPE;
2635 "area_row" "area"%ROWTYPE;
2636 BEGIN
2637 IF TG_OP = 'DELETE' THEN
2638 IF EXISTS (
2639 SELECT NULL FROM "member" WHERE "id" = OLD."truster_id"
2640 ) AND (CASE OLD."scope"
2641 WHEN 'unit'::"delegation_scope" THEN EXISTS (
2642 SELECT NULL FROM "unit" WHERE "id" = OLD."unit_id"
2644 WHEN 'area'::"delegation_scope" THEN EXISTS (
2645 SELECT NULL FROM "area" WHERE "id" = OLD."area_id"
2647 WHEN 'issue'::"delegation_scope" THEN EXISTS (
2648 SELECT NULL FROM "issue" WHERE "id" = OLD."issue_id"
2650 END) THEN
2651 SELECT * INTO "issue_row" FROM "issue"
2652 WHERE "id" = OLD."issue_id" FOR SHARE;
2653 SELECT * INTO "area_row" FROM "area"
2654 WHERE "id" = COALESCE(OLD."area_id", "issue_row"."area_id")
2655 FOR SHARE;
2656 INSERT INTO "event" (
2657 "event", "member_id", "scope",
2658 "unit_id", "area_id", "issue_id", "state",
2659 "boolean_value"
2660 ) VALUES (
2661 'delegation', OLD."truster_id", OLD."scope",
2662 COALESCE(OLD."unit_id", "area_row"."unit_id"), "area_row"."id",
2663 OLD."issue_id", "issue_row"."state",
2664 FALSE
2665 );
2666 END IF;
2667 ELSE
2668 SELECT * INTO "issue_row" FROM "issue"
2669 WHERE "id" = NEW."issue_id" FOR SHARE;
2670 SELECT * INTO "area_row" FROM "area"
2671 WHERE "id" = COALESCE(NEW."area_id", "issue_row"."area_id")
2672 FOR SHARE;
2673 INSERT INTO "event" (
2674 "event", "member_id", "other_member_id", "scope",
2675 "unit_id", "area_id", "issue_id", "state",
2676 "boolean_value"
2677 ) VALUES (
2678 'delegation', NEW."truster_id", NEW."trustee_id", NEW."scope",
2679 COALESCE(NEW."unit_id", "area_row"."unit_id"), "area_row"."id",
2680 NEW."issue_id", "issue_row"."state",
2681 TRUE
2682 );
2683 END IF;
2684 RETURN NULL;
2685 END;
2686 $$;
2688 CREATE TRIGGER "write_event_delegation"
2689 AFTER INSERT OR UPDATE OR DELETE ON "delegation" FOR EACH ROW EXECUTE PROCEDURE
2690 "write_event_delegation_trigger"();
2692 COMMENT ON FUNCTION "write_event_delegation_trigger"() IS 'Implementation of trigger "write_event_delegation" on table "delegation"';
2693 COMMENT ON TRIGGER "write_event_delegation" ON "delegation" IS 'Create entry in "event" table when adding, updating, or removing a delegation';
2696 CREATE FUNCTION "write_event_contact_trigger"()
2697 RETURNS TRIGGER
2698 LANGUAGE 'plpgsql' VOLATILE AS $$
2699 BEGIN
2700 IF TG_OP = 'UPDATE' THEN
2701 IF
2702 OLD."member_id" = NEW."member_id" AND
2703 OLD."other_member_id" = NEW."other_member_id" AND
2704 OLD."public" = NEW."public"
2705 THEN
2706 RETURN NULL;
2707 END IF;
2708 END IF;
2709 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2710 IF OLD."public" THEN
2711 IF EXISTS (
2712 SELECT NULL FROM "member" WHERE "id" = OLD."member_id"
2713 FOR SHARE
2714 ) AND EXISTS (
2715 SELECT NULL FROM "member" WHERE "id" = OLD."other_member_id"
2716 FOR SHARE
2717 ) THEN
2718 INSERT INTO "event" (
2719 "event", "member_id", "other_member_id", "boolean_value"
2720 ) VALUES (
2721 'contact', OLD."member_id", OLD."other_member_id", FALSE
2722 );
2723 END IF;
2724 END IF;
2725 END IF;
2726 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2727 IF NEW."public" THEN
2728 INSERT INTO "event" (
2729 "event", "member_id", "other_member_id", "boolean_value"
2730 ) VALUES (
2731 'contact', NEW."member_id", NEW."other_member_id", TRUE
2732 );
2733 END IF;
2734 END IF;
2735 RETURN NULL;
2736 END;
2737 $$;
2739 CREATE TRIGGER "write_event_contact"
2740 AFTER INSERT OR UPDATE OR DELETE ON "contact" FOR EACH ROW EXECUTE PROCEDURE
2741 "write_event_contact_trigger"();
2743 COMMENT ON FUNCTION "write_event_contact_trigger"() IS 'Implementation of trigger "write_event_contact" on table "contact"';
2744 COMMENT ON TRIGGER "write_event_contact" ON "contact" IS 'Create entry in "event" table when adding or removing public contacts';
2747 CREATE FUNCTION "write_event_posting_trigger"()
2748 RETURNS TRIGGER
2749 LANGUAGE 'plpgsql' VOLATILE AS $$
2750 BEGIN
2751 INSERT INTO "event" (
2752 "event", "posting_id", "member_id",
2753 "unit_id", "area_id", "policy_id",
2754 "issue_id", "initiative_id", "suggestion_id"
2755 ) VALUES (
2756 'posting_created', NEW."id", NEW."author_id",
2757 NEW."unit_id", NEW."area_id", NEW."policy_id",
2758 NEW."issue_id", NEW."initiative_id", NEW."suggestion_id"
2759 );
2760 RETURN NULL;
2761 END;
2762 $$;
2764 CREATE TRIGGER "write_event_posting"
2765 AFTER INSERT ON "posting" FOR EACH ROW EXECUTE PROCEDURE
2766 "write_event_posting_trigger"();
2768 COMMENT ON FUNCTION "write_event_posting_trigger"() IS 'Implementation of trigger "write_event_posting" on table "posting"';
2769 COMMENT ON TRIGGER "write_event_posting" ON "posting" IS 'Create entry in "event" table when creating a new posting';
2772 CREATE FUNCTION "send_event_notify_trigger"()
2773 RETURNS TRIGGER
2774 LANGUAGE 'plpgsql' VOLATILE AS $$
2775 BEGIN
2776 EXECUTE 'NOTIFY "event", ''' || NEW."event" || '''';
2777 RETURN NULL;
2778 END;
2779 $$;
2781 CREATE TRIGGER "send_notify"
2782 AFTER INSERT OR UPDATE ON "event" FOR EACH ROW EXECUTE PROCEDURE
2783 "send_event_notify_trigger"();
2787 ----------------------------
2788 -- Additional constraints --
2789 ----------------------------
2792 CREATE FUNCTION "delete_extended_scope_tokens_trigger"()
2793 RETURNS TRIGGER
2794 LANGUAGE 'plpgsql' VOLATILE AS $$
2795 DECLARE
2796 "system_application_row" "system_application"%ROWTYPE;
2797 BEGIN
2798 IF OLD."system_application_id" NOTNULL THEN
2799 SELECT * FROM "system_application" INTO "system_application_row"
2800 WHERE "id" = OLD."system_application_id";
2801 DELETE FROM "token"
2802 WHERE "member_id" = OLD."member_id"
2803 AND "system_application_id" = OLD."system_application_id"
2804 AND NOT COALESCE(
2805 regexp_split_to_array("scope", E'\\s+') <@
2806 regexp_split_to_array(
2807 "system_application_row"."automatic_scope", E'\\s+'
2808 ),
2809 FALSE
2810 );
2811 END IF;
2812 RETURN OLD;
2813 END;
2814 $$;
2816 CREATE TRIGGER "delete_extended_scope_tokens"
2817 BEFORE DELETE ON "member_application" FOR EACH ROW EXECUTE PROCEDURE
2818 "delete_extended_scope_tokens_trigger"();
2821 CREATE FUNCTION "detach_token_from_session_trigger"()
2822 RETURNS TRIGGER
2823 LANGUAGE 'plpgsql' VOLATILE AS $$
2824 BEGIN
2825 UPDATE "token" SET "session_id" = NULL
2826 WHERE "session_id" = OLD."id";
2827 RETURN OLD;
2828 END;
2829 $$;
2831 CREATE TRIGGER "detach_token_from_session"
2832 BEFORE DELETE ON "session" FOR EACH ROW EXECUTE PROCEDURE
2833 "detach_token_from_session_trigger"();
2836 CREATE FUNCTION "delete_non_detached_scope_with_session_trigger"()
2837 RETURNS TRIGGER
2838 LANGUAGE 'plpgsql' VOLATILE AS $$
2839 BEGIN
2840 IF NEW."session_id" ISNULL THEN
2841 SELECT coalesce(string_agg("element", ' '), '') INTO NEW."scope"
2842 FROM unnest(regexp_split_to_array(NEW."scope", E'\\s+')) AS "element"
2843 WHERE "element" LIKE '%_detached';
2844 END IF;
2845 RETURN NEW;
2846 END;
2847 $$;
2849 CREATE TRIGGER "delete_non_detached_scope_with_session"
2850 BEFORE INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2851 "delete_non_detached_scope_with_session_trigger"();
2854 CREATE FUNCTION "delete_token_with_empty_scope_trigger"()
2855 RETURNS TRIGGER
2856 LANGUAGE 'plpgsql' VOLATILE AS $$
2857 BEGIN
2858 IF NEW."scope" = '' THEN
2859 DELETE FROM "token" WHERE "id" = NEW."id";
2860 END IF;
2861 RETURN NULL;
2862 END;
2863 $$;
2865 CREATE TRIGGER "delete_token_with_empty_scope"
2866 AFTER INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2867 "delete_token_with_empty_scope_trigger"();
2870 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
2871 RETURNS TRIGGER
2872 LANGUAGE 'plpgsql' VOLATILE AS $$
2873 BEGIN
2874 IF NOT EXISTS (
2875 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
2876 ) THEN
2877 RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING
2878 ERRCODE = 'integrity_constraint_violation',
2879 HINT = 'Create issue, initiative, and draft within the same transaction.';
2880 END IF;
2881 RETURN NULL;
2882 END;
2883 $$;
2885 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
2886 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
2887 FOR EACH ROW EXECUTE PROCEDURE
2888 "issue_requires_first_initiative_trigger"();
2890 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
2891 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
2894 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
2895 RETURNS TRIGGER
2896 LANGUAGE 'plpgsql' VOLATILE AS $$
2897 DECLARE
2898 "reference_lost" BOOLEAN;
2899 BEGIN
2900 IF TG_OP = 'DELETE' THEN
2901 "reference_lost" := TRUE;
2902 ELSE
2903 "reference_lost" := NEW."issue_id" != OLD."issue_id";
2904 END IF;
2905 IF
2906 "reference_lost" AND NOT EXISTS (
2907 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
2909 THEN
2910 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
2911 END IF;
2912 RETURN NULL;
2913 END;
2914 $$;
2916 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
2917 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
2918 FOR EACH ROW EXECUTE PROCEDURE
2919 "last_initiative_deletes_issue_trigger"();
2921 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
2922 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
2925 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
2926 RETURNS TRIGGER
2927 LANGUAGE 'plpgsql' VOLATILE AS $$
2928 BEGIN
2929 IF NOT EXISTS (
2930 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
2931 ) THEN
2932 RAISE EXCEPTION 'Cannot create initiative without an initial draft.' USING
2933 ERRCODE = 'integrity_constraint_violation',
2934 HINT = 'Create issue, initiative and draft within the same transaction.';
2935 END IF;
2936 RETURN NULL;
2937 END;
2938 $$;
2940 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
2941 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
2942 FOR EACH ROW EXECUTE PROCEDURE
2943 "initiative_requires_first_draft_trigger"();
2945 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
2946 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
2949 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
2950 RETURNS TRIGGER
2951 LANGUAGE 'plpgsql' VOLATILE AS $$
2952 DECLARE
2953 "reference_lost" BOOLEAN;
2954 BEGIN
2955 IF TG_OP = 'DELETE' THEN
2956 "reference_lost" := TRUE;
2957 ELSE
2958 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
2959 END IF;
2960 IF
2961 "reference_lost" AND NOT EXISTS (
2962 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
2964 THEN
2965 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
2966 END IF;
2967 RETURN NULL;
2968 END;
2969 $$;
2971 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
2972 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
2973 FOR EACH ROW EXECUTE PROCEDURE
2974 "last_draft_deletes_initiative_trigger"();
2976 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
2977 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
2980 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
2981 RETURNS TRIGGER
2982 LANGUAGE 'plpgsql' VOLATILE AS $$
2983 BEGIN
2984 IF NOT EXISTS (
2985 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
2986 ) THEN
2987 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING
2988 ERRCODE = 'integrity_constraint_violation',
2989 HINT = 'Create suggestion and opinion within the same transaction.';
2990 END IF;
2991 RETURN NULL;
2992 END;
2993 $$;
2995 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
2996 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
2997 FOR EACH ROW EXECUTE PROCEDURE
2998 "suggestion_requires_first_opinion_trigger"();
3000 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
3001 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
3004 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
3005 RETURNS TRIGGER
3006 LANGUAGE 'plpgsql' VOLATILE AS $$
3007 DECLARE
3008 "reference_lost" BOOLEAN;
3009 BEGIN
3010 IF TG_OP = 'DELETE' THEN
3011 "reference_lost" := TRUE;
3012 ELSE
3013 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
3014 END IF;
3015 IF
3016 "reference_lost" AND NOT EXISTS (
3017 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
3019 THEN
3020 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
3021 END IF;
3022 RETURN NULL;
3023 END;
3024 $$;
3026 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
3027 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
3028 FOR EACH ROW EXECUTE PROCEDURE
3029 "last_opinion_deletes_suggestion_trigger"();
3031 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
3032 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
3035 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
3036 RETURNS TRIGGER
3037 LANGUAGE 'plpgsql' VOLATILE AS $$
3038 BEGIN
3039 DELETE FROM "direct_voter"
3040 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
3041 RETURN NULL;
3042 END;
3043 $$;
3045 CREATE TRIGGER "non_voter_deletes_direct_voter"
3046 AFTER INSERT OR UPDATE ON "non_voter"
3047 FOR EACH ROW EXECUTE PROCEDURE
3048 "non_voter_deletes_direct_voter_trigger"();
3050 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
3051 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")';
3054 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
3055 RETURNS TRIGGER
3056 LANGUAGE 'plpgsql' VOLATILE AS $$
3057 BEGIN
3058 DELETE FROM "non_voter"
3059 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
3060 RETURN NULL;
3061 END;
3062 $$;
3064 CREATE TRIGGER "direct_voter_deletes_non_voter"
3065 AFTER INSERT OR UPDATE ON "direct_voter"
3066 FOR EACH ROW EXECUTE PROCEDURE
3067 "direct_voter_deletes_non_voter_trigger"();
3069 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
3070 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")';
3073 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
3074 RETURNS TRIGGER
3075 LANGUAGE 'plpgsql' VOLATILE AS $$
3076 BEGIN
3077 IF NEW."comment" ISNULL THEN
3078 NEW."comment_changed" := NULL;
3079 NEW."formatting_engine" := NULL;
3080 END IF;
3081 RETURN NEW;
3082 END;
3083 $$;
3085 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
3086 BEFORE INSERT OR UPDATE ON "direct_voter"
3087 FOR EACH ROW EXECUTE PROCEDURE
3088 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
3090 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"';
3091 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.';
3095 ---------------------------------
3096 -- Delete incomplete snapshots --
3097 ---------------------------------
3100 CREATE FUNCTION "delete_snapshot_on_partial_delete_trigger"()
3101 RETURNS TRIGGER
3102 LANGUAGE 'plpgsql' VOLATILE AS $$
3103 BEGIN
3104 IF TG_OP = 'UPDATE' THEN
3105 IF
3106 OLD."snapshot_id" = NEW."snapshot_id" AND
3107 OLD."issue_id" = NEW."issue_id"
3108 THEN
3109 RETURN NULL;
3110 END IF;
3111 END IF;
3112 DELETE FROM "snapshot" WHERE "id" = OLD."snapshot_id";
3113 RETURN NULL;
3114 END;
3115 $$;
3117 CREATE TRIGGER "delete_snapshot_on_partial_delete"
3118 AFTER UPDATE OR DELETE ON "snapshot_issue"
3119 FOR EACH ROW EXECUTE PROCEDURE
3120 "delete_snapshot_on_partial_delete_trigger"();
3122 COMMENT ON FUNCTION "delete_snapshot_on_partial_delete_trigger"() IS 'Implementation of trigger "delete_snapshot_on_partial_delete" on table "snapshot_issue"';
3123 COMMENT ON TRIGGER "delete_snapshot_on_partial_delete" ON "snapshot_issue" IS 'Deletes whole snapshot if one issue is deleted from the snapshot';
3127 ---------------------------------------------------------------
3128 -- Ensure that votes are not modified when issues are closed --
3129 ---------------------------------------------------------------
3131 -- NOTE: Frontends should ensure this anyway, but in case of programming
3132 -- errors the following triggers ensure data integrity.
3135 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
3136 RETURNS TRIGGER
3137 LANGUAGE 'plpgsql' VOLATILE AS $$
3138 DECLARE
3139 "issue_id_v" "issue"."id"%TYPE;
3140 "issue_row" "issue"%ROWTYPE;
3141 BEGIN
3142 IF EXISTS (
3143 SELECT NULL FROM "temporary_transaction_data"
3144 WHERE "txid" = txid_current()
3145 AND "key" = 'override_protection_triggers'
3146 AND "value" = TRUE::TEXT
3147 ) THEN
3148 RETURN NULL;
3149 END IF;
3150 IF TG_OP = 'DELETE' THEN
3151 "issue_id_v" := OLD."issue_id";
3152 ELSE
3153 "issue_id_v" := NEW."issue_id";
3154 END IF;
3155 SELECT INTO "issue_row" * FROM "issue"
3156 WHERE "id" = "issue_id_v" FOR SHARE;
3157 IF (
3158 "issue_row"."closed" NOTNULL OR (
3159 "issue_row"."state" = 'voting' AND
3160 "issue_row"."phase_finished" NOTNULL
3162 ) THEN
3163 IF
3164 TG_RELID = 'direct_voter'::regclass AND
3165 TG_OP = 'UPDATE'
3166 THEN
3167 IF
3168 OLD."issue_id" = NEW."issue_id" AND
3169 OLD."member_id" = NEW."member_id" AND
3170 OLD."weight" = NEW."weight"
3171 THEN
3172 RETURN NULL; -- allows changing of voter comment
3173 END IF;
3174 END IF;
3175 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
3176 ERRCODE = 'integrity_constraint_violation';
3177 END IF;
3178 RETURN NULL;
3179 END;
3180 $$;
3182 CREATE TRIGGER "forbid_changes_on_closed_issue"
3183 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
3184 FOR EACH ROW EXECUTE PROCEDURE
3185 "forbid_changes_on_closed_issue_trigger"();
3187 CREATE TRIGGER "forbid_changes_on_closed_issue"
3188 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
3189 FOR EACH ROW EXECUTE PROCEDURE
3190 "forbid_changes_on_closed_issue_trigger"();
3192 CREATE TRIGGER "forbid_changes_on_closed_issue"
3193 AFTER INSERT OR UPDATE OR DELETE ON "vote"
3194 FOR EACH ROW EXECUTE PROCEDURE
3195 "forbid_changes_on_closed_issue_trigger"();
3197 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"';
3198 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';
3199 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';
3200 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';
3204 --------------------------------------------------------------------
3205 -- Auto-retrieval of fields only needed for referential integrity --
3206 --------------------------------------------------------------------
3209 CREATE FUNCTION "autofill_issue_id_trigger"()
3210 RETURNS TRIGGER
3211 LANGUAGE 'plpgsql' VOLATILE AS $$
3212 BEGIN
3213 IF NEW."issue_id" ISNULL THEN
3214 SELECT "issue_id" INTO NEW."issue_id"
3215 FROM "initiative" WHERE "id" = NEW."initiative_id";
3216 END IF;
3217 RETURN NEW;
3218 END;
3219 $$;
3221 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
3222 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3224 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
3225 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3227 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
3228 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
3229 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
3232 CREATE FUNCTION "autofill_initiative_id_trigger"()
3233 RETURNS TRIGGER
3234 LANGUAGE 'plpgsql' VOLATILE AS $$
3235 BEGIN
3236 IF NEW."initiative_id" ISNULL THEN
3237 SELECT "initiative_id" INTO NEW."initiative_id"
3238 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3239 END IF;
3240 RETURN NEW;
3241 END;
3242 $$;
3244 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
3245 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
3247 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
3248 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
3252 -------------------------------------------------------
3253 -- Automatic copying of values for indexing purposes --
3254 -------------------------------------------------------
3257 CREATE FUNCTION "copy_current_draft_data"
3258 ("initiative_id_p" "initiative"."id"%TYPE )
3259 RETURNS VOID
3260 LANGUAGE 'plpgsql' VOLATILE AS $$
3261 BEGIN
3262 PERFORM NULL FROM "initiative" WHERE "id" = "initiative_id_p"
3263 FOR UPDATE;
3264 UPDATE "initiative" SET
3265 "location" = "draft"."location",
3266 "draft_text_search_data" = "draft"."text_search_data"
3267 FROM "current_draft" AS "draft"
3268 WHERE "initiative"."id" = "initiative_id_p"
3269 AND "draft"."initiative_id" = "initiative_id_p";
3270 END;
3271 $$;
3273 COMMENT ON FUNCTION "copy_current_draft_data"
3274 ( "initiative"."id"%TYPE )
3275 IS 'Helper function for function "copy_current_draft_data_trigger"';
3278 CREATE FUNCTION "copy_current_draft_data_trigger"()
3279 RETURNS TRIGGER
3280 LANGUAGE 'plpgsql' VOLATILE AS $$
3281 BEGIN
3282 IF TG_OP='DELETE' THEN
3283 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3284 ELSE
3285 IF TG_OP='UPDATE' THEN
3286 IF COALESCE(OLD."inititiave_id" != NEW."initiative_id", TRUE) THEN
3287 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3288 END IF;
3289 END IF;
3290 PERFORM "copy_current_draft_data"(NEW."initiative_id");
3291 END IF;
3292 RETURN NULL;
3293 END;
3294 $$;
3296 CREATE TRIGGER "copy_current_draft_data"
3297 AFTER INSERT OR UPDATE OR DELETE ON "draft"
3298 FOR EACH ROW EXECUTE PROCEDURE
3299 "copy_current_draft_data_trigger"();
3301 COMMENT ON FUNCTION "copy_current_draft_data_trigger"() IS 'Implementation of trigger "copy_current_draft_data" on table "draft"';
3302 COMMENT ON TRIGGER "copy_current_draft_data" ON "draft" IS 'Copy certain fields from most recent "draft" to "initiative"';
3306 -----------------------------------------------------
3307 -- Automatic calculation of certain default values --
3308 -----------------------------------------------------
3311 CREATE FUNCTION "copy_timings_trigger"()
3312 RETURNS TRIGGER
3313 LANGUAGE 'plpgsql' VOLATILE AS $$
3314 DECLARE
3315 "policy_row" "policy"%ROWTYPE;
3316 BEGIN
3317 SELECT * INTO "policy_row" FROM "policy"
3318 WHERE "id" = NEW."policy_id";
3319 IF NEW."min_admission_time" ISNULL THEN
3320 NEW."min_admission_time" := "policy_row"."min_admission_time";
3321 END IF;
3322 IF NEW."max_admission_time" ISNULL THEN
3323 NEW."max_admission_time" := "policy_row"."max_admission_time";
3324 END IF;
3325 IF NEW."discussion_time" ISNULL THEN
3326 NEW."discussion_time" := "policy_row"."discussion_time";
3327 END IF;
3328 IF NEW."verification_time" ISNULL THEN
3329 NEW."verification_time" := "policy_row"."verification_time";
3330 END IF;
3331 IF NEW."voting_time" ISNULL THEN
3332 NEW."voting_time" := "policy_row"."voting_time";
3333 END IF;
3334 RETURN NEW;
3335 END;
3336 $$;
3338 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
3339 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
3341 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
3342 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
3345 CREATE FUNCTION "default_for_draft_id_trigger"()
3346 RETURNS TRIGGER
3347 LANGUAGE 'plpgsql' VOLATILE AS $$
3348 BEGIN
3349 IF NEW."draft_id" ISNULL THEN
3350 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
3351 WHERE "initiative_id" = NEW."initiative_id";
3352 END IF;
3353 RETURN NEW;
3354 END;
3355 $$;
3357 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
3358 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3359 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
3360 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3362 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
3363 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';
3364 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';
3368 ----------------------------------------
3369 -- Automatic creation of dependencies --
3370 ----------------------------------------
3373 CREATE FUNCTION "autocreate_interest_trigger"()
3374 RETURNS TRIGGER
3375 LANGUAGE 'plpgsql' VOLATILE AS $$
3376 BEGIN
3377 IF NOT EXISTS (
3378 SELECT NULL FROM "initiative" JOIN "interest"
3379 ON "initiative"."issue_id" = "interest"."issue_id"
3380 WHERE "initiative"."id" = NEW."initiative_id"
3381 AND "interest"."member_id" = NEW."member_id"
3382 ) THEN
3383 BEGIN
3384 INSERT INTO "interest" ("issue_id", "member_id")
3385 SELECT "issue_id", NEW."member_id"
3386 FROM "initiative" WHERE "id" = NEW."initiative_id";
3387 EXCEPTION WHEN unique_violation THEN END;
3388 END IF;
3389 RETURN NEW;
3390 END;
3391 $$;
3393 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
3394 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
3396 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
3397 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';
3400 CREATE FUNCTION "autocreate_supporter_trigger"()
3401 RETURNS TRIGGER
3402 LANGUAGE 'plpgsql' VOLATILE AS $$
3403 BEGIN
3404 IF NOT EXISTS (
3405 SELECT NULL FROM "suggestion" JOIN "supporter"
3406 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
3407 WHERE "suggestion"."id" = NEW."suggestion_id"
3408 AND "supporter"."member_id" = NEW."member_id"
3409 ) THEN
3410 BEGIN
3411 INSERT INTO "supporter" ("initiative_id", "member_id")
3412 SELECT "initiative_id", NEW."member_id"
3413 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3414 EXCEPTION WHEN unique_violation THEN END;
3415 END IF;
3416 RETURN NEW;
3417 END;
3418 $$;
3420 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
3421 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
3423 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
3424 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.';
3428 ------------------------------------------
3429 -- Views and helper functions for views --
3430 ------------------------------------------
3433 CREATE VIEW "member_eligible_to_be_notified" AS
3434 SELECT * FROM "member"
3435 WHERE "activated" NOTNULL AND "locked" = FALSE;
3437 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")';
3440 CREATE VIEW "member_to_notify" AS
3441 SELECT * FROM "member_eligible_to_be_notified"
3442 WHERE "disable_notifications" = FALSE;
3444 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)';
3447 CREATE VIEW "follower" AS
3448 SELECT
3449 "id" AS "follower_id",
3450 ( SELECT ARRAY["member"."id"] || array_agg("contact"."other_member_id")
3451 FROM "contact"
3452 WHERE "contact"."member_id" = "member"."id" AND "contact"."following" )
3453 AS "following_ids"
3454 FROM "member";
3456 COMMENT ON VIEW "follower" IS 'Provides the contacts of each member that are being followed (including the member itself) as an array of IDs';
3459 CREATE VIEW "area_quorum" AS
3460 SELECT
3461 "area"."id" AS "area_id",
3462 ceil(
3463 "area"."quorum_standard"::FLOAT8 * "quorum_factor"::FLOAT8 ^ (
3464 coalesce(
3465 ( SELECT sum(
3466 ( extract(epoch from "area"."quorum_time")::FLOAT8 /
3467 extract(epoch from
3468 ("issue"."accepted"-"issue"."created") +
3469 "issue"."discussion_time" +
3470 "issue"."verification_time" +
3471 "issue"."voting_time"
3472 )::FLOAT8
3473 ) ^ "area"."quorum_exponent"::FLOAT8
3475 FROM "issue" JOIN "policy"
3476 ON "issue"."policy_id" = "policy"."id"
3477 WHERE "issue"."area_id" = "area"."id"
3478 AND "issue"."accepted" NOTNULL
3479 AND "issue"."closed" ISNULL
3480 AND "policy"."polling" = FALSE
3481 )::FLOAT8, 0::FLOAT8
3482 ) / "area"."quorum_issues"::FLOAT8 - 1::FLOAT8
3483 ) * CASE WHEN "area"."quorum_den" ISNULL THEN 1 ELSE (
3484 SELECT "snapshot"."population"
3485 FROM "snapshot"
3486 WHERE "snapshot"."area_id" = "area"."id"
3487 AND "snapshot"."issue_id" ISNULL
3488 ORDER BY "snapshot"."id" DESC
3489 LIMIT 1
3490 ) END / coalesce("area"."quorum_den", 1)
3492 )::INT4 AS "issue_quorum"
3493 FROM "area";
3495 COMMENT ON VIEW "area_quorum" IS 'Area-based quorum considering number of open (accepted) issues';
3498 CREATE VIEW "issue_quorum" AS
3499 SELECT DISTINCT ON ("issue_id")
3500 "issue"."id" AS "issue_id",
3501 "subquery"."issue_quorum"
3502 FROM "issue"
3503 CROSS JOIN LATERAL (
3504 SELECT "area_quorum"."issue_quorum"
3505 FROM "area_quorum" WHERE "area_quorum"."area_id" = "issue"."area_id"
3506 UNION ALL
3507 SELECT "policy"."issue_quorum"
3508 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3509 UNION ALL
3510 SELECT
3511 ceil(
3512 ("issue"."population"::INT8 * "policy"."issue_quorum_num"::INT8) /
3513 "policy"."issue_quorum_den"::FLOAT8
3514 )::INT4
3515 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3516 ) AS "subquery"
3517 ORDER BY "issue_id", "issue_quorum" DESC;
3519 COMMENT ON VIEW "issue_quorum" IS 'Effective quorum for issue admission';
3522 CREATE VIEW "area_with_unaccepted_issues" AS
3523 SELECT DISTINCT ON ("area"."id") "area".*
3524 FROM "area" JOIN "issue" ON "area"."id" = "issue"."area_id"
3525 WHERE "issue"."state" = 'admission';
3527 COMMENT ON VIEW "area_with_unaccepted_issues" IS 'All areas with unaccepted open issues (needed for issue admission system)';
3530 CREATE VIEW "issue_for_admission" AS
3531 SELECT DISTINCT ON ("issue"."area_id")
3532 "issue".*,
3533 max("initiative"."supporter_count") AS "max_supporter_count"
3534 FROM "issue"
3535 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
3536 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
3537 JOIN "area" ON "issue"."area_id" = "area"."id"
3538 WHERE "issue"."state" = 'admission'::"issue_state"
3539 AND now() >= "issue"."created" + "issue"."min_admission_time"
3540 AND "initiative"."supporter_count" >= "policy"."issue_quorum"
3541 AND "initiative"."supporter_count" * "policy"."issue_quorum_den" >=
3542 "issue"."population" * "policy"."issue_quorum_num"
3543 AND "initiative"."supporter_count" >= "area"."issue_quorum"
3544 AND "initiative"."revoked" ISNULL
3545 GROUP BY "issue"."id"
3546 ORDER BY "issue"."area_id", "max_supporter_count" DESC, "issue"."id";
3548 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';
3551 CREATE VIEW "unit_delegation" AS
3552 SELECT
3553 "unit"."id" AS "unit_id",
3554 "delegation"."id",
3555 "delegation"."truster_id",
3556 "delegation"."trustee_id",
3557 "delegation"."scope"
3558 FROM "unit"
3559 JOIN "delegation"
3560 ON "delegation"."unit_id" = "unit"."id"
3561 JOIN "member"
3562 ON "delegation"."truster_id" = "member"."id"
3563 JOIN "privilege"
3564 ON "delegation"."unit_id" = "privilege"."unit_id"
3565 AND "delegation"."truster_id" = "privilege"."member_id"
3566 WHERE "member"."active" AND "privilege"."voting_right";
3568 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
3571 CREATE VIEW "area_delegation" AS
3572 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
3573 "area"."id" AS "area_id",
3574 "delegation"."id",
3575 "delegation"."truster_id",
3576 "delegation"."trustee_id",
3577 "delegation"."scope"
3578 FROM "area"
3579 JOIN "delegation"
3580 ON "delegation"."unit_id" = "area"."unit_id"
3581 OR "delegation"."area_id" = "area"."id"
3582 JOIN "member"
3583 ON "delegation"."truster_id" = "member"."id"
3584 JOIN "privilege"
3585 ON "area"."unit_id" = "privilege"."unit_id"
3586 AND "delegation"."truster_id" = "privilege"."member_id"
3587 WHERE "member"."active" AND "privilege"."voting_right"
3588 ORDER BY
3589 "area"."id",
3590 "delegation"."truster_id",
3591 "delegation"."scope" DESC;
3593 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
3596 CREATE VIEW "issue_delegation" AS
3597 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
3598 "issue"."id" AS "issue_id",
3599 "delegation"."id",
3600 "delegation"."truster_id",
3601 "delegation"."trustee_id",
3602 "delegation"."scope"
3603 FROM "issue"
3604 JOIN "area"
3605 ON "area"."id" = "issue"."area_id"
3606 JOIN "delegation"
3607 ON "delegation"."unit_id" = "area"."unit_id"
3608 OR "delegation"."area_id" = "area"."id"
3609 OR "delegation"."issue_id" = "issue"."id"
3610 JOIN "member"
3611 ON "delegation"."truster_id" = "member"."id"
3612 JOIN "privilege"
3613 ON "area"."unit_id" = "privilege"."unit_id"
3614 AND "delegation"."truster_id" = "privilege"."member_id"
3615 WHERE "member"."active" AND "privilege"."voting_right"
3616 ORDER BY
3617 "issue"."id",
3618 "delegation"."truster_id",
3619 "delegation"."scope" DESC;
3621 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
3624 CREATE VIEW "member_count_view" AS
3625 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
3627 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
3630 CREATE VIEW "unit_member" AS
3631 SELECT
3632 "unit"."id" AS "unit_id",
3633 "member"."id" AS "member_id"
3634 FROM "privilege"
3635 JOIN "unit" ON "unit"."id" = "privilege"."unit_id"
3636 JOIN "member" ON "member"."id" = "privilege"."member_id"
3637 WHERE "privilege"."voting_right" AND "member"."active";
3639 COMMENT ON VIEW "unit_member" IS 'Active members with voting right in a unit';
3642 CREATE VIEW "unit_member_count" AS
3643 SELECT
3644 "unit"."id" AS "unit_id",
3645 count("unit_member"."member_id") AS "member_count"
3646 FROM "unit" LEFT JOIN "unit_member"
3647 ON "unit"."id" = "unit_member"."unit_id"
3648 GROUP BY "unit"."id";
3650 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
3653 CREATE VIEW "opening_draft" AS
3654 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3655 ORDER BY "initiative_id", "id";
3657 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
3660 CREATE VIEW "current_draft" AS
3661 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3662 ORDER BY "initiative_id", "id" DESC;
3664 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
3667 CREATE VIEW "critical_opinion" AS
3668 SELECT * FROM "opinion"
3669 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
3670 OR ("degree" = -2 AND "fulfilled" = TRUE);
3672 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
3675 CREATE VIEW "issue_supporter_in_admission_state" AS
3676 SELECT
3677 "area"."unit_id",
3678 "issue"."area_id",
3679 "issue"."id" AS "issue_id",
3680 "supporter"."member_id",
3681 "direct_interest_snapshot"."weight"
3682 FROM "issue"
3683 JOIN "area" ON "area"."id" = "issue"."area_id"
3684 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
3685 JOIN "direct_interest_snapshot"
3686 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3687 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3688 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
3689 WHERE "issue"."state" = 'admission'::"issue_state";
3691 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';
3694 CREATE VIEW "initiative_suggestion_order_calculation" AS
3695 SELECT
3696 "initiative"."id" AS "initiative_id",
3697 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
3698 FROM "initiative" JOIN "issue"
3699 ON "initiative"."issue_id" = "issue"."id"
3700 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
3701 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
3703 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
3705 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';
3708 CREATE VIEW "individual_suggestion_ranking" AS
3709 SELECT
3710 "opinion"."initiative_id",
3711 "opinion"."member_id",
3712 "direct_interest_snapshot"."weight",
3713 CASE WHEN
3714 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
3715 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
3716 THEN 1 ELSE
3717 CASE WHEN
3718 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
3719 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
3720 THEN 2 ELSE
3721 CASE WHEN
3722 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
3723 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
3724 THEN 3 ELSE 4 END
3725 END
3726 END AS "preference",
3727 "opinion"."suggestion_id"
3728 FROM "opinion"
3729 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
3730 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3731 JOIN "direct_interest_snapshot"
3732 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3733 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3734 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
3736 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
3739 CREATE VIEW "battle_participant" AS
3740 SELECT "initiative"."id", "initiative"."issue_id"
3741 FROM "issue" JOIN "initiative"
3742 ON "issue"."id" = "initiative"."issue_id"
3743 WHERE "initiative"."admitted"
3744 UNION ALL
3745 SELECT NULL, "id" AS "issue_id"
3746 FROM "issue";
3748 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
3751 CREATE VIEW "battle_view" AS
3752 SELECT
3753 "issue"."id" AS "issue_id",
3754 "winning_initiative"."id" AS "winning_initiative_id",
3755 "losing_initiative"."id" AS "losing_initiative_id",
3756 sum(
3757 CASE WHEN
3758 coalesce("better_vote"."grade", 0) >
3759 coalesce("worse_vote"."grade", 0)
3760 THEN "direct_voter"."weight" ELSE 0 END
3761 ) AS "count"
3762 FROM "issue"
3763 LEFT JOIN "direct_voter"
3764 ON "issue"."id" = "direct_voter"."issue_id"
3765 JOIN "battle_participant" AS "winning_initiative"
3766 ON "issue"."id" = "winning_initiative"."issue_id"
3767 JOIN "battle_participant" AS "losing_initiative"
3768 ON "issue"."id" = "losing_initiative"."issue_id"
3769 LEFT JOIN "vote" AS "better_vote"
3770 ON "direct_voter"."member_id" = "better_vote"."member_id"
3771 AND "winning_initiative"."id" = "better_vote"."initiative_id"
3772 LEFT JOIN "vote" AS "worse_vote"
3773 ON "direct_voter"."member_id" = "worse_vote"."member_id"
3774 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
3775 WHERE "issue"."state" = 'voting'
3776 AND "issue"."phase_finished" NOTNULL
3777 AND (
3778 "winning_initiative"."id" != "losing_initiative"."id" OR
3779 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
3780 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
3781 GROUP BY
3782 "issue"."id",
3783 "winning_initiative"."id",
3784 "losing_initiative"."id";
3786 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';
3789 CREATE VIEW "expired_session" AS
3790 SELECT * FROM "session" WHERE now() > "expiry";
3792 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
3793 DELETE FROM "session" WHERE "id" = OLD."id";
3795 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
3796 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
3799 CREATE VIEW "expired_token" AS
3800 SELECT * FROM "token" WHERE now() > "expiry" AND NOT (
3801 "token_type" = 'authorization' AND "used" AND EXISTS (
3802 SELECT NULL FROM "token" AS "other"
3803 WHERE "other"."authorization_token_id" = "token"."id" ) );
3805 CREATE RULE "delete" AS ON DELETE TO "expired_token" DO INSTEAD
3806 DELETE FROM "token" WHERE "id" = OLD."id";
3808 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';
3811 CREATE VIEW "unused_snapshot" AS
3812 SELECT "snapshot".* FROM "snapshot"
3813 LEFT JOIN "issue"
3814 ON "snapshot"."id" = "issue"."latest_snapshot_id"
3815 OR "snapshot"."id" = "issue"."admission_snapshot_id"
3816 OR "snapshot"."id" = "issue"."half_freeze_snapshot_id"
3817 OR "snapshot"."id" = "issue"."full_freeze_snapshot_id"
3818 WHERE "issue"."id" ISNULL;
3820 CREATE RULE "delete" AS ON DELETE TO "unused_snapshot" DO INSTEAD
3821 DELETE FROM "snapshot" WHERE "id" = OLD."id";
3823 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)';
3826 CREATE VIEW "open_issue" AS
3827 SELECT * FROM "issue" WHERE "closed" ISNULL;
3829 COMMENT ON VIEW "open_issue" IS 'All open issues';
3832 CREATE VIEW "member_contingent" AS
3833 SELECT
3834 "member"."id" AS "member_id",
3835 "contingent"."polling",
3836 "contingent"."time_frame",
3837 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
3839 SELECT count(1) FROM "draft"
3840 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3841 WHERE "draft"."author_id" = "member"."id"
3842 AND "initiative"."polling" = "contingent"."polling"
3843 AND "draft"."created" > now() - "contingent"."time_frame"
3844 ) + (
3845 SELECT count(1) FROM "suggestion"
3846 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
3847 WHERE "suggestion"."author_id" = "member"."id"
3848 AND "contingent"."polling" = FALSE
3849 AND "suggestion"."created" > now() - "contingent"."time_frame"
3851 ELSE NULL END AS "text_entry_count",
3852 "contingent"."text_entry_limit",
3853 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
3854 SELECT count(1) FROM "opening_draft" AS "draft"
3855 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3856 WHERE "draft"."author_id" = "member"."id"
3857 AND "initiative"."polling" = "contingent"."polling"
3858 AND "draft"."created" > now() - "contingent"."time_frame"
3859 ) ELSE NULL END AS "initiative_count",
3860 "contingent"."initiative_limit"
3861 FROM "member" CROSS JOIN "contingent";
3863 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
3865 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
3866 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
3869 CREATE VIEW "member_contingent_left" AS
3870 SELECT
3871 "member_id",
3872 "polling",
3873 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
3874 max("initiative_limit" - "initiative_count") AS "initiatives_left"
3875 FROM "member_contingent" GROUP BY "member_id", "polling";
3877 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.';
3880 CREATE VIEW "event_for_notification" AS
3881 SELECT
3882 "member"."id" AS "recipient_id",
3883 "event".*
3884 FROM "member" CROSS JOIN "event"
3885 JOIN "issue" ON "issue"."id" = "event"."issue_id"
3886 JOIN "area" ON "area"."id" = "issue"."area_id"
3887 LEFT JOIN "privilege" ON
3888 "privilege"."member_id" = "member"."id" AND
3889 "privilege"."unit_id" = "area"."unit_id" AND
3890 "privilege"."voting_right" = TRUE
3891 LEFT JOIN "subscription" ON
3892 "subscription"."member_id" = "member"."id" AND
3893 "subscription"."unit_id" = "area"."unit_id"
3894 LEFT JOIN "ignored_area" ON
3895 "ignored_area"."member_id" = "member"."id" AND
3896 "ignored_area"."area_id" = "issue"."area_id"
3897 LEFT JOIN "interest" ON
3898 "interest"."member_id" = "member"."id" AND
3899 "interest"."issue_id" = "event"."issue_id"
3900 LEFT JOIN "supporter" ON
3901 "supporter"."member_id" = "member"."id" AND
3902 "supporter"."initiative_id" = "event"."initiative_id"
3903 WHERE ("privilege"."member_id" NOTNULL OR "subscription"."member_id" NOTNULL)
3904 AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
3905 AND (
3906 "event"."event" = 'issue_state_changed'::"event_type" OR
3907 ( "event"."event" = 'initiative_revoked'::"event_type" AND
3908 "supporter"."member_id" NOTNULL ) );
3910 COMMENT ON VIEW "event_for_notification" IS 'Entries of the "event" table which are of interest for a particular notification mail recipient';
3912 COMMENT ON COLUMN "event_for_notification"."recipient_id" IS 'member_id of the recipient of a notification mail';
3915 CREATE VIEW "updated_initiative" AS
3916 SELECT
3917 "supporter"."member_id" AS "recipient_id",
3918 FALSE AS "featured",
3919 "supporter"."initiative_id"
3920 FROM "supporter"
3921 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
3922 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3923 LEFT JOIN "notification_initiative_sent" AS "sent" ON
3924 "sent"."member_id" = "supporter"."member_id" AND
3925 "sent"."initiative_id" = "supporter"."initiative_id"
3926 LEFT JOIN "ignored_initiative" ON
3927 "ignored_initiative"."member_id" = "supporter"."member_id" AND
3928 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
3929 WHERE "issue"."state" IN ('admission', 'discussion')
3930 AND "initiative"."revoked" ISNULL
3931 AND "ignored_initiative"."member_id" ISNULL
3932 AND (
3933 EXISTS (
3934 SELECT NULL FROM "draft"
3935 LEFT JOIN "ignored_member" ON
3936 "ignored_member"."member_id" = "supporter"."member_id" AND
3937 "ignored_member"."other_member_id" = "draft"."author_id"
3938 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
3939 AND "draft"."id" > "supporter"."draft_id"
3940 AND "ignored_member"."member_id" ISNULL
3941 ) OR EXISTS (
3942 SELECT NULL FROM "suggestion"
3943 LEFT JOIN "opinion" ON
3944 "opinion"."member_id" = "supporter"."member_id" AND
3945 "opinion"."suggestion_id" = "suggestion"."id"
3946 LEFT JOIN "ignored_member" ON
3947 "ignored_member"."member_id" = "supporter"."member_id" AND
3948 "ignored_member"."other_member_id" = "suggestion"."author_id"
3949 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
3950 AND "opinion"."member_id" ISNULL
3951 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
3952 AND "ignored_member"."member_id" ISNULL
3954 );
3956 COMMENT ON VIEW "updated_initiative" IS 'Helper view for view "updated_or_featured_initiative"';
3959 CREATE FUNCTION "featured_initiative"
3960 ( "recipient_id_p" "member"."id"%TYPE,
3961 "area_id_p" "area"."id"%TYPE )
3962 RETURNS SETOF "initiative"."id"%TYPE
3963 LANGUAGE 'plpgsql' STABLE AS $$
3964 DECLARE
3965 "counter_v" "member"."notification_counter"%TYPE;
3966 "sample_size_v" "member"."notification_sample_size"%TYPE;
3967 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
3968 "match_v" BOOLEAN;
3969 "member_id_v" "member"."id"%TYPE;
3970 "seed_v" TEXT;
3971 "initiative_id_v" "initiative"."id"%TYPE;
3972 BEGIN
3973 SELECT "notification_counter", "notification_sample_size"
3974 INTO "counter_v", "sample_size_v"
3975 FROM "member" WHERE "id" = "recipient_id_p";
3976 IF COALESCE("sample_size_v" <= 0, TRUE) THEN
3977 RETURN;
3978 END IF;
3979 "initiative_id_ary" := '{}';
3980 LOOP
3981 "match_v" := FALSE;
3982 FOR "member_id_v", "seed_v" IN
3983 SELECT * FROM (
3984 SELECT DISTINCT
3985 "supporter"."member_id",
3986 md5(
3987 "recipient_id_p" || '-' ||
3988 "counter_v" || '-' ||
3989 "area_id_p" || '-' ||
3990 "supporter"."member_id"
3991 ) AS "seed"
3992 FROM "supporter"
3993 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
3994 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3995 WHERE "supporter"."member_id" != "recipient_id_p"
3996 AND "issue"."area_id" = "area_id_p"
3997 AND "issue"."state" IN ('admission', 'discussion', 'verification')
3998 ) AS "subquery"
3999 ORDER BY "seed"
4000 LOOP
4001 SELECT "initiative"."id" INTO "initiative_id_v"
4002 FROM "initiative"
4003 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4004 JOIN "area" ON "area"."id" = "issue"."area_id"
4005 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
4006 LEFT JOIN "supporter" AS "self_support" ON
4007 "self_support"."initiative_id" = "initiative"."id" AND
4008 "self_support"."member_id" = "recipient_id_p"
4009 LEFT JOIN "privilege" ON
4010 "privilege"."member_id" = "recipient_id_p" AND
4011 "privilege"."unit_id" = "area"."unit_id" AND
4012 "privilege"."voting_right" = TRUE
4013 LEFT JOIN "subscription" ON
4014 "subscription"."member_id" = "recipient_id_p" AND
4015 "subscription"."unit_id" = "area"."unit_id"
4016 LEFT JOIN "ignored_initiative" ON
4017 "ignored_initiative"."member_id" = "recipient_id_p" AND
4018 "ignored_initiative"."initiative_id" = "initiative"."id"
4019 WHERE "supporter"."member_id" = "member_id_v"
4020 AND "issue"."area_id" = "area_id_p"
4021 AND "issue"."state" IN ('admission', 'discussion', 'verification')
4022 AND "initiative"."revoked" ISNULL
4023 AND "self_support"."member_id" ISNULL
4024 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
4025 AND (
4026 "privilege"."member_id" NOTNULL OR
4027 "subscription"."member_id" NOTNULL )
4028 AND "ignored_initiative"."member_id" ISNULL
4029 AND NOT EXISTS (
4030 SELECT NULL FROM "draft"
4031 JOIN "ignored_member" ON
4032 "ignored_member"."member_id" = "recipient_id_p" AND
4033 "ignored_member"."other_member_id" = "draft"."author_id"
4034 WHERE "draft"."initiative_id" = "initiative"."id"
4036 ORDER BY md5("seed_v" || '-' || "initiative"."id")
4037 LIMIT 1;
4038 IF FOUND THEN
4039 "match_v" := TRUE;
4040 RETURN NEXT "initiative_id_v";
4041 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
4042 RETURN;
4043 END IF;
4044 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
4045 END IF;
4046 END LOOP;
4047 EXIT WHEN NOT "match_v";
4048 END LOOP;
4049 RETURN;
4050 END;
4051 $$;
4053 COMMENT ON FUNCTION "featured_initiative"
4054 ( "recipient_id_p" "member"."id"%TYPE,
4055 "area_id_p" "area"."id"%TYPE )
4056 IS 'Helper function for view "updated_or_featured_initiative"';
4059 CREATE VIEW "updated_or_featured_initiative" AS
4060 SELECT
4061 "subquery".*,
4062 NOT EXISTS (
4063 SELECT NULL FROM "initiative" AS "better_initiative"
4064 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
4065 AND
4066 ( COALESCE("better_initiative"."supporter_count", -1),
4067 -"better_initiative"."id" ) >
4068 ( COALESCE("initiative"."supporter_count", -1),
4069 -"initiative"."id" )
4070 ) AS "leading"
4071 FROM (
4072 SELECT * FROM "updated_initiative"
4073 UNION ALL
4074 SELECT
4075 "member"."id" AS "recipient_id",
4076 TRUE AS "featured",
4077 "featured_initiative_id" AS "initiative_id"
4078 FROM "member" CROSS JOIN "area"
4079 CROSS JOIN LATERAL
4080 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
4081 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
4082 ) AS "subquery"
4083 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
4085 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';
4087 COMMENT ON COLUMN "updated_or_featured_initiative"."recipient_id" IS '"id" of the member who receives the notification mail';
4088 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")';
4089 COMMENT ON COLUMN "updated_or_featured_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4090 COMMENT ON COLUMN "updated_or_featured_initiative"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4093 CREATE VIEW "leading_complement_initiative" AS
4094 SELECT * FROM (
4095 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
4096 "uf_initiative"."recipient_id",
4097 FALSE AS "featured",
4098 "uf_initiative"."initiative_id",
4099 TRUE AS "leading"
4100 FROM "updated_or_featured_initiative" AS "uf_initiative"
4101 JOIN "initiative" AS "uf_initiative_full" ON
4102 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
4103 JOIN "initiative" ON
4104 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
4105 WHERE "initiative"."revoked" ISNULL
4106 ORDER BY
4107 "uf_initiative"."recipient_id",
4108 "initiative"."issue_id",
4109 "initiative"."supporter_count" DESC,
4110 "initiative"."id"
4111 ) AS "subquery"
4112 WHERE NOT EXISTS (
4113 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
4114 WHERE "other"."recipient_id" = "subquery"."recipient_id"
4115 AND "other"."initiative_id" = "subquery"."initiative_id"
4116 );
4118 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';
4119 COMMENT ON COLUMN "leading_complement_initiative"."featured" IS 'Always FALSE in this view';
4120 COMMENT ON COLUMN "leading_complement_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4121 COMMENT ON COLUMN "leading_complement_initiative"."leading" IS 'Always TRUE in this view';
4124 CREATE VIEW "unfiltered_initiative_for_notification" AS
4125 SELECT
4126 "subquery".*,
4127 "supporter"."member_id" NOTNULL AS "supported",
4128 CASE WHEN "supporter"."member_id" NOTNULL THEN
4129 EXISTS (
4130 SELECT NULL FROM "draft"
4131 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4132 AND "draft"."id" > "supporter"."draft_id"
4134 ELSE
4135 EXISTS (
4136 SELECT NULL FROM "draft"
4137 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4138 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
4140 END AS "new_draft",
4141 CASE WHEN "supporter"."member_id" NOTNULL THEN
4142 ( SELECT count(1) FROM "suggestion"
4143 LEFT JOIN "opinion" ON
4144 "opinion"."member_id" = "supporter"."member_id" AND
4145 "opinion"."suggestion_id" = "suggestion"."id"
4146 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4147 AND "opinion"."member_id" ISNULL
4148 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4150 ELSE
4151 ( SELECT count(1) FROM "suggestion"
4152 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4153 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4155 END AS "new_suggestion_count"
4156 FROM (
4157 SELECT * FROM "updated_or_featured_initiative"
4158 UNION ALL
4159 SELECT * FROM "leading_complement_initiative"
4160 ) AS "subquery"
4161 LEFT JOIN "supporter" ON
4162 "supporter"."member_id" = "subquery"."recipient_id" AND
4163 "supporter"."initiative_id" = "subquery"."initiative_id"
4164 LEFT JOIN "notification_initiative_sent" AS "sent" ON
4165 "sent"."member_id" = "subquery"."recipient_id" AND
4166 "sent"."initiative_id" = "subquery"."initiative_id";
4168 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';
4170 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4171 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)';
4172 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")';
4175 CREATE VIEW "initiative_for_notification" AS
4176 SELECT "unfiltered1".*
4177 FROM "unfiltered_initiative_for_notification" "unfiltered1"
4178 JOIN "initiative" AS "initiative1" ON
4179 "initiative1"."id" = "unfiltered1"."initiative_id"
4180 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
4181 WHERE EXISTS (
4182 SELECT NULL
4183 FROM "unfiltered_initiative_for_notification" "unfiltered2"
4184 JOIN "initiative" AS "initiative2" ON
4185 "initiative2"."id" = "unfiltered2"."initiative_id"
4186 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
4187 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
4188 AND "issue1"."area_id" = "issue2"."area_id"
4189 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
4190 );
4192 COMMENT ON VIEW "initiative_for_notification" IS 'Initiatives to be included in a scheduled notification mail';
4194 COMMENT ON COLUMN "initiative_for_notification"."recipient_id" IS '"id" of the member who receives the notification mail';
4195 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")';
4196 COMMENT ON COLUMN "initiative_for_notification"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4197 COMMENT ON COLUMN "initiative_for_notification"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4198 COMMENT ON COLUMN "initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4199 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)';
4200 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")';
4203 CREATE VIEW "scheduled_notification_to_send" AS
4204 SELECT * FROM (
4205 SELECT
4206 "id" AS "recipient_id",
4207 now() - CASE WHEN "notification_dow" ISNULL THEN
4208 ( "notification_sent"::DATE + CASE
4209 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4210 THEN 0 ELSE 1 END
4211 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4212 ELSE
4213 ( "notification_sent"::DATE +
4214 ( 7 + "notification_dow" -
4215 EXTRACT(DOW FROM
4216 ( "notification_sent"::DATE + CASE
4217 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4218 THEN 0 ELSE 1 END
4219 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4220 )::INTEGER
4221 ) % 7 +
4222 CASE
4223 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4224 THEN 0 ELSE 1
4225 END
4226 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4227 END AS "pending"
4228 FROM (
4229 SELECT
4230 "id",
4231 COALESCE("notification_sent", "activated") AS "notification_sent",
4232 "notification_dow",
4233 "notification_hour"
4234 FROM "member_to_notify"
4235 WHERE "notification_hour" NOTNULL
4236 ) AS "subquery1"
4237 ) AS "subquery2"
4238 WHERE "pending" > '0'::INTERVAL;
4240 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
4242 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
4243 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
4246 CREATE VIEW "newsletter_to_send" AS
4247 SELECT
4248 "member"."id" AS "recipient_id",
4249 "newsletter"."id" AS "newsletter_id",
4250 "newsletter"."published"
4251 FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member"
4252 LEFT JOIN "privilege" ON
4253 "privilege"."member_id" = "member"."id" AND
4254 "privilege"."unit_id" = "newsletter"."unit_id" AND
4255 "privilege"."voting_right" = TRUE
4256 LEFT JOIN "subscription" ON
4257 "subscription"."member_id" = "member"."id" AND
4258 "subscription"."unit_id" = "newsletter"."unit_id"
4259 WHERE "newsletter"."published" <= now()
4260 AND "newsletter"."sent" ISNULL
4261 AND (
4262 "member"."disable_notifications" = FALSE OR
4263 "newsletter"."include_all_members" = TRUE )
4264 AND (
4265 "newsletter"."unit_id" ISNULL OR
4266 "privilege"."member_id" NOTNULL OR
4267 "subscription"."member_id" NOTNULL );
4269 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
4271 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
4275 ------------------------------------------------------
4276 -- Row set returning function for delegation chains --
4277 ------------------------------------------------------
4280 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
4281 ('first', 'intermediate', 'last', 'repetition');
4283 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
4286 CREATE TYPE "delegation_chain_row" AS (
4287 "index" INT4,
4288 "member_id" INT4,
4289 "member_valid" BOOLEAN,
4290 "participation" BOOLEAN,
4291 "overridden" BOOLEAN,
4292 "scope_in" "delegation_scope",
4293 "scope_out" "delegation_scope",
4294 "disabled_out" BOOLEAN,
4295 "loop" "delegation_chain_loop_tag" );
4297 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
4299 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
4300 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest; for area and global delegation chains: always null';
4301 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
4302 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
4303 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
4304 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
4305 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
4308 CREATE FUNCTION "delegation_chain_for_closed_issue"
4309 ( "member_id_p" "member"."id"%TYPE,
4310 "issue_id_p" "issue"."id"%TYPE )
4311 RETURNS SETOF "delegation_chain_row"
4312 LANGUAGE 'plpgsql' STABLE AS $$
4313 DECLARE
4314 "output_row" "delegation_chain_row";
4315 "direct_voter_row" "direct_voter"%ROWTYPE;
4316 "delegating_voter_row" "delegating_voter"%ROWTYPE;
4317 BEGIN
4318 "output_row"."index" := 0;
4319 "output_row"."member_id" := "member_id_p";
4320 "output_row"."member_valid" := TRUE;
4321 "output_row"."participation" := FALSE;
4322 "output_row"."overridden" := FALSE;
4323 "output_row"."disabled_out" := FALSE;
4324 LOOP
4325 SELECT INTO "direct_voter_row" * FROM "direct_voter"
4326 WHERE "issue_id" = "issue_id_p"
4327 AND "member_id" = "output_row"."member_id";
4328 IF "direct_voter_row"."member_id" NOTNULL THEN
4329 "output_row"."participation" := TRUE;
4330 "output_row"."scope_out" := NULL;
4331 "output_row"."disabled_out" := NULL;
4332 RETURN NEXT "output_row";
4333 RETURN;
4334 END IF;
4335 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
4336 WHERE "issue_id" = "issue_id_p"
4337 AND "member_id" = "output_row"."member_id";
4338 IF "delegating_voter_row"."member_id" ISNULL THEN
4339 RETURN;
4340 END IF;
4341 "output_row"."scope_out" := "delegating_voter_row"."scope";
4342 RETURN NEXT "output_row";
4343 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
4344 "output_row"."scope_in" := "output_row"."scope_out";
4345 END LOOP;
4346 END;
4347 $$;
4349 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
4350 ( "member"."id"%TYPE,
4351 "member"."id"%TYPE )
4352 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
4355 CREATE FUNCTION "delegation_chain"
4356 ( "member_id_p" "member"."id"%TYPE,
4357 "unit_id_p" "unit"."id"%TYPE,
4358 "area_id_p" "area"."id"%TYPE,
4359 "issue_id_p" "issue"."id"%TYPE,
4360 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4361 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4362 RETURNS SETOF "delegation_chain_row"
4363 LANGUAGE 'plpgsql' STABLE AS $$
4364 DECLARE
4365 "scope_v" "delegation_scope";
4366 "unit_id_v" "unit"."id"%TYPE;
4367 "area_id_v" "area"."id"%TYPE;
4368 "issue_row" "issue"%ROWTYPE;
4369 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
4370 "loop_member_id_v" "member"."id"%TYPE;
4371 "output_row" "delegation_chain_row";
4372 "output_rows" "delegation_chain_row"[];
4373 "simulate_v" BOOLEAN;
4374 "simulate_here_v" BOOLEAN;
4375 "delegation_row" "delegation"%ROWTYPE;
4376 "row_count" INT4;
4377 "i" INT4;
4378 "loop_v" BOOLEAN;
4379 BEGIN
4380 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
4381 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
4382 END IF;
4383 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
4384 "simulate_v" := TRUE;
4385 ELSE
4386 "simulate_v" := FALSE;
4387 END IF;
4388 IF
4389 "unit_id_p" NOTNULL AND
4390 "area_id_p" ISNULL AND
4391 "issue_id_p" ISNULL
4392 THEN
4393 "scope_v" := 'unit';
4394 "unit_id_v" := "unit_id_p";
4395 ELSIF
4396 "unit_id_p" ISNULL AND
4397 "area_id_p" NOTNULL AND
4398 "issue_id_p" ISNULL
4399 THEN
4400 "scope_v" := 'area';
4401 "area_id_v" := "area_id_p";
4402 SELECT "unit_id" INTO "unit_id_v"
4403 FROM "area" WHERE "id" = "area_id_v";
4404 ELSIF
4405 "unit_id_p" ISNULL AND
4406 "area_id_p" ISNULL AND
4407 "issue_id_p" NOTNULL
4408 THEN
4409 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
4410 IF "issue_row"."id" ISNULL THEN
4411 RETURN;
4412 END IF;
4413 IF "issue_row"."closed" NOTNULL THEN
4414 IF "simulate_v" THEN
4415 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
4416 END IF;
4417 FOR "output_row" IN
4418 SELECT * FROM
4419 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
4420 LOOP
4421 RETURN NEXT "output_row";
4422 END LOOP;
4423 RETURN;
4424 END IF;
4425 "scope_v" := 'issue';
4426 SELECT "area_id" INTO "area_id_v"
4427 FROM "issue" WHERE "id" = "issue_id_p";
4428 SELECT "unit_id" INTO "unit_id_v"
4429 FROM "area" WHERE "id" = "area_id_v";
4430 ELSE
4431 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
4432 END IF;
4433 "visited_member_ids" := '{}';
4434 "loop_member_id_v" := NULL;
4435 "output_rows" := '{}';
4436 "output_row"."index" := 0;
4437 "output_row"."member_id" := "member_id_p";
4438 "output_row"."member_valid" := TRUE;
4439 "output_row"."participation" := FALSE;
4440 "output_row"."overridden" := FALSE;
4441 "output_row"."disabled_out" := FALSE;
4442 "output_row"."scope_out" := NULL;
4443 LOOP
4444 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
4445 "loop_member_id_v" := "output_row"."member_id";
4446 ELSE
4447 "visited_member_ids" :=
4448 "visited_member_ids" || "output_row"."member_id";
4449 END IF;
4450 IF "output_row"."participation" ISNULL THEN
4451 "output_row"."overridden" := NULL;
4452 ELSIF "output_row"."participation" THEN
4453 "output_row"."overridden" := TRUE;
4454 END IF;
4455 "output_row"."scope_in" := "output_row"."scope_out";
4456 "output_row"."member_valid" := EXISTS (
4457 SELECT NULL FROM "member" JOIN "privilege"
4458 ON "privilege"."member_id" = "member"."id"
4459 AND "privilege"."unit_id" = "unit_id_v"
4460 WHERE "id" = "output_row"."member_id"
4461 AND "member"."active" AND "privilege"."voting_right"
4462 );
4463 "simulate_here_v" := (
4464 "simulate_v" AND
4465 "output_row"."member_id" = "member_id_p"
4466 );
4467 "delegation_row" := ROW(NULL);
4468 IF "output_row"."member_valid" OR "simulate_here_v" THEN
4469 IF "scope_v" = 'unit' THEN
4470 IF NOT "simulate_here_v" THEN
4471 SELECT * INTO "delegation_row" FROM "delegation"
4472 WHERE "truster_id" = "output_row"."member_id"
4473 AND "unit_id" = "unit_id_v";
4474 END IF;
4475 ELSIF "scope_v" = 'area' THEN
4476 IF "simulate_here_v" THEN
4477 IF "simulate_trustee_id_p" ISNULL THEN
4478 SELECT * INTO "delegation_row" FROM "delegation"
4479 WHERE "truster_id" = "output_row"."member_id"
4480 AND "unit_id" = "unit_id_v";
4481 END IF;
4482 ELSE
4483 SELECT * INTO "delegation_row" FROM "delegation"
4484 WHERE "truster_id" = "output_row"."member_id"
4485 AND (
4486 "unit_id" = "unit_id_v" OR
4487 "area_id" = "area_id_v"
4489 ORDER BY "scope" DESC;
4490 END IF;
4491 ELSIF "scope_v" = 'issue' THEN
4492 IF "issue_row"."fully_frozen" ISNULL THEN
4493 "output_row"."participation" := EXISTS (
4494 SELECT NULL FROM "interest"
4495 WHERE "issue_id" = "issue_id_p"
4496 AND "member_id" = "output_row"."member_id"
4497 );
4498 ELSE
4499 IF "output_row"."member_id" = "member_id_p" THEN
4500 "output_row"."participation" := EXISTS (
4501 SELECT NULL FROM "direct_voter"
4502 WHERE "issue_id" = "issue_id_p"
4503 AND "member_id" = "output_row"."member_id"
4504 );
4505 ELSE
4506 "output_row"."participation" := NULL;
4507 END IF;
4508 END IF;
4509 IF "simulate_here_v" THEN
4510 IF "simulate_trustee_id_p" ISNULL THEN
4511 SELECT * INTO "delegation_row" FROM "delegation"
4512 WHERE "truster_id" = "output_row"."member_id"
4513 AND (
4514 "unit_id" = "unit_id_v" OR
4515 "area_id" = "area_id_v"
4517 ORDER BY "scope" DESC;
4518 END IF;
4519 ELSE
4520 SELECT * INTO "delegation_row" FROM "delegation"
4521 WHERE "truster_id" = "output_row"."member_id"
4522 AND (
4523 "unit_id" = "unit_id_v" OR
4524 "area_id" = "area_id_v" OR
4525 "issue_id" = "issue_id_p"
4527 ORDER BY "scope" DESC;
4528 END IF;
4529 END IF;
4530 ELSE
4531 "output_row"."participation" := FALSE;
4532 END IF;
4533 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
4534 "output_row"."scope_out" := "scope_v";
4535 "output_rows" := "output_rows" || "output_row";
4536 "output_row"."member_id" := "simulate_trustee_id_p";
4537 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
4538 "output_row"."scope_out" := "delegation_row"."scope";
4539 "output_rows" := "output_rows" || "output_row";
4540 "output_row"."member_id" := "delegation_row"."trustee_id";
4541 ELSIF "delegation_row"."scope" NOTNULL THEN
4542 "output_row"."scope_out" := "delegation_row"."scope";
4543 "output_row"."disabled_out" := TRUE;
4544 "output_rows" := "output_rows" || "output_row";
4545 EXIT;
4546 ELSE
4547 "output_row"."scope_out" := NULL;
4548 "output_rows" := "output_rows" || "output_row";
4549 EXIT;
4550 END IF;
4551 EXIT WHEN "loop_member_id_v" NOTNULL;
4552 "output_row"."index" := "output_row"."index" + 1;
4553 END LOOP;
4554 "row_count" := array_upper("output_rows", 1);
4555 "i" := 1;
4556 "loop_v" := FALSE;
4557 LOOP
4558 "output_row" := "output_rows"["i"];
4559 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
4560 IF "loop_v" THEN
4561 IF "i" + 1 = "row_count" THEN
4562 "output_row"."loop" := 'last';
4563 ELSIF "i" = "row_count" THEN
4564 "output_row"."loop" := 'repetition';
4565 ELSE
4566 "output_row"."loop" := 'intermediate';
4567 END IF;
4568 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
4569 "output_row"."loop" := 'first';
4570 "loop_v" := TRUE;
4571 END IF;
4572 IF "scope_v" = 'unit' THEN
4573 "output_row"."participation" := NULL;
4574 END IF;
4575 RETURN NEXT "output_row";
4576 "i" := "i" + 1;
4577 END LOOP;
4578 RETURN;
4579 END;
4580 $$;
4582 COMMENT ON FUNCTION "delegation_chain"
4583 ( "member"."id"%TYPE,
4584 "unit"."id"%TYPE,
4585 "area"."id"%TYPE,
4586 "issue"."id"%TYPE,
4587 "member"."id"%TYPE,
4588 BOOLEAN )
4589 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
4593 ---------------------------------------------------------
4594 -- Single row returning function for delegation chains --
4595 ---------------------------------------------------------
4598 CREATE TYPE "delegation_info_loop_type" AS ENUM
4599 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
4601 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''';
4604 CREATE TYPE "delegation_info_type" AS (
4605 "own_participation" BOOLEAN,
4606 "own_delegation_scope" "delegation_scope",
4607 "first_trustee_id" INT4,
4608 "first_trustee_participation" BOOLEAN,
4609 "first_trustee_ellipsis" BOOLEAN,
4610 "other_trustee_id" INT4,
4611 "other_trustee_participation" BOOLEAN,
4612 "other_trustee_ellipsis" BOOLEAN,
4613 "delegation_loop" "delegation_info_loop_type",
4614 "participating_member_id" INT4 );
4616 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';
4618 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
4619 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
4620 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
4621 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
4622 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
4623 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
4624 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)';
4625 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
4626 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';
4627 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
4630 CREATE FUNCTION "delegation_info"
4631 ( "member_id_p" "member"."id"%TYPE,
4632 "unit_id_p" "unit"."id"%TYPE,
4633 "area_id_p" "area"."id"%TYPE,
4634 "issue_id_p" "issue"."id"%TYPE,
4635 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4636 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4637 RETURNS "delegation_info_type"
4638 LANGUAGE 'plpgsql' STABLE AS $$
4639 DECLARE
4640 "current_row" "delegation_chain_row";
4641 "result" "delegation_info_type";
4642 BEGIN
4643 "result"."own_participation" := FALSE;
4644 FOR "current_row" IN
4645 SELECT * FROM "delegation_chain"(
4646 "member_id_p",
4647 "unit_id_p", "area_id_p", "issue_id_p",
4648 "simulate_trustee_id_p", "simulate_default_p")
4649 LOOP
4650 IF
4651 "result"."participating_member_id" ISNULL AND
4652 "current_row"."participation"
4653 THEN
4654 "result"."participating_member_id" := "current_row"."member_id";
4655 END IF;
4656 IF "current_row"."member_id" = "member_id_p" THEN
4657 "result"."own_participation" := "current_row"."participation";
4658 "result"."own_delegation_scope" := "current_row"."scope_out";
4659 IF "current_row"."loop" = 'first' THEN
4660 "result"."delegation_loop" := 'own';
4661 END IF;
4662 ELSIF
4663 "current_row"."member_valid" AND
4664 ( "current_row"."loop" ISNULL OR
4665 "current_row"."loop" != 'repetition' )
4666 THEN
4667 IF "result"."first_trustee_id" ISNULL THEN
4668 "result"."first_trustee_id" := "current_row"."member_id";
4669 "result"."first_trustee_participation" := "current_row"."participation";
4670 "result"."first_trustee_ellipsis" := FALSE;
4671 IF "current_row"."loop" = 'first' THEN
4672 "result"."delegation_loop" := 'first';
4673 END IF;
4674 ELSIF "result"."other_trustee_id" ISNULL THEN
4675 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
4676 "result"."other_trustee_id" := "current_row"."member_id";
4677 "result"."other_trustee_participation" := TRUE;
4678 "result"."other_trustee_ellipsis" := FALSE;
4679 IF "current_row"."loop" = 'first' THEN
4680 "result"."delegation_loop" := 'other';
4681 END IF;
4682 ELSE
4683 "result"."first_trustee_ellipsis" := TRUE;
4684 IF "current_row"."loop" = 'first' THEN
4685 "result"."delegation_loop" := 'first_ellipsis';
4686 END IF;
4687 END IF;
4688 ELSE
4689 "result"."other_trustee_ellipsis" := TRUE;
4690 IF "current_row"."loop" = 'first' THEN
4691 "result"."delegation_loop" := 'other_ellipsis';
4692 END IF;
4693 END IF;
4694 END IF;
4695 END LOOP;
4696 RETURN "result";
4697 END;
4698 $$;
4700 COMMENT ON FUNCTION "delegation_info"
4701 ( "member"."id"%TYPE,
4702 "unit"."id"%TYPE,
4703 "area"."id"%TYPE,
4704 "issue"."id"%TYPE,
4705 "member"."id"%TYPE,
4706 BOOLEAN )
4707 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
4711 ------------------------
4712 -- Geospatial lookups --
4713 ------------------------
4715 /*
4716 CREATE FUNCTION "closed_initiatives_in_bounding_box"
4717 ( "bounding_box_p" EBOX,
4718 "limit_p" INT4 )
4719 RETURNS SETOF "initiative"
4720 LANGUAGE 'plpgsql' STABLE AS $$
4721 DECLARE
4722 "limit_v" INT4;
4723 "count_v" INT4;
4724 BEGIN
4725 "limit_v" := "limit_p" + 1;
4726 LOOP
4727 SELECT count(1) INTO "count_v"
4728 FROM "initiative"
4729 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4730 WHERE "issue"."closed" NOTNULL
4731 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4732 LIMIT "limit_v";
4733 IF "count_v" < "limit_v" THEN
4734 RETURN QUERY SELECT "initiative".*
4735 FROM (
4736 SELECT
4737 "initiative"."id" AS "initiative_id",
4738 "issue"."closed"
4739 FROM "initiative"
4740 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4741 WHERE "issue"."closed" NOTNULL
4742 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4743 ) AS "subquery"
4744 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4745 ORDER BY "subquery"."closed" DESC
4746 LIMIT "limit_p";
4747 RETURN;
4748 END IF;
4749 SELECT count(1) INTO "count_v"
4750 FROM (
4751 SELECT "initiative"."id" AS "initiative_id"
4752 FROM "initiative"
4753 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4754 WHERE "issue"."closed" NOTNULL
4755 ORDER BY "closed" DESC
4756 LIMIT "limit_v"
4757 ) AS "subquery"
4758 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4759 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4760 LIMIT "limit_p";
4761 IF "count_v" >= "limit_p" THEN
4762 RETURN QUERY SELECT "initiative".*
4763 FROM (
4764 SELECT
4765 "initiative"."id" AS "initiative_id",
4766 "issue"."closed"
4767 FROM "initiative"
4768 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4769 WHERE "issue"."closed" NOTNULL
4770 ORDER BY "closed" DESC
4771 LIMIT "limit_v"
4772 ) AS "subquery"
4773 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4774 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4775 ORDER BY "subquery"."closed" DESC
4776 LIMIT "limit_p";
4777 RETURN;
4778 END IF;
4779 "limit_v" := "limit_v" * 2;
4780 END LOOP;
4781 END;
4782 $$;
4784 COMMENT ON FUNCTION "closed_initiatives_in_bounding_box"
4785 ( EBOX, INT4 )
4786 IS 'TODO';
4787 */
4791 ---------------------------
4792 -- Transaction isolation --
4793 ---------------------------
4796 CREATE FUNCTION "require_transaction_isolation"()
4797 RETURNS VOID
4798 LANGUAGE 'plpgsql' VOLATILE AS $$
4799 BEGIN
4800 IF
4801 current_setting('transaction_isolation') NOT IN
4802 ('repeatable read', 'serializable')
4803 THEN
4804 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
4805 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
4806 END IF;
4807 RETURN;
4808 END;
4809 $$;
4811 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
4814 CREATE FUNCTION "dont_require_transaction_isolation"()
4815 RETURNS VOID
4816 LANGUAGE 'plpgsql' VOLATILE AS $$
4817 BEGIN
4818 IF
4819 current_setting('transaction_isolation') IN
4820 ('repeatable read', 'serializable')
4821 THEN
4822 RAISE WARNING 'Unneccessary transaction isolation level: %',
4823 current_setting('transaction_isolation');
4824 END IF;
4825 RETURN;
4826 END;
4827 $$;
4829 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
4833 -------------------------
4834 -- Notification system --
4835 -------------------------
4837 CREATE FUNCTION "get_initiatives_for_notification"
4838 ( "recipient_id_p" "member"."id"%TYPE )
4839 RETURNS SETOF "initiative_for_notification"
4840 LANGUAGE 'plpgsql' VOLATILE AS $$
4841 DECLARE
4842 "result_row" "initiative_for_notification"%ROWTYPE;
4843 "last_draft_id_v" "draft"."id"%TYPE;
4844 "last_suggestion_id_v" "suggestion"."id"%TYPE;
4845 BEGIN
4846 PERFORM "require_transaction_isolation"();
4847 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
4848 FOR "result_row" IN
4849 SELECT * FROM "initiative_for_notification"
4850 WHERE "recipient_id" = "recipient_id_p"
4851 LOOP
4852 SELECT "id" INTO "last_draft_id_v" FROM "draft"
4853 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
4854 ORDER BY "id" DESC LIMIT 1;
4855 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
4856 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
4857 ORDER BY "id" DESC LIMIT 1;
4858 INSERT INTO "notification_initiative_sent"
4859 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
4860 VALUES (
4861 "recipient_id_p",
4862 "result_row"."initiative_id",
4863 "last_draft_id_v",
4864 "last_suggestion_id_v" )
4865 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
4866 "last_draft_id" = "last_draft_id_v",
4867 "last_suggestion_id" = "last_suggestion_id_v";
4868 RETURN NEXT "result_row";
4869 END LOOP;
4870 DELETE FROM "notification_initiative_sent"
4871 USING "initiative", "issue"
4872 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
4873 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
4874 AND "issue"."id" = "initiative"."issue_id"
4875 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
4876 UPDATE "member" SET
4877 "notification_counter" = "notification_counter" + 1,
4878 "notification_sent" = now()
4879 WHERE "id" = "recipient_id_p";
4880 RETURN;
4881 END;
4882 $$;
4884 COMMENT ON FUNCTION "get_initiatives_for_notification"
4885 ( "member"."id"%TYPE )
4886 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';
4890 ------------------------------------------------------------------------
4891 -- Regular tasks, except calculcation of snapshots and voting results --
4892 ------------------------------------------------------------------------
4895 CREATE FUNCTION "check_activity"()
4896 RETURNS VOID
4897 LANGUAGE 'plpgsql' VOLATILE AS $$
4898 DECLARE
4899 "system_setting_row" "system_setting"%ROWTYPE;
4900 BEGIN
4901 PERFORM "dont_require_transaction_isolation"();
4902 SELECT * INTO "system_setting_row" FROM "system_setting";
4903 IF "system_setting_row"."member_ttl" NOTNULL THEN
4904 UPDATE "member" SET "active" = FALSE
4905 WHERE "active" = TRUE
4906 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
4907 END IF;
4908 RETURN;
4909 END;
4910 $$;
4912 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
4915 CREATE FUNCTION "calculate_member_counts"()
4916 RETURNS VOID
4917 LANGUAGE 'plpgsql' VOLATILE AS $$
4918 BEGIN
4919 PERFORM "require_transaction_isolation"();
4920 DELETE FROM "member_count";
4921 INSERT INTO "member_count" ("total_count")
4922 SELECT "total_count" FROM "member_count_view";
4923 UPDATE "unit" SET "member_count" = "view"."member_count"
4924 FROM "unit_member_count" AS "view"
4925 WHERE "view"."unit_id" = "unit"."id";
4926 RETURN;
4927 END;
4928 $$;
4930 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"';
4934 ------------------------------------
4935 -- Calculation of harmonic weight --
4936 ------------------------------------
4939 CREATE VIEW "remaining_harmonic_supporter_weight" AS
4940 SELECT
4941 "direct_interest_snapshot"."snapshot_id",
4942 "direct_interest_snapshot"."issue_id",
4943 "direct_interest_snapshot"."member_id",
4944 "direct_interest_snapshot"."weight" AS "weight_num",
4945 count("initiative"."id") AS "weight_den"
4946 FROM "issue"
4947 JOIN "direct_interest_snapshot"
4948 ON "issue"."latest_snapshot_id" = "direct_interest_snapshot"."snapshot_id"
4949 AND "issue"."id" = "direct_interest_snapshot"."issue_id"
4950 JOIN "initiative"
4951 ON "issue"."id" = "initiative"."issue_id"
4952 AND "initiative"."harmonic_weight" ISNULL
4953 JOIN "direct_supporter_snapshot"
4954 ON "issue"."latest_snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
4955 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
4956 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
4957 AND (
4958 "direct_supporter_snapshot"."satisfied" = TRUE OR
4959 coalesce("initiative"."admitted", FALSE) = FALSE
4961 GROUP BY
4962 "direct_interest_snapshot"."snapshot_id",
4963 "direct_interest_snapshot"."issue_id",
4964 "direct_interest_snapshot"."member_id",
4965 "direct_interest_snapshot"."weight";
4967 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
4970 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
4971 SELECT
4972 "initiative"."issue_id",
4973 "initiative"."id" AS "initiative_id",
4974 "initiative"."admitted",
4975 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
4976 "remaining_harmonic_supporter_weight"."weight_den"
4977 FROM "remaining_harmonic_supporter_weight"
4978 JOIN "initiative"
4979 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
4980 AND "initiative"."harmonic_weight" ISNULL
4981 JOIN "direct_supporter_snapshot"
4982 ON "remaining_harmonic_supporter_weight"."snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
4983 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
4984 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
4985 AND (
4986 "direct_supporter_snapshot"."satisfied" = TRUE OR
4987 coalesce("initiative"."admitted", FALSE) = FALSE
4989 GROUP BY
4990 "initiative"."issue_id",
4991 "initiative"."id",
4992 "initiative"."admitted",
4993 "remaining_harmonic_supporter_weight"."weight_den";
4995 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
4998 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
4999 SELECT
5000 "issue_id",
5001 "id" AS "initiative_id",
5002 "admitted",
5003 0 AS "weight_num",
5004 1 AS "weight_den"
5005 FROM "initiative"
5006 WHERE "harmonic_weight" ISNULL;
5008 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';
5011 CREATE FUNCTION "set_harmonic_initiative_weights"
5012 ( "issue_id_p" "issue"."id"%TYPE )
5013 RETURNS VOID
5014 LANGUAGE 'plpgsql' VOLATILE AS $$
5015 DECLARE
5016 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
5017 "i" INT4;
5018 "count_v" INT4;
5019 "summand_v" FLOAT;
5020 "id_ary" INT4[];
5021 "weight_ary" FLOAT[];
5022 "min_weight_v" FLOAT;
5023 BEGIN
5024 PERFORM "require_transaction_isolation"();
5025 UPDATE "initiative" SET "harmonic_weight" = NULL
5026 WHERE "issue_id" = "issue_id_p";
5027 LOOP
5028 "min_weight_v" := NULL;
5029 "i" := 0;
5030 "count_v" := 0;
5031 FOR "weight_row" IN
5032 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
5033 WHERE "issue_id" = "issue_id_p"
5034 AND (
5035 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
5036 SELECT NULL FROM "initiative"
5037 WHERE "issue_id" = "issue_id_p"
5038 AND "harmonic_weight" ISNULL
5039 AND coalesce("admitted", FALSE) = FALSE
5042 UNION ALL -- needed for corner cases
5043 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
5044 WHERE "issue_id" = "issue_id_p"
5045 AND (
5046 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
5047 SELECT NULL FROM "initiative"
5048 WHERE "issue_id" = "issue_id_p"
5049 AND "harmonic_weight" ISNULL
5050 AND coalesce("admitted", FALSE) = FALSE
5053 ORDER BY "initiative_id" DESC, "weight_den" DESC
5054 -- NOTE: non-admitted initiatives placed first (at last positions),
5055 -- latest initiatives treated worse in case of tie
5056 LOOP
5057 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
5058 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
5059 "i" := "i" + 1;
5060 "count_v" := "i";
5061 "id_ary"["i"] := "weight_row"."initiative_id";
5062 "weight_ary"["i"] := "summand_v";
5063 ELSE
5064 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
5065 END IF;
5066 END LOOP;
5067 EXIT WHEN "count_v" = 0;
5068 "i" := 1;
5069 LOOP
5070 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
5071 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
5072 "min_weight_v" := "weight_ary"["i"];
5073 END IF;
5074 "i" := "i" + 1;
5075 EXIT WHEN "i" > "count_v";
5076 END LOOP;
5077 "i" := 1;
5078 LOOP
5079 IF "weight_ary"["i"] = "min_weight_v" THEN
5080 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
5081 WHERE "id" = "id_ary"["i"];
5082 EXIT;
5083 END IF;
5084 "i" := "i" + 1;
5085 END LOOP;
5086 END LOOP;
5087 UPDATE "initiative" SET "harmonic_weight" = 0
5088 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
5089 END;
5090 $$;
5092 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
5093 ( "issue"."id"%TYPE )
5094 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
5098 ------------------------------
5099 -- Calculation of snapshots --
5100 ------------------------------
5103 CREATE FUNCTION "weight_of_added_delegations_for_snapshot"
5104 ( "snapshot_id_p" "snapshot"."id"%TYPE,
5105 "issue_id_p" "issue"."id"%TYPE,
5106 "member_id_p" "member"."id"%TYPE,
5107 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
5108 RETURNS "direct_interest_snapshot"."weight"%TYPE
5109 LANGUAGE 'plpgsql' VOLATILE AS $$
5110 DECLARE
5111 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5112 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
5113 "weight_v" INT4;
5114 "sub_weight_v" INT4;
5115 BEGIN
5116 PERFORM "require_transaction_isolation"();
5117 "weight_v" := 0;
5118 FOR "issue_delegation_row" IN
5119 SELECT * FROM "issue_delegation"
5120 WHERE "trustee_id" = "member_id_p"
5121 AND "issue_id" = "issue_id_p"
5122 LOOP
5123 IF NOT EXISTS (
5124 SELECT NULL FROM "direct_interest_snapshot"
5125 WHERE "snapshot_id" = "snapshot_id_p"
5126 AND "issue_id" = "issue_id_p"
5127 AND "member_id" = "issue_delegation_row"."truster_id"
5128 ) AND NOT EXISTS (
5129 SELECT NULL FROM "delegating_interest_snapshot"
5130 WHERE "snapshot_id" = "snapshot_id_p"
5131 AND "issue_id" = "issue_id_p"
5132 AND "member_id" = "issue_delegation_row"."truster_id"
5133 ) THEN
5134 "delegate_member_ids_v" :=
5135 "member_id_p" || "delegate_member_ids_p";
5136 INSERT INTO "delegating_interest_snapshot" (
5137 "snapshot_id",
5138 "issue_id",
5139 "member_id",
5140 "scope",
5141 "delegate_member_ids"
5142 ) VALUES (
5143 "snapshot_id_p",
5144 "issue_id_p",
5145 "issue_delegation_row"."truster_id",
5146 "issue_delegation_row"."scope",
5147 "delegate_member_ids_v"
5148 );
5149 "sub_weight_v" := 1 +
5150 "weight_of_added_delegations_for_snapshot"(
5151 "snapshot_id_p",
5152 "issue_id_p",
5153 "issue_delegation_row"."truster_id",
5154 "delegate_member_ids_v"
5155 );
5156 UPDATE "delegating_interest_snapshot"
5157 SET "weight" = "sub_weight_v"
5158 WHERE "snapshot_id" = "snapshot_id_p"
5159 AND "issue_id" = "issue_id_p"
5160 AND "member_id" = "issue_delegation_row"."truster_id";
5161 "weight_v" := "weight_v" + "sub_weight_v";
5162 END IF;
5163 END LOOP;
5164 RETURN "weight_v";
5165 END;
5166 $$;
5168 COMMENT ON FUNCTION "weight_of_added_delegations_for_snapshot"
5169 ( "snapshot"."id"%TYPE,
5170 "issue"."id"%TYPE,
5171 "member"."id"%TYPE,
5172 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
5173 IS 'Helper function for "fill_snapshot" function';
5176 CREATE FUNCTION "take_snapshot"
5177 ( "issue_id_p" "issue"."id"%TYPE,
5178 "area_id_p" "area"."id"%TYPE = NULL )
5179 RETURNS "snapshot"."id"%TYPE
5180 LANGUAGE 'plpgsql' VOLATILE AS $$
5181 DECLARE
5182 "area_id_v" "area"."id"%TYPE;
5183 "unit_id_v" "unit"."id"%TYPE;
5184 "snapshot_id_v" "snapshot"."id"%TYPE;
5185 "issue_id_v" "issue"."id"%TYPE;
5186 "member_id_v" "member"."id"%TYPE;
5187 BEGIN
5188 IF "issue_id_p" NOTNULL AND "area_id_p" NOTNULL THEN
5189 RAISE EXCEPTION 'One of "issue_id_p" and "area_id_p" must be NULL';
5190 END IF;
5191 PERFORM "require_transaction_isolation"();
5192 IF "issue_id_p" ISNULL THEN
5193 "area_id_v" := "area_id_p";
5194 ELSE
5195 SELECT "area_id" INTO "area_id_v"
5196 FROM "issue" WHERE "id" = "issue_id_p";
5197 END IF;
5198 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5199 INSERT INTO "snapshot" ("area_id", "issue_id")
5200 VALUES ("area_id_v", "issue_id_p")
5201 RETURNING "id" INTO "snapshot_id_v";
5202 INSERT INTO "snapshot_population" ("snapshot_id", "member_id")
5203 SELECT "snapshot_id_v", "member_id"
5204 FROM "unit_member" WHERE "unit_id" = "unit_id_v";
5205 UPDATE "snapshot" SET
5206 "population" = (
5207 SELECT count(1) FROM "snapshot_population"
5208 WHERE "snapshot_id" = "snapshot_id_v"
5209 ) WHERE "id" = "snapshot_id_v";
5210 FOR "issue_id_v" IN
5211 SELECT "id" FROM "issue"
5212 WHERE CASE WHEN "issue_id_p" ISNULL THEN
5213 "area_id" = "area_id_p" AND
5214 "state" = 'admission'
5215 ELSE
5216 "id" = "issue_id_p"
5217 END
5218 LOOP
5219 INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id")
5220 VALUES ("snapshot_id_v", "issue_id_v");
5221 INSERT INTO "direct_interest_snapshot"
5222 ("snapshot_id", "issue_id", "member_id")
5223 SELECT
5224 "snapshot_id_v" AS "snapshot_id",
5225 "issue_id_v" AS "issue_id",
5226 "member"."id" AS "member_id"
5227 FROM "issue"
5228 JOIN "area" ON "issue"."area_id" = "area"."id"
5229 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
5230 JOIN "member" ON "interest"."member_id" = "member"."id"
5231 JOIN "privilege"
5232 ON "privilege"."unit_id" = "area"."unit_id"
5233 AND "privilege"."member_id" = "member"."id"
5234 WHERE "issue"."id" = "issue_id_v"
5235 AND "member"."active" AND "privilege"."voting_right";
5236 FOR "member_id_v" IN
5237 SELECT "member_id" FROM "direct_interest_snapshot"
5238 WHERE "snapshot_id" = "snapshot_id_v"
5239 AND "issue_id" = "issue_id_v"
5240 LOOP
5241 UPDATE "direct_interest_snapshot" SET
5242 "weight" = 1 +
5243 "weight_of_added_delegations_for_snapshot"(
5244 "snapshot_id_v",
5245 "issue_id_v",
5246 "member_id_v",
5247 '{}'
5249 WHERE "snapshot_id" = "snapshot_id_v"
5250 AND "issue_id" = "issue_id_v"
5251 AND "member_id" = "member_id_v";
5252 END LOOP;
5253 INSERT INTO "direct_supporter_snapshot"
5254 ( "snapshot_id", "issue_id", "initiative_id", "member_id",
5255 "draft_id", "informed", "satisfied" )
5256 SELECT
5257 "snapshot_id_v" AS "snapshot_id",
5258 "issue_id_v" AS "issue_id",
5259 "initiative"."id" AS "initiative_id",
5260 "supporter"."member_id" AS "member_id",
5261 "supporter"."draft_id" AS "draft_id",
5262 "supporter"."draft_id" = "current_draft"."id" AS "informed",
5263 NOT EXISTS (
5264 SELECT NULL FROM "critical_opinion"
5265 WHERE "initiative_id" = "initiative"."id"
5266 AND "member_id" = "supporter"."member_id"
5267 ) AS "satisfied"
5268 FROM "initiative"
5269 JOIN "supporter"
5270 ON "supporter"."initiative_id" = "initiative"."id"
5271 JOIN "current_draft"
5272 ON "initiative"."id" = "current_draft"."initiative_id"
5273 JOIN "direct_interest_snapshot"
5274 ON "snapshot_id_v" = "direct_interest_snapshot"."snapshot_id"
5275 AND "supporter"."member_id" = "direct_interest_snapshot"."member_id"
5276 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
5277 WHERE "initiative"."issue_id" = "issue_id_v";
5278 DELETE FROM "temporary_suggestion_counts";
5279 INSERT INTO "temporary_suggestion_counts"
5280 ( "id",
5281 "minus2_unfulfilled_count", "minus2_fulfilled_count",
5282 "minus1_unfulfilled_count", "minus1_fulfilled_count",
5283 "plus1_unfulfilled_count", "plus1_fulfilled_count",
5284 "plus2_unfulfilled_count", "plus2_fulfilled_count" )
5285 SELECT
5286 "suggestion"."id",
5287 ( SELECT coalesce(sum("di"."weight"), 0)
5288 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5289 ON "di"."snapshot_id" = "snapshot_id_v"
5290 AND "di"."issue_id" = "issue_id_v"
5291 AND "di"."member_id" = "opinion"."member_id"
5292 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5293 AND "opinion"."degree" = -2
5294 AND "opinion"."fulfilled" = FALSE
5295 ) AS "minus2_unfulfilled_count",
5296 ( SELECT coalesce(sum("di"."weight"), 0)
5297 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5298 ON "di"."snapshot_id" = "snapshot_id_v"
5299 AND "di"."issue_id" = "issue_id_v"
5300 AND "di"."member_id" = "opinion"."member_id"
5301 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5302 AND "opinion"."degree" = -2
5303 AND "opinion"."fulfilled" = TRUE
5304 ) AS "minus2_fulfilled_count",
5305 ( SELECT coalesce(sum("di"."weight"), 0)
5306 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5307 ON "di"."snapshot_id" = "snapshot_id_v"
5308 AND "di"."issue_id" = "issue_id_v"
5309 AND "di"."member_id" = "opinion"."member_id"
5310 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5311 AND "opinion"."degree" = -1
5312 AND "opinion"."fulfilled" = FALSE
5313 ) AS "minus1_unfulfilled_count",
5314 ( SELECT coalesce(sum("di"."weight"), 0)
5315 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5316 ON "di"."snapshot_id" = "snapshot_id_v"
5317 AND "di"."issue_id" = "issue_id_v"
5318 AND "di"."member_id" = "opinion"."member_id"
5319 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5320 AND "opinion"."degree" = -1
5321 AND "opinion"."fulfilled" = TRUE
5322 ) AS "minus1_fulfilled_count",
5323 ( SELECT coalesce(sum("di"."weight"), 0)
5324 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5325 ON "di"."snapshot_id" = "snapshot_id_v"
5326 AND "di"."issue_id" = "issue_id_v"
5327 AND "di"."member_id" = "opinion"."member_id"
5328 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5329 AND "opinion"."degree" = 1
5330 AND "opinion"."fulfilled" = FALSE
5331 ) AS "plus1_unfulfilled_count",
5332 ( SELECT coalesce(sum("di"."weight"), 0)
5333 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5334 ON "di"."snapshot_id" = "snapshot_id_v"
5335 AND "di"."issue_id" = "issue_id_v"
5336 AND "di"."member_id" = "opinion"."member_id"
5337 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5338 AND "opinion"."degree" = 1
5339 AND "opinion"."fulfilled" = TRUE
5340 ) AS "plus1_fulfilled_count",
5341 ( SELECT coalesce(sum("di"."weight"), 0)
5342 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5343 ON "di"."snapshot_id" = "snapshot_id_v"
5344 AND "di"."issue_id" = "issue_id_v"
5345 AND "di"."member_id" = "opinion"."member_id"
5346 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5347 AND "opinion"."degree" = 2
5348 AND "opinion"."fulfilled" = FALSE
5349 ) AS "plus2_unfulfilled_count",
5350 ( SELECT coalesce(sum("di"."weight"), 0)
5351 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5352 ON "di"."snapshot_id" = "snapshot_id_v"
5353 AND "di"."issue_id" = "issue_id_v"
5354 AND "di"."member_id" = "opinion"."member_id"
5355 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5356 AND "opinion"."degree" = 2
5357 AND "opinion"."fulfilled" = TRUE
5358 ) AS "plus2_fulfilled_count"
5359 FROM "suggestion" JOIN "initiative"
5360 ON "suggestion"."initiative_id" = "initiative"."id"
5361 WHERE "initiative"."issue_id" = "issue_id_v";
5362 END LOOP;
5363 RETURN "snapshot_id_v";
5364 END;
5365 $$;
5367 COMMENT ON FUNCTION "take_snapshot"
5368 ( "issue"."id"%TYPE,
5369 "area"."id"%TYPE )
5370 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.';
5373 CREATE FUNCTION "finish_snapshot"
5374 ( "issue_id_p" "issue"."id"%TYPE )
5375 RETURNS VOID
5376 LANGUAGE 'plpgsql' VOLATILE AS $$
5377 DECLARE
5378 "snapshot_id_v" "snapshot"."id"%TYPE;
5379 BEGIN
5380 -- NOTE: function does not require snapshot isolation but we don't call
5381 -- "dont_require_snapshot_isolation" here because this function is
5382 -- also invoked by "check_issue"
5383 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
5384 SELECT "id" INTO "snapshot_id_v" FROM "snapshot"
5385 ORDER BY "id" DESC LIMIT 1;
5386 UPDATE "issue" SET
5387 "calculated" = "snapshot"."calculated",
5388 "latest_snapshot_id" = "snapshot_id_v",
5389 "population" = "snapshot"."population",
5390 "initiative_quorum" = CASE WHEN
5391 "policy"."initiative_quorum" > ceil(
5392 ( "issue"."population"::INT8 *
5393 "policy"."initiative_quorum_num"::INT8 ) /
5394 "policy"."initiative_quorum_den"::FLOAT8
5395 )::INT4
5396 THEN
5397 "policy"."initiative_quorum"
5398 ELSE
5399 ceil(
5400 ( "issue"."population"::INT8 *
5401 "policy"."initiative_quorum_num"::INT8 ) /
5402 "policy"."initiative_quorum_den"::FLOAT8
5403 )::INT4
5404 END
5405 FROM "snapshot", "policy"
5406 WHERE "issue"."id" = "issue_id_p"
5407 AND "snapshot"."id" = "snapshot_id_v"
5408 AND "policy"."id" = "issue"."policy_id";
5409 UPDATE "initiative" SET
5410 "supporter_count" = (
5411 SELECT coalesce(sum("di"."weight"), 0)
5412 FROM "direct_interest_snapshot" AS "di"
5413 JOIN "direct_supporter_snapshot" AS "ds"
5414 ON "di"."member_id" = "ds"."member_id"
5415 WHERE "di"."snapshot_id" = "snapshot_id_v"
5416 AND "di"."issue_id" = "issue_id_p"
5417 AND "ds"."snapshot_id" = "snapshot_id_v"
5418 AND "ds"."initiative_id" = "initiative"."id"
5419 ),
5420 "informed_supporter_count" = (
5421 SELECT coalesce(sum("di"."weight"), 0)
5422 FROM "direct_interest_snapshot" AS "di"
5423 JOIN "direct_supporter_snapshot" AS "ds"
5424 ON "di"."member_id" = "ds"."member_id"
5425 WHERE "di"."snapshot_id" = "snapshot_id_v"
5426 AND "di"."issue_id" = "issue_id_p"
5427 AND "ds"."snapshot_id" = "snapshot_id_v"
5428 AND "ds"."initiative_id" = "initiative"."id"
5429 AND "ds"."informed"
5430 ),
5431 "satisfied_supporter_count" = (
5432 SELECT coalesce(sum("di"."weight"), 0)
5433 FROM "direct_interest_snapshot" AS "di"
5434 JOIN "direct_supporter_snapshot" AS "ds"
5435 ON "di"."member_id" = "ds"."member_id"
5436 WHERE "di"."snapshot_id" = "snapshot_id_v"
5437 AND "di"."issue_id" = "issue_id_p"
5438 AND "ds"."snapshot_id" = "snapshot_id_v"
5439 AND "ds"."initiative_id" = "initiative"."id"
5440 AND "ds"."satisfied"
5441 ),
5442 "satisfied_informed_supporter_count" = (
5443 SELECT coalesce(sum("di"."weight"), 0)
5444 FROM "direct_interest_snapshot" AS "di"
5445 JOIN "direct_supporter_snapshot" AS "ds"
5446 ON "di"."member_id" = "ds"."member_id"
5447 WHERE "di"."snapshot_id" = "snapshot_id_v"
5448 AND "di"."issue_id" = "issue_id_p"
5449 AND "ds"."snapshot_id" = "snapshot_id_v"
5450 AND "ds"."initiative_id" = "initiative"."id"
5451 AND "ds"."informed"
5452 AND "ds"."satisfied"
5454 WHERE "issue_id" = "issue_id_p";
5455 UPDATE "suggestion" SET
5456 "minus2_unfulfilled_count" = "temp"."minus2_unfulfilled_count",
5457 "minus2_fulfilled_count" = "temp"."minus2_fulfilled_count",
5458 "minus1_unfulfilled_count" = "temp"."minus1_unfulfilled_count",
5459 "minus1_fulfilled_count" = "temp"."minus1_fulfilled_count",
5460 "plus1_unfulfilled_count" = "temp"."plus1_unfulfilled_count",
5461 "plus1_fulfilled_count" = "temp"."plus1_fulfilled_count",
5462 "plus2_unfulfilled_count" = "temp"."plus2_unfulfilled_count",
5463 "plus2_fulfilled_count" = "temp"."plus2_fulfilled_count"
5464 FROM "temporary_suggestion_counts" AS "temp", "initiative"
5465 WHERE "temp"."id" = "suggestion"."id"
5466 AND "initiative"."issue_id" = "issue_id_p"
5467 AND "suggestion"."initiative_id" = "initiative"."id";
5468 DELETE FROM "temporary_suggestion_counts";
5469 RETURN;
5470 END;
5471 $$;
5473 COMMENT ON FUNCTION "finish_snapshot"
5474 ( "issue"."id"%TYPE )
5475 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)';
5479 -----------------------
5480 -- Counting of votes --
5481 -----------------------
5484 CREATE FUNCTION "weight_of_added_vote_delegations"
5485 ( "issue_id_p" "issue"."id"%TYPE,
5486 "member_id_p" "member"."id"%TYPE,
5487 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
5488 RETURNS "direct_voter"."weight"%TYPE
5489 LANGUAGE 'plpgsql' VOLATILE AS $$
5490 DECLARE
5491 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5492 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
5493 "weight_v" INT4;
5494 "sub_weight_v" INT4;
5495 BEGIN
5496 PERFORM "require_transaction_isolation"();
5497 "weight_v" := 0;
5498 FOR "issue_delegation_row" IN
5499 SELECT * FROM "issue_delegation"
5500 WHERE "trustee_id" = "member_id_p"
5501 AND "issue_id" = "issue_id_p"
5502 LOOP
5503 IF NOT EXISTS (
5504 SELECT NULL FROM "direct_voter"
5505 WHERE "member_id" = "issue_delegation_row"."truster_id"
5506 AND "issue_id" = "issue_id_p"
5507 ) AND NOT EXISTS (
5508 SELECT NULL FROM "delegating_voter"
5509 WHERE "member_id" = "issue_delegation_row"."truster_id"
5510 AND "issue_id" = "issue_id_p"
5511 ) THEN
5512 "delegate_member_ids_v" :=
5513 "member_id_p" || "delegate_member_ids_p";
5514 INSERT INTO "delegating_voter" (
5515 "issue_id",
5516 "member_id",
5517 "scope",
5518 "delegate_member_ids"
5519 ) VALUES (
5520 "issue_id_p",
5521 "issue_delegation_row"."truster_id",
5522 "issue_delegation_row"."scope",
5523 "delegate_member_ids_v"
5524 );
5525 "sub_weight_v" := 1 +
5526 "weight_of_added_vote_delegations"(
5527 "issue_id_p",
5528 "issue_delegation_row"."truster_id",
5529 "delegate_member_ids_v"
5530 );
5531 UPDATE "delegating_voter"
5532 SET "weight" = "sub_weight_v"
5533 WHERE "issue_id" = "issue_id_p"
5534 AND "member_id" = "issue_delegation_row"."truster_id";
5535 "weight_v" := "weight_v" + "sub_weight_v";
5536 END IF;
5537 END LOOP;
5538 RETURN "weight_v";
5539 END;
5540 $$;
5542 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
5543 ( "issue"."id"%TYPE,
5544 "member"."id"%TYPE,
5545 "delegating_voter"."delegate_member_ids"%TYPE )
5546 IS 'Helper function for "add_vote_delegations" function';
5549 CREATE FUNCTION "add_vote_delegations"
5550 ( "issue_id_p" "issue"."id"%TYPE )
5551 RETURNS VOID
5552 LANGUAGE 'plpgsql' VOLATILE AS $$
5553 DECLARE
5554 "member_id_v" "member"."id"%TYPE;
5555 BEGIN
5556 PERFORM "require_transaction_isolation"();
5557 FOR "member_id_v" IN
5558 SELECT "member_id" FROM "direct_voter"
5559 WHERE "issue_id" = "issue_id_p"
5560 LOOP
5561 UPDATE "direct_voter" SET
5562 "weight" = "weight" + "weight_of_added_vote_delegations"(
5563 "issue_id_p",
5564 "member_id_v",
5565 '{}'
5567 WHERE "member_id" = "member_id_v"
5568 AND "issue_id" = "issue_id_p";
5569 END LOOP;
5570 RETURN;
5571 END;
5572 $$;
5574 COMMENT ON FUNCTION "add_vote_delegations"
5575 ( "issue_id_p" "issue"."id"%TYPE )
5576 IS 'Helper function for "close_voting" function';
5579 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
5580 RETURNS VOID
5581 LANGUAGE 'plpgsql' VOLATILE AS $$
5582 DECLARE
5583 "area_id_v" "area"."id"%TYPE;
5584 "unit_id_v" "unit"."id"%TYPE;
5585 "member_id_v" "member"."id"%TYPE;
5586 BEGIN
5587 PERFORM "require_transaction_isolation"();
5588 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
5589 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5590 -- override protection triggers:
5591 INSERT INTO "temporary_transaction_data" ("key", "value")
5592 VALUES ('override_protection_triggers', TRUE::TEXT);
5593 -- delete timestamp of voting comment:
5594 UPDATE "direct_voter" SET "comment_changed" = NULL
5595 WHERE "issue_id" = "issue_id_p";
5596 -- delete delegating votes (in cases of manual reset of issue state):
5597 DELETE FROM "delegating_voter"
5598 WHERE "issue_id" = "issue_id_p";
5599 -- delete votes from non-privileged voters:
5600 DELETE FROM "direct_voter"
5601 USING (
5602 SELECT
5603 "direct_voter"."member_id"
5604 FROM "direct_voter"
5605 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
5606 LEFT JOIN "privilege"
5607 ON "privilege"."unit_id" = "unit_id_v"
5608 AND "privilege"."member_id" = "direct_voter"."member_id"
5609 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
5610 "member"."active" = FALSE OR
5611 "privilege"."voting_right" ISNULL OR
5612 "privilege"."voting_right" = FALSE
5614 ) AS "subquery"
5615 WHERE "direct_voter"."issue_id" = "issue_id_p"
5616 AND "direct_voter"."member_id" = "subquery"."member_id";
5617 -- consider delegations:
5618 UPDATE "direct_voter" SET "weight" = 1
5619 WHERE "issue_id" = "issue_id_p";
5620 PERFORM "add_vote_delegations"("issue_id_p");
5621 -- mark first preferences:
5622 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
5623 FROM (
5624 SELECT
5625 "vote"."initiative_id",
5626 "vote"."member_id",
5627 CASE WHEN "vote"."grade" > 0 THEN
5628 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
5629 ELSE NULL
5630 END AS "first_preference"
5631 FROM "vote"
5632 JOIN "initiative" -- NOTE: due to missing index on issue_id
5633 ON "vote"."issue_id" = "initiative"."issue_id"
5634 JOIN "vote" AS "agg"
5635 ON "initiative"."id" = "agg"."initiative_id"
5636 AND "vote"."member_id" = "agg"."member_id"
5637 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
5638 ) AS "subquery"
5639 WHERE "vote"."issue_id" = "issue_id_p"
5640 AND "vote"."initiative_id" = "subquery"."initiative_id"
5641 AND "vote"."member_id" = "subquery"."member_id";
5642 -- finish overriding protection triggers (avoids garbage):
5643 DELETE FROM "temporary_transaction_data"
5644 WHERE "key" = 'override_protection_triggers';
5645 -- materialize battle_view:
5646 -- NOTE: "closed" column of issue must be set at this point
5647 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
5648 INSERT INTO "battle" (
5649 "issue_id",
5650 "winning_initiative_id", "losing_initiative_id",
5651 "count"
5652 ) SELECT
5653 "issue_id",
5654 "winning_initiative_id", "losing_initiative_id",
5655 "count"
5656 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
5657 -- set voter count:
5658 UPDATE "issue" SET
5659 "voter_count" = (
5660 SELECT coalesce(sum("weight"), 0)
5661 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
5663 WHERE "id" = "issue_id_p";
5664 -- copy "positive_votes" and "negative_votes" from "battle" table:
5665 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
5666 UPDATE "initiative" SET
5667 "first_preference_votes" = 0,
5668 "positive_votes" = "battle_win"."count",
5669 "negative_votes" = "battle_lose"."count"
5670 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
5671 WHERE
5672 "battle_win"."issue_id" = "issue_id_p" AND
5673 "battle_win"."winning_initiative_id" = "initiative"."id" AND
5674 "battle_win"."losing_initiative_id" ISNULL AND
5675 "battle_lose"."issue_id" = "issue_id_p" AND
5676 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
5677 "battle_lose"."winning_initiative_id" ISNULL;
5678 -- calculate "first_preference_votes":
5679 -- NOTE: will only set values not equal to zero
5680 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
5681 FROM (
5682 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
5683 FROM "vote" JOIN "direct_voter"
5684 ON "vote"."issue_id" = "direct_voter"."issue_id"
5685 AND "vote"."member_id" = "direct_voter"."member_id"
5686 WHERE "vote"."first_preference"
5687 GROUP BY "vote"."initiative_id"
5688 ) AS "subquery"
5689 WHERE "initiative"."issue_id" = "issue_id_p"
5690 AND "initiative"."admitted"
5691 AND "initiative"."id" = "subquery"."initiative_id";
5692 END;
5693 $$;
5695 COMMENT ON FUNCTION "close_voting"
5696 ( "issue"."id"%TYPE )
5697 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.';
5700 CREATE FUNCTION "defeat_strength"
5701 ( "positive_votes_p" INT4,
5702 "negative_votes_p" INT4,
5703 "defeat_strength_p" "defeat_strength" )
5704 RETURNS INT8
5705 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5706 BEGIN
5707 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
5708 IF "positive_votes_p" > "negative_votes_p" THEN
5709 RETURN "positive_votes_p";
5710 ELSE
5711 RETURN 0;
5712 END IF;
5713 ELSE
5714 IF "positive_votes_p" > "negative_votes_p" THEN
5715 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
5716 ELSIF "positive_votes_p" = "negative_votes_p" THEN
5717 RETURN 0;
5718 ELSE
5719 RETURN -1;
5720 END IF;
5721 END IF;
5722 END;
5723 $$;
5725 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")';
5728 CREATE FUNCTION "secondary_link_strength"
5729 ( "initiative1_ord_p" INT4,
5730 "initiative2_ord_p" INT4,
5731 "tie_breaking_p" "tie_breaking" )
5732 RETURNS INT8
5733 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5734 BEGIN
5735 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
5736 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
5737 END IF;
5738 RETURN (
5739 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
5741 ELSE
5742 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
5743 1::INT8 << 62
5744 ELSE 0 END
5746 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
5747 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
5748 ELSE
5749 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
5750 END
5751 END
5752 );
5753 END;
5754 $$;
5756 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
5759 CREATE TYPE "link_strength" AS (
5760 "primary" INT8,
5761 "secondary" INT8 );
5763 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'')';
5766 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
5767 RETURNS "link_strength"[][]
5768 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5769 DECLARE
5770 "dimension_v" INT4;
5771 "matrix_p" "link_strength"[][];
5772 "i" INT4;
5773 "j" INT4;
5774 "k" INT4;
5775 BEGIN
5776 "dimension_v" := array_upper("matrix_d", 1);
5777 "matrix_p" := "matrix_d";
5778 "i" := 1;
5779 LOOP
5780 "j" := 1;
5781 LOOP
5782 IF "i" != "j" THEN
5783 "k" := 1;
5784 LOOP
5785 IF "i" != "k" AND "j" != "k" THEN
5786 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
5787 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
5788 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
5789 END IF;
5790 ELSE
5791 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
5792 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
5793 END IF;
5794 END IF;
5795 END IF;
5796 EXIT WHEN "k" = "dimension_v";
5797 "k" := "k" + 1;
5798 END LOOP;
5799 END IF;
5800 EXIT WHEN "j" = "dimension_v";
5801 "j" := "j" + 1;
5802 END LOOP;
5803 EXIT WHEN "i" = "dimension_v";
5804 "i" := "i" + 1;
5805 END LOOP;
5806 RETURN "matrix_p";
5807 END;
5808 $$;
5810 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
5813 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
5814 RETURNS VOID
5815 LANGUAGE 'plpgsql' VOLATILE AS $$
5816 DECLARE
5817 "issue_row" "issue"%ROWTYPE;
5818 "policy_row" "policy"%ROWTYPE;
5819 "dimension_v" INT4;
5820 "matrix_a" INT4[][]; -- absolute votes
5821 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
5822 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
5823 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
5824 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
5825 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
5826 "i" INT4;
5827 "j" INT4;
5828 "m" INT4;
5829 "n" INT4;
5830 "battle_row" "battle"%ROWTYPE;
5831 "rank_ary" INT4[];
5832 "rank_v" INT4;
5833 "initiative_id_v" "initiative"."id"%TYPE;
5834 BEGIN
5835 PERFORM "require_transaction_isolation"();
5836 SELECT * INTO "issue_row"
5837 FROM "issue" WHERE "id" = "issue_id_p";
5838 SELECT * INTO "policy_row"
5839 FROM "policy" WHERE "id" = "issue_row"."policy_id";
5840 SELECT count(1) INTO "dimension_v"
5841 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
5842 -- create "matrix_a" with absolute number of votes in pairwise
5843 -- comparison:
5844 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
5845 "i" := 1;
5846 "j" := 2;
5847 FOR "battle_row" IN
5848 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
5849 ORDER BY
5850 "winning_initiative_id" NULLS FIRST,
5851 "losing_initiative_id" NULLS FIRST
5852 LOOP
5853 "matrix_a"["i"]["j"] := "battle_row"."count";
5854 IF "j" = "dimension_v" THEN
5855 "i" := "i" + 1;
5856 "j" := 1;
5857 ELSE
5858 "j" := "j" + 1;
5859 IF "j" = "i" THEN
5860 "j" := "j" + 1;
5861 END IF;
5862 END IF;
5863 END LOOP;
5864 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
5865 RAISE EXCEPTION 'Wrong battle count (should not happen)';
5866 END IF;
5867 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
5868 -- and "secondary_link_strength" functions:
5869 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
5870 "i" := 1;
5871 LOOP
5872 "j" := 1;
5873 LOOP
5874 IF "i" != "j" THEN
5875 "matrix_d"["i"]["j"] := (
5876 "defeat_strength"(
5877 "matrix_a"["i"]["j"],
5878 "matrix_a"["j"]["i"],
5879 "policy_row"."defeat_strength"
5880 ),
5881 "secondary_link_strength"(
5882 "i",
5883 "j",
5884 "policy_row"."tie_breaking"
5886 )::"link_strength";
5887 END IF;
5888 EXIT WHEN "j" = "dimension_v";
5889 "j" := "j" + 1;
5890 END LOOP;
5891 EXIT WHEN "i" = "dimension_v";
5892 "i" := "i" + 1;
5893 END LOOP;
5894 -- find best paths:
5895 "matrix_p" := "find_best_paths"("matrix_d");
5896 -- create partial order:
5897 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
5898 "i" := 1;
5899 LOOP
5900 "j" := "i" + 1;
5901 LOOP
5902 IF "i" != "j" THEN
5903 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
5904 "matrix_b"["i"]["j"] := TRUE;
5905 "matrix_b"["j"]["i"] := FALSE;
5906 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
5907 "matrix_b"["i"]["j"] := FALSE;
5908 "matrix_b"["j"]["i"] := TRUE;
5909 END IF;
5910 END IF;
5911 EXIT WHEN "j" = "dimension_v";
5912 "j" := "j" + 1;
5913 END LOOP;
5914 EXIT WHEN "i" = "dimension_v" - 1;
5915 "i" := "i" + 1;
5916 END LOOP;
5917 -- tie-breaking by forbidding shared weakest links in beat-paths
5918 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
5919 -- is performed later by initiative id):
5920 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
5921 "m" := 1;
5922 LOOP
5923 "n" := "m" + 1;
5924 LOOP
5925 -- only process those candidates m and n, which are tied:
5926 IF "matrix_b"["m"]["n"] ISNULL THEN
5927 -- start with beat-paths prior tie-breaking:
5928 "matrix_t" := "matrix_p";
5929 -- start with all links allowed:
5930 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
5931 LOOP
5932 -- determine (and forbid) that link that is the weakest link
5933 -- in both the best path from candidate m to candidate n and
5934 -- from candidate n to candidate m:
5935 "i" := 1;
5936 <<forbid_one_link>>
5937 LOOP
5938 "j" := 1;
5939 LOOP
5940 IF "i" != "j" THEN
5941 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
5942 "matrix_f"["i"]["j"] := TRUE;
5943 -- exit for performance reasons,
5944 -- as exactly one link will be found:
5945 EXIT forbid_one_link;
5946 END IF;
5947 END IF;
5948 EXIT WHEN "j" = "dimension_v";
5949 "j" := "j" + 1;
5950 END LOOP;
5951 IF "i" = "dimension_v" THEN
5952 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
5953 END IF;
5954 "i" := "i" + 1;
5955 END LOOP;
5956 -- calculate best beat-paths while ignoring forbidden links:
5957 "i" := 1;
5958 LOOP
5959 "j" := 1;
5960 LOOP
5961 IF "i" != "j" THEN
5962 "matrix_t"["i"]["j"] := CASE
5963 WHEN "matrix_f"["i"]["j"]
5964 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
5965 ELSE "matrix_d"["i"]["j"] END;
5966 END IF;
5967 EXIT WHEN "j" = "dimension_v";
5968 "j" := "j" + 1;
5969 END LOOP;
5970 EXIT WHEN "i" = "dimension_v";
5971 "i" := "i" + 1;
5972 END LOOP;
5973 "matrix_t" := "find_best_paths"("matrix_t");
5974 -- extend partial order, if tie-breaking was successful:
5975 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
5976 "matrix_b"["m"]["n"] := TRUE;
5977 "matrix_b"["n"]["m"] := FALSE;
5978 EXIT;
5979 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
5980 "matrix_b"["m"]["n"] := FALSE;
5981 "matrix_b"["n"]["m"] := TRUE;
5982 EXIT;
5983 END IF;
5984 END LOOP;
5985 END IF;
5986 EXIT WHEN "n" = "dimension_v";
5987 "n" := "n" + 1;
5988 END LOOP;
5989 EXIT WHEN "m" = "dimension_v" - 1;
5990 "m" := "m" + 1;
5991 END LOOP;
5992 END IF;
5993 -- store a unique ranking in "rank_ary":
5994 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
5995 "rank_v" := 1;
5996 LOOP
5997 "i" := 1;
5998 <<assign_next_rank>>
5999 LOOP
6000 IF "rank_ary"["i"] ISNULL THEN
6001 "j" := 1;
6002 LOOP
6003 IF
6004 "i" != "j" AND
6005 "rank_ary"["j"] ISNULL AND
6006 ( "matrix_b"["j"]["i"] OR
6007 -- tie-breaking by "id"
6008 ( "matrix_b"["j"]["i"] ISNULL AND
6009 "j" < "i" ) )
6010 THEN
6011 -- someone else is better
6012 EXIT;
6013 END IF;
6014 IF "j" = "dimension_v" THEN
6015 -- noone is better
6016 "rank_ary"["i"] := "rank_v";
6017 EXIT assign_next_rank;
6018 END IF;
6019 "j" := "j" + 1;
6020 END LOOP;
6021 END IF;
6022 "i" := "i" + 1;
6023 IF "i" > "dimension_v" THEN
6024 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
6025 END IF;
6026 END LOOP;
6027 EXIT WHEN "rank_v" = "dimension_v";
6028 "rank_v" := "rank_v" + 1;
6029 END LOOP;
6030 -- write preliminary results:
6031 "i" := 2; -- omit status quo with "i" = 1
6032 FOR "initiative_id_v" IN
6033 SELECT "id" FROM "initiative"
6034 WHERE "issue_id" = "issue_id_p" AND "admitted"
6035 ORDER BY "id"
6036 LOOP
6037 UPDATE "initiative" SET
6038 "direct_majority" =
6039 CASE WHEN "policy_row"."direct_majority_strict" THEN
6040 "positive_votes" * "policy_row"."direct_majority_den" >
6041 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
6042 ELSE
6043 "positive_votes" * "policy_row"."direct_majority_den" >=
6044 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
6045 END
6046 AND "positive_votes" >= "policy_row"."direct_majority_positive"
6047 AND "issue_row"."voter_count"-"negative_votes" >=
6048 "policy_row"."direct_majority_non_negative",
6049 "indirect_majority" =
6050 CASE WHEN "policy_row"."indirect_majority_strict" THEN
6051 "positive_votes" * "policy_row"."indirect_majority_den" >
6052 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
6053 ELSE
6054 "positive_votes" * "policy_row"."indirect_majority_den" >=
6055 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
6056 END
6057 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
6058 AND "issue_row"."voter_count"-"negative_votes" >=
6059 "policy_row"."indirect_majority_non_negative",
6060 "schulze_rank" = "rank_ary"["i"],
6061 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
6062 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
6063 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
6064 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
6065 THEN NULL
6066 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
6067 "eligible" = FALSE,
6068 "winner" = FALSE,
6069 "rank" = NULL -- NOTE: in cases of manual reset of issue state
6070 WHERE "id" = "initiative_id_v";
6071 "i" := "i" + 1;
6072 END LOOP;
6073 IF "i" != "dimension_v" + 1 THEN
6074 RAISE EXCEPTION 'Wrong winner count (should not happen)';
6075 END IF;
6076 -- take indirect majorities into account:
6077 LOOP
6078 UPDATE "initiative" SET "indirect_majority" = TRUE
6079 FROM (
6080 SELECT "new_initiative"."id" AS "initiative_id"
6081 FROM "initiative" "old_initiative"
6082 JOIN "initiative" "new_initiative"
6083 ON "new_initiative"."issue_id" = "issue_id_p"
6084 AND "new_initiative"."indirect_majority" = FALSE
6085 JOIN "battle" "battle_win"
6086 ON "battle_win"."issue_id" = "issue_id_p"
6087 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
6088 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
6089 JOIN "battle" "battle_lose"
6090 ON "battle_lose"."issue_id" = "issue_id_p"
6091 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
6092 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
6093 WHERE "old_initiative"."issue_id" = "issue_id_p"
6094 AND "old_initiative"."indirect_majority" = TRUE
6095 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
6096 "battle_win"."count" * "policy_row"."indirect_majority_den" >
6097 "policy_row"."indirect_majority_num" *
6098 ("battle_win"."count"+"battle_lose"."count")
6099 ELSE
6100 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
6101 "policy_row"."indirect_majority_num" *
6102 ("battle_win"."count"+"battle_lose"."count")
6103 END
6104 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
6105 AND "issue_row"."voter_count"-"battle_lose"."count" >=
6106 "policy_row"."indirect_majority_non_negative"
6107 ) AS "subquery"
6108 WHERE "id" = "subquery"."initiative_id";
6109 EXIT WHEN NOT FOUND;
6110 END LOOP;
6111 -- set "multistage_majority" for remaining matching initiatives:
6112 UPDATE "initiative" SET "multistage_majority" = TRUE
6113 FROM (
6114 SELECT "losing_initiative"."id" AS "initiative_id"
6115 FROM "initiative" "losing_initiative"
6116 JOIN "initiative" "winning_initiative"
6117 ON "winning_initiative"."issue_id" = "issue_id_p"
6118 AND "winning_initiative"."admitted"
6119 JOIN "battle" "battle_win"
6120 ON "battle_win"."issue_id" = "issue_id_p"
6121 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
6122 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
6123 JOIN "battle" "battle_lose"
6124 ON "battle_lose"."issue_id" = "issue_id_p"
6125 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
6126 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
6127 WHERE "losing_initiative"."issue_id" = "issue_id_p"
6128 AND "losing_initiative"."admitted"
6129 AND "winning_initiative"."schulze_rank" <
6130 "losing_initiative"."schulze_rank"
6131 AND "battle_win"."count" > "battle_lose"."count"
6132 AND (
6133 "battle_win"."count" > "winning_initiative"."positive_votes" OR
6134 "battle_lose"."count" < "losing_initiative"."negative_votes" )
6135 ) AS "subquery"
6136 WHERE "id" = "subquery"."initiative_id";
6137 -- mark eligible initiatives:
6138 UPDATE "initiative" SET "eligible" = TRUE
6139 WHERE "issue_id" = "issue_id_p"
6140 AND "initiative"."direct_majority"
6141 AND "initiative"."indirect_majority"
6142 AND "initiative"."better_than_status_quo"
6143 AND (
6144 "policy_row"."no_multistage_majority" = FALSE OR
6145 "initiative"."multistage_majority" = FALSE )
6146 AND (
6147 "policy_row"."no_reverse_beat_path" = FALSE OR
6148 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
6149 -- mark final winner:
6150 UPDATE "initiative" SET "winner" = TRUE
6151 FROM (
6152 SELECT "id" AS "initiative_id"
6153 FROM "initiative"
6154 WHERE "issue_id" = "issue_id_p" AND "eligible"
6155 ORDER BY
6156 "schulze_rank",
6157 "id"
6158 LIMIT 1
6159 ) AS "subquery"
6160 WHERE "id" = "subquery"."initiative_id";
6161 -- write (final) ranks:
6162 "rank_v" := 1;
6163 FOR "initiative_id_v" IN
6164 SELECT "id"
6165 FROM "initiative"
6166 WHERE "issue_id" = "issue_id_p" AND "admitted"
6167 ORDER BY
6168 "winner" DESC,
6169 "eligible" DESC,
6170 "schulze_rank",
6171 "id"
6172 LOOP
6173 UPDATE "initiative" SET "rank" = "rank_v"
6174 WHERE "id" = "initiative_id_v";
6175 "rank_v" := "rank_v" + 1;
6176 END LOOP;
6177 -- set schulze rank of status quo and mark issue as finished:
6178 UPDATE "issue" SET
6179 "status_quo_schulze_rank" = "rank_ary"[1],
6180 "state" =
6181 CASE WHEN EXISTS (
6182 SELECT NULL FROM "initiative"
6183 WHERE "issue_id" = "issue_id_p" AND "winner"
6184 ) THEN
6185 'finished_with_winner'::"issue_state"
6186 ELSE
6187 'finished_without_winner'::"issue_state"
6188 END,
6189 "closed" = "phase_finished",
6190 "phase_finished" = NULL
6191 WHERE "id" = "issue_id_p";
6192 RETURN;
6193 END;
6194 $$;
6196 COMMENT ON FUNCTION "calculate_ranks"
6197 ( "issue"."id"%TYPE )
6198 IS 'Determine ranking (Votes have to be counted first)';
6202 -----------------------------
6203 -- Automatic state changes --
6204 -----------------------------
6207 CREATE FUNCTION "issue_admission"
6208 ( "area_id_p" "area"."id"%TYPE )
6209 RETURNS BOOLEAN
6210 LANGUAGE 'plpgsql' VOLATILE AS $$
6211 DECLARE
6212 "issue_id_v" "issue"."id"%TYPE;
6213 BEGIN
6214 PERFORM "dont_require_transaction_isolation"();
6215 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
6216 UPDATE "area" SET "issue_quorum" = "view"."issue_quorum"
6217 FROM "area_quorum" AS "view"
6218 WHERE "area"."id" = "view"."area_id"
6219 AND "area"."id" = "area_id_p";
6220 SELECT "id" INTO "issue_id_v" FROM "issue_for_admission"
6221 WHERE "area_id" = "area_id_p";
6222 IF "issue_id_v" ISNULL THEN RETURN FALSE; END IF;
6223 UPDATE "issue" SET
6224 "admission_snapshot_id" = "latest_snapshot_id",
6225 "state" = 'discussion',
6226 "accepted" = now(),
6227 "phase_finished" = NULL,
6228 "issue_quorum" = "issue_quorum"."issue_quorum"
6229 FROM "issue_quorum"
6230 WHERE "id" = "issue_id_v"
6231 AND "issue_quorum"."issue_id" = "issue_id_v";
6232 RETURN TRUE;
6233 END;
6234 $$;
6236 COMMENT ON FUNCTION "issue_admission"
6237 ( "area"."id"%TYPE )
6238 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';
6241 CREATE TYPE "check_issue_persistence" AS (
6242 "state" "issue_state",
6243 "phase_finished" BOOLEAN,
6244 "issue_revoked" BOOLEAN,
6245 "snapshot_created" BOOLEAN,
6246 "harmonic_weights_set" BOOLEAN,
6247 "closed_voting" BOOLEAN );
6249 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';
6252 CREATE FUNCTION "check_issue"
6253 ( "issue_id_p" "issue"."id"%TYPE,
6254 "persist" "check_issue_persistence" )
6255 RETURNS "check_issue_persistence"
6256 LANGUAGE 'plpgsql' VOLATILE AS $$
6257 DECLARE
6258 "issue_row" "issue"%ROWTYPE;
6259 "last_calculated_v" "snapshot"."calculated"%TYPE;
6260 "policy_row" "policy"%ROWTYPE;
6261 "initiative_row" "initiative"%ROWTYPE;
6262 "state_v" "issue_state";
6263 BEGIN
6264 PERFORM "require_transaction_isolation"();
6265 IF "persist" ISNULL THEN
6266 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6267 FOR UPDATE;
6268 SELECT "calculated" INTO "last_calculated_v"
6269 FROM "snapshot" JOIN "snapshot_issue"
6270 ON "snapshot"."id" = "snapshot_issue"."snapshot_id"
6271 WHERE "snapshot_issue"."issue_id" = "issue_id_p"
6272 ORDER BY "snapshot"."id" DESC;
6273 IF "issue_row"."closed" NOTNULL THEN
6274 RETURN NULL;
6275 END IF;
6276 "persist"."state" := "issue_row"."state";
6277 IF
6278 ( "issue_row"."state" = 'admission' AND "last_calculated_v" >=
6279 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
6280 ( "issue_row"."state" = 'discussion' AND now() >=
6281 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
6282 ( "issue_row"."state" = 'verification' AND now() >=
6283 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
6284 ( "issue_row"."state" = 'voting' AND now() >=
6285 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
6286 THEN
6287 "persist"."phase_finished" := TRUE;
6288 ELSE
6289 "persist"."phase_finished" := FALSE;
6290 END IF;
6291 IF
6292 NOT EXISTS (
6293 -- all initiatives are revoked
6294 SELECT NULL FROM "initiative"
6295 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6296 ) AND (
6297 -- and issue has not been accepted yet
6298 "persist"."state" = 'admission' OR
6299 -- or verification time has elapsed
6300 ( "persist"."state" = 'verification' AND
6301 "persist"."phase_finished" ) OR
6302 -- or no initiatives have been revoked lately
6303 NOT EXISTS (
6304 SELECT NULL FROM "initiative"
6305 WHERE "issue_id" = "issue_id_p"
6306 AND now() < "revoked" + "issue_row"."verification_time"
6309 THEN
6310 "persist"."issue_revoked" := TRUE;
6311 ELSE
6312 "persist"."issue_revoked" := FALSE;
6313 END IF;
6314 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
6315 UPDATE "issue" SET "phase_finished" = now()
6316 WHERE "id" = "issue_row"."id";
6317 RETURN "persist";
6318 ELSIF
6319 "persist"."state" IN ('admission', 'discussion', 'verification')
6320 THEN
6321 RETURN "persist";
6322 ELSE
6323 RETURN NULL;
6324 END IF;
6325 END IF;
6326 IF
6327 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6328 coalesce("persist"."snapshot_created", FALSE) = FALSE
6329 THEN
6330 IF "persist"."state" != 'admission' THEN
6331 PERFORM "take_snapshot"("issue_id_p");
6332 PERFORM "finish_snapshot"("issue_id_p");
6333 ELSE
6334 UPDATE "issue" SET "issue_quorum" = "issue_quorum"."issue_quorum"
6335 FROM "issue_quorum"
6336 WHERE "id" = "issue_id_p"
6337 AND "issue_quorum"."issue_id" = "issue_id_p";
6338 END IF;
6339 "persist"."snapshot_created" = TRUE;
6340 IF "persist"."phase_finished" THEN
6341 IF "persist"."state" = 'admission' THEN
6342 UPDATE "issue" SET "admission_snapshot_id" = "latest_snapshot_id"
6343 WHERE "id" = "issue_id_p";
6344 ELSIF "persist"."state" = 'discussion' THEN
6345 UPDATE "issue" SET "half_freeze_snapshot_id" = "latest_snapshot_id"
6346 WHERE "id" = "issue_id_p";
6347 ELSIF "persist"."state" = 'verification' THEN
6348 UPDATE "issue" SET "full_freeze_snapshot_id" = "latest_snapshot_id"
6349 WHERE "id" = "issue_id_p";
6350 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
6351 FOR "initiative_row" IN
6352 SELECT * FROM "initiative"
6353 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6354 FOR UPDATE
6355 LOOP
6356 IF
6357 "initiative_row"."polling" OR
6358 "initiative_row"."satisfied_supporter_count" >=
6359 "issue_row"."initiative_quorum"
6360 THEN
6361 UPDATE "initiative" SET "admitted" = TRUE
6362 WHERE "id" = "initiative_row"."id";
6363 ELSE
6364 UPDATE "initiative" SET "admitted" = FALSE
6365 WHERE "id" = "initiative_row"."id";
6366 END IF;
6367 END LOOP;
6368 END IF;
6369 END IF;
6370 RETURN "persist";
6371 END IF;
6372 IF
6373 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6374 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
6375 THEN
6376 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
6377 "persist"."harmonic_weights_set" = TRUE;
6378 IF
6379 "persist"."phase_finished" OR
6380 "persist"."issue_revoked" OR
6381 "persist"."state" = 'admission'
6382 THEN
6383 RETURN "persist";
6384 ELSE
6385 RETURN NULL;
6386 END IF;
6387 END IF;
6388 IF "persist"."issue_revoked" THEN
6389 IF "persist"."state" = 'admission' THEN
6390 "state_v" := 'canceled_revoked_before_accepted';
6391 ELSIF "persist"."state" = 'discussion' THEN
6392 "state_v" := 'canceled_after_revocation_during_discussion';
6393 ELSIF "persist"."state" = 'verification' THEN
6394 "state_v" := 'canceled_after_revocation_during_verification';
6395 END IF;
6396 UPDATE "issue" SET
6397 "state" = "state_v",
6398 "closed" = "phase_finished",
6399 "phase_finished" = NULL
6400 WHERE "id" = "issue_id_p";
6401 RETURN NULL;
6402 END IF;
6403 IF "persist"."state" = 'admission' THEN
6404 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6405 FOR UPDATE;
6406 IF "issue_row"."phase_finished" NOTNULL THEN
6407 UPDATE "issue" SET
6408 "state" = 'canceled_issue_not_accepted',
6409 "closed" = "phase_finished",
6410 "phase_finished" = NULL
6411 WHERE "id" = "issue_id_p";
6412 END IF;
6413 RETURN NULL;
6414 END IF;
6415 IF "persist"."phase_finished" THEN
6416 IF "persist"."state" = 'discussion' THEN
6417 UPDATE "issue" SET
6418 "state" = 'verification',
6419 "half_frozen" = "phase_finished",
6420 "phase_finished" = NULL
6421 WHERE "id" = "issue_id_p";
6422 RETURN NULL;
6423 END IF;
6424 IF "persist"."state" = 'verification' THEN
6425 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6426 FOR UPDATE;
6427 SELECT * INTO "policy_row" FROM "policy"
6428 WHERE "id" = "issue_row"."policy_id";
6429 IF EXISTS (
6430 SELECT NULL FROM "initiative"
6431 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
6432 ) THEN
6433 UPDATE "issue" SET
6434 "state" = 'voting',
6435 "fully_frozen" = "phase_finished",
6436 "phase_finished" = NULL
6437 WHERE "id" = "issue_id_p";
6438 ELSE
6439 UPDATE "issue" SET
6440 "state" = 'canceled_no_initiative_admitted',
6441 "fully_frozen" = "phase_finished",
6442 "closed" = "phase_finished",
6443 "phase_finished" = NULL
6444 WHERE "id" = "issue_id_p";
6445 -- NOTE: The following DELETE statements have effect only when
6446 -- issue state has been manipulated
6447 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
6448 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
6449 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
6450 END IF;
6451 RETURN NULL;
6452 END IF;
6453 IF "persist"."state" = 'voting' THEN
6454 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
6455 PERFORM "close_voting"("issue_id_p");
6456 "persist"."closed_voting" = TRUE;
6457 RETURN "persist";
6458 END IF;
6459 PERFORM "calculate_ranks"("issue_id_p");
6460 RETURN NULL;
6461 END IF;
6462 END IF;
6463 RAISE WARNING 'should not happen';
6464 RETURN NULL;
6465 END;
6466 $$;
6468 COMMENT ON FUNCTION "check_issue"
6469 ( "issue"."id"%TYPE,
6470 "check_issue_persistence" )
6471 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")';
6474 CREATE FUNCTION "check_everything"()
6475 RETURNS VOID
6476 LANGUAGE 'plpgsql' VOLATILE AS $$
6477 DECLARE
6478 "area_id_v" "area"."id"%TYPE;
6479 "snapshot_id_v" "snapshot"."id"%TYPE;
6480 "issue_id_v" "issue"."id"%TYPE;
6481 "persist_v" "check_issue_persistence";
6482 BEGIN
6483 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
6484 DELETE FROM "expired_session";
6485 DELETE FROM "expired_token";
6486 DELETE FROM "unused_snapshot";
6487 PERFORM "check_activity"();
6488 PERFORM "calculate_member_counts"();
6489 FOR "area_id_v" IN SELECT "id" FROM "area_with_unaccepted_issues" LOOP
6490 SELECT "take_snapshot"(NULL, "area_id_v") INTO "snapshot_id_v";
6491 PERFORM "finish_snapshot"("issue_id") FROM "snapshot_issue"
6492 WHERE "snapshot_id" = "snapshot_id_v";
6493 LOOP
6494 EXIT WHEN "issue_admission"("area_id_v") = FALSE;
6495 END LOOP;
6496 END LOOP;
6497 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
6498 "persist_v" := NULL;
6499 LOOP
6500 "persist_v" := "check_issue"("issue_id_v", "persist_v");
6501 EXIT WHEN "persist_v" ISNULL;
6502 END LOOP;
6503 END LOOP;
6504 DELETE FROM "unused_snapshot";
6505 RETURN;
6506 END;
6507 $$;
6509 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';
6513 ----------------------
6514 -- Deletion of data --
6515 ----------------------
6518 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
6519 RETURNS VOID
6520 LANGUAGE 'plpgsql' VOLATILE AS $$
6521 BEGIN
6522 IF EXISTS (
6523 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
6524 ) THEN
6525 -- override protection triggers:
6526 INSERT INTO "temporary_transaction_data" ("key", "value")
6527 VALUES ('override_protection_triggers', TRUE::TEXT);
6528 -- clean data:
6529 DELETE FROM "delegating_voter"
6530 WHERE "issue_id" = "issue_id_p";
6531 DELETE FROM "direct_voter"
6532 WHERE "issue_id" = "issue_id_p";
6533 DELETE FROM "delegating_interest_snapshot"
6534 WHERE "issue_id" = "issue_id_p";
6535 DELETE FROM "direct_interest_snapshot"
6536 WHERE "issue_id" = "issue_id_p";
6537 DELETE FROM "non_voter"
6538 WHERE "issue_id" = "issue_id_p";
6539 DELETE FROM "delegation"
6540 WHERE "issue_id" = "issue_id_p";
6541 DELETE FROM "supporter"
6542 USING "initiative" -- NOTE: due to missing index on issue_id
6543 WHERE "initiative"."issue_id" = "issue_id_p"
6544 AND "supporter"."initiative_id" = "initiative_id";
6545 -- mark issue as cleaned:
6546 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
6547 -- finish overriding protection triggers (avoids garbage):
6548 DELETE FROM "temporary_transaction_data"
6549 WHERE "key" = 'override_protection_triggers';
6550 END IF;
6551 RETURN;
6552 END;
6553 $$;
6555 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
6558 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
6559 RETURNS VOID
6560 LANGUAGE 'plpgsql' VOLATILE AS $$
6561 BEGIN
6562 UPDATE "member" SET
6563 "last_login" = NULL,
6564 "last_delegation_check" = NULL,
6565 "login" = NULL,
6566 "password" = NULL,
6567 "authority" = NULL,
6568 "authority_uid" = NULL,
6569 "authority_login" = NULL,
6570 "deleted" = coalesce("deleted", now()),
6571 "locked" = TRUE,
6572 "active" = FALSE,
6573 "notify_email" = NULL,
6574 "notify_email_unconfirmed" = NULL,
6575 "notify_email_secret" = NULL,
6576 "notify_email_secret_expiry" = NULL,
6577 "notify_email_lock_expiry" = NULL,
6578 "disable_notifications" = TRUE,
6579 "notification_counter" = DEFAULT,
6580 "notification_sample_size" = 0,
6581 "notification_dow" = NULL,
6582 "notification_hour" = NULL,
6583 "notification_sent" = NULL,
6584 "login_recovery_expiry" = NULL,
6585 "password_reset_secret" = NULL,
6586 "password_reset_secret_expiry" = NULL,
6587 "location" = NULL
6588 WHERE "id" = "member_id_p";
6589 -- "text_search_data" is updated by triggers
6590 DELETE FROM "member_settings" WHERE "member_id" = "member_id_p";
6591 DELETE FROM "member_profile" WHERE "member_id" = "member_id_p";
6592 DELETE FROM "rendered_member_statement" WHERE "member_id" = "member_id_p";
6593 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
6594 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
6595 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
6596 DELETE FROM "session" WHERE "member_id" = "member_id_p";
6597 DELETE FROM "member_application" WHERE "member_id" = "member_id_p";
6598 DELETE FROM "token" WHERE "member_id" = "member_id_p";
6599 DELETE FROM "subscription" WHERE "member_id" = "member_id_p";
6600 DELETE FROM "ignored_area" WHERE "member_id" = "member_id_p";
6601 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
6602 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
6603 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
6604 DELETE FROM "direct_voter" USING "issue"
6605 WHERE "direct_voter"."issue_id" = "issue"."id"
6606 AND "issue"."closed" ISNULL
6607 AND "member_id" = "member_id_p";
6608 DELETE FROM "notification_initiative_sent" WHERE "member_id" = "member_id_p";
6609 RETURN;
6610 END;
6611 $$;
6613 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)';
6616 CREATE FUNCTION "delete_private_data"()
6617 RETURNS VOID
6618 LANGUAGE 'plpgsql' VOLATILE AS $$
6619 BEGIN
6620 DELETE FROM "temporary_transaction_data";
6621 DELETE FROM "temporary_suggestion_counts";
6622 DELETE FROM "member" WHERE "activated" ISNULL;
6623 UPDATE "member" SET
6624 "invite_code" = NULL,
6625 "invite_code_expiry" = NULL,
6626 "admin_comment" = NULL,
6627 "last_login" = NULL,
6628 "last_delegation_check" = NULL,
6629 "login" = NULL,
6630 "password" = NULL,
6631 "authority" = NULL,
6632 "authority_uid" = NULL,
6633 "authority_login" = NULL,
6634 "lang" = NULL,
6635 "notify_email" = NULL,
6636 "notify_email_unconfirmed" = NULL,
6637 "notify_email_secret" = NULL,
6638 "notify_email_secret_expiry" = NULL,
6639 "notify_email_lock_expiry" = NULL,
6640 "disable_notifications" = TRUE,
6641 "notification_counter" = DEFAULT,
6642 "notification_sample_size" = 0,
6643 "notification_dow" = NULL,
6644 "notification_hour" = NULL,
6645 "notification_sent" = NULL,
6646 "login_recovery_expiry" = NULL,
6647 "password_reset_secret" = NULL,
6648 "password_reset_secret_expiry" = NULL,
6649 "location" = NULL;
6650 -- "text_search_data" is updated by triggers
6651 DELETE FROM "verification";
6652 DELETE FROM "member_settings";
6653 DELETE FROM "member_useterms";
6654 DELETE FROM "member_profile";
6655 DELETE FROM "rendered_member_statement";
6656 DELETE FROM "member_image";
6657 DELETE FROM "contact";
6658 DELETE FROM "ignored_member";
6659 DELETE FROM "session";
6660 DELETE FROM "system_application";
6661 DELETE FROM "system_application_redirect_uri";
6662 DELETE FROM "dynamic_application_scope";
6663 DELETE FROM "member_application";
6664 DELETE FROM "token";
6665 DELETE FROM "subscription";
6666 DELETE FROM "ignored_area";
6667 DELETE FROM "ignored_initiative";
6668 DELETE FROM "non_voter";
6669 DELETE FROM "direct_voter" USING "issue"
6670 WHERE "direct_voter"."issue_id" = "issue"."id"
6671 AND "issue"."closed" ISNULL;
6672 DELETE FROM "event_processed";
6673 DELETE FROM "notification_initiative_sent";
6674 DELETE FROM "newsletter";
6675 RETURN;
6676 END;
6677 $$;
6679 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.';
6683 COMMIT;

Impressum / About Us