liquid_feedback_core

view core.sql @ 567:797282760db4

Removed unused function "calculate_area_quorum" (done by function "issue_admission")
author jbe
date Thu Sep 28 20:12:23 2017 +0200 (2017-09-28)
parents 74f98b2196ef
children b1326d149247
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.0-dev', 4, 0, -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 "disable_notifications" BOOLEAN NOT NULL DEFAULT FALSE,
119 "notification_counter" INT4 NOT NULL DEFAULT 1,
120 "notification_sample_size" INT4 NOT NULL DEFAULT 3,
121 "notification_dow" INT4 CHECK ("notification_dow" BETWEEN 0 AND 6),
122 "notification_hour" INT4 DEFAULT floor(random() * 24) CHECK ("notification_hour" BETWEEN 0 AND 23),
123 "notification_sent" TIMESTAMP,
124 "login_recovery_expiry" TIMESTAMPTZ,
125 "password_reset_secret" TEXT UNIQUE,
126 "password_reset_secret_expiry" TIMESTAMPTZ,
127 "name" TEXT UNIQUE,
128 "identification" TEXT UNIQUE,
129 "authentication" TEXT,
130 "location" JSONB,
131 "text_search_data" TSVECTOR,
132 CONSTRAINT "deleted_requires_locked"
133 CHECK ("deleted" ISNULL OR "locked" = TRUE),
134 CONSTRAINT "active_requires_activated_and_last_activity"
135 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)),
136 CONSTRAINT "authority_requires_uid_and_vice_versa"
137 CHECK (("authority" NOTNULL) = ("authority_uid" NOTNULL)),
138 CONSTRAINT "authority_uid_unique_per_authority"
139 UNIQUE ("authority", "authority_uid"),
140 CONSTRAINT "authority_login_requires_authority"
141 CHECK ("authority" NOTNULL OR "authority_login" ISNULL),
142 CONSTRAINT "notification_dow_requires_notification_hour"
143 CHECK ("notification_dow" ISNULL OR "notification_hour" NOTNULL),
144 CONSTRAINT "name_not_null_if_activated"
145 CHECK ("activated" ISNULL OR "name" NOTNULL) );
146 CREATE INDEX "member_authority_login_idx" ON "member" ("authority_login");
147 CREATE INDEX "member_active_idx" ON "member" ("active");
148 CREATE INDEX "member_location_idx" ON "member" USING gist ((GeoJSON_to_ecluster("location")));
149 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data");
150 CREATE TRIGGER "update_text_search_data"
151 BEFORE INSERT OR UPDATE ON "member"
152 FOR EACH ROW EXECUTE PROCEDURE
153 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
154 "name", "identification");
156 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization';
158 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code';
159 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time';
160 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"';
161 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes';
162 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';
163 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members';
164 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login';
165 COMMENT ON COLUMN "member"."last_delegation_check" IS 'Timestamp of last delegation check (i.e. confirmation of all unit and area delegations)';
166 COMMENT ON COLUMN "member"."login" IS 'Login name';
167 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)';
168 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)';
169 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)';
170 COMMENT ON COLUMN "member"."authority_login" IS 'Login name for external accounts (field is not unique!)';
171 COMMENT ON COLUMN "member"."deleted" IS 'Timestamp of deletion (set by "delete_member" function)';
172 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.';
173 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".';
174 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas';
175 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member';
176 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to';
177 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification';
178 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"';
179 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"';
180 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)';
181 COMMENT ON COLUMN "member"."disable_notifications" IS 'TRUE if member does not want to receive notifications';
182 COMMENT ON COLUMN "member"."notification_counter" IS 'Sequential number of next scheduled notification message (used as a seed for pseudo-random initiative selection algorithm)';
183 COMMENT ON COLUMN "member"."notification_sample_size" IS 'Number of featured initiatives per issue in scheduled notification messages';
184 COMMENT ON COLUMN "member"."notification_dow" IS 'Day of week for scheduled notifications (NULL to receive a daily digest)';
185 COMMENT ON COLUMN "member"."notification_hour" IS 'Time of day when scheduled notifications are sent out';
186 COMMENT ON COLUMN "member"."notification_sent" IS 'Timestamp of last scheduled notification mail that has been sent out';
187 COMMENT ON COLUMN "member"."login_recovery_expiry" IS 'Date/time after which another login recovery attempt is allowed';
188 COMMENT ON COLUMN "member"."password_reset_secret" IS 'Secret string sent via e-mail for password recovery';
189 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';
190 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet';
191 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member';
192 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated';
193 COMMENT ON COLUMN "member"."location" IS 'Geographic location on earth as GeoJSON object';
196 CREATE TABLE "member_history" ( -- TODO: redundancy with new "event" table
197 "id" SERIAL8 PRIMARY KEY,
198 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
199 "until" TIMESTAMPTZ NOT NULL DEFAULT now(),
200 "active" BOOLEAN NOT NULL,
201 "name" TEXT NOT NULL );
202 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id");
204 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members';
206 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)';
207 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid';
210 CREATE TABLE "verification" (
211 "id" SERIAL8 PRIMARY KEY,
212 "requested" TIMESTAMPTZ,
213 "request_origin" JSONB,
214 "request_data" JSONB,
215 "requesting_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
216 "verifying_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
217 "verified_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
218 "verified" TIMESTAMPTZ,
219 "verification_data" JSONB,
220 "denied" TIMESTAMPTZ,
221 "comment" TEXT,
222 CONSTRAINT "verified_and_denied_conflict" CHECK (
223 "verified" ISNULL OR "denied" ISNULL ) );
224 CREATE INDEX "verification_requested_idx" ON "verification" ("requested");
225 CREATE INDEX "verification_open_request_idx" ON "verification" ("requested") WHERE "verified" ISNULL AND "denied" ISNULL;
226 CREATE INDEX "verification_requesting_member_id_idx" ON "verification" ("requesting_member_id");
227 CREATE INDEX "verification_verified_member_id_idx" ON "verification" ("verified_member_id");
228 CREATE INDEX "verification_verified_idx" ON "verification" ("verified");
229 CREATE INDEX "verification_denied_idx" ON "verification" ("denied");
231 COMMENT ON TABLE "verification" IS 'Request to verify a participant';
233 COMMENT ON COLUMN "verification"."requested" IS 'Timestamp when request for verification has been submitted';
234 COMMENT ON COLUMN "verification"."request_origin" IS 'JSON data containing information about the origin of the request (e.g. IP address or hostname)';
235 COMMENT ON COLUMN "verification"."request_data" IS 'JSON data containing information about the entity to be verified (e.g. real name, address, etc.)';
236 COMMENT ON COLUMN "verification"."requesting_member_id" IS 'Member who requested verification';
237 COMMENT ON COLUMN "verification"."verifying_member_id" IS 'Member who processed the verification request (i.e. who accepted or denied the request)';
238 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)';
239 COMMENT ON COLUMN "verification"."verified" IS 'Timestamp when request for verification has been accepted by authority';
240 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';
241 COMMENT ON COLUMN "verification"."denied" IS 'Timestamp when request for verification has been denied by authority';
242 COMMENT ON COLUMN "verification"."comment" IS 'Administrative comment';
245 CREATE TABLE "member_settings" (
246 "member_id" INT4 PRIMARY KEY REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
247 "settings" JSONB NOT NULL CHECK (jsonb_typeof("settings") = 'object') );
249 COMMENT ON TABLE "member_settings" IS 'Stores a JSON document for each member containing optional (additional) settings for the respective member';
252 CREATE TABLE "member_useterms" (
253 "id" SERIAL8 PRIMARY KEY,
254 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
255 "accepted" TIMESTAMPTZ NOT NULL DEFAULT now(),
256 "contract_identifier" TEXT NOT NULL );
258 COMMENT ON TABLE "member_useterms" IS 'Keeps record of accepted terms of use; may contain multiple rows per member';
260 COMMENT ON COLUMN "member_useterms"."accepted" IS 'Point in time when user accepted the terms of use';
261 COMMENT ON COLUMN "member_useterms"."contract_identifier" IS 'String identifier to denote the accepted terms of use, including their version or revision';
264 CREATE TABLE "member_profile" (
265 "member_id" INT4 PRIMARY KEY REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
266 "formatting_engine" TEXT,
267 "statement" TEXT,
268 "profile" JSONB NOT NULL DEFAULT '{}' CHECK (jsonb_typeof("profile") = 'object'),
269 "profile_text_data" TEXT,
270 "text_search_data" TSVECTOR );
271 CREATE INDEX "member_profile_text_search_data_idx" ON "member_profile" USING gin ("text_search_data");
272 CREATE TRIGGER "update_text_search_data"
273 BEFORE INSERT OR UPDATE ON "member_profile"
274 FOR EACH ROW EXECUTE PROCEDURE
275 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
276 'statement', 'profile_text_data');
278 COMMENT ON COLUMN "member_profile"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member_profile"."statement"';
279 COMMENT ON COLUMN "member_profile"."statement" IS 'Freely chosen text of the member for his/her profile';
280 COMMENT ON COLUMN "member_profile"."profile" IS 'Additional profile data as JSON document';
281 COMMENT ON COLUMN "member_profile"."profile_text_data" IS 'Text data from "profile" field for full text search';
284 CREATE TABLE "rendered_member_statement" (
285 PRIMARY KEY ("member_id", "format"),
286 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
287 "format" TEXT,
288 "content" TEXT NOT NULL );
290 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)';
293 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar');
295 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member';
298 CREATE TABLE "member_image" (
299 PRIMARY KEY ("member_id", "image_type", "scaled"),
300 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
301 "image_type" "member_image_type",
302 "scaled" BOOLEAN,
303 "content_type" TEXT,
304 "data" BYTEA NOT NULL );
306 COMMENT ON TABLE "member_image" IS 'Images of members';
308 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image';
311 CREATE TABLE "member_count" (
312 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
313 "total_count" INT4 NOT NULL );
315 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';
317 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated';
318 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members';
321 CREATE TABLE "contact" (
322 PRIMARY KEY ("member_id", "other_member_id"),
323 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
324 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
325 "public" BOOLEAN NOT NULL DEFAULT FALSE,
326 CONSTRAINT "cant_save_yourself_as_contact"
327 CHECK ("member_id" != "other_member_id") );
328 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
330 COMMENT ON TABLE "contact" IS 'Contact lists';
332 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list';
333 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list';
334 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically';
337 CREATE TABLE "ignored_member" (
338 PRIMARY KEY ("member_id", "other_member_id"),
339 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
340 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
341 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
343 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
345 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone';
346 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
349 CREATE TABLE "session" (
350 UNIQUE ("member_id", "id"), -- index needed for foreign-key on table "token"
351 "id" SERIAL8 PRIMARY KEY,
352 "ident" TEXT NOT NULL UNIQUE,
353 "additional_secret" TEXT,
354 "logout_token" TEXT,
355 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours',
356 "member_id" INT4 REFERENCES "member" ("id") ON DELETE SET NULL,
357 "authority" TEXT,
358 "authority_uid" TEXT,
359 "authority_login" TEXT,
360 "needs_delegation_check" BOOLEAN NOT NULL DEFAULT FALSE,
361 "lang" TEXT );
362 CREATE INDEX "session_expiry_idx" ON "session" ("expiry");
364 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer';
366 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)';
367 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks';
368 COMMENT ON COLUMN "session"."logout_token" IS 'Optional token to authorize logout through external component';
369 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in';
370 COMMENT ON COLUMN "session"."authority" IS 'Temporary store for "member"."authority" during member account creation';
371 COMMENT ON COLUMN "session"."authority_uid" IS 'Temporary store for "member"."authority_uid" during member account creation';
372 COMMENT ON COLUMN "session"."authority_login" IS 'Temporary store for "member"."authority_login" during member account creation';
373 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';
374 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language';
377 CREATE TYPE "authflow" AS ENUM ('code', 'token');
379 COMMENT ON TYPE "authflow" IS 'OAuth 2.0 flows: ''code'' = Authorization Code flow, ''token'' = Implicit flow';
382 CREATE TABLE "system_application" (
383 "id" SERIAL4 PRIMARY KEY,
384 "name" TEXT NOT NULL,
385 "discovery_baseurl" TEXT,
386 "client_id" TEXT NOT NULL UNIQUE,
387 "default_redirect_uri" TEXT NOT NULL,
388 "cert_common_name" TEXT,
389 "client_cred_scope" TEXT,
390 "flow" "authflow",
391 "automatic_scope" TEXT,
392 "permitted_scope" TEXT,
393 "forbidden_scope" TEXT );
395 COMMENT ON TABLE "system_application" IS 'OAuth 2.0 clients that are registered by the system administrator';
397 COMMENT ON COLUMN "system_application"."name" IS 'Human readable name of application';
398 COMMENT ON COLUMN "system_application"."discovery_baseurl" IS 'Base URL for application discovery; NULL for hidden application';
399 COMMENT ON COLUMN "system_application"."client_id" IS 'OAuth 2.0 "client_id"';
400 COMMENT ON COLUMN "system_application"."cert_common_name" IS 'Value for CN field of TLS client certificate';
401 COMMENT ON COLUMN "system_application"."client_cred_scope" IS 'Space-separated list of scopes; If set, Client Credentials Grant is allowed; value determines scope';
402 COMMENT ON COLUMN "system_application"."flow" IS 'If set to ''code'' or ''token'', then Authorization Code or Implicit flow is allowed respectively';
403 COMMENT ON COLUMN "system_application"."automatic_scope" IS 'Space-separated list of scopes; Automatically granted scope for Authorization Code or Implicit flow';
404 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';
405 COMMENT ON COLUMN "system_application"."forbidden_scope" IS 'Space-separated list of scopes that may not be granted to the application by a member';
408 CREATE TABLE "system_application_redirect_uri" (
409 PRIMARY KEY ("system_application_id", "redirect_uri"),
410 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
411 "redirect_uri" TEXT );
413 COMMENT ON TABLE "system_application_redirect_uri" IS 'Additional OAuth 2.0 redirection endpoints, which may be selected through the "redirect_uri" GET parameter';
416 CREATE TABLE "dynamic_application_scope" (
417 PRIMARY KEY ("redirect_uri", "flow", "scope"),
418 "redirect_uri" TEXT,
419 "flow" TEXT,
420 "scope" TEXT,
421 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours' );
422 CREATE INDEX "dynamic_application_scope_redirect_uri_scope_idx" ON "dynamic_application_scope" ("redirect_uri", "flow", "scope");
423 CREATE INDEX "dynamic_application_scope_expiry_idx" ON "dynamic_application_scope" ("expiry");
425 COMMENT ON TABLE "dynamic_application_scope" IS 'Dynamic OAuth 2.0 client registration data';
427 COMMENT ON COLUMN "dynamic_application_scope"."redirect_uri" IS 'Redirection endpoint for which the registration has been done';
428 COMMENT ON COLUMN "dynamic_application_scope"."flow" IS 'OAuth 2.0 flow for which the registration has been done (see also "system_application"."flow")';
429 COMMENT ON COLUMN "dynamic_application_scope"."scope" IS 'Single scope without space characters (use multiple rows for more scopes)';
430 COMMENT ON COLUMN "dynamic_application_scope"."expiry" IS 'Expiry unless renewed';
433 CREATE TABLE "member_application" (
434 "id" SERIAL4 PRIMARY KEY,
435 UNIQUE ("system_application_id", "member_id"),
436 UNIQUE ("domain", "member_id"),
437 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
438 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
439 "domain" TEXT,
440 "session_id" INT8,
441 FOREIGN KEY ("member_id", "session_id") REFERENCES "session" ("member_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
442 "scope" TEXT NOT NULL,
443 CONSTRAINT "system_application_or_domain_but_not_both" CHECK (
444 ("system_application_id" NOTNULL AND "domain" ISNULL) OR
445 ("system_application_id" ISNULL AND "domain" NOTNULL) ) );
446 CREATE INDEX "member_application_member_id_idx" ON "member_application" ("member_id");
448 COMMENT ON TABLE "member_application" IS 'Application authorized by a member';
450 COMMENT ON COLUMN "member_application"."system_application_id" IS 'If set, then application is a system application';
451 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';
452 COMMENT ON COLUMN "member_application"."session_id" IS 'If set, registration ends with session';
453 COMMENT ON COLUMN "member_application"."scope" IS 'Granted scope as space-separated list of strings';
456 CREATE TYPE "token_type" AS ENUM ('authorization', 'refresh', 'access');
458 COMMENT ON TYPE "token_type" IS 'Types for entries in "token" table';
461 CREATE TABLE "token" (
462 "id" SERIAL8 PRIMARY KEY,
463 "token" TEXT NOT NULL UNIQUE,
464 "token_type" "token_type" NOT NULL,
465 "authorization_token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
466 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
467 "system_application_id" INT4 REFERENCES "system_application" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
468 "domain" TEXT,
469 FOREIGN KEY ("member_id", "domain") REFERENCES "member_application" ("member_id", "domain") ON DELETE CASCADE ON UPDATE CASCADE,
470 "session_id" INT8,
471 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"
472 "redirect_uri" TEXT,
473 "redirect_uri_explicit" BOOLEAN,
474 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
475 "expiry" TIMESTAMPTZ DEFAULT now() + '1 hour',
476 "used" BOOLEAN NOT NULL DEFAULT FALSE,
477 "scope" TEXT NOT NULL,
478 CONSTRAINT "access_token_needs_expiry"
479 CHECK ("token_type" != 'access'::"token_type" OR "expiry" NOTNULL),
480 CONSTRAINT "authorization_token_needs_redirect_uri"
481 CHECK ("token_type" != 'authorization'::"token_type" OR ("redirect_uri" NOTNULL AND "redirect_uri_explicit" NOTNULL) ) );
482 CREATE INDEX "token_member_id_idx" ON "token" ("member_id");
483 CREATE INDEX "token_authorization_token_id_idx" ON "token" ("authorization_token_id");
484 CREATE INDEX "token_expiry_idx" ON "token" ("expiry");
486 COMMENT ON TABLE "token" IS 'Issued OAuth 2.0 authorization codes and access/refresh tokens';
488 COMMENT ON COLUMN "token"."token" IS 'String secret (the actual token)';
489 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)';
490 COMMENT ON COLUMN "token"."system_application_id" IS 'If set, then application is a system application';
491 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';
492 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''';
493 COMMENT ON COLUMN "token"."redirect_uri" IS 'Authorization codes must be bound to a specific redirect URI';
494 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)';
495 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';
496 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)';
497 COMMENT ON COLUMN "token"."scope" IS 'Scope as space-separated list of strings (detached scopes are marked with ''_detached'' suffix)';
500 CREATE TABLE "token_scope" (
501 PRIMARY KEY ("token_id", "index"),
502 "token_id" INT8 REFERENCES "token" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
503 "index" INT4,
504 "scope" TEXT NOT NULL );
506 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';
509 CREATE TYPE "defeat_strength" AS ENUM ('simple', 'tuple');
511 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';
514 CREATE TYPE "tie_breaking" AS ENUM ('simple', 'variant1', 'variant2');
516 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';
519 CREATE TABLE "policy" (
520 "id" SERIAL4 PRIMARY KEY,
521 "index" INT4 NOT NULL,
522 "active" BOOLEAN NOT NULL DEFAULT TRUE,
523 "name" TEXT NOT NULL UNIQUE,
524 "description" TEXT NOT NULL DEFAULT '',
525 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
526 "min_admission_time" INTERVAL,
527 "max_admission_time" INTERVAL,
528 "discussion_time" INTERVAL,
529 "verification_time" INTERVAL,
530 "voting_time" INTERVAL,
531 "issue_quorum" INT4 CHECK ("issue_quorum" >= 1),
532 "issue_quorum_num" INT4,
533 "issue_quorum_den" INT4,
534 "initiative_quorum" INT4 NOT NULL CHECK ("initiative_quorum" >= 1),
535 "initiative_quorum_num" INT4 NOT NULL,
536 "initiative_quorum_den" INT4 NOT NULL,
537 "defeat_strength" "defeat_strength" NOT NULL DEFAULT 'tuple',
538 "tie_breaking" "tie_breaking" NOT NULL DEFAULT 'variant1',
539 "direct_majority_num" INT4 NOT NULL DEFAULT 1,
540 "direct_majority_den" INT4 NOT NULL DEFAULT 2,
541 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
542 "direct_majority_positive" INT4 NOT NULL DEFAULT 0,
543 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0,
544 "indirect_majority_num" INT4 NOT NULL DEFAULT 1,
545 "indirect_majority_den" INT4 NOT NULL DEFAULT 2,
546 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE,
547 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0,
548 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0,
549 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT FALSE,
550 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE,
551 CONSTRAINT "issue_quorum_if_and_only_if_not_polling" CHECK (
552 "polling" = ("issue_quorum" ISNULL) AND
553 "polling" = ("issue_quorum_num" ISNULL) AND
554 "polling" = ("issue_quorum_den" ISNULL) ),
555 CONSTRAINT "min_admission_time_smaller_than_max_admission_time" CHECK (
556 "min_admission_time" < "max_admission_time" ),
557 CONSTRAINT "timing_null_or_not_null_constraints" CHECK (
558 ( "polling" = FALSE AND
559 "min_admission_time" NOTNULL AND "max_admission_time" NOTNULL AND
560 "discussion_time" NOTNULL AND
561 "verification_time" NOTNULL AND
562 "voting_time" NOTNULL ) OR
563 ( "polling" = TRUE AND
564 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
565 "discussion_time" NOTNULL AND
566 "verification_time" NOTNULL AND
567 "voting_time" NOTNULL ) OR
568 ( "polling" = TRUE AND
569 "min_admission_time" ISNULL AND "max_admission_time" ISNULL AND
570 "discussion_time" ISNULL AND
571 "verification_time" ISNULL AND
572 "voting_time" ISNULL ) ),
573 CONSTRAINT "no_reverse_beat_path_requires_tuple_defeat_strength" CHECK (
574 "defeat_strength" = 'tuple'::"defeat_strength" OR
575 "no_reverse_beat_path" = FALSE ) );
576 CREATE INDEX "policy_active_idx" ON "policy" ("active");
578 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)';
580 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings';
581 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues';
582 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';
583 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"';
584 COMMENT ON COLUMN "policy"."max_admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
585 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
586 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"';
587 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'')';
588 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';
589 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)';
590 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)';
591 COMMENT ON COLUMN "policy"."initiative_quorum" IS 'Absolute number of satisfied supporters to be reached by an initiative to be "admitted" for voting';
592 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
593 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting';
594 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';
595 COMMENT ON COLUMN "policy"."tie_breaking" IS 'Tie-breaker for the Schulze method; see type "tie_breaking"; ''variant1'' or ''variant2'' are recommended';
596 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
597 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
598 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.';
599 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
600 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';
601 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';
602 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';
603 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.';
604 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';
605 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';
606 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.';
607 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").';
610 CREATE TABLE "unit" (
611 "id" SERIAL4 PRIMARY KEY,
612 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
613 "active" BOOLEAN NOT NULL DEFAULT TRUE,
614 "name" TEXT NOT NULL,
615 "description" TEXT NOT NULL DEFAULT '',
616 "external_reference" TEXT,
617 "member_count" INT4,
618 "location" JSONB,
619 "text_search_data" TSVECTOR );
620 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
621 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
622 CREATE INDEX "unit_active_idx" ON "unit" ("active");
623 CREATE INDEX "unit_location_idx" ON "unit" USING gist ((GeoJSON_to_ecluster("location")));
624 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
625 CREATE TRIGGER "update_text_search_data"
626 BEFORE INSERT OR UPDATE ON "unit"
627 FOR EACH ROW EXECUTE PROCEDURE
628 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
629 "name", "description" );
631 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
633 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed';
634 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit';
635 COMMENT ON COLUMN "unit"."external_reference" IS 'Opaque data field to store an external reference';
636 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege" (only active members counted)';
637 COMMENT ON COLUMN "unit"."location" IS 'Geographic location on earth as GeoJSON object indicating valid coordinates for initiatives of issues with this policy';
640 CREATE TABLE "subscription" (
641 PRIMARY KEY ("member_id", "unit_id"),
642 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
643 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
644 CREATE INDEX "subscription_unit_id_idx" ON "subscription" ("unit_id");
646 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';
649 CREATE TABLE "area" (
650 UNIQUE ("unit_id", "id"), -- index needed for foreign-key on table "event"
651 "id" SERIAL4 PRIMARY KEY,
652 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
653 "active" BOOLEAN NOT NULL DEFAULT TRUE,
654 "name" TEXT NOT NULL,
655 "description" TEXT NOT NULL DEFAULT '',
656 "quorum_standard" NUMERIC NOT NULL DEFAULT 2 CHECK ("quorum_standard" >= 0),
657 "quorum_issues" NUMERIC NOT NULL DEFAULT 1 CHECK ("quorum_issues" > 0),
658 "quorum_time" INTERVAL NOT NULL DEFAULT '1 day' CHECK ("quorum_time" > '0'::INTERVAL),
659 "quorum_exponent" NUMERIC NOT NULL DEFAULT 0.5 CHECK ("quorum_exponent" BETWEEN 0 AND 1),
660 "quorum_factor" NUMERIC NOT NULL DEFAULT 2 CHECK ("quorum_factor" >= 1),
661 "quorum_den" INT4 CHECK ("quorum_den" > 0),
662 "issue_quorum" INT4,
663 "external_reference" TEXT,
664 "location" JSONB,
665 "text_search_data" TSVECTOR );
666 CREATE INDEX "area_active_idx" ON "area" ("active");
667 CREATE INDEX "area_location_idx" ON "area" USING gist ((GeoJSON_to_ecluster("location")));
668 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data");
669 CREATE TRIGGER "update_text_search_data"
670 BEFORE INSERT OR UPDATE ON "area"
671 FOR EACH ROW EXECUTE PROCEDURE
672 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
673 "name", "description" );
675 COMMENT ON TABLE "area" IS 'Subject areas';
677 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area';
678 COMMENT ON COLUMN "area"."quorum_standard" IS 'Parameter for dynamic issue quorum: default quorum';
679 COMMENT ON COLUMN "area"."quorum_issues" IS 'Parameter for dynamic issue quorum: number of open issues for default quorum';
680 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)';
681 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';
682 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';
683 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)';
684 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"';
685 COMMENT ON COLUMN "area"."external_reference" IS 'Opaque data field to store an external reference';
686 COMMENT ON COLUMN "area"."location" IS 'Geographic location on earth as GeoJSON object indicating valid coordinates for initiatives of issues with this policy';
689 CREATE TABLE "ignored_area" (
690 PRIMARY KEY ("member_id", "area_id"),
691 "member_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
692 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
693 CREATE INDEX "ignored_area_area_id_idx" ON "ignored_area" ("area_id");
695 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';
698 CREATE TABLE "allowed_policy" (
699 PRIMARY KEY ("area_id", "policy_id"),
700 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
701 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
702 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE );
703 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy";
705 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area';
707 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.';
710 CREATE TABLE "snapshot" (
711 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "issue"
712 "id" SERIAL8 PRIMARY KEY,
713 "calculated" TIMESTAMPTZ NOT NULL DEFAULT now(),
714 "population" INT4,
715 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
716 "issue_id" INT4 ); -- NOTE: following (cyclic) reference is added later through ALTER command: REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE
718 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';
721 CREATE TABLE "snapshot_population" (
722 PRIMARY KEY ("snapshot_id", "member_id"),
723 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
724 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE );
726 COMMENT ON TABLE "snapshot_population" IS 'Members with voting right relevant for a snapshot';
729 CREATE TYPE "issue_state" AS ENUM (
730 'admission', 'discussion', 'verification', 'voting',
731 'canceled_by_admin',
732 'canceled_revoked_before_accepted',
733 'canceled_issue_not_accepted',
734 'canceled_after_revocation_during_discussion',
735 'canceled_after_revocation_during_verification',
736 'canceled_no_initiative_admitted',
737 'finished_without_winner', 'finished_with_winner');
739 COMMENT ON TYPE "issue_state" IS 'State of issues';
742 CREATE TABLE "issue" (
743 UNIQUE ("area_id", "id"), -- index needed for foreign-key on table "event"
744 UNIQUE ("policy_id", "id"), -- index needed for foreign-key on table "event"
745 "id" SERIAL4 PRIMARY KEY,
746 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
747 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
748 "admin_notice" TEXT,
749 "external_reference" TEXT,
750 "state" "issue_state" NOT NULL DEFAULT 'admission',
751 "phase_finished" TIMESTAMPTZ,
752 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
753 "accepted" TIMESTAMPTZ,
754 "half_frozen" TIMESTAMPTZ,
755 "fully_frozen" TIMESTAMPTZ,
756 "closed" TIMESTAMPTZ,
757 "cleaned" TIMESTAMPTZ,
758 "min_admission_time" INTERVAL,
759 "max_admission_time" INTERVAL,
760 "discussion_time" INTERVAL NOT NULL,
761 "verification_time" INTERVAL NOT NULL,
762 "voting_time" INTERVAL NOT NULL,
763 "calculated" TIMESTAMPTZ, -- NOTE: copy of "calculated" column of latest snapshot, but no referential integrity to avoid overhead
764 "latest_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
765 "admission_snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
766 "half_freeze_snapshot_id" INT8,
767 FOREIGN KEY ("id", "half_freeze_snapshot_id")
768 REFERENCES "snapshot" ("issue_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE,
769 "full_freeze_snapshot_id" INT8,
770 FOREIGN KEY ("id", "full_freeze_snapshot_id")
771 REFERENCES "snapshot" ("issue_id", "id") ON DELETE RESTRICT ON UPDATE CASCADE,
772 "population" INT4,
773 "voter_count" INT4,
774 "status_quo_schulze_rank" INT4,
775 CONSTRAINT "admission_time_not_null_unless_instantly_accepted" CHECK (
776 ("min_admission_time" NOTNULL) = ("max_admission_time" NOTNULL) AND
777 ("min_admission_time" NOTNULL OR ("accepted" NOTNULL AND "accepted" = "created")) ),
778 CONSTRAINT "valid_state" CHECK (
779 (
780 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
781 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL ) OR
782 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL ) OR
783 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL)
784 ) AND (
785 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR
786 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
787 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
788 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
789 ("state" = 'canceled_by_admin' AND "closed" NOTNULL) OR
790 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
791 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR
792 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR
793 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
794 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" = "fully_frozen") OR
795 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen") OR
796 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "closed" != "fully_frozen")
797 )),
798 CONSTRAINT "phase_finished_only_when_not_closed" CHECK (
799 "phase_finished" ISNULL OR "closed" ISNULL ),
800 CONSTRAINT "state_change_order" CHECK (
801 "created" <= "accepted" AND
802 "accepted" <= "half_frozen" AND
803 "half_frozen" <= "fully_frozen" AND
804 "fully_frozen" <= "closed" ),
805 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK (
806 "cleaned" ISNULL OR "closed" NOTNULL ),
807 CONSTRAINT "snapshot_required" CHECK (
808 --("accepted" ISNULL OR "admission_snapshot_id" NOTNULL) AND
809 ("half_frozen" ISNULL OR "half_freeze_snapshot_id" NOTNULL) AND
810 ("fully_frozen" ISNULL OR "full_freeze_snapshot_id" NOTNULL) ) );
811 CREATE INDEX "issue_state_idx" ON "issue" ("state");
812 CREATE INDEX "issue_created_idx" ON "issue" ("created");
813 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted");
814 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen");
815 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen");
816 CREATE INDEX "issue_closed_idx" ON "issue" ("closed");
817 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL;
818 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL;
819 CREATE INDEX "issue_latest_snapshot_id" ON "issue" ("latest_snapshot_id");
820 CREATE INDEX "issue_admission_snapshot_id" ON "issue" ("admission_snapshot_id");
821 CREATE INDEX "issue_half_freeze_snapshot_id" ON "issue" ("half_freeze_snapshot_id");
822 CREATE INDEX "issue_full_freeze_snapshot_id" ON "issue" ("full_freeze_snapshot_id");
824 COMMENT ON TABLE "issue" IS 'Groups of initiatives';
826 COMMENT ON COLUMN "issue"."admin_notice" IS 'Public notice by admin to explain manual interventions, or to announce corrections';
827 COMMENT ON COLUMN "issue"."external_reference" IS 'Opaque data field to store an external reference';
828 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';
829 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")';
830 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.';
831 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.';
832 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.';
833 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted';
834 COMMENT ON COLUMN "issue"."min_admission_time" IS 'Copied from "policy" table at creation of issue';
835 COMMENT ON COLUMN "issue"."max_admission_time" IS 'Copied from "policy" table at creation of issue';
836 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue';
837 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue';
838 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue';
839 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")';
840 COMMENT ON COLUMN "issue"."latest_snapshot_id" IS 'Snapshot id of most recent snapshot';
841 COMMENT ON COLUMN "issue"."admission_snapshot_id" IS 'Snapshot id when issue as accepted or canceled in admission phase';
842 COMMENT ON COLUMN "issue"."half_freeze_snapshot_id" IS 'Snapshot id at end of discussion phase';
843 COMMENT ON COLUMN "issue"."full_freeze_snapshot_id" IS 'Snapshot id at end of verification phase';
844 COMMENT ON COLUMN "issue"."population" IS 'Count of members in "snapshot_population" table with "snapshot_id" equal to "issue"."latest_snapshot_id"';
845 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';
846 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
849 ALTER TABLE "snapshot" ADD FOREIGN KEY ("issue_id") REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE;
852 CREATE TABLE "issue_order_in_admission_state" (
853 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performans/locking issues; REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
854 "order_in_area" INT4,
855 "order_in_unit" INT4 );
857 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"';
859 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';
860 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';
861 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';
864 CREATE TABLE "initiative" (
865 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote"
866 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
867 "id" SERIAL4 PRIMARY KEY,
868 "name" TEXT NOT NULL,
869 "polling" BOOLEAN NOT NULL DEFAULT FALSE,
870 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
871 "revoked" TIMESTAMPTZ,
872 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
873 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE SET NULL ON UPDATE CASCADE,
874 "location" JSONB,
875 "external_reference" TEXT,
876 "admitted" BOOLEAN,
877 "supporter_count" INT4,
878 "informed_supporter_count" INT4,
879 "satisfied_supporter_count" INT4,
880 "satisfied_informed_supporter_count" INT4,
881 "harmonic_weight" NUMERIC(12, 3),
882 "final_suggestion_order_calculated" BOOLEAN NOT NULL DEFAULT FALSE,
883 "first_preference_votes" INT4,
884 "positive_votes" INT4,
885 "negative_votes" INT4,
886 "direct_majority" BOOLEAN,
887 "indirect_majority" BOOLEAN,
888 "schulze_rank" INT4,
889 "better_than_status_quo" BOOLEAN,
890 "worse_than_status_quo" BOOLEAN,
891 "reverse_beat_path" BOOLEAN,
892 "multistage_majority" BOOLEAN,
893 "eligible" BOOLEAN,
894 "winner" BOOLEAN,
895 "rank" INT4,
896 "text_search_data" TSVECTOR,
897 "draft_text_search_data" TSVECTOR,
898 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
899 CHECK (("revoked" NOTNULL) = ("revoked_by_member_id" NOTNULL)),
900 CONSTRAINT "non_revoked_initiatives_cant_suggest_other"
901 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL),
902 CONSTRAINT "revoked_initiatives_cant_be_admitted"
903 CHECK ("revoked" ISNULL OR "admitted" ISNULL),
904 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
905 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
906 ( "first_preference_votes" ISNULL AND
907 "positive_votes" ISNULL AND "negative_votes" ISNULL AND
908 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
909 "schulze_rank" ISNULL AND
910 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
911 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
912 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ),
913 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")),
914 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
915 "eligible" = FALSE OR
916 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ),
917 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE),
918 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1),
919 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE),
920 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") );
921 CREATE INDEX "initiative_created_idx" ON "initiative" ("created");
922 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked");
923 CREATE INDEX "initiative_location_idx" ON "initiative" USING gist ((GeoJSON_to_ecluster("location")));
924 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data");
925 CREATE INDEX "initiative_draft_text_search_data_idx" ON "initiative" USING gin ("draft_text_search_data");
926 CREATE TRIGGER "update_text_search_data"
927 BEFORE INSERT OR UPDATE ON "initiative"
928 FOR EACH ROW EXECUTE PROCEDURE
929 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "name");
931 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.';
933 COMMENT ON COLUMN "initiative"."polling" IS 'Initiative does not need to pass the initiative quorum (see "policy"."polling")';
934 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
935 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
936 COMMENT ON COLUMN "initiative"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied from most recent draft)';
937 COMMENT ON COLUMN "initiative"."external_reference" IS 'Opaque data field to store an external reference';
938 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
939 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
940 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
941 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
942 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"';
943 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';
944 COMMENT ON COLUMN "initiative"."final_suggestion_order_calculated" IS 'Set to TRUE, when "proportional_order" of suggestions has been calculated the last time';
945 COMMENT ON COLUMN "initiative"."first_preference_votes" IS 'Number of direct and delegating voters who ranked this initiative as their first choice';
946 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Number of direct and delegating voters who ranked this initiative better than the status quo';
947 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Number of direct and delegating voters who ranked this initiative worse than the status quo';
948 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"';
949 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
950 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking';
951 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo';
952 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)';
953 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''';
954 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';
955 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"';
956 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank"';
957 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';
960 CREATE TABLE "battle" (
961 "issue_id" INT4 NOT NULL,
962 "winning_initiative_id" INT4,
963 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
964 "losing_initiative_id" INT4,
965 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
966 "count" INT4 NOT NULL,
967 CONSTRAINT "initiative_ids_not_equal" CHECK (
968 "winning_initiative_id" != "losing_initiative_id" OR
969 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
970 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) );
971 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
972 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
973 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
975 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';
978 CREATE TABLE "ignored_initiative" (
979 PRIMARY KEY ("member_id", "initiative_id"),
980 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
981 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
982 CREATE INDEX "ignored_initiative_initiative_id_idx" ON "ignored_initiative" ("initiative_id");
984 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';
987 CREATE TABLE "draft" (
988 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter"
989 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
990 "id" SERIAL8 PRIMARY KEY,
991 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
992 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
993 "formatting_engine" TEXT,
994 "content" TEXT NOT NULL,
995 "location" JSONB,
996 "external_reference" TEXT,
997 "text_search_data" TSVECTOR );
998 CREATE INDEX "draft_created_idx" ON "draft" ("created");
999 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created");
1000 CREATE INDEX "draft_location_idx" ON "draft" USING gist ((GeoJSON_to_ecluster("location")));
1001 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data");
1002 CREATE TRIGGER "update_text_search_data"
1003 BEFORE INSERT OR UPDATE ON "draft"
1004 FOR EACH ROW EXECUTE PROCEDURE
1005 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
1007 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.';
1009 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used';
1010 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"';
1011 COMMENT ON COLUMN "draft"."location" IS 'Geographic location of initiative as GeoJSON object (automatically copied to "initiative" table if draft is most recent)';
1012 COMMENT ON COLUMN "draft"."external_reference" IS 'Opaque data field to store an external reference';
1015 CREATE TABLE "rendered_draft" (
1016 PRIMARY KEY ("draft_id", "format"),
1017 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1018 "format" TEXT,
1019 "content" TEXT NOT NULL );
1021 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)';
1024 CREATE TABLE "suggestion" (
1025 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion"
1026 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1027 "id" SERIAL8 PRIMARY KEY,
1028 "draft_id" INT8 NOT NULL,
1029 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1030 "created" TIMESTAMPTZ NOT NULL DEFAULT now(),
1031 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1032 "name" TEXT NOT NULL,
1033 "formatting_engine" TEXT,
1034 "content" TEXT NOT NULL DEFAULT '',
1035 "location" JSONB,
1036 "external_reference" TEXT,
1037 "text_search_data" TSVECTOR,
1038 "minus2_unfulfilled_count" INT4,
1039 "minus2_fulfilled_count" INT4,
1040 "minus1_unfulfilled_count" INT4,
1041 "minus1_fulfilled_count" INT4,
1042 "plus1_unfulfilled_count" INT4,
1043 "plus1_fulfilled_count" INT4,
1044 "plus2_unfulfilled_count" INT4,
1045 "plus2_fulfilled_count" INT4,
1046 "proportional_order" INT4 );
1047 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created");
1048 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created");
1049 CREATE INDEX "suggestion_location_idx" ON "suggestion" USING gist ((GeoJSON_to_ecluster("location")));
1050 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data");
1051 CREATE TRIGGER "update_text_search_data"
1052 BEFORE INSERT OR UPDATE ON "suggestion"
1053 FOR EACH ROW EXECUTE PROCEDURE
1054 tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
1055 "name", "content");
1057 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';
1059 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")';
1060 COMMENT ON COLUMN "suggestion"."location" IS 'Geographic location of suggestion as GeoJSON object';
1061 COMMENT ON COLUMN "suggestion"."external_reference" IS 'Opaque data field to store an external reference';
1062 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1063 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1064 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1065 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1066 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1067 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1068 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1069 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters';
1070 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"';
1073 CREATE TABLE "rendered_suggestion" (
1074 PRIMARY KEY ("suggestion_id", "format"),
1075 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1076 "format" TEXT,
1077 "content" TEXT NOT NULL );
1079 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)';
1082 CREATE TABLE "temporary_suggestion_counts" (
1083 "id" INT8 PRIMARY KEY, -- NOTE: no referential integrity due to performance/locking issues; REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1084 "minus2_unfulfilled_count" INT4 NOT NULL,
1085 "minus2_fulfilled_count" INT4 NOT NULL,
1086 "minus1_unfulfilled_count" INT4 NOT NULL,
1087 "minus1_fulfilled_count" INT4 NOT NULL,
1088 "plus1_unfulfilled_count" INT4 NOT NULL,
1089 "plus1_fulfilled_count" INT4 NOT NULL,
1090 "plus2_unfulfilled_count" INT4 NOT NULL,
1091 "plus2_fulfilled_count" INT4 NOT NULL );
1093 COMMENT ON TABLE "temporary_suggestion_counts" IS 'Holds certain calculated values (suggestion counts) temporarily until they can be copied into table "suggestion"';
1095 COMMENT ON COLUMN "temporary_suggestion_counts"."id" IS 'References "suggestion" ("id") but has no referential integrity trigger associated, due to performance/locking issues';
1098 CREATE TABLE "privilege" (
1099 PRIMARY KEY ("unit_id", "member_id"),
1100 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1101 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1102 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1103 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1104 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1105 "member_manager" BOOLEAN NOT NULL DEFAULT FALSE,
1106 "initiative_right" BOOLEAN NOT NULL DEFAULT TRUE,
1107 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE,
1108 "polling_right" BOOLEAN NOT NULL DEFAULT FALSE );
1110 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
1112 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke any privileges to/from other members';
1113 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
1114 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
1115 COMMENT ON COLUMN "privilege"."member_manager" IS 'Adding/removing members from the unit, granting or revoking "initiative_right" and "voting_right"';
1116 COMMENT ON COLUMN "privilege"."initiative_right" IS 'Right to create an initiative';
1117 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to support initiatives, create and rate suggestions, and to vote';
1118 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';
1121 CREATE TABLE "interest" (
1122 PRIMARY KEY ("issue_id", "member_id"),
1123 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1124 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE );
1125 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id");
1127 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.';
1130 CREATE TABLE "initiator" (
1131 PRIMARY KEY ("initiative_id", "member_id"),
1132 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1133 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1134 "accepted" BOOLEAN );
1135 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id");
1137 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.';
1139 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.';
1142 CREATE TABLE "supporter" (
1143 "issue_id" INT4 NOT NULL,
1144 PRIMARY KEY ("initiative_id", "member_id"),
1145 "initiative_id" INT4,
1146 "member_id" INT4,
1147 "draft_id" INT8 NOT NULL,
1148 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1149 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE );
1150 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id");
1152 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.';
1154 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1155 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")';
1158 CREATE TABLE "opinion" (
1159 "initiative_id" INT4 NOT NULL,
1160 PRIMARY KEY ("suggestion_id", "member_id"),
1161 "suggestion_id" INT8,
1162 "member_id" INT4,
1163 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0),
1164 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE,
1165 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1166 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1167 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id");
1169 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.';
1171 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support';
1174 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
1176 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
1179 CREATE TABLE "delegation" (
1180 "id" SERIAL8 PRIMARY KEY,
1181 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1182 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1183 "scope" "delegation_scope" NOT NULL,
1184 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1185 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1186 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1187 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"),
1188 CONSTRAINT "no_unit_delegation_to_null"
1189 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'),
1190 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK (
1191 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR
1192 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
1193 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ),
1194 UNIQUE ("unit_id", "truster_id"),
1195 UNIQUE ("area_id", "truster_id"),
1196 UNIQUE ("issue_id", "truster_id") );
1197 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id");
1198 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id");
1200 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members';
1202 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
1203 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL';
1204 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL';
1207 CREATE TABLE "snapshot_issue" (
1208 PRIMARY KEY ("snapshot_id", "issue_id"),
1209 "snapshot_id" INT8 REFERENCES "snapshot" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1210 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); -- NOTE: trigger "delete_snapshot_on_partial_delete" will delete whole "snapshot"
1211 CREATE INDEX "snapshot_issue_issue_id_idx" ON "snapshot_issue" ("issue_id");
1213 COMMENT ON TABLE "snapshot_issue" IS 'List of issues included in a snapshot';
1215 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.';
1218 CREATE TABLE "direct_interest_snapshot" (
1219 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1220 "snapshot_id" INT8,
1221 "issue_id" INT4,
1222 FOREIGN KEY ("snapshot_id", "issue_id")
1223 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1224 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1225 "weight" INT4 );
1226 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id");
1228 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';
1230 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"';
1233 CREATE TABLE "delegating_interest_snapshot" (
1234 PRIMARY KEY ("snapshot_id", "issue_id", "member_id"),
1235 "snapshot_id" INT8,
1236 "issue_id" INT4,
1237 FOREIGN KEY ("snapshot_id", "issue_id")
1238 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1239 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1240 "weight" INT4,
1241 "scope" "delegation_scope" NOT NULL,
1242 "delegate_member_ids" INT4[] NOT NULL );
1243 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id");
1245 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';
1247 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member';
1248 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight';
1249 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"';
1252 CREATE TABLE "direct_supporter_snapshot" (
1253 PRIMARY KEY ("snapshot_id", "initiative_id", "member_id"),
1254 "snapshot_id" INT8,
1255 "issue_id" INT4 NOT NULL,
1256 FOREIGN KEY ("snapshot_id", "issue_id")
1257 REFERENCES "snapshot_issue" ("snapshot_id", "issue_id") ON DELETE CASCADE ON UPDATE CASCADE,
1258 "initiative_id" INT4,
1259 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1260 "draft_id" INT8 NOT NULL,
1261 "informed" BOOLEAN NOT NULL,
1262 "satisfied" BOOLEAN NOT NULL,
1263 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1264 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE,
1265 FOREIGN KEY ("snapshot_id", "issue_id", "member_id") REFERENCES "direct_interest_snapshot" ("snapshot_id", "issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE );
1266 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id");
1268 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';
1270 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';
1271 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative';
1272 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s';
1275 CREATE TABLE "non_voter" (
1276 PRIMARY KEY ("member_id", "issue_id"),
1277 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1278 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
1279 CREATE INDEX "non_voter_issue_id_idx" ON "non_voter" ("issue_id");
1281 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
1284 CREATE TABLE "direct_voter" (
1285 PRIMARY KEY ("issue_id", "member_id"),
1286 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1287 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1288 "weight" INT4,
1289 "comment_changed" TIMESTAMPTZ,
1290 "formatting_engine" TEXT,
1291 "comment" TEXT,
1292 "text_search_data" TSVECTOR );
1293 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id");
1294 CREATE INDEX "direct_voter_text_search_data_idx" ON "direct_voter" USING gin ("text_search_data");
1295 CREATE TRIGGER "update_text_search_data"
1296 BEFORE INSERT OR UPDATE ON "direct_voter"
1297 FOR EACH ROW EXECUTE PROCEDURE
1298 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "comment");
1300 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';
1302 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
1303 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';
1304 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';
1305 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.';
1308 CREATE TABLE "rendered_voter_comment" (
1309 PRIMARY KEY ("issue_id", "member_id", "format"),
1310 FOREIGN KEY ("issue_id", "member_id")
1311 REFERENCES "direct_voter" ("issue_id", "member_id")
1312 ON DELETE CASCADE ON UPDATE CASCADE,
1313 "issue_id" INT4,
1314 "member_id" INT4,
1315 "format" TEXT,
1316 "content" TEXT NOT NULL );
1318 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)';
1321 CREATE TABLE "delegating_voter" (
1322 PRIMARY KEY ("issue_id", "member_id"),
1323 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1324 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT,
1325 "weight" INT4,
1326 "scope" "delegation_scope" NOT NULL,
1327 "delegate_member_ids" INT4[] NOT NULL );
1328 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id");
1330 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';
1332 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member';
1333 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight';
1334 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"';
1337 CREATE TABLE "vote" (
1338 "issue_id" INT4 NOT NULL,
1339 PRIMARY KEY ("initiative_id", "member_id"),
1340 "initiative_id" INT4,
1341 "member_id" INT4,
1342 "grade" INT4 NOT NULL,
1343 "first_preference" BOOLEAN,
1344 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1345 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE,
1346 CONSTRAINT "first_preference_flag_only_set_on_positive_grades"
1347 CHECK ("grade" > 0 OR "first_preference" ISNULL) );
1348 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id");
1350 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';
1352 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
1353 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.';
1354 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.';
1357 CREATE TYPE "event_type" AS ENUM (
1358 'unit_created',
1359 'unit_updated',
1360 'area_created',
1361 'area_updated',
1362 'policy_created',
1363 'policy_updated',
1364 'issue_state_changed',
1365 'initiative_created_in_new_issue',
1366 'initiative_created_in_existing_issue',
1367 'initiative_revoked',
1368 'new_draft_created',
1369 'suggestion_created',
1370 'suggestion_deleted',
1371 'member_activated',
1372 'member_deleted',
1373 'member_active',
1374 'member_name_updated',
1375 'member_profile_updated',
1376 'member_image_updated',
1377 'interest',
1378 'initiator',
1379 'support',
1380 'support_updated',
1381 'suggestion_rated',
1382 'delegation',
1383 'contact' );
1385 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
1388 CREATE TABLE "event" (
1389 "id" SERIAL8 PRIMARY KEY,
1390 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(),
1391 "event" "event_type" NOT NULL,
1392 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1393 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
1394 "scope" "delegation_scope",
1395 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1396 "area_id" INT4,
1397 FOREIGN KEY ("unit_id", "area_id") REFERENCES "area" ("unit_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1398 "policy_id" INT4 REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1399 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1400 FOREIGN KEY ("area_id", "issue_id") REFERENCES "issue" ("area_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1401 FOREIGN KEY ("policy_id", "issue_id") REFERENCES "issue" ("policy_id", "id") ON DELETE CASCADE ON UPDATE CASCADE,
1402 "state" "issue_state",
1403 "initiative_id" INT4,
1404 "draft_id" INT8,
1405 "suggestion_id" INT8,
1406 "boolean_value" BOOLEAN,
1407 "numeric_value" INT4,
1408 "text_value" TEXT,
1409 "old_text_value" TEXT,
1410 FOREIGN KEY ("issue_id", "initiative_id")
1411 REFERENCES "initiative" ("issue_id", "id")
1412 ON DELETE CASCADE ON UPDATE CASCADE,
1413 FOREIGN KEY ("initiative_id", "draft_id")
1414 REFERENCES "draft" ("initiative_id", "id")
1415 ON DELETE CASCADE ON UPDATE CASCADE,
1416 -- NOTE: no referential integrity for suggestions because those are
1417 -- actually deleted
1418 -- FOREIGN KEY ("initiative_id", "suggestion_id")
1419 -- REFERENCES "suggestion" ("initiative_id", "id")
1420 -- ON DELETE CASCADE ON UPDATE CASCADE,
1421 CONSTRAINT "constr_for_issue_state_changed" CHECK (
1422 "event" != 'issue_state_changed' OR (
1423 "member_id" ISNULL AND
1424 "other_member_id" ISNULL AND
1425 "scope" ISNULL AND
1426 "unit_id" NOTNULL AND
1427 "area_id" NOTNULL AND
1428 "policy_id" NOTNULL AND
1429 "issue_id" NOTNULL AND
1430 "state" NOTNULL AND
1431 "initiative_id" ISNULL AND
1432 "draft_id" ISNULL AND
1433 "suggestion_id" ISNULL AND
1434 "boolean_value" ISNULL AND
1435 "numeric_value" ISNULL AND
1436 "text_value" ISNULL AND
1437 "old_text_value" ISNULL )),
1438 CONSTRAINT "constr_for_initiative_creation_or_revocation_or_new_draft" CHECK (
1439 "event" NOT IN (
1440 'initiative_created_in_new_issue',
1441 'initiative_created_in_existing_issue',
1442 'initiative_revoked',
1443 'new_draft_created'
1444 ) OR (
1445 "member_id" NOTNULL AND
1446 "other_member_id" ISNULL AND
1447 "scope" ISNULL AND
1448 "unit_id" NOTNULL AND
1449 "area_id" NOTNULL AND
1450 "policy_id" NOTNULL AND
1451 "issue_id" NOTNULL AND
1452 "state" NOTNULL AND
1453 "initiative_id" NOTNULL AND
1454 "draft_id" NOTNULL AND
1455 "suggestion_id" ISNULL AND
1456 "boolean_value" ISNULL AND
1457 "numeric_value" ISNULL AND
1458 "text_value" ISNULL AND
1459 "old_text_value" ISNULL )),
1460 CONSTRAINT "constr_for_suggestion_creation" CHECK (
1461 "event" != 'suggestion_created' OR (
1462 "member_id" NOTNULL AND
1463 "other_member_id" ISNULL AND
1464 "scope" ISNULL AND
1465 "unit_id" NOTNULL AND
1466 "area_id" NOTNULL AND
1467 "policy_id" NOTNULL AND
1468 "issue_id" NOTNULL AND
1469 "state" NOTNULL AND
1470 "initiative_id" NOTNULL AND
1471 "draft_id" ISNULL AND
1472 "suggestion_id" NOTNULL AND
1473 "boolean_value" ISNULL AND
1474 "numeric_value" ISNULL AND
1475 "text_value" ISNULL AND
1476 "old_text_value" ISNULL )),
1477 CONSTRAINT "constr_for_suggestion_removal" CHECK (
1478 "event" != 'suggestion_deleted' OR (
1479 "member_id" ISNULL AND
1480 "other_member_id" ISNULL AND
1481 "scope" ISNULL AND
1482 "unit_id" NOTNULL AND
1483 "area_id" NOTNULL AND
1484 "policy_id" NOTNULL AND
1485 "issue_id" NOTNULL AND
1486 "state" NOTNULL AND
1487 "initiative_id" NOTNULL AND
1488 "draft_id" ISNULL AND
1489 "suggestion_id" NOTNULL AND
1490 "boolean_value" ISNULL AND
1491 "numeric_value" ISNULL AND
1492 "text_value" ISNULL AND
1493 "old_text_value" ISNULL )),
1494 CONSTRAINT "constr_for_value_less_member_event" CHECK (
1495 "event" NOT IN (
1496 'member_activated',
1497 'member_deleted',
1498 'member_profile_updated',
1499 'member_image_updated'
1500 ) OR (
1501 "member_id" NOTNULL AND
1502 "other_member_id" ISNULL AND
1503 "scope" ISNULL AND
1504 "unit_id" ISNULL AND
1505 "area_id" ISNULL AND
1506 "policy_id" ISNULL AND
1507 "issue_id" ISNULL AND
1508 "state" ISNULL AND
1509 "initiative_id" ISNULL AND
1510 "draft_id" ISNULL AND
1511 "suggestion_id" ISNULL AND
1512 "boolean_value" ISNULL AND
1513 "numeric_value" ISNULL AND
1514 "text_value" ISNULL AND
1515 "old_text_value" ISNULL )),
1516 CONSTRAINT "constr_for_member_active" CHECK (
1517 "event" != 'member_active' OR (
1518 "member_id" NOTNULL AND
1519 "other_member_id" ISNULL AND
1520 "scope" ISNULL AND
1521 "unit_id" ISNULL AND
1522 "area_id" ISNULL AND
1523 "policy_id" ISNULL AND
1524 "issue_id" ISNULL AND
1525 "state" ISNULL AND
1526 "initiative_id" ISNULL AND
1527 "draft_id" ISNULL AND
1528 "suggestion_id" ISNULL AND
1529 "boolean_value" NOTNULL AND
1530 "numeric_value" ISNULL AND
1531 "text_value" ISNULL AND
1532 "old_text_value" ISNULL )),
1533 CONSTRAINT "constr_for_member_name_updated" CHECK (
1534 "event" != 'member_name_updated' OR (
1535 "member_id" NOTNULL AND
1536 "other_member_id" ISNULL AND
1537 "scope" ISNULL AND
1538 "unit_id" ISNULL AND
1539 "area_id" ISNULL AND
1540 "policy_id" ISNULL AND
1541 "issue_id" ISNULL AND
1542 "state" ISNULL AND
1543 "initiative_id" ISNULL AND
1544 "draft_id" ISNULL AND
1545 "suggestion_id" ISNULL AND
1546 "boolean_value" ISNULL AND
1547 "numeric_value" ISNULL AND
1548 "text_value" NOTNULL AND
1549 "old_text_value" NOTNULL )),
1550 CONSTRAINT "constr_for_interest" CHECK (
1551 "event" != 'interest' OR (
1552 "member_id" NOTNULL AND
1553 "other_member_id" ISNULL AND
1554 "scope" ISNULL AND
1555 "unit_id" NOTNULL AND
1556 "area_id" NOTNULL AND
1557 "policy_id" NOTNULL AND
1558 "issue_id" NOTNULL AND
1559 "state" NOTNULL AND
1560 "initiative_id" ISNULL AND
1561 "draft_id" ISNULL AND
1562 "suggestion_id" ISNULL AND
1563 "boolean_value" NOTNULL AND
1564 "numeric_value" ISNULL AND
1565 "text_value" ISNULL AND
1566 "old_text_value" ISNULL )),
1567 CONSTRAINT "constr_for_initiator" CHECK (
1568 "event" != 'initiator' OR (
1569 "member_id" NOTNULL AND
1570 "other_member_id" ISNULL AND
1571 "scope" ISNULL AND
1572 "unit_id" NOTNULL AND
1573 "area_id" NOTNULL AND
1574 "policy_id" NOTNULL AND
1575 "issue_id" NOTNULL AND
1576 "state" NOTNULL AND
1577 "initiative_id" NOTNULL AND
1578 "draft_id" ISNULL AND
1579 "suggestion_id" ISNULL AND
1580 "boolean_value" NOTNULL AND
1581 "numeric_value" ISNULL AND
1582 "text_value" ISNULL AND
1583 "old_text_value" ISNULL )),
1584 CONSTRAINT "constr_for_support" CHECK (
1585 "event" != 'support' OR (
1586 "member_id" NOTNULL AND
1587 "other_member_id" ISNULL AND
1588 "scope" ISNULL AND
1589 "unit_id" NOTNULL AND
1590 "area_id" NOTNULL AND
1591 "policy_id" NOTNULL AND
1592 "issue_id" NOTNULL AND
1593 "state" NOTNULL AND
1594 "initiative_id" NOTNULL AND
1595 ("draft_id" NOTNULL) = ("boolean_value" = TRUE) AND
1596 "suggestion_id" ISNULL AND
1597 "boolean_value" NOTNULL AND
1598 "numeric_value" ISNULL AND
1599 "text_value" ISNULL AND
1600 "old_text_value" ISNULL )),
1601 CONSTRAINT "constr_for_support_updated" CHECK (
1602 "event" != 'support_updated' OR (
1603 "member_id" NOTNULL AND
1604 "other_member_id" ISNULL AND
1605 "scope" ISNULL AND
1606 "unit_id" NOTNULL AND
1607 "area_id" NOTNULL AND
1608 "policy_id" NOTNULL AND
1609 "issue_id" NOTNULL AND
1610 "state" NOTNULL AND
1611 "initiative_id" NOTNULL AND
1612 "draft_id" NOTNULL AND
1613 "suggestion_id" ISNULL AND
1614 "boolean_value" ISNULL AND
1615 "numeric_value" ISNULL AND
1616 "text_value" ISNULL AND
1617 "old_text_value" ISNULL )),
1618 CONSTRAINT "constr_for_suggestion_rated" CHECK (
1619 "event" != 'suggestion_rated' OR (
1620 "member_id" NOTNULL AND
1621 "other_member_id" ISNULL AND
1622 "scope" ISNULL AND
1623 "unit_id" NOTNULL AND
1624 "area_id" NOTNULL AND
1625 "policy_id" NOTNULL AND
1626 "issue_id" NOTNULL AND
1627 "state" NOTNULL AND
1628 "initiative_id" NOTNULL AND
1629 "draft_id" ISNULL AND
1630 "suggestion_id" NOTNULL AND
1631 ("boolean_value" NOTNULL) = ("numeric_value" != 0) AND
1632 "numeric_value" NOTNULL AND
1633 "numeric_value" IN (-2, -1, 0, 1, 2) AND
1634 "text_value" ISNULL AND
1635 "old_text_value" ISNULL )),
1636 CONSTRAINT "constr_for_delegation" CHECK (
1637 "event" != 'delegation' OR (
1638 "member_id" NOTNULL AND
1639 (("other_member_id" ISNULL) OR ("boolean_value" = TRUE)) AND
1640 "scope" NOTNULL AND
1641 "unit_id" NOTNULL AND
1642 ("area_id" NOTNULL) = ("scope" != 'unit'::"delegation_scope") AND
1643 "policy_id" ISNULL AND
1644 ("issue_id" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1645 ("state" NOTNULL) = ("scope" = 'issue'::"delegation_scope") AND
1646 "initiative_id" ISNULL AND
1647 "draft_id" ISNULL AND
1648 "suggestion_id" ISNULL AND
1649 "boolean_value" NOTNULL AND
1650 "numeric_value" ISNULL AND
1651 "text_value" ISNULL AND
1652 "old_text_value" ISNULL )),
1653 CONSTRAINT "constr_for_contact" CHECK (
1654 "event" != 'contact' OR (
1655 "member_id" NOTNULL AND
1656 "other_member_id" NOTNULL AND
1657 "scope" ISNULL AND
1658 "unit_id" ISNULL AND
1659 "area_id" ISNULL AND
1660 "policy_id" ISNULL AND
1661 "issue_id" ISNULL AND
1662 "state" ISNULL AND
1663 "initiative_id" ISNULL AND
1664 "draft_id" ISNULL AND
1665 "suggestion_id" ISNULL AND
1666 "boolean_value" NOTNULL AND
1667 "numeric_value" ISNULL AND
1668 "text_value" ISNULL AND
1669 "old_text_value" ISNULL )) );
1670 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence");
1672 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
1674 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
1675 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")';
1676 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable';
1677 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state';
1680 CREATE TABLE "event_processed" (
1681 "event_id" INT8 NOT NULL );
1682 CREATE UNIQUE INDEX "event_processed_singleton_idx" ON "event_processed" ((1));
1684 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)';
1685 COMMENT ON INDEX "event_processed_singleton_idx" IS 'This index ensures that "event_processed" only contains one row maximum.';
1688 CREATE TABLE "notification_initiative_sent" (
1689 PRIMARY KEY ("member_id", "initiative_id"),
1690 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1691 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1692 "last_draft_id" INT8 NOT NULL,
1693 "last_suggestion_id" INT8 );
1694 CREATE INDEX "notification_initiative_sent_initiative_idx" ON "notification_initiative_sent" ("initiative_id");
1696 COMMENT ON TABLE "notification_initiative_sent" IS 'Information which initiatives have been promoted to a member in a scheduled notification mail';
1698 COMMENT ON COLUMN "notification_initiative_sent"."last_draft_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1699 COMMENT ON COLUMN "notification_initiative_sent"."last_suggestion_id" IS 'Current (i.e. last) draft_id when initiative had been promoted';
1702 CREATE TABLE "newsletter" (
1703 "id" SERIAL4 PRIMARY KEY,
1704 "published" TIMESTAMPTZ NOT NULL,
1705 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
1706 "include_all_members" BOOLEAN NOT NULL,
1707 "sent" TIMESTAMPTZ,
1708 "subject" TEXT NOT NULL,
1709 "content" TEXT NOT NULL );
1710 CREATE INDEX "newsletter_unit_id_idx" ON "newsletter" ("unit_id", "published");
1711 CREATE INDEX "newsletter_all_units_published_idx" ON "newsletter" ("published") WHERE "unit_id" ISNULL;
1712 CREATE INDEX "newsletter_published_idx" ON "newsletter" ("published");
1714 COMMENT ON TABLE "newsletter" IS 'Contains newsletters created by administrators to be sent out and for further reference';
1716 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter is to be sent out (and made available in the frontend)';
1717 COMMENT ON COLUMN "newsletter"."unit_id" IS 'If set, only members with voting right in the given unit are considered to be recipients';
1718 COMMENT ON COLUMN "newsletter"."include_all_members" IS 'TRUE = include all members regardless of their ''disable_notifications'' setting';
1719 COMMENT ON COLUMN "newsletter"."sent" IS 'Timestamp when the newsletter has been mailed out';
1720 COMMENT ON COLUMN "newsletter"."subject" IS 'Subject line (e.g. to be used for the email)';
1721 COMMENT ON COLUMN "newsletter"."content" IS 'Plain text content of the newsletter';
1725 ----------------------------------------------
1726 -- Writing of history entries and event log --
1727 ----------------------------------------------
1730 CREATE FUNCTION "write_member_history_trigger"()
1731 RETURNS TRIGGER
1732 LANGUAGE 'plpgsql' VOLATILE AS $$
1733 BEGIN
1734 IF
1735 ( NEW."active" != OLD."active" OR
1736 NEW."name" != OLD."name" ) AND
1737 OLD."activated" NOTNULL
1738 THEN
1739 INSERT INTO "member_history"
1740 ("member_id", "active", "name")
1741 VALUES (NEW."id", OLD."active", OLD."name");
1742 END IF;
1743 RETURN NULL;
1744 END;
1745 $$;
1747 CREATE TRIGGER "write_member_history"
1748 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
1749 "write_member_history_trigger"();
1751 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"';
1752 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table';
1755 CREATE FUNCTION "write_event_unit_trigger"()
1756 RETURNS TRIGGER
1757 LANGUAGE 'plpgsql' VOLATILE AS $$
1758 DECLARE
1759 "event_v" "event_type";
1760 BEGIN
1761 IF TG_OP = 'UPDATE' THEN
1762 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1763 RETURN NULL;
1764 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1765 -- "event_v" := 'unit_created';
1766 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1767 -- "event_v" := 'unit_deleted';
1768 ELSIF OLD != NEW THEN
1769 "event_v" := 'unit_updated';
1770 ELSE
1771 RETURN NULL;
1772 END IF;
1773 ELSE
1774 "event_v" := 'unit_created';
1775 END IF;
1776 INSERT INTO "event" ("event", "unit_id") VALUES ("event_v", NEW."id");
1777 RETURN NULL;
1778 END;
1779 $$;
1781 CREATE TRIGGER "write_event_unit" AFTER INSERT OR UPDATE ON "unit"
1782 FOR EACH ROW EXECUTE PROCEDURE "write_event_unit_trigger"();
1784 COMMENT ON FUNCTION "write_event_unit_trigger"() IS 'Implementation of trigger "write_event_unit" on table "unit"';
1785 COMMENT ON TRIGGER "write_event_unit" ON "unit" IS 'Create entry in "event" table on new or changed/disabled units';
1788 CREATE FUNCTION "write_event_area_trigger"()
1789 RETURNS TRIGGER
1790 LANGUAGE 'plpgsql' VOLATILE AS $$
1791 DECLARE
1792 "event_v" "event_type";
1793 BEGIN
1794 IF TG_OP = 'UPDATE' THEN
1795 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1796 RETURN NULL;
1797 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1798 -- "event_v" := 'area_created';
1799 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1800 -- "event_v" := 'area_deleted';
1801 ELSIF OLD != NEW THEN
1802 "event_v" := 'area_updated';
1803 ELSE
1804 RETURN NULL;
1805 END IF;
1806 ELSE
1807 "event_v" := 'area_created';
1808 END IF;
1809 INSERT INTO "event" ("event", "area_id") VALUES ("event_v", NEW."id");
1810 RETURN NULL;
1811 END;
1812 $$;
1814 CREATE TRIGGER "write_event_area" AFTER INSERT OR UPDATE ON "area"
1815 FOR EACH ROW EXECUTE PROCEDURE "write_event_area_trigger"();
1817 COMMENT ON FUNCTION "write_event_area_trigger"() IS 'Implementation of trigger "write_event_area" on table "area"';
1818 COMMENT ON TRIGGER "write_event_area" ON "area" IS 'Create entry in "event" table on new or changed/disabled areas';
1821 CREATE FUNCTION "write_event_policy_trigger"()
1822 RETURNS TRIGGER
1823 LANGUAGE 'plpgsql' VOLATILE AS $$
1824 DECLARE
1825 "event_v" "event_type";
1826 BEGIN
1827 IF TG_OP = 'UPDATE' THEN
1828 IF OLD."active" = FALSE AND NEW."active" = FALSE THEN
1829 RETURN NULL;
1830 --ELSIF OLD."active" = FALSE AND NEW."active" = TRUE THEN
1831 -- "event_v" := 'policy_created';
1832 --ELSIF OLD."active" = TRUE AND NEW."active" = FALSE THEN
1833 -- "event_v" := 'policy_deleted';
1834 ELSIF OLD != NEW THEN
1835 "event_v" := 'policy_updated';
1836 ELSE
1837 RETURN NULL;
1838 END IF;
1839 ELSE
1840 "event_v" := 'policy_created';
1841 END IF;
1842 INSERT INTO "event" ("event", "policy_id") VALUES ("event_v", NEW."id");
1843 RETURN NULL;
1844 END;
1845 $$;
1847 CREATE TRIGGER "write_event_policy" AFTER INSERT OR UPDATE ON "policy"
1848 FOR EACH ROW EXECUTE PROCEDURE "write_event_policy_trigger"();
1850 COMMENT ON FUNCTION "write_event_policy_trigger"() IS 'Implementation of trigger "write_event_policy" on table "policy"';
1851 COMMENT ON TRIGGER "write_event_policy" ON "policy" IS 'Create entry in "event" table on new or changed/disabled policies';
1854 CREATE FUNCTION "write_event_issue_state_changed_trigger"()
1855 RETURNS TRIGGER
1856 LANGUAGE 'plpgsql' VOLATILE AS $$
1857 DECLARE
1858 "area_row" "area"%ROWTYPE;
1859 BEGIN
1860 IF NEW."state" != OLD."state" THEN
1861 SELECT * INTO "area_row" FROM "area" WHERE "id" = NEW."area_id"
1862 FOR SHARE;
1863 INSERT INTO "event" (
1864 "event",
1865 "unit_id", "area_id", "policy_id", "issue_id", "state"
1866 ) VALUES (
1867 'issue_state_changed',
1868 "area_row"."unit_id", NEW."area_id", NEW."policy_id",
1869 NEW."id", NEW."state"
1870 );
1871 END IF;
1872 RETURN NULL;
1873 END;
1874 $$;
1876 CREATE TRIGGER "write_event_issue_state_changed"
1877 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
1878 "write_event_issue_state_changed_trigger"();
1880 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
1881 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
1884 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
1885 RETURNS TRIGGER
1886 LANGUAGE 'plpgsql' VOLATILE AS $$
1887 DECLARE
1888 "initiative_row" "initiative"%ROWTYPE;
1889 "issue_row" "issue"%ROWTYPE;
1890 "area_row" "area"%ROWTYPE;
1891 "event_v" "event_type";
1892 BEGIN
1893 SELECT * INTO "initiative_row" FROM "initiative"
1894 WHERE "id" = NEW."initiative_id" FOR SHARE;
1895 SELECT * INTO "issue_row" FROM "issue"
1896 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
1897 SELECT * INTO "area_row" FROM "area"
1898 WHERE "id" = "issue_row"."area_id" FOR SHARE;
1899 IF EXISTS (
1900 SELECT NULL FROM "draft"
1901 WHERE "initiative_id" = NEW."initiative_id" AND "id" != NEW."id"
1902 FOR SHARE
1903 ) THEN
1904 "event_v" := 'new_draft_created';
1905 ELSE
1906 IF EXISTS (
1907 SELECT NULL FROM "initiative"
1908 WHERE "issue_id" = "initiative_row"."issue_id"
1909 AND "id" != "initiative_row"."id"
1910 FOR SHARE
1911 ) THEN
1912 "event_v" := 'initiative_created_in_existing_issue';
1913 ELSE
1914 "event_v" := 'initiative_created_in_new_issue';
1915 END IF;
1916 END IF;
1917 INSERT INTO "event" (
1918 "event", "member_id",
1919 "unit_id", "area_id", "policy_id", "issue_id", "state",
1920 "initiative_id", "draft_id"
1921 ) VALUES (
1922 "event_v", NEW."author_id",
1923 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
1924 "initiative_row"."issue_id", "issue_row"."state",
1925 NEW."initiative_id", NEW."id"
1926 );
1927 RETURN NULL;
1928 END;
1929 $$;
1931 CREATE TRIGGER "write_event_initiative_or_draft_created"
1932 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
1933 "write_event_initiative_or_draft_created_trigger"();
1935 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
1936 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
1939 CREATE FUNCTION "write_event_initiative_revoked_trigger"()
1940 RETURNS TRIGGER
1941 LANGUAGE 'plpgsql' VOLATILE AS $$
1942 DECLARE
1943 "issue_row" "issue"%ROWTYPE;
1944 "area_row" "area"%ROWTYPE;
1945 "draft_id_v" "draft"."id"%TYPE;
1946 BEGIN
1947 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
1948 -- NOTE: lock for primary key update to avoid new drafts
1949 SELECT NULL FROM "initiative" WHERE "id" = NEW."id" FOR UPDATE;
1950 SELECT * INTO "issue_row" FROM "issue"
1951 WHERE "id" = NEW."issue_id" FOR SHARE;
1952 SELECT * INTO "area_row" FROM "area"
1953 WHERE "id" = "issue_row"."area_id" FOR SHARE;
1954 -- NOTE: FOR SHARE cannot be used with DISTINCT in view "current_draft"
1955 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id" FOR SHARE;
1956 SELECT "id" INTO "draft_id_v" FROM "current_draft"
1957 WHERE "initiative_id" = NEW."id";
1958 INSERT INTO "event" (
1959 "event", "member_id",
1960 "unit_id", "area_id", "policy_id", "issue_id", "state",
1961 "initiative_id", "draft_id"
1962 ) VALUES (
1963 'initiative_revoked', NEW."revoked_by_member_id",
1964 "area_row"."unit_id", "issue_row"."area_id",
1965 "issue_row"."policy_id",
1966 NEW."issue_id", "issue_row"."state",
1967 NEW."id", "draft_id_v"
1968 );
1969 END IF;
1970 RETURN NULL;
1971 END;
1972 $$;
1974 CREATE TRIGGER "write_event_initiative_revoked"
1975 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1976 "write_event_initiative_revoked_trigger"();
1978 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1979 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1982 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1983 RETURNS TRIGGER
1984 LANGUAGE 'plpgsql' VOLATILE AS $$
1985 DECLARE
1986 "initiative_row" "initiative"%ROWTYPE;
1987 "issue_row" "issue"%ROWTYPE;
1988 "area_row" "area"%ROWTYPE;
1989 BEGIN
1990 SELECT * INTO "initiative_row" FROM "initiative"
1991 WHERE "id" = NEW."initiative_id" FOR SHARE;
1992 SELECT * INTO "issue_row" FROM "issue"
1993 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
1994 SELECT * INTO "area_row" FROM "area"
1995 WHERE "id" = "issue_row"."area_id" FOR SHARE;
1996 INSERT INTO "event" (
1997 "event", "member_id",
1998 "unit_id", "area_id", "policy_id", "issue_id", "state",
1999 "initiative_id", "suggestion_id"
2000 ) VALUES (
2001 'suggestion_created', NEW."author_id",
2002 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
2003 "initiative_row"."issue_id", "issue_row"."state",
2004 NEW."initiative_id", NEW."id"
2005 );
2006 RETURN NULL;
2007 END;
2008 $$;
2010 CREATE TRIGGER "write_event_suggestion_created"
2011 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2012 "write_event_suggestion_created_trigger"();
2014 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
2015 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2018 CREATE FUNCTION "write_event_suggestion_removed_trigger"()
2019 RETURNS TRIGGER
2020 LANGUAGE 'plpgsql' VOLATILE AS $$
2021 DECLARE
2022 "initiative_row" "initiative"%ROWTYPE;
2023 "issue_row" "issue"%ROWTYPE;
2024 "area_row" "area"%ROWTYPE;
2025 BEGIN
2026 SELECT * INTO "initiative_row" FROM "initiative"
2027 WHERE "id" = OLD."initiative_id" FOR SHARE;
2028 IF "initiative_row"."id" NOTNULL THEN
2029 SELECT * INTO "issue_row" FROM "issue"
2030 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2031 SELECT * INTO "area_row" FROM "area"
2032 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2033 INSERT INTO "event" (
2034 "event",
2035 "unit_id", "area_id", "policy_id", "issue_id", "state",
2036 "initiative_id", "suggestion_id"
2037 ) VALUES (
2038 'suggestion_deleted',
2039 "area_row"."unit_id", "issue_row"."area_id",
2040 "issue_row"."policy_id",
2041 "initiative_row"."issue_id", "issue_row"."state",
2042 OLD."initiative_id", OLD."id"
2043 );
2044 END IF;
2045 RETURN NULL;
2046 END;
2047 $$;
2049 CREATE TRIGGER "write_event_suggestion_removed"
2050 AFTER DELETE ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2051 "write_event_suggestion_removed_trigger"();
2053 COMMENT ON FUNCTION "write_event_suggestion_removed_trigger"() IS 'Implementation of trigger "write_event_suggestion_removed" on table "issue"';
2054 COMMENT ON TRIGGER "write_event_suggestion_removed" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2057 CREATE FUNCTION "write_event_member_trigger"()
2058 RETURNS TRIGGER
2059 LANGUAGE 'plpgsql' VOLATILE AS $$
2060 BEGIN
2061 IF TG_OP = 'INSERT' THEN
2062 IF NEW."activated" NOTNULL AND NEW."deleted" ISNULL THEN
2063 INSERT INTO "event" ("event", "member_id")
2064 VALUES ('member_activated', NEW."id");
2065 END IF;
2066 IF NEW."active" THEN
2067 INSERT INTO "event" ("event", "member_id", "boolean_value")
2068 VALUES ('member_active', NEW."id", TRUE);
2069 END IF;
2070 ELSIF TG_OP = 'UPDATE' THEN
2071 IF OLD."id" != NEW."id" THEN
2072 RAISE EXCEPTION 'Cannot change member ID';
2073 END IF;
2074 IF
2075 (OLD."activated" ISNULL OR OLD."deleted" NOTNULL) AND
2076 NEW."activated" NOTNULL AND NEW."deleted" ISNULL
2077 THEN
2078 INSERT INTO "event" ("event", "member_id")
2079 VALUES ('member_activated', NEW."id");
2080 END IF;
2081 IF OLD."active" != NEW."active" THEN
2082 INSERT INTO "event" ("event", "member_id", "boolean_value") VALUES (
2083 'member_active', NEW."id", NEW."active"
2084 );
2085 END IF;
2086 IF OLD."name" != NEW."name" THEN
2087 INSERT INTO "event" (
2088 "event", "member_id", "text_value", "old_text_value"
2089 ) VALUES (
2090 'member_name_updated', NEW."id", NEW."name", OLD."name"
2091 );
2092 END IF;
2093 IF
2094 OLD."activated" NOTNULL AND OLD."deleted" ISNULL AND
2095 (NEW."activated" ISNULL OR NEW."deleted" NOTNULL)
2096 THEN
2097 INSERT INTO "event" ("event", "member_id")
2098 VALUES ('member_deleted', NEW."id");
2099 END IF;
2100 END IF;
2101 RETURN NULL;
2102 END;
2103 $$;
2105 CREATE TRIGGER "write_event_member"
2106 AFTER INSERT OR UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
2107 "write_event_member_trigger"();
2109 COMMENT ON FUNCTION "write_event_member_trigger"() IS 'Implementation of trigger "write_event_member" on table "member"';
2110 COMMENT ON TRIGGER "write_event_member" ON "member" IS 'Create entries in "event" table on insertion to member table';
2113 CREATE FUNCTION "write_event_member_profile_updated_trigger"()
2114 RETURNS TRIGGER
2115 LANGUAGE 'plpgsql' VOLATILE AS $$
2116 BEGIN
2117 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2118 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2119 INSERT INTO "event" ("event", "member_id") VALUES (
2120 'member_profile_updated', OLD."member_id"
2121 );
2122 END IF;
2123 END IF;
2124 IF TG_OP = 'UPDATE' THEN
2125 IF OLD."member_id" = NEW."member_id" THEN
2126 RETURN NULL;
2127 END IF;
2128 END IF;
2129 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2130 INSERT INTO "event" ("event", "member_id") VALUES (
2131 'member_profile_updated', NEW."member_id"
2132 );
2133 END IF;
2134 RETURN NULL;
2135 END;
2136 $$;
2138 CREATE TRIGGER "write_event_member_profile_updated"
2139 AFTER INSERT OR UPDATE OR DELETE ON "member_profile"
2140 FOR EACH ROW EXECUTE PROCEDURE
2141 "write_event_member_profile_updated_trigger"();
2143 COMMENT ON FUNCTION "write_event_member_profile_updated_trigger"() IS 'Implementation of trigger "write_event_member_profile_updated" on table "member_profile"';
2144 COMMENT ON TRIGGER "write_event_member_profile_updated" ON "member_profile" IS 'Creates entries in "event" table on member profile update';
2147 CREATE FUNCTION "write_event_member_image_updated_trigger"()
2148 RETURNS TRIGGER
2149 LANGUAGE 'plpgsql' VOLATILE AS $$
2150 BEGIN
2151 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2152 IF NOT OLD."scaled" THEN
2153 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2154 INSERT INTO "event" ("event", "member_id") VALUES (
2155 'member_image_updated', OLD."member_id"
2156 );
2157 END IF;
2158 END IF;
2159 END IF;
2160 IF TG_OP = 'UPDATE' THEN
2161 IF
2162 OLD."member_id" = NEW."member_id" AND
2163 OLD."scaled" = NEW."scaled"
2164 THEN
2165 RETURN NULL;
2166 END IF;
2167 END IF;
2168 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2169 IF NOT NEW."scaled" THEN
2170 INSERT INTO "event" ("event", "member_id") VALUES (
2171 'member_image_updated', NEW."member_id"
2172 );
2173 END IF;
2174 END IF;
2175 RETURN NULL;
2176 END;
2177 $$;
2179 CREATE TRIGGER "write_event_member_image_updated"
2180 AFTER INSERT OR UPDATE OR DELETE ON "member_image"
2181 FOR EACH ROW EXECUTE PROCEDURE
2182 "write_event_member_image_updated_trigger"();
2184 COMMENT ON FUNCTION "write_event_member_image_updated_trigger"() IS 'Implementation of trigger "write_event_member_image_updated" on table "member_image"';
2185 COMMENT ON TRIGGER "write_event_member_image_updated" ON "member_image" IS 'Creates entries in "event" table on member image update';
2188 CREATE FUNCTION "write_event_interest_trigger"()
2189 RETURNS TRIGGER
2190 LANGUAGE 'plpgsql' VOLATILE AS $$
2191 DECLARE
2192 "issue_row" "issue"%ROWTYPE;
2193 "area_row" "area"%ROWTYPE;
2194 BEGIN
2195 IF TG_OP = 'UPDATE' THEN
2196 IF OLD = NEW THEN
2197 RETURN NULL;
2198 END IF;
2199 END IF;
2200 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2201 SELECT * INTO "issue_row" FROM "issue"
2202 WHERE "id" = OLD."issue_id" FOR SHARE;
2203 SELECT * INTO "area_row" FROM "area"
2204 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2205 IF "issue_row"."id" NOTNULL THEN
2206 INSERT INTO "event" (
2207 "event", "member_id",
2208 "unit_id", "area_id", "policy_id", "issue_id", "state",
2209 "boolean_value"
2210 ) VALUES (
2211 'interest', OLD."member_id",
2212 "area_row"."unit_id", "issue_row"."area_id",
2213 "issue_row"."policy_id",
2214 OLD."issue_id", "issue_row"."state",
2215 FALSE
2216 );
2217 END IF;
2218 END IF;
2219 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2220 SELECT * INTO "issue_row" FROM "issue"
2221 WHERE "id" = NEW."issue_id" FOR SHARE;
2222 SELECT * INTO "area_row" FROM "area"
2223 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2224 INSERT INTO "event" (
2225 "event", "member_id",
2226 "unit_id", "area_id", "policy_id", "issue_id", "state",
2227 "boolean_value"
2228 ) VALUES (
2229 'interest', NEW."member_id",
2230 "area_row"."unit_id", "issue_row"."area_id",
2231 "issue_row"."policy_id",
2232 NEW."issue_id", "issue_row"."state",
2233 TRUE
2234 );
2235 END IF;
2236 RETURN NULL;
2237 END;
2238 $$;
2240 CREATE TRIGGER "write_event_interest"
2241 AFTER INSERT OR UPDATE OR DELETE ON "interest" FOR EACH ROW EXECUTE PROCEDURE
2242 "write_event_interest_trigger"();
2244 COMMENT ON FUNCTION "write_event_interest_trigger"() IS 'Implementation of trigger "write_event_interest_inserted" on table "interest"';
2245 COMMENT ON TRIGGER "write_event_interest" ON "interest" IS 'Create entry in "event" table on adding or removing interest';
2248 CREATE FUNCTION "write_event_initiator_trigger"()
2249 RETURNS TRIGGER
2250 LANGUAGE 'plpgsql' VOLATILE AS $$
2251 DECLARE
2252 "initiative_row" "initiative"%ROWTYPE;
2253 "issue_row" "issue"%ROWTYPE;
2254 "area_row" "area"%ROWTYPE;
2255 "accepted_v" BOOLEAN = FALSE;
2256 "rejected_v" BOOLEAN = FALSE;
2257 BEGIN
2258 IF TG_OP = 'UPDATE' THEN
2259 IF
2260 OLD."initiative_id" = NEW."initiative_id" AND
2261 OLD."member_id" = NEW."member_id"
2262 THEN
2263 IF
2264 coalesce(OLD."accepted", FALSE) = coalesce(NEW."accepted", FALSE)
2265 THEN
2266 RETURN NULL;
2267 END IF;
2268 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2269 "accepted_v" := TRUE;
2270 ELSE
2271 "rejected_v" := TRUE;
2272 END IF;
2273 END IF;
2274 END IF;
2275 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "accepted_v" THEN
2276 IF coalesce(OLD."accepted", FALSE) = TRUE THEN
2277 SELECT * INTO "initiative_row" FROM "initiative"
2278 WHERE "id" = OLD."initiative_id" FOR SHARE;
2279 IF "initiative_row"."id" NOTNULL THEN
2280 SELECT * INTO "issue_row" FROM "issue"
2281 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2282 SELECT * INTO "area_row" FROM "area"
2283 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2284 INSERT INTO "event" (
2285 "event", "member_id",
2286 "unit_id", "area_id", "policy_id", "issue_id", "state",
2287 "initiative_id", "boolean_value"
2288 ) VALUES (
2289 'initiator', OLD."member_id",
2290 "area_row"."unit_id", "issue_row"."area_id",
2291 "issue_row"."policy_id",
2292 "issue_row"."id", "issue_row"."state",
2293 OLD."initiative_id", FALSE
2294 );
2295 END IF;
2296 END IF;
2297 END IF;
2298 IF TG_OP = 'UPDATE' AND NOT "rejected_v" THEN
2299 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2300 SELECT * INTO "initiative_row" FROM "initiative"
2301 WHERE "id" = NEW."initiative_id" FOR SHARE;
2302 SELECT * INTO "issue_row" FROM "issue"
2303 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2304 SELECT * INTO "area_row" FROM "area"
2305 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2306 INSERT INTO "event" (
2307 "event", "member_id",
2308 "unit_id", "area_id", "policy_id", "issue_id", "state",
2309 "initiative_id", "boolean_value"
2310 ) VALUES (
2311 'initiator', NEW."member_id",
2312 "area_row"."unit_id", "issue_row"."area_id",
2313 "issue_row"."policy_id",
2314 "issue_row"."id", "issue_row"."state",
2315 NEW."initiative_id", TRUE
2316 );
2317 END IF;
2318 END IF;
2319 RETURN NULL;
2320 END;
2321 $$;
2323 CREATE TRIGGER "write_event_initiator"
2324 AFTER UPDATE OR DELETE ON "initiator" FOR EACH ROW EXECUTE PROCEDURE
2325 "write_event_initiator_trigger"();
2327 COMMENT ON FUNCTION "write_event_initiator_trigger"() IS 'Implementation of trigger "write_event_initiator" on table "initiator"';
2328 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)';
2331 CREATE FUNCTION "write_event_support_trigger"()
2332 RETURNS TRIGGER
2333 LANGUAGE 'plpgsql' VOLATILE AS $$
2334 DECLARE
2335 "issue_row" "issue"%ROWTYPE;
2336 "area_row" "area"%ROWTYPE;
2337 BEGIN
2338 IF TG_OP = 'UPDATE' THEN
2339 IF
2340 OLD."initiative_id" = NEW."initiative_id" AND
2341 OLD."member_id" = NEW."member_id"
2342 THEN
2343 IF OLD."draft_id" != NEW."draft_id" THEN
2344 SELECT * INTO "issue_row" FROM "issue"
2345 WHERE "id" = NEW."issue_id" FOR SHARE;
2346 SELECT * INTO "area_row" FROM "area"
2347 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2348 INSERT INTO "event" (
2349 "event", "member_id",
2350 "unit_id", "area_id", "policy_id", "issue_id", "state",
2351 "initiative_id", "draft_id"
2352 ) VALUES (
2353 'support_updated', NEW."member_id",
2354 "area_row"."unit_id", "issue_row"."area_id",
2355 "issue_row"."policy_id",
2356 "issue_row"."id", "issue_row"."state",
2357 NEW."initiative_id", NEW."draft_id"
2358 );
2359 END IF;
2360 RETURN NULL;
2361 END IF;
2362 END IF;
2363 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2364 IF EXISTS (
2365 SELECT NULL FROM "initiative" WHERE "id" = OLD."initiative_id"
2366 FOR SHARE
2367 ) THEN
2368 SELECT * INTO "issue_row" FROM "issue"
2369 WHERE "id" = OLD."issue_id" FOR SHARE;
2370 SELECT * INTO "area_row" FROM "area"
2371 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2372 INSERT INTO "event" (
2373 "event", "member_id",
2374 "unit_id", "area_id", "policy_id", "issue_id", "state",
2375 "initiative_id", "boolean_value"
2376 ) VALUES (
2377 'support', OLD."member_id",
2378 "area_row"."unit_id", "issue_row"."area_id",
2379 "issue_row"."policy_id",
2380 "issue_row"."id", "issue_row"."state",
2381 OLD."initiative_id", FALSE
2382 );
2383 END IF;
2384 END IF;
2385 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2386 SELECT * INTO "issue_row" FROM "issue"
2387 WHERE "id" = NEW."issue_id" FOR SHARE;
2388 SELECT * INTO "area_row" FROM "area"
2389 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2390 INSERT INTO "event" (
2391 "event", "member_id",
2392 "unit_id", "area_id", "policy_id", "issue_id", "state",
2393 "initiative_id", "draft_id", "boolean_value"
2394 ) VALUES (
2395 'support', NEW."member_id",
2396 "area_row"."unit_id", "issue_row"."area_id",
2397 "issue_row"."policy_id",
2398 "issue_row"."id", "issue_row"."state",
2399 NEW."initiative_id", NEW."draft_id", TRUE
2400 );
2401 END IF;
2402 RETURN NULL;
2403 END;
2404 $$;
2406 CREATE TRIGGER "write_event_support"
2407 AFTER INSERT OR UPDATE OR DELETE ON "supporter" FOR EACH ROW EXECUTE PROCEDURE
2408 "write_event_support_trigger"();
2410 COMMENT ON FUNCTION "write_event_support_trigger"() IS 'Implementation of trigger "write_event_support" on table "supporter"';
2411 COMMENT ON TRIGGER "write_event_support" ON "supporter" IS 'Create entry in "event" table when adding, updating, or removing support';
2414 CREATE FUNCTION "write_event_suggestion_rated_trigger"()
2415 RETURNS TRIGGER
2416 LANGUAGE 'plpgsql' VOLATILE AS $$
2417 DECLARE
2418 "same_pkey_v" BOOLEAN = FALSE;
2419 "initiative_row" "initiative"%ROWTYPE;
2420 "issue_row" "issue"%ROWTYPE;
2421 "area_row" "area"%ROWTYPE;
2422 BEGIN
2423 IF TG_OP = 'UPDATE' THEN
2424 IF
2425 OLD."suggestion_id" = NEW."suggestion_id" AND
2426 OLD."member_id" = NEW."member_id"
2427 THEN
2428 IF
2429 OLD."degree" = NEW."degree" AND
2430 OLD."fulfilled" = NEW."fulfilled"
2431 THEN
2432 RETURN NULL;
2433 END IF;
2434 "same_pkey_v" := TRUE;
2435 END IF;
2436 END IF;
2437 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "same_pkey_v" THEN
2438 IF EXISTS (
2439 SELECT NULL FROM "suggestion" WHERE "id" = OLD."suggestion_id"
2440 FOR SHARE
2441 ) THEN
2442 SELECT * INTO "initiative_row" FROM "initiative"
2443 WHERE "id" = OLD."initiative_id" FOR SHARE;
2444 SELECT * INTO "issue_row" FROM "issue"
2445 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2446 SELECT * INTO "area_row" FROM "area"
2447 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2448 INSERT INTO "event" (
2449 "event", "member_id",
2450 "unit_id", "area_id", "policy_id", "issue_id", "state",
2451 "initiative_id", "suggestion_id",
2452 "boolean_value", "numeric_value"
2453 ) VALUES (
2454 'suggestion_rated', OLD."member_id",
2455 "area_row"."unit_id", "issue_row"."area_id",
2456 "issue_row"."policy_id",
2457 "initiative_row"."issue_id", "issue_row"."state",
2458 OLD."initiative_id", OLD."suggestion_id",
2459 NULL, 0
2460 );
2461 END IF;
2462 END IF;
2463 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2464 SELECT * INTO "initiative_row" FROM "initiative"
2465 WHERE "id" = NEW."initiative_id" FOR SHARE;
2466 SELECT * INTO "issue_row" FROM "issue"
2467 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2468 SELECT * INTO "area_row" FROM "area"
2469 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2470 INSERT INTO "event" (
2471 "event", "member_id",
2472 "unit_id", "area_id", "policy_id", "issue_id", "state",
2473 "initiative_id", "suggestion_id",
2474 "boolean_value", "numeric_value"
2475 ) VALUES (
2476 'suggestion_rated', NEW."member_id",
2477 "area_row"."unit_id", "issue_row"."area_id",
2478 "issue_row"."policy_id",
2479 "initiative_row"."issue_id", "issue_row"."state",
2480 NEW."initiative_id", NEW."suggestion_id",
2481 NEW."fulfilled", NEW."degree"
2482 );
2483 END IF;
2484 RETURN NULL;
2485 END;
2486 $$;
2488 CREATE TRIGGER "write_event_suggestion_rated"
2489 AFTER INSERT OR UPDATE OR DELETE ON "opinion" FOR EACH ROW EXECUTE PROCEDURE
2490 "write_event_suggestion_rated_trigger"();
2492 COMMENT ON FUNCTION "write_event_suggestion_rated_trigger"() IS 'Implementation of trigger "write_event_suggestion_rated" on table "opinion"';
2493 COMMENT ON TRIGGER "write_event_suggestion_rated" ON "opinion" IS 'Create entry in "event" table when adding, updating, or removing support';
2496 CREATE FUNCTION "write_event_delegation_trigger"()
2497 RETURNS TRIGGER
2498 LANGUAGE 'plpgsql' VOLATILE AS $$
2499 DECLARE
2500 "issue_row" "issue"%ROWTYPE;
2501 "area_row" "area"%ROWTYPE;
2502 BEGIN
2503 IF TG_OP = 'DELETE' THEN
2504 IF EXISTS (
2505 SELECT NULL FROM "member" WHERE "id" = OLD."truster_id"
2506 ) AND (CASE OLD."scope"
2507 WHEN 'unit'::"delegation_scope" THEN EXISTS (
2508 SELECT NULL FROM "unit" WHERE "id" = OLD."unit_id"
2510 WHEN 'area'::"delegation_scope" THEN EXISTS (
2511 SELECT NULL FROM "area" WHERE "id" = OLD."area_id"
2513 WHEN 'issue'::"delegation_scope" THEN EXISTS (
2514 SELECT NULL FROM "issue" WHERE "id" = OLD."issue_id"
2516 END) THEN
2517 SELECT * INTO "issue_row" FROM "issue"
2518 WHERE "id" = OLD."issue_id" FOR SHARE;
2519 SELECT * INTO "area_row" FROM "area"
2520 WHERE "id" = COALESCE(OLD."area_id", "issue_row"."area_id")
2521 FOR SHARE;
2522 INSERT INTO "event" (
2523 "event", "member_id", "scope",
2524 "unit_id", "area_id", "issue_id", "state",
2525 "boolean_value"
2526 ) VALUES (
2527 'delegation', OLD."truster_id", OLD."scope",
2528 COALESCE(OLD."unit_id", "area_row"."unit_id"), "area_row"."id",
2529 OLD."issue_id", "issue_row"."state",
2530 FALSE
2531 );
2532 END IF;
2533 ELSE
2534 SELECT * INTO "issue_row" FROM "issue"
2535 WHERE "id" = NEW."issue_id" FOR SHARE;
2536 SELECT * INTO "area_row" FROM "area"
2537 WHERE "id" = COALESCE(NEW."area_id", "issue_row"."area_id")
2538 FOR SHARE;
2539 INSERT INTO "event" (
2540 "event", "member_id", "other_member_id", "scope",
2541 "unit_id", "area_id", "issue_id", "state",
2542 "boolean_value"
2543 ) VALUES (
2544 'delegation', NEW."truster_id", NEW."trustee_id", NEW."scope",
2545 COALESCE(NEW."unit_id", "area_row"."unit_id"), "area_row"."id",
2546 NEW."issue_id", "issue_row"."state",
2547 TRUE
2548 );
2549 END IF;
2550 RETURN NULL;
2551 END;
2552 $$;
2554 CREATE TRIGGER "write_event_delegation"
2555 AFTER INSERT OR UPDATE OR DELETE ON "delegation" FOR EACH ROW EXECUTE PROCEDURE
2556 "write_event_delegation_trigger"();
2558 COMMENT ON FUNCTION "write_event_delegation_trigger"() IS 'Implementation of trigger "write_event_delegation" on table "delegation"';
2559 COMMENT ON TRIGGER "write_event_delegation" ON "delegation" IS 'Create entry in "event" table when adding, updating, or removing a delegation';
2562 CREATE FUNCTION "write_event_contact_trigger"()
2563 RETURNS TRIGGER
2564 LANGUAGE 'plpgsql' VOLATILE AS $$
2565 BEGIN
2566 IF TG_OP = 'UPDATE' THEN
2567 IF
2568 OLD."member_id" = NEW."member_id" AND
2569 OLD."other_member_id" = NEW."other_member_id" AND
2570 OLD."public" = NEW."public"
2571 THEN
2572 RETURN NULL;
2573 END IF;
2574 END IF;
2575 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2576 IF OLD."public" THEN
2577 IF EXISTS (
2578 SELECT NULL FROM "member" WHERE "id" = OLD."member_id"
2579 FOR SHARE
2580 ) AND EXISTS (
2581 SELECT NULL FROM "member" WHERE "id" = OLD."other_member_id"
2582 FOR SHARE
2583 ) THEN
2584 INSERT INTO "event" (
2585 "event", "member_id", "other_member_id", "boolean_value"
2586 ) VALUES (
2587 'contact', OLD."member_id", OLD."other_member_id", FALSE
2588 );
2589 END IF;
2590 END IF;
2591 END IF;
2592 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2593 IF NEW."public" THEN
2594 INSERT INTO "event" (
2595 "event", "member_id", "other_member_id", "boolean_value"
2596 ) VALUES (
2597 'contact', NEW."member_id", NEW."other_member_id", TRUE
2598 );
2599 END IF;
2600 END IF;
2601 RETURN NULL;
2602 END;
2603 $$;
2605 CREATE TRIGGER "write_event_contact"
2606 AFTER INSERT OR UPDATE OR DELETE ON "contact" FOR EACH ROW EXECUTE PROCEDURE
2607 "write_event_contact_trigger"();
2609 COMMENT ON FUNCTION "write_event_contact_trigger"() IS 'Implementation of trigger "write_event_contact" on table "contact"';
2610 COMMENT ON TRIGGER "write_event_contact" ON "contact" IS 'Create entry in "event" table when adding or removing public contacts';
2613 CREATE FUNCTION "send_event_notify_trigger"()
2614 RETURNS TRIGGER
2615 LANGUAGE 'plpgsql' VOLATILE AS $$
2616 BEGIN
2617 EXECUTE 'NOTIFY "event", ''' || NEW."event" || '''';
2618 RETURN NULL;
2619 END;
2620 $$;
2622 CREATE TRIGGER "send_notify"
2623 AFTER INSERT OR UPDATE ON "event" FOR EACH ROW EXECUTE PROCEDURE
2624 "send_event_notify_trigger"();
2628 ----------------------------
2629 -- Additional constraints --
2630 ----------------------------
2633 CREATE FUNCTION "delete_extended_scope_tokens_trigger"()
2634 RETURNS TRIGGER
2635 LANGUAGE 'plpgsql' VOLATILE AS $$
2636 DECLARE
2637 "system_application_row" "system_application"%ROWTYPE;
2638 BEGIN
2639 IF OLD."system_application_id" NOTNULL THEN
2640 SELECT * FROM "system_application" INTO "system_application_row"
2641 WHERE "id" = OLD."system_application_id";
2642 DELETE FROM "token"
2643 WHERE "member_id" = OLD."member_id"
2644 AND "system_application_id" = OLD."system_application_id"
2645 AND NOT COALESCE(
2646 regexp_split_to_array("scope", E'\\s+') <@
2647 regexp_split_to_array(
2648 "system_application_row"."automatic_scope", E'\\s+'
2649 ),
2650 FALSE
2651 );
2652 END IF;
2653 RETURN OLD;
2654 END;
2655 $$;
2657 CREATE TRIGGER "delete_extended_scope_tokens"
2658 BEFORE DELETE ON "member_application" FOR EACH ROW EXECUTE PROCEDURE
2659 "delete_extended_scope_tokens_trigger"();
2662 CREATE FUNCTION "detach_token_from_session_trigger"()
2663 RETURNS TRIGGER
2664 LANGUAGE 'plpgsql' VOLATILE AS $$
2665 BEGIN
2666 UPDATE "token" SET "session_id" = NULL
2667 WHERE "session_id" = OLD."id";
2668 RETURN OLD;
2669 END;
2670 $$;
2672 CREATE TRIGGER "detach_token_from_session"
2673 BEFORE DELETE ON "session" FOR EACH ROW EXECUTE PROCEDURE
2674 "detach_token_from_session_trigger"();
2677 CREATE FUNCTION "delete_non_detached_scope_with_session_trigger"()
2678 RETURNS TRIGGER
2679 LANGUAGE 'plpgsql' VOLATILE AS $$
2680 BEGIN
2681 IF NEW."session_id" ISNULL THEN
2682 SELECT coalesce(string_agg("element", ' '), '') INTO NEW."scope"
2683 FROM unnest(regexp_split_to_array(NEW."scope", E'\\s+')) AS "element"
2684 WHERE "element" LIKE '%_detached';
2685 END IF;
2686 RETURN NEW;
2687 END;
2688 $$;
2690 CREATE TRIGGER "delete_non_detached_scope_with_session"
2691 BEFORE INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2692 "delete_non_detached_scope_with_session_trigger"();
2695 CREATE FUNCTION "delete_token_with_empty_scope_trigger"()
2696 RETURNS TRIGGER
2697 LANGUAGE 'plpgsql' VOLATILE AS $$
2698 BEGIN
2699 IF NEW."scope" = '' THEN
2700 DELETE FROM "token" WHERE "id" = NEW."id";
2701 END IF;
2702 RETURN NULL;
2703 END;
2704 $$;
2706 CREATE TRIGGER "delete_token_with_empty_scope"
2707 AFTER INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2708 "delete_token_with_empty_scope_trigger"();
2711 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
2712 RETURNS TRIGGER
2713 LANGUAGE 'plpgsql' VOLATILE AS $$
2714 BEGIN
2715 IF NOT EXISTS (
2716 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
2717 ) THEN
2718 RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING
2719 ERRCODE = 'integrity_constraint_violation',
2720 HINT = 'Create issue, initiative, and draft within the same transaction.';
2721 END IF;
2722 RETURN NULL;
2723 END;
2724 $$;
2726 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
2727 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
2728 FOR EACH ROW EXECUTE PROCEDURE
2729 "issue_requires_first_initiative_trigger"();
2731 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
2732 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
2735 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
2736 RETURNS TRIGGER
2737 LANGUAGE 'plpgsql' VOLATILE AS $$
2738 DECLARE
2739 "reference_lost" BOOLEAN;
2740 BEGIN
2741 IF TG_OP = 'DELETE' THEN
2742 "reference_lost" := TRUE;
2743 ELSE
2744 "reference_lost" := NEW."issue_id" != OLD."issue_id";
2745 END IF;
2746 IF
2747 "reference_lost" AND NOT EXISTS (
2748 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
2750 THEN
2751 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
2752 END IF;
2753 RETURN NULL;
2754 END;
2755 $$;
2757 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
2758 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
2759 FOR EACH ROW EXECUTE PROCEDURE
2760 "last_initiative_deletes_issue_trigger"();
2762 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
2763 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
2766 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
2767 RETURNS TRIGGER
2768 LANGUAGE 'plpgsql' VOLATILE AS $$
2769 BEGIN
2770 IF NOT EXISTS (
2771 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
2772 ) THEN
2773 RAISE EXCEPTION 'Cannot create initiative without an initial draft.' 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 "initiative_requires_first_draft"
2782 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
2783 FOR EACH ROW EXECUTE PROCEDURE
2784 "initiative_requires_first_draft_trigger"();
2786 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
2787 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
2790 CREATE FUNCTION "last_draft_deletes_initiative_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."initiative_id" != OLD."initiative_id";
2800 END IF;
2801 IF
2802 "reference_lost" AND NOT EXISTS (
2803 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
2805 THEN
2806 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
2807 END IF;
2808 RETURN NULL;
2809 END;
2810 $$;
2812 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
2813 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
2814 FOR EACH ROW EXECUTE PROCEDURE
2815 "last_draft_deletes_initiative_trigger"();
2817 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
2818 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
2821 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
2822 RETURNS TRIGGER
2823 LANGUAGE 'plpgsql' VOLATILE AS $$
2824 BEGIN
2825 IF NOT EXISTS (
2826 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
2827 ) THEN
2828 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING
2829 ERRCODE = 'integrity_constraint_violation',
2830 HINT = 'Create suggestion and opinion within the same transaction.';
2831 END IF;
2832 RETURN NULL;
2833 END;
2834 $$;
2836 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
2837 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
2838 FOR EACH ROW EXECUTE PROCEDURE
2839 "suggestion_requires_first_opinion_trigger"();
2841 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
2842 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
2845 CREATE FUNCTION "last_opinion_deletes_suggestion_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."suggestion_id" != OLD."suggestion_id";
2855 END IF;
2856 IF
2857 "reference_lost" AND NOT EXISTS (
2858 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
2860 THEN
2861 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
2862 END IF;
2863 RETURN NULL;
2864 END;
2865 $$;
2867 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
2868 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
2869 FOR EACH ROW EXECUTE PROCEDURE
2870 "last_opinion_deletes_suggestion_trigger"();
2872 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
2873 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
2876 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
2877 RETURNS TRIGGER
2878 LANGUAGE 'plpgsql' VOLATILE AS $$
2879 BEGIN
2880 DELETE FROM "direct_voter"
2881 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
2882 RETURN NULL;
2883 END;
2884 $$;
2886 CREATE TRIGGER "non_voter_deletes_direct_voter"
2887 AFTER INSERT OR UPDATE ON "non_voter"
2888 FOR EACH ROW EXECUTE PROCEDURE
2889 "non_voter_deletes_direct_voter_trigger"();
2891 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
2892 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")';
2895 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
2896 RETURNS TRIGGER
2897 LANGUAGE 'plpgsql' VOLATILE AS $$
2898 BEGIN
2899 DELETE FROM "non_voter"
2900 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
2901 RETURN NULL;
2902 END;
2903 $$;
2905 CREATE TRIGGER "direct_voter_deletes_non_voter"
2906 AFTER INSERT OR UPDATE ON "direct_voter"
2907 FOR EACH ROW EXECUTE PROCEDURE
2908 "direct_voter_deletes_non_voter_trigger"();
2910 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
2911 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")';
2914 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
2915 RETURNS TRIGGER
2916 LANGUAGE 'plpgsql' VOLATILE AS $$
2917 BEGIN
2918 IF NEW."comment" ISNULL THEN
2919 NEW."comment_changed" := NULL;
2920 NEW."formatting_engine" := NULL;
2921 END IF;
2922 RETURN NEW;
2923 END;
2924 $$;
2926 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
2927 BEFORE INSERT OR UPDATE ON "direct_voter"
2928 FOR EACH ROW EXECUTE PROCEDURE
2929 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
2931 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"';
2932 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.';
2936 ---------------------------------
2937 -- Delete incomplete snapshots --
2938 ---------------------------------
2941 CREATE FUNCTION "delete_snapshot_on_partial_delete_trigger"()
2942 RETURNS TRIGGER
2943 LANGUAGE 'plpgsql' VOLATILE AS $$
2944 BEGIN
2945 IF TG_OP = 'UPDATE' THEN
2946 IF
2947 OLD."snapshot_id" = NEW."snapshot_id" AND
2948 OLD."issue_id" = NEW."issue_id"
2949 THEN
2950 RETURN NULL;
2951 END IF;
2952 END IF;
2953 DELETE FROM "snapshot" WHERE "id" = OLD."snapshot_id";
2954 RETURN NULL;
2955 END;
2956 $$;
2958 CREATE TRIGGER "delete_snapshot_on_partial_delete"
2959 AFTER UPDATE OR DELETE ON "snapshot_issue"
2960 FOR EACH ROW EXECUTE PROCEDURE
2961 "delete_snapshot_on_partial_delete_trigger"();
2963 COMMENT ON FUNCTION "delete_snapshot_on_partial_delete_trigger"() IS 'Implementation of trigger "delete_snapshot_on_partial_delete" on table "snapshot_issue"';
2964 COMMENT ON TRIGGER "delete_snapshot_on_partial_delete" ON "snapshot_issue" IS 'Deletes whole snapshot if one issue is deleted from the snapshot';
2968 ---------------------------------------------------------------
2969 -- Ensure that votes are not modified when issues are closed --
2970 ---------------------------------------------------------------
2972 -- NOTE: Frontends should ensure this anyway, but in case of programming
2973 -- errors the following triggers ensure data integrity.
2976 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
2977 RETURNS TRIGGER
2978 LANGUAGE 'plpgsql' VOLATILE AS $$
2979 DECLARE
2980 "issue_id_v" "issue"."id"%TYPE;
2981 "issue_row" "issue"%ROWTYPE;
2982 BEGIN
2983 IF EXISTS (
2984 SELECT NULL FROM "temporary_transaction_data"
2985 WHERE "txid" = txid_current()
2986 AND "key" = 'override_protection_triggers'
2987 AND "value" = TRUE::TEXT
2988 ) THEN
2989 RETURN NULL;
2990 END IF;
2991 IF TG_OP = 'DELETE' THEN
2992 "issue_id_v" := OLD."issue_id";
2993 ELSE
2994 "issue_id_v" := NEW."issue_id";
2995 END IF;
2996 SELECT INTO "issue_row" * FROM "issue"
2997 WHERE "id" = "issue_id_v" FOR SHARE;
2998 IF (
2999 "issue_row"."closed" NOTNULL OR (
3000 "issue_row"."state" = 'voting' AND
3001 "issue_row"."phase_finished" NOTNULL
3003 ) THEN
3004 IF
3005 TG_RELID = 'direct_voter'::regclass AND
3006 TG_OP = 'UPDATE'
3007 THEN
3008 IF
3009 OLD."issue_id" = NEW."issue_id" AND
3010 OLD."member_id" = NEW."member_id" AND
3011 OLD."weight" = NEW."weight"
3012 THEN
3013 RETURN NULL; -- allows changing of voter comment
3014 END IF;
3015 END IF;
3016 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
3017 ERRCODE = 'integrity_constraint_violation';
3018 END IF;
3019 RETURN NULL;
3020 END;
3021 $$;
3023 CREATE TRIGGER "forbid_changes_on_closed_issue"
3024 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
3025 FOR EACH ROW EXECUTE PROCEDURE
3026 "forbid_changes_on_closed_issue_trigger"();
3028 CREATE TRIGGER "forbid_changes_on_closed_issue"
3029 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
3030 FOR EACH ROW EXECUTE PROCEDURE
3031 "forbid_changes_on_closed_issue_trigger"();
3033 CREATE TRIGGER "forbid_changes_on_closed_issue"
3034 AFTER INSERT OR UPDATE OR DELETE ON "vote"
3035 FOR EACH ROW EXECUTE PROCEDURE
3036 "forbid_changes_on_closed_issue_trigger"();
3038 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"';
3039 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';
3040 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';
3041 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';
3045 --------------------------------------------------------------------
3046 -- Auto-retrieval of fields only needed for referential integrity --
3047 --------------------------------------------------------------------
3050 CREATE FUNCTION "autofill_issue_id_trigger"()
3051 RETURNS TRIGGER
3052 LANGUAGE 'plpgsql' VOLATILE AS $$
3053 BEGIN
3054 IF NEW."issue_id" ISNULL THEN
3055 SELECT "issue_id" INTO NEW."issue_id"
3056 FROM "initiative" WHERE "id" = NEW."initiative_id";
3057 END IF;
3058 RETURN NEW;
3059 END;
3060 $$;
3062 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
3063 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3065 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
3066 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3068 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
3069 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
3070 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
3073 CREATE FUNCTION "autofill_initiative_id_trigger"()
3074 RETURNS TRIGGER
3075 LANGUAGE 'plpgsql' VOLATILE AS $$
3076 BEGIN
3077 IF NEW."initiative_id" ISNULL THEN
3078 SELECT "initiative_id" INTO NEW."initiative_id"
3079 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3080 END IF;
3081 RETURN NEW;
3082 END;
3083 $$;
3085 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
3086 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
3088 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
3089 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
3093 -------------------------------------------------------
3094 -- Automatic copying of values for indexing purposes --
3095 -------------------------------------------------------
3098 CREATE FUNCTION "copy_current_draft_data"
3099 ("initiative_id_p" "initiative"."id"%TYPE )
3100 RETURNS VOID
3101 LANGUAGE 'plpgsql' VOLATILE AS $$
3102 BEGIN
3103 PERFORM NULL FROM "initiative" WHERE "id" = "initiative_id_p"
3104 FOR UPDATE;
3105 UPDATE "initiative" SET
3106 "location" = "draft"."location",
3107 "draft_text_search_data" = "draft"."text_search_data"
3108 FROM "current_draft" AS "draft"
3109 WHERE "initiative"."id" = "initiative_id_p"
3110 AND "draft"."initiative_id" = "initiative_id_p";
3111 END;
3112 $$;
3114 COMMENT ON FUNCTION "copy_current_draft_data"
3115 ( "initiative"."id"%TYPE )
3116 IS 'Helper function for function "copy_current_draft_data_trigger"';
3119 CREATE FUNCTION "copy_current_draft_data_trigger"()
3120 RETURNS TRIGGER
3121 LANGUAGE 'plpgsql' VOLATILE AS $$
3122 BEGIN
3123 IF TG_OP='DELETE' THEN
3124 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3125 ELSE
3126 IF TG_OP='UPDATE' THEN
3127 IF COALESCE(OLD."inititiave_id" != NEW."initiative_id", TRUE) THEN
3128 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3129 END IF;
3130 END IF;
3131 PERFORM "copy_current_draft_data"(NEW."initiative_id");
3132 END IF;
3133 RETURN NULL;
3134 END;
3135 $$;
3137 CREATE TRIGGER "copy_current_draft_data"
3138 AFTER INSERT OR UPDATE OR DELETE ON "draft"
3139 FOR EACH ROW EXECUTE PROCEDURE
3140 "copy_current_draft_data_trigger"();
3142 COMMENT ON FUNCTION "copy_current_draft_data_trigger"() IS 'Implementation of trigger "copy_current_draft_data" on table "draft"';
3143 COMMENT ON TRIGGER "copy_current_draft_data" ON "draft" IS 'Copy certain fields from most recent "draft" to "initiative"';
3147 -----------------------------------------------------
3148 -- Automatic calculation of certain default values --
3149 -----------------------------------------------------
3152 CREATE FUNCTION "copy_timings_trigger"()
3153 RETURNS TRIGGER
3154 LANGUAGE 'plpgsql' VOLATILE AS $$
3155 DECLARE
3156 "policy_row" "policy"%ROWTYPE;
3157 BEGIN
3158 SELECT * INTO "policy_row" FROM "policy"
3159 WHERE "id" = NEW."policy_id";
3160 IF NEW."min_admission_time" ISNULL THEN
3161 NEW."min_admission_time" := "policy_row"."min_admission_time";
3162 END IF;
3163 IF NEW."max_admission_time" ISNULL THEN
3164 NEW."max_admission_time" := "policy_row"."max_admission_time";
3165 END IF;
3166 IF NEW."discussion_time" ISNULL THEN
3167 NEW."discussion_time" := "policy_row"."discussion_time";
3168 END IF;
3169 IF NEW."verification_time" ISNULL THEN
3170 NEW."verification_time" := "policy_row"."verification_time";
3171 END IF;
3172 IF NEW."voting_time" ISNULL THEN
3173 NEW."voting_time" := "policy_row"."voting_time";
3174 END IF;
3175 RETURN NEW;
3176 END;
3177 $$;
3179 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
3180 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
3182 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
3183 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
3186 CREATE FUNCTION "default_for_draft_id_trigger"()
3187 RETURNS TRIGGER
3188 LANGUAGE 'plpgsql' VOLATILE AS $$
3189 BEGIN
3190 IF NEW."draft_id" ISNULL THEN
3191 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
3192 WHERE "initiative_id" = NEW."initiative_id";
3193 END IF;
3194 RETURN NEW;
3195 END;
3196 $$;
3198 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
3199 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3200 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
3201 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3203 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
3204 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';
3205 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';
3209 ----------------------------------------
3210 -- Automatic creation of dependencies --
3211 ----------------------------------------
3214 CREATE FUNCTION "autocreate_interest_trigger"()
3215 RETURNS TRIGGER
3216 LANGUAGE 'plpgsql' VOLATILE AS $$
3217 BEGIN
3218 IF NOT EXISTS (
3219 SELECT NULL FROM "initiative" JOIN "interest"
3220 ON "initiative"."issue_id" = "interest"."issue_id"
3221 WHERE "initiative"."id" = NEW."initiative_id"
3222 AND "interest"."member_id" = NEW."member_id"
3223 ) THEN
3224 BEGIN
3225 INSERT INTO "interest" ("issue_id", "member_id")
3226 SELECT "issue_id", NEW."member_id"
3227 FROM "initiative" WHERE "id" = NEW."initiative_id";
3228 EXCEPTION WHEN unique_violation THEN END;
3229 END IF;
3230 RETURN NEW;
3231 END;
3232 $$;
3234 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
3235 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
3237 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
3238 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';
3241 CREATE FUNCTION "autocreate_supporter_trigger"()
3242 RETURNS TRIGGER
3243 LANGUAGE 'plpgsql' VOLATILE AS $$
3244 BEGIN
3245 IF NOT EXISTS (
3246 SELECT NULL FROM "suggestion" JOIN "supporter"
3247 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
3248 WHERE "suggestion"."id" = NEW."suggestion_id"
3249 AND "supporter"."member_id" = NEW."member_id"
3250 ) THEN
3251 BEGIN
3252 INSERT INTO "supporter" ("initiative_id", "member_id")
3253 SELECT "initiative_id", NEW."member_id"
3254 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3255 EXCEPTION WHEN unique_violation THEN END;
3256 END IF;
3257 RETURN NEW;
3258 END;
3259 $$;
3261 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
3262 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
3264 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
3265 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.';
3269 ------------------------------------------
3270 -- Views and helper functions for views --
3271 ------------------------------------------
3274 CREATE VIEW "member_eligible_to_be_notified" AS
3275 SELECT * FROM "member"
3276 WHERE "activated" NOTNULL AND "locked" = FALSE;
3278 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")';
3281 CREATE VIEW "member_to_notify" AS
3282 SELECT * FROM "member_eligible_to_be_notified"
3283 WHERE "disable_notifications" = FALSE;
3285 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)';
3288 CREATE VIEW "area_quorum" AS
3289 SELECT
3290 "area"."id" AS "area_id",
3291 ceil(
3292 "area"."quorum_standard"::FLOAT8 * "quorum_factor"::FLOAT8 ^ (
3293 coalesce(
3294 ( SELECT sum(
3295 ( extract(epoch from "area"."quorum_time")::FLOAT8 /
3296 extract(epoch from
3297 ("issue"."accepted"-"issue"."created") +
3298 "issue"."discussion_time" +
3299 "issue"."verification_time" +
3300 "issue"."voting_time"
3301 )::FLOAT8
3302 ) ^ "area"."quorum_exponent"::FLOAT8
3304 FROM "issue" JOIN "policy"
3305 ON "issue"."policy_id" = "policy"."id"
3306 WHERE "issue"."area_id" = "area"."id"
3307 AND "issue"."accepted" NOTNULL
3308 AND "issue"."closed" ISNULL
3309 AND "policy"."polling" = FALSE
3310 )::FLOAT8, 0::FLOAT8
3311 ) / "area"."quorum_issues"::FLOAT8 - 1::FLOAT8
3312 ) * CASE WHEN "area"."quorum_den" ISNULL THEN 1 ELSE (
3313 SELECT "snapshot"."population"
3314 FROM "snapshot"
3315 WHERE "snapshot"."area_id" = "area"."id"
3316 AND "snapshot"."issue_id" ISNULL
3317 ORDER BY "snapshot"."id" DESC
3318 LIMIT 1
3319 ) END / coalesce("area"."quorum_den", 1)
3321 )::INT4 AS "issue_quorum"
3322 FROM "area";
3324 COMMENT ON VIEW "area_quorum" IS 'Area-based quorum considering number of open (accepted) issues';
3327 CREATE VIEW "area_with_unaccepted_issues" AS
3328 SELECT DISTINCT ON ("area"."id") "area".*
3329 FROM "area" JOIN "issue" ON "area"."id" = "issue"."area_id"
3330 WHERE "issue"."state" = 'admission';
3332 COMMENT ON VIEW "area_with_unaccepted_issues" IS 'All areas with unaccepted open issues (needed for issue admission system)';
3335 CREATE VIEW "issue_for_admission" AS
3336 SELECT DISTINCT ON ("issue"."area_id")
3337 "issue".*,
3338 max("initiative"."supporter_count") AS "max_supporter_count"
3339 FROM "issue"
3340 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
3341 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
3342 JOIN "area" ON "issue"."area_id" = "area"."id"
3343 WHERE "issue"."state" = 'admission'::"issue_state"
3344 AND now() >= "issue"."created" + "issue"."min_admission_time"
3345 AND "initiative"."supporter_count" >= "policy"."issue_quorum"
3346 AND "initiative"."supporter_count" * "policy"."issue_quorum_den" >=
3347 "issue"."population" * "policy"."issue_quorum_num"
3348 AND "initiative"."supporter_count" >= "area"."issue_quorum"
3349 AND "initiative"."revoked" ISNULL
3350 GROUP BY "issue"."id"
3351 ORDER BY "issue"."area_id", "max_supporter_count" DESC, "issue"."id";
3353 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';
3356 CREATE VIEW "unit_delegation" AS
3357 SELECT
3358 "unit"."id" AS "unit_id",
3359 "delegation"."id",
3360 "delegation"."truster_id",
3361 "delegation"."trustee_id",
3362 "delegation"."scope"
3363 FROM "unit"
3364 JOIN "delegation"
3365 ON "delegation"."unit_id" = "unit"."id"
3366 JOIN "member"
3367 ON "delegation"."truster_id" = "member"."id"
3368 JOIN "privilege"
3369 ON "delegation"."unit_id" = "privilege"."unit_id"
3370 AND "delegation"."truster_id" = "privilege"."member_id"
3371 WHERE "member"."active" AND "privilege"."voting_right";
3373 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
3376 CREATE VIEW "area_delegation" AS
3377 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
3378 "area"."id" AS "area_id",
3379 "delegation"."id",
3380 "delegation"."truster_id",
3381 "delegation"."trustee_id",
3382 "delegation"."scope"
3383 FROM "area"
3384 JOIN "delegation"
3385 ON "delegation"."unit_id" = "area"."unit_id"
3386 OR "delegation"."area_id" = "area"."id"
3387 JOIN "member"
3388 ON "delegation"."truster_id" = "member"."id"
3389 JOIN "privilege"
3390 ON "area"."unit_id" = "privilege"."unit_id"
3391 AND "delegation"."truster_id" = "privilege"."member_id"
3392 WHERE "member"."active" AND "privilege"."voting_right"
3393 ORDER BY
3394 "area"."id",
3395 "delegation"."truster_id",
3396 "delegation"."scope" DESC;
3398 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
3401 CREATE VIEW "issue_delegation" AS
3402 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
3403 "issue"."id" AS "issue_id",
3404 "delegation"."id",
3405 "delegation"."truster_id",
3406 "delegation"."trustee_id",
3407 "delegation"."scope"
3408 FROM "issue"
3409 JOIN "area"
3410 ON "area"."id" = "issue"."area_id"
3411 JOIN "delegation"
3412 ON "delegation"."unit_id" = "area"."unit_id"
3413 OR "delegation"."area_id" = "area"."id"
3414 OR "delegation"."issue_id" = "issue"."id"
3415 JOIN "member"
3416 ON "delegation"."truster_id" = "member"."id"
3417 JOIN "privilege"
3418 ON "area"."unit_id" = "privilege"."unit_id"
3419 AND "delegation"."truster_id" = "privilege"."member_id"
3420 WHERE "member"."active" AND "privilege"."voting_right"
3421 ORDER BY
3422 "issue"."id",
3423 "delegation"."truster_id",
3424 "delegation"."scope" DESC;
3426 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
3429 CREATE VIEW "member_count_view" AS
3430 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
3432 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
3435 CREATE VIEW "unit_member" AS
3436 SELECT
3437 "unit"."id" AS "unit_id",
3438 "member"."id" AS "member_id"
3439 FROM "privilege"
3440 JOIN "unit" ON "unit_id" = "privilege"."unit_id"
3441 JOIN "member" ON "member"."id" = "privilege"."member_id"
3442 WHERE "privilege"."voting_right" AND "member"."active";
3444 COMMENT ON VIEW "unit_member" IS 'Active members with voting right in a unit';
3447 CREATE VIEW "unit_member_count" AS
3448 SELECT
3449 "unit"."id" AS "unit_id",
3450 count("unit_member"."member_id") AS "member_count"
3451 FROM "unit" LEFT JOIN "unit_member"
3452 ON "unit"."id" = "unit_member"."unit_id"
3453 GROUP BY "unit"."id";
3455 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
3458 CREATE VIEW "opening_draft" AS
3459 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3460 ORDER BY "initiative_id", "id";
3462 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
3465 CREATE VIEW "current_draft" AS
3466 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3467 ORDER BY "initiative_id", "id" DESC;
3469 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
3472 CREATE VIEW "critical_opinion" AS
3473 SELECT * FROM "opinion"
3474 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
3475 OR ("degree" = -2 AND "fulfilled" = TRUE);
3477 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
3480 CREATE VIEW "issue_supporter_in_admission_state" AS
3481 SELECT
3482 "area"."unit_id",
3483 "issue"."area_id",
3484 "issue"."id" AS "issue_id",
3485 "supporter"."member_id",
3486 "direct_interest_snapshot"."weight"
3487 FROM "issue"
3488 JOIN "area" ON "area"."id" = "issue"."area_id"
3489 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
3490 JOIN "direct_interest_snapshot"
3491 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3492 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3493 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
3494 WHERE "issue"."state" = 'admission'::"issue_state";
3496 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';
3499 CREATE VIEW "initiative_suggestion_order_calculation" AS
3500 SELECT
3501 "initiative"."id" AS "initiative_id",
3502 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
3503 FROM "initiative" JOIN "issue"
3504 ON "initiative"."issue_id" = "issue"."id"
3505 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
3506 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
3508 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
3510 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';
3513 CREATE VIEW "individual_suggestion_ranking" AS
3514 SELECT
3515 "opinion"."initiative_id",
3516 "opinion"."member_id",
3517 "direct_interest_snapshot"."weight",
3518 CASE WHEN
3519 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
3520 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
3521 THEN 1 ELSE
3522 CASE WHEN
3523 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
3524 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
3525 THEN 2 ELSE
3526 CASE WHEN
3527 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
3528 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
3529 THEN 3 ELSE 4 END
3530 END
3531 END AS "preference",
3532 "opinion"."suggestion_id"
3533 FROM "opinion"
3534 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
3535 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3536 JOIN "direct_interest_snapshot"
3537 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3538 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3539 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
3541 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
3544 CREATE VIEW "battle_participant" AS
3545 SELECT "initiative"."id", "initiative"."issue_id"
3546 FROM "issue" JOIN "initiative"
3547 ON "issue"."id" = "initiative"."issue_id"
3548 WHERE "initiative"."admitted"
3549 UNION ALL
3550 SELECT NULL, "id" AS "issue_id"
3551 FROM "issue";
3553 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
3556 CREATE VIEW "battle_view" AS
3557 SELECT
3558 "issue"."id" AS "issue_id",
3559 "winning_initiative"."id" AS "winning_initiative_id",
3560 "losing_initiative"."id" AS "losing_initiative_id",
3561 sum(
3562 CASE WHEN
3563 coalesce("better_vote"."grade", 0) >
3564 coalesce("worse_vote"."grade", 0)
3565 THEN "direct_voter"."weight" ELSE 0 END
3566 ) AS "count"
3567 FROM "issue"
3568 LEFT JOIN "direct_voter"
3569 ON "issue"."id" = "direct_voter"."issue_id"
3570 JOIN "battle_participant" AS "winning_initiative"
3571 ON "issue"."id" = "winning_initiative"."issue_id"
3572 JOIN "battle_participant" AS "losing_initiative"
3573 ON "issue"."id" = "losing_initiative"."issue_id"
3574 LEFT JOIN "vote" AS "better_vote"
3575 ON "direct_voter"."member_id" = "better_vote"."member_id"
3576 AND "winning_initiative"."id" = "better_vote"."initiative_id"
3577 LEFT JOIN "vote" AS "worse_vote"
3578 ON "direct_voter"."member_id" = "worse_vote"."member_id"
3579 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
3580 WHERE "issue"."state" = 'voting'
3581 AND "issue"."phase_finished" NOTNULL
3582 AND (
3583 "winning_initiative"."id" != "losing_initiative"."id" OR
3584 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
3585 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
3586 GROUP BY
3587 "issue"."id",
3588 "winning_initiative"."id",
3589 "losing_initiative"."id";
3591 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';
3594 CREATE VIEW "expired_session" AS
3595 SELECT * FROM "session" WHERE now() > "expiry";
3597 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
3598 DELETE FROM "session" WHERE "id" = OLD."id";
3600 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
3601 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
3604 CREATE VIEW "expired_token" AS
3605 SELECT * FROM "token" WHERE now() > "expiry" AND NOT (
3606 "token_type" = 'authorization' AND "used" AND EXISTS (
3607 SELECT NULL FROM "token" AS "other"
3608 WHERE "other"."authorization_token_id" = "id" ) );
3610 CREATE RULE "delete" AS ON DELETE TO "expired_token" DO INSTEAD
3611 DELETE FROM "token" WHERE "id" = OLD."id";
3613 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';
3616 CREATE VIEW "unused_snapshot" AS
3617 SELECT "snapshot".* FROM "snapshot"
3618 LEFT JOIN "issue"
3619 ON "snapshot"."id" = "issue"."latest_snapshot_id"
3620 OR "snapshot"."id" = "issue"."admission_snapshot_id"
3621 OR "snapshot"."id" = "issue"."half_freeze_snapshot_id"
3622 OR "snapshot"."id" = "issue"."full_freeze_snapshot_id"
3623 WHERE "issue"."id" ISNULL;
3625 CREATE RULE "delete" AS ON DELETE TO "unused_snapshot" DO INSTEAD
3626 DELETE FROM "snapshot" WHERE "id" = OLD."id";
3628 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)';
3631 CREATE VIEW "expired_snapshot" AS
3632 SELECT "unused_snapshot".* FROM "unused_snapshot" CROSS JOIN "system_setting"
3633 WHERE "unused_snapshot"."calculated" <
3634 now() - "system_setting"."snapshot_retention";
3636 CREATE RULE "delete" AS ON DELETE TO "expired_snapshot" DO INSTEAD
3637 DELETE FROM "snapshot" WHERE "id" = OLD."id";
3639 COMMENT ON VIEW "expired_snapshot" IS 'Contains "unused_snapshot"s that are older than "system_setting"."snapshot_retention" (for deletion)';
3642 CREATE VIEW "open_issue" AS
3643 SELECT * FROM "issue" WHERE "closed" ISNULL;
3645 COMMENT ON VIEW "open_issue" IS 'All open issues';
3648 CREATE VIEW "member_contingent" AS
3649 SELECT
3650 "member"."id" AS "member_id",
3651 "contingent"."polling",
3652 "contingent"."time_frame",
3653 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
3655 SELECT count(1) FROM "draft"
3656 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3657 WHERE "draft"."author_id" = "member"."id"
3658 AND "initiative"."polling" = "contingent"."polling"
3659 AND "draft"."created" > now() - "contingent"."time_frame"
3660 ) + (
3661 SELECT count(1) FROM "suggestion"
3662 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
3663 WHERE "suggestion"."author_id" = "member"."id"
3664 AND "contingent"."polling" = FALSE
3665 AND "suggestion"."created" > now() - "contingent"."time_frame"
3667 ELSE NULL END AS "text_entry_count",
3668 "contingent"."text_entry_limit",
3669 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
3670 SELECT count(1) FROM "opening_draft" AS "draft"
3671 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3672 WHERE "draft"."author_id" = "member"."id"
3673 AND "initiative"."polling" = "contingent"."polling"
3674 AND "draft"."created" > now() - "contingent"."time_frame"
3675 ) ELSE NULL END AS "initiative_count",
3676 "contingent"."initiative_limit"
3677 FROM "member" CROSS JOIN "contingent";
3679 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
3681 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
3682 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
3685 CREATE VIEW "member_contingent_left" AS
3686 SELECT
3687 "member_id",
3688 "polling",
3689 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
3690 max("initiative_limit" - "initiative_count") AS "initiatives_left"
3691 FROM "member_contingent" GROUP BY "member_id", "polling";
3693 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.';
3696 CREATE VIEW "event_for_notification" AS
3697 SELECT
3698 "member"."id" AS "recipient_id",
3699 "event".*
3700 FROM "member" CROSS JOIN "event"
3701 JOIN "issue" ON "issue"."id" = "event"."issue_id"
3702 JOIN "area" ON "area"."id" = "issue"."area_id"
3703 LEFT JOIN "privilege" ON
3704 "privilege"."member_id" = "member"."id" AND
3705 "privilege"."unit_id" = "area"."unit_id" AND
3706 "privilege"."voting_right" = TRUE
3707 LEFT JOIN "subscription" ON
3708 "subscription"."member_id" = "member"."id" AND
3709 "subscription"."unit_id" = "area"."unit_id"
3710 LEFT JOIN "ignored_area" ON
3711 "ignored_area"."member_id" = "member"."id" AND
3712 "ignored_area"."area_id" = "issue"."area_id"
3713 LEFT JOIN "interest" ON
3714 "interest"."member_id" = "member"."id" AND
3715 "interest"."issue_id" = "event"."issue_id"
3716 LEFT JOIN "supporter" ON
3717 "supporter"."member_id" = "member"."id" AND
3718 "supporter"."initiative_id" = "event"."initiative_id"
3719 WHERE ("privilege"."member_id" NOTNULL OR "subscription"."member_id" NOTNULL)
3720 AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
3721 AND (
3722 "event"."event" = 'issue_state_changed'::"event_type" OR
3723 ( "event"."event" = 'initiative_revoked'::"event_type" AND
3724 "supporter"."member_id" NOTNULL ) );
3726 COMMENT ON VIEW "event_for_notification" IS 'Entries of the "event" table which are of interest for a particular notification mail recipient';
3728 COMMENT ON COLUMN "event_for_notification"."recipient_id" IS 'member_id of the recipient of a notification mail';
3731 CREATE VIEW "updated_initiative" AS
3732 SELECT
3733 "supporter"."member_id" AS "recipient_id",
3734 FALSE AS "featured",
3735 "supporter"."initiative_id"
3736 FROM "supporter"
3737 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
3738 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3739 LEFT JOIN "notification_initiative_sent" AS "sent" ON
3740 "sent"."member_id" = "supporter"."member_id" AND
3741 "sent"."initiative_id" = "supporter"."initiative_id"
3742 LEFT JOIN "ignored_initiative" ON
3743 "ignored_initiative"."member_id" = "supporter"."member_id" AND
3744 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
3745 WHERE "issue"."state" IN ('admission', 'discussion')
3746 AND "initiative"."revoked" ISNULL
3747 AND "ignored_initiative"."member_id" ISNULL
3748 AND (
3749 EXISTS (
3750 SELECT NULL FROM "draft"
3751 LEFT JOIN "ignored_member" ON
3752 "ignored_member"."member_id" = "supporter"."member_id" AND
3753 "ignored_member"."other_member_id" = "draft"."author_id"
3754 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
3755 AND "draft"."id" > "supporter"."draft_id"
3756 AND "ignored_member"."member_id" ISNULL
3757 ) OR EXISTS (
3758 SELECT NULL FROM "suggestion"
3759 LEFT JOIN "opinion" ON
3760 "opinion"."member_id" = "supporter"."member_id" AND
3761 "opinion"."suggestion_id" = "suggestion"."id"
3762 LEFT JOIN "ignored_member" ON
3763 "ignored_member"."member_id" = "supporter"."member_id" AND
3764 "ignored_member"."other_member_id" = "suggestion"."author_id"
3765 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
3766 AND "opinion"."member_id" ISNULL
3767 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
3768 AND "ignored_member"."member_id" ISNULL
3770 );
3772 COMMENT ON VIEW "updated_initiative" IS 'Helper view for view "updated_or_featured_initiative"';
3775 CREATE FUNCTION "featured_initiative"
3776 ( "recipient_id_p" "member"."id"%TYPE,
3777 "area_id_p" "area"."id"%TYPE )
3778 RETURNS SETOF "initiative"."id"%TYPE
3779 LANGUAGE 'plpgsql' STABLE AS $$
3780 DECLARE
3781 "counter_v" "member"."notification_counter"%TYPE;
3782 "sample_size_v" "member"."notification_sample_size"%TYPE;
3783 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
3784 "match_v" BOOLEAN;
3785 "member_id_v" "member"."id"%TYPE;
3786 "seed_v" TEXT;
3787 "initiative_id_v" "initiative"."id"%TYPE;
3788 BEGIN
3789 SELECT "notification_counter", "notification_sample_size"
3790 INTO "counter_v", "sample_size_v"
3791 FROM "member" WHERE "id" = "recipient_id_p";
3792 IF COALESCE("sample_size_v" <= 0, TRUE) THEN
3793 RETURN;
3794 END IF;
3795 "initiative_id_ary" := '{}';
3796 LOOP
3797 "match_v" := FALSE;
3798 FOR "member_id_v", "seed_v" IN
3799 SELECT * FROM (
3800 SELECT DISTINCT
3801 "supporter"."member_id",
3802 md5(
3803 "recipient_id_p" || '-' ||
3804 "counter_v" || '-' ||
3805 "area_id_p" || '-' ||
3806 "supporter"."member_id"
3807 ) AS "seed"
3808 FROM "supporter"
3809 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
3810 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3811 WHERE "supporter"."member_id" != "recipient_id_p"
3812 AND "issue"."area_id" = "area_id_p"
3813 AND "issue"."state" IN ('admission', 'discussion', 'verification')
3814 ) AS "subquery"
3815 ORDER BY "seed"
3816 LOOP
3817 SELECT "initiative"."id" INTO "initiative_id_v"
3818 FROM "initiative"
3819 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3820 JOIN "area" ON "area"."id" = "issue"."area_id"
3821 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
3822 LEFT JOIN "supporter" AS "self_support" ON
3823 "self_support"."initiative_id" = "initiative"."id" AND
3824 "self_support"."member_id" = "recipient_id_p"
3825 LEFT JOIN "privilege" ON
3826 "privilege"."member_id" = "recipient_id_p" AND
3827 "privilege"."unit_id" = "area"."unit_id" AND
3828 "privilege"."voting_right" = TRUE
3829 LEFT JOIN "subscription" ON
3830 "subscription"."member_id" = "recipient_id_p" AND
3831 "subscription"."unit_id" = "area"."unit_id"
3832 LEFT JOIN "ignored_initiative" ON
3833 "ignored_initiative"."member_id" = "recipient_id_p" AND
3834 "ignored_initiative"."initiative_id" = "initiative"."id"
3835 WHERE "supporter"."member_id" = "member_id_v"
3836 AND "issue"."area_id" = "area_id_p"
3837 AND "issue"."state" IN ('admission', 'discussion', 'verification')
3838 AND "initiative"."revoked" ISNULL
3839 AND "self_support"."member_id" ISNULL
3840 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
3841 AND (
3842 "privilege"."member_id" NOTNULL OR
3843 "subscription"."member_id" NOTNULL )
3844 AND "ignored_initiative"."member_id" ISNULL
3845 AND NOT EXISTS (
3846 SELECT NULL FROM "draft"
3847 JOIN "ignored_member" ON
3848 "ignored_member"."member_id" = "recipient_id_p" AND
3849 "ignored_member"."other_member_id" = "draft"."author_id"
3850 WHERE "draft"."initiative_id" = "initiative"."id"
3852 ORDER BY md5("seed_v" || '-' || "initiative"."id")
3853 LIMIT 1;
3854 IF FOUND THEN
3855 "match_v" := TRUE;
3856 RETURN NEXT "initiative_id_v";
3857 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
3858 RETURN;
3859 END IF;
3860 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
3861 END IF;
3862 END LOOP;
3863 EXIT WHEN NOT "match_v";
3864 END LOOP;
3865 RETURN;
3866 END;
3867 $$;
3869 COMMENT ON FUNCTION "featured_initiative"
3870 ( "recipient_id_p" "member"."id"%TYPE,
3871 "area_id_p" "area"."id"%TYPE )
3872 IS 'Helper function for view "updated_or_featured_initiative"';
3875 CREATE VIEW "updated_or_featured_initiative" AS
3876 SELECT
3877 "subquery".*,
3878 NOT EXISTS (
3879 SELECT NULL FROM "initiative" AS "better_initiative"
3880 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
3881 AND
3882 ( COALESCE("better_initiative"."supporter_count", -1),
3883 -"better_initiative"."id" ) >
3884 ( COALESCE("initiative"."supporter_count", -1),
3885 -"initiative"."id" )
3886 ) AS "leading"
3887 FROM (
3888 SELECT * FROM "updated_initiative"
3889 UNION ALL
3890 SELECT
3891 "member"."id" AS "recipient_id",
3892 TRUE AS "featured",
3893 "featured_initiative_id" AS "initiative_id"
3894 FROM "member" CROSS JOIN "area"
3895 CROSS JOIN LATERAL
3896 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
3897 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
3898 ) AS "subquery"
3899 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
3901 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';
3903 COMMENT ON COLUMN "updated_or_featured_initiative"."recipient_id" IS '"id" of the member who receives the notification mail';
3904 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")';
3905 COMMENT ON COLUMN "updated_or_featured_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
3906 COMMENT ON COLUMN "updated_or_featured_initiative"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
3909 CREATE VIEW "leading_complement_initiative" AS
3910 SELECT * FROM (
3911 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
3912 "uf_initiative"."recipient_id",
3913 FALSE AS "featured",
3914 "uf_initiative"."initiative_id",
3915 TRUE AS "leading"
3916 FROM "updated_or_featured_initiative" AS "uf_initiative"
3917 JOIN "initiative" AS "uf_initiative_full" ON
3918 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
3919 JOIN "initiative" ON
3920 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
3921 WHERE "initiative"."revoked" ISNULL
3922 ORDER BY
3923 "uf_initiative"."recipient_id",
3924 "initiative"."issue_id",
3925 "initiative"."supporter_count" DESC,
3926 "initiative"."id"
3927 ) AS "subquery"
3928 WHERE NOT EXISTS (
3929 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
3930 WHERE "other"."recipient_id" = "subquery"."recipient_id"
3931 AND "other"."initiative_id" = "subquery"."initiative_id"
3932 );
3934 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';
3935 COMMENT ON COLUMN "leading_complement_initiative"."featured" IS 'Always FALSE in this view';
3936 COMMENT ON COLUMN "leading_complement_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
3937 COMMENT ON COLUMN "leading_complement_initiative"."leading" IS 'Always TRUE in this view';
3940 CREATE VIEW "unfiltered_initiative_for_notification" AS
3941 SELECT
3942 "subquery".*,
3943 "supporter"."member_id" NOTNULL AS "supported",
3944 CASE WHEN "supporter"."member_id" NOTNULL THEN
3945 EXISTS (
3946 SELECT NULL FROM "draft"
3947 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
3948 AND "draft"."id" > "supporter"."draft_id"
3950 ELSE
3951 EXISTS (
3952 SELECT NULL FROM "draft"
3953 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
3954 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
3956 END AS "new_draft",
3957 CASE WHEN "supporter"."member_id" NOTNULL THEN
3958 ( SELECT count(1) FROM "suggestion"
3959 LEFT JOIN "opinion" ON
3960 "opinion"."member_id" = "supporter"."member_id" AND
3961 "opinion"."suggestion_id" = "suggestion"."id"
3962 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
3963 AND "opinion"."member_id" ISNULL
3964 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
3966 ELSE
3967 ( SELECT count(1) FROM "suggestion"
3968 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
3969 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
3971 END AS "new_suggestion_count"
3972 FROM (
3973 SELECT * FROM "updated_or_featured_initiative"
3974 UNION ALL
3975 SELECT * FROM "leading_complement_initiative"
3976 ) AS "subquery"
3977 LEFT JOIN "supporter" ON
3978 "supporter"."member_id" = "subquery"."recipient_id" AND
3979 "supporter"."initiative_id" = "subquery"."initiative_id"
3980 LEFT JOIN "notification_initiative_sent" AS "sent" ON
3981 "sent"."member_id" = "subquery"."recipient_id" AND
3982 "sent"."initiative_id" = "subquery"."initiative_id";
3984 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';
3986 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
3987 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)';
3988 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")';
3991 CREATE VIEW "initiative_for_notification" AS
3992 SELECT "unfiltered1".*
3993 FROM "unfiltered_initiative_for_notification" "unfiltered1"
3994 JOIN "initiative" AS "initiative1" ON
3995 "initiative1"."id" = "unfiltered1"."initiative_id"
3996 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
3997 WHERE EXISTS (
3998 SELECT NULL
3999 FROM "unfiltered_initiative_for_notification" "unfiltered2"
4000 JOIN "initiative" AS "initiative2" ON
4001 "initiative2"."id" = "unfiltered2"."initiative_id"
4002 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
4003 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
4004 AND "issue1"."area_id" = "issue2"."area_id"
4005 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
4006 );
4008 COMMENT ON VIEW "initiative_for_notification" IS 'Initiatives to be included in a scheduled notification mail';
4010 COMMENT ON COLUMN "initiative_for_notification"."recipient_id" IS '"id" of the member who receives the notification mail';
4011 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")';
4012 COMMENT ON COLUMN "initiative_for_notification"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4013 COMMENT ON COLUMN "initiative_for_notification"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4014 COMMENT ON COLUMN "initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4015 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)';
4016 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")';
4019 CREATE VIEW "scheduled_notification_to_send" AS
4020 SELECT * FROM (
4021 SELECT
4022 "id" AS "recipient_id",
4023 now() - CASE WHEN "notification_dow" ISNULL THEN
4024 ( "notification_sent"::DATE + CASE
4025 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4026 THEN 0 ELSE 1 END
4027 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4028 ELSE
4029 ( "notification_sent"::DATE +
4030 ( 7 + "notification_dow" -
4031 EXTRACT(DOW FROM
4032 ( "notification_sent"::DATE + CASE
4033 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4034 THEN 0 ELSE 1 END
4035 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4036 )::INTEGER
4037 ) % 7 +
4038 CASE
4039 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4040 THEN 0 ELSE 1
4041 END
4042 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4043 END AS "pending"
4044 FROM (
4045 SELECT
4046 "id",
4047 COALESCE("notification_sent", "activated") AS "notification_sent",
4048 "notification_dow",
4049 "notification_hour"
4050 FROM "member_to_notify"
4051 WHERE "notification_hour" NOTNULL
4052 ) AS "subquery1"
4053 ) AS "subquery2"
4054 WHERE "pending" > '0'::INTERVAL;
4056 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
4058 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
4059 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
4062 CREATE VIEW "newsletter_to_send" AS
4063 SELECT
4064 "member"."id" AS "recipient_id",
4065 "newsletter"."id" AS "newsletter_id",
4066 "newsletter"."published"
4067 FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member"
4068 LEFT JOIN "privilege" ON
4069 "privilege"."member_id" = "member"."id" AND
4070 "privilege"."unit_id" = "newsletter"."unit_id" AND
4071 "privilege"."voting_right" = TRUE
4072 LEFT JOIN "subscription" ON
4073 "subscription"."member_id" = "member"."id" AND
4074 "subscription"."unit_id" = "newsletter"."unit_id"
4075 WHERE "newsletter"."published" <= now()
4076 AND "newsletter"."sent" ISNULL
4077 AND (
4078 "member"."disable_notifications" = FALSE OR
4079 "newsletter"."include_all_members" = TRUE )
4080 AND (
4081 "newsletter"."unit_id" ISNULL OR
4082 "privilege"."member_id" NOTNULL OR
4083 "subscription"."member_id" NOTNULL );
4085 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
4087 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
4091 ------------------------------------------------------
4092 -- Row set returning function for delegation chains --
4093 ------------------------------------------------------
4096 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
4097 ('first', 'intermediate', 'last', 'repetition');
4099 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
4102 CREATE TYPE "delegation_chain_row" AS (
4103 "index" INT4,
4104 "member_id" INT4,
4105 "member_valid" BOOLEAN,
4106 "participation" BOOLEAN,
4107 "overridden" BOOLEAN,
4108 "scope_in" "delegation_scope",
4109 "scope_out" "delegation_scope",
4110 "disabled_out" BOOLEAN,
4111 "loop" "delegation_chain_loop_tag" );
4113 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
4115 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
4116 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest; for area and global delegation chains: always null';
4117 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
4118 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
4119 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
4120 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
4121 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
4124 CREATE FUNCTION "delegation_chain_for_closed_issue"
4125 ( "member_id_p" "member"."id"%TYPE,
4126 "issue_id_p" "issue"."id"%TYPE )
4127 RETURNS SETOF "delegation_chain_row"
4128 LANGUAGE 'plpgsql' STABLE AS $$
4129 DECLARE
4130 "output_row" "delegation_chain_row";
4131 "direct_voter_row" "direct_voter"%ROWTYPE;
4132 "delegating_voter_row" "delegating_voter"%ROWTYPE;
4133 BEGIN
4134 "output_row"."index" := 0;
4135 "output_row"."member_id" := "member_id_p";
4136 "output_row"."member_valid" := TRUE;
4137 "output_row"."participation" := FALSE;
4138 "output_row"."overridden" := FALSE;
4139 "output_row"."disabled_out" := FALSE;
4140 LOOP
4141 SELECT INTO "direct_voter_row" * FROM "direct_voter"
4142 WHERE "issue_id" = "issue_id_p"
4143 AND "member_id" = "output_row"."member_id";
4144 IF "direct_voter_row"."member_id" NOTNULL THEN
4145 "output_row"."participation" := TRUE;
4146 "output_row"."scope_out" := NULL;
4147 "output_row"."disabled_out" := NULL;
4148 RETURN NEXT "output_row";
4149 RETURN;
4150 END IF;
4151 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
4152 WHERE "issue_id" = "issue_id_p"
4153 AND "member_id" = "output_row"."member_id";
4154 IF "delegating_voter_row"."member_id" ISNULL THEN
4155 RETURN;
4156 END IF;
4157 "output_row"."scope_out" := "delegating_voter_row"."scope";
4158 RETURN NEXT "output_row";
4159 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
4160 "output_row"."scope_in" := "output_row"."scope_out";
4161 END LOOP;
4162 END;
4163 $$;
4165 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
4166 ( "member"."id"%TYPE,
4167 "member"."id"%TYPE )
4168 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
4171 CREATE FUNCTION "delegation_chain"
4172 ( "member_id_p" "member"."id"%TYPE,
4173 "unit_id_p" "unit"."id"%TYPE,
4174 "area_id_p" "area"."id"%TYPE,
4175 "issue_id_p" "issue"."id"%TYPE,
4176 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4177 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4178 RETURNS SETOF "delegation_chain_row"
4179 LANGUAGE 'plpgsql' STABLE AS $$
4180 DECLARE
4181 "scope_v" "delegation_scope";
4182 "unit_id_v" "unit"."id"%TYPE;
4183 "area_id_v" "area"."id"%TYPE;
4184 "issue_row" "issue"%ROWTYPE;
4185 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
4186 "loop_member_id_v" "member"."id"%TYPE;
4187 "output_row" "delegation_chain_row";
4188 "output_rows" "delegation_chain_row"[];
4189 "simulate_v" BOOLEAN;
4190 "simulate_here_v" BOOLEAN;
4191 "delegation_row" "delegation"%ROWTYPE;
4192 "row_count" INT4;
4193 "i" INT4;
4194 "loop_v" BOOLEAN;
4195 BEGIN
4196 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
4197 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
4198 END IF;
4199 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
4200 "simulate_v" := TRUE;
4201 ELSE
4202 "simulate_v" := FALSE;
4203 END IF;
4204 IF
4205 "unit_id_p" NOTNULL AND
4206 "area_id_p" ISNULL AND
4207 "issue_id_p" ISNULL
4208 THEN
4209 "scope_v" := 'unit';
4210 "unit_id_v" := "unit_id_p";
4211 ELSIF
4212 "unit_id_p" ISNULL AND
4213 "area_id_p" NOTNULL AND
4214 "issue_id_p" ISNULL
4215 THEN
4216 "scope_v" := 'area';
4217 "area_id_v" := "area_id_p";
4218 SELECT "unit_id" INTO "unit_id_v"
4219 FROM "area" WHERE "id" = "area_id_v";
4220 ELSIF
4221 "unit_id_p" ISNULL AND
4222 "area_id_p" ISNULL AND
4223 "issue_id_p" NOTNULL
4224 THEN
4225 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
4226 IF "issue_row"."id" ISNULL THEN
4227 RETURN;
4228 END IF;
4229 IF "issue_row"."closed" NOTNULL THEN
4230 IF "simulate_v" THEN
4231 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
4232 END IF;
4233 FOR "output_row" IN
4234 SELECT * FROM
4235 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
4236 LOOP
4237 RETURN NEXT "output_row";
4238 END LOOP;
4239 RETURN;
4240 END IF;
4241 "scope_v" := 'issue';
4242 SELECT "area_id" INTO "area_id_v"
4243 FROM "issue" WHERE "id" = "issue_id_p";
4244 SELECT "unit_id" INTO "unit_id_v"
4245 FROM "area" WHERE "id" = "area_id_v";
4246 ELSE
4247 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
4248 END IF;
4249 "visited_member_ids" := '{}';
4250 "loop_member_id_v" := NULL;
4251 "output_rows" := '{}';
4252 "output_row"."index" := 0;
4253 "output_row"."member_id" := "member_id_p";
4254 "output_row"."member_valid" := TRUE;
4255 "output_row"."participation" := FALSE;
4256 "output_row"."overridden" := FALSE;
4257 "output_row"."disabled_out" := FALSE;
4258 "output_row"."scope_out" := NULL;
4259 LOOP
4260 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
4261 "loop_member_id_v" := "output_row"."member_id";
4262 ELSE
4263 "visited_member_ids" :=
4264 "visited_member_ids" || "output_row"."member_id";
4265 END IF;
4266 IF "output_row"."participation" ISNULL THEN
4267 "output_row"."overridden" := NULL;
4268 ELSIF "output_row"."participation" THEN
4269 "output_row"."overridden" := TRUE;
4270 END IF;
4271 "output_row"."scope_in" := "output_row"."scope_out";
4272 "output_row"."member_valid" := EXISTS (
4273 SELECT NULL FROM "member" JOIN "privilege"
4274 ON "privilege"."member_id" = "member"."id"
4275 AND "privilege"."unit_id" = "unit_id_v"
4276 WHERE "id" = "output_row"."member_id"
4277 AND "member"."active" AND "privilege"."voting_right"
4278 );
4279 "simulate_here_v" := (
4280 "simulate_v" AND
4281 "output_row"."member_id" = "member_id_p"
4282 );
4283 "delegation_row" := ROW(NULL);
4284 IF "output_row"."member_valid" OR "simulate_here_v" THEN
4285 IF "scope_v" = 'unit' THEN
4286 IF NOT "simulate_here_v" THEN
4287 SELECT * INTO "delegation_row" FROM "delegation"
4288 WHERE "truster_id" = "output_row"."member_id"
4289 AND "unit_id" = "unit_id_v";
4290 END IF;
4291 ELSIF "scope_v" = 'area' THEN
4292 IF "simulate_here_v" THEN
4293 IF "simulate_trustee_id_p" ISNULL THEN
4294 SELECT * INTO "delegation_row" FROM "delegation"
4295 WHERE "truster_id" = "output_row"."member_id"
4296 AND "unit_id" = "unit_id_v";
4297 END IF;
4298 ELSE
4299 SELECT * INTO "delegation_row" FROM "delegation"
4300 WHERE "truster_id" = "output_row"."member_id"
4301 AND (
4302 "unit_id" = "unit_id_v" OR
4303 "area_id" = "area_id_v"
4305 ORDER BY "scope" DESC;
4306 END IF;
4307 ELSIF "scope_v" = 'issue' THEN
4308 IF "issue_row"."fully_frozen" ISNULL THEN
4309 "output_row"."participation" := EXISTS (
4310 SELECT NULL FROM "interest"
4311 WHERE "issue_id" = "issue_id_p"
4312 AND "member_id" = "output_row"."member_id"
4313 );
4314 ELSE
4315 IF "output_row"."member_id" = "member_id_p" THEN
4316 "output_row"."participation" := EXISTS (
4317 SELECT NULL FROM "direct_voter"
4318 WHERE "issue_id" = "issue_id_p"
4319 AND "member_id" = "output_row"."member_id"
4320 );
4321 ELSE
4322 "output_row"."participation" := NULL;
4323 END IF;
4324 END IF;
4325 IF "simulate_here_v" THEN
4326 IF "simulate_trustee_id_p" ISNULL THEN
4327 SELECT * INTO "delegation_row" FROM "delegation"
4328 WHERE "truster_id" = "output_row"."member_id"
4329 AND (
4330 "unit_id" = "unit_id_v" OR
4331 "area_id" = "area_id_v"
4333 ORDER BY "scope" DESC;
4334 END IF;
4335 ELSE
4336 SELECT * INTO "delegation_row" FROM "delegation"
4337 WHERE "truster_id" = "output_row"."member_id"
4338 AND (
4339 "unit_id" = "unit_id_v" OR
4340 "area_id" = "area_id_v" OR
4341 "issue_id" = "issue_id_p"
4343 ORDER BY "scope" DESC;
4344 END IF;
4345 END IF;
4346 ELSE
4347 "output_row"."participation" := FALSE;
4348 END IF;
4349 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
4350 "output_row"."scope_out" := "scope_v";
4351 "output_rows" := "output_rows" || "output_row";
4352 "output_row"."member_id" := "simulate_trustee_id_p";
4353 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
4354 "output_row"."scope_out" := "delegation_row"."scope";
4355 "output_rows" := "output_rows" || "output_row";
4356 "output_row"."member_id" := "delegation_row"."trustee_id";
4357 ELSIF "delegation_row"."scope" NOTNULL THEN
4358 "output_row"."scope_out" := "delegation_row"."scope";
4359 "output_row"."disabled_out" := TRUE;
4360 "output_rows" := "output_rows" || "output_row";
4361 EXIT;
4362 ELSE
4363 "output_row"."scope_out" := NULL;
4364 "output_rows" := "output_rows" || "output_row";
4365 EXIT;
4366 END IF;
4367 EXIT WHEN "loop_member_id_v" NOTNULL;
4368 "output_row"."index" := "output_row"."index" + 1;
4369 END LOOP;
4370 "row_count" := array_upper("output_rows", 1);
4371 "i" := 1;
4372 "loop_v" := FALSE;
4373 LOOP
4374 "output_row" := "output_rows"["i"];
4375 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
4376 IF "loop_v" THEN
4377 IF "i" + 1 = "row_count" THEN
4378 "output_row"."loop" := 'last';
4379 ELSIF "i" = "row_count" THEN
4380 "output_row"."loop" := 'repetition';
4381 ELSE
4382 "output_row"."loop" := 'intermediate';
4383 END IF;
4384 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
4385 "output_row"."loop" := 'first';
4386 "loop_v" := TRUE;
4387 END IF;
4388 IF "scope_v" = 'unit' THEN
4389 "output_row"."participation" := NULL;
4390 END IF;
4391 RETURN NEXT "output_row";
4392 "i" := "i" + 1;
4393 END LOOP;
4394 RETURN;
4395 END;
4396 $$;
4398 COMMENT ON FUNCTION "delegation_chain"
4399 ( "member"."id"%TYPE,
4400 "unit"."id"%TYPE,
4401 "area"."id"%TYPE,
4402 "issue"."id"%TYPE,
4403 "member"."id"%TYPE,
4404 BOOLEAN )
4405 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
4409 ---------------------------------------------------------
4410 -- Single row returning function for delegation chains --
4411 ---------------------------------------------------------
4414 CREATE TYPE "delegation_info_loop_type" AS ENUM
4415 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
4417 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''';
4420 CREATE TYPE "delegation_info_type" AS (
4421 "own_participation" BOOLEAN,
4422 "own_delegation_scope" "delegation_scope",
4423 "first_trustee_id" INT4,
4424 "first_trustee_participation" BOOLEAN,
4425 "first_trustee_ellipsis" BOOLEAN,
4426 "other_trustee_id" INT4,
4427 "other_trustee_participation" BOOLEAN,
4428 "other_trustee_ellipsis" BOOLEAN,
4429 "delegation_loop" "delegation_info_loop_type",
4430 "participating_member_id" INT4 );
4432 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';
4434 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
4435 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
4436 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
4437 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
4438 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
4439 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
4440 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)';
4441 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
4442 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';
4443 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
4446 CREATE FUNCTION "delegation_info"
4447 ( "member_id_p" "member"."id"%TYPE,
4448 "unit_id_p" "unit"."id"%TYPE,
4449 "area_id_p" "area"."id"%TYPE,
4450 "issue_id_p" "issue"."id"%TYPE,
4451 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4452 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4453 RETURNS "delegation_info_type"
4454 LANGUAGE 'plpgsql' STABLE AS $$
4455 DECLARE
4456 "current_row" "delegation_chain_row";
4457 "result" "delegation_info_type";
4458 BEGIN
4459 "result"."own_participation" := FALSE;
4460 FOR "current_row" IN
4461 SELECT * FROM "delegation_chain"(
4462 "member_id_p",
4463 "unit_id_p", "area_id_p", "issue_id_p",
4464 "simulate_trustee_id_p", "simulate_default_p")
4465 LOOP
4466 IF
4467 "result"."participating_member_id" ISNULL AND
4468 "current_row"."participation"
4469 THEN
4470 "result"."participating_member_id" := "current_row"."member_id";
4471 END IF;
4472 IF "current_row"."member_id" = "member_id_p" THEN
4473 "result"."own_participation" := "current_row"."participation";
4474 "result"."own_delegation_scope" := "current_row"."scope_out";
4475 IF "current_row"."loop" = 'first' THEN
4476 "result"."delegation_loop" := 'own';
4477 END IF;
4478 ELSIF
4479 "current_row"."member_valid" AND
4480 ( "current_row"."loop" ISNULL OR
4481 "current_row"."loop" != 'repetition' )
4482 THEN
4483 IF "result"."first_trustee_id" ISNULL THEN
4484 "result"."first_trustee_id" := "current_row"."member_id";
4485 "result"."first_trustee_participation" := "current_row"."participation";
4486 "result"."first_trustee_ellipsis" := FALSE;
4487 IF "current_row"."loop" = 'first' THEN
4488 "result"."delegation_loop" := 'first';
4489 END IF;
4490 ELSIF "result"."other_trustee_id" ISNULL THEN
4491 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
4492 "result"."other_trustee_id" := "current_row"."member_id";
4493 "result"."other_trustee_participation" := TRUE;
4494 "result"."other_trustee_ellipsis" := FALSE;
4495 IF "current_row"."loop" = 'first' THEN
4496 "result"."delegation_loop" := 'other';
4497 END IF;
4498 ELSE
4499 "result"."first_trustee_ellipsis" := TRUE;
4500 IF "current_row"."loop" = 'first' THEN
4501 "result"."delegation_loop" := 'first_ellipsis';
4502 END IF;
4503 END IF;
4504 ELSE
4505 "result"."other_trustee_ellipsis" := TRUE;
4506 IF "current_row"."loop" = 'first' THEN
4507 "result"."delegation_loop" := 'other_ellipsis';
4508 END IF;
4509 END IF;
4510 END IF;
4511 END LOOP;
4512 RETURN "result";
4513 END;
4514 $$;
4516 COMMENT ON FUNCTION "delegation_info"
4517 ( "member"."id"%TYPE,
4518 "unit"."id"%TYPE,
4519 "area"."id"%TYPE,
4520 "issue"."id"%TYPE,
4521 "member"."id"%TYPE,
4522 BOOLEAN )
4523 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
4527 ---------------------------
4528 -- Transaction isolation --
4529 ---------------------------
4532 CREATE FUNCTION "require_transaction_isolation"()
4533 RETURNS VOID
4534 LANGUAGE 'plpgsql' VOLATILE AS $$
4535 BEGIN
4536 IF
4537 current_setting('transaction_isolation') NOT IN
4538 ('repeatable read', 'serializable')
4539 THEN
4540 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
4541 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
4542 END IF;
4543 RETURN;
4544 END;
4545 $$;
4547 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
4550 CREATE FUNCTION "dont_require_transaction_isolation"()
4551 RETURNS VOID
4552 LANGUAGE 'plpgsql' VOLATILE AS $$
4553 BEGIN
4554 IF
4555 current_setting('transaction_isolation') IN
4556 ('repeatable read', 'serializable')
4557 THEN
4558 RAISE WARNING 'Unneccessary transaction isolation level: %',
4559 current_setting('transaction_isolation');
4560 END IF;
4561 RETURN;
4562 END;
4563 $$;
4565 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
4569 -------------------------
4570 -- Notification system --
4571 -------------------------
4573 CREATE FUNCTION "get_initiatives_for_notification"
4574 ( "recipient_id_p" "member"."id"%TYPE )
4575 RETURNS SETOF "initiative_for_notification"
4576 LANGUAGE 'plpgsql' VOLATILE AS $$
4577 DECLARE
4578 "result_row" "initiative_for_notification"%ROWTYPE;
4579 "last_draft_id_v" "draft"."id"%TYPE;
4580 "last_suggestion_id_v" "suggestion"."id"%TYPE;
4581 BEGIN
4582 PERFORM "require_transaction_isolation"();
4583 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
4584 FOR "result_row" IN
4585 SELECT * FROM "initiative_for_notification"
4586 WHERE "recipient_id" = "recipient_id_p"
4587 LOOP
4588 SELECT "id" INTO "last_draft_id_v" FROM "draft"
4589 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
4590 ORDER BY "id" DESC LIMIT 1;
4591 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
4592 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
4593 ORDER BY "id" DESC LIMIT 1;
4594 INSERT INTO "notification_initiative_sent"
4595 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
4596 VALUES (
4597 "recipient_id_p",
4598 "result_row"."initiative_id",
4599 "last_draft_id_v",
4600 "last_suggestion_id_v" )
4601 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
4602 "last_draft_id" = "last_draft_id_v",
4603 "last_suggestion_id" = "last_suggestion_id_v";
4604 RETURN NEXT "result_row";
4605 END LOOP;
4606 DELETE FROM "notification_initiative_sent"
4607 USING "initiative", "issue"
4608 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
4609 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
4610 AND "issue"."id" = "initiative"."issue_id"
4611 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
4612 UPDATE "member" SET
4613 "notification_counter" = "notification_counter" + 1,
4614 "notification_sent" = now()
4615 WHERE "id" = "recipient_id_p";
4616 RETURN;
4617 END;
4618 $$;
4620 COMMENT ON FUNCTION "get_initiatives_for_notification"
4621 ( "member"."id"%TYPE )
4622 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';
4626 ------------------------------------------------------------------------
4627 -- Regular tasks, except calculcation of snapshots and voting results --
4628 ------------------------------------------------------------------------
4631 CREATE FUNCTION "check_activity"()
4632 RETURNS VOID
4633 LANGUAGE 'plpgsql' VOLATILE AS $$
4634 DECLARE
4635 "system_setting_row" "system_setting"%ROWTYPE;
4636 BEGIN
4637 PERFORM "dont_require_transaction_isolation"();
4638 SELECT * INTO "system_setting_row" FROM "system_setting";
4639 IF "system_setting_row"."member_ttl" NOTNULL THEN
4640 UPDATE "member" SET "active" = FALSE
4641 WHERE "active" = TRUE
4642 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
4643 END IF;
4644 RETURN;
4645 END;
4646 $$;
4648 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
4651 CREATE FUNCTION "calculate_member_counts"()
4652 RETURNS VOID
4653 LANGUAGE 'plpgsql' VOLATILE AS $$
4654 BEGIN
4655 PERFORM "require_transaction_isolation"();
4656 DELETE FROM "member_count";
4657 INSERT INTO "member_count" ("total_count")
4658 SELECT "total_count" FROM "member_count_view";
4659 UPDATE "unit" SET "member_count" = "view"."member_count"
4660 FROM "unit_member_count" AS "view"
4661 WHERE "view"."unit_id" = "unit"."id";
4662 RETURN;
4663 END;
4664 $$;
4666 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"';
4670 ------------------------------------
4671 -- Calculation of harmonic weight --
4672 ------------------------------------
4675 CREATE VIEW "remaining_harmonic_supporter_weight" AS
4676 SELECT
4677 "direct_interest_snapshot"."snapshot_id",
4678 "direct_interest_snapshot"."issue_id",
4679 "direct_interest_snapshot"."member_id",
4680 "direct_interest_snapshot"."weight" AS "weight_num",
4681 count("initiative"."id") AS "weight_den"
4682 FROM "issue"
4683 JOIN "direct_interest_snapshot"
4684 ON "issue"."latest_snapshot_id" = "direct_interest_snapshot"."snapshot_id"
4685 AND "issue"."id" = "direct_interest_snapshot"."issue_id"
4686 JOIN "initiative"
4687 ON "issue"."id" = "initiative"."issue_id"
4688 AND "initiative"."harmonic_weight" ISNULL
4689 JOIN "direct_supporter_snapshot"
4690 ON "issue"."latest_snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
4691 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
4692 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
4693 AND (
4694 "direct_supporter_snapshot"."satisfied" = TRUE OR
4695 coalesce("initiative"."admitted", FALSE) = FALSE
4697 GROUP BY
4698 "direct_interest_snapshot"."snapshot_id",
4699 "direct_interest_snapshot"."issue_id",
4700 "direct_interest_snapshot"."member_id",
4701 "direct_interest_snapshot"."weight";
4703 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
4706 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
4707 SELECT
4708 "initiative"."issue_id",
4709 "initiative"."id" AS "initiative_id",
4710 "initiative"."admitted",
4711 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
4712 "remaining_harmonic_supporter_weight"."weight_den"
4713 FROM "remaining_harmonic_supporter_weight"
4714 JOIN "initiative"
4715 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
4716 AND "initiative"."harmonic_weight" ISNULL
4717 JOIN "direct_supporter_snapshot"
4718 ON "remaining_harmonic_supporter_weight"."snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
4719 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
4720 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
4721 AND (
4722 "direct_supporter_snapshot"."satisfied" = TRUE OR
4723 coalesce("initiative"."admitted", FALSE) = FALSE
4725 GROUP BY
4726 "initiative"."issue_id",
4727 "initiative"."id",
4728 "initiative"."admitted",
4729 "remaining_harmonic_supporter_weight"."weight_den";
4731 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
4734 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
4735 SELECT
4736 "issue_id",
4737 "id" AS "initiative_id",
4738 "admitted",
4739 0 AS "weight_num",
4740 1 AS "weight_den"
4741 FROM "initiative"
4742 WHERE "harmonic_weight" ISNULL;
4744 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';
4747 CREATE FUNCTION "set_harmonic_initiative_weights"
4748 ( "issue_id_p" "issue"."id"%TYPE )
4749 RETURNS VOID
4750 LANGUAGE 'plpgsql' VOLATILE AS $$
4751 DECLARE
4752 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
4753 "i" INT4;
4754 "count_v" INT4;
4755 "summand_v" FLOAT;
4756 "id_ary" INT4[];
4757 "weight_ary" FLOAT[];
4758 "min_weight_v" FLOAT;
4759 BEGIN
4760 PERFORM "require_transaction_isolation"();
4761 UPDATE "initiative" SET "harmonic_weight" = NULL
4762 WHERE "issue_id" = "issue_id_p";
4763 LOOP
4764 "min_weight_v" := NULL;
4765 "i" := 0;
4766 "count_v" := 0;
4767 FOR "weight_row" IN
4768 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
4769 WHERE "issue_id" = "issue_id_p"
4770 AND (
4771 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
4772 SELECT NULL FROM "initiative"
4773 WHERE "issue_id" = "issue_id_p"
4774 AND "harmonic_weight" ISNULL
4775 AND coalesce("admitted", FALSE) = FALSE
4778 UNION ALL -- needed for corner cases
4779 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
4780 WHERE "issue_id" = "issue_id_p"
4781 AND (
4782 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
4783 SELECT NULL FROM "initiative"
4784 WHERE "issue_id" = "issue_id_p"
4785 AND "harmonic_weight" ISNULL
4786 AND coalesce("admitted", FALSE) = FALSE
4789 ORDER BY "initiative_id" DESC, "weight_den" DESC
4790 -- NOTE: non-admitted initiatives placed first (at last positions),
4791 -- latest initiatives treated worse in case of tie
4792 LOOP
4793 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
4794 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
4795 "i" := "i" + 1;
4796 "count_v" := "i";
4797 "id_ary"["i"] := "weight_row"."initiative_id";
4798 "weight_ary"["i"] := "summand_v";
4799 ELSE
4800 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
4801 END IF;
4802 END LOOP;
4803 EXIT WHEN "count_v" = 0;
4804 "i" := 1;
4805 LOOP
4806 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
4807 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
4808 "min_weight_v" := "weight_ary"["i"];
4809 END IF;
4810 "i" := "i" + 1;
4811 EXIT WHEN "i" > "count_v";
4812 END LOOP;
4813 "i" := 1;
4814 LOOP
4815 IF "weight_ary"["i"] = "min_weight_v" THEN
4816 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
4817 WHERE "id" = "id_ary"["i"];
4818 EXIT;
4819 END IF;
4820 "i" := "i" + 1;
4821 END LOOP;
4822 END LOOP;
4823 UPDATE "initiative" SET "harmonic_weight" = 0
4824 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
4825 END;
4826 $$;
4828 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
4829 ( "issue"."id"%TYPE )
4830 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
4834 ------------------------------
4835 -- Calculation of snapshots --
4836 ------------------------------
4839 CREATE FUNCTION "weight_of_added_delegations_for_snapshot"
4840 ( "snapshot_id_p" "snapshot"."id"%TYPE,
4841 "issue_id_p" "issue"."id"%TYPE,
4842 "member_id_p" "member"."id"%TYPE,
4843 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
4844 RETURNS "direct_interest_snapshot"."weight"%TYPE
4845 LANGUAGE 'plpgsql' VOLATILE AS $$
4846 DECLARE
4847 "issue_delegation_row" "issue_delegation"%ROWTYPE;
4848 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
4849 "weight_v" INT4;
4850 "sub_weight_v" INT4;
4851 BEGIN
4852 PERFORM "require_transaction_isolation"();
4853 "weight_v" := 0;
4854 FOR "issue_delegation_row" IN
4855 SELECT * FROM "issue_delegation"
4856 WHERE "trustee_id" = "member_id_p"
4857 AND "issue_id" = "issue_id_p"
4858 LOOP
4859 IF NOT EXISTS (
4860 SELECT NULL FROM "direct_interest_snapshot"
4861 WHERE "snapshot_id" = "snapshot_id_p"
4862 AND "issue_id" = "issue_id_p"
4863 AND "member_id" = "issue_delegation_row"."truster_id"
4864 ) AND NOT EXISTS (
4865 SELECT NULL FROM "delegating_interest_snapshot"
4866 WHERE "snapshot_id" = "snapshot_id_p"
4867 AND "issue_id" = "issue_id_p"
4868 AND "member_id" = "issue_delegation_row"."truster_id"
4869 ) THEN
4870 "delegate_member_ids_v" :=
4871 "member_id_p" || "delegate_member_ids_p";
4872 INSERT INTO "delegating_interest_snapshot" (
4873 "snapshot_id",
4874 "issue_id",
4875 "member_id",
4876 "scope",
4877 "delegate_member_ids"
4878 ) VALUES (
4879 "snapshot_id_p",
4880 "issue_id_p",
4881 "issue_delegation_row"."truster_id",
4882 "issue_delegation_row"."scope",
4883 "delegate_member_ids_v"
4884 );
4885 "sub_weight_v" := 1 +
4886 "weight_of_added_delegations_for_snapshot"(
4887 "snapshot_id_p",
4888 "issue_id_p",
4889 "issue_delegation_row"."truster_id",
4890 "delegate_member_ids_v"
4891 );
4892 UPDATE "delegating_interest_snapshot"
4893 SET "weight" = "sub_weight_v"
4894 WHERE "snapshot_id" = "snapshot_id_p"
4895 AND "issue_id" = "issue_id_p"
4896 AND "member_id" = "issue_delegation_row"."truster_id";
4897 "weight_v" := "weight_v" + "sub_weight_v";
4898 END IF;
4899 END LOOP;
4900 RETURN "weight_v";
4901 END;
4902 $$;
4904 COMMENT ON FUNCTION "weight_of_added_delegations_for_snapshot"
4905 ( "snapshot"."id"%TYPE,
4906 "issue"."id"%TYPE,
4907 "member"."id"%TYPE,
4908 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
4909 IS 'Helper function for "fill_snapshot" function';
4912 CREATE FUNCTION "take_snapshot"
4913 ( "issue_id_p" "issue"."id"%TYPE,
4914 "area_id_p" "area"."id"%TYPE = NULL )
4915 RETURNS "snapshot"."id"%TYPE
4916 LANGUAGE 'plpgsql' VOLATILE AS $$
4917 DECLARE
4918 "area_id_v" "area"."id"%TYPE;
4919 "unit_id_v" "unit"."id"%TYPE;
4920 "snapshot_id_v" "snapshot"."id"%TYPE;
4921 "issue_id_v" "issue"."id"%TYPE;
4922 "member_id_v" "member"."id"%TYPE;
4923 BEGIN
4924 IF "issue_id_p" NOTNULL AND "area_id_p" NOTNULL THEN
4925 RAISE EXCEPTION 'One of "issue_id_p" and "area_id_p" must be NULL';
4926 END IF;
4927 PERFORM "require_transaction_isolation"();
4928 IF "issue_id_p" ISNULL THEN
4929 "area_id_v" := "area_id_p";
4930 ELSE
4931 SELECT "area_id" INTO "area_id_v"
4932 FROM "issue" WHERE "id" = "issue_id_p";
4933 END IF;
4934 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
4935 INSERT INTO "snapshot" ("area_id", "issue_id")
4936 VALUES ("area_id_v", "issue_id_p")
4937 RETURNING "id" INTO "snapshot_id_v";
4938 INSERT INTO "snapshot_population" ("snapshot_id", "member_id")
4939 SELECT "snapshot_id_v", "member_id"
4940 FROM "unit_member" WHERE "unit_id" = "unit_id_v";
4941 UPDATE "snapshot" SET
4942 "population" = (
4943 SELECT count(1) FROM "snapshot_population"
4944 WHERE "snapshot_id" = "snapshot_id_v"
4945 ) WHERE "id" = "snapshot_id_v";
4946 FOR "issue_id_v" IN
4947 SELECT "id" FROM "issue"
4948 WHERE CASE WHEN "issue_id_p" ISNULL THEN
4949 "area_id" = "area_id_p" AND
4950 "state" = 'admission'
4951 ELSE
4952 "id" = "issue_id_p"
4953 END
4954 LOOP
4955 INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id")
4956 VALUES ("snapshot_id_v", "issue_id_v");
4957 INSERT INTO "direct_interest_snapshot"
4958 ("snapshot_id", "issue_id", "member_id")
4959 SELECT
4960 "snapshot_id_v" AS "snapshot_id",
4961 "issue_id_v" AS "issue_id",
4962 "member"."id" AS "member_id"
4963 FROM "issue"
4964 JOIN "area" ON "issue"."area_id" = "area"."id"
4965 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
4966 JOIN "member" ON "interest"."member_id" = "member"."id"
4967 JOIN "privilege"
4968 ON "privilege"."unit_id" = "area"."unit_id"
4969 AND "privilege"."member_id" = "member"."id"
4970 WHERE "issue"."id" = "issue_id_v"
4971 AND "member"."active" AND "privilege"."voting_right";
4972 FOR "member_id_v" IN
4973 SELECT "member_id" FROM "direct_interest_snapshot"
4974 WHERE "snapshot_id" = "snapshot_id_v"
4975 AND "issue_id" = "issue_id_v"
4976 LOOP
4977 UPDATE "direct_interest_snapshot" SET
4978 "weight" = 1 +
4979 "weight_of_added_delegations_for_snapshot"(
4980 "snapshot_id_v",
4981 "issue_id_v",
4982 "member_id_v",
4983 '{}'
4985 WHERE "snapshot_id" = "snapshot_id_v"
4986 AND "issue_id" = "issue_id_v"
4987 AND "member_id" = "member_id_v";
4988 END LOOP;
4989 INSERT INTO "direct_supporter_snapshot"
4990 ( "snapshot_id", "issue_id", "initiative_id", "member_id",
4991 "draft_id", "informed", "satisfied" )
4992 SELECT
4993 "snapshot_id_v" AS "snapshot_id",
4994 "issue_id_v" AS "issue_id",
4995 "initiative"."id" AS "initiative_id",
4996 "supporter"."member_id" AS "member_id",
4997 "supporter"."draft_id" AS "draft_id",
4998 "supporter"."draft_id" = "current_draft"."id" AS "informed",
4999 NOT EXISTS (
5000 SELECT NULL FROM "critical_opinion"
5001 WHERE "initiative_id" = "initiative"."id"
5002 AND "member_id" = "supporter"."member_id"
5003 ) AS "satisfied"
5004 FROM "initiative"
5005 JOIN "supporter"
5006 ON "supporter"."initiative_id" = "initiative"."id"
5007 JOIN "current_draft"
5008 ON "initiative"."id" = "current_draft"."initiative_id"
5009 JOIN "direct_interest_snapshot"
5010 ON "snapshot_id_v" = "direct_interest_snapshot"."snapshot_id"
5011 AND "supporter"."member_id" = "direct_interest_snapshot"."member_id"
5012 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
5013 WHERE "initiative"."issue_id" = "issue_id_v";
5014 DELETE FROM "temporary_suggestion_counts";
5015 INSERT INTO "temporary_suggestion_counts"
5016 ( "id",
5017 "minus2_unfulfilled_count", "minus2_fulfilled_count",
5018 "minus1_unfulfilled_count", "minus1_fulfilled_count",
5019 "plus1_unfulfilled_count", "plus1_fulfilled_count",
5020 "plus2_unfulfilled_count", "plus2_fulfilled_count" )
5021 SELECT
5022 "suggestion"."id",
5023 ( SELECT coalesce(sum("di"."weight"), 0)
5024 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5025 ON "di"."snapshot_id" = "snapshot_id_v"
5026 AND "di"."issue_id" = "issue_id_v"
5027 AND "di"."member_id" = "opinion"."member_id"
5028 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5029 AND "opinion"."degree" = -2
5030 AND "opinion"."fulfilled" = FALSE
5031 ) AS "minus2_unfulfilled_count",
5032 ( SELECT coalesce(sum("di"."weight"), 0)
5033 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5034 ON "di"."snapshot_id" = "snapshot_id_v"
5035 AND "di"."issue_id" = "issue_id_v"
5036 AND "di"."member_id" = "opinion"."member_id"
5037 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5038 AND "opinion"."degree" = -2
5039 AND "opinion"."fulfilled" = TRUE
5040 ) AS "minus2_fulfilled_count",
5041 ( SELECT coalesce(sum("di"."weight"), 0)
5042 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5043 ON "di"."snapshot_id" = "snapshot_id_v"
5044 AND "di"."issue_id" = "issue_id_v"
5045 AND "di"."member_id" = "opinion"."member_id"
5046 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5047 AND "opinion"."degree" = -1
5048 AND "opinion"."fulfilled" = FALSE
5049 ) AS "minus1_unfulfilled_count",
5050 ( SELECT coalesce(sum("di"."weight"), 0)
5051 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5052 ON "di"."snapshot_id" = "snapshot_id_v"
5053 AND "di"."issue_id" = "issue_id_v"
5054 AND "di"."member_id" = "opinion"."member_id"
5055 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5056 AND "opinion"."degree" = -1
5057 AND "opinion"."fulfilled" = TRUE
5058 ) AS "minus1_fulfilled_count",
5059 ( SELECT coalesce(sum("di"."weight"), 0)
5060 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5061 ON "di"."snapshot_id" = "snapshot_id_v"
5062 AND "di"."issue_id" = "issue_id_v"
5063 AND "di"."member_id" = "opinion"."member_id"
5064 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5065 AND "opinion"."degree" = 1
5066 AND "opinion"."fulfilled" = FALSE
5067 ) AS "plus1_unfulfilled_count",
5068 ( SELECT coalesce(sum("di"."weight"), 0)
5069 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5070 ON "di"."snapshot_id" = "snapshot_id_v"
5071 AND "di"."issue_id" = "issue_id_v"
5072 AND "di"."member_id" = "opinion"."member_id"
5073 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5074 AND "opinion"."degree" = 1
5075 AND "opinion"."fulfilled" = TRUE
5076 ) AS "plus1_fulfilled_count",
5077 ( SELECT coalesce(sum("di"."weight"), 0)
5078 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5079 ON "di"."snapshot_id" = "snapshot_id_v"
5080 AND "di"."issue_id" = "issue_id_v"
5081 AND "di"."member_id" = "opinion"."member_id"
5082 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5083 AND "opinion"."degree" = 2
5084 AND "opinion"."fulfilled" = FALSE
5085 ) AS "plus2_unfulfilled_count",
5086 ( SELECT coalesce(sum("di"."weight"), 0)
5087 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5088 ON "di"."snapshot_id" = "snapshot_id_v"
5089 AND "di"."issue_id" = "issue_id_v"
5090 AND "di"."member_id" = "opinion"."member_id"
5091 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5092 AND "opinion"."degree" = 2
5093 AND "opinion"."fulfilled" = TRUE
5094 ) AS "plus2_fulfilled_count"
5095 FROM "suggestion" JOIN "initiative"
5096 ON "suggestion"."initiative_id" = "initiative"."id"
5097 WHERE "initiative"."issue_id" = "issue_id_v";
5098 END LOOP;
5099 RETURN "snapshot_id_v";
5100 END;
5101 $$;
5103 COMMENT ON FUNCTION "take_snapshot"
5104 ( "issue"."id"%TYPE,
5105 "area"."id"%TYPE )
5106 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.';
5109 CREATE FUNCTION "finish_snapshot"
5110 ( "issue_id_p" "issue"."id"%TYPE )
5111 RETURNS VOID
5112 LANGUAGE 'plpgsql' VOLATILE AS $$
5113 DECLARE
5114 "snapshot_id_v" "snapshot"."id"%TYPE;
5115 BEGIN
5116 -- NOTE: function does not require snapshot isolation but we don't call
5117 -- "dont_require_snapshot_isolation" here because this function is
5118 -- also invoked by "check_issue"
5119 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
5120 SELECT "id" INTO "snapshot_id_v" FROM "snapshot"
5121 ORDER BY "id" DESC LIMIT 1;
5122 UPDATE "issue" SET
5123 "calculated" = "snapshot"."calculated",
5124 "latest_snapshot_id" = "snapshot_id_v",
5125 "population" = "snapshot"."population"
5126 FROM "snapshot"
5127 WHERE "issue"."id" = "issue_id_p"
5128 AND "snapshot"."id" = "snapshot_id_v";
5129 UPDATE "initiative" SET
5130 "supporter_count" = (
5131 SELECT coalesce(sum("di"."weight"), 0)
5132 FROM "direct_interest_snapshot" AS "di"
5133 JOIN "direct_supporter_snapshot" AS "ds"
5134 ON "di"."member_id" = "ds"."member_id"
5135 WHERE "di"."snapshot_id" = "snapshot_id_v"
5136 AND "di"."issue_id" = "issue_id_p"
5137 AND "ds"."snapshot_id" = "snapshot_id_v"
5138 AND "ds"."initiative_id" = "initiative"."id"
5139 ),
5140 "informed_supporter_count" = (
5141 SELECT coalesce(sum("di"."weight"), 0)
5142 FROM "direct_interest_snapshot" AS "di"
5143 JOIN "direct_supporter_snapshot" AS "ds"
5144 ON "di"."member_id" = "ds"."member_id"
5145 WHERE "di"."snapshot_id" = "snapshot_id_v"
5146 AND "di"."issue_id" = "issue_id_p"
5147 AND "ds"."snapshot_id" = "snapshot_id_v"
5148 AND "ds"."initiative_id" = "initiative"."id"
5149 AND "ds"."informed"
5150 ),
5151 "satisfied_supporter_count" = (
5152 SELECT coalesce(sum("di"."weight"), 0)
5153 FROM "direct_interest_snapshot" AS "di"
5154 JOIN "direct_supporter_snapshot" AS "ds"
5155 ON "di"."member_id" = "ds"."member_id"
5156 WHERE "di"."snapshot_id" = "snapshot_id_v"
5157 AND "di"."issue_id" = "issue_id_p"
5158 AND "ds"."snapshot_id" = "snapshot_id_v"
5159 AND "ds"."initiative_id" = "initiative"."id"
5160 AND "ds"."satisfied"
5161 ),
5162 "satisfied_informed_supporter_count" = (
5163 SELECT coalesce(sum("di"."weight"), 0)
5164 FROM "direct_interest_snapshot" AS "di"
5165 JOIN "direct_supporter_snapshot" AS "ds"
5166 ON "di"."member_id" = "ds"."member_id"
5167 WHERE "di"."snapshot_id" = "snapshot_id_v"
5168 AND "di"."issue_id" = "issue_id_p"
5169 AND "ds"."snapshot_id" = "snapshot_id_v"
5170 AND "ds"."initiative_id" = "initiative"."id"
5171 AND "ds"."informed"
5172 AND "ds"."satisfied"
5174 WHERE "issue_id" = "issue_id_p";
5175 UPDATE "suggestion" SET
5176 "minus2_unfulfilled_count" = "temp"."minus2_unfulfilled_count",
5177 "minus2_fulfilled_count" = "temp"."minus2_fulfilled_count",
5178 "minus1_unfulfilled_count" = "temp"."minus1_unfulfilled_count",
5179 "minus1_fulfilled_count" = "temp"."minus1_fulfilled_count",
5180 "plus1_unfulfilled_count" = "temp"."plus1_unfulfilled_count",
5181 "plus1_fulfilled_count" = "temp"."plus1_fulfilled_count",
5182 "plus2_unfulfilled_count" = "temp"."plus2_unfulfilled_count",
5183 "plus2_fulfilled_count" = "temp"."plus2_fulfilled_count"
5184 FROM "temporary_suggestion_counts" AS "temp", "initiative"
5185 WHERE "temp"."id" = "suggestion"."id"
5186 AND "initiative"."issue_id" = "issue_id_p"
5187 AND "suggestion"."initiative_id" = "initiative"."id";
5188 DELETE FROM "temporary_suggestion_counts";
5189 RETURN;
5190 END;
5191 $$;
5193 COMMENT ON FUNCTION "finish_snapshot"
5194 ( "issue"."id"%TYPE )
5195 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)';
5199 -----------------------
5200 -- Counting of votes --
5201 -----------------------
5204 CREATE FUNCTION "weight_of_added_vote_delegations"
5205 ( "issue_id_p" "issue"."id"%TYPE,
5206 "member_id_p" "member"."id"%TYPE,
5207 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
5208 RETURNS "direct_voter"."weight"%TYPE
5209 LANGUAGE 'plpgsql' VOLATILE AS $$
5210 DECLARE
5211 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5212 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
5213 "weight_v" INT4;
5214 "sub_weight_v" INT4;
5215 BEGIN
5216 PERFORM "require_transaction_isolation"();
5217 "weight_v" := 0;
5218 FOR "issue_delegation_row" IN
5219 SELECT * FROM "issue_delegation"
5220 WHERE "trustee_id" = "member_id_p"
5221 AND "issue_id" = "issue_id_p"
5222 LOOP
5223 IF NOT EXISTS (
5224 SELECT NULL FROM "direct_voter"
5225 WHERE "member_id" = "issue_delegation_row"."truster_id"
5226 AND "issue_id" = "issue_id_p"
5227 ) AND NOT EXISTS (
5228 SELECT NULL FROM "delegating_voter"
5229 WHERE "member_id" = "issue_delegation_row"."truster_id"
5230 AND "issue_id" = "issue_id_p"
5231 ) THEN
5232 "delegate_member_ids_v" :=
5233 "member_id_p" || "delegate_member_ids_p";
5234 INSERT INTO "delegating_voter" (
5235 "issue_id",
5236 "member_id",
5237 "scope",
5238 "delegate_member_ids"
5239 ) VALUES (
5240 "issue_id_p",
5241 "issue_delegation_row"."truster_id",
5242 "issue_delegation_row"."scope",
5243 "delegate_member_ids_v"
5244 );
5245 "sub_weight_v" := 1 +
5246 "weight_of_added_vote_delegations"(
5247 "issue_id_p",
5248 "issue_delegation_row"."truster_id",
5249 "delegate_member_ids_v"
5250 );
5251 UPDATE "delegating_voter"
5252 SET "weight" = "sub_weight_v"
5253 WHERE "issue_id" = "issue_id_p"
5254 AND "member_id" = "issue_delegation_row"."truster_id";
5255 "weight_v" := "weight_v" + "sub_weight_v";
5256 END IF;
5257 END LOOP;
5258 RETURN "weight_v";
5259 END;
5260 $$;
5262 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
5263 ( "issue"."id"%TYPE,
5264 "member"."id"%TYPE,
5265 "delegating_voter"."delegate_member_ids"%TYPE )
5266 IS 'Helper function for "add_vote_delegations" function';
5269 CREATE FUNCTION "add_vote_delegations"
5270 ( "issue_id_p" "issue"."id"%TYPE )
5271 RETURNS VOID
5272 LANGUAGE 'plpgsql' VOLATILE AS $$
5273 DECLARE
5274 "member_id_v" "member"."id"%TYPE;
5275 BEGIN
5276 PERFORM "require_transaction_isolation"();
5277 FOR "member_id_v" IN
5278 SELECT "member_id" FROM "direct_voter"
5279 WHERE "issue_id" = "issue_id_p"
5280 LOOP
5281 UPDATE "direct_voter" SET
5282 "weight" = "weight" + "weight_of_added_vote_delegations"(
5283 "issue_id_p",
5284 "member_id_v",
5285 '{}'
5287 WHERE "member_id" = "member_id_v"
5288 AND "issue_id" = "issue_id_p";
5289 END LOOP;
5290 RETURN;
5291 END;
5292 $$;
5294 COMMENT ON FUNCTION "add_vote_delegations"
5295 ( "issue_id_p" "issue"."id"%TYPE )
5296 IS 'Helper function for "close_voting" function';
5299 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
5300 RETURNS VOID
5301 LANGUAGE 'plpgsql' VOLATILE AS $$
5302 DECLARE
5303 "area_id_v" "area"."id"%TYPE;
5304 "unit_id_v" "unit"."id"%TYPE;
5305 "member_id_v" "member"."id"%TYPE;
5306 BEGIN
5307 PERFORM "require_transaction_isolation"();
5308 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
5309 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5310 -- override protection triggers:
5311 INSERT INTO "temporary_transaction_data" ("key", "value")
5312 VALUES ('override_protection_triggers', TRUE::TEXT);
5313 -- delete timestamp of voting comment:
5314 UPDATE "direct_voter" SET "comment_changed" = NULL
5315 WHERE "issue_id" = "issue_id_p";
5316 -- delete delegating votes (in cases of manual reset of issue state):
5317 DELETE FROM "delegating_voter"
5318 WHERE "issue_id" = "issue_id_p";
5319 -- delete votes from non-privileged voters:
5320 DELETE FROM "direct_voter"
5321 USING (
5322 SELECT
5323 "direct_voter"."member_id"
5324 FROM "direct_voter"
5325 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
5326 LEFT JOIN "privilege"
5327 ON "privilege"."unit_id" = "unit_id_v"
5328 AND "privilege"."member_id" = "direct_voter"."member_id"
5329 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
5330 "member"."active" = FALSE OR
5331 "privilege"."voting_right" ISNULL OR
5332 "privilege"."voting_right" = FALSE
5334 ) AS "subquery"
5335 WHERE "direct_voter"."issue_id" = "issue_id_p"
5336 AND "direct_voter"."member_id" = "subquery"."member_id";
5337 -- consider delegations:
5338 UPDATE "direct_voter" SET "weight" = 1
5339 WHERE "issue_id" = "issue_id_p";
5340 PERFORM "add_vote_delegations"("issue_id_p");
5341 -- mark first preferences:
5342 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
5343 FROM (
5344 SELECT
5345 "vote"."initiative_id",
5346 "vote"."member_id",
5347 CASE WHEN "vote"."grade" > 0 THEN
5348 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
5349 ELSE NULL
5350 END AS "first_preference"
5351 FROM "vote"
5352 JOIN "initiative" -- NOTE: due to missing index on issue_id
5353 ON "vote"."issue_id" = "initiative"."issue_id"
5354 JOIN "vote" AS "agg"
5355 ON "initiative"."id" = "agg"."initiative_id"
5356 AND "vote"."member_id" = "agg"."member_id"
5357 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
5358 ) AS "subquery"
5359 WHERE "vote"."issue_id" = "issue_id_p"
5360 AND "vote"."initiative_id" = "subquery"."initiative_id"
5361 AND "vote"."member_id" = "subquery"."member_id";
5362 -- finish overriding protection triggers (avoids garbage):
5363 DELETE FROM "temporary_transaction_data"
5364 WHERE "key" = 'override_protection_triggers';
5365 -- materialize battle_view:
5366 -- NOTE: "closed" column of issue must be set at this point
5367 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
5368 INSERT INTO "battle" (
5369 "issue_id",
5370 "winning_initiative_id", "losing_initiative_id",
5371 "count"
5372 ) SELECT
5373 "issue_id",
5374 "winning_initiative_id", "losing_initiative_id",
5375 "count"
5376 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
5377 -- set voter count:
5378 UPDATE "issue" SET
5379 "voter_count" = (
5380 SELECT coalesce(sum("weight"), 0)
5381 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
5383 WHERE "id" = "issue_id_p";
5384 -- copy "positive_votes" and "negative_votes" from "battle" table:
5385 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
5386 UPDATE "initiative" SET
5387 "first_preference_votes" = 0,
5388 "positive_votes" = "battle_win"."count",
5389 "negative_votes" = "battle_lose"."count"
5390 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
5391 WHERE
5392 "battle_win"."issue_id" = "issue_id_p" AND
5393 "battle_win"."winning_initiative_id" = "initiative"."id" AND
5394 "battle_win"."losing_initiative_id" ISNULL AND
5395 "battle_lose"."issue_id" = "issue_id_p" AND
5396 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
5397 "battle_lose"."winning_initiative_id" ISNULL;
5398 -- calculate "first_preference_votes":
5399 -- NOTE: will only set values not equal to zero
5400 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
5401 FROM (
5402 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
5403 FROM "vote" JOIN "direct_voter"
5404 ON "vote"."issue_id" = "direct_voter"."issue_id"
5405 AND "vote"."member_id" = "direct_voter"."member_id"
5406 WHERE "vote"."first_preference"
5407 GROUP BY "vote"."initiative_id"
5408 ) AS "subquery"
5409 WHERE "initiative"."issue_id" = "issue_id_p"
5410 AND "initiative"."admitted"
5411 AND "initiative"."id" = "subquery"."initiative_id";
5412 END;
5413 $$;
5415 COMMENT ON FUNCTION "close_voting"
5416 ( "issue"."id"%TYPE )
5417 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.';
5420 CREATE FUNCTION "defeat_strength"
5421 ( "positive_votes_p" INT4,
5422 "negative_votes_p" INT4,
5423 "defeat_strength_p" "defeat_strength" )
5424 RETURNS INT8
5425 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5426 BEGIN
5427 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
5428 IF "positive_votes_p" > "negative_votes_p" THEN
5429 RETURN "positive_votes_p";
5430 ELSE
5431 RETURN 0;
5432 END IF;
5433 ELSE
5434 IF "positive_votes_p" > "negative_votes_p" THEN
5435 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
5436 ELSIF "positive_votes_p" = "negative_votes_p" THEN
5437 RETURN 0;
5438 ELSE
5439 RETURN -1;
5440 END IF;
5441 END IF;
5442 END;
5443 $$;
5445 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")';
5448 CREATE FUNCTION "secondary_link_strength"
5449 ( "initiative1_ord_p" INT4,
5450 "initiative2_ord_p" INT4,
5451 "tie_breaking_p" "tie_breaking" )
5452 RETURNS INT8
5453 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5454 BEGIN
5455 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
5456 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
5457 END IF;
5458 RETURN (
5459 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
5461 ELSE
5462 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
5463 1::INT8 << 62
5464 ELSE 0 END
5466 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
5467 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
5468 ELSE
5469 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
5470 END
5471 END
5472 );
5473 END;
5474 $$;
5476 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
5479 CREATE TYPE "link_strength" AS (
5480 "primary" INT8,
5481 "secondary" INT8 );
5483 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'')';
5486 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
5487 RETURNS "link_strength"[][]
5488 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5489 DECLARE
5490 "dimension_v" INT4;
5491 "matrix_p" "link_strength"[][];
5492 "i" INT4;
5493 "j" INT4;
5494 "k" INT4;
5495 BEGIN
5496 "dimension_v" := array_upper("matrix_d", 1);
5497 "matrix_p" := "matrix_d";
5498 "i" := 1;
5499 LOOP
5500 "j" := 1;
5501 LOOP
5502 IF "i" != "j" THEN
5503 "k" := 1;
5504 LOOP
5505 IF "i" != "k" AND "j" != "k" THEN
5506 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
5507 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
5508 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
5509 END IF;
5510 ELSE
5511 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
5512 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
5513 END IF;
5514 END IF;
5515 END IF;
5516 EXIT WHEN "k" = "dimension_v";
5517 "k" := "k" + 1;
5518 END LOOP;
5519 END IF;
5520 EXIT WHEN "j" = "dimension_v";
5521 "j" := "j" + 1;
5522 END LOOP;
5523 EXIT WHEN "i" = "dimension_v";
5524 "i" := "i" + 1;
5525 END LOOP;
5526 RETURN "matrix_p";
5527 END;
5528 $$;
5530 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
5533 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
5534 RETURNS VOID
5535 LANGUAGE 'plpgsql' VOLATILE AS $$
5536 DECLARE
5537 "issue_row" "issue"%ROWTYPE;
5538 "policy_row" "policy"%ROWTYPE;
5539 "dimension_v" INT4;
5540 "matrix_a" INT4[][]; -- absolute votes
5541 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
5542 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
5543 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
5544 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
5545 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
5546 "i" INT4;
5547 "j" INT4;
5548 "m" INT4;
5549 "n" INT4;
5550 "battle_row" "battle"%ROWTYPE;
5551 "rank_ary" INT4[];
5552 "rank_v" INT4;
5553 "initiative_id_v" "initiative"."id"%TYPE;
5554 BEGIN
5555 PERFORM "require_transaction_isolation"();
5556 SELECT * INTO "issue_row"
5557 FROM "issue" WHERE "id" = "issue_id_p";
5558 SELECT * INTO "policy_row"
5559 FROM "policy" WHERE "id" = "issue_row"."policy_id";
5560 SELECT count(1) INTO "dimension_v"
5561 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
5562 -- create "matrix_a" with absolute number of votes in pairwise
5563 -- comparison:
5564 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
5565 "i" := 1;
5566 "j" := 2;
5567 FOR "battle_row" IN
5568 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
5569 ORDER BY
5570 "winning_initiative_id" NULLS FIRST,
5571 "losing_initiative_id" NULLS FIRST
5572 LOOP
5573 "matrix_a"["i"]["j"] := "battle_row"."count";
5574 IF "j" = "dimension_v" THEN
5575 "i" := "i" + 1;
5576 "j" := 1;
5577 ELSE
5578 "j" := "j" + 1;
5579 IF "j" = "i" THEN
5580 "j" := "j" + 1;
5581 END IF;
5582 END IF;
5583 END LOOP;
5584 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
5585 RAISE EXCEPTION 'Wrong battle count (should not happen)';
5586 END IF;
5587 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
5588 -- and "secondary_link_strength" functions:
5589 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
5590 "i" := 1;
5591 LOOP
5592 "j" := 1;
5593 LOOP
5594 IF "i" != "j" THEN
5595 "matrix_d"["i"]["j"] := (
5596 "defeat_strength"(
5597 "matrix_a"["i"]["j"],
5598 "matrix_a"["j"]["i"],
5599 "policy_row"."defeat_strength"
5600 ),
5601 "secondary_link_strength"(
5602 "i",
5603 "j",
5604 "policy_row"."tie_breaking"
5606 )::"link_strength";
5607 END IF;
5608 EXIT WHEN "j" = "dimension_v";
5609 "j" := "j" + 1;
5610 END LOOP;
5611 EXIT WHEN "i" = "dimension_v";
5612 "i" := "i" + 1;
5613 END LOOP;
5614 -- find best paths:
5615 "matrix_p" := "find_best_paths"("matrix_d");
5616 -- create partial order:
5617 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
5618 "i" := 1;
5619 LOOP
5620 "j" := "i" + 1;
5621 LOOP
5622 IF "i" != "j" THEN
5623 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
5624 "matrix_b"["i"]["j"] := TRUE;
5625 "matrix_b"["j"]["i"] := FALSE;
5626 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
5627 "matrix_b"["i"]["j"] := FALSE;
5628 "matrix_b"["j"]["i"] := TRUE;
5629 END IF;
5630 END IF;
5631 EXIT WHEN "j" = "dimension_v";
5632 "j" := "j" + 1;
5633 END LOOP;
5634 EXIT WHEN "i" = "dimension_v" - 1;
5635 "i" := "i" + 1;
5636 END LOOP;
5637 -- tie-breaking by forbidding shared weakest links in beat-paths
5638 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
5639 -- is performed later by initiative id):
5640 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
5641 "m" := 1;
5642 LOOP
5643 "n" := "m" + 1;
5644 LOOP
5645 -- only process those candidates m and n, which are tied:
5646 IF "matrix_b"["m"]["n"] ISNULL THEN
5647 -- start with beat-paths prior tie-breaking:
5648 "matrix_t" := "matrix_p";
5649 -- start with all links allowed:
5650 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
5651 LOOP
5652 -- determine (and forbid) that link that is the weakest link
5653 -- in both the best path from candidate m to candidate n and
5654 -- from candidate n to candidate m:
5655 "i" := 1;
5656 <<forbid_one_link>>
5657 LOOP
5658 "j" := 1;
5659 LOOP
5660 IF "i" != "j" THEN
5661 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
5662 "matrix_f"["i"]["j"] := TRUE;
5663 -- exit for performance reasons,
5664 -- as exactly one link will be found:
5665 EXIT forbid_one_link;
5666 END IF;
5667 END IF;
5668 EXIT WHEN "j" = "dimension_v";
5669 "j" := "j" + 1;
5670 END LOOP;
5671 IF "i" = "dimension_v" THEN
5672 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
5673 END IF;
5674 "i" := "i" + 1;
5675 END LOOP;
5676 -- calculate best beat-paths while ignoring forbidden links:
5677 "i" := 1;
5678 LOOP
5679 "j" := 1;
5680 LOOP
5681 IF "i" != "j" THEN
5682 "matrix_t"["i"]["j"] := CASE
5683 WHEN "matrix_f"["i"]["j"]
5684 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
5685 ELSE "matrix_d"["i"]["j"] END;
5686 END IF;
5687 EXIT WHEN "j" = "dimension_v";
5688 "j" := "j" + 1;
5689 END LOOP;
5690 EXIT WHEN "i" = "dimension_v";
5691 "i" := "i" + 1;
5692 END LOOP;
5693 "matrix_t" := "find_best_paths"("matrix_t");
5694 -- extend partial order, if tie-breaking was successful:
5695 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
5696 "matrix_b"["m"]["n"] := TRUE;
5697 "matrix_b"["n"]["m"] := FALSE;
5698 EXIT;
5699 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
5700 "matrix_b"["m"]["n"] := FALSE;
5701 "matrix_b"["n"]["m"] := TRUE;
5702 EXIT;
5703 END IF;
5704 END LOOP;
5705 END IF;
5706 EXIT WHEN "n" = "dimension_v";
5707 "n" := "n" + 1;
5708 END LOOP;
5709 EXIT WHEN "m" = "dimension_v" - 1;
5710 "m" := "m" + 1;
5711 END LOOP;
5712 END IF;
5713 -- store a unique ranking in "rank_ary":
5714 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
5715 "rank_v" := 1;
5716 LOOP
5717 "i" := 1;
5718 <<assign_next_rank>>
5719 LOOP
5720 IF "rank_ary"["i"] ISNULL THEN
5721 "j" := 1;
5722 LOOP
5723 IF
5724 "i" != "j" AND
5725 "rank_ary"["j"] ISNULL AND
5726 ( "matrix_b"["j"]["i"] OR
5727 -- tie-breaking by "id"
5728 ( "matrix_b"["j"]["i"] ISNULL AND
5729 "j" < "i" ) )
5730 THEN
5731 -- someone else is better
5732 EXIT;
5733 END IF;
5734 IF "j" = "dimension_v" THEN
5735 -- noone is better
5736 "rank_ary"["i"] := "rank_v";
5737 EXIT assign_next_rank;
5738 END IF;
5739 "j" := "j" + 1;
5740 END LOOP;
5741 END IF;
5742 "i" := "i" + 1;
5743 IF "i" > "dimension_v" THEN
5744 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
5745 END IF;
5746 END LOOP;
5747 EXIT WHEN "rank_v" = "dimension_v";
5748 "rank_v" := "rank_v" + 1;
5749 END LOOP;
5750 -- write preliminary results:
5751 "i" := 2; -- omit status quo with "i" = 1
5752 FOR "initiative_id_v" IN
5753 SELECT "id" FROM "initiative"
5754 WHERE "issue_id" = "issue_id_p" AND "admitted"
5755 ORDER BY "id"
5756 LOOP
5757 UPDATE "initiative" SET
5758 "direct_majority" =
5759 CASE WHEN "policy_row"."direct_majority_strict" THEN
5760 "positive_votes" * "policy_row"."direct_majority_den" >
5761 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
5762 ELSE
5763 "positive_votes" * "policy_row"."direct_majority_den" >=
5764 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
5765 END
5766 AND "positive_votes" >= "policy_row"."direct_majority_positive"
5767 AND "issue_row"."voter_count"-"negative_votes" >=
5768 "policy_row"."direct_majority_non_negative",
5769 "indirect_majority" =
5770 CASE WHEN "policy_row"."indirect_majority_strict" THEN
5771 "positive_votes" * "policy_row"."indirect_majority_den" >
5772 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
5773 ELSE
5774 "positive_votes" * "policy_row"."indirect_majority_den" >=
5775 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
5776 END
5777 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
5778 AND "issue_row"."voter_count"-"negative_votes" >=
5779 "policy_row"."indirect_majority_non_negative",
5780 "schulze_rank" = "rank_ary"["i"],
5781 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
5782 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
5783 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
5784 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
5785 THEN NULL
5786 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
5787 "eligible" = FALSE,
5788 "winner" = FALSE,
5789 "rank" = NULL -- NOTE: in cases of manual reset of issue state
5790 WHERE "id" = "initiative_id_v";
5791 "i" := "i" + 1;
5792 END LOOP;
5793 IF "i" != "dimension_v" + 1 THEN
5794 RAISE EXCEPTION 'Wrong winner count (should not happen)';
5795 END IF;
5796 -- take indirect majorities into account:
5797 LOOP
5798 UPDATE "initiative" SET "indirect_majority" = TRUE
5799 FROM (
5800 SELECT "new_initiative"."id" AS "initiative_id"
5801 FROM "initiative" "old_initiative"
5802 JOIN "initiative" "new_initiative"
5803 ON "new_initiative"."issue_id" = "issue_id_p"
5804 AND "new_initiative"."indirect_majority" = FALSE
5805 JOIN "battle" "battle_win"
5806 ON "battle_win"."issue_id" = "issue_id_p"
5807 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
5808 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
5809 JOIN "battle" "battle_lose"
5810 ON "battle_lose"."issue_id" = "issue_id_p"
5811 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
5812 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
5813 WHERE "old_initiative"."issue_id" = "issue_id_p"
5814 AND "old_initiative"."indirect_majority" = TRUE
5815 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
5816 "battle_win"."count" * "policy_row"."indirect_majority_den" >
5817 "policy_row"."indirect_majority_num" *
5818 ("battle_win"."count"+"battle_lose"."count")
5819 ELSE
5820 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
5821 "policy_row"."indirect_majority_num" *
5822 ("battle_win"."count"+"battle_lose"."count")
5823 END
5824 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
5825 AND "issue_row"."voter_count"-"battle_lose"."count" >=
5826 "policy_row"."indirect_majority_non_negative"
5827 ) AS "subquery"
5828 WHERE "id" = "subquery"."initiative_id";
5829 EXIT WHEN NOT FOUND;
5830 END LOOP;
5831 -- set "multistage_majority" for remaining matching initiatives:
5832 UPDATE "initiative" SET "multistage_majority" = TRUE
5833 FROM (
5834 SELECT "losing_initiative"."id" AS "initiative_id"
5835 FROM "initiative" "losing_initiative"
5836 JOIN "initiative" "winning_initiative"
5837 ON "winning_initiative"."issue_id" = "issue_id_p"
5838 AND "winning_initiative"."admitted"
5839 JOIN "battle" "battle_win"
5840 ON "battle_win"."issue_id" = "issue_id_p"
5841 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
5842 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
5843 JOIN "battle" "battle_lose"
5844 ON "battle_lose"."issue_id" = "issue_id_p"
5845 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
5846 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
5847 WHERE "losing_initiative"."issue_id" = "issue_id_p"
5848 AND "losing_initiative"."admitted"
5849 AND "winning_initiative"."schulze_rank" <
5850 "losing_initiative"."schulze_rank"
5851 AND "battle_win"."count" > "battle_lose"."count"
5852 AND (
5853 "battle_win"."count" > "winning_initiative"."positive_votes" OR
5854 "battle_lose"."count" < "losing_initiative"."negative_votes" )
5855 ) AS "subquery"
5856 WHERE "id" = "subquery"."initiative_id";
5857 -- mark eligible initiatives:
5858 UPDATE "initiative" SET "eligible" = TRUE
5859 WHERE "issue_id" = "issue_id_p"
5860 AND "initiative"."direct_majority"
5861 AND "initiative"."indirect_majority"
5862 AND "initiative"."better_than_status_quo"
5863 AND (
5864 "policy_row"."no_multistage_majority" = FALSE OR
5865 "initiative"."multistage_majority" = FALSE )
5866 AND (
5867 "policy_row"."no_reverse_beat_path" = FALSE OR
5868 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
5869 -- mark final winner:
5870 UPDATE "initiative" SET "winner" = TRUE
5871 FROM (
5872 SELECT "id" AS "initiative_id"
5873 FROM "initiative"
5874 WHERE "issue_id" = "issue_id_p" AND "eligible"
5875 ORDER BY
5876 "schulze_rank",
5877 "id"
5878 LIMIT 1
5879 ) AS "subquery"
5880 WHERE "id" = "subquery"."initiative_id";
5881 -- write (final) ranks:
5882 "rank_v" := 1;
5883 FOR "initiative_id_v" IN
5884 SELECT "id"
5885 FROM "initiative"
5886 WHERE "issue_id" = "issue_id_p" AND "admitted"
5887 ORDER BY
5888 "winner" DESC,
5889 "eligible" DESC,
5890 "schulze_rank",
5891 "id"
5892 LOOP
5893 UPDATE "initiative" SET "rank" = "rank_v"
5894 WHERE "id" = "initiative_id_v";
5895 "rank_v" := "rank_v" + 1;
5896 END LOOP;
5897 -- set schulze rank of status quo and mark issue as finished:
5898 UPDATE "issue" SET
5899 "status_quo_schulze_rank" = "rank_ary"[1],
5900 "state" =
5901 CASE WHEN EXISTS (
5902 SELECT NULL FROM "initiative"
5903 WHERE "issue_id" = "issue_id_p" AND "winner"
5904 ) THEN
5905 'finished_with_winner'::"issue_state"
5906 ELSE
5907 'finished_without_winner'::"issue_state"
5908 END,
5909 "closed" = "phase_finished",
5910 "phase_finished" = NULL
5911 WHERE "id" = "issue_id_p";
5912 RETURN;
5913 END;
5914 $$;
5916 COMMENT ON FUNCTION "calculate_ranks"
5917 ( "issue"."id"%TYPE )
5918 IS 'Determine ranking (Votes have to be counted first)';
5922 -----------------------------
5923 -- Automatic state changes --
5924 -----------------------------
5927 CREATE FUNCTION "issue_admission"
5928 ( "area_id_p" "area"."id"%TYPE )
5929 RETURNS BOOLEAN
5930 LANGUAGE 'plpgsql' VOLATILE AS $$
5931 DECLARE
5932 "issue_id_v" "issue"."id"%TYPE;
5933 BEGIN
5934 PERFORM "dont_require_transaction_isolation"();
5935 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
5936 UPDATE "area" SET "issue_quorum" = "view"."issue_quorum"
5937 FROM "area_quorum" AS "view"
5938 WHERE "area"."id" = "view"."area_id"
5939 AND "area"."id" = "area_id_p";
5940 SELECT "id" INTO "issue_id_v" FROM "issue_for_admission"
5941 WHERE "area_id" = "area_id_p";
5942 IF "issue_id_v" ISNULL THEN RETURN FALSE; END IF;
5943 UPDATE "issue" SET
5944 "admission_snapshot_id" = "latest_snapshot_id",
5945 "state" = 'discussion',
5946 "accepted" = now(),
5947 "phase_finished" = NULL
5948 WHERE "id" = "issue_id_v";
5949 RETURN TRUE;
5950 END;
5951 $$;
5953 COMMENT ON FUNCTION "issue_admission"
5954 ( "area"."id"%TYPE )
5955 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';
5958 CREATE TYPE "check_issue_persistence" AS (
5959 "state" "issue_state",
5960 "phase_finished" BOOLEAN,
5961 "issue_revoked" BOOLEAN,
5962 "snapshot_created" BOOLEAN,
5963 "harmonic_weights_set" BOOLEAN,
5964 "closed_voting" BOOLEAN );
5966 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';
5969 CREATE FUNCTION "check_issue"
5970 ( "issue_id_p" "issue"."id"%TYPE,
5971 "persist" "check_issue_persistence" )
5972 RETURNS "check_issue_persistence"
5973 LANGUAGE 'plpgsql' VOLATILE AS $$
5974 DECLARE
5975 "issue_row" "issue"%ROWTYPE;
5976 "last_calculated_v" "snapshot"."calculated"%TYPE;
5977 "policy_row" "policy"%ROWTYPE;
5978 "initiative_row" "initiative"%ROWTYPE;
5979 "state_v" "issue_state";
5980 BEGIN
5981 PERFORM "require_transaction_isolation"();
5982 IF "persist" ISNULL THEN
5983 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
5984 FOR UPDATE;
5985 SELECT "calculated" INTO "last_calculated_v"
5986 FROM "snapshot" JOIN "snapshot_issue"
5987 ON "snapshot"."id" = "snapshot_issue"."snapshot_id"
5988 WHERE "snapshot_issue"."issue_id" = "issue_id_p";
5989 IF "issue_row"."closed" NOTNULL THEN
5990 RETURN NULL;
5991 END IF;
5992 "persist"."state" := "issue_row"."state";
5993 IF
5994 ( "issue_row"."state" = 'admission' AND "last_calculated_v" >=
5995 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
5996 ( "issue_row"."state" = 'discussion' AND now() >=
5997 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
5998 ( "issue_row"."state" = 'verification' AND now() >=
5999 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
6000 ( "issue_row"."state" = 'voting' AND now() >=
6001 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
6002 THEN
6003 "persist"."phase_finished" := TRUE;
6004 ELSE
6005 "persist"."phase_finished" := FALSE;
6006 END IF;
6007 IF
6008 NOT EXISTS (
6009 -- all initiatives are revoked
6010 SELECT NULL FROM "initiative"
6011 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6012 ) AND (
6013 -- and issue has not been accepted yet
6014 "persist"."state" = 'admission' OR
6015 -- or verification time has elapsed
6016 ( "persist"."state" = 'verification' AND
6017 "persist"."phase_finished" ) OR
6018 -- or no initiatives have been revoked lately
6019 NOT EXISTS (
6020 SELECT NULL FROM "initiative"
6021 WHERE "issue_id" = "issue_id_p"
6022 AND now() < "revoked" + "issue_row"."verification_time"
6025 THEN
6026 "persist"."issue_revoked" := TRUE;
6027 ELSE
6028 "persist"."issue_revoked" := FALSE;
6029 END IF;
6030 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
6031 UPDATE "issue" SET "phase_finished" = now()
6032 WHERE "id" = "issue_row"."id";
6033 RETURN "persist";
6034 ELSIF
6035 "persist"."state" IN ('admission', 'discussion', 'verification')
6036 THEN
6037 RETURN "persist";
6038 ELSE
6039 RETURN NULL;
6040 END IF;
6041 END IF;
6042 IF
6043 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6044 coalesce("persist"."snapshot_created", FALSE) = FALSE
6045 THEN
6046 IF "persist"."state" != 'admission' THEN
6047 PERFORM "take_snapshot"("issue_id_p");
6048 PERFORM "finish_snapshot"("issue_id_p");
6049 END IF;
6050 "persist"."snapshot_created" = TRUE;
6051 IF "persist"."phase_finished" THEN
6052 IF "persist"."state" = 'admission' THEN
6053 UPDATE "issue" SET "admission_snapshot_id" = "latest_snapshot_id"
6054 WHERE "id" = "issue_id_p";
6055 ELSIF "persist"."state" = 'discussion' THEN
6056 UPDATE "issue" SET "half_freeze_snapshot_id" = "latest_snapshot_id"
6057 WHERE "id" = "issue_id_p";
6058 ELSIF "persist"."state" = 'verification' THEN
6059 UPDATE "issue" SET "full_freeze_snapshot_id" = "latest_snapshot_id"
6060 WHERE "id" = "issue_id_p";
6061 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
6062 SELECT * INTO "policy_row" FROM "policy"
6063 WHERE "id" = "issue_row"."policy_id";
6064 FOR "initiative_row" IN
6065 SELECT * FROM "initiative"
6066 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6067 FOR UPDATE
6068 LOOP
6069 IF
6070 "initiative_row"."polling" OR (
6071 "initiative_row"."satisfied_supporter_count" >=
6072 "policy_row"."initiative_quorum" AND
6073 "initiative_row"."satisfied_supporter_count" *
6074 "policy_row"."initiative_quorum_den" >=
6075 "issue_row"."population" * "policy_row"."initiative_quorum_num"
6077 THEN
6078 UPDATE "initiative" SET "admitted" = TRUE
6079 WHERE "id" = "initiative_row"."id";
6080 ELSE
6081 UPDATE "initiative" SET "admitted" = FALSE
6082 WHERE "id" = "initiative_row"."id";
6083 END IF;
6084 END LOOP;
6085 END IF;
6086 END IF;
6087 RETURN "persist";
6088 END IF;
6089 IF
6090 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6091 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
6092 THEN
6093 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
6094 "persist"."harmonic_weights_set" = TRUE;
6095 IF
6096 "persist"."phase_finished" OR
6097 "persist"."issue_revoked" OR
6098 "persist"."state" = 'admission'
6099 THEN
6100 RETURN "persist";
6101 ELSE
6102 RETURN NULL;
6103 END IF;
6104 END IF;
6105 IF "persist"."issue_revoked" THEN
6106 IF "persist"."state" = 'admission' THEN
6107 "state_v" := 'canceled_revoked_before_accepted';
6108 ELSIF "persist"."state" = 'discussion' THEN
6109 "state_v" := 'canceled_after_revocation_during_discussion';
6110 ELSIF "persist"."state" = 'verification' THEN
6111 "state_v" := 'canceled_after_revocation_during_verification';
6112 END IF;
6113 UPDATE "issue" SET
6114 "state" = "state_v",
6115 "closed" = "phase_finished",
6116 "phase_finished" = NULL
6117 WHERE "id" = "issue_id_p";
6118 RETURN NULL;
6119 END IF;
6120 IF "persist"."state" = 'admission' THEN
6121 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6122 FOR UPDATE;
6123 IF "issue_row"."phase_finished" NOTNULL THEN
6124 UPDATE "issue" SET
6125 "state" = 'canceled_issue_not_accepted',
6126 "closed" = "phase_finished",
6127 "phase_finished" = NULL
6128 WHERE "id" = "issue_id_p";
6129 END IF;
6130 RETURN NULL;
6131 END IF;
6132 IF "persist"."phase_finished" THEN
6133 IF "persist"."state" = 'discussion' THEN
6134 UPDATE "issue" SET
6135 "state" = 'verification',
6136 "half_frozen" = "phase_finished",
6137 "phase_finished" = NULL
6138 WHERE "id" = "issue_id_p";
6139 RETURN NULL;
6140 END IF;
6141 IF "persist"."state" = 'verification' THEN
6142 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6143 FOR UPDATE;
6144 SELECT * INTO "policy_row" FROM "policy"
6145 WHERE "id" = "issue_row"."policy_id";
6146 IF EXISTS (
6147 SELECT NULL FROM "initiative"
6148 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
6149 ) THEN
6150 UPDATE "issue" SET
6151 "state" = 'voting',
6152 "fully_frozen" = "phase_finished",
6153 "phase_finished" = NULL
6154 WHERE "id" = "issue_id_p";
6155 ELSE
6156 UPDATE "issue" SET
6157 "state" = 'canceled_no_initiative_admitted',
6158 "fully_frozen" = "phase_finished",
6159 "closed" = "phase_finished",
6160 "phase_finished" = NULL
6161 WHERE "id" = "issue_id_p";
6162 -- NOTE: The following DELETE statements have effect only when
6163 -- issue state has been manipulated
6164 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
6165 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
6166 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
6167 END IF;
6168 RETURN NULL;
6169 END IF;
6170 IF "persist"."state" = 'voting' THEN
6171 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
6172 PERFORM "close_voting"("issue_id_p");
6173 "persist"."closed_voting" = TRUE;
6174 RETURN "persist";
6175 END IF;
6176 PERFORM "calculate_ranks"("issue_id_p");
6177 RETURN NULL;
6178 END IF;
6179 END IF;
6180 RAISE WARNING 'should not happen';
6181 RETURN NULL;
6182 END;
6183 $$;
6185 COMMENT ON FUNCTION "check_issue"
6186 ( "issue"."id"%TYPE,
6187 "check_issue_persistence" )
6188 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")';
6191 CREATE FUNCTION "check_everything"()
6192 RETURNS VOID
6193 LANGUAGE 'plpgsql' VOLATILE AS $$
6194 DECLARE
6195 "area_id_v" "area"."id"%TYPE;
6196 "snapshot_id_v" "snapshot"."id"%TYPE;
6197 "issue_id_v" "issue"."id"%TYPE;
6198 "persist_v" "check_issue_persistence";
6199 BEGIN
6200 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
6201 DELETE FROM "expired_session";
6202 DELETE FROM "expired_token";
6203 DELETE FROM "expired_snapshot";
6204 PERFORM "check_activity"();
6205 PERFORM "calculate_member_counts"();
6206 FOR "area_id_v" IN SELECT "id" FROM "area_with_unaccepted_issues" LOOP
6207 SELECT "take_snapshot"(NULL, "area_id_v") INTO "snapshot_id_v";
6208 PERFORM "finish_snapshot"("issue_id") FROM "snapshot_issue"
6209 WHERE "snapshot_id" = "snapshot_id_v";
6210 LOOP
6211 EXIT WHEN "issue_admission"("area_id_v") = FALSE;
6212 END LOOP;
6213 END LOOP;
6214 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
6215 "persist_v" := NULL;
6216 LOOP
6217 "persist_v" := "check_issue"("issue_id_v", "persist_v");
6218 EXIT WHEN "persist_v" ISNULL;
6219 END LOOP;
6220 END LOOP;
6221 RETURN;
6222 END;
6223 $$;
6225 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';
6229 ----------------------
6230 -- Deletion of data --
6231 ----------------------
6234 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
6235 RETURNS VOID
6236 LANGUAGE 'plpgsql' VOLATILE AS $$
6237 BEGIN
6238 IF EXISTS (
6239 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
6240 ) THEN
6241 -- override protection triggers:
6242 INSERT INTO "temporary_transaction_data" ("key", "value")
6243 VALUES ('override_protection_triggers', TRUE::TEXT);
6244 -- clean data:
6245 DELETE FROM "delegating_voter"
6246 WHERE "issue_id" = "issue_id_p";
6247 DELETE FROM "direct_voter"
6248 WHERE "issue_id" = "issue_id_p";
6249 DELETE FROM "delegating_interest_snapshot"
6250 WHERE "issue_id" = "issue_id_p";
6251 DELETE FROM "direct_interest_snapshot"
6252 WHERE "issue_id" = "issue_id_p";
6253 DELETE FROM "non_voter"
6254 WHERE "issue_id" = "issue_id_p";
6255 DELETE FROM "delegation"
6256 WHERE "issue_id" = "issue_id_p";
6257 DELETE FROM "supporter"
6258 USING "initiative" -- NOTE: due to missing index on issue_id
6259 WHERE "initiative"."issue_id" = "issue_id_p"
6260 AND "supporter"."initiative_id" = "initiative_id";
6261 -- mark issue as cleaned:
6262 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
6263 -- finish overriding protection triggers (avoids garbage):
6264 DELETE FROM "temporary_transaction_data"
6265 WHERE "key" = 'override_protection_triggers';
6266 END IF;
6267 RETURN;
6268 END;
6269 $$;
6271 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
6274 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
6275 RETURNS VOID
6276 LANGUAGE 'plpgsql' VOLATILE AS $$
6277 BEGIN
6278 UPDATE "member" SET
6279 "last_login" = NULL,
6280 "last_delegation_check" = NULL,
6281 "login" = NULL,
6282 "password" = NULL,
6283 "authority" = NULL,
6284 "authority_uid" = NULL,
6285 "authority_login" = NULL,
6286 "deleted" = coalesce("deleted", now()),
6287 "locked" = TRUE,
6288 "active" = FALSE,
6289 "notify_email" = NULL,
6290 "notify_email_unconfirmed" = NULL,
6291 "notify_email_secret" = NULL,
6292 "notify_email_secret_expiry" = NULL,
6293 "notify_email_lock_expiry" = NULL,
6294 "disable_notifications" = TRUE,
6295 "notification_counter" = DEFAULT,
6296 "notification_sample_size" = 0,
6297 "notification_dow" = NULL,
6298 "notification_hour" = NULL,
6299 "notification_sent" = NULL,
6300 "login_recovery_expiry" = NULL,
6301 "password_reset_secret" = NULL,
6302 "password_reset_secret_expiry" = NULL,
6303 "location" = NULL
6304 WHERE "id" = "member_id_p";
6305 -- "text_search_data" is updated by triggers
6306 DELETE FROM "member_settings" WHERE "member_id" = "member_id_p";
6307 DELETE FROM "member_profile" WHERE "member_id" = "member_id_p";
6308 DELETE FROM "rendered_member_statement" WHERE "member_id" = "member_id_p";
6309 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
6310 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
6311 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
6312 DELETE FROM "session" WHERE "member_id" = "member_id_p";
6313 DELETE FROM "member_application" WHERE "member_id" = "member_id_p";
6314 DELETE FROM "token" WHERE "member_id" = "member_id_p";
6315 DELETE FROM "subscription" WHERE "member_id" = "member_id_p";
6316 DELETE FROM "ignored_area" WHERE "member_id" = "member_id_p";
6317 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
6318 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
6319 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
6320 DELETE FROM "direct_voter" USING "issue"
6321 WHERE "direct_voter"."issue_id" = "issue"."id"
6322 AND "issue"."closed" ISNULL
6323 AND "member_id" = "member_id_p";
6324 DELETE FROM "notification_initiative_sent" WHERE "member_id" = "member_id_p";
6325 RETURN;
6326 END;
6327 $$;
6329 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)';
6332 CREATE FUNCTION "delete_private_data"()
6333 RETURNS VOID
6334 LANGUAGE 'plpgsql' VOLATILE AS $$
6335 BEGIN
6336 DELETE FROM "temporary_transaction_data";
6337 DELETE FROM "temporary_suggestion_counts";
6338 DELETE FROM "member" WHERE "activated" ISNULL;
6339 UPDATE "member" SET
6340 "invite_code" = NULL,
6341 "invite_code_expiry" = NULL,
6342 "admin_comment" = NULL,
6343 "last_login" = NULL,
6344 "last_delegation_check" = NULL,
6345 "login" = NULL,
6346 "password" = NULL,
6347 "authority" = NULL,
6348 "authority_uid" = NULL,
6349 "authority_login" = NULL,
6350 "lang" = NULL,
6351 "notify_email" = NULL,
6352 "notify_email_unconfirmed" = NULL,
6353 "notify_email_secret" = NULL,
6354 "notify_email_secret_expiry" = NULL,
6355 "notify_email_lock_expiry" = NULL,
6356 "disable_notifications" = TRUE,
6357 "notification_counter" = DEFAULT,
6358 "notification_sample_size" = 0,
6359 "notification_dow" = NULL,
6360 "notification_hour" = NULL,
6361 "notification_sent" = NULL,
6362 "login_recovery_expiry" = NULL,
6363 "password_reset_secret" = NULL,
6364 "password_reset_secret_expiry" = NULL,
6365 "location" = NULL;
6366 -- "text_search_data" is updated by triggers
6367 DELETE FROM "verification";
6368 DELETE FROM "member_settings";
6369 DELETE FROM "member_useterms";
6370 DELETE FROM "member_profile";
6371 DELETE FROM "rendered_member_statement";
6372 DELETE FROM "member_image";
6373 DELETE FROM "contact";
6374 DELETE FROM "ignored_member";
6375 DELETE FROM "session";
6376 DELETE FROM "system_application";
6377 DELETE FROM "system_application_redirect_uri";
6378 DELETE FROM "dynamic_application_scope";
6379 DELETE FROM "member_application";
6380 DELETE FROM "token";
6381 DELETE FROM "subscription";
6382 DELETE FROM "ignored_area";
6383 DELETE FROM "ignored_initiative";
6384 DELETE FROM "non_voter";
6385 DELETE FROM "direct_voter" USING "issue"
6386 WHERE "direct_voter"."issue_id" = "issue"."id"
6387 AND "issue"."closed" ISNULL;
6388 DELETE FROM "event_processed";
6389 DELETE FROM "notification_initiative_sent";
6390 DELETE FROM "newsletter";
6391 RETURN;
6392 END;
6393 $$;
6395 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.';
6399 COMMIT;

Impressum / About Us