liquid_feedback_core

view core.sql @ 561:fb2663ca1e6b

Added missing WHERE clause in "check_issue" function when updating snapshot IDs of issues
author jbe
date Mon Sep 25 14:20:07 2017 +0200 (2017-09-25)
parents 318827ecd041
children c3931054bb55
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" NOTNULL) OR ("boolean_value" = FALSE) 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 SELECT * INTO "issue_row" FROM "issue"
1949 WHERE "id" = NEW."issue_id" FOR SHARE;
1950 SELECT * INTO "area_row" FROM "area"
1951 WHERE "id" = "issue_row"."area_id" FOR SHARE;
1952 SELECT "id" INTO "draft_id_v" FROM "current_draft"
1953 WHERE "initiative_id" = NEW."id" FOR SHARE;
1954 INSERT INTO "event" (
1955 "event", "member_id",
1956 "unit_id", "area_id", "policy_id", "issue_id", "state",
1957 "initiative_id", "draft_id"
1958 ) VALUES (
1959 'initiative_revoked', NEW."revoked_by_member_id",
1960 "area_row"."unit_id", "issue_row"."area_id",
1961 "issue_row"."policy_id",
1962 NEW."issue_id", "issue_row"."state",
1963 NEW."id", "draft_id_v"
1964 );
1965 END IF;
1966 RETURN NULL;
1967 END;
1968 $$;
1970 CREATE TRIGGER "write_event_initiative_revoked"
1971 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
1972 "write_event_initiative_revoked_trigger"();
1974 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
1975 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
1978 CREATE FUNCTION "write_event_suggestion_created_trigger"()
1979 RETURNS TRIGGER
1980 LANGUAGE 'plpgsql' VOLATILE AS $$
1981 DECLARE
1982 "initiative_row" "initiative"%ROWTYPE;
1983 "issue_row" "issue"%ROWTYPE;
1984 "area_row" "area"%ROWTYPE;
1985 BEGIN
1986 SELECT * INTO "initiative_row" FROM "initiative"
1987 WHERE "id" = NEW."initiative_id" FOR SHARE;
1988 SELECT * INTO "issue_row" FROM "issue"
1989 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
1990 SELECT * INTO "area_row" FROM "area"
1991 WHERE "id" = "issue_row"."area_id" FOR SHARE;
1992 INSERT INTO "event" (
1993 "event", "member_id",
1994 "unit_id", "area_id", "policy_id", "issue_id", "state",
1995 "initiative_id", "suggestion_id"
1996 ) VALUES (
1997 'suggestion_created', NEW."author_id",
1998 "area_row"."unit_id", "issue_row"."area_id", "issue_row"."policy_id",
1999 "initiative_row"."issue_id", "issue_row"."state",
2000 NEW."initiative_id", NEW."id"
2001 );
2002 RETURN NULL;
2003 END;
2004 $$;
2006 CREATE TRIGGER "write_event_suggestion_created"
2007 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2008 "write_event_suggestion_created_trigger"();
2010 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
2011 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2014 CREATE FUNCTION "write_event_suggestion_removed_trigger"()
2015 RETURNS TRIGGER
2016 LANGUAGE 'plpgsql' VOLATILE AS $$
2017 DECLARE
2018 "initiative_row" "initiative"%ROWTYPE;
2019 "issue_row" "issue"%ROWTYPE;
2020 "area_row" "area"%ROWTYPE;
2021 BEGIN
2022 SELECT * INTO "initiative_row" FROM "initiative"
2023 WHERE "id" = OLD."initiative_id" FOR SHARE;
2024 IF "initiative_row"."id" NOTNULL THEN
2025 SELECT * INTO "issue_row" FROM "issue"
2026 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2027 SELECT * INTO "area_row" FROM "area"
2028 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2029 INSERT INTO "event" (
2030 "event",
2031 "unit_id", "area_id", "policy_id", "issue_id", "state",
2032 "initiative_id", "suggestion_id"
2033 ) VALUES (
2034 'suggestion_deleted',
2035 "area_row"."unit_id", "issue_row"."area_id",
2036 "issue_row"."policy_id",
2037 "initiative_row"."issue_id", "issue_row"."state",
2038 OLD."initiative_id", OLD."id"
2039 );
2040 END IF;
2041 RETURN NULL;
2042 END;
2043 $$;
2045 CREATE TRIGGER "write_event_suggestion_removed"
2046 AFTER DELETE ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
2047 "write_event_suggestion_removed_trigger"();
2049 COMMENT ON FUNCTION "write_event_suggestion_removed_trigger"() IS 'Implementation of trigger "write_event_suggestion_removed" on table "issue"';
2050 COMMENT ON TRIGGER "write_event_suggestion_removed" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
2053 CREATE FUNCTION "write_event_member_trigger"()
2054 RETURNS TRIGGER
2055 LANGUAGE 'plpgsql' VOLATILE AS $$
2056 BEGIN
2057 IF TG_OP = 'INSERT' THEN
2058 IF NEW."activated" NOTNULL AND NEW."deleted" ISNULL THEN
2059 INSERT INTO "event" ("event", "member_id")
2060 VALUES ('member_activated', NEW."id");
2061 END IF;
2062 IF NEW."active" THEN
2063 INSERT INTO "event" ("event", "member_id", "boolean_value")
2064 VALUES ('member_active', NEW."id", TRUE);
2065 END IF;
2066 ELSIF TG_OP = 'UPDATE' THEN
2067 IF OLD."id" != NEW."id" THEN
2068 RAISE EXCEPTION 'Cannot change member ID';
2069 END IF;
2070 IF
2071 (OLD."activated" ISNULL OR OLD."deleted" NOTNULL) AND
2072 NEW."activated" NOTNULL AND NEW."deleted" ISNULL
2073 THEN
2074 INSERT INTO "event" ("event", "member_id")
2075 VALUES ('member_activated', NEW."id");
2076 END IF;
2077 IF OLD."active" != NEW."active" THEN
2078 INSERT INTO "event" ("event", "member_id", "boolean_value") VALUES (
2079 'member_active', NEW."id", NEW."active"
2080 );
2081 END IF;
2082 IF OLD."name" != NEW."name" THEN
2083 INSERT INTO "event" (
2084 "event", "member_id", "text_value", "old_text_value"
2085 ) VALUES (
2086 'member_name_updated', NEW."id", NEW."name", OLD."name"
2087 );
2088 END IF;
2089 IF
2090 OLD."activated" NOTNULL AND OLD."deleted" ISNULL AND
2091 (NEW."activated" ISNULL OR NEW."deleted" NOTNULL)
2092 THEN
2093 INSERT INTO "event" ("event", "member_id")
2094 VALUES ('member_deleted', NEW."id");
2095 END IF;
2096 END IF;
2097 RETURN NULL;
2098 END;
2099 $$;
2101 CREATE TRIGGER "write_event_member"
2102 AFTER INSERT OR UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE
2103 "write_event_member_trigger"();
2105 COMMENT ON FUNCTION "write_event_member_trigger"() IS 'Implementation of trigger "write_event_member" on table "member"';
2106 COMMENT ON TRIGGER "write_event_member" ON "member" IS 'Create entries in "event" table on insertion to member table';
2109 CREATE FUNCTION "write_event_member_profile_updated_trigger"()
2110 RETURNS TRIGGER
2111 LANGUAGE 'plpgsql' VOLATILE AS $$
2112 BEGIN
2113 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2114 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2115 INSERT INTO "event" ("event", "member_id") VALUES (
2116 'member_profile_updated', OLD."member_id"
2117 );
2118 END IF;
2119 END IF;
2120 IF TG_OP = 'UPDATE' THEN
2121 IF OLD."member_id" = NEW."member_id" THEN
2122 RETURN NULL;
2123 END IF;
2124 END IF;
2125 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2126 INSERT INTO "event" ("event", "member_id") VALUES (
2127 'member_profile_updated', NEW."member_id"
2128 );
2129 END IF;
2130 RETURN NULL;
2131 END;
2132 $$;
2134 CREATE TRIGGER "write_event_member_profile_updated"
2135 AFTER INSERT OR UPDATE OR DELETE ON "member_profile"
2136 FOR EACH ROW EXECUTE PROCEDURE
2137 "write_event_member_profile_updated_trigger"();
2139 COMMENT ON FUNCTION "write_event_member_profile_updated_trigger"() IS 'Implementation of trigger "write_event_member_profile_updated" on table "member_profile"';
2140 COMMENT ON TRIGGER "write_event_member_profile_updated" ON "member_profile" IS 'Creates entries in "event" table on member profile update';
2143 CREATE FUNCTION "write_event_member_image_updated_trigger"()
2144 RETURNS TRIGGER
2145 LANGUAGE 'plpgsql' VOLATILE AS $$
2146 BEGIN
2147 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2148 IF NOT OLD."scaled" THEN
2149 IF EXISTS (SELECT NULL FROM "member" WHERE "id" = OLD."member_id") THEN
2150 INSERT INTO "event" ("event", "member_id") VALUES (
2151 'member_image_updated', OLD."member_id"
2152 );
2153 END IF;
2154 END IF;
2155 END IF;
2156 IF TG_OP = 'UPDATE' THEN
2157 IF
2158 OLD."member_id" = NEW."member_id" AND
2159 OLD."scaled" = NEW."scaled"
2160 THEN
2161 RETURN NULL;
2162 END IF;
2163 END IF;
2164 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2165 IF NOT NEW."scaled" THEN
2166 INSERT INTO "event" ("event", "member_id") VALUES (
2167 'member_image_updated', NEW."member_id"
2168 );
2169 END IF;
2170 END IF;
2171 RETURN NULL;
2172 END;
2173 $$;
2175 CREATE TRIGGER "write_event_member_image_updated"
2176 AFTER INSERT OR UPDATE OR DELETE ON "member_image"
2177 FOR EACH ROW EXECUTE PROCEDURE
2178 "write_event_member_image_updated_trigger"();
2180 COMMENT ON FUNCTION "write_event_member_image_updated_trigger"() IS 'Implementation of trigger "write_event_member_image_updated" on table "member_image"';
2181 COMMENT ON TRIGGER "write_event_member_image_updated" ON "member_image" IS 'Creates entries in "event" table on member image update';
2184 CREATE FUNCTION "write_event_interest_trigger"()
2185 RETURNS TRIGGER
2186 LANGUAGE 'plpgsql' VOLATILE AS $$
2187 DECLARE
2188 "issue_row" "issue"%ROWTYPE;
2189 "area_row" "area"%ROWTYPE;
2190 BEGIN
2191 IF TG_OP = 'UPDATE' THEN
2192 IF OLD = NEW THEN
2193 RETURN NULL;
2194 END IF;
2195 END IF;
2196 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2197 SELECT * INTO "issue_row" FROM "issue"
2198 WHERE "id" = OLD."issue_id" FOR SHARE;
2199 SELECT * INTO "area_row" FROM "area"
2200 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2201 IF "issue_row"."id" NOTNULL THEN
2202 INSERT INTO "event" (
2203 "event", "member_id",
2204 "unit_id", "area_id", "policy_id", "issue_id", "state",
2205 "boolean_value"
2206 ) VALUES (
2207 'interest', OLD."member_id",
2208 "area_row"."unit_id", "issue_row"."area_id",
2209 "issue_row"."policy_id",
2210 OLD."issue_id", "issue_row"."state",
2211 FALSE
2212 );
2213 END IF;
2214 END IF;
2215 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2216 SELECT * INTO "issue_row" FROM "issue"
2217 WHERE "id" = NEW."issue_id" FOR SHARE;
2218 SELECT * INTO "area_row" FROM "area"
2219 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2220 INSERT INTO "event" (
2221 "event", "member_id",
2222 "unit_id", "area_id", "policy_id", "issue_id", "state",
2223 "boolean_value"
2224 ) VALUES (
2225 'interest', NEW."member_id",
2226 "area_row"."unit_id", "issue_row"."area_id",
2227 "issue_row"."policy_id",
2228 NEW."issue_id", "issue_row"."state",
2229 TRUE
2230 );
2231 END IF;
2232 RETURN NULL;
2233 END;
2234 $$;
2236 CREATE TRIGGER "write_event_interest"
2237 AFTER INSERT OR UPDATE OR DELETE ON "interest" FOR EACH ROW EXECUTE PROCEDURE
2238 "write_event_interest_trigger"();
2240 COMMENT ON FUNCTION "write_event_interest_trigger"() IS 'Implementation of trigger "write_event_interest_inserted" on table "interest"';
2241 COMMENT ON TRIGGER "write_event_interest" ON "interest" IS 'Create entry in "event" table on adding or removing interest';
2244 CREATE FUNCTION "write_event_initiator_trigger"()
2245 RETURNS TRIGGER
2246 LANGUAGE 'plpgsql' VOLATILE AS $$
2247 DECLARE
2248 "initiative_row" "initiative"%ROWTYPE;
2249 "issue_row" "issue"%ROWTYPE;
2250 "area_row" "area"%ROWTYPE;
2251 "accepted_v" BOOLEAN = FALSE;
2252 "rejected_v" BOOLEAN = FALSE;
2253 BEGIN
2254 IF TG_OP = 'UPDATE' THEN
2255 IF
2256 OLD."initiative_id" = NEW."initiative_id" AND
2257 OLD."member_id" = NEW."member_id"
2258 THEN
2259 IF
2260 coalesce(OLD."accepted", FALSE) = coalesce(NEW."accepted", FALSE)
2261 THEN
2262 RETURN NULL;
2263 END IF;
2264 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2265 "accepted_v" := TRUE;
2266 ELSE
2267 "rejected_v" := TRUE;
2268 END IF;
2269 END IF;
2270 END IF;
2271 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "accepted_v" THEN
2272 IF coalesce(OLD."accepted", FALSE) = TRUE THEN
2273 SELECT * INTO "initiative_row" FROM "initiative"
2274 WHERE "id" = OLD."initiative_id" FOR SHARE;
2275 IF "initiative_row"."id" NOTNULL THEN
2276 SELECT * INTO "issue_row" FROM "issue"
2277 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2278 SELECT * INTO "area_row" FROM "area"
2279 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2280 INSERT INTO "event" (
2281 "event", "member_id",
2282 "unit_id", "area_id", "policy_id", "issue_id", "state",
2283 "initiative_id", "boolean_value"
2284 ) VALUES (
2285 'initiator', OLD."member_id",
2286 "area_row"."unit_id", "issue_row"."area_id",
2287 "issue_row"."policy_id",
2288 "issue_row"."id", "issue_row"."state",
2289 OLD."initiative_id", FALSE
2290 );
2291 END IF;
2292 END IF;
2293 END IF;
2294 IF TG_OP = 'UPDATE' AND NOT "rejected_v" THEN
2295 IF coalesce(NEW."accepted", FALSE) = TRUE THEN
2296 SELECT * INTO "initiative_row" FROM "initiative"
2297 WHERE "id" = NEW."initiative_id" FOR SHARE;
2298 SELECT * INTO "issue_row" FROM "issue"
2299 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2300 SELECT * INTO "area_row" FROM "area"
2301 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2302 INSERT INTO "event" (
2303 "event", "member_id",
2304 "unit_id", "area_id", "policy_id", "issue_id", "state",
2305 "initiative_id", "boolean_value"
2306 ) VALUES (
2307 'initiator', NEW."member_id",
2308 "area_row"."unit_id", "issue_row"."area_id",
2309 "issue_row"."policy_id",
2310 "issue_row"."id", "issue_row"."state",
2311 NEW."initiative_id", TRUE
2312 );
2313 END IF;
2314 END IF;
2315 RETURN NULL;
2316 END;
2317 $$;
2319 CREATE TRIGGER "write_event_initiator"
2320 AFTER UPDATE OR DELETE ON "initiator" FOR EACH ROW EXECUTE PROCEDURE
2321 "write_event_initiator_trigger"();
2323 COMMENT ON FUNCTION "write_event_initiator_trigger"() IS 'Implementation of trigger "write_event_initiator" on table "initiator"';
2324 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)';
2327 CREATE FUNCTION "write_event_support_trigger"()
2328 RETURNS TRIGGER
2329 LANGUAGE 'plpgsql' VOLATILE AS $$
2330 DECLARE
2331 "issue_row" "issue"%ROWTYPE;
2332 "area_row" "area"%ROWTYPE;
2333 BEGIN
2334 IF TG_OP = 'UPDATE' THEN
2335 IF
2336 OLD."initiative_id" = NEW."initiative_id" AND
2337 OLD."member_id" = NEW."member_id"
2338 THEN
2339 IF OLD."draft_id" != NEW."draft_id" THEN
2340 SELECT * INTO "issue_row" FROM "issue"
2341 WHERE "id" = NEW."issue_id" FOR SHARE;
2342 SELECT * INTO "area_row" FROM "area"
2343 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2344 INSERT INTO "event" (
2345 "event", "member_id",
2346 "unit_id", "area_id", "policy_id", "issue_id", "state",
2347 "initiative_id", "draft_id"
2348 ) VALUES (
2349 'support_updated', NEW."member_id",
2350 "area_row"."unit_id", "issue_row"."area_id",
2351 "issue_row"."policy_id",
2352 "issue_row"."id", "issue_row"."state",
2353 NEW."initiative_id", NEW."draft_id"
2354 );
2355 END IF;
2356 RETURN NULL;
2357 END IF;
2358 END IF;
2359 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2360 IF EXISTS (
2361 SELECT NULL FROM "initiative" WHERE "id" = OLD."initiative_id"
2362 FOR SHARE
2363 ) THEN
2364 SELECT * INTO "issue_row" FROM "issue"
2365 WHERE "id" = OLD."issue_id" FOR SHARE;
2366 SELECT * INTO "area_row" FROM "area"
2367 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2368 INSERT INTO "event" (
2369 "event", "member_id",
2370 "unit_id", "area_id", "policy_id", "issue_id", "state",
2371 "initiative_id", "boolean_value"
2372 ) VALUES (
2373 'support', OLD."member_id",
2374 "area_row"."unit_id", "issue_row"."area_id",
2375 "issue_row"."policy_id",
2376 "issue_row"."id", "issue_row"."state",
2377 OLD."initiative_id", FALSE
2378 );
2379 END IF;
2380 END IF;
2381 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2382 SELECT * INTO "issue_row" FROM "issue"
2383 WHERE "id" = NEW."issue_id" FOR SHARE;
2384 SELECT * INTO "area_row" FROM "area"
2385 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2386 INSERT INTO "event" (
2387 "event", "member_id",
2388 "unit_id", "area_id", "policy_id", "issue_id", "state",
2389 "initiative_id", "draft_id", "boolean_value"
2390 ) VALUES (
2391 'support', NEW."member_id",
2392 "area_row"."unit_id", "issue_row"."area_id",
2393 "issue_row"."policy_id",
2394 "issue_row"."id", "issue_row"."state",
2395 NEW."initiative_id", NEW."draft_id", TRUE
2396 );
2397 END IF;
2398 RETURN NULL;
2399 END;
2400 $$;
2402 CREATE TRIGGER "write_event_support"
2403 AFTER INSERT OR UPDATE OR DELETE ON "supporter" FOR EACH ROW EXECUTE PROCEDURE
2404 "write_event_support_trigger"();
2406 COMMENT ON FUNCTION "write_event_support_trigger"() IS 'Implementation of trigger "write_event_support" on table "supporter"';
2407 COMMENT ON TRIGGER "write_event_support" ON "supporter" IS 'Create entry in "event" table when adding, updating, or removing support';
2410 CREATE FUNCTION "write_event_suggestion_rated_trigger"()
2411 RETURNS TRIGGER
2412 LANGUAGE 'plpgsql' VOLATILE AS $$
2413 DECLARE
2414 "same_pkey_v" BOOLEAN = FALSE;
2415 "initiative_row" "initiative"%ROWTYPE;
2416 "issue_row" "issue"%ROWTYPE;
2417 "area_row" "area"%ROWTYPE;
2418 BEGIN
2419 IF TG_OP = 'UPDATE' THEN
2420 IF
2421 OLD."suggestion_id" = NEW."suggestion_id" AND
2422 OLD."member_id" = NEW."member_id"
2423 THEN
2424 IF
2425 OLD."degree" = NEW."degree" AND
2426 OLD."fulfilled" = NEW."fulfilled"
2427 THEN
2428 RETURN NULL;
2429 END IF;
2430 "same_pkey_v" := TRUE;
2431 END IF;
2432 END IF;
2433 IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND NOT "same_pkey_v" THEN
2434 IF EXISTS (
2435 SELECT NULL FROM "suggestion" WHERE "id" = OLD."suggestion_id"
2436 FOR SHARE
2437 ) THEN
2438 SELECT * INTO "initiative_row" FROM "initiative"
2439 WHERE "id" = OLD."initiative_id" FOR SHARE;
2440 SELECT * INTO "issue_row" FROM "issue"
2441 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2442 SELECT * INTO "area_row" FROM "area"
2443 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2444 INSERT INTO "event" (
2445 "event", "member_id",
2446 "unit_id", "area_id", "policy_id", "issue_id", "state",
2447 "initiative_id", "suggestion_id",
2448 "boolean_value", "numeric_value"
2449 ) VALUES (
2450 'suggestion_rated', OLD."member_id",
2451 "area_row"."unit_id", "issue_row"."area_id",
2452 "issue_row"."policy_id",
2453 "initiative_row"."issue_id", "issue_row"."state",
2454 OLD."initiative_id", OLD."suggestion_id",
2455 NULL, 0
2456 );
2457 END IF;
2458 END IF;
2459 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2460 SELECT * INTO "initiative_row" FROM "initiative"
2461 WHERE "id" = NEW."initiative_id" FOR SHARE;
2462 SELECT * INTO "issue_row" FROM "issue"
2463 WHERE "id" = "initiative_row"."issue_id" FOR SHARE;
2464 SELECT * INTO "area_row" FROM "area"
2465 WHERE "id" = "issue_row"."area_id" FOR SHARE;
2466 INSERT INTO "event" (
2467 "event", "member_id",
2468 "unit_id", "area_id", "policy_id", "issue_id", "state",
2469 "initiative_id", "suggestion_id",
2470 "boolean_value", "numeric_value"
2471 ) VALUES (
2472 'suggestion_rated', NEW."member_id",
2473 "area_row"."unit_id", "issue_row"."area_id",
2474 "issue_row"."policy_id",
2475 "initiative_row"."issue_id", "issue_row"."state",
2476 NEW."initiative_id", NEW."suggestion_id",
2477 NEW."fulfilled", NEW."degree"
2478 );
2479 END IF;
2480 RETURN NULL;
2481 END;
2482 $$;
2484 CREATE TRIGGER "write_event_suggestion_rated"
2485 AFTER INSERT OR UPDATE OR DELETE ON "opinion" FOR EACH ROW EXECUTE PROCEDURE
2486 "write_event_suggestion_rated_trigger"();
2488 COMMENT ON FUNCTION "write_event_suggestion_rated_trigger"() IS 'Implementation of trigger "write_event_suggestion_rated" on table "opinion"';
2489 COMMENT ON TRIGGER "write_event_suggestion_rated" ON "opinion" IS 'Create entry in "event" table when adding, updating, or removing support';
2492 CREATE FUNCTION "write_event_delegation_trigger"()
2493 RETURNS TRIGGER
2494 LANGUAGE 'plpgsql' VOLATILE AS $$
2495 DECLARE
2496 "issue_row" "issue"%ROWTYPE;
2497 "area_row" "area"%ROWTYPE;
2498 BEGIN
2499 IF TG_OP = 'DELETE' THEN
2500 IF EXISTS (
2501 SELECT NULL FROM "member" WHERE "id" = OLD."truster_id"
2502 ) AND (CASE OLD."scope"
2503 WHEN 'unit'::"delegation_scope" THEN EXISTS (
2504 SELECT NULL FROM "unit" WHERE "id" = OLD."unit_id"
2506 WHEN 'area'::"delegation_scope" THEN EXISTS (
2507 SELECT NULL FROM "area" WHERE "id" = OLD."area_id"
2509 WHEN 'issue'::"delegation_scope" THEN EXISTS (
2510 SELECT NULL FROM "issue" WHERE "id" = OLD."issue_id"
2512 END) THEN
2513 SELECT * INTO "issue_row" FROM "issue"
2514 WHERE "id" = OLD."issue_id" FOR SHARE;
2515 SELECT * INTO "area_row" FROM "area"
2516 WHERE "id" = COALESCE(OLD."area_id", "issue_row"."area_id")
2517 FOR SHARE;
2518 INSERT INTO "event" (
2519 "event", "member_id", "scope",
2520 "unit_id", "area_id", "issue_id", "state",
2521 "boolean_value"
2522 ) VALUES (
2523 'delegation', OLD."truster_id", OLD."scope",
2524 COALESCE(OLD."unit_id", "area_row"."unit_id"), "area_row"."id",
2525 OLD."issue_id", "issue_row"."state",
2526 FALSE
2527 );
2528 END IF;
2529 ELSE
2530 SELECT * INTO "issue_row" FROM "issue"
2531 WHERE "id" = NEW."issue_id" FOR SHARE;
2532 SELECT * INTO "area_row" FROM "area"
2533 WHERE "id" = COALESCE(NEW."area_id", "issue_row"."area_id")
2534 FOR SHARE;
2535 INSERT INTO "event" (
2536 "event", "member_id", "other_member_id", "scope",
2537 "unit_id", "area_id", "issue_id", "state",
2538 "boolean_value"
2539 ) VALUES (
2540 'delegation', NEW."truster_id", NEW."trustee_id", NEW."scope",
2541 COALESCE(NEW."unit_id", "area_row"."unit_id"), "area_row"."id",
2542 NEW."issue_id", "issue_row"."state",
2543 TRUE
2544 );
2545 END IF;
2546 RETURN NULL;
2547 END;
2548 $$;
2550 CREATE TRIGGER "write_event_delegation"
2551 AFTER INSERT OR UPDATE OR DELETE ON "delegation" FOR EACH ROW EXECUTE PROCEDURE
2552 "write_event_delegation_trigger"();
2554 COMMENT ON FUNCTION "write_event_delegation_trigger"() IS 'Implementation of trigger "write_event_delegation" on table "delegation"';
2555 COMMENT ON TRIGGER "write_event_delegation" ON "delegation" IS 'Create entry in "event" table when adding, updating, or removing a delegation';
2558 CREATE FUNCTION "write_event_contact_trigger"()
2559 RETURNS TRIGGER
2560 LANGUAGE 'plpgsql' VOLATILE AS $$
2561 BEGIN
2562 IF TG_OP = 'UPDATE' THEN
2563 IF
2564 OLD."member_id" = NEW."member_id" AND
2565 OLD."other_member_id" = NEW."other_member_id" AND
2566 OLD."public" = NEW."public"
2567 THEN
2568 RETURN NULL;
2569 END IF;
2570 END IF;
2571 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
2572 IF OLD."public" THEN
2573 IF EXISTS (
2574 SELECT NULL FROM "member" WHERE "id" = OLD."member_id"
2575 FOR SHARE
2576 ) AND EXISTS (
2577 SELECT NULL FROM "member" WHERE "id" = OLD."other_member_id"
2578 FOR SHARE
2579 ) THEN
2580 INSERT INTO "event" (
2581 "event", "member_id", "other_member_id", "boolean_value"
2582 ) VALUES (
2583 'contact', OLD."member_id", OLD."other_member_id", FALSE
2584 );
2585 END IF;
2586 END IF;
2587 END IF;
2588 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
2589 IF NEW."public" THEN
2590 INSERT INTO "event" (
2591 "event", "member_id", "other_member_id", "boolean_value"
2592 ) VALUES (
2593 'contact', NEW."member_id", NEW."other_member_id", TRUE
2594 );
2595 END IF;
2596 END IF;
2597 RETURN NULL;
2598 END;
2599 $$;
2601 CREATE TRIGGER "write_event_contact"
2602 AFTER INSERT OR UPDATE OR DELETE ON "contact" FOR EACH ROW EXECUTE PROCEDURE
2603 "write_event_contact_trigger"();
2605 COMMENT ON FUNCTION "write_event_contact_trigger"() IS 'Implementation of trigger "write_event_contact" on table "contact"';
2606 COMMENT ON TRIGGER "write_event_contact" ON "contact" IS 'Create entry in "event" table when adding or removing public contacts';
2609 CREATE FUNCTION "send_event_notify_trigger"()
2610 RETURNS TRIGGER
2611 LANGUAGE 'plpgsql' VOLATILE AS $$
2612 BEGIN
2613 EXECUTE 'NOTIFY "event", ''' || NEW."event" || '''';
2614 RETURN NULL;
2615 END;
2616 $$;
2618 CREATE TRIGGER "send_notify"
2619 AFTER INSERT OR UPDATE ON "event" FOR EACH ROW EXECUTE PROCEDURE
2620 "send_event_notify_trigger"();
2624 ----------------------------
2625 -- Additional constraints --
2626 ----------------------------
2629 CREATE FUNCTION "delete_extended_scope_tokens_trigger"()
2630 RETURNS TRIGGER
2631 LANGUAGE 'plpgsql' VOLATILE AS $$
2632 DECLARE
2633 "system_application_row" "system_application"%ROWTYPE;
2634 BEGIN
2635 IF OLD."system_application_id" NOTNULL THEN
2636 SELECT * FROM "system_application" INTO "system_application_row"
2637 WHERE "id" = OLD."system_application_id";
2638 DELETE FROM "token"
2639 WHERE "member_id" = OLD."member_id"
2640 AND "system_application_id" = OLD."system_application_id"
2641 AND NOT COALESCE(
2642 regexp_split_to_array("scope", E'\\s+') <@
2643 regexp_split_to_array(
2644 "system_application_row"."automatic_scope", E'\\s+'
2645 ),
2646 FALSE
2647 );
2648 END IF;
2649 RETURN OLD;
2650 END;
2651 $$;
2653 CREATE TRIGGER "delete_extended_scope_tokens"
2654 BEFORE DELETE ON "member_application" FOR EACH ROW EXECUTE PROCEDURE
2655 "delete_extended_scope_tokens_trigger"();
2658 CREATE FUNCTION "detach_token_from_session_trigger"()
2659 RETURNS TRIGGER
2660 LANGUAGE 'plpgsql' VOLATILE AS $$
2661 BEGIN
2662 UPDATE "token" SET "session_id" = NULL
2663 WHERE "session_id" = OLD."id";
2664 RETURN OLD;
2665 END;
2666 $$;
2668 CREATE TRIGGER "detach_token_from_session"
2669 BEFORE DELETE ON "session" FOR EACH ROW EXECUTE PROCEDURE
2670 "detach_token_from_session_trigger"();
2673 CREATE FUNCTION "delete_non_detached_scope_with_session_trigger"()
2674 RETURNS TRIGGER
2675 LANGUAGE 'plpgsql' VOLATILE AS $$
2676 BEGIN
2677 IF NEW."session_id" ISNULL THEN
2678 SELECT coalesce(string_agg("element", ' '), '') INTO NEW."scope"
2679 FROM unnest(regexp_split_to_array(NEW."scope", E'\\s+')) AS "element"
2680 WHERE "element" LIKE '%_detached';
2681 END IF;
2682 RETURN NEW;
2683 END;
2684 $$;
2686 CREATE TRIGGER "delete_non_detached_scope_with_session"
2687 BEFORE INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2688 "delete_non_detached_scope_with_session_trigger"();
2691 CREATE FUNCTION "delete_token_with_empty_scope_trigger"()
2692 RETURNS TRIGGER
2693 LANGUAGE 'plpgsql' VOLATILE AS $$
2694 BEGIN
2695 IF NEW."scope" = '' THEN
2696 DELETE FROM "token" WHERE "id" = NEW."id";
2697 END IF;
2698 RETURN NULL;
2699 END;
2700 $$;
2702 CREATE TRIGGER "delete_token_with_empty_scope"
2703 AFTER INSERT OR UPDATE ON "token" FOR EACH ROW EXECUTE PROCEDURE
2704 "delete_token_with_empty_scope_trigger"();
2707 CREATE FUNCTION "issue_requires_first_initiative_trigger"()
2708 RETURNS TRIGGER
2709 LANGUAGE 'plpgsql' VOLATILE AS $$
2710 BEGIN
2711 IF NOT EXISTS (
2712 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id"
2713 ) THEN
2714 RAISE EXCEPTION 'Cannot create issue without an initial initiative.' USING
2715 ERRCODE = 'integrity_constraint_violation',
2716 HINT = 'Create issue, initiative, and draft within the same transaction.';
2717 END IF;
2718 RETURN NULL;
2719 END;
2720 $$;
2722 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative"
2723 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED
2724 FOR EACH ROW EXECUTE PROCEDURE
2725 "issue_requires_first_initiative_trigger"();
2727 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"';
2728 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative';
2731 CREATE FUNCTION "last_initiative_deletes_issue_trigger"()
2732 RETURNS TRIGGER
2733 LANGUAGE 'plpgsql' VOLATILE AS $$
2734 DECLARE
2735 "reference_lost" BOOLEAN;
2736 BEGIN
2737 IF TG_OP = 'DELETE' THEN
2738 "reference_lost" := TRUE;
2739 ELSE
2740 "reference_lost" := NEW."issue_id" != OLD."issue_id";
2741 END IF;
2742 IF
2743 "reference_lost" AND NOT EXISTS (
2744 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id"
2746 THEN
2747 DELETE FROM "issue" WHERE "id" = OLD."issue_id";
2748 END IF;
2749 RETURN NULL;
2750 END;
2751 $$;
2753 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue"
2754 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED
2755 FOR EACH ROW EXECUTE PROCEDURE
2756 "last_initiative_deletes_issue_trigger"();
2758 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"';
2759 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue';
2762 CREATE FUNCTION "initiative_requires_first_draft_trigger"()
2763 RETURNS TRIGGER
2764 LANGUAGE 'plpgsql' VOLATILE AS $$
2765 BEGIN
2766 IF NOT EXISTS (
2767 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id"
2768 ) THEN
2769 RAISE EXCEPTION 'Cannot create initiative without an initial draft.' USING
2770 ERRCODE = 'integrity_constraint_violation',
2771 HINT = 'Create issue, initiative and draft within the same transaction.';
2772 END IF;
2773 RETURN NULL;
2774 END;
2775 $$;
2777 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft"
2778 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED
2779 FOR EACH ROW EXECUTE PROCEDURE
2780 "initiative_requires_first_draft_trigger"();
2782 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"';
2783 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft';
2786 CREATE FUNCTION "last_draft_deletes_initiative_trigger"()
2787 RETURNS TRIGGER
2788 LANGUAGE 'plpgsql' VOLATILE AS $$
2789 DECLARE
2790 "reference_lost" BOOLEAN;
2791 BEGIN
2792 IF TG_OP = 'DELETE' THEN
2793 "reference_lost" := TRUE;
2794 ELSE
2795 "reference_lost" := NEW."initiative_id" != OLD."initiative_id";
2796 END IF;
2797 IF
2798 "reference_lost" AND NOT EXISTS (
2799 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id"
2801 THEN
2802 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id";
2803 END IF;
2804 RETURN NULL;
2805 END;
2806 $$;
2808 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative"
2809 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED
2810 FOR EACH ROW EXECUTE PROCEDURE
2811 "last_draft_deletes_initiative_trigger"();
2813 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"';
2814 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative';
2817 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"()
2818 RETURNS TRIGGER
2819 LANGUAGE 'plpgsql' VOLATILE AS $$
2820 BEGIN
2821 IF NOT EXISTS (
2822 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id"
2823 ) THEN
2824 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.' USING
2825 ERRCODE = 'integrity_constraint_violation',
2826 HINT = 'Create suggestion and opinion within the same transaction.';
2827 END IF;
2828 RETURN NULL;
2829 END;
2830 $$;
2832 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion"
2833 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED
2834 FOR EACH ROW EXECUTE PROCEDURE
2835 "suggestion_requires_first_opinion_trigger"();
2837 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"';
2838 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion';
2841 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"()
2842 RETURNS TRIGGER
2843 LANGUAGE 'plpgsql' VOLATILE AS $$
2844 DECLARE
2845 "reference_lost" BOOLEAN;
2846 BEGIN
2847 IF TG_OP = 'DELETE' THEN
2848 "reference_lost" := TRUE;
2849 ELSE
2850 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id";
2851 END IF;
2852 IF
2853 "reference_lost" AND NOT EXISTS (
2854 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id"
2856 THEN
2857 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id";
2858 END IF;
2859 RETURN NULL;
2860 END;
2861 $$;
2863 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion"
2864 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED
2865 FOR EACH ROW EXECUTE PROCEDURE
2866 "last_opinion_deletes_suggestion_trigger"();
2868 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"';
2869 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion';
2872 CREATE FUNCTION "non_voter_deletes_direct_voter_trigger"()
2873 RETURNS TRIGGER
2874 LANGUAGE 'plpgsql' VOLATILE AS $$
2875 BEGIN
2876 DELETE FROM "direct_voter"
2877 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
2878 RETURN NULL;
2879 END;
2880 $$;
2882 CREATE TRIGGER "non_voter_deletes_direct_voter"
2883 AFTER INSERT OR UPDATE ON "non_voter"
2884 FOR EACH ROW EXECUTE PROCEDURE
2885 "non_voter_deletes_direct_voter_trigger"();
2887 COMMENT ON FUNCTION "non_voter_deletes_direct_voter_trigger"() IS 'Implementation of trigger "non_voter_deletes_direct_voter" on table "non_voter"';
2888 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")';
2891 CREATE FUNCTION "direct_voter_deletes_non_voter_trigger"()
2892 RETURNS TRIGGER
2893 LANGUAGE 'plpgsql' VOLATILE AS $$
2894 BEGIN
2895 DELETE FROM "non_voter"
2896 WHERE "issue_id" = NEW."issue_id" AND "member_id" = NEW."member_id";
2897 RETURN NULL;
2898 END;
2899 $$;
2901 CREATE TRIGGER "direct_voter_deletes_non_voter"
2902 AFTER INSERT OR UPDATE ON "direct_voter"
2903 FOR EACH ROW EXECUTE PROCEDURE
2904 "direct_voter_deletes_non_voter_trigger"();
2906 COMMENT ON FUNCTION "direct_voter_deletes_non_voter_trigger"() IS 'Implementation of trigger "direct_voter_deletes_non_voter" on table "direct_voter"';
2907 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")';
2910 CREATE FUNCTION "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"()
2911 RETURNS TRIGGER
2912 LANGUAGE 'plpgsql' VOLATILE AS $$
2913 BEGIN
2914 IF NEW."comment" ISNULL THEN
2915 NEW."comment_changed" := NULL;
2916 NEW."formatting_engine" := NULL;
2917 END IF;
2918 RETURN NEW;
2919 END;
2920 $$;
2922 CREATE TRIGGER "voter_comment_fields_only_set_when_voter_comment_is_set"
2923 BEFORE INSERT OR UPDATE ON "direct_voter"
2924 FOR EACH ROW EXECUTE PROCEDURE
2925 "voter_comment_fields_only_set_when_voter_comment_is_set_trigger"();
2927 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"';
2928 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.';
2932 ---------------------------------
2933 -- Delete incomplete snapshots --
2934 ---------------------------------
2937 CREATE FUNCTION "delete_snapshot_on_partial_delete_trigger"()
2938 RETURNS TRIGGER
2939 LANGUAGE 'plpgsql' VOLATILE AS $$
2940 BEGIN
2941 IF TG_OP = 'UPDATE' THEN
2942 IF
2943 OLD."snapshot_id" = NEW."snapshot_id" AND
2944 OLD."issue_id" = NEW."issue_id"
2945 THEN
2946 RETURN NULL;
2947 END IF;
2948 END IF;
2949 DELETE FROM "snapshot" WHERE "id" = OLD."snapshot_id";
2950 RETURN NULL;
2951 END;
2952 $$;
2954 CREATE TRIGGER "delete_snapshot_on_partial_delete"
2955 AFTER UPDATE OR DELETE ON "snapshot_issue"
2956 FOR EACH ROW EXECUTE PROCEDURE
2957 "delete_snapshot_on_partial_delete_trigger"();
2959 COMMENT ON FUNCTION "delete_snapshot_on_partial_delete_trigger"() IS 'Implementation of trigger "delete_snapshot_on_partial_delete" on table "snapshot_issue"';
2960 COMMENT ON TRIGGER "delete_snapshot_on_partial_delete" ON "snapshot_issue" IS 'Deletes whole snapshot if one issue is deleted from the snapshot';
2964 ---------------------------------------------------------------
2965 -- Ensure that votes are not modified when issues are closed --
2966 ---------------------------------------------------------------
2968 -- NOTE: Frontends should ensure this anyway, but in case of programming
2969 -- errors the following triggers ensure data integrity.
2972 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"()
2973 RETURNS TRIGGER
2974 LANGUAGE 'plpgsql' VOLATILE AS $$
2975 DECLARE
2976 "issue_id_v" "issue"."id"%TYPE;
2977 "issue_row" "issue"%ROWTYPE;
2978 BEGIN
2979 IF EXISTS (
2980 SELECT NULL FROM "temporary_transaction_data"
2981 WHERE "txid" = txid_current()
2982 AND "key" = 'override_protection_triggers'
2983 AND "value" = TRUE::TEXT
2984 ) THEN
2985 RETURN NULL;
2986 END IF;
2987 IF TG_OP = 'DELETE' THEN
2988 "issue_id_v" := OLD."issue_id";
2989 ELSE
2990 "issue_id_v" := NEW."issue_id";
2991 END IF;
2992 SELECT INTO "issue_row" * FROM "issue"
2993 WHERE "id" = "issue_id_v" FOR SHARE;
2994 IF (
2995 "issue_row"."closed" NOTNULL OR (
2996 "issue_row"."state" = 'voting' AND
2997 "issue_row"."phase_finished" NOTNULL
2999 ) THEN
3000 IF
3001 TG_RELID = 'direct_voter'::regclass AND
3002 TG_OP = 'UPDATE'
3003 THEN
3004 IF
3005 OLD."issue_id" = NEW."issue_id" AND
3006 OLD."member_id" = NEW."member_id" AND
3007 OLD."weight" = NEW."weight"
3008 THEN
3009 RETURN NULL; -- allows changing of voter comment
3010 END IF;
3011 END IF;
3012 RAISE EXCEPTION 'Tried to modify data after voting has been closed.' USING
3013 ERRCODE = 'integrity_constraint_violation';
3014 END IF;
3015 RETURN NULL;
3016 END;
3017 $$;
3019 CREATE TRIGGER "forbid_changes_on_closed_issue"
3020 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter"
3021 FOR EACH ROW EXECUTE PROCEDURE
3022 "forbid_changes_on_closed_issue_trigger"();
3024 CREATE TRIGGER "forbid_changes_on_closed_issue"
3025 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter"
3026 FOR EACH ROW EXECUTE PROCEDURE
3027 "forbid_changes_on_closed_issue_trigger"();
3029 CREATE TRIGGER "forbid_changes_on_closed_issue"
3030 AFTER INSERT OR UPDATE OR DELETE ON "vote"
3031 FOR EACH ROW EXECUTE PROCEDURE
3032 "forbid_changes_on_closed_issue_trigger"();
3034 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"';
3035 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';
3036 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';
3037 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';
3041 --------------------------------------------------------------------
3042 -- Auto-retrieval of fields only needed for referential integrity --
3043 --------------------------------------------------------------------
3046 CREATE FUNCTION "autofill_issue_id_trigger"()
3047 RETURNS TRIGGER
3048 LANGUAGE 'plpgsql' VOLATILE AS $$
3049 BEGIN
3050 IF NEW."issue_id" ISNULL THEN
3051 SELECT "issue_id" INTO NEW."issue_id"
3052 FROM "initiative" WHERE "id" = NEW."initiative_id";
3053 END IF;
3054 RETURN NEW;
3055 END;
3056 $$;
3058 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter"
3059 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3061 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote"
3062 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"();
3064 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"';
3065 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL';
3066 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL';
3069 CREATE FUNCTION "autofill_initiative_id_trigger"()
3070 RETURNS TRIGGER
3071 LANGUAGE 'plpgsql' VOLATILE AS $$
3072 BEGIN
3073 IF NEW."initiative_id" ISNULL THEN
3074 SELECT "initiative_id" INTO NEW."initiative_id"
3075 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3076 END IF;
3077 RETURN NEW;
3078 END;
3079 $$;
3081 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion"
3082 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"();
3084 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"';
3085 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL';
3089 -------------------------------------------------------
3090 -- Automatic copying of values for indexing purposes --
3091 -------------------------------------------------------
3094 CREATE FUNCTION "copy_current_draft_data"
3095 ("initiative_id_p" "initiative"."id"%TYPE )
3096 RETURNS VOID
3097 LANGUAGE 'plpgsql' VOLATILE AS $$
3098 BEGIN
3099 PERFORM NULL FROM "initiative" WHERE "id" = "initiative_id_p"
3100 FOR UPDATE;
3101 UPDATE "initiative" SET
3102 "location" = "draft"."location",
3103 "draft_text_search_data" = "draft"."text_search_data"
3104 FROM "current_draft" AS "draft"
3105 WHERE "initiative"."id" = "initiative_id_p"
3106 AND "draft"."initiative_id" = "initiative_id_p";
3107 END;
3108 $$;
3110 COMMENT ON FUNCTION "copy_current_draft_data"
3111 ( "initiative"."id"%TYPE )
3112 IS 'Helper function for function "copy_current_draft_data_trigger"';
3115 CREATE FUNCTION "copy_current_draft_data_trigger"()
3116 RETURNS TRIGGER
3117 LANGUAGE 'plpgsql' VOLATILE AS $$
3118 BEGIN
3119 IF TG_OP='DELETE' THEN
3120 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3121 ELSE
3122 IF TG_OP='UPDATE' THEN
3123 IF COALESCE(OLD."inititiave_id" != NEW."initiative_id", TRUE) THEN
3124 PERFORM "copy_current_draft_data"(OLD."initiative_id");
3125 END IF;
3126 END IF;
3127 PERFORM "copy_current_draft_data"(NEW."initiative_id");
3128 END IF;
3129 RETURN NULL;
3130 END;
3131 $$;
3133 CREATE TRIGGER "copy_current_draft_data"
3134 AFTER INSERT OR UPDATE OR DELETE ON "draft"
3135 FOR EACH ROW EXECUTE PROCEDURE
3136 "copy_current_draft_data_trigger"();
3138 COMMENT ON FUNCTION "copy_current_draft_data_trigger"() IS 'Implementation of trigger "copy_current_draft_data" on table "draft"';
3139 COMMENT ON TRIGGER "copy_current_draft_data" ON "draft" IS 'Copy certain fields from most recent "draft" to "initiative"';
3143 -----------------------------------------------------
3144 -- Automatic calculation of certain default values --
3145 -----------------------------------------------------
3148 CREATE FUNCTION "copy_timings_trigger"()
3149 RETURNS TRIGGER
3150 LANGUAGE 'plpgsql' VOLATILE AS $$
3151 DECLARE
3152 "policy_row" "policy"%ROWTYPE;
3153 BEGIN
3154 SELECT * INTO "policy_row" FROM "policy"
3155 WHERE "id" = NEW."policy_id";
3156 IF NEW."min_admission_time" ISNULL THEN
3157 NEW."min_admission_time" := "policy_row"."min_admission_time";
3158 END IF;
3159 IF NEW."max_admission_time" ISNULL THEN
3160 NEW."max_admission_time" := "policy_row"."max_admission_time";
3161 END IF;
3162 IF NEW."discussion_time" ISNULL THEN
3163 NEW."discussion_time" := "policy_row"."discussion_time";
3164 END IF;
3165 IF NEW."verification_time" ISNULL THEN
3166 NEW."verification_time" := "policy_row"."verification_time";
3167 END IF;
3168 IF NEW."voting_time" ISNULL THEN
3169 NEW."voting_time" := "policy_row"."voting_time";
3170 END IF;
3171 RETURN NEW;
3172 END;
3173 $$;
3175 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue"
3176 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"();
3178 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"';
3179 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.';
3182 CREATE FUNCTION "default_for_draft_id_trigger"()
3183 RETURNS TRIGGER
3184 LANGUAGE 'plpgsql' VOLATILE AS $$
3185 BEGIN
3186 IF NEW."draft_id" ISNULL THEN
3187 SELECT "id" INTO NEW."draft_id" FROM "current_draft"
3188 WHERE "initiative_id" = NEW."initiative_id";
3189 END IF;
3190 RETURN NEW;
3191 END;
3192 $$;
3194 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
3195 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3196 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
3197 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
3199 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
3200 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';
3201 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';
3205 ----------------------------------------
3206 -- Automatic creation of dependencies --
3207 ----------------------------------------
3210 CREATE FUNCTION "autocreate_interest_trigger"()
3211 RETURNS TRIGGER
3212 LANGUAGE 'plpgsql' VOLATILE AS $$
3213 BEGIN
3214 IF NOT EXISTS (
3215 SELECT NULL FROM "initiative" JOIN "interest"
3216 ON "initiative"."issue_id" = "interest"."issue_id"
3217 WHERE "initiative"."id" = NEW."initiative_id"
3218 AND "interest"."member_id" = NEW."member_id"
3219 ) THEN
3220 BEGIN
3221 INSERT INTO "interest" ("issue_id", "member_id")
3222 SELECT "issue_id", NEW."member_id"
3223 FROM "initiative" WHERE "id" = NEW."initiative_id";
3224 EXCEPTION WHEN unique_violation THEN END;
3225 END IF;
3226 RETURN NEW;
3227 END;
3228 $$;
3230 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter"
3231 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"();
3233 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"';
3234 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';
3237 CREATE FUNCTION "autocreate_supporter_trigger"()
3238 RETURNS TRIGGER
3239 LANGUAGE 'plpgsql' VOLATILE AS $$
3240 BEGIN
3241 IF NOT EXISTS (
3242 SELECT NULL FROM "suggestion" JOIN "supporter"
3243 ON "suggestion"."initiative_id" = "supporter"."initiative_id"
3244 WHERE "suggestion"."id" = NEW."suggestion_id"
3245 AND "supporter"."member_id" = NEW."member_id"
3246 ) THEN
3247 BEGIN
3248 INSERT INTO "supporter" ("initiative_id", "member_id")
3249 SELECT "initiative_id", NEW."member_id"
3250 FROM "suggestion" WHERE "id" = NEW."suggestion_id";
3251 EXCEPTION WHEN unique_violation THEN END;
3252 END IF;
3253 RETURN NEW;
3254 END;
3255 $$;
3257 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion"
3258 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"();
3260 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"';
3261 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.';
3265 ------------------------------------------
3266 -- Views and helper functions for views --
3267 ------------------------------------------
3270 CREATE VIEW "member_eligible_to_be_notified" AS
3271 SELECT * FROM "member"
3272 WHERE "activated" NOTNULL AND "locked" = FALSE;
3274 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")';
3277 CREATE VIEW "member_to_notify" AS
3278 SELECT * FROM "member_eligible_to_be_notified"
3279 WHERE "disable_notifications" = FALSE;
3281 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)';
3284 CREATE VIEW "area_quorum" AS
3285 SELECT
3286 "area"."id" AS "area_id",
3287 ceil(
3288 "area"."quorum_standard"::FLOAT8 * "quorum_factor"::FLOAT8 ^ (
3289 coalesce(
3290 ( SELECT sum(
3291 ( extract(epoch from "area"."quorum_time")::FLOAT8 /
3292 extract(epoch from
3293 ("issue"."accepted"-"issue"."created") +
3294 "issue"."discussion_time" +
3295 "issue"."verification_time" +
3296 "issue"."voting_time"
3297 )::FLOAT8
3298 ) ^ "area"."quorum_exponent"::FLOAT8
3300 FROM "issue" JOIN "policy"
3301 ON "issue"."policy_id" = "policy"."id"
3302 WHERE "issue"."area_id" = "area"."id"
3303 AND "issue"."accepted" NOTNULL
3304 AND "issue"."closed" ISNULL
3305 AND "policy"."polling" = FALSE
3306 )::FLOAT8, 0::FLOAT8
3307 ) / "area"."quorum_issues"::FLOAT8 - 1::FLOAT8
3308 ) * CASE WHEN "area"."quorum_den" ISNULL THEN 1 ELSE (
3309 SELECT "snapshot"."population"
3310 FROM "snapshot"
3311 WHERE "snapshot"."area_id" = "area"."id"
3312 AND "snapshot"."issue_id" ISNULL
3313 ORDER BY "snapshot"."id" DESC
3314 LIMIT 1
3315 ) END / coalesce("area"."quorum_den", 1)
3317 )::INT4 AS "issue_quorum"
3318 FROM "area";
3320 COMMENT ON VIEW "area_quorum" IS 'Area-based quorum considering number of open (accepted) issues';
3323 CREATE VIEW "area_with_unaccepted_issues" AS
3324 SELECT DISTINCT ON ("area"."id") "area".*
3325 FROM "area" JOIN "issue" ON "area"."id" = "issue"."area_id"
3326 WHERE "issue"."state" = 'admission';
3328 COMMENT ON VIEW "area_with_unaccepted_issues" IS 'All areas with unaccepted open issues (needed for issue admission system)';
3331 CREATE VIEW "issue_for_admission" AS
3332 SELECT DISTINCT ON ("issue"."area_id")
3333 "issue".*,
3334 max("initiative"."supporter_count") AS "max_supporter_count"
3335 FROM "issue"
3336 JOIN "policy" ON "issue"."policy_id" = "policy"."id"
3337 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id"
3338 JOIN "area" ON "issue"."area_id" = "area"."id"
3339 WHERE "issue"."state" = 'admission'::"issue_state"
3340 AND now() >= "issue"."created" + "issue"."min_admission_time"
3341 AND "initiative"."supporter_count" >= "policy"."issue_quorum"
3342 AND "initiative"."supporter_count" * "policy"."issue_quorum_den" >=
3343 "issue"."population" * "policy"."issue_quorum_num"
3344 AND "initiative"."supporter_count" >= "area"."issue_quorum"
3345 AND "initiative"."revoked" ISNULL
3346 GROUP BY "issue"."id"
3347 ORDER BY "issue"."area_id", "max_supporter_count" DESC, "issue"."id";
3349 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';
3352 CREATE VIEW "unit_delegation" AS
3353 SELECT
3354 "unit"."id" AS "unit_id",
3355 "delegation"."id",
3356 "delegation"."truster_id",
3357 "delegation"."trustee_id",
3358 "delegation"."scope"
3359 FROM "unit"
3360 JOIN "delegation"
3361 ON "delegation"."unit_id" = "unit"."id"
3362 JOIN "member"
3363 ON "delegation"."truster_id" = "member"."id"
3364 JOIN "privilege"
3365 ON "delegation"."unit_id" = "privilege"."unit_id"
3366 AND "delegation"."truster_id" = "privilege"."member_id"
3367 WHERE "member"."active" AND "privilege"."voting_right";
3369 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
3372 CREATE VIEW "area_delegation" AS
3373 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
3374 "area"."id" AS "area_id",
3375 "delegation"."id",
3376 "delegation"."truster_id",
3377 "delegation"."trustee_id",
3378 "delegation"."scope"
3379 FROM "area"
3380 JOIN "delegation"
3381 ON "delegation"."unit_id" = "area"."unit_id"
3382 OR "delegation"."area_id" = "area"."id"
3383 JOIN "member"
3384 ON "delegation"."truster_id" = "member"."id"
3385 JOIN "privilege"
3386 ON "area"."unit_id" = "privilege"."unit_id"
3387 AND "delegation"."truster_id" = "privilege"."member_id"
3388 WHERE "member"."active" AND "privilege"."voting_right"
3389 ORDER BY
3390 "area"."id",
3391 "delegation"."truster_id",
3392 "delegation"."scope" DESC;
3394 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
3397 CREATE VIEW "issue_delegation" AS
3398 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
3399 "issue"."id" AS "issue_id",
3400 "delegation"."id",
3401 "delegation"."truster_id",
3402 "delegation"."trustee_id",
3403 "delegation"."scope"
3404 FROM "issue"
3405 JOIN "area"
3406 ON "area"."id" = "issue"."area_id"
3407 JOIN "delegation"
3408 ON "delegation"."unit_id" = "area"."unit_id"
3409 OR "delegation"."area_id" = "area"."id"
3410 OR "delegation"."issue_id" = "issue"."id"
3411 JOIN "member"
3412 ON "delegation"."truster_id" = "member"."id"
3413 JOIN "privilege"
3414 ON "area"."unit_id" = "privilege"."unit_id"
3415 AND "delegation"."truster_id" = "privilege"."member_id"
3416 WHERE "member"."active" AND "privilege"."voting_right"
3417 ORDER BY
3418 "issue"."id",
3419 "delegation"."truster_id",
3420 "delegation"."scope" DESC;
3422 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
3425 CREATE VIEW "member_count_view" AS
3426 SELECT count(1) AS "total_count" FROM "member" WHERE "active";
3428 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table';
3431 CREATE VIEW "unit_member" AS
3432 SELECT
3433 "unit"."id" AS "unit_id",
3434 "member"."id" AS "member_id"
3435 FROM "privilege"
3436 JOIN "unit" ON "unit_id" = "privilege"."unit_id"
3437 JOIN "member" ON "member"."id" = "privilege"."member_id"
3438 WHERE "privilege"."voting_right" AND "member"."active";
3440 COMMENT ON VIEW "unit_member" IS 'Active members with voting right in a unit';
3443 CREATE VIEW "unit_member_count" AS
3444 SELECT
3445 "unit"."id" AS "unit_id",
3446 count("unit_member"."member_id") AS "member_count"
3447 FROM "unit" LEFT JOIN "unit_member"
3448 ON "unit"."id" = "unit_member"."unit_id"
3449 GROUP BY "unit"."id";
3451 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
3454 CREATE VIEW "opening_draft" AS
3455 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3456 ORDER BY "initiative_id", "id";
3458 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives';
3461 CREATE VIEW "current_draft" AS
3462 SELECT DISTINCT ON ("initiative_id") * FROM "draft"
3463 ORDER BY "initiative_id", "id" DESC;
3465 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative';
3468 CREATE VIEW "critical_opinion" AS
3469 SELECT * FROM "opinion"
3470 WHERE ("degree" = 2 AND "fulfilled" = FALSE)
3471 OR ("degree" = -2 AND "fulfilled" = TRUE);
3473 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction';
3476 CREATE VIEW "issue_supporter_in_admission_state" AS
3477 SELECT
3478 "area"."unit_id",
3479 "issue"."area_id",
3480 "issue"."id" AS "issue_id",
3481 "supporter"."member_id",
3482 "direct_interest_snapshot"."weight"
3483 FROM "issue"
3484 JOIN "area" ON "area"."id" = "issue"."area_id"
3485 JOIN "supporter" ON "supporter"."issue_id" = "issue"."id"
3486 JOIN "direct_interest_snapshot"
3487 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3488 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3489 AND "direct_interest_snapshot"."member_id" = "supporter"."member_id"
3490 WHERE "issue"."state" = 'admission'::"issue_state";
3492 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';
3495 CREATE VIEW "initiative_suggestion_order_calculation" AS
3496 SELECT
3497 "initiative"."id" AS "initiative_id",
3498 ("issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL) AS "final"
3499 FROM "initiative" JOIN "issue"
3500 ON "initiative"."issue_id" = "issue"."id"
3501 WHERE ("issue"."closed" ISNULL AND "issue"."fully_frozen" ISNULL)
3502 OR ("initiative"."final_suggestion_order_calculated" = FALSE);
3504 COMMENT ON VIEW "initiative_suggestion_order_calculation" IS 'Initiatives, where the "proportional_order" of its suggestions has to be calculated';
3506 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';
3509 CREATE VIEW "individual_suggestion_ranking" AS
3510 SELECT
3511 "opinion"."initiative_id",
3512 "opinion"."member_id",
3513 "direct_interest_snapshot"."weight",
3514 CASE WHEN
3515 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = FALSE) OR
3516 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = TRUE)
3517 THEN 1 ELSE
3518 CASE WHEN
3519 ("opinion"."degree" = 1 AND "opinion"."fulfilled" = FALSE) OR
3520 ("opinion"."degree" = -1 AND "opinion"."fulfilled" = TRUE)
3521 THEN 2 ELSE
3522 CASE WHEN
3523 ("opinion"."degree" = 2 AND "opinion"."fulfilled" = TRUE) OR
3524 ("opinion"."degree" = -2 AND "opinion"."fulfilled" = FALSE)
3525 THEN 3 ELSE 4 END
3526 END
3527 END AS "preference",
3528 "opinion"."suggestion_id"
3529 FROM "opinion"
3530 JOIN "initiative" ON "initiative"."id" = "opinion"."initiative_id"
3531 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3532 JOIN "direct_interest_snapshot"
3533 ON "direct_interest_snapshot"."snapshot_id" = "issue"."latest_snapshot_id"
3534 AND "direct_interest_snapshot"."issue_id" = "issue"."id"
3535 AND "direct_interest_snapshot"."member_id" = "opinion"."member_id";
3537 COMMENT ON VIEW "individual_suggestion_ranking" IS 'Helper view for "lf_update_suggestion_order" to allow a proportional ordering of suggestions within an initiative';
3540 CREATE VIEW "battle_participant" AS
3541 SELECT "initiative"."id", "initiative"."issue_id"
3542 FROM "issue" JOIN "initiative"
3543 ON "issue"."id" = "initiative"."issue_id"
3544 WHERE "initiative"."admitted"
3545 UNION ALL
3546 SELECT NULL, "id" AS "issue_id"
3547 FROM "issue";
3549 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
3552 CREATE VIEW "battle_view" AS
3553 SELECT
3554 "issue"."id" AS "issue_id",
3555 "winning_initiative"."id" AS "winning_initiative_id",
3556 "losing_initiative"."id" AS "losing_initiative_id",
3557 sum(
3558 CASE WHEN
3559 coalesce("better_vote"."grade", 0) >
3560 coalesce("worse_vote"."grade", 0)
3561 THEN "direct_voter"."weight" ELSE 0 END
3562 ) AS "count"
3563 FROM "issue"
3564 LEFT JOIN "direct_voter"
3565 ON "issue"."id" = "direct_voter"."issue_id"
3566 JOIN "battle_participant" AS "winning_initiative"
3567 ON "issue"."id" = "winning_initiative"."issue_id"
3568 JOIN "battle_participant" AS "losing_initiative"
3569 ON "issue"."id" = "losing_initiative"."issue_id"
3570 LEFT JOIN "vote" AS "better_vote"
3571 ON "direct_voter"."member_id" = "better_vote"."member_id"
3572 AND "winning_initiative"."id" = "better_vote"."initiative_id"
3573 LEFT JOIN "vote" AS "worse_vote"
3574 ON "direct_voter"."member_id" = "worse_vote"."member_id"
3575 AND "losing_initiative"."id" = "worse_vote"."initiative_id"
3576 WHERE "issue"."state" = 'voting'
3577 AND "issue"."phase_finished" NOTNULL
3578 AND (
3579 "winning_initiative"."id" != "losing_initiative"."id" OR
3580 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
3581 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
3582 GROUP BY
3583 "issue"."id",
3584 "winning_initiative"."id",
3585 "losing_initiative"."id";
3587 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';
3590 CREATE VIEW "expired_session" AS
3591 SELECT * FROM "session" WHERE now() > "expiry";
3593 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD
3594 DELETE FROM "session" WHERE "id" = OLD."id";
3596 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible';
3597 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"';
3600 CREATE VIEW "expired_token" AS
3601 SELECT * FROM "token" WHERE now() > "expiry" AND NOT (
3602 "token_type" = 'authorization' AND "used" AND EXISTS (
3603 SELECT NULL FROM "token" AS "other"
3604 WHERE "other"."authorization_token_id" = "id" ) );
3606 CREATE RULE "delete" AS ON DELETE TO "expired_token" DO INSTEAD
3607 DELETE FROM "token" WHERE "id" = OLD."id";
3609 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';
3612 CREATE VIEW "unused_snapshot" AS
3613 SELECT "snapshot".* FROM "snapshot"
3614 LEFT JOIN "issue"
3615 ON "snapshot"."id" = "issue"."latest_snapshot_id"
3616 OR "snapshot"."id" = "issue"."admission_snapshot_id"
3617 OR "snapshot"."id" = "issue"."half_freeze_snapshot_id"
3618 OR "snapshot"."id" = "issue"."full_freeze_snapshot_id"
3619 WHERE "issue"."id" ISNULL;
3621 CREATE RULE "delete" AS ON DELETE TO "unused_snapshot" DO INSTEAD
3622 DELETE FROM "snapshot" WHERE "id" = OLD."id";
3624 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)';
3627 CREATE VIEW "expired_snapshot" AS
3628 SELECT "unused_snapshot".* FROM "unused_snapshot" CROSS JOIN "system_setting"
3629 WHERE "unused_snapshot"."calculated" <
3630 now() - "system_setting"."snapshot_retention";
3632 CREATE RULE "delete" AS ON DELETE TO "expired_snapshot" DO INSTEAD
3633 DELETE FROM "snapshot" WHERE "id" = OLD."id";
3635 COMMENT ON VIEW "expired_snapshot" IS 'Contains "unused_snapshot"s that are older than "system_setting"."snapshot_retention" (for deletion)';
3638 CREATE VIEW "open_issue" AS
3639 SELECT * FROM "issue" WHERE "closed" ISNULL;
3641 COMMENT ON VIEW "open_issue" IS 'All open issues';
3644 CREATE VIEW "member_contingent" AS
3645 SELECT
3646 "member"."id" AS "member_id",
3647 "contingent"."polling",
3648 "contingent"."time_frame",
3649 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN
3651 SELECT count(1) FROM "draft"
3652 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3653 WHERE "draft"."author_id" = "member"."id"
3654 AND "initiative"."polling" = "contingent"."polling"
3655 AND "draft"."created" > now() - "contingent"."time_frame"
3656 ) + (
3657 SELECT count(1) FROM "suggestion"
3658 JOIN "initiative" ON "initiative"."id" = "suggestion"."initiative_id"
3659 WHERE "suggestion"."author_id" = "member"."id"
3660 AND "contingent"."polling" = FALSE
3661 AND "suggestion"."created" > now() - "contingent"."time_frame"
3663 ELSE NULL END AS "text_entry_count",
3664 "contingent"."text_entry_limit",
3665 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN (
3666 SELECT count(1) FROM "opening_draft" AS "draft"
3667 JOIN "initiative" ON "initiative"."id" = "draft"."initiative_id"
3668 WHERE "draft"."author_id" = "member"."id"
3669 AND "initiative"."polling" = "contingent"."polling"
3670 AND "draft"."created" > now() - "contingent"."time_frame"
3671 ) ELSE NULL END AS "initiative_count",
3672 "contingent"."initiative_limit"
3673 FROM "member" CROSS JOIN "contingent";
3675 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.';
3677 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row';
3678 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row';
3681 CREATE VIEW "member_contingent_left" AS
3682 SELECT
3683 "member_id",
3684 "polling",
3685 max("text_entry_limit" - "text_entry_count") AS "text_entries_left",
3686 max("initiative_limit" - "initiative_count") AS "initiatives_left"
3687 FROM "member_contingent" GROUP BY "member_id", "polling";
3689 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.';
3692 CREATE VIEW "event_for_notification" AS
3693 SELECT
3694 "member"."id" AS "recipient_id",
3695 "event".*
3696 FROM "member" CROSS JOIN "event"
3697 JOIN "issue" ON "issue"."id" = "event"."issue_id"
3698 JOIN "area" ON "area"."id" = "issue"."area_id"
3699 LEFT JOIN "privilege" ON
3700 "privilege"."member_id" = "member"."id" AND
3701 "privilege"."unit_id" = "area"."unit_id" AND
3702 "privilege"."voting_right" = TRUE
3703 LEFT JOIN "subscription" ON
3704 "subscription"."member_id" = "member"."id" AND
3705 "subscription"."unit_id" = "area"."unit_id"
3706 LEFT JOIN "ignored_area" ON
3707 "ignored_area"."member_id" = "member"."id" AND
3708 "ignored_area"."area_id" = "issue"."area_id"
3709 LEFT JOIN "interest" ON
3710 "interest"."member_id" = "member"."id" AND
3711 "interest"."issue_id" = "event"."issue_id"
3712 LEFT JOIN "supporter" ON
3713 "supporter"."member_id" = "member"."id" AND
3714 "supporter"."initiative_id" = "event"."initiative_id"
3715 WHERE ("privilege"."member_id" NOTNULL OR "subscription"."member_id" NOTNULL)
3716 AND ("ignored_area"."member_id" ISNULL OR "interest"."member_id" NOTNULL)
3717 AND (
3718 "event"."event" = 'issue_state_changed'::"event_type" OR
3719 ( "event"."event" = 'initiative_revoked'::"event_type" AND
3720 "supporter"."member_id" NOTNULL ) );
3722 COMMENT ON VIEW "event_for_notification" IS 'Entries of the "event" table which are of interest for a particular notification mail recipient';
3724 COMMENT ON COLUMN "event_for_notification"."recipient_id" IS 'member_id of the recipient of a notification mail';
3727 CREATE VIEW "updated_initiative" AS
3728 SELECT
3729 "supporter"."member_id" AS "recipient_id",
3730 FALSE AS "featured",
3731 "supporter"."initiative_id"
3732 FROM "supporter"
3733 JOIN "initiative" ON "supporter"."initiative_id" = "initiative"."id"
3734 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3735 LEFT JOIN "notification_initiative_sent" AS "sent" ON
3736 "sent"."member_id" = "supporter"."member_id" AND
3737 "sent"."initiative_id" = "supporter"."initiative_id"
3738 LEFT JOIN "ignored_initiative" ON
3739 "ignored_initiative"."member_id" = "supporter"."member_id" AND
3740 "ignored_initiative"."initiative_id" = "supporter"."initiative_id"
3741 WHERE "issue"."state" IN ('admission', 'discussion')
3742 AND "initiative"."revoked" ISNULL
3743 AND "ignored_initiative"."member_id" ISNULL
3744 AND (
3745 EXISTS (
3746 SELECT NULL FROM "draft"
3747 LEFT JOIN "ignored_member" ON
3748 "ignored_member"."member_id" = "supporter"."member_id" AND
3749 "ignored_member"."other_member_id" = "draft"."author_id"
3750 WHERE "draft"."initiative_id" = "supporter"."initiative_id"
3751 AND "draft"."id" > "supporter"."draft_id"
3752 AND "ignored_member"."member_id" ISNULL
3753 ) OR EXISTS (
3754 SELECT NULL FROM "suggestion"
3755 LEFT JOIN "opinion" ON
3756 "opinion"."member_id" = "supporter"."member_id" AND
3757 "opinion"."suggestion_id" = "suggestion"."id"
3758 LEFT JOIN "ignored_member" ON
3759 "ignored_member"."member_id" = "supporter"."member_id" AND
3760 "ignored_member"."other_member_id" = "suggestion"."author_id"
3761 WHERE "suggestion"."initiative_id" = "supporter"."initiative_id"
3762 AND "opinion"."member_id" ISNULL
3763 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
3764 AND "ignored_member"."member_id" ISNULL
3766 );
3768 COMMENT ON VIEW "updated_initiative" IS 'Helper view for view "updated_or_featured_initiative"';
3771 CREATE FUNCTION "featured_initiative"
3772 ( "recipient_id_p" "member"."id"%TYPE,
3773 "area_id_p" "area"."id"%TYPE )
3774 RETURNS SETOF "initiative"."id"%TYPE
3775 LANGUAGE 'plpgsql' STABLE AS $$
3776 DECLARE
3777 "counter_v" "member"."notification_counter"%TYPE;
3778 "sample_size_v" "member"."notification_sample_size"%TYPE;
3779 "initiative_id_ary" INT4[]; --"initiative"."id"%TYPE[]
3780 "match_v" BOOLEAN;
3781 "member_id_v" "member"."id"%TYPE;
3782 "seed_v" TEXT;
3783 "initiative_id_v" "initiative"."id"%TYPE;
3784 BEGIN
3785 SELECT "notification_counter", "notification_sample_size"
3786 INTO "counter_v", "sample_size_v"
3787 FROM "member" WHERE "id" = "recipient_id_p";
3788 IF COALESCE("sample_size_v" <= 0, TRUE) THEN
3789 RETURN;
3790 END IF;
3791 "initiative_id_ary" := '{}';
3792 LOOP
3793 "match_v" := FALSE;
3794 FOR "member_id_v", "seed_v" IN
3795 SELECT * FROM (
3796 SELECT DISTINCT
3797 "supporter"."member_id",
3798 md5(
3799 "recipient_id_p" || '-' ||
3800 "counter_v" || '-' ||
3801 "area_id_p" || '-' ||
3802 "supporter"."member_id"
3803 ) AS "seed"
3804 FROM "supporter"
3805 JOIN "initiative" ON "initiative"."id" = "supporter"."initiative_id"
3806 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3807 WHERE "supporter"."member_id" != "recipient_id_p"
3808 AND "issue"."area_id" = "area_id_p"
3809 AND "issue"."state" IN ('admission', 'discussion', 'verification')
3810 ) AS "subquery"
3811 ORDER BY "seed"
3812 LOOP
3813 SELECT "initiative"."id" INTO "initiative_id_v"
3814 FROM "initiative"
3815 JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
3816 JOIN "area" ON "area"."id" = "issue"."area_id"
3817 JOIN "supporter" ON "supporter"."initiative_id" = "initiative"."id"
3818 LEFT JOIN "supporter" AS "self_support" ON
3819 "self_support"."initiative_id" = "initiative"."id" AND
3820 "self_support"."member_id" = "recipient_id_p"
3821 LEFT JOIN "privilege" ON
3822 "privilege"."member_id" = "recipient_id_p" AND
3823 "privilege"."unit_id" = "area"."unit_id" AND
3824 "privilege"."voting_right" = TRUE
3825 LEFT JOIN "subscription" ON
3826 "subscription"."member_id" = "recipient_id_p" AND
3827 "subscription"."unit_id" = "area"."unit_id"
3828 LEFT JOIN "ignored_initiative" ON
3829 "ignored_initiative"."member_id" = "recipient_id_p" AND
3830 "ignored_initiative"."initiative_id" = "initiative"."id"
3831 WHERE "supporter"."member_id" = "member_id_v"
3832 AND "issue"."area_id" = "area_id_p"
3833 AND "issue"."state" IN ('admission', 'discussion', 'verification')
3834 AND "initiative"."revoked" ISNULL
3835 AND "self_support"."member_id" ISNULL
3836 AND NOT "initiative_id_ary" @> ARRAY["initiative"."id"]
3837 AND (
3838 "privilege"."member_id" NOTNULL OR
3839 "subscription"."member_id" NOTNULL )
3840 AND "ignored_initiative"."member_id" ISNULL
3841 AND NOT EXISTS (
3842 SELECT NULL FROM "draft"
3843 JOIN "ignored_member" ON
3844 "ignored_member"."member_id" = "recipient_id_p" AND
3845 "ignored_member"."other_member_id" = "draft"."author_id"
3846 WHERE "draft"."initiative_id" = "initiative"."id"
3848 ORDER BY md5("seed_v" || '-' || "initiative"."id")
3849 LIMIT 1;
3850 IF FOUND THEN
3851 "match_v" := TRUE;
3852 RETURN NEXT "initiative_id_v";
3853 IF array_length("initiative_id_ary", 1) + 1 >= "sample_size_v" THEN
3854 RETURN;
3855 END IF;
3856 "initiative_id_ary" := "initiative_id_ary" || "initiative_id_v";
3857 END IF;
3858 END LOOP;
3859 EXIT WHEN NOT "match_v";
3860 END LOOP;
3861 RETURN;
3862 END;
3863 $$;
3865 COMMENT ON FUNCTION "featured_initiative"
3866 ( "recipient_id_p" "member"."id"%TYPE,
3867 "area_id_p" "area"."id"%TYPE )
3868 IS 'Helper function for view "updated_or_featured_initiative"';
3871 CREATE VIEW "updated_or_featured_initiative" AS
3872 SELECT
3873 "subquery".*,
3874 NOT EXISTS (
3875 SELECT NULL FROM "initiative" AS "better_initiative"
3876 WHERE "better_initiative"."issue_id" = "initiative"."issue_id"
3877 AND
3878 ( COALESCE("better_initiative"."supporter_count", -1),
3879 -"better_initiative"."id" ) >
3880 ( COALESCE("initiative"."supporter_count", -1),
3881 -"initiative"."id" )
3882 ) AS "leading"
3883 FROM (
3884 SELECT * FROM "updated_initiative"
3885 UNION ALL
3886 SELECT
3887 "member"."id" AS "recipient_id",
3888 TRUE AS "featured",
3889 "featured_initiative_id" AS "initiative_id"
3890 FROM "member" CROSS JOIN "area"
3891 CROSS JOIN LATERAL
3892 "featured_initiative"("member"."id", "area"."id") AS "featured_initiative_id"
3893 JOIN "initiative" ON "initiative"."id" = "featured_initiative_id"
3894 ) AS "subquery"
3895 JOIN "initiative" ON "initiative"."id" = "subquery"."initiative_id";
3897 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';
3899 COMMENT ON COLUMN "updated_or_featured_initiative"."recipient_id" IS '"id" of the member who receives the notification mail';
3900 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")';
3901 COMMENT ON COLUMN "updated_or_featured_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
3902 COMMENT ON COLUMN "updated_or_featured_initiative"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
3905 CREATE VIEW "leading_complement_initiative" AS
3906 SELECT * FROM (
3907 SELECT DISTINCT ON ("uf_initiative"."recipient_id", "initiative"."issue_id")
3908 "uf_initiative"."recipient_id",
3909 FALSE AS "featured",
3910 "uf_initiative"."initiative_id",
3911 TRUE AS "leading"
3912 FROM "updated_or_featured_initiative" AS "uf_initiative"
3913 JOIN "initiative" AS "uf_initiative_full" ON
3914 "uf_initiative_full"."id" = "uf_initiative"."initiative_id"
3915 JOIN "initiative" ON
3916 "initiative"."issue_id" = "uf_initiative_full"."issue_id"
3917 WHERE "initiative"."revoked" ISNULL
3918 ORDER BY
3919 "uf_initiative"."recipient_id",
3920 "initiative"."issue_id",
3921 "initiative"."supporter_count" DESC,
3922 "initiative"."id"
3923 ) AS "subquery"
3924 WHERE NOT EXISTS (
3925 SELECT NULL FROM "updated_or_featured_initiative" AS "other"
3926 WHERE "other"."recipient_id" = "subquery"."recipient_id"
3927 AND "other"."initiative_id" = "subquery"."initiative_id"
3928 );
3930 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';
3931 COMMENT ON COLUMN "leading_complement_initiative"."featured" IS 'Always FALSE in this view';
3932 COMMENT ON COLUMN "leading_complement_initiative"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
3933 COMMENT ON COLUMN "leading_complement_initiative"."leading" IS 'Always TRUE in this view';
3936 CREATE VIEW "unfiltered_initiative_for_notification" AS
3937 SELECT
3938 "subquery".*,
3939 "supporter"."member_id" NOTNULL AS "supported",
3940 CASE WHEN "supporter"."member_id" NOTNULL THEN
3941 EXISTS (
3942 SELECT NULL FROM "draft"
3943 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
3944 AND "draft"."id" > "supporter"."draft_id"
3946 ELSE
3947 EXISTS (
3948 SELECT NULL FROM "draft"
3949 WHERE "draft"."initiative_id" = "subquery"."initiative_id"
3950 AND COALESCE("draft"."id" > "sent"."last_draft_id", TRUE)
3952 END AS "new_draft",
3953 CASE WHEN "supporter"."member_id" NOTNULL THEN
3954 ( SELECT count(1) FROM "suggestion"
3955 LEFT JOIN "opinion" ON
3956 "opinion"."member_id" = "supporter"."member_id" AND
3957 "opinion"."suggestion_id" = "suggestion"."id"
3958 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
3959 AND "opinion"."member_id" ISNULL
3960 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
3962 ELSE
3963 ( SELECT count(1) FROM "suggestion"
3964 WHERE "suggestion"."initiative_id" = "subquery"."initiative_id"
3965 AND COALESCE("suggestion"."id" > "sent"."last_suggestion_id", TRUE)
3967 END AS "new_suggestion_count"
3968 FROM (
3969 SELECT * FROM "updated_or_featured_initiative"
3970 UNION ALL
3971 SELECT * FROM "leading_complement_initiative"
3972 ) AS "subquery"
3973 LEFT JOIN "supporter" ON
3974 "supporter"."member_id" = "subquery"."recipient_id" AND
3975 "supporter"."initiative_id" = "subquery"."initiative_id"
3976 LEFT JOIN "notification_initiative_sent" AS "sent" ON
3977 "sent"."member_id" = "subquery"."recipient_id" AND
3978 "sent"."initiative_id" = "subquery"."initiative_id";
3980 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';
3982 COMMENT ON COLUMN "unfiltered_initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
3983 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)';
3984 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")';
3987 CREATE VIEW "initiative_for_notification" AS
3988 SELECT "unfiltered1".*
3989 FROM "unfiltered_initiative_for_notification" "unfiltered1"
3990 JOIN "initiative" AS "initiative1" ON
3991 "initiative1"."id" = "unfiltered1"."initiative_id"
3992 JOIN "issue" AS "issue1" ON "issue1"."id" = "initiative1"."issue_id"
3993 WHERE EXISTS (
3994 SELECT NULL
3995 FROM "unfiltered_initiative_for_notification" "unfiltered2"
3996 JOIN "initiative" AS "initiative2" ON
3997 "initiative2"."id" = "unfiltered2"."initiative_id"
3998 JOIN "issue" AS "issue2" ON "issue2"."id" = "initiative2"."issue_id"
3999 WHERE "unfiltered1"."recipient_id" = "unfiltered2"."recipient_id"
4000 AND "issue1"."area_id" = "issue2"."area_id"
4001 AND ("unfiltered2"."new_draft" OR "unfiltered2"."new_suggestion_count" > 0 )
4002 );
4004 COMMENT ON VIEW "initiative_for_notification" IS 'Initiatives to be included in a scheduled notification mail';
4006 COMMENT ON COLUMN "initiative_for_notification"."recipient_id" IS '"id" of the member who receives the notification mail';
4007 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")';
4008 COMMENT ON COLUMN "initiative_for_notification"."initiative_id" IS '"id" of the initiative to be included in the notification mail';
4009 COMMENT ON COLUMN "initiative_for_notification"."leading" IS 'TRUE if the initiative has the highest "supporter_count" in the issue';
4010 COMMENT ON COLUMN "initiative_for_notification"."supported" IS 'TRUE if initiative is supported by the recipient';
4011 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)';
4012 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")';
4015 CREATE VIEW "scheduled_notification_to_send" AS
4016 SELECT * FROM (
4017 SELECT
4018 "id" AS "recipient_id",
4019 now() - CASE WHEN "notification_dow" ISNULL THEN
4020 ( "notification_sent"::DATE + CASE
4021 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4022 THEN 0 ELSE 1 END
4023 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4024 ELSE
4025 ( "notification_sent"::DATE +
4026 ( 7 + "notification_dow" -
4027 EXTRACT(DOW FROM
4028 ( "notification_sent"::DATE + CASE
4029 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4030 THEN 0 ELSE 1 END
4031 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4032 )::INTEGER
4033 ) % 7 +
4034 CASE
4035 WHEN EXTRACT(HOUR FROM "notification_sent") < "notification_hour"
4036 THEN 0 ELSE 1
4037 END
4038 )::TIMESTAMP + '1 hour'::INTERVAL * "notification_hour"
4039 END AS "pending"
4040 FROM (
4041 SELECT
4042 "id",
4043 COALESCE("notification_sent", "activated") AS "notification_sent",
4044 "notification_dow",
4045 "notification_hour"
4046 FROM "member_to_notify"
4047 WHERE "notification_hour" NOTNULL
4048 ) AS "subquery1"
4049 ) AS "subquery2"
4050 WHERE "pending" > '0'::INTERVAL;
4052 COMMENT ON VIEW "scheduled_notification_to_send" IS 'Set of members where a scheduled notification mail is pending';
4054 COMMENT ON COLUMN "scheduled_notification_to_send"."recipient_id" IS '"id" of the member who needs to receive a notification mail';
4055 COMMENT ON COLUMN "scheduled_notification_to_send"."pending" IS 'Duration for which the notification mail has already been pending';
4058 CREATE VIEW "newsletter_to_send" AS
4059 SELECT
4060 "member"."id" AS "recipient_id",
4061 "newsletter"."id" AS "newsletter_id",
4062 "newsletter"."published"
4063 FROM "newsletter" CROSS JOIN "member_eligible_to_be_notified" AS "member"
4064 LEFT JOIN "privilege" ON
4065 "privilege"."member_id" = "member"."id" AND
4066 "privilege"."unit_id" = "newsletter"."unit_id" AND
4067 "privilege"."voting_right" = TRUE
4068 LEFT JOIN "subscription" ON
4069 "subscription"."member_id" = "member"."id" AND
4070 "subscription"."unit_id" = "newsletter"."unit_id"
4071 WHERE "newsletter"."published" <= now()
4072 AND "newsletter"."sent" ISNULL
4073 AND (
4074 "member"."disable_notifications" = FALSE OR
4075 "newsletter"."include_all_members" = TRUE )
4076 AND (
4077 "newsletter"."unit_id" ISNULL OR
4078 "privilege"."member_id" NOTNULL OR
4079 "subscription"."member_id" NOTNULL );
4081 COMMENT ON VIEW "newsletter_to_send" IS 'List of "newsletter_id"s for each member that are due to be sent out';
4083 COMMENT ON COLUMN "newsletter"."published" IS 'Timestamp when the newsletter was supposed to be sent out (can be used for ordering)';
4087 ------------------------------------------------------
4088 -- Row set returning function for delegation chains --
4089 ------------------------------------------------------
4092 CREATE TYPE "delegation_chain_loop_tag" AS ENUM
4093 ('first', 'intermediate', 'last', 'repetition');
4095 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type';
4098 CREATE TYPE "delegation_chain_row" AS (
4099 "index" INT4,
4100 "member_id" INT4,
4101 "member_valid" BOOLEAN,
4102 "participation" BOOLEAN,
4103 "overridden" BOOLEAN,
4104 "scope_in" "delegation_scope",
4105 "scope_out" "delegation_scope",
4106 "disabled_out" BOOLEAN,
4107 "loop" "delegation_chain_loop_tag" );
4109 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain" function';
4111 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up';
4112 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest; for area and global delegation chains: always null';
4113 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true';
4114 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation';
4115 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation';
4116 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
4117 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
4120 CREATE FUNCTION "delegation_chain_for_closed_issue"
4121 ( "member_id_p" "member"."id"%TYPE,
4122 "issue_id_p" "issue"."id"%TYPE )
4123 RETURNS SETOF "delegation_chain_row"
4124 LANGUAGE 'plpgsql' STABLE AS $$
4125 DECLARE
4126 "output_row" "delegation_chain_row";
4127 "direct_voter_row" "direct_voter"%ROWTYPE;
4128 "delegating_voter_row" "delegating_voter"%ROWTYPE;
4129 BEGIN
4130 "output_row"."index" := 0;
4131 "output_row"."member_id" := "member_id_p";
4132 "output_row"."member_valid" := TRUE;
4133 "output_row"."participation" := FALSE;
4134 "output_row"."overridden" := FALSE;
4135 "output_row"."disabled_out" := FALSE;
4136 LOOP
4137 SELECT INTO "direct_voter_row" * FROM "direct_voter"
4138 WHERE "issue_id" = "issue_id_p"
4139 AND "member_id" = "output_row"."member_id";
4140 IF "direct_voter_row"."member_id" NOTNULL THEN
4141 "output_row"."participation" := TRUE;
4142 "output_row"."scope_out" := NULL;
4143 "output_row"."disabled_out" := NULL;
4144 RETURN NEXT "output_row";
4145 RETURN;
4146 END IF;
4147 SELECT INTO "delegating_voter_row" * FROM "delegating_voter"
4148 WHERE "issue_id" = "issue_id_p"
4149 AND "member_id" = "output_row"."member_id";
4150 IF "delegating_voter_row"."member_id" ISNULL THEN
4151 RETURN;
4152 END IF;
4153 "output_row"."scope_out" := "delegating_voter_row"."scope";
4154 RETURN NEXT "output_row";
4155 "output_row"."member_id" := "delegating_voter_row"."delegate_member_ids"[1];
4156 "output_row"."scope_in" := "output_row"."scope_out";
4157 END LOOP;
4158 END;
4159 $$;
4161 COMMENT ON FUNCTION "delegation_chain_for_closed_issue"
4162 ( "member"."id"%TYPE,
4163 "member"."id"%TYPE )
4164 IS 'Helper function for "delegation_chain" function, handling the special case of closed issues after voting';
4167 CREATE FUNCTION "delegation_chain"
4168 ( "member_id_p" "member"."id"%TYPE,
4169 "unit_id_p" "unit"."id"%TYPE,
4170 "area_id_p" "area"."id"%TYPE,
4171 "issue_id_p" "issue"."id"%TYPE,
4172 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4173 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4174 RETURNS SETOF "delegation_chain_row"
4175 LANGUAGE 'plpgsql' STABLE AS $$
4176 DECLARE
4177 "scope_v" "delegation_scope";
4178 "unit_id_v" "unit"."id"%TYPE;
4179 "area_id_v" "area"."id"%TYPE;
4180 "issue_row" "issue"%ROWTYPE;
4181 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[]
4182 "loop_member_id_v" "member"."id"%TYPE;
4183 "output_row" "delegation_chain_row";
4184 "output_rows" "delegation_chain_row"[];
4185 "simulate_v" BOOLEAN;
4186 "simulate_here_v" BOOLEAN;
4187 "delegation_row" "delegation"%ROWTYPE;
4188 "row_count" INT4;
4189 "i" INT4;
4190 "loop_v" BOOLEAN;
4191 BEGIN
4192 IF "simulate_trustee_id_p" NOTNULL AND "simulate_default_p" THEN
4193 RAISE EXCEPTION 'Both "simulate_trustee_id_p" is set, and "simulate_default_p" is true';
4194 END IF;
4195 IF "simulate_trustee_id_p" NOTNULL OR "simulate_default_p" THEN
4196 "simulate_v" := TRUE;
4197 ELSE
4198 "simulate_v" := FALSE;
4199 END IF;
4200 IF
4201 "unit_id_p" NOTNULL AND
4202 "area_id_p" ISNULL AND
4203 "issue_id_p" ISNULL
4204 THEN
4205 "scope_v" := 'unit';
4206 "unit_id_v" := "unit_id_p";
4207 ELSIF
4208 "unit_id_p" ISNULL AND
4209 "area_id_p" NOTNULL AND
4210 "issue_id_p" ISNULL
4211 THEN
4212 "scope_v" := 'area';
4213 "area_id_v" := "area_id_p";
4214 SELECT "unit_id" INTO "unit_id_v"
4215 FROM "area" WHERE "id" = "area_id_v";
4216 ELSIF
4217 "unit_id_p" ISNULL AND
4218 "area_id_p" ISNULL AND
4219 "issue_id_p" NOTNULL
4220 THEN
4221 SELECT INTO "issue_row" * FROM "issue" WHERE "id" = "issue_id_p";
4222 IF "issue_row"."id" ISNULL THEN
4223 RETURN;
4224 END IF;
4225 IF "issue_row"."closed" NOTNULL THEN
4226 IF "simulate_v" THEN
4227 RAISE EXCEPTION 'Tried to simulate delegation chain for closed issue.';
4228 END IF;
4229 FOR "output_row" IN
4230 SELECT * FROM
4231 "delegation_chain_for_closed_issue"("member_id_p", "issue_id_p")
4232 LOOP
4233 RETURN NEXT "output_row";
4234 END LOOP;
4235 RETURN;
4236 END IF;
4237 "scope_v" := 'issue';
4238 SELECT "area_id" INTO "area_id_v"
4239 FROM "issue" WHERE "id" = "issue_id_p";
4240 SELECT "unit_id" INTO "unit_id_v"
4241 FROM "area" WHERE "id" = "area_id_v";
4242 ELSE
4243 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
4244 END IF;
4245 "visited_member_ids" := '{}';
4246 "loop_member_id_v" := NULL;
4247 "output_rows" := '{}';
4248 "output_row"."index" := 0;
4249 "output_row"."member_id" := "member_id_p";
4250 "output_row"."member_valid" := TRUE;
4251 "output_row"."participation" := FALSE;
4252 "output_row"."overridden" := FALSE;
4253 "output_row"."disabled_out" := FALSE;
4254 "output_row"."scope_out" := NULL;
4255 LOOP
4256 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
4257 "loop_member_id_v" := "output_row"."member_id";
4258 ELSE
4259 "visited_member_ids" :=
4260 "visited_member_ids" || "output_row"."member_id";
4261 END IF;
4262 IF "output_row"."participation" ISNULL THEN
4263 "output_row"."overridden" := NULL;
4264 ELSIF "output_row"."participation" THEN
4265 "output_row"."overridden" := TRUE;
4266 END IF;
4267 "output_row"."scope_in" := "output_row"."scope_out";
4268 "output_row"."member_valid" := EXISTS (
4269 SELECT NULL FROM "member" JOIN "privilege"
4270 ON "privilege"."member_id" = "member"."id"
4271 AND "privilege"."unit_id" = "unit_id_v"
4272 WHERE "id" = "output_row"."member_id"
4273 AND "member"."active" AND "privilege"."voting_right"
4274 );
4275 "simulate_here_v" := (
4276 "simulate_v" AND
4277 "output_row"."member_id" = "member_id_p"
4278 );
4279 "delegation_row" := ROW(NULL);
4280 IF "output_row"."member_valid" OR "simulate_here_v" THEN
4281 IF "scope_v" = 'unit' THEN
4282 IF NOT "simulate_here_v" THEN
4283 SELECT * INTO "delegation_row" FROM "delegation"
4284 WHERE "truster_id" = "output_row"."member_id"
4285 AND "unit_id" = "unit_id_v";
4286 END IF;
4287 ELSIF "scope_v" = 'area' THEN
4288 IF "simulate_here_v" THEN
4289 IF "simulate_trustee_id_p" ISNULL THEN
4290 SELECT * INTO "delegation_row" FROM "delegation"
4291 WHERE "truster_id" = "output_row"."member_id"
4292 AND "unit_id" = "unit_id_v";
4293 END IF;
4294 ELSE
4295 SELECT * INTO "delegation_row" FROM "delegation"
4296 WHERE "truster_id" = "output_row"."member_id"
4297 AND (
4298 "unit_id" = "unit_id_v" OR
4299 "area_id" = "area_id_v"
4301 ORDER BY "scope" DESC;
4302 END IF;
4303 ELSIF "scope_v" = 'issue' THEN
4304 IF "issue_row"."fully_frozen" ISNULL THEN
4305 "output_row"."participation" := EXISTS (
4306 SELECT NULL FROM "interest"
4307 WHERE "issue_id" = "issue_id_p"
4308 AND "member_id" = "output_row"."member_id"
4309 );
4310 ELSE
4311 IF "output_row"."member_id" = "member_id_p" THEN
4312 "output_row"."participation" := EXISTS (
4313 SELECT NULL FROM "direct_voter"
4314 WHERE "issue_id" = "issue_id_p"
4315 AND "member_id" = "output_row"."member_id"
4316 );
4317 ELSE
4318 "output_row"."participation" := NULL;
4319 END IF;
4320 END IF;
4321 IF "simulate_here_v" THEN
4322 IF "simulate_trustee_id_p" ISNULL THEN
4323 SELECT * INTO "delegation_row" FROM "delegation"
4324 WHERE "truster_id" = "output_row"."member_id"
4325 AND (
4326 "unit_id" = "unit_id_v" OR
4327 "area_id" = "area_id_v"
4329 ORDER BY "scope" DESC;
4330 END IF;
4331 ELSE
4332 SELECT * INTO "delegation_row" FROM "delegation"
4333 WHERE "truster_id" = "output_row"."member_id"
4334 AND (
4335 "unit_id" = "unit_id_v" OR
4336 "area_id" = "area_id_v" OR
4337 "issue_id" = "issue_id_p"
4339 ORDER BY "scope" DESC;
4340 END IF;
4341 END IF;
4342 ELSE
4343 "output_row"."participation" := FALSE;
4344 END IF;
4345 IF "simulate_here_v" AND "simulate_trustee_id_p" NOTNULL THEN
4346 "output_row"."scope_out" := "scope_v";
4347 "output_rows" := "output_rows" || "output_row";
4348 "output_row"."member_id" := "simulate_trustee_id_p";
4349 ELSIF "delegation_row"."trustee_id" NOTNULL THEN
4350 "output_row"."scope_out" := "delegation_row"."scope";
4351 "output_rows" := "output_rows" || "output_row";
4352 "output_row"."member_id" := "delegation_row"."trustee_id";
4353 ELSIF "delegation_row"."scope" NOTNULL THEN
4354 "output_row"."scope_out" := "delegation_row"."scope";
4355 "output_row"."disabled_out" := TRUE;
4356 "output_rows" := "output_rows" || "output_row";
4357 EXIT;
4358 ELSE
4359 "output_row"."scope_out" := NULL;
4360 "output_rows" := "output_rows" || "output_row";
4361 EXIT;
4362 END IF;
4363 EXIT WHEN "loop_member_id_v" NOTNULL;
4364 "output_row"."index" := "output_row"."index" + 1;
4365 END LOOP;
4366 "row_count" := array_upper("output_rows", 1);
4367 "i" := 1;
4368 "loop_v" := FALSE;
4369 LOOP
4370 "output_row" := "output_rows"["i"];
4371 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
4372 IF "loop_v" THEN
4373 IF "i" + 1 = "row_count" THEN
4374 "output_row"."loop" := 'last';
4375 ELSIF "i" = "row_count" THEN
4376 "output_row"."loop" := 'repetition';
4377 ELSE
4378 "output_row"."loop" := 'intermediate';
4379 END IF;
4380 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
4381 "output_row"."loop" := 'first';
4382 "loop_v" := TRUE;
4383 END IF;
4384 IF "scope_v" = 'unit' THEN
4385 "output_row"."participation" := NULL;
4386 END IF;
4387 RETURN NEXT "output_row";
4388 "i" := "i" + 1;
4389 END LOOP;
4390 RETURN;
4391 END;
4392 $$;
4394 COMMENT ON FUNCTION "delegation_chain"
4395 ( "member"."id"%TYPE,
4396 "unit"."id"%TYPE,
4397 "area"."id"%TYPE,
4398 "issue"."id"%TYPE,
4399 "member"."id"%TYPE,
4400 BOOLEAN )
4401 IS 'Shows a delegation chain for unit, area, or issue; See "delegation_chain_row" type for more information';
4405 ---------------------------------------------------------
4406 -- Single row returning function for delegation chains --
4407 ---------------------------------------------------------
4410 CREATE TYPE "delegation_info_loop_type" AS ENUM
4411 ('own', 'first', 'first_ellipsis', 'other', 'other_ellipsis');
4413 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''';
4416 CREATE TYPE "delegation_info_type" AS (
4417 "own_participation" BOOLEAN,
4418 "own_delegation_scope" "delegation_scope",
4419 "first_trustee_id" INT4,
4420 "first_trustee_participation" BOOLEAN,
4421 "first_trustee_ellipsis" BOOLEAN,
4422 "other_trustee_id" INT4,
4423 "other_trustee_participation" BOOLEAN,
4424 "other_trustee_ellipsis" BOOLEAN,
4425 "delegation_loop" "delegation_info_loop_type",
4426 "participating_member_id" INT4 );
4428 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';
4430 COMMENT ON COLUMN "delegation_info_type"."own_participation" IS 'Member is directly participating';
4431 COMMENT ON COLUMN "delegation_info_type"."own_delegation_scope" IS 'Delegation scope of member';
4432 COMMENT ON COLUMN "delegation_info_type"."first_trustee_id" IS 'Direct trustee of member';
4433 COMMENT ON COLUMN "delegation_info_type"."first_trustee_participation" IS 'Direct trustee of member is participating';
4434 COMMENT ON COLUMN "delegation_info_type"."first_trustee_ellipsis" IS 'Ellipsis in delegation chain after "first_trustee"';
4435 COMMENT ON COLUMN "delegation_info_type"."other_trustee_id" IS 'Another relevant trustee (due to participation)';
4436 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)';
4437 COMMENT ON COLUMN "delegation_info_type"."other_trustee_ellipsis" IS 'Ellipsis in delegation chain after "other_trustee"';
4438 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';
4439 COMMENT ON COLUMN "delegation_info_type"."participating_member_id" IS 'First participating member in delegation chain';
4442 CREATE FUNCTION "delegation_info"
4443 ( "member_id_p" "member"."id"%TYPE,
4444 "unit_id_p" "unit"."id"%TYPE,
4445 "area_id_p" "area"."id"%TYPE,
4446 "issue_id_p" "issue"."id"%TYPE,
4447 "simulate_trustee_id_p" "member"."id"%TYPE DEFAULT NULL,
4448 "simulate_default_p" BOOLEAN DEFAULT FALSE )
4449 RETURNS "delegation_info_type"
4450 LANGUAGE 'plpgsql' STABLE AS $$
4451 DECLARE
4452 "current_row" "delegation_chain_row";
4453 "result" "delegation_info_type";
4454 BEGIN
4455 "result"."own_participation" := FALSE;
4456 FOR "current_row" IN
4457 SELECT * FROM "delegation_chain"(
4458 "member_id_p",
4459 "unit_id_p", "area_id_p", "issue_id_p",
4460 "simulate_trustee_id_p", "simulate_default_p")
4461 LOOP
4462 IF
4463 "result"."participating_member_id" ISNULL AND
4464 "current_row"."participation"
4465 THEN
4466 "result"."participating_member_id" := "current_row"."member_id";
4467 END IF;
4468 IF "current_row"."member_id" = "member_id_p" THEN
4469 "result"."own_participation" := "current_row"."participation";
4470 "result"."own_delegation_scope" := "current_row"."scope_out";
4471 IF "current_row"."loop" = 'first' THEN
4472 "result"."delegation_loop" := 'own';
4473 END IF;
4474 ELSIF
4475 "current_row"."member_valid" AND
4476 ( "current_row"."loop" ISNULL OR
4477 "current_row"."loop" != 'repetition' )
4478 THEN
4479 IF "result"."first_trustee_id" ISNULL THEN
4480 "result"."first_trustee_id" := "current_row"."member_id";
4481 "result"."first_trustee_participation" := "current_row"."participation";
4482 "result"."first_trustee_ellipsis" := FALSE;
4483 IF "current_row"."loop" = 'first' THEN
4484 "result"."delegation_loop" := 'first';
4485 END IF;
4486 ELSIF "result"."other_trustee_id" ISNULL THEN
4487 IF "current_row"."participation" AND NOT "current_row"."overridden" THEN
4488 "result"."other_trustee_id" := "current_row"."member_id";
4489 "result"."other_trustee_participation" := TRUE;
4490 "result"."other_trustee_ellipsis" := FALSE;
4491 IF "current_row"."loop" = 'first' THEN
4492 "result"."delegation_loop" := 'other';
4493 END IF;
4494 ELSE
4495 "result"."first_trustee_ellipsis" := TRUE;
4496 IF "current_row"."loop" = 'first' THEN
4497 "result"."delegation_loop" := 'first_ellipsis';
4498 END IF;
4499 END IF;
4500 ELSE
4501 "result"."other_trustee_ellipsis" := TRUE;
4502 IF "current_row"."loop" = 'first' THEN
4503 "result"."delegation_loop" := 'other_ellipsis';
4504 END IF;
4505 END IF;
4506 END IF;
4507 END LOOP;
4508 RETURN "result";
4509 END;
4510 $$;
4512 COMMENT ON FUNCTION "delegation_info"
4513 ( "member"."id"%TYPE,
4514 "unit"."id"%TYPE,
4515 "area"."id"%TYPE,
4516 "issue"."id"%TYPE,
4517 "member"."id"%TYPE,
4518 BOOLEAN )
4519 IS 'Notable information about a delegation chain for unit, area, or issue; See "delegation_info_type" for more information';
4523 ---------------------------
4524 -- Transaction isolation --
4525 ---------------------------
4528 CREATE FUNCTION "require_transaction_isolation"()
4529 RETURNS VOID
4530 LANGUAGE 'plpgsql' VOLATILE AS $$
4531 BEGIN
4532 IF
4533 current_setting('transaction_isolation') NOT IN
4534 ('repeatable read', 'serializable')
4535 THEN
4536 RAISE EXCEPTION 'Insufficient transaction isolation level' USING
4537 HINT = 'Consider using SET TRANSACTION ISOLATION LEVEL REPEATABLE READ.';
4538 END IF;
4539 RETURN;
4540 END;
4541 $$;
4543 COMMENT ON FUNCTION "require_transaction_isolation"() IS 'Throws an exception, if transaction isolation level is too low to provide a consistent snapshot';
4546 CREATE FUNCTION "dont_require_transaction_isolation"()
4547 RETURNS VOID
4548 LANGUAGE 'plpgsql' VOLATILE AS $$
4549 BEGIN
4550 IF
4551 current_setting('transaction_isolation') IN
4552 ('repeatable read', 'serializable')
4553 THEN
4554 RAISE WARNING 'Unneccessary transaction isolation level: %',
4555 current_setting('transaction_isolation');
4556 END IF;
4557 RETURN;
4558 END;
4559 $$;
4561 COMMENT ON FUNCTION "dont_require_transaction_isolation"() IS 'Raises a warning, if transaction isolation level is higher than READ COMMITTED';
4565 -------------------------
4566 -- Notification system --
4567 -------------------------
4569 CREATE FUNCTION "get_initiatives_for_notification"
4570 ( "recipient_id_p" "member"."id"%TYPE )
4571 RETURNS SETOF "initiative_for_notification"
4572 LANGUAGE 'plpgsql' VOLATILE AS $$
4573 DECLARE
4574 "result_row" "initiative_for_notification"%ROWTYPE;
4575 "last_draft_id_v" "draft"."id"%TYPE;
4576 "last_suggestion_id_v" "suggestion"."id"%TYPE;
4577 BEGIN
4578 PERFORM "require_transaction_isolation"();
4579 PERFORM NULL FROM "member" WHERE "id" = "recipient_id_p" FOR UPDATE;
4580 FOR "result_row" IN
4581 SELECT * FROM "initiative_for_notification"
4582 WHERE "recipient_id" = "recipient_id_p"
4583 LOOP
4584 SELECT "id" INTO "last_draft_id_v" FROM "draft"
4585 WHERE "draft"."initiative_id" = "result_row"."initiative_id"
4586 ORDER BY "id" DESC LIMIT 1;
4587 SELECT "id" INTO "last_suggestion_id_v" FROM "suggestion"
4588 WHERE "suggestion"."initiative_id" = "result_row"."initiative_id"
4589 ORDER BY "id" DESC LIMIT 1;
4590 INSERT INTO "notification_initiative_sent"
4591 ("member_id", "initiative_id", "last_draft_id", "last_suggestion_id")
4592 VALUES (
4593 "recipient_id_p",
4594 "result_row"."initiative_id",
4595 "last_draft_id_v",
4596 "last_suggestion_id_v" )
4597 ON CONFLICT ("member_id", "initiative_id") DO UPDATE SET
4598 "last_draft_id" = "last_draft_id_v",
4599 "last_suggestion_id" = "last_suggestion_id_v";
4600 RETURN NEXT "result_row";
4601 END LOOP;
4602 DELETE FROM "notification_initiative_sent"
4603 USING "initiative", "issue"
4604 WHERE "notification_initiative_sent"."member_id" = "recipient_id_p"
4605 AND "initiative"."id" = "notification_initiative_sent"."initiative_id"
4606 AND "issue"."id" = "initiative"."issue_id"
4607 AND ( "issue"."closed" NOTNULL OR "issue"."fully_frozen" NOTNULL );
4608 UPDATE "member" SET
4609 "notification_counter" = "notification_counter" + 1,
4610 "notification_sent" = now()
4611 WHERE "id" = "recipient_id_p";
4612 RETURN;
4613 END;
4614 $$;
4616 COMMENT ON FUNCTION "get_initiatives_for_notification"
4617 ( "member"."id"%TYPE )
4618 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';
4622 ------------------------------------------------------------------------
4623 -- Regular tasks, except calculcation of snapshots and voting results --
4624 ------------------------------------------------------------------------
4627 CREATE FUNCTION "check_activity"()
4628 RETURNS VOID
4629 LANGUAGE 'plpgsql' VOLATILE AS $$
4630 DECLARE
4631 "system_setting_row" "system_setting"%ROWTYPE;
4632 BEGIN
4633 PERFORM "dont_require_transaction_isolation"();
4634 SELECT * INTO "system_setting_row" FROM "system_setting";
4635 IF "system_setting_row"."member_ttl" NOTNULL THEN
4636 UPDATE "member" SET "active" = FALSE
4637 WHERE "active" = TRUE
4638 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
4639 END IF;
4640 RETURN;
4641 END;
4642 $$;
4644 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
4647 CREATE FUNCTION "calculate_member_counts"()
4648 RETURNS VOID
4649 LANGUAGE 'plpgsql' VOLATILE AS $$
4650 BEGIN
4651 PERFORM "require_transaction_isolation"();
4652 DELETE FROM "member_count";
4653 INSERT INTO "member_count" ("total_count")
4654 SELECT "total_count" FROM "member_count_view";
4655 UPDATE "unit" SET "member_count" = "view"."member_count"
4656 FROM "unit_member_count" AS "view"
4657 WHERE "view"."unit_id" = "unit"."id";
4658 RETURN;
4659 END;
4660 $$;
4662 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"';
4665 CREATE FUNCTION "calculate_area_quorum"()
4666 RETURNS VOID
4667 LANGUAGE 'plpgsql' VOLATILE AS $$
4668 BEGIN
4669 PERFORM "dont_require_transaction_isolation"();
4670 UPDATE "area" SET "issue_quorum" = "view"."issue_quorum"
4671 FROM "area_quorum" AS "view"
4672 WHERE "view"."area_id" = "area"."id";
4673 RETURN;
4674 END;
4675 $$;
4677 COMMENT ON FUNCTION "calculate_area_quorum"() IS 'Calculate column "issue_quorum" in table "area" from view "area_quorum"';
4681 ------------------------------------
4682 -- Calculation of harmonic weight --
4683 ------------------------------------
4686 CREATE VIEW "remaining_harmonic_supporter_weight" AS
4687 SELECT
4688 "direct_interest_snapshot"."snapshot_id",
4689 "direct_interest_snapshot"."issue_id",
4690 "direct_interest_snapshot"."member_id",
4691 "direct_interest_snapshot"."weight" AS "weight_num",
4692 count("initiative"."id") AS "weight_den"
4693 FROM "issue"
4694 JOIN "direct_interest_snapshot"
4695 ON "issue"."latest_snapshot_id" = "direct_interest_snapshot"."snapshot_id"
4696 AND "issue"."id" = "direct_interest_snapshot"."issue_id"
4697 JOIN "initiative"
4698 ON "issue"."id" = "initiative"."issue_id"
4699 AND "initiative"."harmonic_weight" ISNULL
4700 JOIN "direct_supporter_snapshot"
4701 ON "issue"."latest_snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
4702 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
4703 AND "direct_interest_snapshot"."member_id" = "direct_supporter_snapshot"."member_id"
4704 AND (
4705 "direct_supporter_snapshot"."satisfied" = TRUE OR
4706 coalesce("initiative"."admitted", FALSE) = FALSE
4708 GROUP BY
4709 "direct_interest_snapshot"."snapshot_id",
4710 "direct_interest_snapshot"."issue_id",
4711 "direct_interest_snapshot"."member_id",
4712 "direct_interest_snapshot"."weight";
4714 COMMENT ON VIEW "remaining_harmonic_supporter_weight" IS 'Helper view for function "set_harmonic_initiative_weights"';
4717 CREATE VIEW "remaining_harmonic_initiative_weight_summands" AS
4718 SELECT
4719 "initiative"."issue_id",
4720 "initiative"."id" AS "initiative_id",
4721 "initiative"."admitted",
4722 sum("remaining_harmonic_supporter_weight"."weight_num") AS "weight_num",
4723 "remaining_harmonic_supporter_weight"."weight_den"
4724 FROM "remaining_harmonic_supporter_weight"
4725 JOIN "initiative"
4726 ON "remaining_harmonic_supporter_weight"."issue_id" = "initiative"."issue_id"
4727 AND "initiative"."harmonic_weight" ISNULL
4728 JOIN "direct_supporter_snapshot"
4729 ON "remaining_harmonic_supporter_weight"."snapshot_id" = "direct_supporter_snapshot"."snapshot_id"
4730 AND "initiative"."id" = "direct_supporter_snapshot"."initiative_id"
4731 AND "remaining_harmonic_supporter_weight"."member_id" = "direct_supporter_snapshot"."member_id"
4732 AND (
4733 "direct_supporter_snapshot"."satisfied" = TRUE OR
4734 coalesce("initiative"."admitted", FALSE) = FALSE
4736 GROUP BY
4737 "initiative"."issue_id",
4738 "initiative"."id",
4739 "initiative"."admitted",
4740 "remaining_harmonic_supporter_weight"."weight_den";
4742 COMMENT ON VIEW "remaining_harmonic_initiative_weight_summands" IS 'Helper view for function "set_harmonic_initiative_weights"';
4745 CREATE VIEW "remaining_harmonic_initiative_weight_dummies" AS
4746 SELECT
4747 "issue_id",
4748 "id" AS "initiative_id",
4749 "admitted",
4750 0 AS "weight_num",
4751 1 AS "weight_den"
4752 FROM "initiative"
4753 WHERE "harmonic_weight" ISNULL;
4755 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';
4758 CREATE FUNCTION "set_harmonic_initiative_weights"
4759 ( "issue_id_p" "issue"."id"%TYPE )
4760 RETURNS VOID
4761 LANGUAGE 'plpgsql' VOLATILE AS $$
4762 DECLARE
4763 "weight_row" "remaining_harmonic_initiative_weight_summands"%ROWTYPE;
4764 "i" INT4;
4765 "count_v" INT4;
4766 "summand_v" FLOAT;
4767 "id_ary" INT4[];
4768 "weight_ary" FLOAT[];
4769 "min_weight_v" FLOAT;
4770 BEGIN
4771 PERFORM "require_transaction_isolation"();
4772 UPDATE "initiative" SET "harmonic_weight" = NULL
4773 WHERE "issue_id" = "issue_id_p";
4774 LOOP
4775 "min_weight_v" := NULL;
4776 "i" := 0;
4777 "count_v" := 0;
4778 FOR "weight_row" IN
4779 SELECT * FROM "remaining_harmonic_initiative_weight_summands"
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 UNION ALL -- needed for corner cases
4790 SELECT * FROM "remaining_harmonic_initiative_weight_dummies"
4791 WHERE "issue_id" = "issue_id_p"
4792 AND (
4793 coalesce("admitted", FALSE) = FALSE OR NOT EXISTS (
4794 SELECT NULL FROM "initiative"
4795 WHERE "issue_id" = "issue_id_p"
4796 AND "harmonic_weight" ISNULL
4797 AND coalesce("admitted", FALSE) = FALSE
4800 ORDER BY "initiative_id" DESC, "weight_den" DESC
4801 -- NOTE: non-admitted initiatives placed first (at last positions),
4802 -- latest initiatives treated worse in case of tie
4803 LOOP
4804 "summand_v" := "weight_row"."weight_num"::FLOAT / "weight_row"."weight_den"::FLOAT;
4805 IF "i" = 0 OR "weight_row"."initiative_id" != "id_ary"["i"] THEN
4806 "i" := "i" + 1;
4807 "count_v" := "i";
4808 "id_ary"["i"] := "weight_row"."initiative_id";
4809 "weight_ary"["i"] := "summand_v";
4810 ELSE
4811 "weight_ary"["i"] := "weight_ary"["i"] + "summand_v";
4812 END IF;
4813 END LOOP;
4814 EXIT WHEN "count_v" = 0;
4815 "i" := 1;
4816 LOOP
4817 "weight_ary"["i"] := "weight_ary"["i"]::NUMERIC(18,9)::NUMERIC(12,3);
4818 IF "min_weight_v" ISNULL OR "weight_ary"["i"] < "min_weight_v" THEN
4819 "min_weight_v" := "weight_ary"["i"];
4820 END IF;
4821 "i" := "i" + 1;
4822 EXIT WHEN "i" > "count_v";
4823 END LOOP;
4824 "i" := 1;
4825 LOOP
4826 IF "weight_ary"["i"] = "min_weight_v" THEN
4827 UPDATE "initiative" SET "harmonic_weight" = "min_weight_v"
4828 WHERE "id" = "id_ary"["i"];
4829 EXIT;
4830 END IF;
4831 "i" := "i" + 1;
4832 END LOOP;
4833 END LOOP;
4834 UPDATE "initiative" SET "harmonic_weight" = 0
4835 WHERE "issue_id" = "issue_id_p" AND "harmonic_weight" ISNULL;
4836 END;
4837 $$;
4839 COMMENT ON FUNCTION "set_harmonic_initiative_weights"
4840 ( "issue"."id"%TYPE )
4841 IS 'Calculates and sets "harmonic_weight" of initiatives in a given issue';
4845 ------------------------------
4846 -- Calculation of snapshots --
4847 ------------------------------
4850 CREATE FUNCTION "weight_of_added_delegations_for_snapshot"
4851 ( "snapshot_id_p" "snapshot"."id"%TYPE,
4852 "issue_id_p" "issue"."id"%TYPE,
4853 "member_id_p" "member"."id"%TYPE,
4854 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
4855 RETURNS "direct_interest_snapshot"."weight"%TYPE
4856 LANGUAGE 'plpgsql' VOLATILE AS $$
4857 DECLARE
4858 "issue_delegation_row" "issue_delegation"%ROWTYPE;
4859 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE;
4860 "weight_v" INT4;
4861 "sub_weight_v" INT4;
4862 BEGIN
4863 PERFORM "require_transaction_isolation"();
4864 "weight_v" := 0;
4865 FOR "issue_delegation_row" IN
4866 SELECT * FROM "issue_delegation"
4867 WHERE "trustee_id" = "member_id_p"
4868 AND "issue_id" = "issue_id_p"
4869 LOOP
4870 IF NOT EXISTS (
4871 SELECT NULL FROM "direct_interest_snapshot"
4872 WHERE "snapshot_id" = "snapshot_id_p"
4873 AND "issue_id" = "issue_id_p"
4874 AND "member_id" = "issue_delegation_row"."truster_id"
4875 ) AND NOT EXISTS (
4876 SELECT NULL FROM "delegating_interest_snapshot"
4877 WHERE "snapshot_id" = "snapshot_id_p"
4878 AND "issue_id" = "issue_id_p"
4879 AND "member_id" = "issue_delegation_row"."truster_id"
4880 ) THEN
4881 "delegate_member_ids_v" :=
4882 "member_id_p" || "delegate_member_ids_p";
4883 INSERT INTO "delegating_interest_snapshot" (
4884 "snapshot_id",
4885 "issue_id",
4886 "member_id",
4887 "scope",
4888 "delegate_member_ids"
4889 ) VALUES (
4890 "snapshot_id_p",
4891 "issue_id_p",
4892 "issue_delegation_row"."truster_id",
4893 "issue_delegation_row"."scope",
4894 "delegate_member_ids_v"
4895 );
4896 "sub_weight_v" := 1 +
4897 "weight_of_added_delegations_for_snapshot"(
4898 "snapshot_id_p",
4899 "issue_id_p",
4900 "issue_delegation_row"."truster_id",
4901 "delegate_member_ids_v"
4902 );
4903 UPDATE "delegating_interest_snapshot"
4904 SET "weight" = "sub_weight_v"
4905 WHERE "snapshot_id" = "snapshot_id_p"
4906 AND "issue_id" = "issue_id_p"
4907 AND "member_id" = "issue_delegation_row"."truster_id";
4908 "weight_v" := "weight_v" + "sub_weight_v";
4909 END IF;
4910 END LOOP;
4911 RETURN "weight_v";
4912 END;
4913 $$;
4915 COMMENT ON FUNCTION "weight_of_added_delegations_for_snapshot"
4916 ( "snapshot"."id"%TYPE,
4917 "issue"."id"%TYPE,
4918 "member"."id"%TYPE,
4919 "delegating_interest_snapshot"."delegate_member_ids"%TYPE )
4920 IS 'Helper function for "fill_snapshot" function';
4923 CREATE FUNCTION "take_snapshot"
4924 ( "issue_id_p" "issue"."id"%TYPE,
4925 "area_id_p" "area"."id"%TYPE = NULL )
4926 RETURNS "snapshot"."id"%TYPE
4927 LANGUAGE 'plpgsql' VOLATILE AS $$
4928 DECLARE
4929 "area_id_v" "area"."id"%TYPE;
4930 "unit_id_v" "unit"."id"%TYPE;
4931 "snapshot_id_v" "snapshot"."id"%TYPE;
4932 "issue_id_v" "issue"."id"%TYPE;
4933 "member_id_v" "member"."id"%TYPE;
4934 BEGIN
4935 IF "issue_id_p" NOTNULL AND "area_id_p" NOTNULL THEN
4936 RAISE EXCEPTION 'One of "issue_id_p" and "area_id_p" must be NULL';
4937 END IF;
4938 PERFORM "require_transaction_isolation"();
4939 IF "issue_id_p" ISNULL THEN
4940 "area_id_v" := "area_id_p";
4941 ELSE
4942 SELECT "area_id" INTO "area_id_v"
4943 FROM "issue" WHERE "id" = "issue_id_p";
4944 END IF;
4945 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_p";
4946 INSERT INTO "snapshot" ("area_id", "issue_id")
4947 VALUES ("area_id_v", "issue_id_p")
4948 RETURNING "id" INTO "snapshot_id_v";
4949 INSERT INTO "snapshot_population" ("snapshot_id", "member_id")
4950 SELECT "snapshot_id_v", "member_id"
4951 FROM "unit_member" WHERE "unit_id" = "unit_id_v";
4952 UPDATE "snapshot" SET
4953 "population" = (
4954 SELECT count(1) FROM "snapshot_population"
4955 WHERE "snapshot_id" = "snapshot_id_v"
4956 ) WHERE "id" = "snapshot_id_v";
4957 FOR "issue_id_v" IN
4958 SELECT "id" FROM "issue"
4959 WHERE CASE WHEN "issue_id_p" ISNULL THEN
4960 "area_id" = "area_id_p" AND
4961 "state" = 'admission'
4962 ELSE
4963 "id" = "issue_id_p"
4964 END
4965 LOOP
4966 INSERT INTO "snapshot_issue" ("snapshot_id", "issue_id")
4967 VALUES ("snapshot_id_v", "issue_id_v");
4968 INSERT INTO "direct_interest_snapshot"
4969 ("snapshot_id", "issue_id", "member_id")
4970 SELECT
4971 "snapshot_id_v" AS "snapshot_id",
4972 "issue_id_v" AS "issue_id",
4973 "member"."id" AS "member_id"
4974 FROM "issue"
4975 JOIN "area" ON "issue"."area_id" = "area"."id"
4976 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
4977 JOIN "member" ON "interest"."member_id" = "member"."id"
4978 JOIN "privilege"
4979 ON "privilege"."unit_id" = "area"."unit_id"
4980 AND "privilege"."member_id" = "member"."id"
4981 WHERE "issue"."id" = "issue_id_v"
4982 AND "member"."active" AND "privilege"."voting_right";
4983 FOR "member_id_v" IN
4984 SELECT "member_id" FROM "direct_interest_snapshot"
4985 WHERE "snapshot_id" = "snapshot_id_v"
4986 AND "issue_id" = "issue_id_v"
4987 LOOP
4988 UPDATE "direct_interest_snapshot" SET
4989 "weight" = 1 +
4990 "weight_of_added_delegations_for_snapshot"(
4991 "snapshot_id_v",
4992 "issue_id_v",
4993 "member_id_v",
4994 '{}'
4996 WHERE "snapshot_id" = "snapshot_id_v"
4997 AND "issue_id" = "issue_id_v"
4998 AND "member_id" = "member_id_v";
4999 END LOOP;
5000 INSERT INTO "direct_supporter_snapshot"
5001 ( "snapshot_id", "issue_id", "initiative_id", "member_id",
5002 "draft_id", "informed", "satisfied" )
5003 SELECT
5004 "snapshot_id_v" AS "snapshot_id",
5005 "issue_id_v" AS "issue_id",
5006 "initiative"."id" AS "initiative_id",
5007 "supporter"."member_id" AS "member_id",
5008 "supporter"."draft_id" AS "draft_id",
5009 "supporter"."draft_id" = "current_draft"."id" AS "informed",
5010 NOT EXISTS (
5011 SELECT NULL FROM "critical_opinion"
5012 WHERE "initiative_id" = "initiative"."id"
5013 AND "member_id" = "supporter"."member_id"
5014 ) AS "satisfied"
5015 FROM "initiative"
5016 JOIN "supporter"
5017 ON "supporter"."initiative_id" = "initiative"."id"
5018 JOIN "current_draft"
5019 ON "initiative"."id" = "current_draft"."initiative_id"
5020 JOIN "direct_interest_snapshot"
5021 ON "snapshot_id_v" = "direct_interest_snapshot"."snapshot_id"
5022 AND "supporter"."member_id" = "direct_interest_snapshot"."member_id"
5023 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
5024 WHERE "initiative"."issue_id" = "issue_id_v";
5025 DELETE FROM "temporary_suggestion_counts";
5026 INSERT INTO "temporary_suggestion_counts"
5027 ( "id",
5028 "minus2_unfulfilled_count", "minus2_fulfilled_count",
5029 "minus1_unfulfilled_count", "minus1_fulfilled_count",
5030 "plus1_unfulfilled_count", "plus1_fulfilled_count",
5031 "plus2_unfulfilled_count", "plus2_fulfilled_count" )
5032 SELECT
5033 "suggestion"."id",
5034 ( SELECT coalesce(sum("di"."weight"), 0)
5035 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5036 ON "di"."snapshot_id" = "snapshot_id_v"
5037 AND "di"."issue_id" = "issue_id_v"
5038 AND "di"."member_id" = "opinion"."member_id"
5039 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5040 AND "opinion"."degree" = -2
5041 AND "opinion"."fulfilled" = FALSE
5042 ) AS "minus2_unfulfilled_count",
5043 ( SELECT coalesce(sum("di"."weight"), 0)
5044 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5045 ON "di"."snapshot_id" = "snapshot_id_v"
5046 AND "di"."issue_id" = "issue_id_v"
5047 AND "di"."member_id" = "opinion"."member_id"
5048 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5049 AND "opinion"."degree" = -2
5050 AND "opinion"."fulfilled" = TRUE
5051 ) AS "minus2_fulfilled_count",
5052 ( SELECT coalesce(sum("di"."weight"), 0)
5053 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5054 ON "di"."snapshot_id" = "snapshot_id_v"
5055 AND "di"."issue_id" = "issue_id_v"
5056 AND "di"."member_id" = "opinion"."member_id"
5057 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5058 AND "opinion"."degree" = -1
5059 AND "opinion"."fulfilled" = FALSE
5060 ) AS "minus1_unfulfilled_count",
5061 ( SELECT coalesce(sum("di"."weight"), 0)
5062 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5063 ON "di"."snapshot_id" = "snapshot_id_v"
5064 AND "di"."issue_id" = "issue_id_v"
5065 AND "di"."member_id" = "opinion"."member_id"
5066 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5067 AND "opinion"."degree" = -1
5068 AND "opinion"."fulfilled" = TRUE
5069 ) AS "minus1_fulfilled_count",
5070 ( SELECT coalesce(sum("di"."weight"), 0)
5071 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5072 ON "di"."snapshot_id" = "snapshot_id_v"
5073 AND "di"."issue_id" = "issue_id_v"
5074 AND "di"."member_id" = "opinion"."member_id"
5075 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5076 AND "opinion"."degree" = 1
5077 AND "opinion"."fulfilled" = FALSE
5078 ) AS "plus1_unfulfilled_count",
5079 ( SELECT coalesce(sum("di"."weight"), 0)
5080 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5081 ON "di"."snapshot_id" = "snapshot_id_v"
5082 AND "di"."issue_id" = "issue_id_v"
5083 AND "di"."member_id" = "opinion"."member_id"
5084 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5085 AND "opinion"."degree" = 1
5086 AND "opinion"."fulfilled" = TRUE
5087 ) AS "plus1_fulfilled_count",
5088 ( SELECT coalesce(sum("di"."weight"), 0)
5089 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5090 ON "di"."snapshot_id" = "snapshot_id_v"
5091 AND "di"."issue_id" = "issue_id_v"
5092 AND "di"."member_id" = "opinion"."member_id"
5093 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5094 AND "opinion"."degree" = 2
5095 AND "opinion"."fulfilled" = FALSE
5096 ) AS "plus2_unfulfilled_count",
5097 ( SELECT coalesce(sum("di"."weight"), 0)
5098 FROM "opinion" JOIN "direct_interest_snapshot" AS "di"
5099 ON "di"."snapshot_id" = "snapshot_id_v"
5100 AND "di"."issue_id" = "issue_id_v"
5101 AND "di"."member_id" = "opinion"."member_id"
5102 WHERE "opinion"."suggestion_id" = "suggestion"."id"
5103 AND "opinion"."degree" = 2
5104 AND "opinion"."fulfilled" = TRUE
5105 ) AS "plus2_fulfilled_count"
5106 FROM "suggestion" JOIN "initiative"
5107 ON "suggestion"."initiative_id" = "initiative"."id"
5108 WHERE "initiative"."issue_id" = "issue_id_v";
5109 END LOOP;
5110 RETURN "snapshot_id_v";
5111 END;
5112 $$;
5114 COMMENT ON FUNCTION "take_snapshot"
5115 ( "issue"."id"%TYPE,
5116 "area"."id"%TYPE )
5117 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.';
5120 CREATE FUNCTION "finish_snapshot"
5121 ( "issue_id_p" "issue"."id"%TYPE )
5122 RETURNS VOID
5123 LANGUAGE 'plpgsql' VOLATILE AS $$
5124 DECLARE
5125 "snapshot_id_v" "snapshot"."id"%TYPE;
5126 BEGIN
5127 -- NOTE: function does not require snapshot isolation but we don't call
5128 -- "dont_require_snapshot_isolation" here because this function is
5129 -- also invoked by "check_issue"
5130 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
5131 SELECT "id" INTO "snapshot_id_v" FROM "snapshot"
5132 ORDER BY "id" DESC LIMIT 1;
5133 UPDATE "issue" SET
5134 "calculated" = "snapshot"."calculated",
5135 "latest_snapshot_id" = "snapshot_id_v",
5136 "population" = "snapshot"."population"
5137 FROM "snapshot"
5138 WHERE "issue"."id" = "issue_id_p"
5139 AND "snapshot"."id" = "snapshot_id_v";
5140 UPDATE "initiative" SET
5141 "supporter_count" = (
5142 SELECT coalesce(sum("di"."weight"), 0)
5143 FROM "direct_interest_snapshot" AS "di"
5144 JOIN "direct_supporter_snapshot" AS "ds"
5145 ON "di"."member_id" = "ds"."member_id"
5146 WHERE "di"."snapshot_id" = "snapshot_id_v"
5147 AND "di"."issue_id" = "issue_id_p"
5148 AND "ds"."snapshot_id" = "snapshot_id_v"
5149 AND "ds"."initiative_id" = "initiative"."id"
5150 ),
5151 "informed_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"."informed"
5161 ),
5162 "satisfied_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"."satisfied"
5172 ),
5173 "satisfied_informed_supporter_count" = (
5174 SELECT coalesce(sum("di"."weight"), 0)
5175 FROM "direct_interest_snapshot" AS "di"
5176 JOIN "direct_supporter_snapshot" AS "ds"
5177 ON "di"."member_id" = "ds"."member_id"
5178 WHERE "di"."snapshot_id" = "snapshot_id_v"
5179 AND "di"."issue_id" = "issue_id_p"
5180 AND "ds"."snapshot_id" = "snapshot_id_v"
5181 AND "ds"."initiative_id" = "initiative"."id"
5182 AND "ds"."informed"
5183 AND "ds"."satisfied"
5185 WHERE "issue_id" = "issue_id_p";
5186 UPDATE "suggestion" SET
5187 "minus2_unfulfilled_count" = "temp"."minus2_unfulfilled_count",
5188 "minus2_fulfilled_count" = "temp"."minus2_fulfilled_count",
5189 "minus1_unfulfilled_count" = "temp"."minus1_unfulfilled_count",
5190 "minus1_fulfilled_count" = "temp"."minus1_fulfilled_count",
5191 "plus1_unfulfilled_count" = "temp"."plus1_unfulfilled_count",
5192 "plus1_fulfilled_count" = "temp"."plus1_fulfilled_count",
5193 "plus2_unfulfilled_count" = "temp"."plus2_unfulfilled_count",
5194 "plus2_fulfilled_count" = "temp"."plus2_fulfilled_count"
5195 FROM "temporary_suggestion_counts" AS "temp", "initiative"
5196 WHERE "temp"."id" = "suggestion"."id"
5197 AND "initiative"."issue_id" = "issue_id_p"
5198 AND "suggestion"."initiative_id" = "initiative"."id";
5199 DELETE FROM "temporary_suggestion_counts";
5200 RETURN;
5201 END;
5202 $$;
5204 COMMENT ON FUNCTION "finish_snapshot"
5205 ( "issue"."id"%TYPE )
5206 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)';
5210 -----------------------
5211 -- Counting of votes --
5212 -----------------------
5215 CREATE FUNCTION "weight_of_added_vote_delegations"
5216 ( "issue_id_p" "issue"."id"%TYPE,
5217 "member_id_p" "member"."id"%TYPE,
5218 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE )
5219 RETURNS "direct_voter"."weight"%TYPE
5220 LANGUAGE 'plpgsql' VOLATILE AS $$
5221 DECLARE
5222 "issue_delegation_row" "issue_delegation"%ROWTYPE;
5223 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE;
5224 "weight_v" INT4;
5225 "sub_weight_v" INT4;
5226 BEGIN
5227 PERFORM "require_transaction_isolation"();
5228 "weight_v" := 0;
5229 FOR "issue_delegation_row" IN
5230 SELECT * FROM "issue_delegation"
5231 WHERE "trustee_id" = "member_id_p"
5232 AND "issue_id" = "issue_id_p"
5233 LOOP
5234 IF NOT EXISTS (
5235 SELECT NULL FROM "direct_voter"
5236 WHERE "member_id" = "issue_delegation_row"."truster_id"
5237 AND "issue_id" = "issue_id_p"
5238 ) AND NOT EXISTS (
5239 SELECT NULL FROM "delegating_voter"
5240 WHERE "member_id" = "issue_delegation_row"."truster_id"
5241 AND "issue_id" = "issue_id_p"
5242 ) THEN
5243 "delegate_member_ids_v" :=
5244 "member_id_p" || "delegate_member_ids_p";
5245 INSERT INTO "delegating_voter" (
5246 "issue_id",
5247 "member_id",
5248 "scope",
5249 "delegate_member_ids"
5250 ) VALUES (
5251 "issue_id_p",
5252 "issue_delegation_row"."truster_id",
5253 "issue_delegation_row"."scope",
5254 "delegate_member_ids_v"
5255 );
5256 "sub_weight_v" := 1 +
5257 "weight_of_added_vote_delegations"(
5258 "issue_id_p",
5259 "issue_delegation_row"."truster_id",
5260 "delegate_member_ids_v"
5261 );
5262 UPDATE "delegating_voter"
5263 SET "weight" = "sub_weight_v"
5264 WHERE "issue_id" = "issue_id_p"
5265 AND "member_id" = "issue_delegation_row"."truster_id";
5266 "weight_v" := "weight_v" + "sub_weight_v";
5267 END IF;
5268 END LOOP;
5269 RETURN "weight_v";
5270 END;
5271 $$;
5273 COMMENT ON FUNCTION "weight_of_added_vote_delegations"
5274 ( "issue"."id"%TYPE,
5275 "member"."id"%TYPE,
5276 "delegating_voter"."delegate_member_ids"%TYPE )
5277 IS 'Helper function for "add_vote_delegations" function';
5280 CREATE FUNCTION "add_vote_delegations"
5281 ( "issue_id_p" "issue"."id"%TYPE )
5282 RETURNS VOID
5283 LANGUAGE 'plpgsql' VOLATILE AS $$
5284 DECLARE
5285 "member_id_v" "member"."id"%TYPE;
5286 BEGIN
5287 PERFORM "require_transaction_isolation"();
5288 FOR "member_id_v" IN
5289 SELECT "member_id" FROM "direct_voter"
5290 WHERE "issue_id" = "issue_id_p"
5291 LOOP
5292 UPDATE "direct_voter" SET
5293 "weight" = "weight" + "weight_of_added_vote_delegations"(
5294 "issue_id_p",
5295 "member_id_v",
5296 '{}'
5298 WHERE "member_id" = "member_id_v"
5299 AND "issue_id" = "issue_id_p";
5300 END LOOP;
5301 RETURN;
5302 END;
5303 $$;
5305 COMMENT ON FUNCTION "add_vote_delegations"
5306 ( "issue_id_p" "issue"."id"%TYPE )
5307 IS 'Helper function for "close_voting" function';
5310 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
5311 RETURNS VOID
5312 LANGUAGE 'plpgsql' VOLATILE AS $$
5313 DECLARE
5314 "area_id_v" "area"."id"%TYPE;
5315 "unit_id_v" "unit"."id"%TYPE;
5316 "member_id_v" "member"."id"%TYPE;
5317 BEGIN
5318 PERFORM "require_transaction_isolation"();
5319 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
5320 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v";
5321 -- override protection triggers:
5322 INSERT INTO "temporary_transaction_data" ("key", "value")
5323 VALUES ('override_protection_triggers', TRUE::TEXT);
5324 -- delete timestamp of voting comment:
5325 UPDATE "direct_voter" SET "comment_changed" = NULL
5326 WHERE "issue_id" = "issue_id_p";
5327 -- delete delegating votes (in cases of manual reset of issue state):
5328 DELETE FROM "delegating_voter"
5329 WHERE "issue_id" = "issue_id_p";
5330 -- delete votes from non-privileged voters:
5331 DELETE FROM "direct_voter"
5332 USING (
5333 SELECT
5334 "direct_voter"."member_id"
5335 FROM "direct_voter"
5336 JOIN "member" ON "direct_voter"."member_id" = "member"."id"
5337 LEFT JOIN "privilege"
5338 ON "privilege"."unit_id" = "unit_id_v"
5339 AND "privilege"."member_id" = "direct_voter"."member_id"
5340 WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
5341 "member"."active" = FALSE OR
5342 "privilege"."voting_right" ISNULL OR
5343 "privilege"."voting_right" = FALSE
5345 ) AS "subquery"
5346 WHERE "direct_voter"."issue_id" = "issue_id_p"
5347 AND "direct_voter"."member_id" = "subquery"."member_id";
5348 -- consider delegations:
5349 UPDATE "direct_voter" SET "weight" = 1
5350 WHERE "issue_id" = "issue_id_p";
5351 PERFORM "add_vote_delegations"("issue_id_p");
5352 -- mark first preferences:
5353 UPDATE "vote" SET "first_preference" = "subquery"."first_preference"
5354 FROM (
5355 SELECT
5356 "vote"."initiative_id",
5357 "vote"."member_id",
5358 CASE WHEN "vote"."grade" > 0 THEN
5359 CASE WHEN "vote"."grade" = max("agg"."grade") THEN TRUE ELSE FALSE END
5360 ELSE NULL
5361 END AS "first_preference"
5362 FROM "vote"
5363 JOIN "initiative" -- NOTE: due to missing index on issue_id
5364 ON "vote"."issue_id" = "initiative"."issue_id"
5365 JOIN "vote" AS "agg"
5366 ON "initiative"."id" = "agg"."initiative_id"
5367 AND "vote"."member_id" = "agg"."member_id"
5368 GROUP BY "vote"."initiative_id", "vote"."member_id", "vote"."grade"
5369 ) AS "subquery"
5370 WHERE "vote"."issue_id" = "issue_id_p"
5371 AND "vote"."initiative_id" = "subquery"."initiative_id"
5372 AND "vote"."member_id" = "subquery"."member_id";
5373 -- finish overriding protection triggers (avoids garbage):
5374 DELETE FROM "temporary_transaction_data"
5375 WHERE "key" = 'override_protection_triggers';
5376 -- materialize battle_view:
5377 -- NOTE: "closed" column of issue must be set at this point
5378 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
5379 INSERT INTO "battle" (
5380 "issue_id",
5381 "winning_initiative_id", "losing_initiative_id",
5382 "count"
5383 ) SELECT
5384 "issue_id",
5385 "winning_initiative_id", "losing_initiative_id",
5386 "count"
5387 FROM "battle_view" WHERE "issue_id" = "issue_id_p";
5388 -- set voter count:
5389 UPDATE "issue" SET
5390 "voter_count" = (
5391 SELECT coalesce(sum("weight"), 0)
5392 FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
5394 WHERE "id" = "issue_id_p";
5395 -- copy "positive_votes" and "negative_votes" from "battle" table:
5396 -- NOTE: "first_preference_votes" is set to a default of 0 at this step
5397 UPDATE "initiative" SET
5398 "first_preference_votes" = 0,
5399 "positive_votes" = "battle_win"."count",
5400 "negative_votes" = "battle_lose"."count"
5401 FROM "battle" AS "battle_win", "battle" AS "battle_lose"
5402 WHERE
5403 "battle_win"."issue_id" = "issue_id_p" AND
5404 "battle_win"."winning_initiative_id" = "initiative"."id" AND
5405 "battle_win"."losing_initiative_id" ISNULL AND
5406 "battle_lose"."issue_id" = "issue_id_p" AND
5407 "battle_lose"."losing_initiative_id" = "initiative"."id" AND
5408 "battle_lose"."winning_initiative_id" ISNULL;
5409 -- calculate "first_preference_votes":
5410 -- NOTE: will only set values not equal to zero
5411 UPDATE "initiative" SET "first_preference_votes" = "subquery"."sum"
5412 FROM (
5413 SELECT "vote"."initiative_id", sum("direct_voter"."weight")
5414 FROM "vote" JOIN "direct_voter"
5415 ON "vote"."issue_id" = "direct_voter"."issue_id"
5416 AND "vote"."member_id" = "direct_voter"."member_id"
5417 WHERE "vote"."first_preference"
5418 GROUP BY "vote"."initiative_id"
5419 ) AS "subquery"
5420 WHERE "initiative"."issue_id" = "issue_id_p"
5421 AND "initiative"."admitted"
5422 AND "initiative"."id" = "subquery"."initiative_id";
5423 END;
5424 $$;
5426 COMMENT ON FUNCTION "close_voting"
5427 ( "issue"."id"%TYPE )
5428 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.';
5431 CREATE FUNCTION "defeat_strength"
5432 ( "positive_votes_p" INT4,
5433 "negative_votes_p" INT4,
5434 "defeat_strength_p" "defeat_strength" )
5435 RETURNS INT8
5436 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5437 BEGIN
5438 IF "defeat_strength_p" = 'simple'::"defeat_strength" THEN
5439 IF "positive_votes_p" > "negative_votes_p" THEN
5440 RETURN "positive_votes_p";
5441 ELSE
5442 RETURN 0;
5443 END IF;
5444 ELSE
5445 IF "positive_votes_p" > "negative_votes_p" THEN
5446 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8;
5447 ELSIF "positive_votes_p" = "negative_votes_p" THEN
5448 RETURN 0;
5449 ELSE
5450 RETURN -1;
5451 END IF;
5452 END IF;
5453 END;
5454 $$;
5456 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")';
5459 CREATE FUNCTION "secondary_link_strength"
5460 ( "initiative1_ord_p" INT4,
5461 "initiative2_ord_p" INT4,
5462 "tie_breaking_p" "tie_breaking" )
5463 RETURNS INT8
5464 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5465 BEGIN
5466 IF "initiative1_ord_p" = "initiative2_ord_p" THEN
5467 RAISE EXCEPTION 'Identical initiative ids passed to "secondary_link_strength" function (should not happen)';
5468 END IF;
5469 RETURN (
5470 CASE WHEN "tie_breaking_p" = 'simple'::"tie_breaking" THEN
5472 ELSE
5473 CASE WHEN "initiative1_ord_p" < "initiative2_ord_p" THEN
5474 1::INT8 << 62
5475 ELSE 0 END
5477 CASE WHEN "tie_breaking_p" = 'variant2'::"tie_breaking" THEN
5478 ("initiative2_ord_p"::INT8 << 31) - "initiative1_ord_p"::INT8
5479 ELSE
5480 "initiative2_ord_p"::INT8 - ("initiative1_ord_p"::INT8 << 31)
5481 END
5482 END
5483 );
5484 END;
5485 $$;
5487 COMMENT ON FUNCTION "secondary_link_strength"(INT4, INT4, "tie_breaking") IS 'Calculates a secondary criterion for the defeat strength (tie-breaking of the links)';
5490 CREATE TYPE "link_strength" AS (
5491 "primary" INT8,
5492 "secondary" INT8 );
5494 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'')';
5497 CREATE FUNCTION "find_best_paths"("matrix_d" "link_strength"[][])
5498 RETURNS "link_strength"[][]
5499 LANGUAGE 'plpgsql' IMMUTABLE AS $$
5500 DECLARE
5501 "dimension_v" INT4;
5502 "matrix_p" "link_strength"[][];
5503 "i" INT4;
5504 "j" INT4;
5505 "k" INT4;
5506 BEGIN
5507 "dimension_v" := array_upper("matrix_d", 1);
5508 "matrix_p" := "matrix_d";
5509 "i" := 1;
5510 LOOP
5511 "j" := 1;
5512 LOOP
5513 IF "i" != "j" THEN
5514 "k" := 1;
5515 LOOP
5516 IF "i" != "k" AND "j" != "k" THEN
5517 IF "matrix_p"["j"]["i"] < "matrix_p"["i"]["k"] THEN
5518 IF "matrix_p"["j"]["i"] > "matrix_p"["j"]["k"] THEN
5519 "matrix_p"["j"]["k"] := "matrix_p"["j"]["i"];
5520 END IF;
5521 ELSE
5522 IF "matrix_p"["i"]["k"] > "matrix_p"["j"]["k"] THEN
5523 "matrix_p"["j"]["k"] := "matrix_p"["i"]["k"];
5524 END IF;
5525 END IF;
5526 END IF;
5527 EXIT WHEN "k" = "dimension_v";
5528 "k" := "k" + 1;
5529 END LOOP;
5530 END IF;
5531 EXIT WHEN "j" = "dimension_v";
5532 "j" := "j" + 1;
5533 END LOOP;
5534 EXIT WHEN "i" = "dimension_v";
5535 "i" := "i" + 1;
5536 END LOOP;
5537 RETURN "matrix_p";
5538 END;
5539 $$;
5541 COMMENT ON FUNCTION "find_best_paths"("link_strength"[][]) IS 'Computes the strengths of the best beat-paths from a square matrix';
5544 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
5545 RETURNS VOID
5546 LANGUAGE 'plpgsql' VOLATILE AS $$
5547 DECLARE
5548 "issue_row" "issue"%ROWTYPE;
5549 "policy_row" "policy"%ROWTYPE;
5550 "dimension_v" INT4;
5551 "matrix_a" INT4[][]; -- absolute votes
5552 "matrix_d" "link_strength"[][]; -- defeat strength (direct)
5553 "matrix_p" "link_strength"[][]; -- defeat strength (best path)
5554 "matrix_t" "link_strength"[][]; -- defeat strength (tie-breaking)
5555 "matrix_f" BOOLEAN[][]; -- forbidden link (tie-breaking)
5556 "matrix_b" BOOLEAN[][]; -- final order (who beats who)
5557 "i" INT4;
5558 "j" INT4;
5559 "m" INT4;
5560 "n" INT4;
5561 "battle_row" "battle"%ROWTYPE;
5562 "rank_ary" INT4[];
5563 "rank_v" INT4;
5564 "initiative_id_v" "initiative"."id"%TYPE;
5565 BEGIN
5566 PERFORM "require_transaction_isolation"();
5567 SELECT * INTO "issue_row"
5568 FROM "issue" WHERE "id" = "issue_id_p";
5569 SELECT * INTO "policy_row"
5570 FROM "policy" WHERE "id" = "issue_row"."policy_id";
5571 SELECT count(1) INTO "dimension_v"
5572 FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
5573 -- create "matrix_a" with absolute number of votes in pairwise
5574 -- comparison:
5575 "matrix_a" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
5576 "i" := 1;
5577 "j" := 2;
5578 FOR "battle_row" IN
5579 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
5580 ORDER BY
5581 "winning_initiative_id" NULLS FIRST,
5582 "losing_initiative_id" NULLS FIRST
5583 LOOP
5584 "matrix_a"["i"]["j"] := "battle_row"."count";
5585 IF "j" = "dimension_v" THEN
5586 "i" := "i" + 1;
5587 "j" := 1;
5588 ELSE
5589 "j" := "j" + 1;
5590 IF "j" = "i" THEN
5591 "j" := "j" + 1;
5592 END IF;
5593 END IF;
5594 END LOOP;
5595 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
5596 RAISE EXCEPTION 'Wrong battle count (should not happen)';
5597 END IF;
5598 -- store direct defeat strengths in "matrix_d" using "defeat_strength"
5599 -- and "secondary_link_strength" functions:
5600 "matrix_d" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
5601 "i" := 1;
5602 LOOP
5603 "j" := 1;
5604 LOOP
5605 IF "i" != "j" THEN
5606 "matrix_d"["i"]["j"] := (
5607 "defeat_strength"(
5608 "matrix_a"["i"]["j"],
5609 "matrix_a"["j"]["i"],
5610 "policy_row"."defeat_strength"
5611 ),
5612 "secondary_link_strength"(
5613 "i",
5614 "j",
5615 "policy_row"."tie_breaking"
5617 )::"link_strength";
5618 END IF;
5619 EXIT WHEN "j" = "dimension_v";
5620 "j" := "j" + 1;
5621 END LOOP;
5622 EXIT WHEN "i" = "dimension_v";
5623 "i" := "i" + 1;
5624 END LOOP;
5625 -- find best paths:
5626 "matrix_p" := "find_best_paths"("matrix_d");
5627 -- create partial order:
5628 "matrix_b" := array_fill(NULL::BOOLEAN, ARRAY["dimension_v", "dimension_v"]);
5629 "i" := 1;
5630 LOOP
5631 "j" := "i" + 1;
5632 LOOP
5633 IF "i" != "j" THEN
5634 IF "matrix_p"["i"]["j"] > "matrix_p"["j"]["i"] THEN
5635 "matrix_b"["i"]["j"] := TRUE;
5636 "matrix_b"["j"]["i"] := FALSE;
5637 ELSIF "matrix_p"["i"]["j"] < "matrix_p"["j"]["i"] THEN
5638 "matrix_b"["i"]["j"] := FALSE;
5639 "matrix_b"["j"]["i"] := TRUE;
5640 END IF;
5641 END IF;
5642 EXIT WHEN "j" = "dimension_v";
5643 "j" := "j" + 1;
5644 END LOOP;
5645 EXIT WHEN "i" = "dimension_v" - 1;
5646 "i" := "i" + 1;
5647 END LOOP;
5648 -- tie-breaking by forbidding shared weakest links in beat-paths
5649 -- (unless "tie_breaking" is set to 'simple', in which case tie-breaking
5650 -- is performed later by initiative id):
5651 IF "policy_row"."tie_breaking" != 'simple'::"tie_breaking" THEN
5652 "m" := 1;
5653 LOOP
5654 "n" := "m" + 1;
5655 LOOP
5656 -- only process those candidates m and n, which are tied:
5657 IF "matrix_b"["m"]["n"] ISNULL THEN
5658 -- start with beat-paths prior tie-breaking:
5659 "matrix_t" := "matrix_p";
5660 -- start with all links allowed:
5661 "matrix_f" := array_fill(FALSE, ARRAY["dimension_v", "dimension_v"]);
5662 LOOP
5663 -- determine (and forbid) that link that is the weakest link
5664 -- in both the best path from candidate m to candidate n and
5665 -- from candidate n to candidate m:
5666 "i" := 1;
5667 <<forbid_one_link>>
5668 LOOP
5669 "j" := 1;
5670 LOOP
5671 IF "i" != "j" THEN
5672 IF "matrix_d"["i"]["j"] = "matrix_t"["m"]["n"] THEN
5673 "matrix_f"["i"]["j"] := TRUE;
5674 -- exit for performance reasons,
5675 -- as exactly one link will be found:
5676 EXIT forbid_one_link;
5677 END IF;
5678 END IF;
5679 EXIT WHEN "j" = "dimension_v";
5680 "j" := "j" + 1;
5681 END LOOP;
5682 IF "i" = "dimension_v" THEN
5683 RAISE EXCEPTION 'Did not find shared weakest link for tie-breaking (should not happen)';
5684 END IF;
5685 "i" := "i" + 1;
5686 END LOOP;
5687 -- calculate best beat-paths while ignoring forbidden links:
5688 "i" := 1;
5689 LOOP
5690 "j" := 1;
5691 LOOP
5692 IF "i" != "j" THEN
5693 "matrix_t"["i"]["j"] := CASE
5694 WHEN "matrix_f"["i"]["j"]
5695 THEN ((-1::INT8) << 63, 0)::"link_strength" -- worst possible value
5696 ELSE "matrix_d"["i"]["j"] END;
5697 END IF;
5698 EXIT WHEN "j" = "dimension_v";
5699 "j" := "j" + 1;
5700 END LOOP;
5701 EXIT WHEN "i" = "dimension_v";
5702 "i" := "i" + 1;
5703 END LOOP;
5704 "matrix_t" := "find_best_paths"("matrix_t");
5705 -- extend partial order, if tie-breaking was successful:
5706 IF "matrix_t"["m"]["n"] > "matrix_t"["n"]["m"] THEN
5707 "matrix_b"["m"]["n"] := TRUE;
5708 "matrix_b"["n"]["m"] := FALSE;
5709 EXIT;
5710 ELSIF "matrix_t"["m"]["n"] < "matrix_t"["n"]["m"] THEN
5711 "matrix_b"["m"]["n"] := FALSE;
5712 "matrix_b"["n"]["m"] := TRUE;
5713 EXIT;
5714 END IF;
5715 END LOOP;
5716 END IF;
5717 EXIT WHEN "n" = "dimension_v";
5718 "n" := "n" + 1;
5719 END LOOP;
5720 EXIT WHEN "m" = "dimension_v" - 1;
5721 "m" := "m" + 1;
5722 END LOOP;
5723 END IF;
5724 -- store a unique ranking in "rank_ary":
5725 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
5726 "rank_v" := 1;
5727 LOOP
5728 "i" := 1;
5729 <<assign_next_rank>>
5730 LOOP
5731 IF "rank_ary"["i"] ISNULL THEN
5732 "j" := 1;
5733 LOOP
5734 IF
5735 "i" != "j" AND
5736 "rank_ary"["j"] ISNULL AND
5737 ( "matrix_b"["j"]["i"] OR
5738 -- tie-breaking by "id"
5739 ( "matrix_b"["j"]["i"] ISNULL AND
5740 "j" < "i" ) )
5741 THEN
5742 -- someone else is better
5743 EXIT;
5744 END IF;
5745 IF "j" = "dimension_v" THEN
5746 -- noone is better
5747 "rank_ary"["i"] := "rank_v";
5748 EXIT assign_next_rank;
5749 END IF;
5750 "j" := "j" + 1;
5751 END LOOP;
5752 END IF;
5753 "i" := "i" + 1;
5754 IF "i" > "dimension_v" THEN
5755 RAISE EXCEPTION 'Schulze ranking does not compute (should not happen)';
5756 END IF;
5757 END LOOP;
5758 EXIT WHEN "rank_v" = "dimension_v";
5759 "rank_v" := "rank_v" + 1;
5760 END LOOP;
5761 -- write preliminary results:
5762 "i" := 2; -- omit status quo with "i" = 1
5763 FOR "initiative_id_v" IN
5764 SELECT "id" FROM "initiative"
5765 WHERE "issue_id" = "issue_id_p" AND "admitted"
5766 ORDER BY "id"
5767 LOOP
5768 UPDATE "initiative" SET
5769 "direct_majority" =
5770 CASE WHEN "policy_row"."direct_majority_strict" THEN
5771 "positive_votes" * "policy_row"."direct_majority_den" >
5772 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
5773 ELSE
5774 "positive_votes" * "policy_row"."direct_majority_den" >=
5775 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
5776 END
5777 AND "positive_votes" >= "policy_row"."direct_majority_positive"
5778 AND "issue_row"."voter_count"-"negative_votes" >=
5779 "policy_row"."direct_majority_non_negative",
5780 "indirect_majority" =
5781 CASE WHEN "policy_row"."indirect_majority_strict" THEN
5782 "positive_votes" * "policy_row"."indirect_majority_den" >
5783 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
5784 ELSE
5785 "positive_votes" * "policy_row"."indirect_majority_den" >=
5786 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
5787 END
5788 AND "positive_votes" >= "policy_row"."indirect_majority_positive"
5789 AND "issue_row"."voter_count"-"negative_votes" >=
5790 "policy_row"."indirect_majority_non_negative",
5791 "schulze_rank" = "rank_ary"["i"],
5792 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"[1],
5793 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"[1],
5794 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"[1],
5795 "reverse_beat_path" = CASE WHEN "policy_row"."defeat_strength" = 'simple'::"defeat_strength"
5796 THEN NULL
5797 ELSE "matrix_p"[1]["i"]."primary" >= 0 END,
5798 "eligible" = FALSE,
5799 "winner" = FALSE,
5800 "rank" = NULL -- NOTE: in cases of manual reset of issue state
5801 WHERE "id" = "initiative_id_v";
5802 "i" := "i" + 1;
5803 END LOOP;
5804 IF "i" != "dimension_v" + 1 THEN
5805 RAISE EXCEPTION 'Wrong winner count (should not happen)';
5806 END IF;
5807 -- take indirect majorities into account:
5808 LOOP
5809 UPDATE "initiative" SET "indirect_majority" = TRUE
5810 FROM (
5811 SELECT "new_initiative"."id" AS "initiative_id"
5812 FROM "initiative" "old_initiative"
5813 JOIN "initiative" "new_initiative"
5814 ON "new_initiative"."issue_id" = "issue_id_p"
5815 AND "new_initiative"."indirect_majority" = FALSE
5816 JOIN "battle" "battle_win"
5817 ON "battle_win"."issue_id" = "issue_id_p"
5818 AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
5819 AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
5820 JOIN "battle" "battle_lose"
5821 ON "battle_lose"."issue_id" = "issue_id_p"
5822 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
5823 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
5824 WHERE "old_initiative"."issue_id" = "issue_id_p"
5825 AND "old_initiative"."indirect_majority" = TRUE
5826 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
5827 "battle_win"."count" * "policy_row"."indirect_majority_den" >
5828 "policy_row"."indirect_majority_num" *
5829 ("battle_win"."count"+"battle_lose"."count")
5830 ELSE
5831 "battle_win"."count" * "policy_row"."indirect_majority_den" >=
5832 "policy_row"."indirect_majority_num" *
5833 ("battle_win"."count"+"battle_lose"."count")
5834 END
5835 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
5836 AND "issue_row"."voter_count"-"battle_lose"."count" >=
5837 "policy_row"."indirect_majority_non_negative"
5838 ) AS "subquery"
5839 WHERE "id" = "subquery"."initiative_id";
5840 EXIT WHEN NOT FOUND;
5841 END LOOP;
5842 -- set "multistage_majority" for remaining matching initiatives:
5843 UPDATE "initiative" SET "multistage_majority" = TRUE
5844 FROM (
5845 SELECT "losing_initiative"."id" AS "initiative_id"
5846 FROM "initiative" "losing_initiative"
5847 JOIN "initiative" "winning_initiative"
5848 ON "winning_initiative"."issue_id" = "issue_id_p"
5849 AND "winning_initiative"."admitted"
5850 JOIN "battle" "battle_win"
5851 ON "battle_win"."issue_id" = "issue_id_p"
5852 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
5853 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
5854 JOIN "battle" "battle_lose"
5855 ON "battle_lose"."issue_id" = "issue_id_p"
5856 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
5857 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
5858 WHERE "losing_initiative"."issue_id" = "issue_id_p"
5859 AND "losing_initiative"."admitted"
5860 AND "winning_initiative"."schulze_rank" <
5861 "losing_initiative"."schulze_rank"
5862 AND "battle_win"."count" > "battle_lose"."count"
5863 AND (
5864 "battle_win"."count" > "winning_initiative"."positive_votes" OR
5865 "battle_lose"."count" < "losing_initiative"."negative_votes" )
5866 ) AS "subquery"
5867 WHERE "id" = "subquery"."initiative_id";
5868 -- mark eligible initiatives:
5869 UPDATE "initiative" SET "eligible" = TRUE
5870 WHERE "issue_id" = "issue_id_p"
5871 AND "initiative"."direct_majority"
5872 AND "initiative"."indirect_majority"
5873 AND "initiative"."better_than_status_quo"
5874 AND (
5875 "policy_row"."no_multistage_majority" = FALSE OR
5876 "initiative"."multistage_majority" = FALSE )
5877 AND (
5878 "policy_row"."no_reverse_beat_path" = FALSE OR
5879 coalesce("initiative"."reverse_beat_path", FALSE) = FALSE );
5880 -- mark final winner:
5881 UPDATE "initiative" SET "winner" = TRUE
5882 FROM (
5883 SELECT "id" AS "initiative_id"
5884 FROM "initiative"
5885 WHERE "issue_id" = "issue_id_p" AND "eligible"
5886 ORDER BY
5887 "schulze_rank",
5888 "id"
5889 LIMIT 1
5890 ) AS "subquery"
5891 WHERE "id" = "subquery"."initiative_id";
5892 -- write (final) ranks:
5893 "rank_v" := 1;
5894 FOR "initiative_id_v" IN
5895 SELECT "id"
5896 FROM "initiative"
5897 WHERE "issue_id" = "issue_id_p" AND "admitted"
5898 ORDER BY
5899 "winner" DESC,
5900 "eligible" DESC,
5901 "schulze_rank",
5902 "id"
5903 LOOP
5904 UPDATE "initiative" SET "rank" = "rank_v"
5905 WHERE "id" = "initiative_id_v";
5906 "rank_v" := "rank_v" + 1;
5907 END LOOP;
5908 -- set schulze rank of status quo and mark issue as finished:
5909 UPDATE "issue" SET
5910 "status_quo_schulze_rank" = "rank_ary"[1],
5911 "state" =
5912 CASE WHEN EXISTS (
5913 SELECT NULL FROM "initiative"
5914 WHERE "issue_id" = "issue_id_p" AND "winner"
5915 ) THEN
5916 'finished_with_winner'::"issue_state"
5917 ELSE
5918 'finished_without_winner'::"issue_state"
5919 END,
5920 "closed" = "phase_finished",
5921 "phase_finished" = NULL
5922 WHERE "id" = "issue_id_p";
5923 RETURN;
5924 END;
5925 $$;
5927 COMMENT ON FUNCTION "calculate_ranks"
5928 ( "issue"."id"%TYPE )
5929 IS 'Determine ranking (Votes have to be counted first)';
5933 -----------------------------
5934 -- Automatic state changes --
5935 -----------------------------
5938 CREATE FUNCTION "issue_admission"
5939 ( "area_id_p" "area"."id"%TYPE )
5940 RETURNS BOOLEAN
5941 LANGUAGE 'plpgsql' VOLATILE AS $$
5942 DECLARE
5943 "issue_id_v" "issue"."id"%TYPE;
5944 BEGIN
5945 PERFORM "dont_require_transaction_isolation"();
5946 LOCK TABLE "snapshot" IN EXCLUSIVE MODE;
5947 UPDATE "area" SET "issue_quorum" = "view"."issue_quorum"
5948 FROM "area_quorum" AS "view"
5949 WHERE "area"."id" = "view"."area_id"
5950 AND "area"."id" = "area_id_p";
5951 SELECT "id" INTO "issue_id_v" FROM "issue_for_admission"
5952 WHERE "area_id" = "area_id_p";
5953 IF "issue_id_v" ISNULL THEN RETURN FALSE; END IF;
5954 UPDATE "issue" SET
5955 "admission_snapshot_id" = "latest_snapshot_id",
5956 "state" = 'discussion',
5957 "accepted" = now(),
5958 "phase_finished" = NULL
5959 WHERE "id" = "issue_id_v";
5960 RETURN TRUE;
5961 END;
5962 $$;
5964 COMMENT ON FUNCTION "issue_admission"
5965 ( "area"."id"%TYPE )
5966 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';
5969 CREATE TYPE "check_issue_persistence" AS (
5970 "state" "issue_state",
5971 "phase_finished" BOOLEAN,
5972 "issue_revoked" BOOLEAN,
5973 "snapshot_created" BOOLEAN,
5974 "harmonic_weights_set" BOOLEAN,
5975 "closed_voting" BOOLEAN );
5977 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';
5980 CREATE FUNCTION "check_issue"
5981 ( "issue_id_p" "issue"."id"%TYPE,
5982 "persist" "check_issue_persistence" )
5983 RETURNS "check_issue_persistence"
5984 LANGUAGE 'plpgsql' VOLATILE AS $$
5985 DECLARE
5986 "issue_row" "issue"%ROWTYPE;
5987 "last_calculated_v" "snapshot"."calculated"%TYPE;
5988 "policy_row" "policy"%ROWTYPE;
5989 "initiative_row" "initiative"%ROWTYPE;
5990 "state_v" "issue_state";
5991 BEGIN
5992 PERFORM "require_transaction_isolation"();
5993 IF "persist" ISNULL THEN
5994 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
5995 FOR UPDATE;
5996 SELECT "calculated" INTO "last_calculated_v"
5997 FROM "snapshot" JOIN "snapshot_issue"
5998 ON "snapshot"."id" = "snapshot_issue"."snapshot_id"
5999 WHERE "snapshot_issue"."issue_id" = "issue_id_p";
6000 IF "issue_row"."closed" NOTNULL THEN
6001 RETURN NULL;
6002 END IF;
6003 "persist"."state" := "issue_row"."state";
6004 IF
6005 ( "issue_row"."state" = 'admission' AND "last_calculated_v" >=
6006 "issue_row"."created" + "issue_row"."max_admission_time" ) OR
6007 ( "issue_row"."state" = 'discussion' AND now() >=
6008 "issue_row"."accepted" + "issue_row"."discussion_time" ) OR
6009 ( "issue_row"."state" = 'verification' AND now() >=
6010 "issue_row"."half_frozen" + "issue_row"."verification_time" ) OR
6011 ( "issue_row"."state" = 'voting' AND now() >=
6012 "issue_row"."fully_frozen" + "issue_row"."voting_time" )
6013 THEN
6014 "persist"."phase_finished" := TRUE;
6015 ELSE
6016 "persist"."phase_finished" := FALSE;
6017 END IF;
6018 IF
6019 NOT EXISTS (
6020 -- all initiatives are revoked
6021 SELECT NULL FROM "initiative"
6022 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6023 ) AND (
6024 -- and issue has not been accepted yet
6025 "persist"."state" = 'admission' OR
6026 -- or verification time has elapsed
6027 ( "persist"."state" = 'verification' AND
6028 "persist"."phase_finished" ) OR
6029 -- or no initiatives have been revoked lately
6030 NOT EXISTS (
6031 SELECT NULL FROM "initiative"
6032 WHERE "issue_id" = "issue_id_p"
6033 AND now() < "revoked" + "issue_row"."verification_time"
6036 THEN
6037 "persist"."issue_revoked" := TRUE;
6038 ELSE
6039 "persist"."issue_revoked" := FALSE;
6040 END IF;
6041 IF "persist"."phase_finished" OR "persist"."issue_revoked" THEN
6042 UPDATE "issue" SET "phase_finished" = now()
6043 WHERE "id" = "issue_row"."id";
6044 RETURN "persist";
6045 ELSIF
6046 "persist"."state" IN ('admission', 'discussion', 'verification')
6047 THEN
6048 RETURN "persist";
6049 ELSE
6050 RETURN NULL;
6051 END IF;
6052 END IF;
6053 IF
6054 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6055 coalesce("persist"."snapshot_created", FALSE) = FALSE
6056 THEN
6057 IF "persist"."state" != 'admission' THEN
6058 PERFORM "take_snapshot"("issue_id_p");
6059 PERFORM "finish_snapshot"("issue_id_p");
6060 END IF;
6061 "persist"."snapshot_created" = TRUE;
6062 IF "persist"."phase_finished" THEN
6063 IF "persist"."state" = 'admission' THEN
6064 UPDATE "issue" SET "admission_snapshot_id" = "latest_snapshot_id"
6065 WHERE "id" = "issue_id_p";
6066 ELSIF "persist"."state" = 'discussion' THEN
6067 UPDATE "issue" SET "half_freeze_snapshot_id" = "latest_snapshot_id"
6068 WHERE "id" = "issue_id_p";
6069 ELSIF "persist"."state" = 'verification' THEN
6070 UPDATE "issue" SET "full_freeze_snapshot_id" = "latest_snapshot_id"
6071 WHERE "id" = "issue_id_p";
6072 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
6073 SELECT * INTO "policy_row" FROM "policy"
6074 WHERE "id" = "issue_row"."policy_id";
6075 FOR "initiative_row" IN
6076 SELECT * FROM "initiative"
6077 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
6078 FOR UPDATE
6079 LOOP
6080 IF
6081 "initiative_row"."polling" OR (
6082 "initiative_row"."satisfied_supporter_count" >
6083 "policy_row"."initiative_quorum" AND
6084 "initiative_row"."satisfied_supporter_count" *
6085 "policy_row"."initiative_quorum_den" >=
6086 "issue_row"."population" * "policy_row"."initiative_quorum_num"
6088 THEN
6089 UPDATE "initiative" SET "admitted" = TRUE
6090 WHERE "id" = "initiative_row"."id";
6091 ELSE
6092 UPDATE "initiative" SET "admitted" = FALSE
6093 WHERE "id" = "initiative_row"."id";
6094 END IF;
6095 END LOOP;
6096 END IF;
6097 END IF;
6098 RETURN "persist";
6099 END IF;
6100 IF
6101 "persist"."state" IN ('admission', 'discussion', 'verification') AND
6102 coalesce("persist"."harmonic_weights_set", FALSE) = FALSE
6103 THEN
6104 PERFORM "set_harmonic_initiative_weights"("issue_id_p");
6105 "persist"."harmonic_weights_set" = TRUE;
6106 IF
6107 "persist"."phase_finished" OR
6108 "persist"."issue_revoked" OR
6109 "persist"."state" = 'admission'
6110 THEN
6111 RETURN "persist";
6112 ELSE
6113 RETURN NULL;
6114 END IF;
6115 END IF;
6116 IF "persist"."issue_revoked" THEN
6117 IF "persist"."state" = 'admission' THEN
6118 "state_v" := 'canceled_revoked_before_accepted';
6119 ELSIF "persist"."state" = 'discussion' THEN
6120 "state_v" := 'canceled_after_revocation_during_discussion';
6121 ELSIF "persist"."state" = 'verification' THEN
6122 "state_v" := 'canceled_after_revocation_during_verification';
6123 END IF;
6124 UPDATE "issue" SET
6125 "state" = "state_v",
6126 "closed" = "phase_finished",
6127 "phase_finished" = NULL
6128 WHERE "id" = "issue_id_p";
6129 RETURN NULL;
6130 END IF;
6131 IF "persist"."state" = 'admission' THEN
6132 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6133 FOR UPDATE;
6134 IF "issue_row"."phase_finished" NOTNULL THEN
6135 UPDATE "issue" SET
6136 "state" = 'canceled_issue_not_accepted',
6137 "closed" = "phase_finished",
6138 "phase_finished" = NULL
6139 WHERE "id" = "issue_id_p";
6140 END IF;
6141 RETURN NULL;
6142 END IF;
6143 IF "persist"."phase_finished" THEN
6144 IF "persist"."state" = 'discussion' THEN
6145 UPDATE "issue" SET
6146 "state" = 'verification',
6147 "half_frozen" = "phase_finished",
6148 "phase_finished" = NULL
6149 WHERE "id" = "issue_id_p";
6150 RETURN NULL;
6151 END IF;
6152 IF "persist"."state" = 'verification' THEN
6153 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"
6154 FOR UPDATE;
6155 SELECT * INTO "policy_row" FROM "policy"
6156 WHERE "id" = "issue_row"."policy_id";
6157 IF EXISTS (
6158 SELECT NULL FROM "initiative"
6159 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
6160 ) THEN
6161 UPDATE "issue" SET
6162 "state" = 'voting',
6163 "fully_frozen" = "phase_finished",
6164 "phase_finished" = NULL
6165 WHERE "id" = "issue_id_p";
6166 ELSE
6167 UPDATE "issue" SET
6168 "state" = 'canceled_no_initiative_admitted',
6169 "fully_frozen" = "phase_finished",
6170 "closed" = "phase_finished",
6171 "phase_finished" = NULL
6172 WHERE "id" = "issue_id_p";
6173 -- NOTE: The following DELETE statements have effect only when
6174 -- issue state has been manipulated
6175 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p";
6176 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
6177 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
6178 END IF;
6179 RETURN NULL;
6180 END IF;
6181 IF "persist"."state" = 'voting' THEN
6182 IF coalesce("persist"."closed_voting", FALSE) = FALSE THEN
6183 PERFORM "close_voting"("issue_id_p");
6184 "persist"."closed_voting" = TRUE;
6185 RETURN "persist";
6186 END IF;
6187 PERFORM "calculate_ranks"("issue_id_p");
6188 RETURN NULL;
6189 END IF;
6190 END IF;
6191 RAISE WARNING 'should not happen';
6192 RETURN NULL;
6193 END;
6194 $$;
6196 COMMENT ON FUNCTION "check_issue"
6197 ( "issue"."id"%TYPE,
6198 "check_issue_persistence" )
6199 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")';
6202 CREATE FUNCTION "check_everything"()
6203 RETURNS VOID
6204 LANGUAGE 'plpgsql' VOLATILE AS $$
6205 DECLARE
6206 "area_id_v" "area"."id"%TYPE;
6207 "snapshot_id_v" "snapshot"."id"%TYPE;
6208 "issue_id_v" "issue"."id"%TYPE;
6209 "persist_v" "check_issue_persistence";
6210 BEGIN
6211 RAISE WARNING 'Function "check_everything" should only be used for development and debugging purposes';
6212 DELETE FROM "expired_session";
6213 DELETE FROM "expired_token";
6214 DELETE FROM "expired_snapshot";
6215 PERFORM "check_activity"();
6216 PERFORM "calculate_member_counts"();
6217 FOR "area_id_v" IN SELECT "id" FROM "area_with_unaccepted_issues" LOOP
6218 SELECT "take_snapshot"(NULL, "area_id_v") INTO "snapshot_id_v";
6219 PERFORM "finish_snapshot"("issue_id") FROM "snapshot_issue"
6220 WHERE "snapshot_id" = "snapshot_id_v";
6221 LOOP
6222 EXIT WHEN "issue_admission"("area_id_v") = FALSE;
6223 END LOOP;
6224 END LOOP;
6225 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
6226 "persist_v" := NULL;
6227 LOOP
6228 "persist_v" := "check_issue"("issue_id_v", "persist_v");
6229 EXIT WHEN "persist_v" ISNULL;
6230 END LOOP;
6231 END LOOP;
6232 RETURN;
6233 END;
6234 $$;
6236 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';
6240 ----------------------
6241 -- Deletion of data --
6242 ----------------------
6245 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
6246 RETURNS VOID
6247 LANGUAGE 'plpgsql' VOLATILE AS $$
6248 BEGIN
6249 IF EXISTS (
6250 SELECT NULL FROM "issue" WHERE "id" = "issue_id_p" AND "cleaned" ISNULL
6251 ) THEN
6252 -- override protection triggers:
6253 INSERT INTO "temporary_transaction_data" ("key", "value")
6254 VALUES ('override_protection_triggers', TRUE::TEXT);
6255 -- clean data:
6256 DELETE FROM "delegating_voter"
6257 WHERE "issue_id" = "issue_id_p";
6258 DELETE FROM "direct_voter"
6259 WHERE "issue_id" = "issue_id_p";
6260 DELETE FROM "delegating_interest_snapshot"
6261 WHERE "issue_id" = "issue_id_p";
6262 DELETE FROM "direct_interest_snapshot"
6263 WHERE "issue_id" = "issue_id_p";
6264 DELETE FROM "non_voter"
6265 WHERE "issue_id" = "issue_id_p";
6266 DELETE FROM "delegation"
6267 WHERE "issue_id" = "issue_id_p";
6268 DELETE FROM "supporter"
6269 USING "initiative" -- NOTE: due to missing index on issue_id
6270 WHERE "initiative"."issue_id" = "issue_id_p"
6271 AND "supporter"."initiative_id" = "initiative_id";
6272 -- mark issue as cleaned:
6273 UPDATE "issue" SET "cleaned" = now() WHERE "id" = "issue_id_p";
6274 -- finish overriding protection triggers (avoids garbage):
6275 DELETE FROM "temporary_transaction_data"
6276 WHERE "key" = 'override_protection_triggers';
6277 END IF;
6278 RETURN;
6279 END;
6280 $$;
6282 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue';
6285 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
6286 RETURNS VOID
6287 LANGUAGE 'plpgsql' VOLATILE AS $$
6288 BEGIN
6289 UPDATE "member" SET
6290 "last_login" = NULL,
6291 "last_delegation_check" = NULL,
6292 "login" = NULL,
6293 "password" = NULL,
6294 "authority" = NULL,
6295 "authority_uid" = NULL,
6296 "authority_login" = NULL,
6297 "deleted" = coalesce("deleted", now()),
6298 "locked" = TRUE,
6299 "active" = FALSE,
6300 "notify_email" = NULL,
6301 "notify_email_unconfirmed" = NULL,
6302 "notify_email_secret" = NULL,
6303 "notify_email_secret_expiry" = NULL,
6304 "notify_email_lock_expiry" = NULL,
6305 "disable_notifications" = TRUE,
6306 "notification_counter" = DEFAULT,
6307 "notification_sample_size" = 0,
6308 "notification_dow" = NULL,
6309 "notification_hour" = NULL,
6310 "notification_sent" = NULL,
6311 "login_recovery_expiry" = NULL,
6312 "password_reset_secret" = NULL,
6313 "password_reset_secret_expiry" = NULL,
6314 "location" = NULL
6315 WHERE "id" = "member_id_p";
6316 -- "text_search_data" is updated by triggers
6317 DELETE FROM "member_settings" WHERE "member_id" = "member_id_p";
6318 DELETE FROM "member_profile" WHERE "member_id" = "member_id_p";
6319 DELETE FROM "rendered_member_statement" WHERE "member_id" = "member_id_p";
6320 DELETE FROM "member_image" WHERE "member_id" = "member_id_p";
6321 DELETE FROM "contact" WHERE "member_id" = "member_id_p";
6322 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p";
6323 DELETE FROM "session" WHERE "member_id" = "member_id_p";
6324 DELETE FROM "member_application" WHERE "member_id" = "member_id_p";
6325 DELETE FROM "token" WHERE "member_id" = "member_id_p";
6326 DELETE FROM "subscription" WHERE "member_id" = "member_id_p";
6327 DELETE FROM "ignored_area" WHERE "member_id" = "member_id_p";
6328 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
6329 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p";
6330 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p";
6331 DELETE FROM "direct_voter" USING "issue"
6332 WHERE "direct_voter"."issue_id" = "issue"."id"
6333 AND "issue"."closed" ISNULL
6334 AND "member_id" = "member_id_p";
6335 DELETE FROM "notification_initiative_sent" WHERE "member_id" = "member_id_p";
6336 RETURN;
6337 END;
6338 $$;
6340 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)';
6343 CREATE FUNCTION "delete_private_data"()
6344 RETURNS VOID
6345 LANGUAGE 'plpgsql' VOLATILE AS $$
6346 BEGIN
6347 DELETE FROM "temporary_transaction_data";
6348 DELETE FROM "temporary_suggestion_counts";
6349 DELETE FROM "member" WHERE "activated" ISNULL;
6350 UPDATE "member" SET
6351 "invite_code" = NULL,
6352 "invite_code_expiry" = NULL,
6353 "admin_comment" = NULL,
6354 "last_login" = NULL,
6355 "last_delegation_check" = NULL,
6356 "login" = NULL,
6357 "password" = NULL,
6358 "authority" = NULL,
6359 "authority_uid" = NULL,
6360 "authority_login" = NULL,
6361 "lang" = NULL,
6362 "notify_email" = NULL,
6363 "notify_email_unconfirmed" = NULL,
6364 "notify_email_secret" = NULL,
6365 "notify_email_secret_expiry" = NULL,
6366 "notify_email_lock_expiry" = NULL,
6367 "disable_notifications" = TRUE,
6368 "notification_counter" = DEFAULT,
6369 "notification_sample_size" = 0,
6370 "notification_dow" = NULL,
6371 "notification_hour" = NULL,
6372 "notification_sent" = NULL,
6373 "login_recovery_expiry" = NULL,
6374 "password_reset_secret" = NULL,
6375 "password_reset_secret_expiry" = NULL,
6376 "location" = NULL;
6377 -- "text_search_data" is updated by triggers
6378 DELETE FROM "verification";
6379 DELETE FROM "member_settings";
6380 DELETE FROM "member_useterms";
6381 DELETE FROM "member_profile";
6382 DELETE FROM "rendered_member_statement";
6383 DELETE FROM "member_image";
6384 DELETE FROM "contact";
6385 DELETE FROM "ignored_member";
6386 DELETE FROM "session";
6387 DELETE FROM "system_application";
6388 DELETE FROM "system_application_redirect_uri";
6389 DELETE FROM "dynamic_application_scope";
6390 DELETE FROM "member_application";
6391 DELETE FROM "token";
6392 DELETE FROM "subscription";
6393 DELETE FROM "ignored_area";
6394 DELETE FROM "ignored_initiative";
6395 DELETE FROM "non_voter";
6396 DELETE FROM "direct_voter" USING "issue"
6397 WHERE "direct_voter"."issue_id" = "issue"."id"
6398 AND "issue"."closed" ISNULL;
6399 DELETE FROM "event_processed";
6400 DELETE FROM "notification_initiative_sent";
6401 DELETE FROM "newsletter";
6402 RETURN;
6403 END;
6404 $$;
6406 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.';
6410 COMMIT;

Impressum / About Us