liquid_feedback_core

view core.sql @ 583:f5095a9696eb

Added "unsubscribe_secret" column
author jbe
date Sun Nov 18 00:38:59 2018 +0100 (2018-11-18)
parents 225a0c047691
children f9e09710ec60
line source
2 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index
4 BEGIN;
6 CREATE EXTENSION IF NOT EXISTS latlon; -- load pgLatLon extenstion
8 CREATE VIEW "liquid_feedback_version" AS
9 SELECT * FROM (VALUES ('4.1-dev', 4, 1, -1))
10 AS "subquery"("string", "major", "minor", "revision");
14 ----------------------
15 -- Full text search --
16 ----------------------
19 CREATE FUNCTION "text_search_query"("query_text_p" TEXT)
20 RETURNS TSQUERY
21 LANGUAGE 'plpgsql' IMMUTABLE AS $$
22 BEGIN
23 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p");
24 END;
25 $$;
27 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')';
30 CREATE FUNCTION "highlight"
31 ( "body_p" TEXT,
32 "query_text_p" TEXT )
33 RETURNS TEXT
34 LANGUAGE 'plpgsql' IMMUTABLE AS $$
35 BEGIN
36 RETURN ts_headline(
37 'pg_catalog.simple',
38 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'),
39 "text_search_query"("query_text_p"),
40 'StartSel=* StopSel=* HighlightAll=TRUE' );
41 END;
42 $$;
44 COMMENT ON FUNCTION "highlight"
45 ( "body_p" TEXT,
46 "query_text_p" TEXT )
47 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.';
51 -------------------------
52 -- Tables and indicies --
53 -------------------------
56 CREATE TABLE "temporary_transaction_data" (
57 PRIMARY KEY ("txid", "key"),
58 "txid" INT8 DEFAULT txid_current(),
59 "key" TEXT,
60 "value" TEXT NOT NULL );
62 COMMENT ON TABLE "temporary_transaction_data" IS 'Table to store temporary transaction data; shall be emptied before a transaction is committed';
64 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';
67 CREATE TABLE "system_setting" (
68 "member_ttl" INTERVAL,
69 "snapshot_retention" INTERVAL );
70 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1));
72 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.';
73 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.';
75 COMMENT ON COLUMN "system_setting"."member_ttl" IS 'Time after members get their "active" flag set to FALSE, if they do not show any activity.';
76 COMMENT ON COLUMN "system_setting"."snapshot_retention" IS 'Unreferenced snapshots are retained for the given period of time after creation; set to NULL for infinite retention.';
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 );
305 COMMENT ON TABLE "member_useterms" IS 'Keeps record of accepted terms of use; may contain multiple rows per member';
307 COMMENT ON COLUMN "member_useterms"."accepted" IS 'Point in time when user accepted the terms of use';
308 COMMENT ON COLUMN "member_useterms"."contract_identifier" IS 'String identifier to denote the accepted terms of use, including their version or revision';
311 CREATE TABLE "member_profile" (
312 "member_id" INT4 PRIMARY KEY REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
313 "formatting_engine" TEXT,
314 "statement" TEXT,
315 "profile" JSONB NOT NULL DEFAULT '{}' CHECK (jsonb_typeof("profile") = 'object'),
316 "profile_text_data" TEXT,
317 "text_search_data" TSVECTOR );
318 CREATE INDEX "member_profile_text_search_data_idx" ON "member_profile" USING gin ("text_search_data");
319 CREATE TRIGGER "update_text_search_data"
320 BEFORE INSERT OR UPDATE ON "member_profile"
321 FOR EACH ROW EXECUTE PROCEDURE
322 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
323 'statement', 'profile_text_data');
325 COMMENT ON COLUMN "member_profile"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member_profile"."statement"';
326 COMMENT ON COLUMN "member_profile"."statement" IS 'Freely chosen text of the member for his/her profile';
327 COMMENT ON COLUMN "member_profile"."profile" IS 'Additional profile data as JSON document';
328 COMMENT ON COLUMN "member_profile"."profile_text_data" IS 'Text data from "profile" field for full text search';
331 CREATE TABLE "rendered_member_statement" (
332 PRIMARY KEY ("member_id", "format"),
333 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
334 "format" TEXT,
335 "content" TEXT NOT NULL );
337 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)';
340 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
342 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
345 CREATE TABLE "member_image" (
346 PRIMARY KEY ("member_id", "image_type", "scaled"),
347 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
348 "image_type" "member_image_type",
349 "scaled" BOOLEAN,
350 "content_type" TEXT,
351 "data" BYTEA NOT NULL );
353 COMMENT ON TABLE "member_image" IS 'Images of members';
355 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
358 CREATE TABLE "member_count" (
359 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
360 "total_count" INT4 NOT NULL );
362 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';
364 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
365 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
368 CREATE TABLE "contact" (
369 PRIMARY KEY ("member_id", "other_member_id"),
370 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
371 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
372 "public" BOOLEAN NOT NULL DEFAULT FALSE,
373 CONSTRAINT "cant_save_yourself_as_contact"
374 CHECK ("member_id" != "other_member_id") );
375 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
377 COMMENT ON TABLE "contact" IS 'Contact lists';
379 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
380 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
381 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
384 CREATE TABLE "ignored_member" (
385 PRIMARY KEY ("member_id", "other_member_id"),
386 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
387 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
388 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
390 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
392 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
393 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
396 CREATE TABLE "session" (
397 UNIQUE ("member_id", "id"), -- index needed for foreign-key on table "token"
398 "id" SERIAL8 PRIMARY KEY,
399 "ident" TEXT NOT NULL UNIQUE,
400 "additional_secret" TEXT,
401 "logout_token" TEXT,
402 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
403 "member_id" INT4 REFERENCES "member" ("id") ON DELETE SET NULL,
404 "real_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
405 "authority" TEXT,
406 "authority_uid" TEXT,
407 "authority_login" TEXT,
408 "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE,
409 "lang" TEXT );
410 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
412 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
414 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
415 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
416 COMMENT ON COLUMN "session"."logout_token" IS 'Optional token to authorize logout through external component';
417 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in, or role account in use';
418 COMMENT ON COLUMN "session"."real_member_id" IS 'Reference to member, who is really logged in (real person rather than role account)';
419 COMMENT ON COLUMN "session"."authority" IS 'Temporary store for "member"."authority" during member account creation';
420 COMMENT ON COLUMN "session"."authority_uid" IS 'Temporary store for "member"."authority_uid" during member account creation';
421 COMMENT ON COLUMN "session"."authority_login" IS 'Temporary store for "member"."authority_login" during member account creation';
422 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';
423 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
426 CREATE TYPE "authflow" AS ENUM ('code', 'token');
428 COMMENT ON TYPE "authflow" IS 'OAuth 2.0 flows: ''code'' = Authorization Code flow, ''token'' = Implicit flow';
431 CREATE TABLE "system_application" (
432 "id" SERIAL4 PRIMARY KEY,
433 "name" TEXT NOT NULL,
434 "base_url" TEXT,
435 "manifest_url" TEXT,
436 "client_id" TEXT NOT NULL UNIQUE,
437 "default_redirect_uri" TEXT NOT NULL,
438 "cert_common_name" TEXT,
439 "client_cred_scope" TEXT,
440 "flow" "authflow",
441 "automatic_scope" TEXT,
442 "permitted_scope" TEXT,
443 "forbidden_scope" TEXT );
445 COMMENT ON TABLE "system_application" IS 'OAuth 2.0 clients that are registered by the system administrator';
447 COMMENT ON COLUMN "system_application"."name" IS 'Human readable name of application';
448 COMMENT ON COLUMN "system_application"."base_url" IS 'Base URL for users';
449 COMMENT ON COLUMN "system_application"."manifest_url" IS 'URL referring to a manifest that can be used for application (type/version) discovery';
450 COMMENT ON COLUMN "system_application"."client_id" IS 'OAuth 2.0 "client_id"';
451 COMMENT ON COLUMN "system_application"."cert_common_name" IS 'Value for CN field of TLS client certificate';
452 COMMENT ON COLUMN "system_application"."client_cred_scope" IS 'Space-separated list of scopes; If set, Client Credentials Grant is allowed; value determines scope';
453 COMMENT ON COLUMN "system_application"."flow" IS 'If set to ''code'' or ''token'', then Authorization Code or Implicit flow is allowed respectively';
454 COMMENT ON COLUMN "system_application"."automatic_scope" IS 'Space-separated list of scopes; Automatically granted scope for Authorization Code or Implicit flow';
455 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';
456 COMMENT ON COLUMN "system_application"."forbidden_scope" IS 'Space-separated list of scopes that may not be granted to the application by a member';
459 CREATE TABLE "system_application_redirect_uri" (
460 PRIMARY KEY ("system_application_id", "redirect_uri"),
461 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
462 "redirect_uri" TEXT );
464 COMMENT ON TABLE "system_application_redirect_uri" IS 'Additional OAuth 2.0 redirection endpoints, which may be selected through the "redirect_uri" GET parameter';
467 CREATE TABLE "dynamic_application_scope" (
468 PRIMARY KEY ("redirect_uri", "flow", "scope"),
469 "redirect_uri" TEXT,
470 "flow" TEXT,
471 "scope" TEXT,
472 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours' );
473 CREATE INDEX "dynamic_application_scope_redirect_uri_scope_idx" ON "dynamic_application_scope" ("redirect_uri", "flow", "scope");
474 CREATE INDEX "dynamic_application_scope_expiry_idx" ON "dynamic_application_scope" ("expiry");
476 COMMENT ON TABLE "dynamic_application_scope" IS 'Dynamic OAuth 2.0 client registration data';
478 COMMENT ON COLUMN "dynamic_application_scope"."redirect_uri" IS 'Redirection endpoint for which the registration has been done';
479 COMMENT ON COLUMN "dynamic_application_scope"."flow" IS 'OAuth 2.0 flow for which the registration has been done (see also "system_application"."flow")';
480 COMMENT ON COLUMN "dynamic_application_scope"."scope" IS 'Single scope without space characters (use multiple rows for more scopes)';
481 COMMENT ON COLUMN "dynamic_application_scope"."expiry" IS 'Expiry unless renewed';
484 CREATE TABLE "member_application" (
485 "id" SERIAL4 PRIMARY KEY,
486 UNIQUE ("system_application_id", "member_id"),
487 UNIQUE ("domain", "member_id"),
488 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
489 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
490 "domain" TEXT,
491 "session_id" INT8,
492 FOREIGN KEY ("member_id", "session_id") REFERENCES "session" ("member_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
493 "scope" TEXT NOT NULL,
494 CONSTRAINT "system_application_or_domain_but_not_both" CHECK (
495 ("system_application_id" NOTNULL AND "domain" ISNULL) OR
496 ("system_application_id" ISNULL AND "domain" NOTNULL) ) );
497 CREATE INDEX "member_application_member_id_idx" ON "member_application" ("member_id");
499 COMMENT ON TABLE "member_application" IS 'Application authorized by a member';
501 COMMENT ON COLUMN "member_application"."system_application_id" IS 'If set, then application is a system application';
502 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';
503 COMMENT ON COLUMN "member_application"."session_id" IS 'If set, registration ends with session';
504 COMMENT ON COLUMN "member_application"."scope" IS 'Granted scope as space-separated list of strings';
507 CREATE TYPE "token_type" AS ENUM ('authorization', 'refresh', 'access');
509 COMMENT ON TYPE "token_type" IS 'Types for entries in "token" table';
512 CREATE TABLE "token" (
513 "id" SERIAL8 PRIMARY KEY,
514 "token" TEXT NOT NULL UNIQUE,
515 "token_type" "token_type" NOT NULL,
516 "authorization_token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
517 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
518 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
519 "domain" TEXT,
520 FOREIGN KEY ("member_id", "domain") REFERENCES "member_application" ("member_id", "domain") ON DELETE CASCADE ON UPDATE CASCADE,
521 "session_id" INT8,
522 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"
523 "redirect_uri" TEXT,
524 "redirect_uri_explicit" BOOLEAN,
525 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
526 "expiry" TIMESTAMPTZ DEFAULT now() + '1 hour',
527 "used" BOOLEAN NOT NULL DEFAULT FALSE,
528 "scope" TEXT NOT NULL,
529 CONSTRAINT "access_token_needs_expiry"
530 CHECK ("token_type" != 'access'::"token_type" OR "expiry" NOTNULL),
531 CONSTRAINT "authorization_token_needs_redirect_uri"
532 CHECK ("token_type" != 'authorization'::"token_type" OR ("redirect_uri" NOTNULL AND "redirect_uri_explicit" NOTNULL) ) );
533 CREATE INDEX "token_member_id_idx" ON "token" ("member_id");
534 CREATE INDEX "token_authorization_token_id_idx" ON "token" ("authorization_token_id");
535 CREATE INDEX "token_expiry_idx" ON "token" ("expiry");
537 COMMENT ON TABLE "token" IS 'Issued OAuth 2.0 authorization codes and access/refresh tokens';
539 COMMENT ON COLUMN "token"."token" IS 'String secret (the actual token)';
540 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)';
541 COMMENT ON COLUMN "token"."system_application_id" IS 'If set, then application is a system application';
542 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';
543 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''';
544 COMMENT ON COLUMN "token"."redirect_uri" IS 'Authorization codes must be bound to a specific redirect URI';
545 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)';
546 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';
547 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)';
548 COMMENT ON COLUMN "token"."scope" IS 'Scope as space-separated list of strings (detached scopes are marked with ''_detached'' suffix)';
551 CREATE TABLE "token_scope" (
552 PRIMARY KEY ("token_id", "index"),
553 "token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
554 "index" INT4,
555 "scope" TEXT NOT NULL );
557 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';
560 CREATE TYPE "defeat_strength" AS ENUM ('simple', 'tuple');
562 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';
565 CREATE TYPE "tie_breaking" AS ENUM ('simple', 'variant1', 'variant2');
567 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';
570 CREATE TABLE "policy" (
571 "id" SERIAL4 PRIMARY KEY,
572 "index" INT4 NOT NULL,
573 "active" BOOLEAN NOT NULL DEFAULT TRUE,
574 "name" TEXT NOT NULL UNIQUE,
575 "description" TEXT NOT NULL DEFAULT '',
576 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
577 "min_admission_time" INTERVAL,
578 "max_admission_time" INTERVAL,
579 "discussion_time" INTERVAL,
580 "verification_time" INTERVAL,
581 "voting_time" INTERVAL,
582 "issue_quorum" INT4 CHECK ("issue_quorum" >= 1),
583 "issue_quorum_num" INT4,
584 "issue_quorum_den" INT4,
585 "initiative_quorum" INT4 NOT NULL CHECK ("initiative_quorum" >= 1),
586 "initiative_quorum_num" INT4 NOT NULL,
587 "initiative_quorum_den" INT4 NOT NULL,
588 "defeat_strength" "defeat_strength" NOT NULL DEFAULT 'tuple',
589 "tie_breaking" "tie_breaking" NOT NULL DEFAULT 'variant1',
590 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
591 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
592 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
593 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
594 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
595 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
596 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
597 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
598 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
599 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
600 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT FALSE,
601 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
602 CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK (
603 "polling" = ("issue_quorum" ISNULL) AND
604 "polling" = ("issue_quorum_num" ISNULL) AND
605 "polling" = ("issue_quorum_den" ISNULL) ),
606 CONSTRAINT "min_admission_time_smaller_than_max_admission_time" CHECK (
607 "min_admission_time" < "max_admission_time" ),
608 CONSTRAINT "timing_null_or_not_null_constraints" CHECK (
609 ( "polling" = FALSE AND
610 "min_admission_time" NOTNULL AND "max_admission_time" NOTNULL AND
611 "discussion_time" NOTNULL AND
612 "verification_time" NOTNULL AND
613 "voting_time" NOTNULL ) OR
614 ( "polling" = TRUE AND
615 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
616 "discussion_time" NOTNULL AND
617 "verification_time" NOTNULL AND
618 "voting_time" NOTNULL ) OR
619 ( "polling" = TRUE AND
620 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
621 "discussion_time" ISNULL AND
622 "verification_time" ISNULL AND
623 "voting_time" ISNULL ) ),
624 CONSTRAINT "no_reverse_beat_path_requires_tuple_defeat_strength" CHECK (
625 "defeat_strength" = 'tuple'::"defeat_strength" OR
626 "no_reverse_beat_path" = FALSE ) );
627 CREATE INDEX "policy_active_idx" ON "policy" ("active");
629 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
631 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
632 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
633 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';
634 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"';
635 COMMENT ON COLUMN "policy"."max_admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
636 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
637 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"';
638 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'')';
639 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';
640 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)';
641 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)';
642 COMMENT ON COLUMN "policy"."initiative_quorum" IS 'Absolute number of satisfied supporters to be reached by an initiative to be "admitted" for voting';
643 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
644 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
645 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';
646 COMMENT ON COLUMN "policy"."tie_breaking" IS 'Tie-breaker for the Schulze method; see type "tie_breaking"; ''variant1'' or ''variant2'' are recommended';
647 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
648 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
649 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.';
650 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
651 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';
652 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';
653 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';
654 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.';
655 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';
656 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';
657 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.';
658 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").';
661 CREATE TABLE "unit" (
662 "id" SERIAL4 PRIMARY KEY,
663 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
664 "active" BOOLEAN NOT NULL DEFAULT TRUE,
665 "name" TEXT NOT NULL,
666 "description" TEXT NOT NULL DEFAULT '',
667 "external_reference" TEXT,
668 "member_count" INT4,
669 "location" JSONB,
670 "text_search_data" TSVECTOR );
671 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
672 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
673 CREATE INDEX "unit_active_idx" ON "unit" ("active");
674 CREATE INDEX "unit_location_idx" ON "unit" USING gist ((GeoJSON_to_ecluster("location")));
675 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
676 CREATE TRIGGER "update_text_search_data"
677 BEFORE INSERT OR UPDATE ON "unit"
678 FOR EACH ROW EXECUTE PROCEDURE
679 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
680 "name", "description" );
682 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
684 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
685 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
686 COMMENT ON COLUMN "unit"."external_reference" IS 'Opaque data field to store an external reference';
687 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege" (only active members counted)';
688 COMMENT ON COLUMN "unit"."location" IS 'Geographic location on earth as GeoJSON object indicating valid coordinates for initiatives of issues with this policy';
691 CREATE TABLE "subscription" (
692 PRIMARY KEY ("member_id", "unit_id"),
693 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
694 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
695 CREATE INDEX "subscription_unit_id_idx" ON "subscription" ("unit_id");
697 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';
700 CREATE TABLE "area" (
701 UNIQUE ("unit_id", "id"), -- index needed for foreign-key on table "event"
702 "id" SERIAL4 PRIMARY KEY,
703 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
704 "active" BOOLEAN NOT NULL DEFAULT TRUE,
705 "name" TEXT NOT NULL,
706 "description" TEXT NOT NULL DEFAULT '',
707 "quorum_standard" NUMERIC NOT NULL DEFAULT 2 CHECK ("quorum_standard" >= 0),
708 "quorum_issues" NUMERIC NOT NULL DEFAULT 1 CHECK ("quorum_issues" > 0),
709 "quorum_time" INTERVAL NOT NULL DEFAULT '1 day' CHECK ("quorum_time" > '0'::INTERVAL),
710 "quorum_exponent" NUMERIC NOT NULL DEFAULT 0.5 CHECK ("quorum_exponent" BETWEEN 0 AND 1),
711 "quorum_factor" NUMERIC NOT NULL DEFAULT 2 CHECK ("quorum_factor" >= 1),
712 "quorum_den" INT4 CHECK ("quorum_den" > 0),
713 "issue_quorum" INT4,
714 "external_reference" TEXT,
715 "location" JSONB,
716 "text_search_data" TSVECTOR );
717 CREATE INDEX "area_active_idx" ON "area" ("active");
718 CREATE INDEX "area_location_idx" ON "area" USING gist ((GeoJSON_to_ecluster("location")));
719 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
720 CREATE TRIGGER "update_text_search_data"
721 BEFORE INSERT OR UPDATE ON "area"
722 FOR EACH ROW EXECUTE PROCEDURE
723 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
724 "name", "description" );
726 COMMENT ON TABLE "area" IS 'Subject areas';
728 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
729 COMMENT ON COLUMN "area"."quorum_standard" IS 'Parameter for dynamic issue quorum: default quorum';
730 COMMENT ON COLUMN "area"."quorum_issues" IS 'Parameter for dynamic issue quorum: number of open issues for default quorum';
731 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)';
732 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';
733 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';
734 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)';
735 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"';
736 COMMENT ON COLUMN "area"."external_reference" IS 'Opaque data field to store an external reference';
737 COMMENT ON COLUMN "area"."location" IS 'Geographic location on earth as GeoJSON object indicating valid coordinates for initiatives of issues with this policy';
740 CREATE TABLE "ignored_area" (
741 PRIMARY KEY ("member_id", "area_id"),
742 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
743 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
744 CREATE INDEX "ignored_area_area_id_idx" ON "ignored_area" ("area_id");
746 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';
749 CREATE TABLE "allowed_policy" (
750 PRIMARY KEY ("area_id", "policy_id"),
751 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
752 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
753 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
754 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
756 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
758 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
761 CREATE TABLE "snapshot" (
762 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "issue"
763 "id" SERIAL8 PRIMARY KEY,
764 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
765 "population" INT4,
766 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
767 "issue_id" INT4 ); -- NOTE: following (cyclic) reference is added later through ALTER command: REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE
769 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';
772 CREATE TABLE "snapshot_population" (
773 PRIMARY KEY ("snapshot_id", "member_id"),
774 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
775 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE );
777 COMMENT ON TABLE "snapshot_population" IS 'Members with voting right relevant for a snapshot';
780 CREATE TYPE "issue_state" AS ENUM (
781 'admission', 'discussion', 'verification', 'voting',
782 'canceled_by_admin',
783 'canceled_revoked_before_accepted',
784 'canceled_issue_not_accepted',
785 'canceled_after_revocation_during_discussion',
786 'canceled_after_revocation_during_verification',
787 'canceled_no_initiative_admitted',
788 'finished_without_winner', 'finished_with_winner');
790 COMMENT ON TYPE "issue_state" IS 'State of issues';
793 CREATE TABLE "issue" (
794 UNIQUE ("area_id", "id"), -- index needed for foreign-key on table "event"
795 UNIQUE ("policy_id", "id"), -- index needed for foreign-key on table "event"
796 "id" SERIAL4 PRIMARY KEY,
797 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
798 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
799 "admin_notice" TEXT,
800 "external_reference" TEXT,
801 "state" "issue_state" NOT NULL DEFAULT 'admission',
802 "phase_finished" TIMESTAMPTZ,
803 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
804 "accepted" TIMESTAMPTZ,
805 "half_frozen" TIMESTAMPTZ,
806 "fully_frozen" TIMESTAMPTZ,
807 "closed" TIMESTAMPTZ,
808 "cleaned" TIMESTAMPTZ,
809 "min_admission_time" INTERVAL,
810 "max_admission_time" INTERVAL,
811 "discussion_time" INTERVAL NOT NULL,
812 "verification_time" INTERVAL NOT NULL,
813 "voting_time" INTERVAL NOT NULL,
814 "calculated" TIMESTAMPTZ, -- NOTE: copy of "calculated" column of latest snapshot, but no referential integrity to avoid overhead
815 "latest_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
816 "admission_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
817 "half_freeze_snapshot_id" INT8,
818 FOREIGN KEY ("id", "half_freeze_snapshot_id")
819 REFERENCES "snapshot" ("issue_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE,
820 "full_freeze_snapshot_id" INT8,
821 FOREIGN KEY ("id", "full_freeze_snapshot_id")
822 REFERENCES "snapshot" ("issue_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE,
823 "issue_quorum" INT4,
824 "initiative_quorum" INT4,
825 "population" INT4,
826 "voter_count" INT4,
827 "status_quo_schulze_rank" INT4,
828 CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK (
829 ("min_admission_time" NOTNULL) = ("max_admission_time" NOTNULL) AND
830 ("min_admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created")) ),
831 CONSTRAINT "valid_state" CHECK (
832 (
833 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
834 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
835 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL ) OR
836 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL)
837 ) AND (
838 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
839 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
840 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
841 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
842 ("state" = 'canceled_by_admin' AND "closed" NOTNULL) OR
843 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
844 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
845 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
846 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
847 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" = "fully_frozen") OR
848 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") OR
849 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen")
850 )),
851 CONSTRAINT "phase_finished_only_when_not_closed" CHECK (
852 "phase_finished" ISNULL OR "closed" ISNULL ),
853 CONSTRAINT "state_change_order" CHECK (
854 "created" <= "accepted" AND
855 "accepted" <= "half_frozen" AND
856 "half_frozen" <= "fully_frozen" AND
857 "fully_frozen" <= "closed" ),
858 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
859 "cleaned" ISNULL OR "closed" NOTNULL ),
860 CONSTRAINT "snapshot_required" CHECK (
861 --("accepted" ISNULL OR "admission_snapshot_id" NOTNULL) AND
862 ("half_frozen" ISNULL OR "half_freeze_snapshot_id" NOTNULL) AND
863 ("fully_frozen" ISNULL OR "full_freeze_snapshot_id" NOTNULL) ) );
864 CREATE INDEX "issue_state_idx" ON "issue" ("state");
865 CREATE INDEX "issue_created_idx" ON "issue" ("created");
866 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
867 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
868 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
869 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
870 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
871 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
872 CREATE INDEX "issue_latest_snapshot_id" ON "issue" ("latest_snapshot_id");
873 CREATE INDEX "issue_admission_snapshot_id" ON "issue" ("admission_snapshot_id");
874 CREATE INDEX "issue_half_freeze_snapshot_id" ON "issue" ("half_freeze_snapshot_id");
875 CREATE INDEX "issue_full_freeze_snapshot_id" ON "issue" ("full_freeze_snapshot_id");
877 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
879 COMMENT ON COLUMN "issue"."admin_notice" IS 'Public notice by admin to explain manual interventions, or to announce corrections';
880 COMMENT ON COLUMN "issue"."external_reference" IS 'Opaque data field to store an external reference';
881 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';
882 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")';
883 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.';
884 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.';
885 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.';
886 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
887 COMMENT ON COLUMN "issue"."min_admission_time" IS 'Copied from "policy" table at creation of issue';
888 COMMENT ON COLUMN "issue"."max_admission_time" IS 'Copied from "policy" table at creation of issue';
889 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
890 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
891 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
892 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")';
893 COMMENT ON COLUMN "issue"."latest_snapshot_id" IS 'Snapshot id of most recent snapshot';
894 COMMENT ON COLUMN "issue"."admission_snapshot_id" IS 'Snapshot id when issue as accepted or canceled in admission phase';
895 COMMENT ON COLUMN "issue"."half_freeze_snapshot_id" IS 'Snapshot id at end of discussion phase';
896 COMMENT ON COLUMN "issue"."full_freeze_snapshot_id" IS 'Snapshot id at end of verification phase';
897 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';
898 COMMENT ON COLUMN "issue"."initiative_quorum" IS 'Calculated number of satisfied supporters to be reached by an initiative to be "admitted" for voting';
899 COMMENT ON COLUMN "issue"."population" IS 'Count of members in "snapshot_population" table with "snapshot_id" equal to "issue"."latest_snapshot_id"';
900 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';
901 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
904 ALTER TABLE "snapshot" ADD FOREIGN KEY ("issue_id") REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE;
907 CREATE TABLE "issue_order_in_admission_state" (
908 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performans/locking issues; REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
909 "order_in_area" INT4,
910 "order_in_unit" INT4 );
912 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"';
914 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';
915 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';
916 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';
919 CREATE TABLE "initiative" (
920 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
921 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
922 "id" SERIAL4 PRIMARY KEY,
923 "name" TEXT NOT NULL,
924 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
925 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
926 "revoked" TIMESTAMPTZ,
927 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
928 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
929 "location" JSONB,
930 "external_reference" TEXT,
931 "admitted" BOOLEAN,
932 "supporter_count" INT4,
933 "informed_supporter_count" INT4,
934 "satisfied_supporter_count" INT4,
935 "satisfied_informed_supporter_count" INT4,
936 "harmonic_weight" NUMERIC(12, 3),
937 "final_suggestion_order_calculated" BOOLEAN NOT NULL DEFAULT FALSE,
938 "first_preference_votes" INT4,
939 "positive_votes" INT4,
940 "negative_votes" INT4,
941 "direct_majority" BOOLEAN,
942 "indirect_majority" BOOLEAN,
943 "schulze_rank" INT4,
944 "better_than_status_quo" BOOLEAN,
945 "worse_than_status_quo" BOOLEAN,
946 "reverse_beat_path" BOOLEAN,
947 "multistage_majority" BOOLEAN,
948 "eligible" BOOLEAN,
949 "winner" BOOLEAN,
950 "rank" INT4,
951 "text_search_data" TSVECTOR,
952 "draft_text_search_data" TSVECTOR,
953 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
954 CHECK (("revoked" NOTNULL) = ("revoked_by_member_id" NOTNULL)),
955 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
956 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
957 CONSTRAINT "revoked_initiatives_cant_be_admitted"
958 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
959 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
960 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
961 ( "first_preference_votes" ISNULL AND
962 "positive_votes" ISNULL AND "negative_votes" ISNULL AND
963 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
964 "schulze_rank" ISNULL AND
965 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
966 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
967 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
968 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
969 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
970 "eligible" = FALSE OR
971 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
972 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
973 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
974 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
975 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
976 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
977 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
978 CREATE INDEX "initiative_location_idx" ON "initiative" USING gist ((GeoJSON_to_ecluster("location")));
979 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
980 CREATE INDEX "initiative_draft_text_search_data_idx" ON "initiative" USING gin ("draft_text_search_data");
981 CREATE TRIGGER "update_text_search_data"
982 BEFORE INSERT OR UPDATE ON "initiative"
983 FOR EACH ROW EXECUTE PROCEDURE
984 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "name");
986 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.';
988 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
989 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
990 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
991 COMMENT ON COLUMN "initiative"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied from most recent draft)';
992 COMMENT ON COLUMN "initiative"."external_reference" IS 'Opaque data field to store an external reference';
993 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
994 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
995 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
996 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
997 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
998 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';
999 COMMENT ON COLUMN "initiative"."final_suggestion_order_calculated" IS 'Set to TRUE, when "proportional_order" of suggestions has been calculated the last time';
1000 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
1001 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
1002 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
1003 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"';
1004 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
1005 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking';
1006 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo';
1007 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)';
1008 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''';
1009 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';
1010 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"';
1011 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"';
1012 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';
1015 CREATE TABLE "battle" (
1016 "issue_id" INT4 NOT NULL,
1017 "winning_initiative_id" INT4,
1018 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1019 "losing_initiative_id" INT4,
1020 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1021 "count" INT4 NOT NULL,
1022 CONSTRAINT "initiative_ids_not_equal" CHECK (
1023 "winning_initiative_id" != "losing_initiative_id" OR
1024 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
1025 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
1026 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
1027 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
1028 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
1030 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';
1033 CREATE TABLE "ignored_initiative" (
1034 PRIMARY KEY ("member_id", "initiative_id"),
1035 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1036 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1037 CREATE INDEX "ignored_initiative_initiative_id_idx" ON "ignored_initiative" ("initiative_id");
1039 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';
1042 CREATE TABLE "draft" (
1043 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
1044 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1045 "id" SERIAL8 PRIMARY KEY,
1046 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1047 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1048 "formatting_engine" TEXT,
1049 "content" TEXT NOT NULL,
1050 "location" JSONB,
1051 "external_reference" TEXT,
1052 "text_search_data" TSVECTOR );
1053 CREATE INDEX "draft_created_idx" ON "draft" ("created");
1054 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
1055 CREATE INDEX "draft_location_idx" ON "draft" USING gist ((GeoJSON_to_ecluster("location")));
1056 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
1057 CREATE TRIGGER "update_text_search_data"
1058 BEFORE INSERT OR UPDATE ON "draft"
1059 FOR EACH ROW EXECUTE PROCEDURE
1060 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1062 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.';
1064 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
1065 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
1066 COMMENT ON COLUMN "draft"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied to "initiative" table if draft is most recent)';
1067 COMMENT ON COLUMN "draft"."external_reference" IS 'Opaque data field to store an external reference';
1070 CREATE TABLE "rendered_draft" (
1071 PRIMARY KEY ("draft_id", "format"),
1072 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1073 "format" TEXT,
1074 "content" TEXT NOT NULL );
1076 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)';
1079 CREATE TABLE "suggestion" (
1080 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
1081 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1082 "id" SERIAL8 PRIMARY KEY,
1083 "draft_id" INT8 NOT NULL,
1084 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1085 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1086 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1087 "name" TEXT NOT NULL,
1088 "formatting_engine" TEXT,
1089 "content" TEXT NOT NULL DEFAULT '',
1090 "location" JSONB,
1091 "external_reference" TEXT,
1092 "text_search_data" TSVECTOR,
1093 "minus2_unfulfilled_count" INT4,
1094 "minus2_fulfilled_count" INT4,
1095 "minus1_unfulfilled_count" INT4,
1096 "minus1_fulfilled_count" INT4,
1097 "plus1_unfulfilled_count" INT4,
1098 "plus1_fulfilled_count" INT4,
1099 "plus2_unfulfilled_count" INT4,
1100 "plus2_fulfilled_count" INT4,
1101 "proportional_order" INT4 );
1102 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
1103 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
1104 CREATE INDEX "suggestion_location_idx" ON "suggestion" USING gist ((GeoJSON_to_ecluster("location")));
1105 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
1106 CREATE TRIGGER "update_text_search_data"
1107 BEFORE INSERT OR UPDATE ON "suggestion"
1108 FOR EACH ROW EXECUTE PROCEDURE
1109 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
1110 "name", "content");
1112 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';
1114 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")';
1115 COMMENT ON COLUMN "suggestion"."location" IS 'Geographic location of suggestion as GeoJSON object';
1116 COMMENT ON COLUMN "suggestion"."external_reference" IS 'Opaque data field to store an external reference';
1117 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1118 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1119 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1120 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1121 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1122 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1123 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1124 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1125 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"';
1128 CREATE TABLE "rendered_suggestion" (
1129 PRIMARY KEY ("suggestion_id", "format"),
1130 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1131 "format" TEXT,
1132 "content" TEXT NOT NULL );
1134 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)';
1137 CREATE TABLE "temporary_suggestion_counts" (
1138 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performance/locking issues; REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1139 "minus2_unfulfilled_count" INT4 NOT NULL,
1140 "minus2_fulfilled_count" INT4 NOT NULL,
1141 "minus1_unfulfilled_count" INT4 NOT NULL,
1142 "minus1_fulfilled_count" INT4 NOT NULL,
1143 "plus1_unfulfilled_count" INT4 NOT NULL,
1144 "plus1_fulfilled_count" INT4 NOT NULL,
1145 "plus2_unfulfilled_count" INT4 NOT NULL,
1146 "plus2_fulfilled_count" INT4 NOT NULL );
1148 COMMENT ON TABLE "temporary_suggestion_counts" IS 'Holds certain calculated values (suggestion counts) temporarily until they can be copied into table "suggestion"';
1150 COMMENT ON COLUMN "temporary_suggestion_counts"."id" IS 'References "suggestion" ("id") but has no referential integrity trigger associated, due to performance/locking issues';
1153 CREATE TABLE "privilege" (
1154 PRIMARY KEY ("unit_id", "member_id"),
1155 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1156 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1157 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1158 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1159 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1160 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1161 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
1162 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
1163 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
1165 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
1167 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
1168 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
1169 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
1170 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
1171 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
1172 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
1173 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';
1176 CREATE TABLE "interest" (
1177 PRIMARY KEY ("issue_id", "member_id"),
1178 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1179 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE );
1180 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
1182 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.';
1185 CREATE TABLE "initiator" (
1186 PRIMARY KEY ("initiative_id", "member_id"),
1187 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1188 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1189 "accepted" BOOLEAN );
1190 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
1192 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.';
1194 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.';
1197 CREATE TABLE "supporter" (
1198 "issue_id" INT4 NOT NULL,
1199 PRIMARY KEY ("initiative_id", "member_id"),
1200 "initiative_id" INT4,
1201 "member_id" INT4,
1202 "draft_id" INT8 NOT NULL,
1203 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1204 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
1205 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
1207 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.';
1209 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1210 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")';
1213 CREATE TABLE "opinion" (
1214 "initiative_id" INT4 NOT NULL,
1215 PRIMARY KEY ("suggestion_id", "member_id"),
1216 "suggestion_id" INT8,
1217 "member_id" INT4,
1218 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
1219 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
1220 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1221 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1222 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
1224 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.';
1226 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
1229 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
1231 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
1234 CREATE TABLE "delegation" (
1235 "id" SERIAL8 PRIMARY KEY,
1236 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1237 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1238 "scope" "delegation_scope" NOT NULL,
1239 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1240 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1241 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1242 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
1243 CONSTRAINT "no_unit_delegation_to_null"
1244 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
1245 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
1246 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
1247 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
1248 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
1249 UNIQUE ("unit_id", "truster_id"),
1250 UNIQUE ("area_id", "truster_id"),
1251 UNIQUE ("issue_id", "truster_id") );
1252 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
1253 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
1255 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
1257 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
1258 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
1259 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
1262 CREATE TABLE "snapshot_issue" (
1263 PRIMARY KEY ("snapshot_id", "issue_id"),
1264 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1265 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); -- NOTE: trigger "delete_snapshot_on_partial_delete" will delete whole "snapshot"
1266 CREATE INDEX "snapshot_issue_issue_id_idx" ON "snapshot_issue" ("issue_id");
1268 COMMENT ON TABLE "snapshot_issue" IS 'List of issues included in a snapshot';
1270 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.';
1273 CREATE TABLE "direct_interest_snapshot" (
1274 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1275 "snapshot_id" INT8,
1276 "issue_id" INT4,
1277 FOREIGN KEY ("snapshot_id", "issue_id")
1278 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1279 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1280 "weight" INT4 );
1281 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
1283 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';
1285 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
1288 CREATE TABLE "delegating_interest_snapshot" (
1289 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1290 "snapshot_id" INT8,
1291 "issue_id" INT4,
1292 FOREIGN KEY ("snapshot_id", "issue_id")
1293 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1294 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1295 "weight" INT4,
1296 "scope" "delegation_scope" NOT NULL,
1297 "delegate_member_ids" INT4[] NOT NULL );
1298 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
1300 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';
1302 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
1303 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
1304 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"';
1307 CREATE TABLE "direct_supporter_snapshot" (
1308 PRIMARY KEY ("snapshot_id", "initiative_id", "member_id"),
1309 "snapshot_id" INT8,
1310 "issue_id" INT4 NOT NULL,
1311 FOREIGN KEY ("snapshot_id", "issue_id")
1312 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1313 "initiative_id" INT4,
1314 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1315 "draft_id" INT8 NOT NULL,
1316 "informed" BOOLEAN NOT NULL,
1317 "satisfied" BOOLEAN NOT NULL,
1318 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1319 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1320 FOREIGN KEY ("snapshot_id", "issue_id", "member_id") REFERENCES "direct_interest_snapshot" ("snapshot_id", "issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1321 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1323 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';
1325 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';
1326 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1327 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1330 CREATE TABLE "non_voter" (
1331 PRIMARY KEY ("member_id", "issue_id"),
1332 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1333 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1334 CREATE INDEX "non_voter_issue_id_idx" ON "non_voter" ("issue_id");
1336 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1339 CREATE TABLE "direct_voter" (
1340 PRIMARY KEY ("issue_id", "member_id"),
1341 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1342 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1343 "weight" INT4,
1344 "comment_changed" TIMESTAMPTZ,
1345 "formatting_engine" TEXT,
1346 "comment" TEXT,
1347 "text_search_data" TSVECTOR );
1348 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1349 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
1350 CREATE TRIGGER "update_text_search_data"
1351 BEFORE INSERT OR UPDATE ON "direct_voter"
1352 FOR EACH ROW EXECUTE PROCEDURE
1353 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
1355 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';
1357 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1358 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';
1359 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';
1360 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.';
1363 CREATE TABLE "rendered_voter_comment" (
1364 PRIMARY KEY ("issue_id", "member_id", "format"),
1365 FOREIGN KEY ("issue_id", "member_id")
1366 REFERENCES "direct_voter" ("issue_id", "member_id")
1367 ON DELETE CASCADE ON UPDATE CASCADE,
1368 "issue_id" INT4,
1369 "member_id" INT4,
1370 "format" TEXT,
1371 "content" TEXT NOT NULL );
1373 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)';
1376 CREATE TABLE "delegating_voter" (
1377 PRIMARY KEY ("issue_id", "member_id"),
1378 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1379 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1380 "weight" INT4,
1381 "scope" "delegation_scope" NOT NULL,
1382 "delegate_member_ids" INT4[] NOT NULL );
1383 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1385 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';
1387 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1388 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1389 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"';
1392 CREATE TABLE "vote" (
1393 "issue_id" INT4 NOT NULL,
1394 PRIMARY KEY ("initiative_id", "member_id"),
1395 "initiative_id" INT4,
1396 "member_id" INT4,
1397 "grade" INT4 NOT NULL,
1398 "first_preference" BOOLEAN,
1399 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1400 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1401 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
1402 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
1403 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1405 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';
1407 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1408 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.';
1409 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.';
1412 CREATE TYPE "event_type" AS ENUM (
1413 'unit_created',
1414 'unit_updated',
1415 'area_created',
1416 'area_updated',
1417 'policy_created',
1418 'policy_updated',
1419 'issue_state_changed',
1420 'initiative_created_in_new_issue',
1421 'initiative_created_in_existing_issue',
1422 'initiative_revoked',
1423 'new_draft_created',
1424 'suggestion_created',
1425 'suggestion_deleted',
1426 'member_activated',
1427 'member_deleted',
1428 'member_active',
1429 'member_name_updated',
1430 'member_profile_updated',
1431 'member_image_updated',
1432 'interest',
1433 'initiator',
1434 'support',
1435 'support_updated',
1436 'suggestion_rated',
1437 'delegation',
1438 'contact' );
1440 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1443 CREATE TABLE "event" (
1444 "id" SERIAL8 PRIMARY KEY,
1445 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1446 "event" "event_type" NOT NULL,
1447 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1448 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1449 "scope" "delegation_scope",
1450 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1451 "area_id" INT4,
1452 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1453 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1454 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1455 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1456 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1457 "state" "issue_state",
1458 "initiative_id" INT4,
1459 "draft_id" INT8,
1460 "suggestion_id" INT8,
1461 "boolean_value" BOOLEAN,
1462 "numeric_value" INT4,
1463 "text_value" TEXT,
1464 "old_text_value" TEXT,
1465 FOREIGN KEY ("issue_id", "initiative_id")
1466 REFERENCES "initiative" ("issue_id", "id")
1467 ON DELETE CASCADE ON UPDATE CASCADE,
1468 FOREIGN KEY ("initiative_id", "draft_id")
1469 REFERENCES "draft" ("initiative_id", "id")
1470 ON DELETE CASCADE ON UPDATE CASCADE,
1471 -- NOTE: no referential integrity for suggestions because those are
1472 -- actually deleted
1473 -- FOREIGN KEY ("initiative_id", "suggestion_id")
1474 -- REFERENCES "suggestion" ("initiative_id", "id")
1475 -- ON DELETE CASCADE ON UPDATE CASCADE,
1476 CONSTRAINT "constr_for_issue_state_changed" CHECK (
1477 "event" != 'issue_state_changed' OR (
1478 "member_id" ISNULL AND
1479 "other_member_id" ISNULL AND
1480 "scope" ISNULL AND
1481 "unit_id" NOTNULL AND
1482 "area_id" NOTNULL AND
1483 "policy_id" NOTNULL AND
1484 "issue_id" NOTNULL AND
1485 "state" NOTNULL AND
1486 "initiative_id" ISNULL AND
1487 "draft_id" ISNULL AND
1488 "suggestion_id" ISNULL AND
1489 "boolean_value" ISNULL AND
1490 "numeric_value" ISNULL AND
1491 "text_value" ISNULL AND
1492 "old_text_value" ISNULL )),
1493 CONSTRAINT "constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1494 "event" NOT IN (
1495 'initiative_created_in_new_issue',
1496 'initiative_created_in_existing_issue',
1497 'initiative_revoked',
1498 'new_draft_created'
1499 ) OR (
1500 "member_id" NOTNULL AND
1501 "other_member_id" ISNULL AND
1502 "scope" ISNULL AND
1503 "unit_id" NOTNULL AND
1504 "area_id" NOTNULL AND
1505 "policy_id" NOTNULL AND
1506 "issue_id" NOTNULL AND
1507 "state" NOTNULL AND
1508 "initiative_id" NOTNULL AND
1509 "draft_id" NOTNULL AND
1510 "suggestion_id" ISNULL AND
1511 "boolean_value" ISNULL AND
1512 "numeric_value" ISNULL AND
1513 "text_value" ISNULL AND
1514 "old_text_value" ISNULL )),
1515 CONSTRAINT "constr_for_suggestion_creation" CHECK (
1516 "event" != 'suggestion_created' OR (
1517 "member_id" NOTNULL AND
1518 "other_member_id" ISNULL AND
1519 "scope" ISNULL AND
1520 "unit_id" NOTNULL AND
1521 "area_id" NOTNULL AND
1522 "policy_id" NOTNULL AND
1523 "issue_id" NOTNULL AND
1524 "state" NOTNULL AND
1525 "initiative_id" NOTNULL AND
1526 "draft_id" ISNULL AND
1527 "suggestion_id" NOTNULL AND
1528 "boolean_value" ISNULL AND
1529 "numeric_value" ISNULL AND
1530 "text_value" ISNULL AND
1531 "old_text_value" ISNULL )),
1532 CONSTRAINT "constr_for_suggestion_removal" CHECK (
1533 "event" != 'suggestion_deleted' OR (
1534 "member_id" ISNULL AND
1535 "other_member_id" ISNULL AND
1536 "scope" ISNULL AND
1537 "unit_id" NOTNULL AND
1538 "area_id" NOTNULL AND
1539 "policy_id" NOTNULL AND
1540 "issue_id" NOTNULL AND
1541 "state" NOTNULL AND
1542 "initiative_id" NOTNULL AND
1543 "draft_id" ISNULL AND
1544 "suggestion_id" NOTNULL AND
1545 "boolean_value" ISNULL AND
1546 "numeric_value" ISNULL AND
1547 "text_value" ISNULL AND
1548 "old_text_value" ISNULL )),
1549 CONSTRAINT "constr_for_value_less_member_event" CHECK (
1550 "event" NOT IN (
1551 'member_activated',
1552 'member_deleted',
1553 'member_profile_updated',
1554 'member_image_updated'
1555 ) OR (
1556 "member_id" NOTNULL AND
1557 "other_member_id" ISNULL AND
1558 "scope" ISNULL AND
1559 "unit_id" ISNULL AND
1560 "area_id" ISNULL AND
1561 "policy_id" ISNULL AND
1562 "issue_id" ISNULL AND
1563 "state" ISNULL AND
1564 "initiative_id" ISNULL AND
1565 "draft_id" ISNULL AND
1566 "suggestion_id" ISNULL AND
1567 "boolean_value" ISNULL AND
1568 "numeric_value" ISNULL AND
1569 "text_value" ISNULL AND
1570 "old_text_value" ISNULL )),
1571 CONSTRAINT "constr_for_member_active" CHECK (
1572 "event" != 'member_active' OR (
1573 "member_id" NOTNULL AND
1574 "other_member_id" ISNULL AND
1575 "scope" ISNULL AND
1576 "unit_id" ISNULL AND
1577 "area_id" ISNULL AND
1578 "policy_id" ISNULL AND
1579 "issue_id" ISNULL AND
1580 "state" ISNULL AND
1581 "initiative_id" ISNULL AND
1582 "draft_id" ISNULL AND
1583 "suggestion_id" ISNULL AND
1584 "boolean_value" NOTNULL AND
1585 "numeric_value" ISNULL AND
1586 "text_value" ISNULL AND
1587 "old_text_value" ISNULL )),
1588 CONSTRAINT "constr_for_member_name_updated" CHECK (
1589 "event" != 'member_name_updated' OR (
1590 "member_id" NOTNULL AND
1591 "other_member_id" ISNULL AND
1592 "scope" ISNULL AND
1593 "unit_id" ISNULL AND
1594 "area_id" ISNULL AND
1595 "policy_id" ISNULL AND
1596 "issue_id" ISNULL AND
1597 "state" ISNULL AND
1598 "initiative_id" ISNULL AND
1599 "draft_id" ISNULL AND
1600 "suggestion_id" ISNULL AND
1601 "boolean_value" ISNULL AND
1602 "numeric_value" ISNULL AND
1603 "text_value" NOTNULL AND
1604 "old_text_value" NOTNULL )),
1605 CONSTRAINT "constr_for_interest" CHECK (
1606 "event" != 'interest' OR (
1607 "member_id" NOTNULL AND
1608 "other_member_id" ISNULL AND
1609 "scope" ISNULL AND
1610 "unit_id" NOTNULL AND
1611 "area_id" NOTNULL AND
1612 "policy_id" NOTNULL AND
1613 "issue_id" NOTNULL AND
1614 "state" NOTNULL AND
1615 "initiative_id" ISNULL AND
1616 "draft_id" ISNULL AND
1617 "suggestion_id" ISNULL AND
1618 "boolean_value" NOTNULL AND
1619 "numeric_value" ISNULL AND
1620 "text_value" ISNULL AND
1621 "old_text_value" ISNULL )),
1622 CONSTRAINT "constr_for_initiator" CHECK (
1623 "event" != 'initiator' OR (
1624 "member_id" NOTNULL AND
1625 "other_member_id" ISNULL AND
1626 "scope" ISNULL AND
1627 "unit_id" NOTNULL AND
1628 "area_id" NOTNULL AND
1629 "policy_id" NOTNULL AND
1630 "issue_id" NOTNULL AND
1631 "state" NOTNULL AND
1632 "initiative_id" NOTNULL AND
1633 "draft_id" ISNULL AND
1634 "suggestion_id" ISNULL AND
1635 "boolean_value" NOTNULL AND
1636 "numeric_value" ISNULL AND
1637 "text_value" ISNULL AND
1638 "old_text_value" ISNULL )),
1639 CONSTRAINT "constr_for_support" CHECK (
1640 "event" != 'support' OR (
1641 "member_id" NOTNULL AND
1642 "other_member_id" ISNULL AND
1643 "scope" ISNULL AND
1644 "unit_id" NOTNULL AND
1645 "area_id" NOTNULL AND
1646 "policy_id" NOTNULL AND
1647 "issue_id" NOTNULL AND
1648 "state" NOTNULL AND
1649 "initiative_id" NOTNULL AND
1650 ("draft_id" NOTNULL) = ("boolean_value" = TRUE) AND
1651 "suggestion_id" ISNULL AND
1652 "boolean_value" NOTNULL AND
1653 "numeric_value" ISNULL AND
1654 "text_value" ISNULL AND
1655 "old_text_value" ISNULL )),
1656 CONSTRAINT "constr_for_support_updated" CHECK (
1657 "event" != 'support_updated' OR (
1658 "member_id" NOTNULL AND
1659 "other_member_id" ISNULL AND
1660 "scope" ISNULL AND
1661 "unit_id" NOTNULL AND
1662 "area_id" NOTNULL AND
1663 "policy_id" NOTNULL AND
1664 "issue_id" NOTNULL AND
1665 "state" NOTNULL AND
1666 "initiative_id" NOTNULL AND
1667 "draft_id" NOTNULL AND
1668 "suggestion_id" ISNULL AND
1669 "boolean_value" ISNULL AND
1670 "numeric_value" ISNULL AND
1671 "text_value" ISNULL AND
1672 "old_text_value" ISNULL )),
1673 CONSTRAINT "constr_for_suggestion_rated" CHECK (
1674 "event" != 'suggestion_rated' OR (
1675 "member_id" NOTNULL AND
1676 "other_member_id" ISNULL AND
1677 "scope" ISNULL AND
1678 "unit_id" NOTNULL AND
1679 "area_id" NOTNULL AND
1680 "policy_id" NOTNULL AND
1681 "issue_id" NOTNULL AND
1682 "state" NOTNULL AND
1683 "initiative_id" NOTNULL AND
1684 "draft_id" ISNULL AND
1685 "suggestion_id" NOTNULL AND
1686 ("boolean_value" NOTNULL) = ("numeric_value" != 0) AND
1687 "numeric_value" NOTNULL AND
1688 "numeric_value" IN (-2, -1, 0, 1, 2) AND
1689 "text_value" ISNULL AND
1690 "old_text_value" ISNULL )),
1691 CONSTRAINT "constr_for_delegation" CHECK (
1692 "event" != 'delegation' OR (
1693 "member_id" NOTNULL AND
1694 (("other_member_id" ISNULL) OR ("boolean_value" = TRUE)) AND
1695 "scope" NOTNULL AND
1696 "unit_id" NOTNULL AND
1697 ("area_id" NOTNULL) = ("scope" != 'unit'::"delegation_scope") AND
1698 "policy_id" ISNULL AND
1699 ("issue_id" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1700 ("state" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1701 "initiative_id" ISNULL AND
1702 "draft_id" ISNULL AND
1703 "suggestion_id" ISNULL AND
1704 "boolean_value" NOTNULL AND
1705 "numeric_value" ISNULL AND
1706 "text_value" ISNULL AND
1707 "old_text_value" ISNULL )),
1708 CONSTRAINT "constr_for_contact" CHECK (
1709 "event" != 'contact' OR (
1710 "member_id" NOTNULL AND
1711 "other_member_id" NOTNULL AND
1712 "scope" ISNULL AND
1713 "unit_id" ISNULL AND
1714 "area_id" ISNULL AND
1715 "policy_id" ISNULL AND
1716 "issue_id" ISNULL AND
1717 "state" ISNULL AND
1718 "initiative_id" ISNULL AND
1719 "draft_id" ISNULL AND
1720 "suggestion_id" ISNULL AND
1721 "boolean_value" NOTNULL AND
1722 "numeric_value" ISNULL AND
1723 "text_value" ISNULL AND
1724 "old_text_value" ISNULL )) );
1725 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1727 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1729 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1730 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1731 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1732 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1735 CREATE TABLE "event_processed" (
1736 "event_id" INT8 NOT NULL );
1737 CREATE UNIQUE INDEX "event_processed_singleton_idx" ON "event_processed" ((1));
1739 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)';
1740 COMMENT ON INDEX "event_processed_singleton_idx" IS 'This index ensures that "event_processed" only contains one row maximum.';
1743 CREATE TABLE "notification_initiative_sent" (
1744 PRIMARY KEY ("member_id", "initiative_id"),
1745 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1746 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1747 "last_draft_id" INT8 NOT NULL,
1748 "last_suggestion_id" INT8 );
1749 CREATE INDEX "notification_initiative_sent_initiative_idx" ON "notification_initiative_sent" ("initiative_id");
1751 COMMENT ON TABLE "notification_initiative_sent" IS 'Information which initiatives have been promoted to a member in a scheduled notification mail';
1753 COMMENT ON COLUMN "notification_initiative_sent"."last_draft_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1754 COMMENT ON COLUMN "notification_initiative_sent"."last_suggestion_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1757 CREATE TABLE "newsletter" (
1758 "id" SERIAL4 PRIMARY KEY,
1759 "published" TIMESTAMPTZ NOT NULL,
1760 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1761 "include_all_members" BOOLEAN NOT NULL,
1762 "sent" TIMESTAMPTZ,
1763 "subject" TEXT NOT NULL,
1764 "content" TEXT NOT NULL );
1765 CREATE INDEX "newsletter_unit_id_idx" ON "newsletter" ("unit_id", "published");
1766 CREATE INDEX "newsletter_all_units_published_idx" ON "newsletter" ("published") WHERE "unit_id" ISNULL;
1767 CREATE INDEX "newsletter_published_idx" ON "newsletter" ("published");
1769 COMMENT ON TABLE "newsletter" IS 'Contains newsletters created by administrators to be sent out and for further reference';
1771 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter is to be sent out (and made available in the frontend)';
1772 COMMENT ON COLUMN "newsletter"."unit_id" IS 'If set, only members with voting right in the given unit are considered to be recipients';
1773 COMMENT ON COLUMN "newsletter"."include_all_members" IS 'TRUE = include all members regardless of their ''disable_notifications'' setting';
1774 COMMENT ON COLUMN "newsletter"."sent" IS 'Timestamp when the newsletter has been mailed out';
1775 COMMENT ON COLUMN "newsletter"."subject" IS 'Subject line (e.g. to be used for the email)';
1776 COMMENT ON COLUMN "newsletter"."content" IS 'Plain text content of the newsletter';
1780 ----------------------------------------------
1781 -- Writing of history entries and event log --
1782 ----------------------------------------------
1785 CREATE FUNCTION "write_member_history_trigger"()
1786 RETURNS TRIGGER
1787 LANGUAGE 'plpgsql' VOLATILE AS $$
1788 BEGIN
1789 IF
1790 ( NEW."active" != OLD."active" OR
1791 NEW."name" != OLD."name" ) AND
1792 OLD."activated" NOTNULL
1793 THEN
1794 INSERT INTO "member_history"
1795 ("member_id", "active", "name")
1796 VALUES (NEW."id", OLD."active", OLD."name");
1797 END IF;
1798 RETURN NULL;
1799 END;
1800 $$;
1802 CREATE TRIGGER "write_member_history"
1803 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1804 "write_member_history_trigger"();
1806 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1807 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1810 CREATE FUNCTION "write_event_unit_trigger"()
1811 RETURNS TRIGGER
1812 LANGUAGE 'plpgsql' VOLATILE AS $$
1813 DECLARE
1814 "event_v" "event_type";
1815 BEGIN
1816 IF TG_OP = 'UPDATE' THEN
1817 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1818 RETURN NULL;
1819 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1820 -- "event_v" := 'unit_created';
1821 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1822 -- "event_v" := 'unit_deleted';
1823 ELSIF OLD != NEW THEN
1824 "event_v" := 'unit_updated';
1825 ELSE
1826 RETURN NULL;
1827 END IF;
1828 ELSE
1829 "event_v" := 'unit_created';
1830 END IF;
1831 INSERT INTO "event" ("event", "unit_id") VALUES ("event_v", NEW."id");
1832 RETURN NULL;
1833 END;
1834 $$;
1836 CREATE TRIGGER "write_event_unit" AFTER INSERT OR UPDATE ON "unit"
1837 FOR EACH ROW EXECUTE PROCEDURE "write_event_unit_trigger"();
1839 COMMENT ON FUNCTION "write_event_unit_trigger"() IS 'Implementation of trigger "write_event_unit" on table "unit"';
1840 COMMENT ON TRIGGER "write_event_unit" ON "unit" IS 'Create entry in "event" table on new or changed/disabled units';
1843 CREATE FUNCTION "write_event_area_trigger"()
1844 RETURNS TRIGGER
1845 LANGUAGE 'plpgsql' VOLATILE AS $$
1846 DECLARE
1847 "event_v" "event_type";
1848 BEGIN
1849 IF TG_OP = 'UPDATE' THEN
1850 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1851 RETURN NULL;
1852 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1853 -- "event_v" := 'area_created';
1854 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1855 -- "event_v" := 'area_deleted';
1856 ELSIF OLD != NEW THEN
1857 "event_v" := 'area_updated';
1858 ELSE
1859 RETURN NULL;
1860 END IF;
1861 ELSE
1862 "event_v" := 'area_created';
1863 END IF;
1864 INSERT INTO "event" ("event", "area_id") VALUES ("event_v", NEW."id");
1865 RETURN NULL;
1866 END;
1867 $$;
1869 CREATE TRIGGER "write_event_area" AFTER INSERT OR UPDATE ON "area"
1870 FOR EACH ROW EXECUTE PROCEDURE "write_event_area_trigger"();
1872 COMMENT ON FUNCTION "write_event_area_trigger"() IS 'Implementation of trigger "write_event_area" on table "area"';
1873 COMMENT ON TRIGGER "write_event_area" ON "area" IS 'Create entry in "event" table on new or changed/disabled areas';
1876 CREATE FUNCTION "write_event_policy_trigger"()
1877 RETURNS TRIGGER
1878 LANGUAGE 'plpgsql' VOLATILE AS $$
1879 DECLARE
1880 "event_v" "event_type";
1881 BEGIN
1882 IF TG_OP = 'UPDATE' THEN
1883 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1884 RETURN NULL;
1885 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1886 -- "event_v" := 'policy_created';
1887 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1888 -- "event_v" := 'policy_deleted';
1889 ELSIF OLD != NEW THEN
1890 "event_v" := 'policy_updated';
1891 ELSE
1892 RETURN NULL;
1893 END IF;
1894 ELSE
1895 "event_v" := 'policy_created';
1896 END IF;
1897 INSERT INTO "event" ("event", "policy_id") VALUES ("event_v", NEW."id");
1898 RETURN NULL;
1899 END;
1900 $$;
1902 CREATE TRIGGER "write_event_policy" AFTER INSERT OR UPDATE ON "policy"
1903 FOR EACH ROW EXECUTE PROCEDURE "write_event_policy_trigger"();
1905 COMMENT ON FUNCTION "write_event_policy_trigger"() IS 'Implementation of trigger "write_event_policy" on table "policy"';
1906 COMMENT ON TRIGGER "write_event_policy" ON "policy" IS 'Create entry in "event" table on new or changed/disabled policies';
1909 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1910 RETURNS TRIGGER
1911 LANGUAGE 'plpgsql' VOLATILE AS $$
1912 DECLARE
1913 "area_row" "area"%ROWTYPE;
1914 BEGIN
1915 IF NEW."state" != OLD."state" THEN
1916 SELECT * INTO "area_row" FROM "area" WHERE "id" = NEW."area_id"
1917 FOR SHARE;
1918 INSERT INTO "event" (
1919 "event",
1920 "unit_id", "area_id", "policy_id", "issue_id", "state"
1921 ) VALUES (
1922 'issue_state_changed',
1923 "area_row"."unit_id", NEW."area_id", NEW."policy_id",
1924 NEW."id", NEW."state"
1925 );
1926 END IF;
1927 RETURN NULL;
1928 END;
1929 $$;
1931 CREATE TRIGGER "write_event_issue_state_changed"
1932 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1933 "write_event_issue_state_changed_trigger"();
1935 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1936 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1939 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1940 RETURNS TRIGGER
1941 LANGUAGE 'plpgsql' VOLATILE AS $$
1942 DECLARE
1943 "initiative_row" "initiative"%ROWTYPE;
1944 "issue_row" "issue"%ROWTYPE;
1945 "area_row" "area"%ROWTYPE;
1946 "event_v" "event_type";
1947 BEGIN
1948 SELECT * INTO "initiative_row" FROM "initiative"
1949 WHERE "id" = NEW."initiative_id" FOR SHARE;
1950 SELECT * INTO "issue_row" FROM "issue"
1951 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
1952 SELECT * INTO "area_row" FROM "area"
1953 WHERE "id" = "issue_row"."area_id" FOR SHARE;
1954 IF EXISTS (
1955 SELECT NULL FROM "draft"
1956 WHERE "initiative_id" = NEW."initiative_id" AND "id" != NEW."id"
1957 FOR SHARE
1958 ) THEN
1959 "event_v" := 'new_draft_created';
1960 ELSE
1961 IF EXISTS (
1962 SELECT NULL FROM "initiative"
1963 WHERE "issue_id" = "initiative_row"."issue_id"
1964 AND "id" != "initiative_row"."id"
1965 FOR SHARE
1966 ) THEN
1967 "event_v" := 'initiative_created_in_existing_issue';
1968 ELSE
1969 "event_v" := 'initiative_created_in_new_issue';
1970 END IF;
1971 END IF;
1972 INSERT INTO "event" (
1973 "event", "member_id",
1974 "unit_id", "area_id", "policy_id", "issue_id", "state",
1975 "initiative_id", "draft_id"
1976 ) VALUES (
1977 "event_v", NEW."author_id",
1978 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
1979 "initiative_row"."issue_id", "issue_row"."state",
1980 NEW."initiative_id", NEW."id"
1981 );
1982 RETURN NULL;
1983 END;
1984 $$;
1986 CREATE TRIGGER "write_event_initiative_or_draft_created"
1987 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1988 "write_event_initiative_or_draft_created_trigger"();
1990 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1991 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1994 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1995 RETURNS TRIGGER
1996 LANGUAGE 'plpgsql' VOLATILE AS $$
1997 DECLARE
1998 "issue_row" "issue"%ROWTYPE;
1999 "area_row" "area"%ROWTYPE;
2000 "draft_id_v" "draft"."id"%TYPE;
2001 BEGIN
2002 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
2003 -- NOTE: lock for primary key update to avoid new drafts
2004 PERFORM NULL FROM "initiative" WHERE "id" = NEW."id" FOR UPDATE;
2005 SELECT * INTO "issue_row" FROM "issue"
2006 WHERE "id" = NEW."issue_id" FOR SHARE;
2007 SELECT * INTO "area_row" FROM "area"
2008 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2009 -- NOTE: FOR SHARE cannot be used with DISTINCT in view "current_draft"
2010 PERFORM NULL FROM "draft" WHERE "initiative_id" = NEW."id" FOR SHARE;
2011 SELECT "id" INTO "draft_id_v" FROM "current_draft"
2012 WHERE "initiative_id" = NEW."id";
2013 INSERT INTO "event" (
2014 "event", "member_id",
2015 "unit_id", "area_id", "policy_id", "issue_id", "state",
2016 "initiative_id", "draft_id"
2017 ) VALUES (
2018 'initiative_revoked', NEW."revoked_by_member_id",
2019 "area_row"."unit_id", "issue_row"."area_id",
2020 "issue_row"."policy_id",
2021 NEW."issue_id", "issue_row"."state",
2022 NEW."id", "draft_id_v"
2023 );
2024 END IF;
2025 RETURN NULL;
2026 END;
2027 $$;
2029 CREATE TRIGGER "write_event_initiative_revoked"
2030 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
2031 "write_event_initiative_revoked_trigger"();
2033 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
2034 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
2037 CREATE FUNCTION "write_event_suggestion_created_trigger"()
2038 RETURNS TRIGGER
2039 LANGUAGE 'plpgsql' VOLATILE AS $$
2040 DECLARE
2041 "initiative_row" "initiative"%ROWTYPE;
2042 "issue_row" "issue"%ROWTYPE;
2043 "area_row" "area"%ROWTYPE;
2044 BEGIN
2045 SELECT * INTO "initiative_row" FROM "initiative"
2046 WHERE "id" = NEW."initiative_id" FOR SHARE;
2047 SELECT * INTO "issue_row" FROM "issue"
2048 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2049 SELECT * INTO "area_row" FROM "area"
2050 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2051 INSERT INTO "event" (
2052 "event", "member_id",
2053 "unit_id", "area_id", "policy_id", "issue_id", "state",
2054 "initiative_id", "suggestion_id"
2055 ) VALUES (
2056 'suggestion_created', 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_suggestion_created"
2066 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2067 "write_event_suggestion_created_trigger"();
2069 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
2070 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2073 CREATE FUNCTION "write_event_suggestion_removed_trigger"()
2074 RETURNS TRIGGER
2075 LANGUAGE 'plpgsql' VOLATILE AS $$
2076 DECLARE
2077 "initiative_row" "initiative"%ROWTYPE;
2078 "issue_row" "issue"%ROWTYPE;
2079 "area_row" "area"%ROWTYPE;
2080 BEGIN
2081 SELECT * INTO "initiative_row" FROM "initiative"
2082 WHERE "id" = OLD."initiative_id" FOR SHARE;
2083 IF "initiative_row"."id" NOTNULL THEN
2084 SELECT * INTO "issue_row" FROM "issue"
2085 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2086 SELECT * INTO "area_row" FROM "area"
2087 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2088 INSERT INTO "event" (
2089 "event",
2090 "unit_id", "area_id", "policy_id", "issue_id", "state",
2091 "initiative_id", "suggestion_id"
2092 ) VALUES (
2093 'suggestion_deleted',
2094 "area_row"."unit_id", "issue_row"."area_id",
2095 "issue_row"."policy_id",
2096 "initiative_row"."issue_id", "issue_row"."state",
2097 OLD."initiative_id", OLD."id"
2098 );
2099 END IF;
2100 RETURN NULL;
2101 END;
2102 $$;
2104 CREATE TRIGGER "write_event_suggestion_removed"
2105 AFTER DELETE ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2106 "write_event_suggestion_removed_trigger"();
2108 COMMENT ON FUNCTION "write_event_suggestion_removed_trigger"() IS 'Implementation of trigger "write_event_suggestion_removed" on table "issue"';
2109 COMMENT ON TRIGGER "write_event_suggestion_removed" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2112 CREATE FUNCTION "write_event_member_trigger"()
2113 RETURNS TRIGGER
2114 LANGUAGE 'plpgsql' VOLATILE AS $$
2115 BEGIN
2116 IF TG_OP = 'INSERT' THEN
2117 IF NEW."activated" NOTNULL AND NEW."deleted" ISNULL THEN
2118 INSERT INTO "event" ("event", "member_id")
2119 VALUES ('member_activated', NEW."id");
2120 END IF;
2121 IF NEW."active" THEN
2122 INSERT INTO "event" ("event", "member_id", "boolean_value")
2123 VALUES ('member_active', NEW."id", TRUE);
2124 END IF;
2125 ELSIF TG_OP = 'UPDATE' THEN
2126 IF OLD."id" != NEW."id" THEN
2127 RAISE EXCEPTION 'Cannot change member ID';
2128 END IF;
2129 IF
2130 (OLD."activated" ISNULL OR OLD."deleted" NOTNULL) AND
2131 NEW."activated" NOTNULL AND NEW."deleted" ISNULL
2132 THEN
2133 INSERT INTO "event" ("event", "member_id")
2134 VALUES ('member_activated', NEW."id");
2135 END IF;
2136 IF OLD."active" != NEW."active" THEN
2137 INSERT INTO "event" ("event", "member_id", "boolean_value") VALUES (
2138 'member_active', NEW."id", NEW."active"
2139 );
2140 END IF;
2141 IF OLD."name" != NEW."name" THEN
2142 INSERT INTO "event" (
2143 "event", "member_id", "text_value", "old_text_value"
2144 ) VALUES (
2145 'member_name_updated', NEW."id", NEW."name", OLD."name"
2146 );
2147 END IF;
2148 IF
2149 OLD."activated" NOTNULL AND OLD."deleted" ISNULL AND
2150 (NEW."activated" ISNULL OR NEW."deleted" NOTNULL)
2151 THEN
2152 INSERT INTO "event" ("event", "member_id")
2153 VALUES ('member_deleted', NEW."id");
2154 END IF;
2155 END IF;
2156 RETURN NULL;
2157 END;
2158 $$;
2160 CREATE TRIGGER "write_event_member"
2161 AFTER INSERT OR UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
2162 "write_event_member_trigger"();
2164 COMMENT ON FUNCTION "write_event_member_trigger"() IS 'Implementation of trigger "write_event_member" on table "member"';
2165 COMMENT ON TRIGGER "write_event_member" ON "member" IS 'Create entries in "event" table on insertion to member table';
2168 CREATE FUNCTION "write_event_member_profile_updated_trigger"()
2169 RETURNS TRIGGER
2170 LANGUAGE 'plpgsql' VOLATILE AS $$
2171 BEGIN
2172 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2173 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2174 INSERT INTO "event" ("event", "member_id") VALUES (
2175 'member_profile_updated', OLD."member_id"
2176 );
2177 END IF;
2178 END IF;
2179 IF TG_OP = 'UPDATE' THEN
2180 IF OLD."member_id" = NEW."member_id" THEN
2181 RETURN NULL;
2182 END IF;
2183 END IF;
2184 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2185 INSERT INTO "event" ("event", "member_id") VALUES (
2186 'member_profile_updated', NEW."member_id"
2187 );
2188 END IF;
2189 RETURN NULL;
2190 END;
2191 $$;
2193 CREATE TRIGGER "write_event_member_profile_updated"
2194 AFTER INSERT OR UPDATE OR DELETE ON "member_profile"
2195 FOR EACH ROW EXECUTE PROCEDURE
2196 "write_event_member_profile_updated_trigger"();
2198 COMMENT ON FUNCTION "write_event_member_profile_updated_trigger"() IS 'Implementation of trigger "write_event_member_profile_updated" on table "member_profile"';
2199 COMMENT ON TRIGGER "write_event_member_profile_updated" ON "member_profile" IS 'Creates entries in "event" table on member profile update';
2202 CREATE FUNCTION "write_event_member_image_updated_trigger"()
2203 RETURNS TRIGGER
2204 LANGUAGE 'plpgsql' VOLATILE AS $$
2205 BEGIN
2206 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2207 IF NOT OLD."scaled" THEN
2208 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2209 INSERT INTO "event" ("event", "member_id") VALUES (
2210 'member_image_updated', OLD."member_id"
2211 );
2212 END IF;
2213 END IF;
2214 END IF;
2215 IF TG_OP = 'UPDATE' THEN
2216 IF
2217 OLD."member_id" = NEW."member_id" AND
2218 OLD."scaled" = NEW."scaled"
2219 THEN
2220 RETURN NULL;
2221 END IF;
2222 END IF;
2223 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2224 IF NOT NEW."scaled" THEN
2225 INSERT INTO "event" ("event", "member_id") VALUES (
2226 'member_image_updated', NEW."member_id"
2227 );
2228 END IF;
2229 END IF;
2230 RETURN NULL;
2231 END;
2232 $$;
2234 CREATE TRIGGER "write_event_member_image_updated"
2235 AFTER INSERT OR UPDATE OR DELETE ON "member_image"
2236 FOR EACH ROW EXECUTE PROCEDURE
2237 "write_event_member_image_updated_trigger"();
2239 COMMENT ON FUNCTION "write_event_member_image_updated_trigger"() IS 'Implementation of trigger "write_event_member_image_updated" on table "member_image"';
2240 COMMENT ON TRIGGER "write_event_member_image_updated" ON "member_image" IS 'Creates entries in "event" table on member image update';
2243 CREATE FUNCTION "write_event_interest_trigger"()
2244 RETURNS TRIGGER
2245 LANGUAGE 'plpgsql' VOLATILE AS $$
2246 DECLARE
2247 "issue_row" "issue"%ROWTYPE;
2248 "area_row" "area"%ROWTYPE;
2249 BEGIN
2250 IF TG_OP = 'UPDATE' THEN
2251 IF OLD = NEW THEN
2252 RETURN NULL;
2253 END IF;
2254 END IF;
2255 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2256 SELECT * INTO "issue_row" FROM "issue"
2257 WHERE "id" = OLD."issue_id" FOR SHARE;
2258 SELECT * INTO "area_row" FROM "area"
2259 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2260 IF "issue_row"."id" NOTNULL THEN
2261 INSERT INTO "event" (
2262 "event", "member_id",
2263 "unit_id", "area_id", "policy_id", "issue_id", "state",
2264 "boolean_value"
2265 ) VALUES (
2266 'interest', OLD."member_id",
2267 "area_row"."unit_id", "issue_row"."area_id",
2268 "issue_row"."policy_id",
2269 OLD."issue_id", "issue_row"."state",
2270 FALSE
2271 );
2272 END IF;
2273 END IF;
2274 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2275 SELECT * INTO "issue_row" FROM "issue"
2276 WHERE "id" = NEW."issue_id" FOR SHARE;
2277 SELECT * INTO "area_row" FROM "area"
2278 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2279 INSERT INTO "event" (
2280 "event", "member_id",
2281 "unit_id", "area_id", "policy_id", "issue_id", "state",
2282 "boolean_value"
2283 ) VALUES (
2284 'interest', NEW."member_id",
2285 "area_row"."unit_id", "issue_row"."area_id",
2286 "issue_row"."policy_id",
2287 NEW."issue_id", "issue_row"."state",
2288 TRUE
2289 );
2290 END IF;
2291 RETURN NULL;
2292 END;
2293 $$;
2295 CREATE TRIGGER "write_event_interest"
2296 AFTER INSERT OR UPDATE OR DELETE ON "interest" FOR EACH ROW EXECUTE PROCEDURE
2297 "write_event_interest_trigger"();
2299 COMMENT ON FUNCTION "write_event_interest_trigger"() IS 'Implementation of trigger "write_event_interest_inserted" on table "interest"';
2300 COMMENT ON TRIGGER "write_event_interest" ON "interest" IS 'Create entry in "event" table on adding or removing interest';
2303 CREATE FUNCTION "write_event_initiator_trigger"()
2304 RETURNS TRIGGER
2305 LANGUAGE 'plpgsql' VOLATILE AS $$
2306 DECLARE
2307 "initiative_row" "initiative"%ROWTYPE;
2308 "issue_row" "issue"%ROWTYPE;
2309 "area_row" "area"%ROWTYPE;
2310 "accepted_v" BOOLEAN = FALSE;
2311 "rejected_v" BOOLEAN = FALSE;
2312 BEGIN
2313 IF TG_OP = 'UPDATE' THEN
2314 IF
2315 OLD."initiative_id" = NEW."initiative_id" AND
2316 OLD."member_id" = NEW."member_id"
2317 THEN
2318 IF
2319 coalesce(OLD."accepted", FALSE) = coalesce(NEW."accepted", FALSE)
2320 THEN
2321 RETURN NULL;
2322 END IF;
2323 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2324 "accepted_v" := TRUE;
2325 ELSE
2326 "rejected_v" := TRUE;
2327 END IF;
2328 END IF;
2329 END IF;
2330 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "accepted_v" THEN
2331 IF coalesce(OLD."accepted", FALSE) = TRUE THEN
2332 SELECT * INTO "initiative_row" FROM "initiative"
2333 WHERE "id" = OLD."initiative_id" FOR SHARE;
2334 IF "initiative_row"."id" NOTNULL THEN
2335 SELECT * INTO "issue_row" FROM "issue"
2336 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2337 SELECT * INTO "area_row" FROM "area"
2338 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2339 INSERT INTO "event" (
2340 "event", "member_id",
2341 "unit_id", "area_id", "policy_id", "issue_id", "state",
2342 "initiative_id", "boolean_value"
2343 ) VALUES (
2344 'initiator', OLD."member_id",
2345 "area_row"."unit_id", "issue_row"."area_id",
2346 "issue_row"."policy_id",
2347 "issue_row"."id", "issue_row"."state",
2348 OLD."initiative_id", FALSE
2349 );
2350 END IF;
2351 END IF;
2352 END IF;
2353 IF TG_OP = 'UPDATE' AND NOT "rejected_v" THEN
2354 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2355 SELECT * INTO "initiative_row" FROM "initiative"
2356 WHERE "id" = NEW."initiative_id" FOR SHARE;
2357 SELECT * INTO "issue_row" FROM "issue"
2358 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2359 SELECT * INTO "area_row" FROM "area"
2360 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2361 INSERT INTO "event" (
2362 "event", "member_id",
2363 "unit_id", "area_id", "policy_id", "issue_id", "state",
2364 "initiative_id", "boolean_value"
2365 ) VALUES (
2366 'initiator', NEW."member_id",
2367 "area_row"."unit_id", "issue_row"."area_id",
2368 "issue_row"."policy_id",
2369 "issue_row"."id", "issue_row"."state",
2370 NEW."initiative_id", TRUE
2371 );
2372 END IF;
2373 END IF;
2374 RETURN NULL;
2375 END;
2376 $$;
2378 CREATE TRIGGER "write_event_initiator"
2379 AFTER UPDATE OR DELETE ON "initiator" FOR EACH ROW EXECUTE PROCEDURE
2380 "write_event_initiator_trigger"();
2382 COMMENT ON FUNCTION "write_event_initiator_trigger"() IS 'Implementation of trigger "write_event_initiator" on table "initiator"';
2383 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)';
2386 CREATE FUNCTION "write_event_support_trigger"()
2387 RETURNS TRIGGER
2388 LANGUAGE 'plpgsql' VOLATILE AS $$
2389 DECLARE
2390 "issue_row" "issue"%ROWTYPE;
2391 "area_row" "area"%ROWTYPE;
2392 BEGIN
2393 IF TG_OP = 'UPDATE' THEN
2394 IF
2395 OLD."initiative_id" = NEW."initiative_id" AND
2396 OLD."member_id" = NEW."member_id"
2397 THEN
2398 IF OLD."draft_id" != NEW."draft_id" THEN
2399 SELECT * INTO "issue_row" FROM "issue"
2400 WHERE "id" = NEW."issue_id" FOR SHARE;
2401 SELECT * INTO "area_row" FROM "area"
2402 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2403 INSERT INTO "event" (
2404 "event", "member_id",
2405 "unit_id", "area_id", "policy_id", "issue_id", "state",
2406 "initiative_id", "draft_id"
2407 ) VALUES (
2408 'support_updated', NEW."member_id",
2409 "area_row"."unit_id", "issue_row"."area_id",
2410 "issue_row"."policy_id",
2411 "issue_row"."id", "issue_row"."state",
2412 NEW."initiative_id", NEW."draft_id"
2413 );
2414 END IF;
2415 RETURN NULL;
2416 END IF;
2417 END IF;
2418 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2419 IF EXISTS (
2420 SELECT NULL FROM "initiative" WHERE "id" = OLD."initiative_id"
2421 FOR SHARE
2422 ) THEN
2423 SELECT * INTO "issue_row" FROM "issue"
2424 WHERE "id" = OLD."issue_id" FOR SHARE;
2425 SELECT * INTO "area_row" FROM "area"
2426 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2427 INSERT INTO "event" (
2428 "event", "member_id",
2429 "unit_id", "area_id", "policy_id", "issue_id", "state",
2430 "initiative_id", "boolean_value"
2431 ) VALUES (
2432 'support', OLD."member_id",
2433 "area_row"."unit_id", "issue_row"."area_id",
2434 "issue_row"."policy_id",
2435 "issue_row"."id", "issue_row"."state",
2436 OLD."initiative_id", FALSE
2437 );
2438 END IF;
2439 END IF;
2440 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2441 SELECT * INTO "issue_row" FROM "issue"
2442 WHERE "id" = NEW."issue_id" FOR SHARE;
2443 SELECT * INTO "area_row" FROM "area"
2444 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2445 INSERT INTO "event" (
2446 "event", "member_id",
2447 "unit_id", "area_id", "policy_id", "issue_id", "state",
2448 "initiative_id", "draft_id", "boolean_value"
2449 ) VALUES (
2450 'support', NEW."member_id",
2451 "area_row"."unit_id", "issue_row"."area_id",
2452 "issue_row"."policy_id",
2453 "issue_row"."id", "issue_row"."state",
2454 NEW."initiative_id", NEW."draft_id", TRUE
2455 );
2456 END IF;
2457 RETURN NULL;
2458 END;
2459 $$;
2461 CREATE TRIGGER "write_event_support"
2462 AFTER INSERT OR UPDATE OR DELETE ON "supporter" FOR EACH ROW EXECUTE PROCEDURE
2463 "write_event_support_trigger"();
2465 COMMENT ON FUNCTION "write_event_support_trigger"() IS 'Implementation of trigger "write_event_support" on table "supporter"';
2466 COMMENT ON TRIGGER "write_event_support" ON "supporter" IS 'Create entry in "event" table when adding, updating, or removing support';
2469 CREATE FUNCTION "write_event_suggestion_rated_trigger"()
2470 RETURNS TRIGGER
2471 LANGUAGE 'plpgsql' VOLATILE AS $$
2472 DECLARE
2473 "same_pkey_v" BOOLEAN = FALSE;
2474 "initiative_row" "initiative"%ROWTYPE;
2475 "issue_row" "issue"%ROWTYPE;
2476 "area_row" "area"%ROWTYPE;
2477 BEGIN
2478 IF TG_OP = 'UPDATE' THEN
2479 IF
2480 OLD."suggestion_id" = NEW."suggestion_id" AND
2481 OLD."member_id" = NEW."member_id"
2482 THEN
2483 IF
2484 OLD."degree" = NEW."degree" AND
2485 OLD."fulfilled" = NEW."fulfilled"
2486 THEN
2487 RETURN NULL;
2488 END IF;
2489 "same_pkey_v" := TRUE;
2490 END IF;
2491 END IF;
2492 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "same_pkey_v" THEN
2493 IF EXISTS (
2494 SELECT NULL FROM "suggestion" WHERE "id" = OLD."suggestion_id"
2495 FOR SHARE
2496 ) THEN
2497 SELECT * INTO "initiative_row" FROM "initiative"
2498 WHERE "id" = OLD."initiative_id" FOR SHARE;
2499 SELECT * INTO "issue_row" FROM "issue"
2500 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2501 SELECT * INTO "area_row" FROM "area"
2502 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2503 INSERT INTO "event" (
2504 "event", "member_id",
2505 "unit_id", "area_id", "policy_id", "issue_id", "state",
2506 "initiative_id", "suggestion_id",
2507 "boolean_value", "numeric_value"
2508 ) VALUES (
2509 'suggestion_rated', OLD."member_id",
2510 "area_row"."unit_id", "issue_row"."area_id",
2511 "issue_row"."policy_id",
2512 "initiative_row"."issue_id", "issue_row"."state",
2513 OLD."initiative_id", OLD."suggestion_id",
2514 NULL, 0
2515 );
2516 END IF;
2517 END IF;
2518 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2519 SELECT * INTO "initiative_row" FROM "initiative"
2520 WHERE "id" = NEW."initiative_id" FOR SHARE;
2521 SELECT * INTO "issue_row" FROM "issue"
2522 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2523 SELECT * INTO "area_row" FROM "area"
2524 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2525 INSERT INTO "event" (
2526 "event", "member_id",
2527 "unit_id", "area_id", "policy_id", "issue_id", "state",
2528 "initiative_id", "suggestion_id",
2529 "boolean_value", "numeric_value"
2530 ) VALUES (
2531 'suggestion_rated', NEW."member_id",
2532 "area_row"."unit_id", "issue_row"."area_id",
2533 "issue_row"."policy_id",
2534 "initiative_row"."issue_id", "issue_row"."state",
2535 NEW."initiative_id", NEW."suggestion_id",
2536 NEW."fulfilled", NEW."degree"
2537 );
2538 END IF;
2539 RETURN NULL;
2540 END;
2541 $$;
2543 CREATE TRIGGER "write_event_suggestion_rated"
2544 AFTER INSERT OR UPDATE OR DELETE ON "opinion" FOR EACH ROW EXECUTE PROCEDURE
2545 "write_event_suggestion_rated_trigger"();
2547 COMMENT ON FUNCTION "write_event_suggestion_rated_trigger"() IS 'Implementation of trigger "write_event_suggestion_rated" on table "opinion"';
2548 COMMENT ON TRIGGER "write_event_suggestion_rated" ON "opinion" IS 'Create entry in "event" table when adding, updating, or removing support';
2551 CREATE FUNCTION "write_event_delegation_trigger"()
2552 RETURNS TRIGGER
2553 LANGUAGE 'plpgsql' VOLATILE AS $$
2554 DECLARE
2555 "issue_row" "issue"%ROWTYPE;
2556 "area_row" "area"%ROWTYPE;
2557 BEGIN
2558 IF TG_OP = 'DELETE' THEN
2559 IF EXISTS (
2560 SELECT NULL FROM "member" WHERE "id" = OLD."truster_id"
2561 ) AND (CASE OLD."scope"
2562 WHEN 'unit'::"delegation_scope" THEN EXISTS (
2563 SELECT NULL FROM "unit" WHERE "id" = OLD."unit_id"
2565 WHEN 'area'::"delegation_scope" THEN EXISTS (
2566 SELECT NULL FROM "area" WHERE "id" = OLD."area_id"
2568 WHEN 'issue'::"delegation_scope" THEN EXISTS (
2569 SELECT NULL FROM "issue" WHERE "id" = OLD."issue_id"
2571 END) THEN
2572 SELECT * INTO "issue_row" FROM "issue"
2573 WHERE "id" = OLD."issue_id" FOR SHARE;
2574 SELECT * INTO "area_row" FROM "area"
2575 WHERE "id" = COALESCE(OLD."area_id", "issue_row"."area_id")
2576 FOR SHARE;
2577 INSERT INTO "event" (
2578 "event", "member_id", "scope",
2579 "unit_id", "area_id", "issue_id", "state",
2580 "boolean_value"
2581 ) VALUES (
2582 'delegation', OLD."truster_id", OLD."scope",
2583 COALESCE(OLD."unit_id", "area_row"."unit_id"), "area_row"."id",
2584 OLD."issue_id", "issue_row"."state",
2585 FALSE
2586 );
2587 END IF;
2588 ELSE
2589 SELECT * INTO "issue_row" FROM "issue"
2590 WHERE "id" = NEW."issue_id" FOR SHARE;
2591 SELECT * INTO "area_row" FROM "area"
2592 WHERE "id" = COALESCE(NEW."area_id", "issue_row"."area_id")
2593 FOR SHARE;
2594 INSERT INTO "event" (
2595 "event", "member_id", "other_member_id", "scope",
2596 "unit_id", "area_id", "issue_id", "state",
2597 "boolean_value"
2598 ) VALUES (
2599 'delegation', NEW."truster_id", NEW."trustee_id", NEW."scope",
2600 COALESCE(NEW."unit_id", "area_row"."unit_id"), "area_row"."id",
2601 NEW."issue_id", "issue_row"."state",
2602 TRUE
2603 );
2604 END IF;
2605 RETURN NULL;
2606 END;
2607 $$;
2609 CREATE TRIGGER "write_event_delegation"
2610 AFTER INSERT OR UPDATE OR DELETE ON "delegation" FOR EACH ROW EXECUTE PROCEDURE
2611 "write_event_delegation_trigger"();
2613 COMMENT ON FUNCTION "write_event_delegation_trigger"() IS 'Implementation of trigger "write_event_delegation" on table "delegation"';
2614 COMMENT ON TRIGGER "write_event_delegation" ON "delegation" IS 'Create entry in "event" table when adding, updating, or removing a delegation';
2617 CREATE FUNCTION "write_event_contact_trigger"()
2618 RETURNS TRIGGER
2619 LANGUAGE 'plpgsql' VOLATILE AS $$
2620 BEGIN
2621 IF TG_OP = 'UPDATE' THEN
2622 IF
2623 OLD."member_id" = NEW."member_id" AND
2624 OLD."other_member_id" = NEW."other_member_id" AND
2625 OLD."public" = NEW."public"
2626 THEN
2627 RETURN NULL;
2628 END IF;
2629 END IF;
2630 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2631 IF OLD."public" THEN
2632 IF EXISTS (
2633 SELECT NULL FROM "member" WHERE "id" = OLD."member_id"
2634 FOR SHARE
2635 ) AND EXISTS (
2636 SELECT NULL FROM "member" WHERE "id" = OLD."other_member_id"
2637 FOR SHARE
2638 ) THEN
2639 INSERT INTO "event" (
2640 "event", "member_id", "other_member_id", "boolean_value"
2641 ) VALUES (
2642 'contact', OLD."member_id", OLD."other_member_id", FALSE
2643 );
2644 END IF;
2645 END IF;
2646 END IF;
2647 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2648 IF NEW."public" THEN
2649 INSERT INTO "event" (
2650 "event", "member_id", "other_member_id", "boolean_value"
2651 ) VALUES (
2652 'contact', NEW."member_id", NEW."other_member_id", TRUE
2653 );
2654 END IF;
2655 END IF;
2656 RETURN NULL;
2657 END;
2658 $$;
2660 CREATE TRIGGER "write_event_contact"
2661 AFTER INSERT OR UPDATE OR DELETE ON "contact" FOR EACH ROW EXECUTE PROCEDURE
2662 "write_event_contact_trigger"();
2664 COMMENT ON FUNCTION "write_event_contact_trigger"() IS 'Implementation of trigger "write_event_contact" on table "contact"';
2665 COMMENT ON TRIGGER "write_event_contact" ON "contact" IS 'Create entry in "event" table when adding or removing public contacts';
2668 CREATE FUNCTION "send_event_notify_trigger"()
2669 RETURNS TRIGGER
2670 LANGUAGE 'plpgsql' VOLATILE AS $$
2671 BEGIN
2672 EXECUTE 'NOTIFY "event", ''' || NEW."event" || '''';
2673 RETURN NULL;
2674 END;
2675 $$;
2677 CREATE TRIGGER "send_notify"
2678 AFTER INSERT OR UPDATE ON "event" FOR EACH ROW EXECUTE PROCEDURE
2679 "send_event_notify_trigger"();
2683 ----------------------------
2684 -- Additional constraints --
2685 ----------------------------
2688 CREATE FUNCTION "delete_extended_scope_tokens_trigger"()
2689 RETURNS TRIGGER
2690 LANGUAGE 'plpgsql' VOLATILE AS $$
2691 DECLARE
2692 "system_application_row" "system_application"%ROWTYPE;
2693 BEGIN
2694 IF OLD."system_application_id" NOTNULL THEN
2695 SELECT * FROM "system_application" INTO "system_application_row"
2696 WHERE "id" = OLD."system_application_id";
2697 DELETE FROM "token"
2698 WHERE "member_id" = OLD."member_id"
2699 AND "system_application_id" = OLD."system_application_id"
2700 AND NOT COALESCE(
2701 regexp_split_to_array("scope", E'\\s+') <@
2702 regexp_split_to_array(
2703 "system_application_row"."automatic_scope", E'\\s+'
2704 ),
2705 FALSE
2706 );
2707 END IF;
2708 RETURN OLD;
2709 END;
2710 $$;
2712 CREATE TRIGGER "delete_extended_scope_tokens"
2713 BEFORE DELETE ON "member_application" FOR EACH ROW EXECUTE PROCEDURE
2714 "delete_extended_scope_tokens_trigger"();
2717 CREATE FUNCTION "detach_token_from_session_trigger"()
2718 RETURNS TRIGGER
2719 LANGUAGE 'plpgsql' VOLATILE AS $$
2720 BEGIN
2721 UPDATE "token" SET "session_id" = NULL
2722 WHERE "session_id" = OLD."id";
2723 RETURN OLD;
2724 END;
2725 $$;
2727 CREATE TRIGGER "detach_token_from_session"
2728 BEFORE DELETE ON "session" FOR EACH ROW EXECUTE PROCEDURE
2729 "detach_token_from_session_trigger"();
2732 CREATE FUNCTION "delete_non_detached_scope_with_session_trigger"()
2733 RETURNS TRIGGER
2734 LANGUAGE 'plpgsql' VOLATILE AS $$
2735 BEGIN
2736 IF NEW."session_id" ISNULL THEN
2737 SELECT coalesce(string_agg("element", ' '), '') INTO NEW."scope"
2738 FROM unnest(regexp_split_to_array(NEW."scope", E'\\s+')) AS "element"
2739 WHERE "element" LIKE '%_detached';
2740 END IF;
2741 RETURN NEW;
2742 END;
2743 $$;
2745 CREATE TRIGGER "delete_non_detached_scope_with_session"
2746 BEFORE INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2747 "delete_non_detached_scope_with_session_trigger"();
2750 CREATE FUNCTION "delete_token_with_empty_scope_trigger"()
2751 RETURNS TRIGGER
2752 LANGUAGE 'plpgsql' VOLATILE AS $$
2753 BEGIN
2754 IF NEW."scope" = '' THEN
2755 DELETE FROM "token" WHERE "id" = NEW."id";
2756 END IF;
2757 RETURN NULL;
2758 END;
2759 $$;
2761 CREATE TRIGGER "delete_token_with_empty_scope"
2762 AFTER INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2763 "delete_token_with_empty_scope_trigger"();
2766 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
2767 RETURNS TRIGGER
2768 LANGUAGE 'plpgsql' VOLATILE AS $$
2769 BEGIN
2770 IF NOT EXISTS (
2771 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
2772 ) THEN
2773 RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING
2774 ERRCODE = 'integrity_constraint_violation',
2775 HINT = 'Create issue, initiative, and draft within the same transaction.';
2776 END IF;
2777 RETURN NULL;
2778 END;
2779 $$;
2781 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
2782 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
2783 FOR EACH ROW EXECUTE PROCEDURE
2784 "issue_requires_first_initiative_trigger"();
2786 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
2787 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
2790 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
2791 RETURNS TRIGGER
2792 LANGUAGE 'plpgsql' VOLATILE AS $$
2793 DECLARE
2794 "reference_lost" BOOLEAN;
2795 BEGIN
2796 IF TG_OP = 'DELETE' THEN
2797 "reference_lost" := TRUE;
2798 ELSE
2799 "reference_lost" := NEW."issue_id" != OLD."issue_id";
2800 END IF;
2801 IF
2802 "reference_lost" AND NOT EXISTS (
2803 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
2805 THEN
2806 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
2807 END IF;
2808 RETURN NULL;
2809 END;
2810 $$;
2812 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
2813 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
2814 FOR EACH ROW EXECUTE PROCEDURE
2815 "last_initiative_deletes_issue_trigger"();
2817 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
2818 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
2821 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
2822 RETURNS TRIGGER
2823 LANGUAGE 'plpgsql' VOLATILE AS $$
2824 BEGIN
2825 IF NOT EXISTS (
2826 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
2827 ) THEN
2828 RAISE EXCEPTION 'Cannot create initiative without an initial draft.' USING
2829 ERRCODE = 'integrity_constraint_violation',
2830 HINT = 'Create issue, initiative and draft within the same transaction.';
2831 END IF;
2832 RETURN NULL;
2833 END;
2834 $$;
2836 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
2837 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
2838 FOR EACH ROW EXECUTE PROCEDURE
2839 "initiative_requires_first_draft_trigger"();
2841 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
2842 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
2845 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
2846 RETURNS TRIGGER
2847 LANGUAGE 'plpgsql' VOLATILE AS $$
2848 DECLARE
2849 "reference_lost" BOOLEAN;
2850 BEGIN
2851 IF TG_OP = 'DELETE' THEN
2852 "reference_lost" := TRUE;
2853 ELSE
2854 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
2855 END IF;
2856 IF
2857 "reference_lost" AND NOT EXISTS (
2858 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
2860 THEN
2861 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
2862 END IF;
2863 RETURN NULL;
2864 END;
2865 $$;
2867 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
2868 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
2869 FOR EACH ROW EXECUTE PROCEDURE
2870 "last_draft_deletes_initiative_trigger"();
2872 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
2873 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
2876 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
2877 RETURNS TRIGGER
2878 LANGUAGE 'plpgsql' VOLATILE AS $$
2879 BEGIN
2880 IF NOT EXISTS (
2881 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
2882 ) THEN
2883 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING
2884 ERRCODE = 'integrity_constraint_violation',
2885 HINT = 'Create suggestion and opinion within the same transaction.';
2886 END IF;
2887 RETURN NULL;
2888 END;
2889 $$;
2891 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
2892 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
2893 FOR EACH ROW EXECUTE PROCEDURE
2894 "suggestion_requires_first_opinion_trigger"();
2896 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
2897 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
2900 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
2901 RETURNS TRIGGER
2902 LANGUAGE 'plpgsql' VOLATILE AS $$
2903 DECLARE
2904 "reference_lost" BOOLEAN;
2905 BEGIN
2906 IF TG_OP = 'DELETE' THEN
2907 "reference_lost" := TRUE;
2908 ELSE
2909 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
2910 END IF;
2911 IF
2912 "reference_lost" AND NOT EXISTS (
2913 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
2915 THEN
2916 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
2917 END IF;
2918 RETURN NULL;
2919 END;
2920 $$;
2922 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
2923 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
2924 FOR EACH ROW EXECUTE PROCEDURE
2925 "last_opinion_deletes_suggestion_trigger"();
2927 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
2928 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
2931 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
2932 RETURNS TRIGGER
2933 LANGUAGE 'plpgsql' VOLATILE AS $$
2934 BEGIN
2935 DELETE FROM "direct_voter"
2936 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
2937 RETURN NULL;
2938 END;
2939 $$;
2941 CREATE TRIGGER "non_voter_deletes_direct_voter"
2942 AFTER INSERT OR UPDATE ON "non_voter"
2943 FOR EACH ROW EXECUTE PROCEDURE
2944 "non_voter_deletes_direct_voter_trigger"();
2946 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
2947 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")';
2950 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
2951 RETURNS TRIGGER
2952 LANGUAGE 'plpgsql' VOLATILE AS $$
2953 BEGIN
2954 DELETE FROM "non_voter"
2955 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
2956 RETURN NULL;
2957 END;
2958 $$;
2960 CREATE TRIGGER "direct_voter_deletes_non_voter"
2961 AFTER INSERT OR UPDATE ON "direct_voter"
2962 FOR EACH ROW EXECUTE PROCEDURE
2963 "direct_voter_deletes_non_voter_trigger"();
2965 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
2966 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")';
2969 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
2970 RETURNS TRIGGER
2971 LANGUAGE 'plpgsql' VOLATILE AS $$
2972 BEGIN
2973 IF NEW."comment" ISNULL THEN
2974 NEW."comment_changed" := NULL;
2975 NEW."formatting_engine" := NULL;
2976 END IF;
2977 RETURN NEW;
2978 END;
2979 $$;
2981 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
2982 BEFORE INSERT OR UPDATE ON "direct_voter"
2983 FOR EACH ROW EXECUTE PROCEDURE
2984 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
2986 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"';
2987 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.';
2991 ---------------------------------
2992 -- Delete incomplete snapshots --
2993 ---------------------------------
2996 CREATE FUNCTION "delete_snapshot_on_partial_delete_trigger"()
2997 RETURNS TRIGGER
2998 LANGUAGE 'plpgsql' VOLATILE AS $$
2999 BEGIN
3000 IF TG_OP = 'UPDATE' THEN
3001 IF
3002 OLD."snapshot_id" = NEW."snapshot_id" AND
3003 OLD."issue_id" = NEW."issue_id"
3004 THEN
3005 RETURN NULL;
3006 END IF;
3007 END IF;
3008 DELETE FROM "snapshot" WHERE "id" = OLD."snapshot_id";
3009 RETURN NULL;
3010 END;
3011 $$;
3013 CREATE TRIGGER "delete_snapshot_on_partial_delete"
3014 AFTER UPDATE OR DELETE ON "snapshot_issue"
3015 FOR EACH ROW EXECUTE PROCEDURE
3016 "delete_snapshot_on_partial_delete_trigger"();
3018 COMMENT ON FUNCTION "delete_snapshot_on_partial_delete_trigger"() IS 'Implementation of trigger "delete_snapshot_on_partial_delete" on table "snapshot_issue"';
3019 COMMENT ON TRIGGER "delete_snapshot_on_partial_delete" ON "snapshot_issue" IS 'Deletes whole snapshot if one issue is deleted from the snapshot';
3023 ---------------------------------------------------------------
3024 -- Ensure that votes are not modified when issues are closed --
3025 ---------------------------------------------------------------
3027 -- NOTE: Frontends should ensure this anyway, but in case of programming
3028 -- errors the following triggers ensure data integrity.
3031 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
3032 RETURNS TRIGGER
3033 LANGUAGE 'plpgsql' VOLATILE AS $$
3034 DECLARE
3035 "issue_id_v" "issue"."id"%TYPE;
3036 "issue_row" "issue"%ROWTYPE;
3037 BEGIN
3038 IF EXISTS (
3039 SELECT NULL FROM "temporary_transaction_data"
3040 WHERE "txid" = txid_current()
3041 AND "key" = 'override_protection_triggers'
3042 AND "value" = TRUE::TEXT
3043 ) THEN
3044 RETURN NULL;
3045 END IF;
3046 IF TG_OP = 'DELETE' THEN
3047 "issue_id_v" := OLD."issue_id";
3048 ELSE
3049 "issue_id_v" := NEW."issue_id";
3050 END IF;
3051 SELECT INTO "issue_row" * FROM "issue"
3052 WHERE "id" = "issue_id_v" FOR SHARE;
3053 IF (
3054 "issue_row"."closed" NOTNULL OR (
3055 "issue_row"."state" = 'voting' AND
3056 "issue_row"."phase_finished" NOTNULL
3058 ) THEN
3059 IF
3060 TG_RELID = 'direct_voter'::regclass AND
3061 TG_OP = 'UPDATE'
3062 THEN
3063 IF
3064 OLD."issue_id" = NEW."issue_id" AND
3065 OLD."member_id" = NEW."member_id" AND
3066 OLD."weight" = NEW."weight"
3067 THEN
3068 RETURN NULL; -- allows changing of voter comment
3069 END IF;
3070 END IF;
3071 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
3072 ERRCODE = 'integrity_constraint_violation';
3073 END IF;
3074 RETURN NULL;
3075 END;
3076 $$;
3078 CREATE TRIGGER "forbid_changes_on_closed_issue"
3079 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
3080 FOR EACH ROW EXECUTE PROCEDURE
3081 "forbid_changes_on_closed_issue_trigger"();
3083 CREATE TRIGGER "forbid_changes_on_closed_issue"
3084 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
3085 FOR EACH ROW EXECUTE PROCEDURE
3086 "forbid_changes_on_closed_issue_trigger"();
3088 CREATE TRIGGER "forbid_changes_on_closed_issue"
3089 AFTER INSERT OR UPDATE OR DELETE ON "vote"
3090 FOR EACH ROW EXECUTE PROCEDURE
3091 "forbid_changes_on_closed_issue_trigger"();
3093 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"';
3094 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';
3095 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';
3096 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';
3100 --------------------------------------------------------------------
3101 -- Auto-retrieval of fields only needed for referential integrity --
3102 --------------------------------------------------------------------
3105 CREATE FUNCTION "autofill_issue_id_trigger"()
3106 RETURNS TRIGGER
3107 LANGUAGE 'plpgsql' VOLATILE AS $$
3108 BEGIN
3109 IF NEW."issue_id" ISNULL THEN
3110 SELECT "issue_id" INTO NEW."issue_id"
3111 FROM "initiative" WHERE "id" = NEW."initiative_id";
3112 END IF;
3113 RETURN NEW;
3114 END;
3115 $$;
3117 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
3118 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3120 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
3121 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3123 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
3124 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
3125 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
3128 CREATE FUNCTION "autofill_initiative_id_trigger"()
3129 RETURNS TRIGGER
3130 LANGUAGE 'plpgsql' VOLATILE AS $$
3131 BEGIN
3132 IF NEW."initiative_id" ISNULL THEN
3133 SELECT "initiative_id" INTO NEW."initiative_id"
3134 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3135 END IF;
3136 RETURN NEW;
3137 END;
3138 $$;
3140 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
3141 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
3143 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
3144 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
3148 -------------------------------------------------------
3149 -- Automatic copying of values for indexing purposes --
3150 -------------------------------------------------------
3153 CREATE FUNCTION "copy_current_draft_data"
3154 ("initiative_id_p" "initiative"."id"%TYPE )
3155 RETURNS VOID
3156 LANGUAGE 'plpgsql' VOLATILE AS $$
3157 BEGIN
3158 PERFORM NULL FROM "initiative" WHERE "id" = "initiative_id_p"
3159 FOR UPDATE;
3160 UPDATE "initiative" SET
3161 "location" = "draft"."location",
3162 "draft_text_search_data" = "draft"."text_search_data"
3163 FROM "current_draft" AS "draft"
3164 WHERE "initiative"."id" = "initiative_id_p"
3165 AND "draft"."initiative_id" = "initiative_id_p";
3166 END;
3167 $$;
3169 COMMENT ON FUNCTION "copy_current_draft_data"
3170 ( "initiative"."id"%TYPE )
3171 IS 'Helper function for function "copy_current_draft_data_trigger"';
3174 CREATE FUNCTION "copy_current_draft_data_trigger"()
3175 RETURNS TRIGGER
3176 LANGUAGE 'plpgsql' VOLATILE AS $$
3177 BEGIN
3178 IF TG_OP='DELETE' THEN
3179 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3180 ELSE
3181 IF TG_OP='UPDATE' THEN
3182 IF COALESCE(OLD."inititiave_id" != NEW."initiative_id", TRUE) THEN
3183 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3184 END IF;
3185 END IF;
3186 PERFORM "copy_current_draft_data"(NEW."initiative_id");
3187 END IF;
3188 RETURN NULL;
3189 END;
3190 $$;
3192 CREATE TRIGGER "copy_current_draft_data"
3193 AFTER INSERT OR UPDATE OR DELETE ON "draft"
3194 FOR EACH ROW EXECUTE PROCEDURE
3195 "copy_current_draft_data_trigger"();
3197 COMMENT ON FUNCTION "copy_current_draft_data_trigger"() IS 'Implementation of trigger "copy_current_draft_data" on table "draft"';
3198 COMMENT ON TRIGGER "copy_current_draft_data" ON "draft" IS 'Copy certain fields from most recent "draft" to "initiative"';
3202 -----------------------------------------------------
3203 -- Automatic calculation of certain default values --
3204 -----------------------------------------------------
3207 CREATE FUNCTION "copy_timings_trigger"()
3208 RETURNS TRIGGER
3209 LANGUAGE 'plpgsql' VOLATILE AS $$
3210 DECLARE
3211 "policy_row" "policy"%ROWTYPE;
3212 BEGIN
3213 SELECT * INTO "policy_row" FROM "policy"
3214 WHERE "id" = NEW."policy_id";
3215 IF NEW."min_admission_time" ISNULL THEN
3216 NEW."min_admission_time" := "policy_row"."min_admission_time";
3217 END IF;
3218 IF NEW."max_admission_time" ISNULL THEN
3219 NEW."max_admission_time" := "policy_row"."max_admission_time";
3220 END IF;
3221 IF NEW."discussion_time" ISNULL THEN
3222 NEW."discussion_time" := "policy_row"."discussion_time";
3223 END IF;
3224 IF NEW."verification_time" ISNULL THEN
3225 NEW."verification_time" := "policy_row"."verification_time";
3226 END IF;
3227 IF NEW."voting_time" ISNULL THEN
3228 NEW."voting_time" := "policy_row"."voting_time";
3229 END IF;
3230 RETURN NEW;
3231 END;
3232 $$;
3234 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
3235 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
3237 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
3238 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
3241 CREATE FUNCTION "default_for_draft_id_trigger"()
3242 RETURNS TRIGGER
3243 LANGUAGE 'plpgsql' VOLATILE AS $$
3244 BEGIN
3245 IF NEW."draft_id" ISNULL THEN
3246 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
3247 WHERE "initiative_id" = NEW."initiative_id";
3248 END IF;
3249 RETURN NEW;
3250 END;
3251 $$;
3253 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
3254 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3255 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
3256 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3258 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
3259 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';
3260 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';
3264 ----------------------------------------
3265 -- Automatic creation of dependencies --
3266 ----------------------------------------
3269 CREATE FUNCTION "autocreate_interest_trigger"()
3270 RETURNS TRIGGER
3271 LANGUAGE 'plpgsql' VOLATILE AS $$
3272 BEGIN
3273 IF NOT EXISTS (
3274 SELECT NULL FROM "initiative" JOIN "interest"
3275 ON "initiative"."issue_id" = "interest"."issue_id"
3276 WHERE "initiative"."id" = NEW."initiative_id"
3277 AND "interest"."member_id" = NEW."member_id"
3278 ) THEN
3279 BEGIN
3280 INSERT INTO "interest" ("issue_id", "member_id")
3281 SELECT "issue_id", NEW."member_id"
3282 FROM "initiative" WHERE "id" = NEW."initiative_id";
3283 EXCEPTION WHEN unique_violation THEN END;
3284 END IF;
3285 RETURN NEW;
3286 END;
3287 $$;
3289 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
3290 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
3292 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
3293 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';
3296 CREATE FUNCTION "autocreate_supporter_trigger"()
3297 RETURNS TRIGGER
3298 LANGUAGE 'plpgsql' VOLATILE AS $$
3299 BEGIN
3300 IF NOT EXISTS (
3301 SELECT NULL FROM "suggestion" JOIN "supporter"
3302 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
3303 WHERE "suggestion"."id" = NEW."suggestion_id"
3304 AND "supporter"."member_id" = NEW."member_id"
3305 ) THEN
3306 BEGIN
3307 INSERT INTO "supporter" ("initiative_id", "member_id")
3308 SELECT "initiative_id", NEW."member_id"
3309 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3310 EXCEPTION WHEN unique_violation THEN END;
3311 END IF;
3312 RETURN NEW;
3313 END;
3314 $$;
3316 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
3317 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
3319 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
3320 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.';
3324 ------------------------------------------
3325 -- Views and helper functions for views --
3326 ------------------------------------------
3329 CREATE VIEW "member_eligible_to_be_notified" AS
3330 SELECT * FROM "member"
3331 WHERE "activated" NOTNULL AND "locked" = FALSE;
3333 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")';
3336 CREATE VIEW "member_to_notify" AS
3337 SELECT * FROM "member_eligible_to_be_notified"
3338 WHERE "disable_notifications" = FALSE;
3340 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)';
3343 CREATE VIEW "area_quorum" AS
3344 SELECT
3345 "area"."id" AS "area_id",
3346 ceil(
3347 "area"."quorum_standard"::FLOAT8 * "quorum_factor"::FLOAT8 ^ (
3348 coalesce(
3349 ( SELECT sum(
3350 ( extract(epoch from "area"."quorum_time")::FLOAT8 /
3351 extract(epoch from
3352 ("issue"."accepted"-"issue"."created") +
3353 "issue"."discussion_time" +
3354 "issue"."verification_time" +
3355 "issue"."voting_time"
3356 )::FLOAT8
3357 ) ^ "area"."quorum_exponent"::FLOAT8
3359 FROM "issue" JOIN "policy"
3360 ON "issue"."policy_id" = "policy"."id"
3361 WHERE "issue"."area_id" = "area"."id"
3362 AND "issue"."accepted" NOTNULL
3363 AND "issue"."closed" ISNULL
3364 AND "policy"."polling" = FALSE
3365 )::FLOAT8, 0::FLOAT8
3366 ) / "area"."quorum_issues"::FLOAT8 - 1::FLOAT8
3367 ) * CASE WHEN "area"."quorum_den" ISNULL THEN 1 ELSE (
3368 SELECT "snapshot"."population"
3369 FROM "snapshot"
3370 WHERE "snapshot"."area_id" = "area"."id"
3371 AND "snapshot"."issue_id" ISNULL
3372 ORDER BY "snapshot"."id" DESC
3373 LIMIT 1
3374 ) END / coalesce("area"."quorum_den", 1)
3376 )::INT4 AS "issue_quorum"
3377 FROM "area";
3379 COMMENT ON VIEW "area_quorum" IS 'Area-based quorum considering number of open (accepted) issues';
3382 CREATE VIEW "issue_quorum" AS
3383 SELECT DISTINCT ON ("issue_id")
3384 "issue"."id" AS "issue_id",
3385 "subquery"."issue_quorum"
3386 FROM "issue"
3387 CROSS JOIN LATERAL (
3388 SELECT "area_quorum"."issue_quorum"
3389 FROM "area_quorum" WHERE "area_quorum"."area_id" = "issue"."area_id"
3390 UNION ALL
3391 SELECT "policy"."issue_quorum"
3392 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3393 UNION ALL
3394 SELECT
3395 ceil(
3396 ("issue"."population"::INT8 * "policy"."issue_quorum_num"::INT8) /
3397 "policy"."issue_quorum_den"::FLOAT8
3398 )::INT4
3399 FROM "policy" WHERE "policy"."id" = "issue"."policy_id"
3400 ) AS "subquery"
3401 ORDER BY "issue_id", "issue_quorum" DESC;
3403 COMMENT ON VIEW "issue_quorum" IS 'Effective quorum for issue admission';
3406 CREATE VIEW "area_with_unaccepted_issues" AS
3407 SELECT DISTINCT ON ("area"."id") "area".*
3408 FROM "area" JOIN "issue" ON "area"."id" = "issue"."area_id"
3409 WHERE "issue"."state" = 'admission';
3411 COMMENT ON VIEW "area_with_unaccepted_issues" IS 'All areas with unaccepted open issues (needed for issue admission system)';
3414 CREATE VIEW "issue_for_admission" AS
3415 SELECT DISTINCT ON ("issue"."area_id")
3416 "issue".*,
3417 max("initiative"."supporter_count") AS "max_supporter_count"
3418 FROM "issue"
3419 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
3420 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
3421 JOIN "area" ON "issue"."area_id" = "area"."id"
3422 WHERE "issue"."state" = 'admission'::"issue_state"
3423 AND now() >= "issue"."created" + "issue"."min_admission_time"
3424 AND "initiative"."supporter_count" >= "policy"."issue_quorum"
3425 AND "initiative"."supporter_count" * "policy"."issue_quorum_den" >=
3426 "issue"."population" * "policy"."issue_quorum_num"
3427 AND "initiative"."supporter_count" >= "area"."issue_quorum"
3428 AND "initiative"."revoked" ISNULL
3429 GROUP BY "issue"."id"
3430 ORDER BY "issue"."area_id", "max_supporter_count" DESC, "issue"."id";
3432 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';
3435 CREATE VIEW "unit_delegation" AS
3436 SELECT
3437 "unit"."id" AS "unit_id",
3438 "delegation"."id",
3439 "delegation"."truster_id",
3440 "delegation"."trustee_id",
3441 "delegation"."scope"
3442 FROM "unit"
3443 JOIN "delegation"
3444 ON "delegation"."unit_id" = "unit"."id"
3445 JOIN "member"
3446 ON "delegation"."truster_id" = "member"."id"
3447 JOIN "privilege"
3448 ON "delegation"."unit_id" = "privilege"."unit_id"
3449 AND "delegation"."truster_id" = "privilege"."member_id"
3450 WHERE "member"."active" AND "privilege"."voting_right";
3452 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
3455 CREATE VIEW "area_delegation" AS
3456 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
3457 "area"."id" AS "area_id",
3458 "delegation"."id",
3459 "delegation"."truster_id",
3460 "delegation"."trustee_id",
3461 "delegation"."scope"
3462 FROM "area"
3463 JOIN "delegation"
3464 ON "delegation"."unit_id" = "area"."unit_id"
3465 OR "delegation"."area_id" = "area"."id"
3466 JOIN "member"
3467 ON "delegation"."truster_id" = "member"."id"
3468 JOIN "privilege"
3469 ON "area"."unit_id" = "privilege"."unit_id"
3470 AND "delegation"."truster_id" = "privilege"."member_id"
3471 WHERE "member"."active" AND "privilege"."voting_right"
3472 ORDER BY
3473 "area"."id",
3474 "delegation"."truster_id",
3475 "delegation"."scope" DESC;
3477 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
3480 CREATE VIEW "issue_delegation" AS
3481 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
3482 "issue"."id" AS "issue_id",
3483 "delegation"."id",
3484 "delegation"."truster_id",
3485 "delegation"."trustee_id",
3486 "delegation"."scope"
3487 FROM "issue"
3488 JOIN "area"
3489 ON "area"."id" = "issue"."area_id"
3490 JOIN "delegation"
3491 ON "delegation"."unit_id" = "area"."unit_id"
3492 OR "delegation"."area_id" = "area"."id"
3493 OR "delegation"."issue_id" = "issue"."id"
3494 JOIN "member"
3495 ON "delegation"."truster_id" = "member"."id"
3496 JOIN "privilege"
3497 ON "area"."unit_id" = "privilege"."unit_id"
3498 AND "delegation"."truster_id" = "privilege"."member_id"
3499 WHERE "member"."active" AND "privilege"."voting_right"
3500 ORDER BY
3501 "issue"."id",
3502 "delegation"."truster_id",
3503 "delegation"."scope" DESC;
3505 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
3508 CREATE VIEW "member_count_view" AS
3509 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
3511 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
3514 CREATE VIEW "unit_member" AS
3515 SELECT
3516 "unit"."id" AS "unit_id",
3517 "member"."id" AS "member_id"
3518 FROM "privilege"
3519 JOIN "unit" ON "unit"."id" = "privilege"."unit_id"
3520 JOIN "member" ON "member"."id" = "privilege"."member_id"
3521 WHERE "privilege"."voting_right" AND "member"."active";
3523 COMMENT ON VIEW "unit_member" IS 'Active members with voting right in a unit';
3526 CREATE VIEW "unit_member_count" AS
3527 SELECT
3528 "unit"."id" AS "unit_id",
3529 count("unit_member"."member_id") AS "member_count"
3530 FROM "unit" LEFT JOIN "unit_member"
3531 ON "unit"."id" = "unit_member"."unit_id"
3532 GROUP BY "unit"."id";
3534 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
3537 CREATE VIEW "opening_draft" AS
3538 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3539 ORDER BY "initiative_id", "id";
3541 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
3544 CREATE VIEW "current_draft" AS
3545 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3546 ORDER BY "initiative_id", "id" DESC;
3548 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
3551 CREATE VIEW "critical_opinion" AS
3552 SELECT * FROM "opinion"
3553 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
3554 OR ("degree" = -2 AND "fulfilled" = TRUE);
3556 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
3559 CREATE VIEW "issue_supporter_in_admission_state" AS
3560 SELECT
3561 "area"."unit_id",
3562 "issue"."area_id",
3563 "issue"."id" AS "issue_id",
3564 "supporter"."member_id",
3565 "direct_interest_snapshot"."weight"
3566 FROM "issue"
3567 JOIN "area" ON "area"."id" = "issue"."area_id"
3568 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
3569 JOIN "direct_interest_snapshot"
3570 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3571 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3572 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
3573 WHERE "issue"."state" = 'admission'::"issue_state";
3575 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';
3578 CREATE VIEW "initiative_suggestion_order_calculation" AS
3579 SELECT
3580 "initiative"."id" AS "initiative_id",
3581 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
3582 FROM "initiative" JOIN "issue"
3583 ON "initiative"."issue_id" = "issue"."id"
3584 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
3585 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
3587 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
3589 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';
3592 CREATE VIEW "individual_suggestion_ranking" AS
3593 SELECT
3594 "opinion"."initiative_id",
3595 "opinion"."member_id",
3596 "direct_interest_snapshot"."weight",
3597 CASE WHEN
3598 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
3599 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
3600 THEN 1 ELSE
3601 CASE WHEN
3602 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
3603 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
3604 THEN 2 ELSE
3605 CASE WHEN
3606 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
3607 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
3608 THEN 3 ELSE 4 END
3609 END
3610 END AS "preference",
3611 "opinion"."suggestion_id"
3612 FROM "opinion"
3613 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
3614 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3615 JOIN "direct_interest_snapshot"
3616 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3617 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3618 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
3620 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
3623 CREATE VIEW "battle_participant" AS
3624 SELECT "initiative"."id", "initiative"."issue_id"
3625 FROM "issue" JOIN "initiative"
3626 ON "issue"."id" = "initiative"."issue_id"
3627 WHERE "initiative"."admitted"
3628 UNION ALL
3629 SELECT NULL, "id" AS "issue_id"
3630 FROM "issue";
3632 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
3635 CREATE VIEW "battle_view" AS
3636 SELECT
3637 "issue"."id" AS "issue_id",
3638 "winning_initiative"."id" AS "winning_initiative_id",
3639 "losing_initiative"."id" AS "losing_initiative_id",
3640 sum(
3641 CASE WHEN
3642 coalesce("better_vote"."grade", 0) >
3643 coalesce("worse_vote"."grade", 0)
3644 THEN "direct_voter"."weight" ELSE 0 END
3645 ) AS "count"
3646 FROM "issue"
3647 LEFT JOIN "direct_voter"
3648 ON "issue"."id" = "direct_voter"."issue_id"
3649 JOIN "battle_participant" AS "winning_initiative"
3650 ON "issue"."id" = "winning_initiative"."issue_id"
3651 JOIN "battle_participant" AS "losing_initiative"
3652 ON "issue"."id" = "losing_initiative"."issue_id"
3653 LEFT JOIN "vote" AS "better_vote"
3654 ON "direct_voter"."member_id" = "better_vote"."member_id"
3655 AND "winning_initiative"."id" = "better_vote"."initiative_id"
3656 LEFT JOIN "vote" AS "worse_vote"
3657 ON "direct_voter"."member_id" = "worse_vote"."member_id"
3658 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
3659 WHERE "issue"."state" = 'voting'
3660 AND "issue"."phase_finished" NOTNULL
3661 AND (
3662 "winning_initiative"."id" != "losing_initiative"."id" OR
3663 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
3664 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
3665 GROUP BY
3666 "issue"."id",
3667 "winning_initiative"."id",
3668 "losing_initiative"."id";
3670 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';
3673 CREATE VIEW "expired_session" AS
3674 SELECT * FROM "session" WHERE now() > "expiry";
3676 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
3677 DELETE FROM "session" WHERE "id" = OLD."id";
3679 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
3680 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
3683 CREATE VIEW "expired_token" AS
3684 SELECT * FROM "token" WHERE now() > "expiry" AND NOT (
3685 "token_type" = 'authorization' AND "used" AND EXISTS (
3686 SELECT NULL FROM "token" AS "other"
3687 WHERE "other"."authorization_token_id" = "token"."id" ) );
3689 CREATE RULE "delete" AS ON DELETE TO "expired_token" DO INSTEAD
3690 DELETE FROM "token" WHERE "id" = OLD."id";
3692 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';
3695 CREATE VIEW "unused_snapshot" AS
3696 SELECT "snapshot".* FROM "snapshot"
3697 LEFT JOIN "issue"
3698 ON "snapshot"."id" = "issue"."latest_snapshot_id"
3699 OR "snapshot"."id" = "issue"."admission_snapshot_id"
3700 OR "snapshot"."id" = "issue"."half_freeze_snapshot_id"
3701 OR "snapshot"."id" = "issue"."full_freeze_snapshot_id"
3702 WHERE "issue"."id" ISNULL;
3704 CREATE RULE "delete" AS ON DELETE TO "unused_snapshot" DO INSTEAD
3705 DELETE FROM "snapshot" WHERE "id" = OLD."id";
3707 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)';
3710 CREATE VIEW "expired_snapshot" AS
3711 SELECT "unused_snapshot".* FROM "unused_snapshot" CROSS JOIN "system_setting"
3712 WHERE "unused_snapshot"."calculated" <
3713 now() - "system_setting"."snapshot_retention";
3715 CREATE RULE "delete" AS ON DELETE TO "expired_snapshot" DO INSTEAD
3716 DELETE FROM "snapshot" WHERE "id" = OLD."id";
3718 COMMENT ON VIEW "expired_snapshot" IS 'Contains "unused_snapshot"s that are older than "system_setting"."snapshot_retention" (for deletion)';
3721 CREATE VIEW "open_issue" AS
3722 SELECT * FROM "issue" WHERE "closed" ISNULL;
3724 COMMENT ON VIEW "open_issue" IS 'All open issues';
3727 CREATE VIEW "member_contingent" AS
3728 SELECT
3729 "member"."id" AS "member_id",
3730 "contingent"."polling",
3731 "contingent"."time_frame",
3732 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
3734 SELECT count(1) FROM "draft"
3735 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3736 WHERE "draft"."author_id" = "member"."id"
3737 AND "initiative"."polling" = "contingent"."polling"
3738 AND "draft"."created" > now() - "contingent"."time_frame"
3739 ) + (
3740 SELECT count(1) FROM "suggestion"
3741 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
3742 WHERE "suggestion"."author_id" = "member"."id"
3743 AND "contingent"."polling" = FALSE
3744 AND "suggestion"."created" > now() - "contingent"."time_frame"
3746 ELSE NULL END AS "text_entry_count",
3747 "contingent"."text_entry_limit",
3748 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
3749 SELECT count(1) FROM "opening_draft" AS "draft"
3750 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3751 WHERE "draft"."author_id" = "member"."id"
3752 AND "initiative"."polling" = "contingent"."polling"
3753 AND "draft"."created" > now() - "contingent"."time_frame"
3754 ) ELSE NULL END AS "initiative_count",
3755 "contingent"."initiative_limit"
3756 FROM "member" CROSS JOIN "contingent";
3758 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
3760 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
3761 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
3764 CREATE VIEW "member_contingent_left" AS
3765 SELECT
3766 "member_id",
3767 "polling",
3768 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
3769 max("initiative_limit" - "initiative_count") AS "initiatives_left"
3770 FROM "member_contingent" GROUP BY "member_id", "polling";
3772 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.';
3775 CREATE VIEW "event_for_notification" AS
3776 SELECT
3777 "member"."id" AS "recipient_id",
3778 "event".*
3779 FROM "member" CROSS JOIN "event"
3780 JOIN "issue" ON "issue"."id" = "event"."issue_id"
3781 JOIN "area" ON "area"."id" = "issue"."area_id"
3782 LEFT JOIN "privilege" ON
3783 "privilege"."member_id" = "member"."id" AND
3784 "privilege"."unit_id" = "area"."unit_id" AND
3785 "privilege"."voting_right" = TRUE
3786 LEFT JOIN "subscription" ON
3787 "subscription"."member_id" = "member"."id" AND
3788 "subscription"."unit_id" = "area"."unit_id"
3789 LEFT JOIN "ignored_area" ON
3790 "ignored_area"."member_id" = "member"."id" AND
3791 "ignored_area"."area_id" = "issue"."area_id"
3792 LEFT JOIN "interest" ON
3793 "interest"."member_id" = "member"."id" AND
3794 "interest"."issue_id" = "event"."issue_id"
3795 LEFT JOIN "supporter" ON
3796 "supporter"."member_id" = "member"."id" AND
3797 "supporter"."initiative_id" = "event"."initiative_id"
3798 WHERE ("privilege"."member_id" NOTNULL OR "subscription"."member_id" NOTNULL)
3799 AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
3800 AND (
3801 "event"."event" = 'issue_state_changed'::"event_type" OR
3802 ( "event"."event" = 'initiative_revoked'::"event_type" AND
3803 "supporter"."member_id" NOTNULL ) );
3805 COMMENT ON VIEW "event_for_notification" IS 'Entries of the "event" table which are of interest for a particular notification mail recipient';
3807 COMMENT ON COLUMN "event_for_notification"."recipient_id" IS 'member_id of the recipient of a notification mail';
3810 CREATE VIEW "updated_initiative" AS
3811 SELECT
3812 "supporter"."member_id" AS "recipient_id",
3813 FALSE AS "featured",
3814 "supporter"."initiative_id"
3815 FROM "supporter"
3816 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
3817 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3818 LEFT JOIN "notification_initiative_sent" AS "sent" ON
3819 "sent"."member_id" = "supporter"."member_id" AND
3820 "sent"."initiative_id" = "supporter"."initiative_id"
3821 LEFT JOIN "ignored_initiative" ON
3822 "ignored_initiative"."member_id" = "supporter"."member_id" AND
3823 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
3824 WHERE "issue"."state" IN ('admission', 'discussion')
3825 AND "initiative"."revoked" ISNULL
3826 AND "ignored_initiative"."member_id" ISNULL
3827 AND (
3828 EXISTS (
3829 SELECT NULL FROM "draft"
3830 LEFT JOIN "ignored_member" ON
3831 "ignored_member"."member_id" = "supporter"."member_id" AND
3832 "ignored_member"."other_member_id" = "draft"."author_id"
3833 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
3834 AND "draft"."id" > "supporter"."draft_id"
3835 AND "ignored_member"."member_id" ISNULL
3836 ) OR EXISTS (
3837 SELECT NULL FROM "suggestion"
3838 LEFT JOIN "opinion" ON
3839 "opinion"."member_id" = "supporter"."member_id" AND
3840 "opinion"."suggestion_id" = "suggestion"."id"
3841 LEFT JOIN "ignored_member" ON
3842 "ignored_member"."member_id" = "supporter"."member_id" AND
3843 "ignored_member"."other_member_id" = "suggestion"."author_id"
3844 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
3845 AND "opinion"."member_id" ISNULL
3846 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
3847 AND "ignored_member"."member_id" ISNULL
3849 );
3851 COMMENT ON VIEW "updated_initiative" IS 'Helper view for view "updated_or_featured_initiative"';
3854 CREATE FUNCTION "featured_initiative"
3855 ( "recipient_id_p" "member"."id"%TYPE,
3856 "area_id_p" "area"."id"%TYPE )
3857 RETURNS SETOF "initiative"."id"%TYPE
3858 LANGUAGE 'plpgsql' STABLE AS $$
3859 DECLARE
3860 "counter_v" "member"."notification_counter"%TYPE;
3861 "sample_size_v" "member"."notification_sample_size"%TYPE;
3862 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
3863 "match_v" BOOLEAN;
3864 "member_id_v" "member"."id"%TYPE;
3865 "seed_v" TEXT;
3866 "initiative_id_v" "initiative"."id"%TYPE;
3867 BEGIN
3868 SELECT "notification_counter", "notification_sample_size"
3869 INTO "counter_v", "sample_size_v"
3870 FROM "member" WHERE "id" = "recipient_id_p";
3871 IF COALESCE("sample_size_v" <= 0, TRUE) THEN
3872 RETURN;
3873 END IF;
3874 "initiative_id_ary" := '{}';
3875 LOOP
3876 "match_v" := FALSE;
3877 FOR "member_id_v", "seed_v" IN
3878 SELECT * FROM (
3879 SELECT DISTINCT
3880 "supporter"."member_id",
3881 md5(
3882 "recipient_id_p" || '-' ||
3883 "counter_v" || '-' ||
3884 "area_id_p" || '-' ||
3885 "supporter"."member_id"
3886 ) AS "seed"
3887 FROM "supporter"
3888 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
3889 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3890 WHERE "supporter"."member_id" != "recipient_id_p"
3891 AND "issue"."area_id" = "area_id_p"
3892 AND "issue"."state" IN ('admission', 'discussion', 'verification')
3893 ) AS "subquery"
3894 ORDER BY "seed"
3895 LOOP
3896 SELECT "initiative"."id" INTO "initiative_id_v"
3897 FROM "initiative"
3898 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3899 JOIN "area" ON "area"."id" = "issue"."area_id"
3900 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
3901 LEFT JOIN "supporter" AS "self_support" ON
3902 "self_support"."initiative_id" = "initiative"."id" AND
3903 "self_support"."member_id" = "recipient_id_p"
3904 LEFT JOIN "privilege" ON
3905 "privilege"."member_id" = "recipient_id_p" AND
3906 "privilege"."unit_id" = "area"."unit_id" AND
3907 "privilege"."voting_right" = TRUE
3908 LEFT JOIN "subscription" ON
3909 "subscription"."member_id" = "recipient_id_p" AND
3910 "subscription"."unit_id" = "area"."unit_id"
3911 LEFT JOIN "ignored_initiative" ON
3912 "ignored_initiative"."member_id" = "recipient_id_p" AND
3913 "ignored_initiative"."initiative_id" = "initiative"."id"
3914 WHERE "supporter"."member_id" = "member_id_v"
3915 AND "issue"."area_id" = "area_id_p"
3916 AND "issue"."state" IN ('admission', 'discussion', 'verification')
3917 AND "initiative"."revoked" ISNULL
3918 AND "self_support"."member_id" ISNULL
3919 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
3920 AND (
3921 "privilege"."member_id" NOTNULL OR
3922 "subscription"."member_id" NOTNULL )
3923 AND "ignored_initiative"."member_id" ISNULL
3924 AND NOT EXISTS (
3925 SELECT NULL FROM "draft"
3926 JOIN "ignored_member" ON
3927 "ignored_member"."member_id" = "recipient_id_p" AND
3928 "ignored_member"."other_member_id" = "draft"."author_id"
3929 WHERE "draft"."initiative_id" = "initiative"."id"
3931 ORDER BY md5("seed_v" || '-' || "initiative"."id")
3932 LIMIT 1;
3933 IF FOUND THEN
3934 "match_v" := TRUE;
3935 RETURN NEXT "initiative_id_v";
3936 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
3937 RETURN;
3938 END IF;
3939 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
3940 END IF;
3941 END LOOP;
3942 EXIT WHEN NOT "match_v";
3943 END LOOP;
3944 RETURN;
3945 END;
3946 $$;
3948 COMMENT ON FUNCTION "featured_initiative"
3949 ( "recipient_id_p" "member"."id"%TYPE,
3950 "area_id_p" "area"."id"%TYPE )
3951 IS 'Helper function for view "updated_or_featured_initiative"';
3954 CREATE VIEW "updated_or_featured_initiative" AS
3955 SELECT
3956 "subquery".*,
3957 NOT EXISTS (
3958 SELECT NULL FROM "initiative" AS "better_initiative"
3959 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
3960 AND
3961 ( COALESCE("better_initiative"."supporter_count", -1),
3962 -"better_initiative"."id" ) >
3963 ( COALESCE("initiative"."supporter_count", -1),
3964 -"initiative"."id" )
3965 ) AS "leading"
3966 FROM (
3967 SELECT * FROM "updated_initiative"
3968 UNION ALL
3969 SELECT
3970 "member"."id" AS "recipient_id",
3971 TRUE AS "featured",
3972 "featured_initiative_id" AS "initiative_id"
3973 FROM "member" CROSS JOIN "area"
3974 CROSS JOIN LATERAL
3975 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
3976 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
3977 ) AS "subquery"
3978 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
3980 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';
3982 COMMENT ON COLUMN "updated_or_featured_initiative"."recipient_id" IS '"id" of the member who receives the notification mail';
3983 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")';
3984 COMMENT ON COLUMN "updated_or_featured_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
3985 COMMENT ON COLUMN "updated_or_featured_initiative"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
3988 CREATE VIEW "leading_complement_initiative" AS
3989 SELECT * FROM (
3990 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
3991 "uf_initiative"."recipient_id",
3992 FALSE AS "featured",
3993 "uf_initiative"."initiative_id",
3994 TRUE AS "leading"
3995 FROM "updated_or_featured_initiative" AS "uf_initiative"
3996 JOIN "initiative" AS "uf_initiative_full" ON
3997 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
3998 JOIN "initiative" ON
3999 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
4000 WHERE "initiative"."revoked" ISNULL
4001 ORDER BY
4002 "uf_initiative"."recipient_id",
4003 "initiative"."issue_id",
4004 "initiative"."supporter_count" DESC,
4005 "initiative"."id"
4006 ) AS "subquery"
4007 WHERE NOT EXISTS (
4008 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
4009 WHERE "other"."recipient_id" = "subquery"."recipient_id"
4010 AND "other"."initiative_id" = "subquery"."initiative_id"
4011 );
4013 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';
4014 COMMENT ON COLUMN "leading_complement_initiative"."featured" IS 'Always FALSE in this view';
4015 COMMENT ON COLUMN "leading_complement_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4016 COMMENT ON COLUMN "leading_complement_initiative"."leading" IS 'Always TRUE in this view';
4019 CREATE VIEW "unfiltered_initiative_for_notification" AS
4020 SELECT
4021 "subquery".*,
4022 "supporter"."member_id" NOTNULL AS "supported",
4023 CASE WHEN "supporter"."member_id" NOTNULL THEN
4024 EXISTS (
4025 SELECT NULL FROM "draft"
4026 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4027 AND "draft"."id" > "supporter"."draft_id"
4029 ELSE
4030 EXISTS (
4031 SELECT NULL FROM "draft"
4032 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
4033 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
4035 END AS "new_draft",
4036 CASE WHEN "supporter"."member_id" NOTNULL THEN
4037 ( SELECT count(1) FROM "suggestion"
4038 LEFT JOIN "opinion" ON
4039 "opinion"."member_id" = "supporter"."member_id" AND
4040 "opinion"."suggestion_id" = "suggestion"."id"
4041 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4042 AND "opinion"."member_id" ISNULL
4043 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4045 ELSE
4046 ( SELECT count(1) FROM "suggestion"
4047 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
4048 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
4050 END AS "new_suggestion_count"
4051 FROM (
4052 SELECT * FROM "updated_or_featured_initiative"
4053 UNION ALL
4054 SELECT * FROM "leading_complement_initiative"
4055 ) AS "subquery"
4056 LEFT JOIN "supporter" ON
4057 "supporter"."member_id" = "subquery"."recipient_id" AND
4058 "supporter"."initiative_id" = "subquery"."initiative_id"
4059 LEFT JOIN "notification_initiative_sent" AS "sent" ON
4060 "sent"."member_id" = "subquery"."recipient_id" AND
4061 "sent"."initiative_id" = "subquery"."initiative_id";
4063 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';
4065 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4066 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)';
4067 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")';
4070 CREATE VIEW "initiative_for_notification" AS
4071 SELECT "unfiltered1".*
4072 FROM "unfiltered_initiative_for_notification" "unfiltered1"
4073 JOIN "initiative" AS "initiative1" ON
4074 "initiative1"."id" = "unfiltered1"."initiative_id"
4075 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
4076 WHERE EXISTS (
4077 SELECT NULL
4078 FROM "unfiltered_initiative_for_notification" "unfiltered2"
4079 JOIN "initiative" AS "initiative2" ON
4080 "initiative2"."id" = "unfiltered2"."initiative_id"
4081 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
4082 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
4083 AND "issue1"."area_id" = "issue2"."area_id"
4084 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
4085 );
4087 COMMENT ON VIEW "initiative_for_notification" IS 'Initiatives to be included in a scheduled notification mail';
4089 COMMENT ON COLUMN "initiative_for_notification"."recipient_id" IS '"id" of the member who receives the notification mail';
4090 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")';
4091 COMMENT ON COLUMN "initiative_for_notification"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4092 COMMENT ON COLUMN "initiative_for_notification"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4093 COMMENT ON COLUMN "initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4094 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)';
4095 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")';
4098 CREATE VIEW "scheduled_notification_to_send" AS
4099 SELECT * FROM (
4100 SELECT
4101 "id" AS "recipient_id",
4102 now() - CASE WHEN "notification_dow" ISNULL THEN
4103 ( "notification_sent"::DATE + CASE
4104 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4105 THEN 0 ELSE 1 END
4106 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4107 ELSE
4108 ( "notification_sent"::DATE +
4109 ( 7 + "notification_dow" -
4110 EXTRACT(DOW FROM
4111 ( "notification_sent"::DATE + CASE
4112 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4113 THEN 0 ELSE 1 END
4114 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4115 )::INTEGER
4116 ) % 7 +
4117 CASE
4118 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4119 THEN 0 ELSE 1
4120 END
4121 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4122 END AS "pending"
4123 FROM (
4124 SELECT
4125 "id",
4126 COALESCE("notification_sent", "activated") AS "notification_sent",
4127 "notification_dow",
4128 "notification_hour"
4129 FROM "member_to_notify"
4130 WHERE "notification_hour" NOTNULL
4131 ) AS "subquery1"
4132 ) AS "subquery2"
4133 WHERE "pending" > '0'::INTERVAL;
4135 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
4137 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
4138 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
4141 CREATE VIEW "newsletter_to_send" AS
4142 SELECT
4143 "member"."id" AS "recipient_id",
4144 "newsletter"."id" AS "newsletter_id",
4145 "newsletter"."published"
4146 FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member"
4147 LEFT JOIN "privilege" ON
4148 "privilege"."member_id" = "member"."id" AND
4149 "privilege"."unit_id" = "newsletter"."unit_id" AND
4150 "privilege"."voting_right" = TRUE
4151 LEFT JOIN "subscription" ON
4152 "subscription"."member_id" = "member"."id" AND
4153 "subscription"."unit_id" = "newsletter"."unit_id"
4154 WHERE "newsletter"."published" <= now()
4155 AND "newsletter"."sent" ISNULL
4156 AND (
4157 "member"."disable_notifications" = FALSE OR
4158 "newsletter"."include_all_members" = TRUE )
4159 AND (
4160 "newsletter"."unit_id" ISNULL OR
4161 "privilege"."member_id" NOTNULL OR
4162 "subscription"."member_id" NOTNULL );
4164 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
4166 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
4170 ------------------------------------------------------
4171 -- Row set returning function for delegation chains --
4172 ------------------------------------------------------
4175 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
4176 ('first', 'intermediate', 'last', 'repetition');
4178 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
4181 CREATE TYPE "delegation_chain_row" AS (
4182 "index" INT4,
4183 "member_id" INT4,
4184 "member_valid" BOOLEAN,
4185 "participation" BOOLEAN,
4186 "overridden" BOOLEAN,
4187 "scope_in" "delegation_scope",
4188 "scope_out" "delegation_scope",
4189 "disabled_out" BOOLEAN,
4190 "loop" "delegation_chain_loop_tag" );
4192 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
4194 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
4195 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest; for area and global delegation chains: always null';
4196 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
4197 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
4198 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
4199 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
4200 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
4203 CREATE FUNCTION "delegation_chain_for_closed_issue"
4204 ( "member_id_p" "member"."id"%TYPE,
4205 "issue_id_p" "issue"."id"%TYPE )
4206 RETURNS SETOF "delegation_chain_row"
4207 LANGUAGE 'plpgsql' STABLE AS $$
4208 DECLARE
4209 "output_row" "delegation_chain_row";
4210 "direct_voter_row" "direct_voter"%ROWTYPE;
4211 "delegating_voter_row" "delegating_voter"%ROWTYPE;
4212 BEGIN
4213 "output_row"."index" := 0;
4214 "output_row"."member_id" := "member_id_p";
4215 "output_row"."member_valid" := TRUE;
4216 "output_row"."participation" := FALSE;
4217 "output_row"."overridden" := FALSE;
4218 "output_row"."disabled_out" := FALSE;
4219 LOOP
4220 SELECT INTO "direct_voter_row" * FROM "direct_voter"
4221 WHERE "issue_id" = "issue_id_p"
4222 AND "member_id" = "output_row"."member_id";
4223 IF "direct_voter_row"."member_id" NOTNULL THEN
4224 "output_row"."participation" := TRUE;
4225 "output_row"."scope_out" := NULL;
4226 "output_row"."disabled_out" := NULL;
4227 RETURN NEXT "output_row";
4228 RETURN;
4229 END IF;
4230 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
4231 WHERE "issue_id" = "issue_id_p"
4232 AND "member_id" = "output_row"."member_id";
4233 IF "delegating_voter_row"."member_id" ISNULL THEN
4234 RETURN;
4235 END IF;
4236 "output_row"."scope_out" := "delegating_voter_row"."scope";
4237 RETURN NEXT "output_row";
4238 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
4239 "output_row"."scope_in" := "output_row"."scope_out";
4240 END LOOP;
4241 END;
4242 $$;
4244 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
4245 ( "member"."id"%TYPE,
4246 "member"."id"%TYPE )
4247 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
4250 CREATE FUNCTION "delegation_chain"
4251 ( "member_id_p" "member"."id"%TYPE,
4252 "unit_id_p" "unit"."id"%TYPE,
4253 "area_id_p" "area"."id"%TYPE,
4254 "issue_id_p" "issue"."id"%TYPE,
4255 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4256 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4257 RETURNS SETOF "delegation_chain_row"
4258 LANGUAGE 'plpgsql' STABLE AS $$
4259 DECLARE
4260 "scope_v" "delegation_scope";
4261 "unit_id_v" "unit"."id"%TYPE;
4262 "area_id_v" "area"."id"%TYPE;
4263 "issue_row" "issue"%ROWTYPE;
4264 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
4265 "loop_member_id_v" "member"."id"%TYPE;
4266 "output_row" "delegation_chain_row";
4267 "output_rows" "delegation_chain_row"[];
4268 "simulate_v" BOOLEAN;
4269 "simulate_here_v" BOOLEAN;
4270 "delegation_row" "delegation"%ROWTYPE;
4271 "row_count" INT4;
4272 "i" INT4;
4273 "loop_v" BOOLEAN;
4274 BEGIN
4275 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
4276 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
4277 END IF;
4278 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
4279 "simulate_v" := TRUE;
4280 ELSE
4281 "simulate_v" := FALSE;
4282 END IF;
4283 IF
4284 "unit_id_p" NOTNULL AND
4285 "area_id_p" ISNULL AND
4286 "issue_id_p" ISNULL
4287 THEN
4288 "scope_v" := 'unit';
4289 "unit_id_v" := "unit_id_p";
4290 ELSIF
4291 "unit_id_p" ISNULL AND
4292 "area_id_p" NOTNULL AND
4293 "issue_id_p" ISNULL
4294 THEN
4295 "scope_v" := 'area';
4296 "area_id_v" := "area_id_p";
4297 SELECT "unit_id" INTO "unit_id_v"
4298 FROM "area" WHERE "id" = "area_id_v";
4299 ELSIF
4300 "unit_id_p" ISNULL AND
4301 "area_id_p" ISNULL AND
4302 "issue_id_p" NOTNULL
4303 THEN
4304 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
4305 IF "issue_row"."id" ISNULL THEN
4306 RETURN;
4307 END IF;
4308 IF "issue_row"."closed" NOTNULL THEN
4309 IF "simulate_v" THEN
4310 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
4311 END IF;
4312 FOR "output_row" IN
4313 SELECT * FROM
4314 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
4315 LOOP
4316 RETURN NEXT "output_row";
4317 END LOOP;
4318 RETURN;
4319 END IF;
4320 "scope_v" := 'issue';
4321 SELECT "area_id" INTO "area_id_v"
4322 FROM "issue" WHERE "id" = "issue_id_p";
4323 SELECT "unit_id" INTO "unit_id_v"
4324 FROM "area" WHERE "id" = "area_id_v";
4325 ELSE
4326 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
4327 END IF;
4328 "visited_member_ids" := '{}';
4329 "loop_member_id_v" := NULL;
4330 "output_rows" := '{}';
4331 "output_row"."index" := 0;
4332 "output_row"."member_id" := "member_id_p";
4333 "output_row"."member_valid" := TRUE;
4334 "output_row"."participation" := FALSE;
4335 "output_row"."overridden" := FALSE;
4336 "output_row"."disabled_out" := FALSE;
4337 "output_row"."scope_out" := NULL;
4338 LOOP
4339 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
4340 "loop_member_id_v" := "output_row"."member_id";
4341 ELSE
4342 "visited_member_ids" :=
4343 "visited_member_ids" || "output_row"."member_id";
4344 END IF;
4345 IF "output_row"."participation" ISNULL THEN
4346 "output_row"."overridden" := NULL;
4347 ELSIF "output_row"."participation" THEN
4348 "output_row"."overridden" := TRUE;
4349 END IF;
4350 "output_row"."scope_in" := "output_row"."scope_out";
4351 "output_row"."member_valid" := EXISTS (
4352 SELECT NULL FROM "member" JOIN "privilege"
4353 ON "privilege"."member_id" = "member"."id"
4354 AND "privilege"."unit_id" = "unit_id_v"
4355 WHERE "id" = "output_row"."member_id"
4356 AND "member"."active" AND "privilege"."voting_right"
4357 );
4358 "simulate_here_v" := (
4359 "simulate_v" AND
4360 "output_row"."member_id" = "member_id_p"
4361 );
4362 "delegation_row" := ROW(NULL);
4363 IF "output_row"."member_valid" OR "simulate_here_v" THEN
4364 IF "scope_v" = 'unit' THEN
4365 IF NOT "simulate_here_v" THEN
4366 SELECT * INTO "delegation_row" FROM "delegation"
4367 WHERE "truster_id" = "output_row"."member_id"
4368 AND "unit_id" = "unit_id_v";
4369 END IF;
4370 ELSIF "scope_v" = 'area' THEN
4371 IF "simulate_here_v" THEN
4372 IF "simulate_trustee_id_p" ISNULL THEN
4373 SELECT * INTO "delegation_row" FROM "delegation"
4374 WHERE "truster_id" = "output_row"."member_id"
4375 AND "unit_id" = "unit_id_v";
4376 END IF;
4377 ELSE
4378 SELECT * INTO "delegation_row" FROM "delegation"
4379 WHERE "truster_id" = "output_row"."member_id"
4380 AND (
4381 "unit_id" = "unit_id_v" OR
4382 "area_id" = "area_id_v"
4384 ORDER BY "scope" DESC;
4385 END IF;
4386 ELSIF "scope_v" = 'issue' THEN
4387 IF "issue_row"."fully_frozen" ISNULL THEN
4388 "output_row"."participation" := EXISTS (
4389 SELECT NULL FROM "interest"
4390 WHERE "issue_id" = "issue_id_p"
4391 AND "member_id" = "output_row"."member_id"
4392 );
4393 ELSE
4394 IF "output_row"."member_id" = "member_id_p" THEN
4395 "output_row"."participation" := EXISTS (
4396 SELECT NULL FROM "direct_voter"
4397 WHERE "issue_id" = "issue_id_p"
4398 AND "member_id" = "output_row"."member_id"
4399 );
4400 ELSE
4401 "output_row"."participation" := NULL;
4402 END IF;
4403 END IF;
4404 IF "simulate_here_v" THEN
4405 IF "simulate_trustee_id_p" ISNULL THEN
4406 SELECT * INTO "delegation_row" FROM "delegation"
4407 WHERE "truster_id" = "output_row"."member_id"
4408 AND (
4409 "unit_id" = "unit_id_v" OR
4410 "area_id" = "area_id_v"
4412 ORDER BY "scope" DESC;
4413 END IF;
4414 ELSE
4415 SELECT * INTO "delegation_row" FROM "delegation"
4416 WHERE "truster_id" = "output_row"."member_id"
4417 AND (
4418 "unit_id" = "unit_id_v" OR
4419 "area_id" = "area_id_v" OR
4420 "issue_id" = "issue_id_p"
4422 ORDER BY "scope" DESC;
4423 END IF;
4424 END IF;
4425 ELSE
4426 "output_row"."participation" := FALSE;
4427 END IF;
4428 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
4429 "output_row"."scope_out" := "scope_v";
4430 "output_rows" := "output_rows" || "output_row";
4431 "output_row"."member_id" := "simulate_trustee_id_p";
4432 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
4433 "output_row"."scope_out" := "delegation_row"."scope";
4434 "output_rows" := "output_rows" || "output_row";
4435 "output_row"."member_id" := "delegation_row"."trustee_id";
4436 ELSIF "delegation_row"."scope" NOTNULL THEN
4437 "output_row"."scope_out" := "delegation_row"."scope";
4438 "output_row"."disabled_out" := TRUE;
4439 "output_rows" := "output_rows" || "output_row";
4440 EXIT;
4441 ELSE
4442 "output_row"."scope_out" := NULL;
4443 "output_rows" := "output_rows" || "output_row";
4444 EXIT;
4445 END IF;
4446 EXIT WHEN "loop_member_id_v" NOTNULL;
4447 "output_row"."index" := "output_row"."index" + 1;
4448 END LOOP;
4449 "row_count" := array_upper("output_rows", 1);
4450 "i" := 1;
4451 "loop_v" := FALSE;
4452 LOOP
4453 "output_row" := "output_rows"["i"];
4454 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
4455 IF "loop_v" THEN
4456 IF "i" + 1 = "row_count" THEN
4457 "output_row"."loop" := 'last';
4458 ELSIF "i" = "row_count" THEN
4459 "output_row"."loop" := 'repetition';
4460 ELSE
4461 "output_row"."loop" := 'intermediate';
4462 END IF;
4463 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
4464 "output_row"."loop" := 'first';
4465 "loop_v" := TRUE;
4466 END IF;
4467 IF "scope_v" = 'unit' THEN
4468 "output_row"."participation" := NULL;
4469 END IF;
4470 RETURN NEXT "output_row";
4471 "i" := "i" + 1;
4472 END LOOP;
4473 RETURN;
4474 END;
4475 $$;
4477 COMMENT ON FUNCTION "delegation_chain"
4478 ( "member"."id"%TYPE,
4479 "unit"."id"%TYPE,
4480 "area"."id"%TYPE,
4481 "issue"."id"%TYPE,
4482 "member"."id"%TYPE,
4483 BOOLEAN )
4484 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
4488 ---------------------------------------------------------
4489 -- Single row returning function for delegation chains --
4490 ---------------------------------------------------------
4493 CREATE TYPE "delegation_info_loop_type" AS ENUM
4494 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
4496 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''';
4499 CREATE TYPE "delegation_info_type" AS (
4500 "own_participation" BOOLEAN,
4501 "own_delegation_scope" "delegation_scope",
4502 "first_trustee_id" INT4,
4503 "first_trustee_participation" BOOLEAN,
4504 "first_trustee_ellipsis" BOOLEAN,
4505 "other_trustee_id" INT4,
4506 "other_trustee_participation" BOOLEAN,
4507 "other_trustee_ellipsis" BOOLEAN,
4508 "delegation_loop" "delegation_info_loop_type",
4509 "participating_member_id" INT4 );
4511 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';
4513 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
4514 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
4515 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
4516 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
4517 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
4518 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
4519 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)';
4520 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
4521 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';
4522 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
4525 CREATE FUNCTION "delegation_info"
4526 ( "member_id_p" "member"."id"%TYPE,
4527 "unit_id_p" "unit"."id"%TYPE,
4528 "area_id_p" "area"."id"%TYPE,
4529 "issue_id_p" "issue"."id"%TYPE,
4530 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4531 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4532 RETURNS "delegation_info_type"
4533 LANGUAGE 'plpgsql' STABLE AS $$
4534 DECLARE
4535 "current_row" "delegation_chain_row";
4536 "result" "delegation_info_type";
4537 BEGIN
4538 "result"."own_participation" := FALSE;
4539 FOR "current_row" IN
4540 SELECT * FROM "delegation_chain"(
4541 "member_id_p",
4542 "unit_id_p", "area_id_p", "issue_id_p",
4543 "simulate_trustee_id_p", "simulate_default_p")
4544 LOOP
4545 IF
4546 "result"."participating_member_id" ISNULL AND
4547 "current_row"."participation"
4548 THEN
4549 "result"."participating_member_id" := "current_row"."member_id";
4550 END IF;
4551 IF "current_row"."member_id" = "member_id_p" THEN
4552 "result"."own_participation" := "current_row"."participation";
4553 "result"."own_delegation_scope" := "current_row"."scope_out";
4554 IF "current_row"."loop" = 'first' THEN
4555 "result"."delegation_loop" := 'own';
4556 END IF;
4557 ELSIF
4558 "current_row"."member_valid" AND
4559 ( "current_row"."loop" ISNULL OR
4560 "current_row"."loop" != 'repetition' )
4561 THEN
4562 IF "result"."first_trustee_id" ISNULL THEN
4563 "result"."first_trustee_id" := "current_row"."member_id";
4564 "result"."first_trustee_participation" := "current_row"."participation";
4565 "result"."first_trustee_ellipsis" := FALSE;
4566 IF "current_row"."loop" = 'first' THEN
4567 "result"."delegation_loop" := 'first';
4568 END IF;
4569 ELSIF "result"."other_trustee_id" ISNULL THEN
4570 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
4571 "result"."other_trustee_id" := "current_row"."member_id";
4572 "result"."other_trustee_participation" := TRUE;
4573 "result"."other_trustee_ellipsis" := FALSE;
4574 IF "current_row"."loop" = 'first' THEN
4575 "result"."delegation_loop" := 'other';
4576 END IF;
4577 ELSE
4578 "result"."first_trustee_ellipsis" := TRUE;
4579 IF "current_row"."loop" = 'first' THEN
4580 "result"."delegation_loop" := 'first_ellipsis';
4581 END IF;
4582 END IF;
4583 ELSE
4584 "result"."other_trustee_ellipsis" := TRUE;
4585 IF "current_row"."loop" = 'first' THEN
4586 "result"."delegation_loop" := 'other_ellipsis';
4587 END IF;
4588 END IF;
4589 END IF;
4590 END LOOP;
4591 RETURN "result";
4592 END;
4593 $$;
4595 COMMENT ON FUNCTION "delegation_info"
4596 ( "member"."id"%TYPE,
4597 "unit"."id"%TYPE,
4598 "area"."id"%TYPE,
4599 "issue"."id"%TYPE,
4600 "member"."id"%TYPE,
4601 BOOLEAN )
4602 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
4606 ------------------------
4607 -- Geospatial lookups --
4608 ------------------------
4610 /*
4611 CREATE FUNCTION "closed_initiatives_in_bounding_box"
4612 ( "bounding_box_p" EBOX,
4613 "limit_p" INT4 )
4614 RETURNS SETOF "initiative"
4615 LANGUAGE 'plpgsql' STABLE AS $$
4616 DECLARE
4617 "limit_v" INT4;
4618 "count_v" INT4;
4619 BEGIN
4620 "limit_v" := "limit_p" + 1;
4621 LOOP
4622 SELECT count(1) INTO "count_v"
4623 FROM "initiative"
4624 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4625 WHERE "issue"."closed" NOTNULL
4626 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4627 LIMIT "limit_v";
4628 IF "count_v" < "limit_v" THEN
4629 RETURN QUERY SELECT "initiative".*
4630 FROM (
4631 SELECT
4632 "initiative"."id" AS "initiative_id",
4633 "issue"."closed"
4634 FROM "initiative"
4635 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4636 WHERE "issue"."closed" NOTNULL
4637 AND GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4638 ) AS "subquery"
4639 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4640 ORDER BY "subquery"."closed" DESC
4641 LIMIT "limit_p";
4642 RETURN;
4643 END IF;
4644 SELECT count(1) INTO "count_v"
4645 FROM (
4646 SELECT "initiative"."id" AS "initiative_id"
4647 FROM "initiative"
4648 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4649 WHERE "issue"."closed" NOTNULL
4650 ORDER BY "closed" DESC
4651 LIMIT "limit_v"
4652 ) AS "subquery"
4653 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4654 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4655 LIMIT "limit_p";
4656 IF "count_v" >= "limit_p" THEN
4657 RETURN QUERY SELECT "initiative".*
4658 FROM (
4659 SELECT
4660 "initiative"."id" AS "initiative_id",
4661 "issue"."closed"
4662 FROM "initiative"
4663 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
4664 WHERE "issue"."closed" NOTNULL
4665 ORDER BY "closed" DESC
4666 LIMIT "limit_v"
4667 ) AS "subquery"
4668 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id"
4669 WHERE GeoJSON_to_ecluster("initiative"."location") && "bounding_box_p"
4670 ORDER BY "subquery"."closed" DESC
4671 LIMIT "limit_p";
4672 RETURN;
4673 END IF;
4674 "limit_v" := "limit_v" * 2;
4675 END LOOP;
4676 END;
4677 $$;
4679 COMMENT ON FUNCTION "closed_initiatives_in_bounding_box"
4680 ( EBOX, INT4 )
4681 IS 'TODO';
4682 */
4686 ---------------------------
4687 -- Transaction isolation --
4688 ---------------------------
4691 CREATE FUNCTION "require_transaction_isolation"()
4692 RETURNS VOID
4693 LANGUAGE 'plpgsql' VOLATILE AS $$
4694 BEGIN
4695 IF
4696 current_setting('transaction_isolation') NOT IN
4697 ('repeatable read', 'serializable')
4698 THEN
4699 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
4700 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
4701 END IF;
4702 RETURN;
4703 END;
4704 $$;
4706 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
4709 CREATE FUNCTION "dont_require_transaction_isolation"()
4710 RETURNS VOID
4711 LANGUAGE 'plpgsql' VOLATILE AS $$
4712 BEGIN
4713 IF
4714 current_setting('transaction_isolation') IN
4715 ('repeatable read', 'serializable')
4716 THEN
4717 RAISE WARNING 'Unneccessary transaction isolation level: %',
4718 current_setting('transaction_isolation');
4719 END IF;
4720 RETURN;
4721 END;
4722 $$;
4724 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
4728 -------------------------
4729 -- Notification system --
4730 -------------------------
4732 CREATE FUNCTION "get_initiatives_for_notification"
4733 ( "recipient_id_p" "member"."id"%TYPE )
4734 RETURNS SETOF "initiative_for_notification"
4735 LANGUAGE 'plpgsql' VOLATILE AS $$
4736 DECLARE
4737 "result_row" "initiative_for_notification"%ROWTYPE;
4738 "last_draft_id_v" "draft"."id"%TYPE;
4739 "last_suggestion_id_v" "suggestion"."id"%TYPE;
4740 BEGIN
4741 PERFORM "require_transaction_isolation"();
4742 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
4743 FOR "result_row" IN
4744 SELECT * FROM "initiative_for_notification"
4745 WHERE "recipient_id" = "recipient_id_p"
4746 LOOP
4747 SELECT "id" INTO "last_draft_id_v" FROM "draft"
4748 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
4749 ORDER BY "id" DESC LIMIT 1;
4750 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
4751 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
4752 ORDER BY "id" DESC LIMIT 1;
4753 INSERT INTO "notification_initiative_sent"
4754 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
4755 VALUES (
4756 "recipient_id_p",
4757 "result_row"."initiative_id",
4758 "last_draft_id_v",
4759 "last_suggestion_id_v" )
4760 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
4761 "last_draft_id" = "last_draft_id_v",
4762 "last_suggestion_id" = "last_suggestion_id_v";
4763 RETURN NEXT "result_row";
4764 END LOOP;
4765 DELETE FROM "notification_initiative_sent"
4766 USING "initiative", "issue"
4767 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
4768 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
4769 AND "issue"."id" = "initiative"."issue_id"
4770 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
4771 UPDATE "member" SET
4772 "notification_counter" = "notification_counter" + 1,
4773 "notification_sent" = now()
4774 WHERE "id" = "recipient_id_p";
4775 RETURN;
4776 END;
4777 $$;
4779 COMMENT ON FUNCTION "get_initiatives_for_notification"
4780 ( "member"."id"%TYPE )
4781 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';
4785 ------------------------------------------------------------------------
4786 -- Regular tasks, except calculcation of snapshots and voting results --
4787 ------------------------------------------------------------------------
4790 CREATE FUNCTION "check_activity"()
4791 RETURNS VOID
4792 LANGUAGE 'plpgsql' VOLATILE AS $$
4793 DECLARE
4794 "system_setting_row" "system_setting"%ROWTYPE;
4795 BEGIN
4796 PERFORM "dont_require_transaction_isolation"();
4797 SELECT * INTO "system_setting_row" FROM "system_setting";
4798 IF "system_setting_row"."member_ttl" NOTNULL THEN
4799 UPDATE "member" SET "active" = FALSE
4800 WHERE "active" = TRUE
4801 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
4802 END IF;
4803 RETURN;
4804 END;
4805 $$;
4807 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
4810 CREATE FUNCTION "calculate_member_counts"()
4811 RETURNS VOID
4812 LANGUAGE 'plpgsql' VOLATILE AS $$
4813 BEGIN
4814 PERFORM "require_transaction_isolation"();
4815 DELETE FROM "member_count";
4816 INSERT INTO "member_count" ("total_count")
4817 SELECT "total_count" FROM "member_count_view";
4818 UPDATE "unit" SET "member_count" = "view"."member_count"
4819 FROM "unit_member_count" AS "view"
4820 WHERE "view"."unit_id" = "unit"."id";
4821 RETURN;
4822 END;
4823 $$;
4825 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"';
4829 ------------------------------------
4830 -- Calculation of harmonic weight --
4831 ------------------------------------
4834 CREATE VIEW "remaining_harmonic_supporter_weight" AS
4835 SELECT
4836 "direct_interest_snapshot"."snapshot_id",
4837 "direct_interest_snapshot"."issue_id",
4838 "direct_interest_snapshot"."member_id",
4839 "direct_interest_snapshot"."weight" AS "weight_num",
4840 count("initiative"."id") AS "weight_den"
4841 FROM "issue"
4842 JOIN "direct_interest_snapshot"
4843 ON "issue"."latest_snapshot_id" = "direct_interest_snapshot"."snapshot_id"
4844 AND "issue"."id" = "direct_interest_snapshot"."issue_id"
4845 JOIN "initiative"
4846 ON "issue"."id" = "initiative"."issue_id"
4847 AND "initiative"."harmonic_weight" ISNULL
4848 JOIN "direct_supporter_snapshot"
4849 ON "issue"."latest_snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
4850 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
4851 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
4852 AND (
4853 "direct_supporter_snapshot"."satisfied" = TRUE OR
4854 coalesce("initiative"."admitted", FALSE) = FALSE
4856 GROUP BY
4857 "direct_interest_snapshot"."snapshot_id",
4858 "direct_interest_snapshot"."issue_id",
4859 "direct_interest_snapshot"."member_id",
4860 "direct_interest_snapshot"."weight";
4862 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
4865 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
4866 SELECT
4867 "initiative"."issue_id",
4868 "initiative"."id" AS "initiative_id",
4869 "initiative"."admitted",
4870 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
4871 "remaining_harmonic_supporter_weight"."weight_den"
4872 FROM "remaining_harmonic_supporter_weight"
4873 JOIN "initiative"
4874 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
4875 AND "initiative"."harmonic_weight" ISNULL
4876 JOIN "direct_supporter_snapshot"
4877 ON "remaining_harmonic_supporter_weight"."snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
4878 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
4879 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
4880 AND (
4881 "direct_supporter_snapshot"."satisfied" = TRUE OR
4882 coalesce("initiative"."admitted", FALSE) = FALSE
4884 GROUP BY
4885 "initiative"."issue_id",
4886 "initiative"."id",
4887 "initiative"."admitted",
4888 "remaining_harmonic_supporter_weight"."weight_den";
4890 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
4893 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
4894 SELECT
4895 "issue_id",
4896 "id" AS "initiative_id",
4897 "admitted",
4898 0 AS "weight_num",
4899 1 AS "weight_den"
4900 FROM "initiative"
4901 WHERE "harmonic_weight" ISNULL;
4903 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';
4906 CREATE FUNCTION "set_harmonic_initiative_weights"
4907 ( "issue_id_p" "issue"."id"%TYPE )
4908 RETURNS VOID
4909 LANGUAGE 'plpgsql' VOLATILE AS $$
4910 DECLARE
4911 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
4912 "i" INT4;
4913 "count_v" INT4;
4914 "summand_v" FLOAT;
4915 "id_ary" INT4[];
4916 "weight_ary" FLOAT[];
4917 "min_weight_v" FLOAT;
4918 BEGIN
4919 PERFORM "require_transaction_isolation"();
4920 UPDATE "initiative" SET "harmonic_weight" = NULL
4921 WHERE "issue_id" = "issue_id_p";
4922 LOOP
4923 "min_weight_v" := NULL;
4924 "i" := 0;
4925 "count_v" := 0;
4926 FOR "weight_row" IN
4927 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
4928 WHERE "issue_id" = "issue_id_p"
4929 AND (
4930 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
4931 SELECT NULL FROM "initiative"
4932 WHERE "issue_id" = "issue_id_p"
4933 AND "harmonic_weight" ISNULL
4934 AND coalesce("admitted", FALSE) = FALSE
4937 UNION ALL -- needed for corner cases
4938 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
4939 WHERE "issue_id" = "issue_id_p"
4940 AND (
4941 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
4942 SELECT NULL FROM "initiative"
4943 WHERE "issue_id" = "issue_id_p"
4944 AND "harmonic_weight" ISNULL
4945 AND coalesce("admitted", FALSE) = FALSE
4948 ORDER BY "initiative_id" DESC, "weight_den" DESC
4949 -- NOTE: non-admitted initiatives placed first (at last positions),
4950 -- latest initiatives treated worse in case of tie
4951 LOOP
4952 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
4953 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
4954 "i" := "i" + 1;
4955 "count_v" := "i";
4956 "id_ary"["i"] := "weight_row"."initiative_id";
4957 "weight_ary"["i"] := "summand_v";
4958 ELSE
4959 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
4960 END IF;
4961 END LOOP;
4962 EXIT WHEN "count_v" = 0;
4963 "i" := 1;
4964 LOOP
4965 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
4966 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
4967 "min_weight_v" := "weight_ary"["i"];
4968 END IF;
4969 "i" := "i" + 1;
4970 EXIT WHEN "i" > "count_v";
4971 END LOOP;
4972 "i" := 1;
4973 LOOP
4974 IF "weight_ary"["i"] = "min_weight_v" THEN
4975 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
4976 WHERE "id" = "id_ary"["i"];
4977 EXIT;
4978 END IF;
4979 "i" := "i" + 1;
4980 END LOOP;
4981 END LOOP;
4982 UPDATE "initiative" SET "harmonic_weight" = 0
4983 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
4984 END;
4985 $$;
4987 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
4988 ( "issue"."id"%TYPE )
4989 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
4993 ------------------------------
4994 -- Calculation of snapshots --
4995 ------------------------------
4998 CREATE FUNCTION "weight_of_added_delegations_for_snapshot"
4999 ( "snapshot_id_p" "snapshot"."id"%TYPE,
5000 "issue_id_p" "issue"."id"%TYPE,
5001 "member_id_p" "member"."id"%TYPE,
5002 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
5003 RETURNS "direct_interest_snapshot"."weight"%TYPE
5004 LANGUAGE 'plpgsql' VOLATILE AS $$
5005 DECLARE
5006 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5007 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
5008 "weight_v" INT4;
5009 "sub_weight_v" INT4;
5010 BEGIN
5011 PERFORM "require_transaction_isolation"();
5012 "weight_v" := 0;
5013 FOR "issue_delegation_row" IN
5014 SELECT * FROM "issue_delegation"
5015 WHERE "trustee_id" = "member_id_p"
5016 AND "issue_id" = "issue_id_p"
5017 LOOP
5018 IF NOT EXISTS (
5019 SELECT NULL FROM "direct_interest_snapshot"
5020 WHERE "snapshot_id" = "snapshot_id_p"
5021 AND "issue_id" = "issue_id_p"
5022 AND "member_id" = "issue_delegation_row"."truster_id"
5023 ) AND NOT EXISTS (
5024 SELECT NULL FROM "delegating_interest_snapshot"
5025 WHERE "snapshot_id" = "snapshot_id_p"
5026 AND "issue_id" = "issue_id_p"
5027 AND "member_id" = "issue_delegation_row"."truster_id"
5028 ) THEN
5029 "delegate_member_ids_v" :=
5030 "member_id_p" || "delegate_member_ids_p";
5031 INSERT INTO "delegating_interest_snapshot" (
5032 "snapshot_id",
5033 "issue_id",
5034 "member_id",
5035 "scope",
5036 "delegate_member_ids"
5037 ) VALUES (
5038 "snapshot_id_p",
5039 "issue_id_p",
5040 "issue_delegation_row"."truster_id",
5041 "issue_delegation_row"."scope",
5042 "delegate_member_ids_v"
5043 );
5044 "sub_weight_v" := 1 +
5045 "weight_of_added_delegations_for_snapshot"(
5046 "snapshot_id_p",
5047 "issue_id_p",
5048 "issue_delegation_row"."truster_id",
5049 "delegate_member_ids_v"
5050 );
5051 UPDATE "delegating_interest_snapshot"
5052 SET "weight" = "sub_weight_v"
5053 WHERE "snapshot_id" = "snapshot_id_p"
5054 AND "issue_id" = "issue_id_p"
5055 AND "member_id" = "issue_delegation_row"."truster_id";
5056 "weight_v" := "weight_v" + "sub_weight_v";
5057 END IF;
5058 END LOOP;
5059 RETURN "weight_v";
5060 END;
5061 $$;
5063 COMMENT ON FUNCTION "weight_of_added_delegations_for_snapshot"
5064 ( "snapshot"."id"%TYPE,
5065 "issue"."id"%TYPE,
5066 "member"."id"%TYPE,
5067 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
5068 IS 'Helper function for "fill_snapshot" function';
5071 CREATE FUNCTION "take_snapshot"
5072 ( "issue_id_p" "issue"."id"%TYPE,
5073 "area_id_p" "area"."id"%TYPE = NULL )
5074 RETURNS "snapshot"."id"%TYPE
5075 LANGUAGE 'plpgsql' VOLATILE AS $$
5076 DECLARE
5077 "area_id_v" "area"."id"%TYPE;
5078 "unit_id_v" "unit"."id"%TYPE;
5079 "snapshot_id_v" "snapshot"."id"%TYPE;
5080 "issue_id_v" "issue"."id"%TYPE;
5081 "member_id_v" "member"."id"%TYPE;
5082 BEGIN
5083 IF "issue_id_p" NOTNULL AND "area_id_p" NOTNULL THEN
5084 RAISE EXCEPTION 'One of "issue_id_p" and "area_id_p" must be NULL';
5085 END IF;
5086 PERFORM "require_transaction_isolation"();
5087 IF "issue_id_p" ISNULL THEN
5088 "area_id_v" := "area_id_p";
5089 ELSE
5090 SELECT "area_id" INTO "area_id_v"
5091 FROM "issue" WHERE "id" = "issue_id_p";
5092 END IF;
5093 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5094 INSERT INTO "snapshot" ("area_id", "issue_id")
5095 VALUES ("area_id_v", "issue_id_p")
5096 RETURNING "id" INTO "snapshot_id_v";
5097 INSERT INTO "snapshot_population" ("snapshot_id", "member_id")
5098 SELECT "snapshot_id_v", "member_id"
5099 FROM "unit_member" WHERE "unit_id" = "unit_id_v";
5100 UPDATE "snapshot" SET
5101 "population" = (
5102 SELECT count(1) FROM "snapshot_population"
5103 WHERE "snapshot_id" = "snapshot_id_v"
5104 ) WHERE "id" = "snapshot_id_v";
5105 FOR "issue_id_v" IN
5106 SELECT "id" FROM "issue"
5107 WHERE CASE WHEN "issue_id_p" ISNULL THEN
5108 "area_id" = "area_id_p" AND
5109 "state" = 'admission'
5110 ELSE
5111 "id" = "issue_id_p"
5112 END
5113 LOOP
5114 INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id")
5115 VALUES ("snapshot_id_v", "issue_id_v");
5116 INSERT INTO "direct_interest_snapshot"
5117 ("snapshot_id", "issue_id", "member_id")
5118 SELECT
5119 "snapshot_id_v" AS "snapshot_id",
5120 "issue_id_v" AS "issue_id",
5121 "member"."id" AS "member_id"
5122 FROM "issue"
5123 JOIN "area" ON "issue"."area_id" = "area"."id"
5124 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
5125 JOIN "member" ON "interest"."member_id" = "member"."id"
5126 JOIN "privilege"
5127 ON "privilege"."unit_id" = "area"."unit_id"
5128 AND "privilege"."member_id" = "member"."id"
5129 WHERE "issue"."id" = "issue_id_v"
5130 AND "member"."active" AND "privilege"."voting_right";
5131 FOR "member_id_v" IN
5132 SELECT "member_id" FROM "direct_interest_snapshot"
5133 WHERE "snapshot_id" = "snapshot_id_v"
5134 AND "issue_id" = "issue_id_v"
5135 LOOP
5136 UPDATE "direct_interest_snapshot" SET
5137 "weight" = 1 +
5138 "weight_of_added_delegations_for_snapshot"(
5139 "snapshot_id_v",
5140 "issue_id_v",
5141 "member_id_v",
5142 '{}'
5144 WHERE "snapshot_id" = "snapshot_id_v"
5145 AND "issue_id" = "issue_id_v"
5146 AND "member_id" = "member_id_v";
5147 END LOOP;
5148 INSERT INTO "direct_supporter_snapshot"
5149 ( "snapshot_id", "issue_id", "initiative_id", "member_id",
5150 "draft_id", "informed", "satisfied" )
5151 SELECT
5152 "snapshot_id_v" AS "snapshot_id",
5153 "issue_id_v" AS "issue_id",
5154 "initiative"."id" AS "initiative_id",
5155 "supporter"."member_id" AS "member_id",
5156 "supporter"."draft_id" AS "draft_id",
5157 "supporter"."draft_id" = "current_draft"."id" AS "informed",
5158 NOT EXISTS (
5159 SELECT NULL FROM "critical_opinion"
5160 WHERE "initiative_id" = "initiative"."id"
5161 AND "member_id" = "supporter"."member_id"
5162 ) AS "satisfied"
5163 FROM "initiative"
5164 JOIN "supporter"
5165 ON "supporter"."initiative_id" = "initiative"."id"
5166 JOIN "current_draft"
5167 ON "initiative"."id" = "current_draft"."initiative_id"
5168 JOIN "direct_interest_snapshot"
5169 ON "snapshot_id_v" = "direct_interest_snapshot"."snapshot_id"
5170 AND "supporter"."member_id" = "direct_interest_snapshot"."member_id"
5171 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
5172 WHERE "initiative"."issue_id" = "issue_id_v";
5173 DELETE FROM "temporary_suggestion_counts";
5174 INSERT INTO "temporary_suggestion_counts"
5175 ( "id",
5176 "minus2_unfulfilled_count", "minus2_fulfilled_count",
5177 "minus1_unfulfilled_count", "minus1_fulfilled_count",
5178 "plus1_unfulfilled_count", "plus1_fulfilled_count",
5179 "plus2_unfulfilled_count", "plus2_fulfilled_count" )
5180 SELECT
5181 "suggestion"."id",
5182 ( SELECT coalesce(sum("di"."weight"), 0)
5183 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5184 ON "di"."snapshot_id" = "snapshot_id_v"
5185 AND "di"."issue_id" = "issue_id_v"
5186 AND "di"."member_id" = "opinion"."member_id"
5187 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5188 AND "opinion"."degree" = -2
5189 AND "opinion"."fulfilled" = FALSE
5190 ) AS "minus2_unfulfilled_count",
5191 ( SELECT coalesce(sum("di"."weight"), 0)
5192 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5193 ON "di"."snapshot_id" = "snapshot_id_v"
5194 AND "di"."issue_id" = "issue_id_v"
5195 AND "di"."member_id" = "opinion"."member_id"
5196 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5197 AND "opinion"."degree" = -2
5198 AND "opinion"."fulfilled" = TRUE
5199 ) AS "minus2_fulfilled_count",
5200 ( SELECT coalesce(sum("di"."weight"), 0)
5201 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5202 ON "di"."snapshot_id" = "snapshot_id_v"
5203 AND "di"."issue_id" = "issue_id_v"
5204 AND "di"."member_id" = "opinion"."member_id"
5205 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5206 AND "opinion"."degree" = -1
5207 AND "opinion"."fulfilled" = FALSE
5208 ) AS "minus1_unfulfilled_count",
5209 ( SELECT coalesce(sum("di"."weight"), 0)
5210 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5211 ON "di"."snapshot_id" = "snapshot_id_v"
5212 AND "di"."issue_id" = "issue_id_v"
5213 AND "di"."member_id" = "opinion"."member_id"
5214 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5215 AND "opinion"."degree" = -1
5216 AND "opinion"."fulfilled" = TRUE
5217 ) AS "minus1_fulfilled_count",
5218 ( SELECT coalesce(sum("di"."weight"), 0)
5219 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5220 ON "di"."snapshot_id" = "snapshot_id_v"
5221 AND "di"."issue_id" = "issue_id_v"
5222 AND "di"."member_id" = "opinion"."member_id"
5223 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5224 AND "opinion"."degree" = 1
5225 AND "opinion"."fulfilled" = FALSE
5226 ) AS "plus1_unfulfilled_count",
5227 ( SELECT coalesce(sum("di"."weight"), 0)
5228 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5229 ON "di"."snapshot_id" = "snapshot_id_v"
5230 AND "di"."issue_id" = "issue_id_v"
5231 AND "di"."member_id" = "opinion"."member_id"
5232 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5233 AND "opinion"."degree" = 1
5234 AND "opinion"."fulfilled" = TRUE
5235 ) AS "plus1_fulfilled_count",
5236 ( SELECT coalesce(sum("di"."weight"), 0)
5237 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5238 ON "di"."snapshot_id" = "snapshot_id_v"
5239 AND "di"."issue_id" = "issue_id_v"
5240 AND "di"."member_id" = "opinion"."member_id"
5241 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5242 AND "opinion"."degree" = 2
5243 AND "opinion"."fulfilled" = FALSE
5244 ) AS "plus2_unfulfilled_count",
5245 ( SELECT coalesce(sum("di"."weight"), 0)
5246 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5247 ON "di"."snapshot_id" = "snapshot_id_v"
5248 AND "di"."issue_id" = "issue_id_v"
5249 AND "di"."member_id" = "opinion"."member_id"
5250 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5251 AND "opinion"."degree" = 2
5252 AND "opinion"."fulfilled" = TRUE
5253 ) AS "plus2_fulfilled_count"
5254 FROM "suggestion" JOIN "initiative"
5255 ON "suggestion"."initiative_id" = "initiative"."id"
5256 WHERE "initiative"."issue_id" = "issue_id_v";
5257 END LOOP;
5258 RETURN "snapshot_id_v";
5259 END;
5260 $$;
5262 COMMENT ON FUNCTION "take_snapshot"
5263 ( "issue"."id"%TYPE,
5264 "area"."id"%TYPE )
5265 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.';
5268 CREATE FUNCTION "finish_snapshot"
5269 ( "issue_id_p" "issue"."id"%TYPE )
5270 RETURNS VOID
5271 LANGUAGE 'plpgsql' VOLATILE AS $$
5272 DECLARE
5273 "snapshot_id_v" "snapshot"."id"%TYPE;
5274 BEGIN
5275 -- NOTE: function does not require snapshot isolation but we don't call
5276 -- "dont_require_snapshot_isolation" here because this function is
5277 -- also invoked by "check_issue"
5278 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
5279 SELECT "id" INTO "snapshot_id_v" FROM "snapshot"
5280 ORDER BY "id" DESC LIMIT 1;
5281 UPDATE "issue" SET
5282 "calculated" = "snapshot"."calculated",
5283 "latest_snapshot_id" = "snapshot_id_v",
5284 "population" = "snapshot"."population",
5285 "initiative_quorum" = CASE WHEN
5286 "policy"."initiative_quorum" > ceil(
5287 ( "issue"."population"::INT8 *
5288 "policy"."initiative_quorum_num"::INT8 ) /
5289 "policy"."initiative_quorum_den"::FLOAT8
5290 )::INT4
5291 THEN
5292 "policy"."initiative_quorum"
5293 ELSE
5294 ceil(
5295 ( "issue"."population"::INT8 *
5296 "policy"."initiative_quorum_num"::INT8 ) /
5297 "policy"."initiative_quorum_den"::FLOAT8
5298 )::INT4
5299 END
5300 FROM "snapshot", "policy"
5301 WHERE "issue"."id" = "issue_id_p"
5302 AND "snapshot"."id" = "snapshot_id_v"
5303 AND "policy"."id" = "issue"."policy_id";
5304 UPDATE "initiative" SET
5305 "supporter_count" = (
5306 SELECT coalesce(sum("di"."weight"), 0)
5307 FROM "direct_interest_snapshot" AS "di"
5308 JOIN "direct_supporter_snapshot" AS "ds"
5309 ON "di"."member_id" = "ds"."member_id"
5310 WHERE "di"."snapshot_id" = "snapshot_id_v"
5311 AND "di"."issue_id" = "issue_id_p"
5312 AND "ds"."snapshot_id" = "snapshot_id_v"
5313 AND "ds"."initiative_id" = "initiative"."id"
5314 ),
5315 "informed_supporter_count" = (
5316 SELECT coalesce(sum("di"."weight"), 0)
5317 FROM "direct_interest_snapshot" AS "di"
5318 JOIN "direct_supporter_snapshot" AS "ds"
5319 ON "di"."member_id" = "ds"."member_id"
5320 WHERE "di"."snapshot_id" = "snapshot_id_v"
5321 AND "di"."issue_id" = "issue_id_p"
5322 AND "ds"."snapshot_id" = "snapshot_id_v"
5323 AND "ds"."initiative_id" = "initiative"."id"
5324 AND "ds"."informed"
5325 ),
5326 "satisfied_supporter_count" = (
5327 SELECT coalesce(sum("di"."weight"), 0)
5328 FROM "direct_interest_snapshot" AS "di"
5329 JOIN "direct_supporter_snapshot" AS "ds"
5330 ON "di"."member_id" = "ds"."member_id"
5331 WHERE "di"."snapshot_id" = "snapshot_id_v"
5332 AND "di"."issue_id" = "issue_id_p"
5333 AND "ds"."snapshot_id" = "snapshot_id_v"
5334 AND "ds"."initiative_id" = "initiative"."id"
5335 AND "ds"."satisfied"
5336 ),
5337 "satisfied_informed_supporter_count" = (
5338 SELECT coalesce(sum("di"."weight"), 0)
5339 FROM "direct_interest_snapshot" AS "di"
5340 JOIN "direct_supporter_snapshot" AS "ds"
5341 ON "di"."member_id" = "ds"."member_id"
5342 WHERE "di"."snapshot_id" = "snapshot_id_v"
5343 AND "di"."issue_id" = "issue_id_p"
5344 AND "ds"."snapshot_id" = "snapshot_id_v"
5345 AND "ds"."initiative_id" = "initiative"."id"
5346 AND "ds"."informed"
5347 AND "ds"."satisfied"
5349 WHERE "issue_id" = "issue_id_p";
5350 UPDATE "suggestion" SET
5351 "minus2_unfulfilled_count" = "temp"."minus2_unfulfilled_count",
5352 "minus2_fulfilled_count" = "temp"."minus2_fulfilled_count",
5353 "minus1_unfulfilled_count" = "temp"."minus1_unfulfilled_count",
5354 "minus1_fulfilled_count" = "temp"."minus1_fulfilled_count",
5355 "plus1_unfulfilled_count" = "temp"."plus1_unfulfilled_count",
5356 "plus1_fulfilled_count" = "temp"."plus1_fulfilled_count",
5357 "plus2_unfulfilled_count" = "temp"."plus2_unfulfilled_count",
5358 "plus2_fulfilled_count" = "temp"."plus2_fulfilled_count"
5359 FROM "temporary_suggestion_counts" AS "temp", "initiative"
5360 WHERE "temp"."id" = "suggestion"."id"
5361 AND "initiative"."issue_id" = "issue_id_p"
5362 AND "suggestion"."initiative_id" = "initiative"."id";
5363 DELETE FROM "temporary_suggestion_counts";
5364 RETURN;
5365 END;
5366 $$;
5368 COMMENT ON FUNCTION "finish_snapshot"
5369 ( "issue"."id"%TYPE )
5370 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)';
5374 -----------------------
5375 -- Counting of votes --
5376 -----------------------
5379 CREATE FUNCTION "weight_of_added_vote_delegations"
5380 ( "issue_id_p" "issue"."id"%TYPE,
5381 "member_id_p" "member"."id"%TYPE,
5382 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
5383 RETURNS "direct_voter"."weight"%TYPE
5384 LANGUAGE 'plpgsql' VOLATILE AS $$
5385 DECLARE
5386 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5387 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
5388 "weight_v" INT4;
5389 "sub_weight_v" INT4;
5390 BEGIN
5391 PERFORM "require_transaction_isolation"();
5392 "weight_v" := 0;
5393 FOR "issue_delegation_row" IN
5394 SELECT * FROM "issue_delegation"
5395 WHERE "trustee_id" = "member_id_p"
5396 AND "issue_id" = "issue_id_p"
5397 LOOP
5398 IF NOT EXISTS (
5399 SELECT NULL FROM "direct_voter"
5400 WHERE "member_id" = "issue_delegation_row"."truster_id"
5401 AND "issue_id" = "issue_id_p"
5402 ) AND NOT EXISTS (
5403 SELECT NULL FROM "delegating_voter"
5404 WHERE "member_id" = "issue_delegation_row"."truster_id"
5405 AND "issue_id" = "issue_id_p"
5406 ) THEN
5407 "delegate_member_ids_v" :=
5408 "member_id_p" || "delegate_member_ids_p";
5409 INSERT INTO "delegating_voter" (
5410 "issue_id",
5411 "member_id",
5412 "scope",
5413 "delegate_member_ids"
5414 ) VALUES (
5415 "issue_id_p",
5416 "issue_delegation_row"."truster_id",
5417 "issue_delegation_row"."scope",
5418 "delegate_member_ids_v"
5419 );
5420 "sub_weight_v" := 1 +
5421 "weight_of_added_vote_delegations"(
5422 "issue_id_p",
5423 "issue_delegation_row"."truster_id",
5424 "delegate_member_ids_v"
5425 );
5426 UPDATE "delegating_voter"
5427 SET "weight" = "sub_weight_v"
5428 WHERE "issue_id" = "issue_id_p"
5429 AND "member_id" = "issue_delegation_row"."truster_id";
5430 "weight_v" := "weight_v" + "sub_weight_v";
5431 END IF;
5432 END LOOP;
5433 RETURN "weight_v";
5434 END;
5435 $$;
5437 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
5438 ( "issue"."id"%TYPE,
5439 "member"."id"%TYPE,
5440 "delegating_voter"."delegate_member_ids"%TYPE )
5441 IS 'Helper function for "add_vote_delegations" function';
5444 CREATE FUNCTION "add_vote_delegations"
5445 ( "issue_id_p" "issue"."id"%TYPE )
5446 RETURNS VOID
5447 LANGUAGE 'plpgsql' VOLATILE AS $$
5448 DECLARE
5449 "member_id_v" "member"."id"%TYPE;
5450 BEGIN
5451 PERFORM "require_transaction_isolation"();
5452 FOR "member_id_v" IN
5453 SELECT "member_id" FROM "direct_voter"
5454 WHERE "issue_id" = "issue_id_p"
5455 LOOP
5456 UPDATE "direct_voter" SET
5457 "weight" = "weight" + "weight_of_added_vote_delegations"(
5458 "issue_id_p",
5459 "member_id_v",
5460 '{}'
5462 WHERE "member_id" = "member_id_v"
5463 AND "issue_id" = "issue_id_p";
5464 END LOOP;
5465 RETURN;
5466 END;
5467 $$;
5469 COMMENT ON FUNCTION "add_vote_delegations"
5470 ( "issue_id_p" "issue"."id"%TYPE )
5471 IS 'Helper function for "close_voting" function';
5474 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
5475 RETURNS VOID
5476 LANGUAGE 'plpgsql' VOLATILE AS $$
5477 DECLARE
5478 "area_id_v" "area"."id"%TYPE;
5479 "unit_id_v" "unit"."id"%TYPE;
5480 "member_id_v" "member"."id"%TYPE;
5481 BEGIN
5482 PERFORM "require_transaction_isolation"();
5483 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
5484 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5485 -- override protection triggers:
5486 INSERT INTO "temporary_transaction_data" ("key", "value")
5487 VALUES ('override_protection_triggers', TRUE::TEXT);
5488 -- delete timestamp of voting comment:
5489 UPDATE "direct_voter" SET "comment_changed" = NULL
5490 WHERE "issue_id" = "issue_id_p";
5491 -- delete delegating votes (in cases of manual reset of issue state):
5492 DELETE FROM "delegating_voter"
5493 WHERE "issue_id" = "issue_id_p";
5494 -- delete votes from non-privileged voters:
5495 DELETE FROM "direct_voter"
5496 USING (
5497 SELECT
5498 "direct_voter"."member_id"
5499 FROM "direct_voter"
5500 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
5501 LEFT JOIN "privilege"
5502 ON "privilege"."unit_id" = "unit_id_v"
5503 AND "privilege"."member_id" = "direct_voter"."member_id"
5504 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
5505 "member"."active" = FALSE OR
5506 "privilege"."voting_right" ISNULL OR
5507 "privilege"."voting_right" = FALSE
5509 ) AS "subquery"
5510 WHERE "direct_voter"."issue_id" = "issue_id_p"
5511 AND "direct_voter"."member_id" = "subquery"."member_id";
5512 -- consider delegations:
5513 UPDATE "direct_voter" SET "weight" = 1
5514 WHERE "issue_id" = "issue_id_p";
5515 PERFORM "add_vote_delegations"("issue_id_p");
5516 -- mark first preferences:
5517 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
5518 FROM (
5519 SELECT
5520 "vote"."initiative_id",
5521 "vote"."member_id",
5522 CASE WHEN "vote"."grade" > 0 THEN
5523 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
5524 ELSE NULL
5525 END AS "first_preference"
5526 FROM "vote"
5527 JOIN "initiative" -- NOTE: due to missing index on issue_id
5528 ON "vote"."issue_id" = "initiative"."issue_id"
5529 JOIN "vote" AS "agg"
5530 ON "initiative"."id" = "agg"."initiative_id"
5531 AND "vote"."member_id" = "agg"."member_id"
5532 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
5533 ) AS "subquery"
5534 WHERE "vote"."issue_id" = "issue_id_p"
5535 AND "vote"."initiative_id" = "subquery"."initiative_id"
5536 AND "vote"."member_id" = "subquery"."member_id";
5537 -- finish overriding protection triggers (avoids garbage):
5538 DELETE FROM "temporary_transaction_data"
5539 WHERE "key" = 'override_protection_triggers';
5540 -- materialize battle_view:
5541 -- NOTE: "closed" column of issue must be set at this point
5542 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
5543 INSERT INTO "battle" (
5544 "issue_id",
5545 "winning_initiative_id", "losing_initiative_id",
5546 "count"
5547 ) SELECT
5548 "issue_id",
5549 "winning_initiative_id", "losing_initiative_id",
5550 "count"
5551 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
5552 -- set voter count:
5553 UPDATE "issue" SET
5554 "voter_count" = (
5555 SELECT coalesce(sum("weight"), 0)
5556 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
5558 WHERE "id" = "issue_id_p";
5559 -- copy "positive_votes" and "negative_votes" from "battle" table:
5560 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
5561 UPDATE "initiative" SET
5562 "first_preference_votes" = 0,
5563 "positive_votes" = "battle_win"."count",
5564 "negative_votes" = "battle_lose"."count"
5565 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
5566 WHERE
5567 "battle_win"."issue_id" = "issue_id_p" AND
5568 "battle_win"."winning_initiative_id" = "initiative"."id" AND
5569 "battle_win"."losing_initiative_id" ISNULL AND
5570 "battle_lose"."issue_id" = "issue_id_p" AND
5571 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
5572 "battle_lose"."winning_initiative_id" ISNULL;
5573 -- calculate "first_preference_votes":
5574 -- NOTE: will only set values not equal to zero
5575 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
5576 FROM (
5577 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
5578 FROM "vote" JOIN "direct_voter"
5579 ON "vote"."issue_id" = "direct_voter"."issue_id"
5580 AND "vote"."member_id" = "direct_voter"."member_id"
5581 WHERE "vote"."first_preference"
5582 GROUP BY "vote"."initiative_id"
5583 ) AS "subquery"
5584 WHERE "initiative"."issue_id" = "issue_id_p"
5585 AND "initiative"."admitted"
5586 AND "initiative"."id" = "subquery"."initiative_id";
5587 END;
5588 $$;
5590 COMMENT ON FUNCTION "close_voting"
5591 ( "issue"."id"%TYPE )
5592 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.';
5595 CREATE FUNCTION "defeat_strength"
5596 ( "positive_votes_p" INT4,
5597 "negative_votes_p" INT4,
5598 "defeat_strength_p" "defeat_strength" )
5599 RETURNS INT8
5600 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5601 BEGIN
5602 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
5603 IF "positive_votes_p" > "negative_votes_p" THEN
5604 RETURN "positive_votes_p";
5605 ELSE
5606 RETURN 0;
5607 END IF;
5608 ELSE
5609 IF "positive_votes_p" > "negative_votes_p" THEN
5610 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
5611 ELSIF "positive_votes_p" = "negative_votes_p" THEN
5612 RETURN 0;
5613 ELSE
5614 RETURN -1;
5615 END IF;
5616 END IF;
5617 END;
5618 $$;
5620 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")';
5623 CREATE FUNCTION "secondary_link_strength"
5624 ( "initiative1_ord_p" INT4,
5625 "initiative2_ord_p" INT4,
5626 "tie_breaking_p" "tie_breaking" )
5627 RETURNS INT8
5628 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5629 BEGIN
5630 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
5631 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
5632 END IF;
5633 RETURN (
5634 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
5636 ELSE
5637 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
5638 1::INT8 << 62
5639 ELSE 0 END
5641 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
5642 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
5643 ELSE
5644 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
5645 END
5646 END
5647 );
5648 END;
5649 $$;
5651 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
5654 CREATE TYPE "link_strength" AS (
5655 "primary" INT8,
5656 "secondary" INT8 );
5658 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'')';
5661 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
5662 RETURNS "link_strength"[][]
5663 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5664 DECLARE
5665 "dimension_v" INT4;
5666 "matrix_p" "link_strength"[][];
5667 "i" INT4;
5668 "j" INT4;
5669 "k" INT4;
5670 BEGIN
5671 "dimension_v" := array_upper("matrix_d", 1);
5672 "matrix_p" := "matrix_d";
5673 "i" := 1;
5674 LOOP
5675 "j" := 1;
5676 LOOP
5677 IF "i" != "j" THEN
5678 "k" := 1;
5679 LOOP
5680 IF "i" != "k" AND "j" != "k" THEN
5681 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
5682 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
5683 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
5684 END IF;
5685 ELSE
5686 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
5687 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
5688 END IF;
5689 END IF;
5690 END IF;
5691 EXIT WHEN "k" = "dimension_v";
5692 "k" := "k" + 1;
5693 END LOOP;
5694 END IF;
5695 EXIT WHEN "j" = "dimension_v";
5696 "j" := "j" + 1;
5697 END LOOP;
5698 EXIT WHEN "i" = "dimension_v";
5699 "i" := "i" + 1;
5700 END LOOP;
5701 RETURN "matrix_p";
5702 END;
5703 $$;
5705 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
5708 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
5709 RETURNS VOID
5710 LANGUAGE 'plpgsql' VOLATILE AS $$
5711 DECLARE
5712 "issue_row" "issue"%ROWTYPE;
5713 "policy_row" "policy"%ROWTYPE;
5714 "dimension_v" INT4;
5715 "matrix_a" INT4[][]; -- absolute votes
5716 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
5717 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
5718 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
5719 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
5720 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
5721 "i" INT4;
5722 "j" INT4;
5723 "m" INT4;
5724 "n" INT4;
5725 "battle_row" "battle"%ROWTYPE;
5726 "rank_ary" INT4[];
5727 "rank_v" INT4;
5728 "initiative_id_v" "initiative"."id"%TYPE;
5729 BEGIN
5730 PERFORM "require_transaction_isolation"();
5731 SELECT * INTO "issue_row"
5732 FROM "issue" WHERE "id" = "issue_id_p";
5733 SELECT * INTO "policy_row"
5734 FROM "policy" WHERE "id" = "issue_row"."policy_id";
5735 SELECT count(1) INTO "dimension_v"
5736 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
5737 -- create "matrix_a" with absolute number of votes in pairwise
5738 -- comparison:
5739 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
5740 "i" := 1;
5741 "j" := 2;
5742 FOR "battle_row" IN
5743 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
5744 ORDER BY
5745 "winning_initiative_id" NULLS FIRST,
5746 "losing_initiative_id" NULLS FIRST
5747 LOOP
5748 "matrix_a"["i"]["j"] := "battle_row"."count";
5749 IF "j" = "dimension_v" THEN
5750 "i" := "i" + 1;
5751 "j" := 1;
5752 ELSE
5753 "j" := "j" + 1;
5754 IF "j" = "i" THEN
5755 "j" := "j" + 1;
5756 END IF;
5757 END IF;
5758 END LOOP;
5759 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
5760 RAISE EXCEPTION 'Wrong battle count (should not happen)';
5761 END IF;
5762 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
5763 -- and "secondary_link_strength" functions:
5764 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
5765 "i" := 1;
5766 LOOP
5767 "j" := 1;
5768 LOOP
5769 IF "i" != "j" THEN
5770 "matrix_d"["i"]["j"] := (
5771 "defeat_strength"(
5772 "matrix_a"["i"]["j"],
5773 "matrix_a"["j"]["i"],
5774 "policy_row"."defeat_strength"
5775 ),
5776 "secondary_link_strength"(
5777 "i",
5778 "j",
5779 "policy_row"."tie_breaking"
5781 )::"link_strength";
5782 END IF;
5783 EXIT WHEN "j" = "dimension_v";
5784 "j" := "j" + 1;
5785 END LOOP;
5786 EXIT WHEN "i" = "dimension_v";
5787 "i" := "i" + 1;
5788 END LOOP;
5789 -- find best paths:
5790 "matrix_p" := "find_best_paths"("matrix_d");
5791 -- create partial order:
5792 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
5793 "i" := 1;
5794 LOOP
5795 "j" := "i" + 1;
5796 LOOP
5797 IF "i" != "j" THEN
5798 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
5799 "matrix_b"["i"]["j"] := TRUE;
5800 "matrix_b"["j"]["i"] := FALSE;
5801 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
5802 "matrix_b"["i"]["j"] := FALSE;
5803 "matrix_b"["j"]["i"] := TRUE;
5804 END IF;
5805 END IF;
5806 EXIT WHEN "j" = "dimension_v";
5807 "j" := "j" + 1;
5808 END LOOP;
5809 EXIT WHEN "i" = "dimension_v" - 1;
5810 "i" := "i" + 1;
5811 END LOOP;
5812 -- tie-breaking by forbidding shared weakest links in beat-paths
5813 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
5814 -- is performed later by initiative id):
5815 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
5816 "m" := 1;
5817 LOOP
5818 "n" := "m" + 1;
5819 LOOP
5820 -- only process those candidates m and n, which are tied:
5821 IF "matrix_b"["m"]["n"] ISNULL THEN
5822 -- start with beat-paths prior tie-breaking:
5823 "matrix_t" := "matrix_p";
5824 -- start with all links allowed:
5825 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
5826 LOOP
5827 -- determine (and forbid) that link that is the weakest link
5828 -- in both the best path from candidate m to candidate n and
5829 -- from candidate n to candidate m:
5830 "i" := 1;
5831 <<forbid_one_link>>
5832 LOOP
5833 "j" := 1;
5834 LOOP
5835 IF "i" != "j" THEN
5836 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
5837 "matrix_f"["i"]["j"] := TRUE;
5838 -- exit for performance reasons,
5839 -- as exactly one link will be found:
5840 EXIT forbid_one_link;
5841 END IF;
5842 END IF;
5843 EXIT WHEN "j" = "dimension_v";
5844 "j" := "j" + 1;
5845 END LOOP;
5846 IF "i" = "dimension_v" THEN
5847 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
5848 END IF;
5849 "i" := "i" + 1;
5850 END LOOP;
5851 -- calculate best beat-paths while ignoring forbidden links:
5852 "i" := 1;
5853 LOOP
5854 "j" := 1;
5855 LOOP
5856 IF "i" != "j" THEN
5857 "matrix_t"["i"]["j"] := CASE
5858 WHEN "matrix_f"["i"]["j"]
5859 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
5860 ELSE "matrix_d"["i"]["j"] END;
5861 END IF;
5862 EXIT WHEN "j" = "dimension_v";
5863 "j" := "j" + 1;
5864 END LOOP;
5865 EXIT WHEN "i" = "dimension_v";
5866 "i" := "i" + 1;
5867 END LOOP;
5868 "matrix_t" := "find_best_paths"("matrix_t");
5869 -- extend partial order, if tie-breaking was successful:
5870 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
5871 "matrix_b"["m"]["n"] := TRUE;
5872 "matrix_b"["n"]["m"] := FALSE;
5873 EXIT;
5874 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
5875 "matrix_b"["m"]["n"] := FALSE;
5876 "matrix_b"["n"]["m"] := TRUE;
5877 EXIT;
5878 END IF;
5879 END LOOP;
5880 END IF;
5881 EXIT WHEN "n" = "dimension_v";
5882 "n" := "n" + 1;
5883 END LOOP;
5884 EXIT WHEN "m" = "dimension_v" - 1;
5885 "m" := "m" + 1;
5886 END LOOP;
5887 END IF;
5888 -- store a unique ranking in "rank_ary":
5889 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
5890 "rank_v" := 1;
5891 LOOP
5892 "i" := 1;
5893 <<assign_next_rank>>
5894 LOOP
5895 IF "rank_ary"["i"] ISNULL THEN
5896 "j" := 1;
5897 LOOP
5898 IF
5899 "i" != "j" AND
5900 "rank_ary"["j"] ISNULL AND
5901 ( "matrix_b"["j"]["i"] OR
5902 -- tie-breaking by "id"
5903 ( "matrix_b"["j"]["i"] ISNULL AND
5904 "j" < "i" ) )
5905 THEN
5906 -- someone else is better
5907 EXIT;
5908 END IF;
5909 IF "j" = "dimension_v" THEN
5910 -- noone is better
5911 "rank_ary"["i"] := "rank_v";
5912 EXIT assign_next_rank;
5913 END IF;
5914 "j" := "j" + 1;
5915 END LOOP;
5916 END IF;
5917 "i" := "i" + 1;
5918 IF "i" > "dimension_v" THEN
5919 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
5920 END IF;
5921 END LOOP;
5922 EXIT WHEN "rank_v" = "dimension_v";
5923 "rank_v" := "rank_v" + 1;
5924 END LOOP;
5925 -- write preliminary results:
5926 "i" := 2; -- omit status quo with "i" = 1
5927 FOR "initiative_id_v" IN
5928 SELECT "id" FROM "initiative"
5929 WHERE "issue_id" = "issue_id_p" AND "admitted"
5930 ORDER BY "id"
5931 LOOP
5932 UPDATE "initiative" SET
5933 "direct_majority" =
5934 CASE WHEN "policy_row"."direct_majority_strict" THEN
5935 "positive_votes" * "policy_row"."direct_majority_den" >
5936 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
5937 ELSE
5938 "positive_votes" * "policy_row"."direct_majority_den" >=
5939 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
5940 END
5941 AND "positive_votes" >= "policy_row"."direct_majority_positive"
5942 AND "issue_row"."voter_count"-"negative_votes" >=
5943 "policy_row"."direct_majority_non_negative",
5944 "indirect_majority" =
5945 CASE WHEN "policy_row"."indirect_majority_strict" THEN
5946 "positive_votes" * "policy_row"."indirect_majority_den" >
5947 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
5948 ELSE
5949 "positive_votes" * "policy_row"."indirect_majority_den" >=
5950 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
5951 END
5952 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
5953 AND "issue_row"."voter_count"-"negative_votes" >=
5954 "policy_row"."indirect_majority_non_negative",
5955 "schulze_rank" = "rank_ary"["i"],
5956 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
5957 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
5958 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
5959 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
5960 THEN NULL
5961 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
5962 "eligible" = FALSE,
5963 "winner" = FALSE,
5964 "rank" = NULL -- NOTE: in cases of manual reset of issue state
5965 WHERE "id" = "initiative_id_v";
5966 "i" := "i" + 1;
5967 END LOOP;
5968 IF "i" != "dimension_v" + 1 THEN
5969 RAISE EXCEPTION 'Wrong winner count (should not happen)';
5970 END IF;
5971 -- take indirect majorities into account:
5972 LOOP
5973 UPDATE "initiative" SET "indirect_majority" = TRUE
5974 FROM (
5975 SELECT "new_initiative"."id" AS "initiative_id"
5976 FROM "initiative" "old_initiative"
5977 JOIN "initiative" "new_initiative"
5978 ON "new_initiative"."issue_id" = "issue_id_p"
5979 AND "new_initiative"."indirect_majority" = FALSE
5980 JOIN "battle" "battle_win"
5981 ON "battle_win"."issue_id" = "issue_id_p"
5982 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
5983 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
5984 JOIN "battle" "battle_lose"
5985 ON "battle_lose"."issue_id" = "issue_id_p"
5986 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
5987 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
5988 WHERE "old_initiative"."issue_id" = "issue_id_p"
5989 AND "old_initiative"."indirect_majority" = TRUE
5990 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
5991 "battle_win"."count" * "policy_row"."indirect_majority_den" >
5992 "policy_row"."indirect_majority_num" *
5993 ("battle_win"."count"+"battle_lose"."count")
5994 ELSE
5995 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
5996 "policy_row"."indirect_majority_num" *
5997 ("battle_win"."count"+"battle_lose"."count")
5998 END
5999 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
6000 AND "issue_row"."voter_count"-"battle_lose"."count" >=
6001 "policy_row"."indirect_majority_non_negative"
6002 ) AS "subquery"
6003 WHERE "id" = "subquery"."initiative_id";
6004 EXIT WHEN NOT FOUND;
6005 END LOOP;
6006 -- set "multistage_majority" for remaining matching initiatives:
6007 UPDATE "initiative" SET "multistage_majority" = TRUE
6008 FROM (
6009 SELECT "losing_initiative"."id" AS "initiative_id"
6010 FROM "initiative" "losing_initiative"
6011 JOIN "initiative" "winning_initiative"
6012 ON "winning_initiative"."issue_id" = "issue_id_p"
6013 AND "winning_initiative"."admitted"
6014 JOIN "battle" "battle_win"
6015 ON "battle_win"."issue_id" = "issue_id_p"
6016 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
6017 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
6018 JOIN "battle" "battle_lose"
6019 ON "battle_lose"."issue_id" = "issue_id_p"
6020 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
6021 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
6022 WHERE "losing_initiative"."issue_id" = "issue_id_p"
6023 AND "losing_initiative"."admitted"
6024 AND "winning_initiative"."schulze_rank" <
6025 "losing_initiative"."schulze_rank"
6026 AND "battle_win"."count" > "battle_lose"."count"
6027 AND (
6028 "battle_win"."count" > "winning_initiative"."positive_votes" OR
6029 "battle_lose"."count" < "losing_initiative"."negative_votes" )
6030 ) AS "subquery"
6031 WHERE "id" = "subquery"."initiative_id";
6032 -- mark eligible initiatives:
6033 UPDATE "initiative" SET "eligible" = TRUE
6034 WHERE "issue_id" = "issue_id_p"
6035 AND "initiative"."direct_majority"
6036 AND "initiative"."indirect_majority"
6037 AND "initiative"."better_than_status_quo"
6038 AND (
6039 "policy_row"."no_multistage_majority" = FALSE OR
6040 "initiative"."multistage_majority" = FALSE )
6041 AND (
6042 "policy_row"."no_reverse_beat_path" = FALSE OR
6043 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
6044 -- mark final winner:
6045 UPDATE "initiative" SET "winner" = TRUE
6046 FROM (
6047 SELECT "id" AS "initiative_id"
6048 FROM "initiative"
6049 WHERE "issue_id" = "issue_id_p" AND "eligible"
6050 ORDER BY
6051 "schulze_rank",
6052 "id"
6053 LIMIT 1
6054 ) AS "subquery"
6055 WHERE "id" = "subquery"."initiative_id";
6056 -- write (final) ranks:
6057 "rank_v" := 1;
6058 FOR "initiative_id_v" IN
6059 SELECT "id"
6060 FROM "initiative"
6061 WHERE "issue_id" = "issue_id_p" AND "admitted"
6062 ORDER BY
6063 "winner" DESC,
6064 "eligible" DESC,
6065 "schulze_rank",
6066 "id"
6067 LOOP
6068 UPDATE "initiative" SET "rank" = "rank_v"
6069 WHERE "id" = "initiative_id_v";
6070 "rank_v" := "rank_v" + 1;
6071 END LOOP;
6072 -- set schulze rank of status quo and mark issue as finished:
6073 UPDATE "issue" SET
6074 "status_quo_schulze_rank" = "rank_ary"[1],
6075 "state" =
6076 CASE WHEN EXISTS (
6077 SELECT NULL FROM "initiative"
6078 WHERE "issue_id" = "issue_id_p" AND "winner"
6079 ) THEN
6080 'finished_with_winner'::"issue_state"
6081 ELSE
6082 'finished_without_winner'::"issue_state"
6083 END,
6084 "closed" = "phase_finished",
6085 "phase_finished" = NULL
6086 WHERE "id" = "issue_id_p";
6087 RETURN;
6088 END;
6089 $$;
6091 COMMENT ON FUNCTION "calculate_ranks"
6092 ( "issue"."id"%TYPE )
6093 IS 'Determine ranking (Votes have to be counted first)';
6097 -----------------------------
6098 -- Automatic state changes --
6099 -----------------------------
6102 CREATE FUNCTION "issue_admission"
6103 ( "area_id_p" "area"."id"%TYPE )
6104 RETURNS BOOLEAN
6105 LANGUAGE 'plpgsql' VOLATILE AS $$
6106 DECLARE
6107 "issue_id_v" "issue"."id"%TYPE;
6108 BEGIN
6109 PERFORM "dont_require_transaction_isolation"();
6110 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
6111 UPDATE "area" SET "issue_quorum" = "view"."issue_quorum"
6112 FROM "area_quorum" AS "view"
6113 WHERE "area"."id" = "view"."area_id"
6114 AND "area"."id" = "area_id_p";
6115 SELECT "id" INTO "issue_id_v" FROM "issue_for_admission"
6116 WHERE "area_id" = "area_id_p";
6117 IF "issue_id_v" ISNULL THEN RETURN FALSE; END IF;
6118 UPDATE "issue" SET
6119 "admission_snapshot_id" = "latest_snapshot_id",
6120 "state" = 'discussion',
6121 "accepted" = now(),
6122 "phase_finished" = NULL,
6123 "issue_quorum" = "issue_quorum"."issue_quorum"
6124 FROM "issue_quorum"
6125 WHERE "id" = "issue_id_v"
6126 AND "issue_quorum"."issue_id" = "issue_id_v";
6127 RETURN TRUE;
6128 END;
6129 $$;
6131 COMMENT ON FUNCTION "issue_admission"
6132 ( "area"."id"%TYPE )
6133 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';
6136 CREATE TYPE "check_issue_persistence" AS (
6137 "state" "issue_state",
6138 "phase_finished" BOOLEAN,
6139 "issue_revoked" BOOLEAN,
6140 "snapshot_created" BOOLEAN,
6141 "harmonic_weights_set" BOOLEAN,
6142 "closed_voting" BOOLEAN );
6144 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';
6147 CREATE FUNCTION "check_issue"
6148 ( "issue_id_p" "issue"."id"%TYPE,
6149 "persist" "check_issue_persistence" )
6150 RETURNS "check_issue_persistence"
6151 LANGUAGE 'plpgsql' VOLATILE AS $$
6152 DECLARE
6153 "issue_row" "issue"%ROWTYPE;
6154 "last_calculated_v" "snapshot"."calculated"%TYPE;
6155 "policy_row" "policy"%ROWTYPE;
6156 "initiative_row" "initiative"%ROWTYPE;
6157 "state_v" "issue_state";
6158 BEGIN
6159 PERFORM "require_transaction_isolation"();
6160 IF "persist" ISNULL THEN
6161 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6162 FOR UPDATE;
6163 SELECT "calculated" INTO "last_calculated_v"
6164 FROM "snapshot" JOIN "snapshot_issue"
6165 ON "snapshot"."id" = "snapshot_issue"."snapshot_id"
6166 WHERE "snapshot_issue"."issue_id" = "issue_id_p";
6167 IF "issue_row"."closed" NOTNULL THEN
6168 RETURN NULL;
6169 END IF;
6170 "persist"."state" := "issue_row"."state";
6171 IF
6172 ( "issue_row"."state" = 'admission' AND "last_calculated_v" >=
6173 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
6174 ( "issue_row"."state" = 'discussion' AND now() >=
6175 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
6176 ( "issue_row"."state" = 'verification' AND now() >=
6177 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
6178 ( "issue_row"."state" = 'voting' AND now() >=
6179 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
6180 THEN
6181 "persist"."phase_finished" := TRUE;
6182 ELSE
6183 "persist"."phase_finished" := FALSE;
6184 END IF;
6185 IF
6186 NOT EXISTS (
6187 -- all initiatives are revoked
6188 SELECT NULL FROM "initiative"
6189 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6190 ) AND (
6191 -- and issue has not been accepted yet
6192 "persist"."state" = 'admission' OR
6193 -- or verification time has elapsed
6194 ( "persist"."state" = 'verification' AND
6195 "persist"."phase_finished" ) OR
6196 -- or no initiatives have been revoked lately
6197 NOT EXISTS (
6198 SELECT NULL FROM "initiative"
6199 WHERE "issue_id" = "issue_id_p"
6200 AND now() < "revoked" + "issue_row"."verification_time"
6203 THEN
6204 "persist"."issue_revoked" := TRUE;
6205 ELSE
6206 "persist"."issue_revoked" := FALSE;
6207 END IF;
6208 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
6209 UPDATE "issue" SET "phase_finished" = now()
6210 WHERE "id" = "issue_row"."id";
6211 RETURN "persist";
6212 ELSIF
6213 "persist"."state" IN ('admission', 'discussion', 'verification')
6214 THEN
6215 RETURN "persist";
6216 ELSE
6217 RETURN NULL;
6218 END IF;
6219 END IF;
6220 IF
6221 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6222 coalesce("persist"."snapshot_created", FALSE) = FALSE
6223 THEN
6224 IF "persist"."state" != 'admission' THEN
6225 PERFORM "take_snapshot"("issue_id_p");
6226 PERFORM "finish_snapshot"("issue_id_p");
6227 ELSE
6228 UPDATE "issue" SET "issue_quorum" = "issue_quorum"."issue_quorum"
6229 FROM "issue_quorum"
6230 WHERE "id" = "issue_id_p"
6231 AND "issue_quorum"."issue_id" = "issue_id_p";
6232 END IF;
6233 "persist"."snapshot_created" = TRUE;
6234 IF "persist"."phase_finished" THEN
6235 IF "persist"."state" = 'admission' THEN
6236 UPDATE "issue" SET "admission_snapshot_id" = "latest_snapshot_id"
6237 WHERE "id" = "issue_id_p";
6238 ELSIF "persist"."state" = 'discussion' THEN
6239 UPDATE "issue" SET "half_freeze_snapshot_id" = "latest_snapshot_id"
6240 WHERE "id" = "issue_id_p";
6241 ELSIF "persist"."state" = 'verification' THEN
6242 UPDATE "issue" SET "full_freeze_snapshot_id" = "latest_snapshot_id"
6243 WHERE "id" = "issue_id_p";
6244 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
6245 FOR "initiative_row" IN
6246 SELECT * FROM "initiative"
6247 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6248 FOR UPDATE
6249 LOOP
6250 IF
6251 "initiative_row"."polling" OR
6252 "initiative_row"."satisfied_supporter_count" >=
6253 "issue_row"."initiative_quorum"
6254 THEN
6255 UPDATE "initiative" SET "admitted" = TRUE
6256 WHERE "id" = "initiative_row"."id";
6257 ELSE
6258 UPDATE "initiative" SET "admitted" = FALSE
6259 WHERE "id" = "initiative_row"."id";
6260 END IF;
6261 END LOOP;
6262 END IF;
6263 END IF;
6264 RETURN "persist";
6265 END IF;
6266 IF
6267 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6268 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
6269 THEN
6270 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
6271 "persist"."harmonic_weights_set" = TRUE;
6272 IF
6273 "persist"."phase_finished" OR
6274 "persist"."issue_revoked" OR
6275 "persist"."state" = 'admission'
6276 THEN
6277 RETURN "persist";
6278 ELSE
6279 RETURN NULL;
6280 END IF;
6281 END IF;
6282 IF "persist"."issue_revoked" THEN
6283 IF "persist"."state" = 'admission' THEN
6284 "state_v" := 'canceled_revoked_before_accepted';
6285 ELSIF "persist"."state" = 'discussion' THEN
6286 "state_v" := 'canceled_after_revocation_during_discussion';
6287 ELSIF "persist"."state" = 'verification' THEN
6288 "state_v" := 'canceled_after_revocation_during_verification';
6289 END IF;
6290 UPDATE "issue" SET
6291 "state" = "state_v",
6292 "closed" = "phase_finished",
6293 "phase_finished" = NULL
6294 WHERE "id" = "issue_id_p";
6295 RETURN NULL;
6296 END IF;
6297 IF "persist"."state" = 'admission' THEN
6298 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6299 FOR UPDATE;
6300 IF "issue_row"."phase_finished" NOTNULL THEN
6301 UPDATE "issue" SET
6302 "state" = 'canceled_issue_not_accepted',
6303 "closed" = "phase_finished",
6304 "phase_finished" = NULL
6305 WHERE "id" = "issue_id_p";
6306 END IF;
6307 RETURN NULL;
6308 END IF;
6309 IF "persist"."phase_finished" THEN
6310 IF "persist"."state" = 'discussion' THEN
6311 UPDATE "issue" SET
6312 "state" = 'verification',
6313 "half_frozen" = "phase_finished",
6314 "phase_finished" = NULL
6315 WHERE "id" = "issue_id_p";
6316 RETURN NULL;
6317 END IF;
6318 IF "persist"."state" = 'verification' THEN
6319 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6320 FOR UPDATE;
6321 SELECT * INTO "policy_row" FROM "policy"
6322 WHERE "id" = "issue_row"."policy_id";
6323 IF EXISTS (
6324 SELECT NULL FROM "initiative"
6325 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
6326 ) THEN
6327 UPDATE "issue" SET
6328 "state" = 'voting',
6329 "fully_frozen" = "phase_finished",
6330 "phase_finished" = NULL
6331 WHERE "id" = "issue_id_p";
6332 ELSE
6333 UPDATE "issue" SET
6334 "state" = 'canceled_no_initiative_admitted',
6335 "fully_frozen" = "phase_finished",
6336 "closed" = "phase_finished",
6337 "phase_finished" = NULL
6338 WHERE "id" = "issue_id_p";
6339 -- NOTE: The following DELETE statements have effect only when
6340 -- issue state has been manipulated
6341 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
6342 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
6343 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
6344 END IF;
6345 RETURN NULL;
6346 END IF;
6347 IF "persist"."state" = 'voting' THEN
6348 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
6349 PERFORM "close_voting"("issue_id_p");
6350 "persist"."closed_voting" = TRUE;
6351 RETURN "persist";
6352 END IF;
6353 PERFORM "calculate_ranks"("issue_id_p");
6354 RETURN NULL;
6355 END IF;
6356 END IF;
6357 RAISE WARNING 'should not happen';
6358 RETURN NULL;
6359 END;
6360 $$;
6362 COMMENT ON FUNCTION "check_issue"
6363 ( "issue"."id"%TYPE,
6364 "check_issue_persistence" )
6365 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")';
6368 CREATE FUNCTION "check_everything"()
6369 RETURNS VOID
6370 LANGUAGE 'plpgsql' VOLATILE AS $$
6371 DECLARE
6372 "area_id_v" "area"."id"%TYPE;
6373 "snapshot_id_v" "snapshot"."id"%TYPE;
6374 "issue_id_v" "issue"."id"%TYPE;
6375 "persist_v" "check_issue_persistence";
6376 BEGIN
6377 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
6378 DELETE FROM "expired_session";
6379 DELETE FROM "expired_token";
6380 DELETE FROM "expired_snapshot";
6381 PERFORM "check_activity"();
6382 PERFORM "calculate_member_counts"();
6383 FOR "area_id_v" IN SELECT "id" FROM "area_with_unaccepted_issues" LOOP
6384 SELECT "take_snapshot"(NULL, "area_id_v") INTO "snapshot_id_v";
6385 PERFORM "finish_snapshot"("issue_id") FROM "snapshot_issue"
6386 WHERE "snapshot_id" = "snapshot_id_v";
6387 LOOP
6388 EXIT WHEN "issue_admission"("area_id_v") = FALSE;
6389 END LOOP;
6390 END LOOP;
6391 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
6392 "persist_v" := NULL;
6393 LOOP
6394 "persist_v" := "check_issue"("issue_id_v", "persist_v");
6395 EXIT WHEN "persist_v" ISNULL;
6396 END LOOP;
6397 END LOOP;
6398 RETURN;
6399 END;
6400 $$;
6402 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';
6406 ----------------------
6407 -- Deletion of data --
6408 ----------------------
6411 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
6412 RETURNS VOID
6413 LANGUAGE 'plpgsql' VOLATILE AS $$
6414 BEGIN
6415 IF EXISTS (
6416 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
6417 ) THEN
6418 -- override protection triggers:
6419 INSERT INTO "temporary_transaction_data" ("key", "value")
6420 VALUES ('override_protection_triggers', TRUE::TEXT);
6421 -- clean data:
6422 DELETE FROM "delegating_voter"
6423 WHERE "issue_id" = "issue_id_p";
6424 DELETE FROM "direct_voter"
6425 WHERE "issue_id" = "issue_id_p";
6426 DELETE FROM "delegating_interest_snapshot"
6427 WHERE "issue_id" = "issue_id_p";
6428 DELETE FROM "direct_interest_snapshot"
6429 WHERE "issue_id" = "issue_id_p";
6430 DELETE FROM "non_voter"
6431 WHERE "issue_id" = "issue_id_p";
6432 DELETE FROM "delegation"
6433 WHERE "issue_id" = "issue_id_p";
6434 DELETE FROM "supporter"
6435 USING "initiative" -- NOTE: due to missing index on issue_id
6436 WHERE "initiative"."issue_id" = "issue_id_p"
6437 AND "supporter"."initiative_id" = "initiative_id";
6438 -- mark issue as cleaned:
6439 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
6440 -- finish overriding protection triggers (avoids garbage):
6441 DELETE FROM "temporary_transaction_data"
6442 WHERE "key" = 'override_protection_triggers';
6443 END IF;
6444 RETURN;
6445 END;
6446 $$;
6448 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
6451 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
6452 RETURNS VOID
6453 LANGUAGE 'plpgsql' VOLATILE AS $$
6454 BEGIN
6455 UPDATE "member" SET
6456 "last_login" = NULL,
6457 "last_delegation_check" = NULL,
6458 "login" = NULL,
6459 "password" = NULL,
6460 "authority" = NULL,
6461 "authority_uid" = NULL,
6462 "authority_login" = NULL,
6463 "deleted" = coalesce("deleted", now()),
6464 "locked" = TRUE,
6465 "active" = FALSE,
6466 "notify_email" = NULL,
6467 "notify_email_unconfirmed" = NULL,
6468 "notify_email_secret" = NULL,
6469 "notify_email_secret_expiry" = NULL,
6470 "notify_email_lock_expiry" = NULL,
6471 "disable_notifications" = TRUE,
6472 "notification_counter" = DEFAULT,
6473 "notification_sample_size" = 0,
6474 "notification_dow" = NULL,
6475 "notification_hour" = NULL,
6476 "notification_sent" = NULL,
6477 "login_recovery_expiry" = NULL,
6478 "password_reset_secret" = NULL,
6479 "password_reset_secret_expiry" = NULL,
6480 "location" = NULL
6481 WHERE "id" = "member_id_p";
6482 -- "text_search_data" is updated by triggers
6483 DELETE FROM "member_settings" WHERE "member_id" = "member_id_p";
6484 DELETE FROM "member_profile" WHERE "member_id" = "member_id_p";
6485 DELETE FROM "rendered_member_statement" WHERE "member_id" = "member_id_p";
6486 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
6487 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
6488 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
6489 DELETE FROM "session" WHERE "member_id" = "member_id_p";
6490 DELETE FROM "member_application" WHERE "member_id" = "member_id_p";
6491 DELETE FROM "token" WHERE "member_id" = "member_id_p";
6492 DELETE FROM "subscription" WHERE "member_id" = "member_id_p";
6493 DELETE FROM "ignored_area" WHERE "member_id" = "member_id_p";
6494 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
6495 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
6496 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
6497 DELETE FROM "direct_voter" USING "issue"
6498 WHERE "direct_voter"."issue_id" = "issue"."id"
6499 AND "issue"."closed" ISNULL
6500 AND "member_id" = "member_id_p";
6501 DELETE FROM "notification_initiative_sent" WHERE "member_id" = "member_id_p";
6502 RETURN;
6503 END;
6504 $$;
6506 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)';
6509 CREATE FUNCTION "delete_private_data"()
6510 RETURNS VOID
6511 LANGUAGE 'plpgsql' VOLATILE AS $$
6512 BEGIN
6513 DELETE FROM "temporary_transaction_data";
6514 DELETE FROM "temporary_suggestion_counts";
6515 DELETE FROM "member" WHERE "activated" ISNULL;
6516 UPDATE "member" SET
6517 "invite_code" = NULL,
6518 "invite_code_expiry" = NULL,
6519 "admin_comment" = NULL,
6520 "last_login" = NULL,
6521 "last_delegation_check" = NULL,
6522 "login" = NULL,
6523 "password" = NULL,
6524 "authority" = NULL,
6525 "authority_uid" = NULL,
6526 "authority_login" = NULL,
6527 "lang" = NULL,
6528 "notify_email" = NULL,
6529 "notify_email_unconfirmed" = NULL,
6530 "notify_email_secret" = NULL,
6531 "notify_email_secret_expiry" = NULL,
6532 "notify_email_lock_expiry" = NULL,
6533 "disable_notifications" = TRUE,
6534 "notification_counter" = DEFAULT,
6535 "notification_sample_size" = 0,
6536 "notification_dow" = NULL,
6537 "notification_hour" = NULL,
6538 "notification_sent" = NULL,
6539 "login_recovery_expiry" = NULL,
6540 "password_reset_secret" = NULL,
6541 "password_reset_secret_expiry" = NULL,
6542 "location" = NULL;
6543 -- "text_search_data" is updated by triggers
6544 DELETE FROM "verification";
6545 DELETE FROM "member_settings";
6546 DELETE FROM "member_useterms";
6547 DELETE FROM "member_profile";
6548 DELETE FROM "rendered_member_statement";
6549 DELETE FROM "member_image";
6550 DELETE FROM "contact";
6551 DELETE FROM "ignored_member";
6552 DELETE FROM "session";
6553 DELETE FROM "system_application";
6554 DELETE FROM "system_application_redirect_uri";
6555 DELETE FROM "dynamic_application_scope";
6556 DELETE FROM "member_application";
6557 DELETE FROM "token";
6558 DELETE FROM "subscription";
6559 DELETE FROM "ignored_area";
6560 DELETE FROM "ignored_initiative";
6561 DELETE FROM "non_voter";
6562 DELETE FROM "direct_voter" USING "issue"
6563 WHERE "direct_voter"."issue_id" = "issue"."id"
6564 AND "issue"."closed" ISNULL;
6565 DELETE FROM "event_processed";
6566 DELETE FROM "notification_initiative_sent";
6567 DELETE FROM "newsletter";
6568 RETURN;
6569 END;
6570 $$;
6572 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.';
6576 COMMIT;

Impressum / About Us