liquid_feedback_core
annotate core.sql @ 235:2a6984869ba3
Delete sessions:
- when they expire
- in function "delete_private_data" (security relevant in certain setups)
- in function "delete_member"
(Sessions had been removed in changeset ed2f94a397cd and re-added in changeset 4e3d8f1ca3a9 without mechanisms for deletion of sessions)
- when they expire
- in function "delete_private_data" (security relevant in certain setups)
- in function "delete_member"
(Sessions had been removed in changeset ed2f94a397cd and re-added in changeset 4e3d8f1ca3a9 without mechanisms for deletion of sessions)
author | jbe |
---|---|
date | Tue Mar 13 18:04:53 2012 +0100 (2012-03-13) |
parents | cf8a090503c0 |
children | fefc15eb747b |
rev | line source |
---|---|
jbe@0 | 1 |
jbe@92 | 2 -- Execute the following command manually for PostgreSQL prior version 9.0: |
jbe@92 | 3 -- CREATE LANGUAGE plpgsql; |
jbe@0 | 4 |
jbe@0 | 5 -- NOTE: In PostgreSQL every UNIQUE constraint implies creation of an index |
jbe@0 | 6 |
jbe@0 | 7 BEGIN; |
jbe@0 | 8 |
jbe@5 | 9 CREATE VIEW "liquid_feedback_version" AS |
jbe@228 | 10 SELECT * FROM (VALUES ('2.0.5', 2, 0, 5)) |
jbe@5 | 11 AS "subquery"("string", "major", "minor", "revision"); |
jbe@5 | 12 |
jbe@0 | 13 |
jbe@0 | 14 |
jbe@7 | 15 ---------------------- |
jbe@7 | 16 -- Full text search -- |
jbe@7 | 17 ---------------------- |
jbe@7 | 18 |
jbe@7 | 19 |
jbe@7 | 20 CREATE FUNCTION "text_search_query"("query_text_p" TEXT) |
jbe@7 | 21 RETURNS TSQUERY |
jbe@7 | 22 LANGUAGE 'plpgsql' IMMUTABLE AS $$ |
jbe@7 | 23 BEGIN |
jbe@7 | 24 RETURN plainto_tsquery('pg_catalog.simple', "query_text_p"); |
jbe@7 | 25 END; |
jbe@7 | 26 $$; |
jbe@7 | 27 |
jbe@7 | 28 COMMENT ON FUNCTION "text_search_query"(TEXT) IS 'Usage: WHERE "text_search_data" @@ "text_search_query"(''<user query>'')'; |
jbe@7 | 29 |
jbe@7 | 30 |
jbe@7 | 31 CREATE FUNCTION "highlight" |
jbe@7 | 32 ( "body_p" TEXT, |
jbe@7 | 33 "query_text_p" TEXT ) |
jbe@7 | 34 RETURNS TEXT |
jbe@7 | 35 LANGUAGE 'plpgsql' IMMUTABLE AS $$ |
jbe@7 | 36 BEGIN |
jbe@7 | 37 RETURN ts_headline( |
jbe@7 | 38 'pg_catalog.simple', |
jbe@8 | 39 replace(replace("body_p", e'\\', e'\\\\'), '*', e'\\*'), |
jbe@7 | 40 "text_search_query"("query_text_p"), |
jbe@7 | 41 'StartSel=* StopSel=* HighlightAll=TRUE' ); |
jbe@7 | 42 END; |
jbe@7 | 43 $$; |
jbe@7 | 44 |
jbe@7 | 45 COMMENT ON FUNCTION "highlight" |
jbe@7 | 46 ( "body_p" TEXT, |
jbe@7 | 47 "query_text_p" TEXT ) |
jbe@7 | 48 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.'; |
jbe@7 | 49 |
jbe@7 | 50 |
jbe@7 | 51 |
jbe@0 | 52 ------------------------- |
jbe@0 | 53 -- Tables and indicies -- |
jbe@0 | 54 ------------------------- |
jbe@0 | 55 |
jbe@8 | 56 |
jbe@104 | 57 CREATE TABLE "system_setting" ( |
jbe@104 | 58 "member_ttl" INTERVAL ); |
jbe@104 | 59 CREATE UNIQUE INDEX "system_setting_singleton_idx" ON "system_setting" ((1)); |
jbe@104 | 60 |
jbe@104 | 61 COMMENT ON TABLE "system_setting" IS 'This table contains only one row with different settings in each column.'; |
jbe@104 | 62 COMMENT ON INDEX "system_setting_singleton_idx" IS 'This index ensures that "system_setting" only contains one row maximum.'; |
jbe@104 | 63 |
jbe@184 | 64 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.'; |
jbe@104 | 65 |
jbe@104 | 66 |
jbe@111 | 67 CREATE TABLE "contingent" ( |
jbe@111 | 68 "time_frame" INTERVAL PRIMARY KEY, |
jbe@111 | 69 "text_entry_limit" INT4, |
jbe@111 | 70 "initiative_limit" INT4 ); |
jbe@111 | 71 |
jbe@111 | 72 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.'; |
jbe@111 | 73 |
jbe@111 | 74 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'; |
jbe@111 | 75 COMMENT ON COLUMN "contingent"."initiative_limit" IS 'Number of new initiatives to be opened by each member within a given time frame'; |
jbe@111 | 76 |
jbe@111 | 77 |
jbe@113 | 78 CREATE TYPE "notify_level" AS ENUM |
jbe@113 | 79 ('none', 'voting', 'verification', 'discussion', 'all'); |
jbe@113 | 80 |
jbe@113 | 81 COMMENT ON TYPE "notify_level" IS 'Level of notification: ''none'' = no notifications, ''voting'' = notifications about finished issues and issues in voting, ''verification'' = notifications about finished issues, issues in voting and verification phase, ''discussion'' = notifications about everything except issues in admission phase, ''all'' = notifications about everything'; |
jbe@113 | 82 |
jbe@113 | 83 |
jbe@0 | 84 CREATE TABLE "member" ( |
jbe@0 | 85 "id" SERIAL4 PRIMARY KEY, |
jbe@13 | 86 "created" TIMESTAMPTZ NOT NULL DEFAULT now(), |
jbe@181 | 87 "invite_code" TEXT UNIQUE, |
jbe@232 | 88 "invite_code_expiry" TIMESTAMPTZ, |
jbe@182 | 89 "admin_comment" TEXT, |
jbe@181 | 90 "activated" TIMESTAMPTZ, |
jbe@184 | 91 "last_activity" DATE, |
jbe@42 | 92 "last_login" TIMESTAMPTZ, |
jbe@45 | 93 "login" TEXT UNIQUE, |
jbe@0 | 94 "password" TEXT, |
jbe@99 | 95 "locked" BOOLEAN NOT NULL DEFAULT FALSE, |
jbe@181 | 96 "active" BOOLEAN NOT NULL DEFAULT FALSE, |
jbe@0 | 97 "admin" BOOLEAN NOT NULL DEFAULT FALSE, |
jbe@221 | 98 "lang" TEXT, |
jbe@7 | 99 "notify_email" TEXT, |
jbe@11 | 100 "notify_email_unconfirmed" TEXT, |
jbe@11 | 101 "notify_email_secret" TEXT UNIQUE, |
jbe@11 | 102 "notify_email_secret_expiry" TIMESTAMPTZ, |
jbe@55 | 103 "notify_email_lock_expiry" TIMESTAMPTZ, |
jbe@225 | 104 "notify_level" "notify_level", |
jbe@11 | 105 "password_reset_secret" TEXT UNIQUE, |
jbe@11 | 106 "password_reset_secret_expiry" TIMESTAMPTZ, |
jbe@225 | 107 "name" TEXT UNIQUE, |
jbe@7 | 108 "identification" TEXT UNIQUE, |
jbe@214 | 109 "authentication" TEXT, |
jbe@7 | 110 "organizational_unit" TEXT, |
jbe@7 | 111 "internal_posts" TEXT, |
jbe@7 | 112 "realname" TEXT, |
jbe@7 | 113 "birthday" DATE, |
jbe@7 | 114 "address" TEXT, |
jbe@7 | 115 "email" TEXT, |
jbe@7 | 116 "xmpp_address" TEXT, |
jbe@7 | 117 "website" TEXT, |
jbe@7 | 118 "phone" TEXT, |
jbe@7 | 119 "mobile_phone" TEXT, |
jbe@7 | 120 "profession" TEXT, |
jbe@7 | 121 "external_memberships" TEXT, |
jbe@7 | 122 "external_posts" TEXT, |
jbe@159 | 123 "formatting_engine" TEXT, |
jbe@7 | 124 "statement" TEXT, |
jbe@181 | 125 "text_search_data" TSVECTOR, |
jbe@184 | 126 CONSTRAINT "active_requires_activated_and_last_activity" |
jbe@225 | 127 CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL)), |
jbe@225 | 128 CONSTRAINT "name_not_null_if_activated" |
jbe@225 | 129 CHECK ("activated" ISNULL OR "name" NOTNULL) ); |
jbe@0 | 130 CREATE INDEX "member_active_idx" ON "member" ("active"); |
jbe@8 | 131 CREATE INDEX "member_text_search_data_idx" ON "member" USING gin ("text_search_data"); |
jbe@7 | 132 CREATE TRIGGER "update_text_search_data" |
jbe@7 | 133 BEFORE INSERT OR UPDATE ON "member" |
jbe@7 | 134 FOR EACH ROW EXECUTE PROCEDURE |
jbe@7 | 135 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', |
jbe@7 | 136 "name", "identification", "organizational_unit", "internal_posts", |
jbe@7 | 137 "realname", "external_memberships", "external_posts", "statement" ); |
jbe@0 | 138 |
jbe@0 | 139 COMMENT ON TABLE "member" IS 'Users of the system, e.g. members of an organization'; |
jbe@0 | 140 |
jbe@181 | 141 COMMENT ON COLUMN "member"."created" IS 'Creation of member record and/or invite code'; |
jbe@181 | 142 COMMENT ON COLUMN "member"."invite_code" IS 'Optional invite code, to allow a member to initialize his/her account the first time'; |
jbe@232 | 143 COMMENT ON COLUMN "member"."invite_code_expiry" IS 'Expiry data/time for "invite_code"'; |
jbe@182 | 144 COMMENT ON COLUMN "member"."admin_comment" IS 'Hidden comment for administrative purposes'; |
jbe@207 | 145 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'; |
jbe@184 | 146 COMMENT ON COLUMN "member"."last_activity" IS 'Date of last activity of member; required to be set for "active" members'; |
jbe@103 | 147 COMMENT ON COLUMN "member"."last_login" IS 'Timestamp of last login'; |
jbe@10 | 148 COMMENT ON COLUMN "member"."login" IS 'Login name'; |
jbe@10 | 149 COMMENT ON COLUMN "member"."password" IS 'Password (preferably as crypto-hash, depending on the frontend or access layer)'; |
jbe@99 | 150 COMMENT ON COLUMN "member"."locked" IS 'Locked members can not log in.'; |
jbe@184 | 151 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".'; |
jbe@10 | 152 COMMENT ON COLUMN "member"."admin" IS 'TRUE for admins, which can administrate other users and setup policies and areas'; |
jbe@221 | 153 COMMENT ON COLUMN "member"."lang" IS 'Language code of the preferred language of the member'; |
jbe@10 | 154 COMMENT ON COLUMN "member"."notify_email" IS 'Email address where notifications of the system are sent to'; |
jbe@10 | 155 COMMENT ON COLUMN "member"."notify_email_unconfirmed" IS 'Unconfirmed email address provided by the member to be copied into "notify_email" field after verification'; |
jbe@10 | 156 COMMENT ON COLUMN "member"."notify_email_secret" IS 'Secret sent to the address in "notify_email_unconformed"'; |
jbe@10 | 157 COMMENT ON COLUMN "member"."notify_email_secret_expiry" IS 'Expiry date/time for "notify_email_secret"'; |
jbe@55 | 158 COMMENT ON COLUMN "member"."notify_email_lock_expiry" IS 'Date/time until no further email confirmation mails may be sent (abuse protection)'; |
jbe@225 | 159 COMMENT ON COLUMN "member"."notify_level" IS 'Selects which event notifications are to be sent to the "notify_email" mail address, may be NULL if member did not make any selection yet'; |
jbe@225 | 160 COMMENT ON COLUMN "member"."name" IS 'Distinct name of the member, may be NULL if account has not been activated yet'; |
jbe@10 | 161 COMMENT ON COLUMN "member"."identification" IS 'Optional identification number or code of the member'; |
jbe@214 | 162 COMMENT ON COLUMN "member"."authentication" IS 'Information about how this member was authenticated'; |
jbe@10 | 163 COMMENT ON COLUMN "member"."organizational_unit" IS 'Branch or division of the organization the member belongs to'; |
jbe@10 | 164 COMMENT ON COLUMN "member"."internal_posts" IS 'Posts (offices) of the member inside the organization'; |
jbe@10 | 165 COMMENT ON COLUMN "member"."realname" IS 'Real name of the member, may be identical with "name"'; |
jbe@10 | 166 COMMENT ON COLUMN "member"."email" IS 'Published email address of the member; not used for system notifications'; |
jbe@10 | 167 COMMENT ON COLUMN "member"."external_memberships" IS 'Other organizations the member is involved in'; |
jbe@10 | 168 COMMENT ON COLUMN "member"."external_posts" IS 'Posts (offices) outside the organization'; |
jbe@159 | 169 COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"'; |
jbe@207 | 170 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his/her profile'; |
jbe@7 | 171 |
jbe@7 | 172 |
jbe@185 | 173 CREATE TYPE "application_access_level" AS ENUM |
jbe@185 | 174 ('member', 'full', 'pseudonymous', 'anonymous'); |
jbe@185 | 175 |
jbe@185 | 176 COMMENT ON TYPE "application_access_level" IS 'Access privileges for applications using the API'; |
jbe@185 | 177 |
jbe@185 | 178 |
jbe@185 | 179 CREATE TABLE "member_application" ( |
jbe@185 | 180 "id" SERIAL8 PRIMARY KEY, |
jbe@185 | 181 UNIQUE ("member_id", "name"), |
jbe@185 | 182 "member_id" INT4 NOT NULL REFERENCES "member" ("id") |
jbe@185 | 183 ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@185 | 184 "name" TEXT NOT NULL, |
jbe@185 | 185 "comment" TEXT, |
jbe@185 | 186 "access_level" "application_access_level" NOT NULL, |
jbe@190 | 187 "key" TEXT NOT NULL UNIQUE, |
jbe@185 | 188 "last_usage" TIMESTAMPTZ ); |
jbe@185 | 189 |
jbe@185 | 190 COMMENT ON TABLE "member_application" IS 'Registered application being allowed to use the API'; |
jbe@185 | 191 |
jbe@185 | 192 |
jbe@13 | 193 CREATE TABLE "member_history" ( |
jbe@13 | 194 "id" SERIAL8 PRIMARY KEY, |
jbe@13 | 195 "member_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@13 | 196 "until" TIMESTAMPTZ NOT NULL DEFAULT now(), |
jbe@42 | 197 "active" BOOLEAN NOT NULL, |
jbe@13 | 198 "name" TEXT NOT NULL ); |
jbe@45 | 199 CREATE INDEX "member_history_member_id_idx" ON "member_history" ("member_id"); |
jbe@13 | 200 |
jbe@57 | 201 COMMENT ON TABLE "member_history" IS 'Filled by trigger; keeps information about old names and active flag of members'; |
jbe@13 | 202 |
jbe@13 | 203 COMMENT ON COLUMN "member_history"."id" IS 'Primary key, which can be used to sort entries correctly (and time warp resistant)'; |
jbe@57 | 204 COMMENT ON COLUMN "member_history"."until" IS 'Timestamp until the data was valid'; |
jbe@13 | 205 |
jbe@13 | 206 |
jbe@159 | 207 CREATE TABLE "rendered_member_statement" ( |
jbe@159 | 208 PRIMARY KEY ("member_id", "format"), |
jbe@159 | 209 "member_id" INT8 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@159 | 210 "format" TEXT, |
jbe@159 | 211 "content" TEXT NOT NULL ); |
jbe@159 | 212 |
jbe@159 | 213 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)'; |
jbe@9 | 214 |
jbe@9 | 215 |
jbe@9 | 216 CREATE TABLE "setting" ( |
jbe@9 | 217 PRIMARY KEY ("member_id", "key"), |
jbe@9 | 218 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@9 | 219 "key" TEXT NOT NULL, |
jbe@9 | 220 "value" TEXT NOT NULL ); |
jbe@9 | 221 CREATE INDEX "setting_key_idx" ON "setting" ("key"); |
jbe@9 | 222 |
jbe@38 | 223 COMMENT ON TABLE "setting" IS 'Place to store a frontend specific setting for members as a string'; |
jbe@9 | 224 |
jbe@9 | 225 COMMENT ON COLUMN "setting"."key" IS 'Name of the setting, preceded by a frontend specific prefix'; |
jbe@9 | 226 |
jbe@9 | 227 |
jbe@16 | 228 CREATE TABLE "setting_map" ( |
jbe@16 | 229 PRIMARY KEY ("member_id", "key", "subkey"), |
jbe@16 | 230 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@16 | 231 "key" TEXT NOT NULL, |
jbe@16 | 232 "subkey" TEXT NOT NULL, |
jbe@16 | 233 "value" TEXT NOT NULL ); |
jbe@16 | 234 CREATE INDEX "setting_map_key_idx" ON "setting_map" ("key"); |
jbe@16 | 235 |
jbe@23 | 236 COMMENT ON TABLE "setting_map" IS 'Place to store a frontend specific setting for members as a map of key value pairs'; |
jbe@16 | 237 |
jbe@16 | 238 COMMENT ON COLUMN "setting_map"."key" IS 'Name of the setting, preceded by a frontend specific prefix'; |
jbe@16 | 239 COMMENT ON COLUMN "setting_map"."subkey" IS 'Key of a map entry'; |
jbe@16 | 240 COMMENT ON COLUMN "setting_map"."value" IS 'Value of a map entry'; |
jbe@16 | 241 |
jbe@16 | 242 |
jbe@23 | 243 CREATE TABLE "member_relation_setting" ( |
jbe@23 | 244 PRIMARY KEY ("member_id", "key", "other_member_id"), |
jbe@23 | 245 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@23 | 246 "key" TEXT NOT NULL, |
jbe@23 | 247 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@23 | 248 "value" TEXT NOT NULL ); |
jbe@23 | 249 |
jbe@38 | 250 COMMENT ON TABLE "member_relation_setting" IS 'Place to store a frontend specific setting related to relations between members as a string'; |
jbe@23 | 251 |
jbe@23 | 252 |
jbe@7 | 253 CREATE TYPE "member_image_type" AS ENUM ('photo', 'avatar'); |
jbe@7 | 254 |
jbe@7 | 255 COMMENT ON TYPE "member_image_type" IS 'Types of images for a member'; |
jbe@7 | 256 |
jbe@7 | 257 |
jbe@7 | 258 CREATE TABLE "member_image" ( |
jbe@7 | 259 PRIMARY KEY ("member_id", "image_type", "scaled"), |
jbe@7 | 260 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@7 | 261 "image_type" "member_image_type", |
jbe@7 | 262 "scaled" BOOLEAN, |
jbe@7 | 263 "content_type" TEXT, |
jbe@7 | 264 "data" BYTEA NOT NULL ); |
jbe@7 | 265 |
jbe@7 | 266 COMMENT ON TABLE "member_image" IS 'Images of members'; |
jbe@7 | 267 |
jbe@7 | 268 COMMENT ON COLUMN "member_image"."scaled" IS 'FALSE for original image, TRUE for scaled version of the image'; |
jbe@0 | 269 |
jbe@0 | 270 |
jbe@4 | 271 CREATE TABLE "member_count" ( |
jbe@5 | 272 "calculated" TIMESTAMPTZ NOT NULL DEFAULT NOW(), |
jbe@5 | 273 "total_count" INT4 NOT NULL ); |
jbe@4 | 274 |
jbe@5 | 275 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'; |
jbe@4 | 276 |
jbe@5 | 277 COMMENT ON COLUMN "member_count"."calculated" IS 'timestamp indicating when the total member count and area member counts were calculated'; |
jbe@5 | 278 COMMENT ON COLUMN "member_count"."total_count" IS 'Total count of active(!) members'; |
jbe@4 | 279 |
jbe@4 | 280 |
jbe@0 | 281 CREATE TABLE "contact" ( |
jbe@0 | 282 PRIMARY KEY ("member_id", "other_member_id"), |
jbe@0 | 283 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@0 | 284 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@11 | 285 "public" BOOLEAN NOT NULL DEFAULT FALSE, |
jbe@11 | 286 CONSTRAINT "cant_save_yourself_as_contact" |
jbe@11 | 287 CHECK ("member_id" != "other_member_id") ); |
jbe@113 | 288 CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id"); |
jbe@0 | 289 |
jbe@0 | 290 COMMENT ON TABLE "contact" IS 'Contact lists'; |
jbe@0 | 291 |
jbe@0 | 292 COMMENT ON COLUMN "contact"."member_id" IS 'Member having the contact list'; |
jbe@0 | 293 COMMENT ON COLUMN "contact"."other_member_id" IS 'Member referenced in the contact list'; |
jbe@0 | 294 COMMENT ON COLUMN "contact"."public" IS 'TRUE = display contact publically'; |
jbe@0 | 295 |
jbe@0 | 296 |
jbe@113 | 297 CREATE TABLE "ignored_member" ( |
jbe@113 | 298 PRIMARY KEY ("member_id", "other_member_id"), |
jbe@113 | 299 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@113 | 300 "other_member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); |
jbe@113 | 301 CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id"); |
jbe@113 | 302 |
jbe@113 | 303 COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members'; |
jbe@113 | 304 |
jbe@113 | 305 COMMENT ON COLUMN "ignored_member"."member_id" IS 'Member ignoring someone'; |
jbe@113 | 306 COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored'; |
jbe@113 | 307 |
jbe@113 | 308 |
jbe@220 | 309 CREATE TABLE "session" ( |
jbe@220 | 310 "ident" TEXT PRIMARY KEY, |
jbe@220 | 311 "additional_secret" TEXT, |
jbe@220 | 312 "expiry" TIMESTAMPTZ NOT NULL DEFAULT now() + '24 hours', |
jbe@220 | 313 "member_id" INT8 REFERENCES "member" ("id") ON DELETE SET NULL, |
jbe@220 | 314 "lang" TEXT ); |
jbe@220 | 315 CREATE INDEX "session_expiry_idx" ON "session" ("expiry"); |
jbe@220 | 316 |
jbe@220 | 317 COMMENT ON TABLE "session" IS 'Sessions, i.e. for a web-frontend or API layer'; |
jbe@220 | 318 |
jbe@220 | 319 COMMENT ON COLUMN "session"."ident" IS 'Secret session identifier (i.e. random string)'; |
jbe@220 | 320 COMMENT ON COLUMN "session"."additional_secret" IS 'Additional field to store a secret, which can be used against CSRF attacks'; |
jbe@220 | 321 COMMENT ON COLUMN "session"."member_id" IS 'Reference to member, who is logged in'; |
jbe@220 | 322 COMMENT ON COLUMN "session"."lang" IS 'Language code of the selected language'; |
jbe@220 | 323 |
jbe@220 | 324 |
jbe@0 | 325 CREATE TABLE "policy" ( |
jbe@0 | 326 "id" SERIAL4 PRIMARY KEY, |
jbe@9 | 327 "index" INT4 NOT NULL, |
jbe@0 | 328 "active" BOOLEAN NOT NULL DEFAULT TRUE, |
jbe@0 | 329 "name" TEXT NOT NULL UNIQUE, |
jbe@0 | 330 "description" TEXT NOT NULL DEFAULT '', |
jbe@0 | 331 "admission_time" INTERVAL NOT NULL, |
jbe@0 | 332 "discussion_time" INTERVAL NOT NULL, |
jbe@3 | 333 "verification_time" INTERVAL NOT NULL, |
jbe@0 | 334 "voting_time" INTERVAL NOT NULL, |
jbe@0 | 335 "issue_quorum_num" INT4 NOT NULL, |
jbe@0 | 336 "issue_quorum_den" INT4 NOT NULL, |
jbe@0 | 337 "initiative_quorum_num" INT4 NOT NULL, |
jbe@10 | 338 "initiative_quorum_den" INT4 NOT NULL, |
jbe@167 | 339 "direct_majority_num" INT4 NOT NULL DEFAULT 1, |
jbe@167 | 340 "direct_majority_den" INT4 NOT NULL DEFAULT 2, |
jbe@167 | 341 "direct_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE, |
jbe@167 | 342 "direct_majority_positive" INT4 NOT NULL DEFAULT 0, |
jbe@167 | 343 "direct_majority_non_negative" INT4 NOT NULL DEFAULT 0, |
jbe@167 | 344 "indirect_majority_num" INT4 NOT NULL DEFAULT 1, |
jbe@167 | 345 "indirect_majority_den" INT4 NOT NULL DEFAULT 2, |
jbe@167 | 346 "indirect_majority_strict" BOOLEAN NOT NULL DEFAULT TRUE, |
jbe@167 | 347 "indirect_majority_positive" INT4 NOT NULL DEFAULT 0, |
jbe@167 | 348 "indirect_majority_non_negative" INT4 NOT NULL DEFAULT 0, |
jbe@167 | 349 "no_reverse_beat_path" BOOLEAN NOT NULL DEFAULT TRUE, |
jbe@167 | 350 "no_multistage_majority" BOOLEAN NOT NULL DEFAULT FALSE ); |
jbe@0 | 351 CREATE INDEX "policy_active_idx" ON "policy" ("active"); |
jbe@0 | 352 |
jbe@0 | 353 COMMENT ON TABLE "policy" IS 'Policies for a particular proceeding type (timelimits, quorum)'; |
jbe@0 | 354 |
jbe@9 | 355 COMMENT ON COLUMN "policy"."index" IS 'Determines the order in listings'; |
jbe@0 | 356 COMMENT ON COLUMN "policy"."active" IS 'TRUE = policy can be used for new issues'; |
jbe@207 | 357 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"'; |
jbe@207 | 358 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"'; |
jbe@207 | 359 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"'; |
jbe@207 | 360 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'')'; |
jbe@207 | 361 COMMENT ON COLUMN "policy"."issue_quorum_num" IS 'Numerator of potential supporter quorum to be reached by one initiative of an issue to be "accepted" and enter issue state ''discussion'''; |
jbe@207 | 362 COMMENT ON COLUMN "policy"."issue_quorum_den" IS 'Denominator of potential supporter quorum to be reached by one initiative of an issue to be "accepted" and enter issue state ''discussion'''; |
jbe@10 | 363 COMMENT ON COLUMN "policy"."initiative_quorum_num" IS 'Numerator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting'; |
jbe@10 | 364 COMMENT ON COLUMN "policy"."initiative_quorum_den" IS 'Denominator of satisfied supporter quorum to be reached by an initiative to be "admitted" for voting'; |
jbe@167 | 365 COMMENT ON COLUMN "policy"."direct_majority_num" IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner'; |
jbe@167 | 366 COMMENT ON COLUMN "policy"."direct_majority_den" IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner'; |
jbe@167 | 367 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.'; |
jbe@167 | 368 COMMENT ON COLUMN "policy"."direct_majority_positive" IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner'; |
jbe@167 | 369 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'; |
jbe@167 | 370 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'; |
jbe@167 | 371 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'; |
jbe@167 | 372 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.'; |
jbe@167 | 373 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'; |
jbe@167 | 374 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'; |
jbe@158 | 375 COMMENT ON COLUMN "policy"."no_reverse_beat_path" IS '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.'; |
jbe@167 | 376 COMMENT ON COLUMN "policy"."no_multistage_majority" IS '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").'; |
jbe@0 | 377 |
jbe@0 | 378 |
jbe@97 | 379 CREATE TABLE "unit" ( |
jbe@97 | 380 "id" SERIAL4 PRIMARY KEY, |
jbe@97 | 381 "parent_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@97 | 382 "active" BOOLEAN NOT NULL DEFAULT TRUE, |
jbe@97 | 383 "name" TEXT NOT NULL, |
jbe@97 | 384 "description" TEXT NOT NULL DEFAULT '', |
jbe@97 | 385 "member_count" INT4, |
jbe@97 | 386 "text_search_data" TSVECTOR ); |
jbe@97 | 387 CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL; |
jbe@97 | 388 CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id"); |
jbe@97 | 389 CREATE INDEX "unit_active_idx" ON "unit" ("active"); |
jbe@97 | 390 CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data"); |
jbe@97 | 391 CREATE TRIGGER "update_text_search_data" |
jbe@97 | 392 BEFORE INSERT OR UPDATE ON "unit" |
jbe@97 | 393 FOR EACH ROW EXECUTE PROCEDURE |
jbe@97 | 394 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', |
jbe@97 | 395 "name", "description" ); |
jbe@97 | 396 |
jbe@97 | 397 COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.'; |
jbe@97 | 398 |
jbe@97 | 399 COMMENT ON COLUMN "unit"."parent_id" IS 'Parent id of tree node; Multiple roots allowed'; |
jbe@212 | 400 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this unit'; |
jbe@97 | 401 COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"'; |
jbe@97 | 402 |
jbe@97 | 403 |
jbe@203 | 404 CREATE TABLE "unit_setting" ( |
jbe@203 | 405 PRIMARY KEY ("member_id", "key", "unit_id"), |
jbe@203 | 406 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@203 | 407 "key" TEXT NOT NULL, |
jbe@203 | 408 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@203 | 409 "value" TEXT NOT NULL ); |
jbe@203 | 410 |
jbe@203 | 411 COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings'; |
jbe@203 | 412 |
jbe@203 | 413 |
jbe@0 | 414 CREATE TABLE "area" ( |
jbe@0 | 415 "id" SERIAL4 PRIMARY KEY, |
jbe@97 | 416 "unit_id" INT4 NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@0 | 417 "active" BOOLEAN NOT NULL DEFAULT TRUE, |
jbe@0 | 418 "name" TEXT NOT NULL, |
jbe@4 | 419 "description" TEXT NOT NULL DEFAULT '', |
jbe@5 | 420 "direct_member_count" INT4, |
jbe@5 | 421 "member_weight" INT4, |
jbe@7 | 422 "text_search_data" TSVECTOR ); |
jbe@97 | 423 CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id"); |
jbe@0 | 424 CREATE INDEX "area_active_idx" ON "area" ("active"); |
jbe@8 | 425 CREATE INDEX "area_text_search_data_idx" ON "area" USING gin ("text_search_data"); |
jbe@7 | 426 CREATE TRIGGER "update_text_search_data" |
jbe@7 | 427 BEFORE INSERT OR UPDATE ON "area" |
jbe@7 | 428 FOR EACH ROW EXECUTE PROCEDURE |
jbe@7 | 429 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', |
jbe@7 | 430 "name", "description" ); |
jbe@0 | 431 |
jbe@0 | 432 COMMENT ON TABLE "area" IS 'Subject areas'; |
jbe@0 | 433 |
jbe@5 | 434 COMMENT ON COLUMN "area"."active" IS 'TRUE means new issues can be created in this area'; |
jbe@5 | 435 COMMENT ON COLUMN "area"."direct_member_count" IS 'Number of active members of that area (ignoring their weight), as calculated from view "area_member_count"'; |
jbe@5 | 436 COMMENT ON COLUMN "area"."member_weight" IS 'Same as "direct_member_count" but respecting delegations'; |
jbe@0 | 437 |
jbe@0 | 438 |
jbe@23 | 439 CREATE TABLE "area_setting" ( |
jbe@23 | 440 PRIMARY KEY ("member_id", "key", "area_id"), |
jbe@23 | 441 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@23 | 442 "key" TEXT NOT NULL, |
jbe@23 | 443 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@23 | 444 "value" TEXT NOT NULL ); |
jbe@23 | 445 |
jbe@23 | 446 COMMENT ON TABLE "area_setting" IS 'Place for frontend to store area specific settings of members as strings'; |
jbe@23 | 447 |
jbe@23 | 448 |
jbe@9 | 449 CREATE TABLE "allowed_policy" ( |
jbe@9 | 450 PRIMARY KEY ("area_id", "policy_id"), |
jbe@9 | 451 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@9 | 452 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@9 | 453 "default_policy" BOOLEAN NOT NULL DEFAULT FALSE ); |
jbe@9 | 454 CREATE UNIQUE INDEX "allowed_policy_one_default_per_area_idx" ON "allowed_policy" ("area_id") WHERE "default_policy"; |
jbe@9 | 455 |
jbe@9 | 456 COMMENT ON TABLE "allowed_policy" IS 'Selects which policies can be used in each area'; |
jbe@9 | 457 |
jbe@9 | 458 COMMENT ON COLUMN "allowed_policy"."default_policy" IS 'One policy per area can be set as default.'; |
jbe@9 | 459 |
jbe@9 | 460 |
jbe@21 | 461 CREATE TYPE "snapshot_event" AS ENUM ('periodic', 'end_of_admission', 'half_freeze', 'full_freeze'); |
jbe@21 | 462 |
jbe@21 | 463 COMMENT ON TYPE "snapshot_event" IS 'Reason for snapshots: ''periodic'' = due to periodic recalculation, ''end_of_admission'' = saved state at end of admission period, ''half_freeze'' = saved state at end of discussion period, ''full_freeze'' = saved state at end of verification period'; |
jbe@8 | 464 |
jbe@8 | 465 |
jbe@112 | 466 CREATE TYPE "issue_state" AS ENUM ( |
jbe@112 | 467 'admission', 'discussion', 'verification', 'voting', |
jbe@113 | 468 'canceled_revoked_before_accepted', |
jbe@113 | 469 'canceled_issue_not_accepted', |
jbe@113 | 470 'canceled_after_revocation_during_discussion', |
jbe@113 | 471 'canceled_after_revocation_during_verification', |
jbe@113 | 472 'calculation', |
jbe@113 | 473 'canceled_no_initiative_admitted', |
jbe@112 | 474 'finished_without_winner', 'finished_with_winner'); |
jbe@111 | 475 |
jbe@111 | 476 COMMENT ON TYPE "issue_state" IS 'State of issues'; |
jbe@111 | 477 |
jbe@111 | 478 |
jbe@0 | 479 CREATE TABLE "issue" ( |
jbe@0 | 480 "id" SERIAL4 PRIMARY KEY, |
jbe@0 | 481 "area_id" INT4 NOT NULL REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@0 | 482 "policy_id" INT4 NOT NULL REFERENCES "policy" ("id") ON DELETE RESTRICT ON UPDATE CASCADE, |
jbe@111 | 483 "state" "issue_state" NOT NULL DEFAULT 'admission', |
jbe@0 | 484 "created" TIMESTAMPTZ NOT NULL DEFAULT now(), |
jbe@0 | 485 "accepted" TIMESTAMPTZ, |
jbe@3 | 486 "half_frozen" TIMESTAMPTZ, |
jbe@3 | 487 "fully_frozen" TIMESTAMPTZ, |
jbe@0 | 488 "closed" TIMESTAMPTZ, |
jbe@0 | 489 "ranks_available" BOOLEAN NOT NULL DEFAULT FALSE, |
jbe@59 | 490 "cleaned" TIMESTAMPTZ, |
jbe@22 | 491 "admission_time" INTERVAL NOT NULL, |
jbe@22 | 492 "discussion_time" INTERVAL NOT NULL, |
jbe@22 | 493 "verification_time" INTERVAL NOT NULL, |
jbe@22 | 494 "voting_time" INTERVAL NOT NULL, |
jbe@0 | 495 "snapshot" TIMESTAMPTZ, |
jbe@8 | 496 "latest_snapshot_event" "snapshot_event", |
jbe@0 | 497 "population" INT4, |
jbe@4 | 498 "voter_count" INT4, |
jbe@170 | 499 "status_quo_schulze_rank" INT4, |
jbe@111 | 500 CONSTRAINT "valid_state" CHECK (( |
jbe@3 | 501 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR |
jbe@3 | 502 ("accepted" ISNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR |
jbe@3 | 503 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR |
jbe@34 | 504 ("accepted" NOTNULL AND "half_frozen" ISNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR |
jbe@3 | 505 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR |
jbe@34 | 506 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR |
jbe@3 | 507 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL AND "ranks_available" = FALSE) OR |
jbe@3 | 508 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR |
jbe@111 | 509 ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE)) AND ( |
jbe@111 | 510 ("state" = 'admission' AND "closed" ISNULL AND "accepted" ISNULL) OR |
jbe@111 | 511 ("state" = 'discussion' AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR |
jbe@111 | 512 ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR |
jbe@111 | 513 ("state" = 'voting' AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR |
jbe@113 | 514 ("state" = 'canceled_revoked_before_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR |
jbe@113 | 515 ("state" = 'canceled_issue_not_accepted' AND "closed" NOTNULL AND "accepted" ISNULL) OR |
jbe@113 | 516 ("state" = 'canceled_after_revocation_during_discussion' AND "closed" NOTNULL AND "half_frozen" ISNULL) OR |
jbe@113 | 517 ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR |
jbe@113 | 518 ("state" = 'calculation' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = FALSE) OR |
jbe@113 | 519 ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR |
jbe@113 | 520 ("state" = 'finished_without_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR |
jbe@113 | 521 ("state" = 'finished_with_winner' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) |
jbe@111 | 522 )), |
jbe@3 | 523 CONSTRAINT "state_change_order" CHECK ( |
jbe@10 | 524 "created" <= "accepted" AND |
jbe@10 | 525 "accepted" <= "half_frozen" AND |
jbe@10 | 526 "half_frozen" <= "fully_frozen" AND |
jbe@3 | 527 "fully_frozen" <= "closed" ), |
jbe@61 | 528 CONSTRAINT "only_closed_issues_may_be_cleaned" CHECK ( |
jbe@61 | 529 "cleaned" ISNULL OR "closed" NOTNULL ), |
jbe@10 | 530 CONSTRAINT "last_snapshot_on_full_freeze" |
jbe@10 | 531 CHECK ("snapshot" = "fully_frozen"), -- NOTE: snapshot can be set, while frozen is NULL yet |
jbe@10 | 532 CONSTRAINT "freeze_requires_snapshot" |
jbe@10 | 533 CHECK ("fully_frozen" ISNULL OR "snapshot" NOTNULL), |
jbe@10 | 534 CONSTRAINT "set_both_or_none_of_snapshot_and_latest_snapshot_event" |
jbe@10 | 535 CHECK ("snapshot" NOTNULL = "latest_snapshot_event" NOTNULL) ); |
jbe@0 | 536 CREATE INDEX "issue_area_id_idx" ON "issue" ("area_id"); |
jbe@0 | 537 CREATE INDEX "issue_policy_id_idx" ON "issue" ("policy_id"); |
jbe@16 | 538 CREATE INDEX "issue_created_idx" ON "issue" ("created"); |
jbe@16 | 539 CREATE INDEX "issue_accepted_idx" ON "issue" ("accepted"); |
jbe@16 | 540 CREATE INDEX "issue_half_frozen_idx" ON "issue" ("half_frozen"); |
jbe@16 | 541 CREATE INDEX "issue_fully_frozen_idx" ON "issue" ("fully_frozen"); |
jbe@16 | 542 CREATE INDEX "issue_closed_idx" ON "issue" ("closed"); |
jbe@0 | 543 CREATE INDEX "issue_created_idx_open" ON "issue" ("created") WHERE "closed" ISNULL; |
jbe@16 | 544 CREATE INDEX "issue_closed_idx_canceled" ON "issue" ("closed") WHERE "fully_frozen" ISNULL; |
jbe@0 | 545 |
jbe@0 | 546 COMMENT ON TABLE "issue" IS 'Groups of initiatives'; |
jbe@0 | 547 |
jbe@170 | 548 COMMENT ON COLUMN "issue"."accepted" IS 'Point in time, when one initiative of issue reached the "issue_quorum"'; |
jbe@170 | 549 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.'; |
jbe@170 | 550 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.'; |
jbe@170 | 551 COMMENT ON COLUMN "issue"."closed" IS 'Point in time, when "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.'; |
jbe@170 | 552 COMMENT ON COLUMN "issue"."ranks_available" IS 'TRUE = ranks have been calculated'; |
jbe@170 | 553 COMMENT ON COLUMN "issue"."cleaned" IS 'Point in time, when discussion data and votes had been deleted'; |
jbe@170 | 554 COMMENT ON COLUMN "issue"."admission_time" IS 'Copied from "policy" table at creation of issue'; |
jbe@170 | 555 COMMENT ON COLUMN "issue"."discussion_time" IS 'Copied from "policy" table at creation of issue'; |
jbe@170 | 556 COMMENT ON COLUMN "issue"."verification_time" IS 'Copied from "policy" table at creation of issue'; |
jbe@170 | 557 COMMENT ON COLUMN "issue"."voting_time" IS 'Copied from "policy" table at creation of issue'; |
jbe@170 | 558 COMMENT ON COLUMN "issue"."snapshot" IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated'; |
jbe@170 | 559 COMMENT ON COLUMN "issue"."latest_snapshot_event" IS 'Event type of latest snapshot for issue; Can be used to select the latest snapshot data in the snapshot tables'; |
jbe@170 | 560 COMMENT ON COLUMN "issue"."population" IS 'Sum of "weight" column in table "direct_population_snapshot"'; |
jbe@170 | 561 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'; |
jbe@170 | 562 COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function'; |
jbe@0 | 563 |
jbe@0 | 564 |
jbe@23 | 565 CREATE TABLE "issue_setting" ( |
jbe@23 | 566 PRIMARY KEY ("member_id", "key", "issue_id"), |
jbe@23 | 567 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@23 | 568 "key" TEXT NOT NULL, |
jbe@23 | 569 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@23 | 570 "value" TEXT NOT NULL ); |
jbe@23 | 571 |
jbe@23 | 572 COMMENT ON TABLE "issue_setting" IS 'Place for frontend to store issue specific settings of members as strings'; |
jbe@23 | 573 |
jbe@23 | 574 |
jbe@0 | 575 CREATE TABLE "initiative" ( |
jbe@0 | 576 UNIQUE ("issue_id", "id"), -- index needed for foreign-key on table "vote" |
jbe@0 | 577 "issue_id" INT4 NOT NULL REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@0 | 578 "id" SERIAL4 PRIMARY KEY, |
jbe@0 | 579 "name" TEXT NOT NULL, |
jbe@8 | 580 "discussion_url" TEXT, |
jbe@0 | 581 "created" TIMESTAMPTZ NOT NULL DEFAULT now(), |
jbe@0 | 582 "revoked" TIMESTAMPTZ, |
jbe@112 | 583 "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE, |
jbe@14 | 584 "suggested_initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@0 | 585 "admitted" BOOLEAN, |
jbe@0 | 586 "supporter_count" INT4, |
jbe@0 | 587 "informed_supporter_count" INT4, |
jbe@0 | 588 "satisfied_supporter_count" INT4, |
jbe@0 | 589 "satisfied_informed_supporter_count" INT4, |
jbe@0 | 590 "positive_votes" INT4, |
jbe@0 | 591 "negative_votes" INT4, |
jbe@167 | 592 "direct_majority" BOOLEAN, |
jbe@167 | 593 "indirect_majority" BOOLEAN, |
jbe@170 | 594 "schulze_rank" INT4, |
jbe@167 | 595 "better_than_status_quo" BOOLEAN, |
jbe@167 | 596 "worse_than_status_quo" BOOLEAN, |
jbe@158 | 597 "reverse_beat_path" BOOLEAN, |
jbe@154 | 598 "multistage_majority" BOOLEAN, |
jbe@154 | 599 "eligible" BOOLEAN, |
jbe@126 | 600 "winner" BOOLEAN, |
jbe@0 | 601 "rank" INT4, |
jbe@7 | 602 "text_search_data" TSVECTOR, |
jbe@112 | 603 CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null" |
jbe@112 | 604 CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL), |
jbe@14 | 605 CONSTRAINT "non_revoked_initiatives_cant_suggest_other" |
jbe@14 | 606 CHECK ("revoked" NOTNULL OR "suggested_initiative_id" ISNULL), |
jbe@0 | 607 CONSTRAINT "revoked_initiatives_cant_be_admitted" |
jbe@0 | 608 CHECK ("revoked" ISNULL OR "admitted" ISNULL), |
jbe@128 | 609 CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK ( |
jbe@128 | 610 ( "admitted" NOTNULL AND "admitted" = TRUE ) OR |
jbe@167 | 611 ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND |
jbe@167 | 612 "direct_majority" ISNULL AND "indirect_majority" ISNULL AND |
jbe@173 | 613 "schulze_rank" ISNULL AND |
jbe@167 | 614 "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND |
jbe@167 | 615 "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND |
jbe@173 | 616 "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) ), |
jbe@173 | 617 CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo")), |
jbe@175 | 618 CONSTRAINT "minimum_requirement_to_be_eligible" CHECK ( |
jbe@175 | 619 "eligible" = FALSE OR |
jbe@175 | 620 ("direct_majority" AND "indirect_majority" AND "better_than_status_quo") ), |
jbe@175 | 621 CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE), |
jbe@175 | 622 CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1), |
jbe@176 | 623 CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE), |
jbe@173 | 624 CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank") ); |
jbe@16 | 625 CREATE INDEX "initiative_created_idx" ON "initiative" ("created"); |
jbe@16 | 626 CREATE INDEX "initiative_revoked_idx" ON "initiative" ("revoked"); |
jbe@8 | 627 CREATE INDEX "initiative_text_search_data_idx" ON "initiative" USING gin ("text_search_data"); |
jbe@7 | 628 CREATE TRIGGER "update_text_search_data" |
jbe@7 | 629 BEFORE INSERT OR UPDATE ON "initiative" |
jbe@7 | 630 FOR EACH ROW EXECUTE PROCEDURE |
jbe@8 | 631 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', |
jbe@8 | 632 "name", "discussion_url"); |
jbe@0 | 633 |
jbe@10 | 634 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.'; |
jbe@0 | 635 |
jbe@210 | 636 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative'; |
jbe@210 | 637 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative'; |
jbe@210 | 638 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative'; |
jbe@210 | 639 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue'; |
jbe@0 | 640 COMMENT ON COLUMN "initiative"."supporter_count" IS 'Calculated from table "direct_supporter_snapshot"'; |
jbe@0 | 641 COMMENT ON COLUMN "initiative"."informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"'; |
jbe@0 | 642 COMMENT ON COLUMN "initiative"."satisfied_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"'; |
jbe@0 | 643 COMMENT ON COLUMN "initiative"."satisfied_informed_supporter_count" IS 'Calculated from table "direct_supporter_snapshot"'; |
jbe@210 | 644 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"'; |
jbe@210 | 645 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"'; |
jbe@210 | 646 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"'; |
jbe@210 | 647 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths'; |
jbe@210 | 648 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking'; |
jbe@210 | 649 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)'; |
jbe@210 | 650 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)'; |
jbe@210 | 651 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'; |
jbe@210 | 652 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'; |
jbe@210 | 653 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"'; |
jbe@210 | 654 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"'; |
jbe@210 | 655 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'; |
jbe@0 | 656 |
jbe@0 | 657 |
jbe@61 | 658 CREATE TABLE "battle" ( |
jbe@126 | 659 "issue_id" INT4 NOT NULL, |
jbe@61 | 660 "winning_initiative_id" INT4, |
jbe@61 | 661 FOREIGN KEY ("issue_id", "winning_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@61 | 662 "losing_initiative_id" INT4, |
jbe@61 | 663 FOREIGN KEY ("issue_id", "losing_initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@126 | 664 "count" INT4 NOT NULL, |
jbe@126 | 665 CONSTRAINT "initiative_ids_not_equal" CHECK ( |
jbe@126 | 666 "winning_initiative_id" != "losing_initiative_id" OR |
jbe@126 | 667 ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR |
jbe@126 | 668 ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) ) ); |
jbe@126 | 669 CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id"); |
jbe@126 | 670 CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL; |
jbe@126 | 671 CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL; |
jbe@126 | 672 |
jbe@126 | 673 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'; |
jbe@61 | 674 |
jbe@61 | 675 |
jbe@113 | 676 CREATE TABLE "ignored_initiative" ( |
jbe@113 | 677 PRIMARY KEY ("initiative_id", "member_id"), |
jbe@113 | 678 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@113 | 679 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); |
jbe@113 | 680 CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id"); |
jbe@113 | 681 |
jbe@113 | 682 COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives'; |
jbe@113 | 683 |
jbe@113 | 684 |
jbe@23 | 685 CREATE TABLE "initiative_setting" ( |
jbe@23 | 686 PRIMARY KEY ("member_id", "key", "initiative_id"), |
jbe@23 | 687 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@23 | 688 "key" TEXT NOT NULL, |
jbe@23 | 689 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@23 | 690 "value" TEXT NOT NULL ); |
jbe@23 | 691 |
jbe@23 | 692 COMMENT ON TABLE "initiative_setting" IS 'Place for frontend to store initiative specific settings of members as strings'; |
jbe@23 | 693 |
jbe@23 | 694 |
jbe@0 | 695 CREATE TABLE "draft" ( |
jbe@0 | 696 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "supporter" |
jbe@0 | 697 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@0 | 698 "id" SERIAL8 PRIMARY KEY, |
jbe@0 | 699 "created" TIMESTAMPTZ NOT NULL DEFAULT now(), |
jbe@0 | 700 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE, |
jbe@9 | 701 "formatting_engine" TEXT, |
jbe@7 | 702 "content" TEXT NOT NULL, |
jbe@7 | 703 "text_search_data" TSVECTOR ); |
jbe@16 | 704 CREATE INDEX "draft_created_idx" ON "draft" ("created"); |
jbe@9 | 705 CREATE INDEX "draft_author_id_created_idx" ON "draft" ("author_id", "created"); |
jbe@8 | 706 CREATE INDEX "draft_text_search_data_idx" ON "draft" USING gin ("text_search_data"); |
jbe@7 | 707 CREATE TRIGGER "update_text_search_data" |
jbe@7 | 708 BEFORE INSERT OR UPDATE ON "draft" |
jbe@7 | 709 FOR EACH ROW EXECUTE PROCEDURE |
jbe@7 | 710 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content"); |
jbe@0 | 711 |
jbe@10 | 712 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.'; |
jbe@0 | 713 |
jbe@9 | 714 COMMENT ON COLUMN "draft"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used'; |
jbe@9 | 715 COMMENT ON COLUMN "draft"."content" IS 'Text of the draft in a format depending on the field "formatting_engine"'; |
jbe@9 | 716 |
jbe@0 | 717 |
jbe@63 | 718 CREATE TABLE "rendered_draft" ( |
jbe@63 | 719 PRIMARY KEY ("draft_id", "format"), |
jbe@63 | 720 "draft_id" INT8 REFERENCES "draft" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@63 | 721 "format" TEXT, |
jbe@63 | 722 "content" TEXT NOT NULL ); |
jbe@63 | 723 |
jbe@63 | 724 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)'; |
jbe@63 | 725 |
jbe@63 | 726 |
jbe@0 | 727 CREATE TABLE "suggestion" ( |
jbe@0 | 728 UNIQUE ("initiative_id", "id"), -- index needed for foreign-key on table "opinion" |
jbe@0 | 729 "initiative_id" INT4 NOT NULL REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@0 | 730 "id" SERIAL8 PRIMARY KEY, |
jbe@160 | 731 "draft_id" INT8 NOT NULL, |
jbe@160 | 732 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE, |
jbe@0 | 733 "created" TIMESTAMPTZ NOT NULL DEFAULT now(), |
jbe@0 | 734 "author_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE, |
jbe@0 | 735 "name" TEXT NOT NULL, |
jbe@159 | 736 "formatting_engine" TEXT, |
jbe@159 | 737 "content" TEXT NOT NULL DEFAULT '', |
jbe@7 | 738 "text_search_data" TSVECTOR, |
jbe@0 | 739 "minus2_unfulfilled_count" INT4, |
jbe@0 | 740 "minus2_fulfilled_count" INT4, |
jbe@0 | 741 "minus1_unfulfilled_count" INT4, |
jbe@0 | 742 "minus1_fulfilled_count" INT4, |
jbe@0 | 743 "plus1_unfulfilled_count" INT4, |
jbe@0 | 744 "plus1_fulfilled_count" INT4, |
jbe@0 | 745 "plus2_unfulfilled_count" INT4, |
jbe@0 | 746 "plus2_fulfilled_count" INT4 ); |
jbe@16 | 747 CREATE INDEX "suggestion_created_idx" ON "suggestion" ("created"); |
jbe@9 | 748 CREATE INDEX "suggestion_author_id_created_idx" ON "suggestion" ("author_id", "created"); |
jbe@8 | 749 CREATE INDEX "suggestion_text_search_data_idx" ON "suggestion" USING gin ("text_search_data"); |
jbe@7 | 750 CREATE TRIGGER "update_text_search_data" |
jbe@7 | 751 BEFORE INSERT OR UPDATE ON "suggestion" |
jbe@7 | 752 FOR EACH ROW EXECUTE PROCEDURE |
jbe@7 | 753 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', |
jbe@159 | 754 "name", "content"); |
jbe@0 | 755 |
jbe@10 | 756 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'; |
jbe@0 | 757 |
jbe@160 | 758 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")'; |
jbe@0 | 759 COMMENT ON COLUMN "suggestion"."minus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters'; |
jbe@0 | 760 COMMENT ON COLUMN "suggestion"."minus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters'; |
jbe@0 | 761 COMMENT ON COLUMN "suggestion"."minus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters'; |
jbe@0 | 762 COMMENT ON COLUMN "suggestion"."minus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters'; |
jbe@0 | 763 COMMENT ON COLUMN "suggestion"."plus1_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters'; |
jbe@0 | 764 COMMENT ON COLUMN "suggestion"."plus1_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters'; |
jbe@0 | 765 COMMENT ON COLUMN "suggestion"."plus2_unfulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters'; |
jbe@0 | 766 COMMENT ON COLUMN "suggestion"."plus2_fulfilled_count" IS 'Calculated from table "direct_supporter_snapshot", not requiring informed supporters'; |
jbe@0 | 767 |
jbe@0 | 768 |
jbe@159 | 769 CREATE TABLE "rendered_suggestion" ( |
jbe@159 | 770 PRIMARY KEY ("suggestion_id", "format"), |
jbe@159 | 771 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@159 | 772 "format" TEXT, |
jbe@159 | 773 "content" TEXT NOT NULL ); |
jbe@159 | 774 |
jbe@159 | 775 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)'; |
jbe@159 | 776 |
jbe@159 | 777 |
jbe@23 | 778 CREATE TABLE "suggestion_setting" ( |
jbe@23 | 779 PRIMARY KEY ("member_id", "key", "suggestion_id"), |
jbe@23 | 780 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@23 | 781 "key" TEXT NOT NULL, |
jbe@23 | 782 "suggestion_id" INT8 REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@23 | 783 "value" TEXT NOT NULL ); |
jbe@23 | 784 |
jbe@23 | 785 COMMENT ON TABLE "suggestion_setting" IS 'Place for frontend to store suggestion specific settings of members as strings'; |
jbe@23 | 786 |
jbe@23 | 787 |
jbe@97 | 788 CREATE TABLE "privilege" ( |
jbe@97 | 789 PRIMARY KEY ("unit_id", "member_id"), |
jbe@97 | 790 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@97 | 791 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@97 | 792 "admin_manager" BOOLEAN NOT NULL DEFAULT FALSE, |
jbe@97 | 793 "unit_manager" BOOLEAN NOT NULL DEFAULT FALSE, |
jbe@97 | 794 "area_manager" BOOLEAN NOT NULL DEFAULT FALSE, |
jbe@97 | 795 "voting_right_manager" BOOLEAN NOT NULL DEFAULT FALSE, |
jbe@97 | 796 "voting_right" BOOLEAN NOT NULL DEFAULT TRUE ); |
jbe@97 | 797 |
jbe@97 | 798 COMMENT ON TABLE "privilege" IS 'Members rights related to each unit'; |
jbe@97 | 799 |
jbe@207 | 800 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke admin privileges to/from other members'; |
jbe@207 | 801 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units'; |
jbe@207 | 802 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters'; |
jbe@207 | 803 COMMENT ON COLUMN "privilege"."voting_right_manager" IS 'Select which members are allowed to discuss and vote within the unit'; |
jbe@97 | 804 COMMENT ON COLUMN "privilege"."voting_right" IS 'Right to discuss and vote'; |
jbe@97 | 805 |
jbe@97 | 806 |
jbe@0 | 807 CREATE TABLE "membership" ( |
jbe@0 | 808 PRIMARY KEY ("area_id", "member_id"), |
jbe@0 | 809 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@169 | 810 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); |
jbe@0 | 811 CREATE INDEX "membership_member_id_idx" ON "membership" ("member_id"); |
jbe@0 | 812 |
jbe@0 | 813 COMMENT ON TABLE "membership" IS 'Interest of members in topic areas'; |
jbe@0 | 814 |
jbe@0 | 815 |
jbe@0 | 816 CREATE TABLE "interest" ( |
jbe@0 | 817 PRIMARY KEY ("issue_id", "member_id"), |
jbe@0 | 818 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@148 | 819 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); |
jbe@0 | 820 CREATE INDEX "interest_member_id_idx" ON "interest" ("member_id"); |
jbe@0 | 821 |
jbe@10 | 822 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.'; |
jbe@0 | 823 |
jbe@0 | 824 |
jbe@0 | 825 CREATE TABLE "initiator" ( |
jbe@0 | 826 PRIMARY KEY ("initiative_id", "member_id"), |
jbe@0 | 827 "initiative_id" INT4 REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@0 | 828 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@14 | 829 "accepted" BOOLEAN ); |
jbe@0 | 830 CREATE INDEX "initiator_member_id_idx" ON "initiator" ("member_id"); |
jbe@0 | 831 |
jbe@10 | 832 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.'; |
jbe@0 | 833 |
jbe@14 | 834 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.'; |
jbe@0 | 835 |
jbe@0 | 836 |
jbe@0 | 837 CREATE TABLE "supporter" ( |
jbe@0 | 838 "issue_id" INT4 NOT NULL, |
jbe@0 | 839 PRIMARY KEY ("initiative_id", "member_id"), |
jbe@0 | 840 "initiative_id" INT4, |
jbe@0 | 841 "member_id" INT4, |
jbe@0 | 842 "draft_id" INT8 NOT NULL, |
jbe@10 | 843 FOREIGN KEY ("issue_id", "member_id") REFERENCES "interest" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@160 | 844 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE ); |
jbe@0 | 845 CREATE INDEX "supporter_member_id_idx" ON "supporter" ("member_id"); |
jbe@0 | 846 |
jbe@10 | 847 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.'; |
jbe@0 | 848 |
jbe@207 | 849 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary'; |
jbe@160 | 850 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")'; |
jbe@84 | 851 |
jbe@0 | 852 |
jbe@0 | 853 CREATE TABLE "opinion" ( |
jbe@0 | 854 "initiative_id" INT4 NOT NULL, |
jbe@0 | 855 PRIMARY KEY ("suggestion_id", "member_id"), |
jbe@0 | 856 "suggestion_id" INT8, |
jbe@0 | 857 "member_id" INT4, |
jbe@0 | 858 "degree" INT2 NOT NULL CHECK ("degree" >= -2 AND "degree" <= 2 AND "degree" != 0), |
jbe@0 | 859 "fulfilled" BOOLEAN NOT NULL DEFAULT FALSE, |
jbe@42 | 860 FOREIGN KEY ("initiative_id", "suggestion_id") REFERENCES "suggestion" ("initiative_id", "id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@0 | 861 FOREIGN KEY ("initiative_id", "member_id") REFERENCES "supporter" ("initiative_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE ); |
jbe@10 | 862 CREATE INDEX "opinion_member_id_initiative_id_idx" ON "opinion" ("member_id", "initiative_id"); |
jbe@0 | 863 |
jbe@10 | 864 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.'; |
jbe@0 | 865 |
jbe@0 | 866 COMMENT ON COLUMN "opinion"."degree" IS '2 = fulfillment required for support; 1 = fulfillment desired; -1 = fulfillment unwanted; -2 = fulfillment cancels support'; |
jbe@0 | 867 |
jbe@0 | 868 |
jbe@97 | 869 CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue'); |
jbe@97 | 870 |
jbe@97 | 871 COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)'; |
jbe@10 | 872 |
jbe@10 | 873 |
jbe@0 | 874 CREATE TABLE "delegation" ( |
jbe@0 | 875 "id" SERIAL8 PRIMARY KEY, |
jbe@0 | 876 "truster_id" INT4 NOT NULL REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@86 | 877 "trustee_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@10 | 878 "scope" "delegation_scope" NOT NULL, |
jbe@97 | 879 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@0 | 880 "area_id" INT4 REFERENCES "area" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@0 | 881 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@0 | 882 CONSTRAINT "cant_delegate_to_yourself" CHECK ("truster_id" != "trustee_id"), |
jbe@97 | 883 CONSTRAINT "no_unit_delegation_to_null" |
jbe@97 | 884 CHECK ("trustee_id" NOTNULL OR "scope" != 'unit'), |
jbe@10 | 885 CONSTRAINT "area_id_and_issue_id_set_according_to_scope" CHECK ( |
jbe@97 | 886 ("scope" = 'unit' AND "unit_id" NOTNULL AND "area_id" ISNULL AND "issue_id" ISNULL ) OR |
jbe@97 | 887 ("scope" = 'area' AND "unit_id" ISNULL AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR |
jbe@97 | 888 ("scope" = 'issue' AND "unit_id" ISNULL AND "area_id" ISNULL AND "issue_id" NOTNULL) ), |
jbe@97 | 889 UNIQUE ("unit_id", "truster_id"), |
jbe@74 | 890 UNIQUE ("area_id", "truster_id"), |
jbe@74 | 891 UNIQUE ("issue_id", "truster_id") ); |
jbe@0 | 892 CREATE INDEX "delegation_truster_id_idx" ON "delegation" ("truster_id"); |
jbe@0 | 893 CREATE INDEX "delegation_trustee_id_idx" ON "delegation" ("trustee_id"); |
jbe@0 | 894 |
jbe@0 | 895 COMMENT ON TABLE "delegation" IS 'Delegation of vote-weight to other members'; |
jbe@0 | 896 |
jbe@97 | 897 COMMENT ON COLUMN "delegation"."unit_id" IS 'Reference to unit, if delegation is unit-wide, otherwise NULL'; |
jbe@0 | 898 COMMENT ON COLUMN "delegation"."area_id" IS 'Reference to area, if delegation is area-wide, otherwise NULL'; |
jbe@0 | 899 COMMENT ON COLUMN "delegation"."issue_id" IS 'Reference to issue, if delegation is issue-wide, otherwise NULL'; |
jbe@0 | 900 |
jbe@0 | 901 |
jbe@0 | 902 CREATE TABLE "direct_population_snapshot" ( |
jbe@0 | 903 PRIMARY KEY ("issue_id", "event", "member_id"), |
jbe@0 | 904 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@0 | 905 "event" "snapshot_event", |
jbe@45 | 906 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT, |
jbe@54 | 907 "weight" INT4 ); |
jbe@0 | 908 CREATE INDEX "direct_population_snapshot_member_id_idx" ON "direct_population_snapshot" ("member_id"); |
jbe@0 | 909 |
jbe@0 | 910 COMMENT ON TABLE "direct_population_snapshot" IS 'Snapshot of active members having either a "membership" in the "area" or an "interest" in the "issue"'; |
jbe@0 | 911 |
jbe@148 | 912 COMMENT ON COLUMN "direct_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details'; |
jbe@148 | 913 COMMENT ON COLUMN "direct_population_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_population_snapshot"'; |
jbe@0 | 914 |
jbe@0 | 915 |
jbe@0 | 916 CREATE TABLE "delegating_population_snapshot" ( |
jbe@0 | 917 PRIMARY KEY ("issue_id", "event", "member_id"), |
jbe@0 | 918 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@0 | 919 "event" "snapshot_event", |
jbe@45 | 920 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT, |
jbe@8 | 921 "weight" INT4, |
jbe@10 | 922 "scope" "delegation_scope" NOT NULL, |
jbe@0 | 923 "delegate_member_ids" INT4[] NOT NULL ); |
jbe@0 | 924 CREATE INDEX "delegating_population_snapshot_member_id_idx" ON "delegating_population_snapshot" ("member_id"); |
jbe@0 | 925 |
jbe@0 | 926 COMMENT ON TABLE "direct_population_snapshot" IS 'Delegations increasing the weight of entries in the "direct_population_snapshot" table'; |
jbe@0 | 927 |
jbe@0 | 928 COMMENT ON COLUMN "delegating_population_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details'; |
jbe@0 | 929 COMMENT ON COLUMN "delegating_population_snapshot"."member_id" IS 'Delegating member'; |
jbe@8 | 930 COMMENT ON COLUMN "delegating_population_snapshot"."weight" IS 'Intermediate weight'; |
jbe@0 | 931 COMMENT ON COLUMN "delegating_population_snapshot"."delegate_member_ids" IS 'Chain of members who act as delegates; last entry referes to "member_id" column of table "direct_population_snapshot"'; |
jbe@0 | 932 |
jbe@0 | 933 |
jbe@0 | 934 CREATE TABLE "direct_interest_snapshot" ( |
jbe@0 | 935 PRIMARY KEY ("issue_id", "event", "member_id"), |
jbe@0 | 936 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@0 | 937 "event" "snapshot_event", |
jbe@45 | 938 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT, |
jbe@144 | 939 "weight" INT4 ); |
jbe@0 | 940 CREATE INDEX "direct_interest_snapshot_member_id_idx" ON "direct_interest_snapshot" ("member_id"); |
jbe@0 | 941 |
jbe@0 | 942 COMMENT ON TABLE "direct_interest_snapshot" IS 'Snapshot of active members having an "interest" in the "issue"'; |
jbe@0 | 943 |
jbe@0 | 944 COMMENT ON COLUMN "direct_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details'; |
jbe@0 | 945 COMMENT ON COLUMN "direct_interest_snapshot"."weight" IS 'Weight of member (1 or higher) according to "delegating_interest_snapshot"'; |
jbe@0 | 946 |
jbe@0 | 947 |
jbe@0 | 948 CREATE TABLE "delegating_interest_snapshot" ( |
jbe@0 | 949 PRIMARY KEY ("issue_id", "event", "member_id"), |
jbe@0 | 950 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@0 | 951 "event" "snapshot_event", |
jbe@45 | 952 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT, |
jbe@8 | 953 "weight" INT4, |
jbe@10 | 954 "scope" "delegation_scope" NOT NULL, |
jbe@0 | 955 "delegate_member_ids" INT4[] NOT NULL ); |
jbe@0 | 956 CREATE INDEX "delegating_interest_snapshot_member_id_idx" ON "delegating_interest_snapshot" ("member_id"); |
jbe@0 | 957 |
jbe@0 | 958 COMMENT ON TABLE "delegating_interest_snapshot" IS 'Delegations increasing the weight of entries in the "direct_interest_snapshot" table'; |
jbe@0 | 959 |
jbe@0 | 960 COMMENT ON COLUMN "delegating_interest_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details'; |
jbe@0 | 961 COMMENT ON COLUMN "delegating_interest_snapshot"."member_id" IS 'Delegating member'; |
jbe@8 | 962 COMMENT ON COLUMN "delegating_interest_snapshot"."weight" IS 'Intermediate weight'; |
jbe@0 | 963 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"'; |
jbe@0 | 964 |
jbe@0 | 965 |
jbe@0 | 966 CREATE TABLE "direct_supporter_snapshot" ( |
jbe@0 | 967 "issue_id" INT4 NOT NULL, |
jbe@0 | 968 PRIMARY KEY ("initiative_id", "event", "member_id"), |
jbe@0 | 969 "initiative_id" INT4, |
jbe@0 | 970 "event" "snapshot_event", |
jbe@45 | 971 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT, |
jbe@204 | 972 "draft_id" INT8 NOT NULL, |
jbe@0 | 973 "informed" BOOLEAN NOT NULL, |
jbe@0 | 974 "satisfied" BOOLEAN NOT NULL, |
jbe@0 | 975 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@204 | 976 FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE, |
jbe@0 | 977 FOREIGN KEY ("issue_id", "event", "member_id") REFERENCES "direct_interest_snapshot" ("issue_id", "event", "member_id") ON DELETE CASCADE ON UPDATE CASCADE ); |
jbe@0 | 978 CREATE INDEX "direct_supporter_snapshot_member_id_idx" ON "direct_supporter_snapshot" ("member_id"); |
jbe@0 | 979 |
jbe@8 | 980 COMMENT ON TABLE "direct_supporter_snapshot" IS 'Snapshot of supporters of initiatives (weight is stored in "direct_interest_snapshot")'; |
jbe@0 | 981 |
jbe@207 | 982 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'; |
jbe@0 | 983 COMMENT ON COLUMN "direct_supporter_snapshot"."event" IS 'Reason for snapshot, see "snapshot_event" type for details'; |
jbe@0 | 984 COMMENT ON COLUMN "direct_supporter_snapshot"."informed" IS 'Supporter has seen the latest draft of the initiative'; |
jbe@0 | 985 COMMENT ON COLUMN "direct_supporter_snapshot"."satisfied" IS 'Supporter has no "critical_opinion"s'; |
jbe@0 | 986 |
jbe@0 | 987 |
jbe@113 | 988 CREATE TABLE "non_voter" ( |
jbe@113 | 989 PRIMARY KEY ("issue_id", "member_id"), |
jbe@113 | 990 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@113 | 991 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE ); |
jbe@113 | 992 CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id"); |
jbe@113 | 993 |
jbe@113 | 994 COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue'; |
jbe@113 | 995 |
jbe@113 | 996 |
jbe@0 | 997 CREATE TABLE "direct_voter" ( |
jbe@0 | 998 PRIMARY KEY ("issue_id", "member_id"), |
jbe@0 | 999 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@45 | 1000 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT, |
jbe@169 | 1001 "weight" INT4 ); |
jbe@0 | 1002 CREATE INDEX "direct_voter_member_id_idx" ON "direct_voter" ("member_id"); |
jbe@0 | 1003 |
jbe@10 | 1004 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.'; |
jbe@0 | 1005 |
jbe@207 | 1006 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table'; |
jbe@0 | 1007 |
jbe@0 | 1008 |
jbe@0 | 1009 CREATE TABLE "delegating_voter" ( |
jbe@0 | 1010 PRIMARY KEY ("issue_id", "member_id"), |
jbe@0 | 1011 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@45 | 1012 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE RESTRICT, |
jbe@8 | 1013 "weight" INT4, |
jbe@10 | 1014 "scope" "delegation_scope" NOT NULL, |
jbe@0 | 1015 "delegate_member_ids" INT4[] NOT NULL ); |
jbe@52 | 1016 CREATE INDEX "delegating_voter_member_id_idx" ON "delegating_voter" ("member_id"); |
jbe@0 | 1017 |
jbe@0 | 1018 COMMENT ON TABLE "delegating_voter" IS 'Delegations increasing the weight of entries in the "direct_voter" table'; |
jbe@0 | 1019 |
jbe@0 | 1020 COMMENT ON COLUMN "delegating_voter"."member_id" IS 'Delegating member'; |
jbe@8 | 1021 COMMENT ON COLUMN "delegating_voter"."weight" IS 'Intermediate weight'; |
jbe@0 | 1022 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"'; |
jbe@0 | 1023 |
jbe@0 | 1024 |
jbe@0 | 1025 CREATE TABLE "vote" ( |
jbe@0 | 1026 "issue_id" INT4 NOT NULL, |
jbe@0 | 1027 PRIMARY KEY ("initiative_id", "member_id"), |
jbe@0 | 1028 "initiative_id" INT4, |
jbe@0 | 1029 "member_id" INT4, |
jbe@0 | 1030 "grade" INT4, |
jbe@0 | 1031 FOREIGN KEY ("issue_id", "initiative_id") REFERENCES "initiative" ("issue_id", "id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@0 | 1032 FOREIGN KEY ("issue_id", "member_id") REFERENCES "direct_voter" ("issue_id", "member_id") ON DELETE CASCADE ON UPDATE CASCADE ); |
jbe@0 | 1033 CREATE INDEX "vote_member_id_idx" ON "vote" ("member_id"); |
jbe@0 | 1034 |
jbe@10 | 1035 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.'; |
jbe@0 | 1036 |
jbe@207 | 1037 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary'; |
jbe@207 | 1038 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.'; |
jbe@0 | 1039 |
jbe@0 | 1040 |
jbe@111 | 1041 CREATE TABLE "issue_comment" ( |
jbe@111 | 1042 PRIMARY KEY ("issue_id", "member_id"), |
jbe@111 | 1043 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@111 | 1044 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@111 | 1045 "changed" TIMESTAMPTZ NOT NULL DEFAULT now(), |
jbe@111 | 1046 "formatting_engine" TEXT, |
jbe@111 | 1047 "content" TEXT NOT NULL, |
jbe@111 | 1048 "text_search_data" TSVECTOR ); |
jbe@111 | 1049 CREATE INDEX "issue_comment_member_id_idx" ON "issue_comment" ("member_id"); |
jbe@111 | 1050 CREATE INDEX "issue_comment_text_search_data_idx" ON "issue_comment" USING gin ("text_search_data"); |
jbe@111 | 1051 CREATE TRIGGER "update_text_search_data" |
jbe@111 | 1052 BEFORE INSERT OR UPDATE ON "issue_comment" |
jbe@111 | 1053 FOR EACH ROW EXECUTE PROCEDURE |
jbe@111 | 1054 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content"); |
jbe@111 | 1055 |
jbe@111 | 1056 COMMENT ON TABLE "issue_comment" IS 'Place to store free comments of members related to issues'; |
jbe@111 | 1057 |
jbe@111 | 1058 COMMENT ON COLUMN "issue_comment"."changed" IS 'Time the comment was last changed'; |
jbe@111 | 1059 |
jbe@111 | 1060 |
jbe@111 | 1061 CREATE TABLE "rendered_issue_comment" ( |
jbe@111 | 1062 PRIMARY KEY ("issue_id", "member_id", "format"), |
jbe@111 | 1063 FOREIGN KEY ("issue_id", "member_id") |
jbe@111 | 1064 REFERENCES "issue_comment" ("issue_id", "member_id") |
jbe@111 | 1065 ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@111 | 1066 "issue_id" INT4, |
jbe@111 | 1067 "member_id" INT4, |
jbe@111 | 1068 "format" TEXT, |
jbe@111 | 1069 "content" TEXT NOT NULL ); |
jbe@111 | 1070 |
jbe@111 | 1071 COMMENT ON TABLE "rendered_issue_comment" IS 'This table may be used by frontends to cache "rendered" issue comments (e.g. HTML output generated from wiki text)'; |
jbe@111 | 1072 |
jbe@111 | 1073 |
jbe@111 | 1074 CREATE TABLE "voting_comment" ( |
jbe@111 | 1075 PRIMARY KEY ("issue_id", "member_id"), |
jbe@111 | 1076 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@111 | 1077 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@111 | 1078 "changed" TIMESTAMPTZ, |
jbe@111 | 1079 "formatting_engine" TEXT, |
jbe@111 | 1080 "content" TEXT NOT NULL, |
jbe@111 | 1081 "text_search_data" TSVECTOR ); |
jbe@111 | 1082 CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id"); |
jbe@111 | 1083 CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data"); |
jbe@111 | 1084 CREATE TRIGGER "update_text_search_data" |
jbe@111 | 1085 BEFORE INSERT OR UPDATE ON "voting_comment" |
jbe@111 | 1086 FOR EACH ROW EXECUTE PROCEDURE |
jbe@111 | 1087 tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content"); |
jbe@111 | 1088 |
jbe@111 | 1089 COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.'; |
jbe@111 | 1090 |
jbe@111 | 1091 COMMENT ON COLUMN "voting_comment"."changed" 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.'; |
jbe@111 | 1092 |
jbe@111 | 1093 |
jbe@111 | 1094 CREATE TABLE "rendered_voting_comment" ( |
jbe@111 | 1095 PRIMARY KEY ("issue_id", "member_id", "format"), |
jbe@111 | 1096 FOREIGN KEY ("issue_id", "member_id") |
jbe@111 | 1097 REFERENCES "voting_comment" ("issue_id", "member_id") |
jbe@111 | 1098 ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@111 | 1099 "issue_id" INT4, |
jbe@111 | 1100 "member_id" INT4, |
jbe@111 | 1101 "format" TEXT, |
jbe@111 | 1102 "content" TEXT NOT NULL ); |
jbe@111 | 1103 |
jbe@111 | 1104 COMMENT ON TABLE "rendered_voting_comment" IS 'This table may be used by frontends to cache "rendered" voting comments (e.g. HTML output generated from wiki text)'; |
jbe@111 | 1105 |
jbe@111 | 1106 |
jbe@112 | 1107 CREATE TYPE "event_type" AS ENUM ( |
jbe@112 | 1108 'issue_state_changed', |
jbe@112 | 1109 'initiative_created_in_new_issue', |
jbe@112 | 1110 'initiative_created_in_existing_issue', |
jbe@112 | 1111 'initiative_revoked', |
jbe@112 | 1112 'new_draft_created', |
jbe@112 | 1113 'suggestion_created'); |
jbe@112 | 1114 |
jbe@112 | 1115 COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"'; |
jbe@112 | 1116 |
jbe@112 | 1117 |
jbe@112 | 1118 CREATE TABLE "event" ( |
jbe@112 | 1119 "id" SERIAL8 PRIMARY KEY, |
jbe@112 | 1120 "occurrence" TIMESTAMPTZ NOT NULL DEFAULT now(), |
jbe@112 | 1121 "event" "event_type" NOT NULL, |
jbe@112 | 1122 "member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE, |
jbe@112 | 1123 "issue_id" INT4 REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@112 | 1124 "state" "issue_state" CHECK ("state" != 'calculation'), |
jbe@112 | 1125 "initiative_id" INT4, |
jbe@112 | 1126 "draft_id" INT8, |
jbe@112 | 1127 "suggestion_id" INT8, |
jbe@112 | 1128 FOREIGN KEY ("issue_id", "initiative_id") |
jbe@112 | 1129 REFERENCES "initiative" ("issue_id", "id") |
jbe@112 | 1130 ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@112 | 1131 FOREIGN KEY ("initiative_id", "draft_id") |
jbe@112 | 1132 REFERENCES "draft" ("initiative_id", "id") |
jbe@112 | 1133 ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@112 | 1134 FOREIGN KEY ("initiative_id", "suggestion_id") |
jbe@112 | 1135 REFERENCES "suggestion" ("initiative_id", "id") |
jbe@112 | 1136 ON DELETE CASCADE ON UPDATE CASCADE, |
jbe@112 | 1137 CONSTRAINT "null_constraints_for_issue_state_changed" CHECK ( |
jbe@112 | 1138 "event" != 'issue_state_changed' OR ( |
jbe@112 | 1139 "member_id" ISNULL AND |
jbe@112 | 1140 "issue_id" NOTNULL AND |
jbe@113 | 1141 "state" NOTNULL AND |
jbe@112 | 1142 "initiative_id" ISNULL AND |
jbe@112 | 1143 "draft_id" ISNULL AND |
jbe@112 | 1144 "suggestion_id" ISNULL )), |
jbe@112 | 1145 CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK ( |
jbe@112 | 1146 "event" NOT IN ( |
jbe@112 | 1147 'initiative_created_in_new_issue', |
jbe@112 | 1148 'initiative_created_in_existing_issue', |
jbe@112 | 1149 'initiative_revoked', |
jbe@112 | 1150 'new_draft_created' |
jbe@112 | 1151 ) OR ( |
jbe@112 | 1152 "member_id" NOTNULL AND |
jbe@112 | 1153 "issue_id" NOTNULL AND |
jbe@113 | 1154 "state" NOTNULL AND |
jbe@112 | 1155 "initiative_id" NOTNULL AND |
jbe@112 | 1156 "draft_id" NOTNULL AND |
jbe@112 | 1157 "suggestion_id" ISNULL )), |
jbe@112 | 1158 CONSTRAINT "null_constraints_for_suggestion_creation" CHECK ( |
jbe@112 | 1159 "event" != 'suggestion_created' OR ( |
jbe@112 | 1160 "member_id" NOTNULL AND |
jbe@112 | 1161 "issue_id" NOTNULL AND |
jbe@113 | 1162 "state" NOTNULL AND |
jbe@112 | 1163 "initiative_id" NOTNULL AND |
jbe@112 | 1164 "draft_id" ISNULL AND |
jbe@112 | 1165 "suggestion_id" NOTNULL )) ); |
jbe@223 | 1166 CREATE INDEX "event_occurrence_idx" ON "event" ("occurrence"); |
jbe@112 | 1167 |
jbe@112 | 1168 COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers'; |
jbe@112 | 1169 |
jbe@114 | 1170 COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred'; |
jbe@114 | 1171 COMMENT ON COLUMN "event"."event" IS 'Type of event (see TYPE "event_type")'; |
jbe@114 | 1172 COMMENT ON COLUMN "event"."member_id" IS 'Member who caused the event, if applicable'; |
jbe@114 | 1173 COMMENT ON COLUMN "event"."state" IS 'If issue_id is set: state of affected issue; If state changed: new state'; |
jbe@114 | 1174 |
jbe@112 | 1175 |
jbe@222 | 1176 CREATE TABLE "notification_sent" ( |
jbe@222 | 1177 "event_id" INT8 NOT NULL ); |
jbe@222 | 1178 CREATE UNIQUE INDEX "notification_sent_singleton_idx" ON "notification_sent" ((1)); |
jbe@222 | 1179 |
jbe@222 | 1180 COMMENT ON TABLE "notification_sent" IS 'This table stores one row with the last event_id, for which notifications have been sent out'; |
jbe@222 | 1181 COMMENT ON INDEX "notification_sent_singleton_idx" IS 'This index ensures that "notification_sent" only contains one row maximum.'; |
jbe@222 | 1182 |
jbe@222 | 1183 |
jbe@112 | 1184 |
jbe@112 | 1185 ---------------------------------------------- |
jbe@112 | 1186 -- Writing of history entries and event log -- |
jbe@112 | 1187 ---------------------------------------------- |
jbe@13 | 1188 |
jbe@181 | 1189 |
jbe@13 | 1190 CREATE FUNCTION "write_member_history_trigger"() |
jbe@13 | 1191 RETURNS TRIGGER |
jbe@13 | 1192 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@13 | 1193 BEGIN |
jbe@42 | 1194 IF |
jbe@230 | 1195 ( NEW."active" != OLD."active" OR |
jbe@230 | 1196 NEW."name" != OLD."name" ) AND |
jbe@230 | 1197 OLD."activated" NOTNULL |
jbe@42 | 1198 THEN |
jbe@42 | 1199 INSERT INTO "member_history" |
jbe@57 | 1200 ("member_id", "active", "name") |
jbe@57 | 1201 VALUES (NEW."id", OLD."active", OLD."name"); |
jbe@13 | 1202 END IF; |
jbe@13 | 1203 RETURN NULL; |
jbe@13 | 1204 END; |
jbe@13 | 1205 $$; |
jbe@13 | 1206 |
jbe@13 | 1207 CREATE TRIGGER "write_member_history" |
jbe@13 | 1208 AFTER UPDATE ON "member" FOR EACH ROW EXECUTE PROCEDURE |
jbe@13 | 1209 "write_member_history_trigger"(); |
jbe@13 | 1210 |
jbe@13 | 1211 COMMENT ON FUNCTION "write_member_history_trigger"() IS 'Implementation of trigger "write_member_history" on table "member"'; |
jbe@57 | 1212 COMMENT ON TRIGGER "write_member_history" ON "member" IS 'When changing certain fields of a member, create a history entry in "member_history" table'; |
jbe@13 | 1213 |
jbe@13 | 1214 |
jbe@112 | 1215 CREATE FUNCTION "write_event_issue_state_changed_trigger"() |
jbe@112 | 1216 RETURNS TRIGGER |
jbe@112 | 1217 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@112 | 1218 BEGIN |
jbe@112 | 1219 IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN |
jbe@112 | 1220 INSERT INTO "event" ("event", "issue_id", "state") |
jbe@112 | 1221 VALUES ('issue_state_changed', NEW."id", NEW."state"); |
jbe@112 | 1222 END IF; |
jbe@112 | 1223 RETURN NULL; |
jbe@112 | 1224 END; |
jbe@112 | 1225 $$; |
jbe@112 | 1226 |
jbe@112 | 1227 CREATE TRIGGER "write_event_issue_state_changed" |
jbe@112 | 1228 AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE |
jbe@112 | 1229 "write_event_issue_state_changed_trigger"(); |
jbe@112 | 1230 |
jbe@112 | 1231 COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"'; |
jbe@112 | 1232 COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change'; |
jbe@112 | 1233 |
jbe@112 | 1234 |
jbe@112 | 1235 CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"() |
jbe@112 | 1236 RETURNS TRIGGER |
jbe@112 | 1237 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@112 | 1238 DECLARE |
jbe@112 | 1239 "initiative_row" "initiative"%ROWTYPE; |
jbe@113 | 1240 "issue_row" "issue"%ROWTYPE; |
jbe@112 | 1241 "event_v" "event_type"; |
jbe@112 | 1242 BEGIN |
jbe@112 | 1243 SELECT * INTO "initiative_row" FROM "initiative" |
jbe@112 | 1244 WHERE "id" = NEW."initiative_id"; |
jbe@113 | 1245 SELECT * INTO "issue_row" FROM "issue" |
jbe@113 | 1246 WHERE "id" = "initiative_row"."issue_id"; |
jbe@112 | 1247 IF EXISTS ( |
jbe@112 | 1248 SELECT NULL FROM "draft" |
jbe@112 | 1249 WHERE "initiative_id" = NEW."initiative_id" |
jbe@112 | 1250 AND "id" != NEW."id" |
jbe@112 | 1251 ) THEN |
jbe@112 | 1252 "event_v" := 'new_draft_created'; |
jbe@112 | 1253 ELSE |
jbe@112 | 1254 IF EXISTS ( |
jbe@112 | 1255 SELECT NULL FROM "initiative" |
jbe@112 | 1256 WHERE "issue_id" = "initiative_row"."issue_id" |
jbe@112 | 1257 AND "id" != "initiative_row"."id" |
jbe@112 | 1258 ) THEN |
jbe@112 | 1259 "event_v" := 'initiative_created_in_existing_issue'; |
jbe@112 | 1260 ELSE |
jbe@112 | 1261 "event_v" := 'initiative_created_in_new_issue'; |
jbe@112 | 1262 END IF; |
jbe@112 | 1263 END IF; |
jbe@112 | 1264 INSERT INTO "event" ( |
jbe@112 | 1265 "event", "member_id", |
jbe@113 | 1266 "issue_id", "state", "initiative_id", "draft_id" |
jbe@112 | 1267 ) VALUES ( |
jbe@112 | 1268 "event_v", |
jbe@112 | 1269 NEW."author_id", |
jbe@112 | 1270 "initiative_row"."issue_id", |
jbe@113 | 1271 "issue_row"."state", |
jbe@112 | 1272 "initiative_row"."id", |
jbe@112 | 1273 NEW."id" ); |
jbe@112 | 1274 RETURN NULL; |
jbe@112 | 1275 END; |
jbe@112 | 1276 $$; |
jbe@112 | 1277 |
jbe@112 | 1278 CREATE TRIGGER "write_event_initiative_or_draft_created" |
jbe@112 | 1279 AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE |
jbe@112 | 1280 "write_event_initiative_or_draft_created_trigger"(); |
jbe@112 | 1281 |
jbe@112 | 1282 COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"'; |
jbe@112 | 1283 COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation'; |
jbe@112 | 1284 |
jbe@112 | 1285 |
jbe@112 | 1286 CREATE FUNCTION "write_event_initiative_revoked_trigger"() |
jbe@112 | 1287 RETURNS TRIGGER |
jbe@112 | 1288 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@113 | 1289 DECLARE |
jbe@231 | 1290 "issue_row" "issue"%ROWTYPE; |
jbe@231 | 1291 "draft_id_v" "draft"."id"%TYPE; |
jbe@112 | 1292 BEGIN |
jbe@112 | 1293 IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN |
jbe@231 | 1294 SELECT * INTO "issue_row" FROM "issue" |
jbe@231 | 1295 WHERE "id" = NEW."issue_id"; |
jbe@231 | 1296 SELECT "id" INTO "draft_id_v" FROM "current_draft" |
jbe@231 | 1297 WHERE "initiative_id" = NEW."id"; |
jbe@112 | 1298 INSERT INTO "event" ( |
jbe@231 | 1299 "event", "member_id", "issue_id", "state", "initiative_id", "draft_id" |
jbe@112 | 1300 ) VALUES ( |
jbe@112 | 1301 'initiative_revoked', |
jbe@112 | 1302 NEW."revoked_by_member_id", |
jbe@112 | 1303 NEW."issue_id", |
jbe@113 | 1304 "issue_row"."state", |
jbe@231 | 1305 NEW."id", |
jbe@231 | 1306 "draft_id_v"); |
jbe@112 | 1307 END IF; |
jbe@112 | 1308 RETURN NULL; |
jbe@112 | 1309 END; |
jbe@112 | 1310 $$; |
jbe@112 | 1311 |
jbe@112 | 1312 CREATE TRIGGER "write_event_initiative_revoked" |
jbe@112 | 1313 AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE |
jbe@112 | 1314 "write_event_initiative_revoked_trigger"(); |
jbe@112 | 1315 |
jbe@112 | 1316 COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"() IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"'; |
jbe@112 | 1317 COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked'; |
jbe@112 | 1318 |
jbe@112 | 1319 |
jbe@112 | 1320 CREATE FUNCTION "write_event_suggestion_created_trigger"() |
jbe@112 | 1321 RETURNS TRIGGER |
jbe@112 | 1322 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@112 | 1323 DECLARE |
jbe@112 | 1324 "initiative_row" "initiative"%ROWTYPE; |
jbe@113 | 1325 "issue_row" "issue"%ROWTYPE; |
jbe@112 | 1326 BEGIN |
jbe@112 | 1327 SELECT * INTO "initiative_row" FROM "initiative" |
jbe@112 | 1328 WHERE "id" = NEW."initiative_id"; |
jbe@113 | 1329 SELECT * INTO "issue_row" FROM "issue" |
jbe@113 | 1330 WHERE "id" = "initiative_row"."issue_id"; |
jbe@112 | 1331 INSERT INTO "event" ( |
jbe@112 | 1332 "event", "member_id", |
jbe@113 | 1333 "issue_id", "state", "initiative_id", "suggestion_id" |
jbe@112 | 1334 ) VALUES ( |
jbe@112 | 1335 'suggestion_created', |
jbe@112 | 1336 NEW."author_id", |
jbe@112 | 1337 "initiative_row"."issue_id", |
jbe@113 | 1338 "issue_row"."state", |
jbe@112 | 1339 "initiative_row"."id", |
jbe@112 | 1340 NEW."id" ); |
jbe@112 | 1341 RETURN NULL; |
jbe@112 | 1342 END; |
jbe@112 | 1343 $$; |
jbe@112 | 1344 |
jbe@112 | 1345 CREATE TRIGGER "write_event_suggestion_created" |
jbe@112 | 1346 AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE |
jbe@112 | 1347 "write_event_suggestion_created_trigger"(); |
jbe@112 | 1348 |
jbe@112 | 1349 COMMENT ON FUNCTION "write_event_suggestion_created_trigger"() IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"'; |
jbe@112 | 1350 COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation'; |
jbe@112 | 1351 |
jbe@112 | 1352 |
jbe@13 | 1353 |
jbe@0 | 1354 ---------------------------- |
jbe@0 | 1355 -- Additional constraints -- |
jbe@0 | 1356 ---------------------------- |
jbe@0 | 1357 |
jbe@0 | 1358 |
jbe@0 | 1359 CREATE FUNCTION "issue_requires_first_initiative_trigger"() |
jbe@0 | 1360 RETURNS TRIGGER |
jbe@0 | 1361 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 1362 BEGIN |
jbe@0 | 1363 IF NOT EXISTS ( |
jbe@0 | 1364 SELECT NULL FROM "initiative" WHERE "issue_id" = NEW."id" |
jbe@0 | 1365 ) THEN |
jbe@0 | 1366 --RAISE 'Cannot create issue without an initial initiative.' USING |
jbe@0 | 1367 -- ERRCODE = 'integrity_constraint_violation', |
jbe@0 | 1368 -- HINT = 'Create issue, initiative, and draft within the same transaction.'; |
jbe@0 | 1369 RAISE EXCEPTION 'Cannot create issue without an initial initiative.'; |
jbe@0 | 1370 END IF; |
jbe@0 | 1371 RETURN NULL; |
jbe@0 | 1372 END; |
jbe@0 | 1373 $$; |
jbe@0 | 1374 |
jbe@0 | 1375 CREATE CONSTRAINT TRIGGER "issue_requires_first_initiative" |
jbe@0 | 1376 AFTER INSERT OR UPDATE ON "issue" DEFERRABLE INITIALLY DEFERRED |
jbe@0 | 1377 FOR EACH ROW EXECUTE PROCEDURE |
jbe@0 | 1378 "issue_requires_first_initiative_trigger"(); |
jbe@0 | 1379 |
jbe@0 | 1380 COMMENT ON FUNCTION "issue_requires_first_initiative_trigger"() IS 'Implementation of trigger "issue_requires_first_initiative" on table "issue"'; |
jbe@0 | 1381 COMMENT ON TRIGGER "issue_requires_first_initiative" ON "issue" IS 'Ensure that new issues have at least one initiative'; |
jbe@0 | 1382 |
jbe@0 | 1383 |
jbe@0 | 1384 CREATE FUNCTION "last_initiative_deletes_issue_trigger"() |
jbe@0 | 1385 RETURNS TRIGGER |
jbe@0 | 1386 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 1387 DECLARE |
jbe@0 | 1388 "reference_lost" BOOLEAN; |
jbe@0 | 1389 BEGIN |
jbe@0 | 1390 IF TG_OP = 'DELETE' THEN |
jbe@0 | 1391 "reference_lost" := TRUE; |
jbe@0 | 1392 ELSE |
jbe@0 | 1393 "reference_lost" := NEW."issue_id" != OLD."issue_id"; |
jbe@0 | 1394 END IF; |
jbe@0 | 1395 IF |
jbe@0 | 1396 "reference_lost" AND NOT EXISTS ( |
jbe@0 | 1397 SELECT NULL FROM "initiative" WHERE "issue_id" = OLD."issue_id" |
jbe@0 | 1398 ) |
jbe@0 | 1399 THEN |
jbe@0 | 1400 DELETE FROM "issue" WHERE "id" = OLD."issue_id"; |
jbe@0 | 1401 END IF; |
jbe@0 | 1402 RETURN NULL; |
jbe@0 | 1403 END; |
jbe@0 | 1404 $$; |
jbe@0 | 1405 |
jbe@0 | 1406 CREATE CONSTRAINT TRIGGER "last_initiative_deletes_issue" |
jbe@0 | 1407 AFTER UPDATE OR DELETE ON "initiative" DEFERRABLE INITIALLY DEFERRED |
jbe@0 | 1408 FOR EACH ROW EXECUTE PROCEDURE |
jbe@0 | 1409 "last_initiative_deletes_issue_trigger"(); |
jbe@0 | 1410 |
jbe@0 | 1411 COMMENT ON FUNCTION "last_initiative_deletes_issue_trigger"() IS 'Implementation of trigger "last_initiative_deletes_issue" on table "initiative"'; |
jbe@0 | 1412 COMMENT ON TRIGGER "last_initiative_deletes_issue" ON "initiative" IS 'Removing the last initiative of an issue deletes the issue'; |
jbe@0 | 1413 |
jbe@0 | 1414 |
jbe@0 | 1415 CREATE FUNCTION "initiative_requires_first_draft_trigger"() |
jbe@0 | 1416 RETURNS TRIGGER |
jbe@0 | 1417 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 1418 BEGIN |
jbe@0 | 1419 IF NOT EXISTS ( |
jbe@0 | 1420 SELECT NULL FROM "draft" WHERE "initiative_id" = NEW."id" |
jbe@0 | 1421 ) THEN |
jbe@0 | 1422 --RAISE 'Cannot create initiative without an initial draft.' USING |
jbe@0 | 1423 -- ERRCODE = 'integrity_constraint_violation', |
jbe@0 | 1424 -- HINT = 'Create issue, initiative and draft within the same transaction.'; |
jbe@0 | 1425 RAISE EXCEPTION 'Cannot create initiative without an initial draft.'; |
jbe@0 | 1426 END IF; |
jbe@0 | 1427 RETURN NULL; |
jbe@0 | 1428 END; |
jbe@0 | 1429 $$; |
jbe@0 | 1430 |
jbe@0 | 1431 CREATE CONSTRAINT TRIGGER "initiative_requires_first_draft" |
jbe@0 | 1432 AFTER INSERT OR UPDATE ON "initiative" DEFERRABLE INITIALLY DEFERRED |
jbe@0 | 1433 FOR EACH ROW EXECUTE PROCEDURE |
jbe@0 | 1434 "initiative_requires_first_draft_trigger"(); |
jbe@0 | 1435 |
jbe@0 | 1436 COMMENT ON FUNCTION "initiative_requires_first_draft_trigger"() IS 'Implementation of trigger "initiative_requires_first_draft" on table "initiative"'; |
jbe@0 | 1437 COMMENT ON TRIGGER "initiative_requires_first_draft" ON "initiative" IS 'Ensure that new initiatives have at least one draft'; |
jbe@0 | 1438 |
jbe@0 | 1439 |
jbe@0 | 1440 CREATE FUNCTION "last_draft_deletes_initiative_trigger"() |
jbe@0 | 1441 RETURNS TRIGGER |
jbe@0 | 1442 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 1443 DECLARE |
jbe@0 | 1444 "reference_lost" BOOLEAN; |
jbe@0 | 1445 BEGIN |
jbe@0 | 1446 IF TG_OP = 'DELETE' THEN |
jbe@0 | 1447 "reference_lost" := TRUE; |
jbe@0 | 1448 ELSE |
jbe@0 | 1449 "reference_lost" := NEW."initiative_id" != OLD."initiative_id"; |
jbe@0 | 1450 END IF; |
jbe@0 | 1451 IF |
jbe@0 | 1452 "reference_lost" AND NOT EXISTS ( |
jbe@0 | 1453 SELECT NULL FROM "draft" WHERE "initiative_id" = OLD."initiative_id" |
jbe@0 | 1454 ) |
jbe@0 | 1455 THEN |
jbe@0 | 1456 DELETE FROM "initiative" WHERE "id" = OLD."initiative_id"; |
jbe@0 | 1457 END IF; |
jbe@0 | 1458 RETURN NULL; |
jbe@0 | 1459 END; |
jbe@0 | 1460 $$; |
jbe@0 | 1461 |
jbe@0 | 1462 CREATE CONSTRAINT TRIGGER "last_draft_deletes_initiative" |
jbe@0 | 1463 AFTER UPDATE OR DELETE ON "draft" DEFERRABLE INITIALLY DEFERRED |
jbe@0 | 1464 FOR EACH ROW EXECUTE PROCEDURE |
jbe@0 | 1465 "last_draft_deletes_initiative_trigger"(); |
jbe@0 | 1466 |
jbe@0 | 1467 COMMENT ON FUNCTION "last_draft_deletes_initiative_trigger"() IS 'Implementation of trigger "last_draft_deletes_initiative" on table "draft"'; |
jbe@0 | 1468 COMMENT ON TRIGGER "last_draft_deletes_initiative" ON "draft" IS 'Removing the last draft of an initiative deletes the initiative'; |
jbe@0 | 1469 |
jbe@0 | 1470 |
jbe@0 | 1471 CREATE FUNCTION "suggestion_requires_first_opinion_trigger"() |
jbe@0 | 1472 RETURNS TRIGGER |
jbe@0 | 1473 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 1474 BEGIN |
jbe@0 | 1475 IF NOT EXISTS ( |
jbe@0 | 1476 SELECT NULL FROM "opinion" WHERE "suggestion_id" = NEW."id" |
jbe@0 | 1477 ) THEN |
jbe@0 | 1478 RAISE EXCEPTION 'Cannot create a suggestion without an opinion.'; |
jbe@0 | 1479 END IF; |
jbe@0 | 1480 RETURN NULL; |
jbe@0 | 1481 END; |
jbe@0 | 1482 $$; |
jbe@0 | 1483 |
jbe@0 | 1484 CREATE CONSTRAINT TRIGGER "suggestion_requires_first_opinion" |
jbe@0 | 1485 AFTER INSERT OR UPDATE ON "suggestion" DEFERRABLE INITIALLY DEFERRED |
jbe@0 | 1486 FOR EACH ROW EXECUTE PROCEDURE |
jbe@0 | 1487 "suggestion_requires_first_opinion_trigger"(); |
jbe@0 | 1488 |
jbe@0 | 1489 COMMENT ON FUNCTION "suggestion_requires_first_opinion_trigger"() IS 'Implementation of trigger "suggestion_requires_first_opinion" on table "suggestion"'; |
jbe@0 | 1490 COMMENT ON TRIGGER "suggestion_requires_first_opinion" ON "suggestion" IS 'Ensure that new suggestions have at least one opinion'; |
jbe@0 | 1491 |
jbe@0 | 1492 |
jbe@0 | 1493 CREATE FUNCTION "last_opinion_deletes_suggestion_trigger"() |
jbe@0 | 1494 RETURNS TRIGGER |
jbe@0 | 1495 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 1496 DECLARE |
jbe@0 | 1497 "reference_lost" BOOLEAN; |
jbe@0 | 1498 BEGIN |
jbe@0 | 1499 IF TG_OP = 'DELETE' THEN |
jbe@0 | 1500 "reference_lost" := TRUE; |
jbe@0 | 1501 ELSE |
jbe@0 | 1502 "reference_lost" := NEW."suggestion_id" != OLD."suggestion_id"; |
jbe@0 | 1503 END IF; |
jbe@0 | 1504 IF |
jbe@0 | 1505 "reference_lost" AND NOT EXISTS ( |
jbe@0 | 1506 SELECT NULL FROM "opinion" WHERE "suggestion_id" = OLD."suggestion_id" |
jbe@0 | 1507 ) |
jbe@0 | 1508 THEN |
jbe@0 | 1509 DELETE FROM "suggestion" WHERE "id" = OLD."suggestion_id"; |
jbe@0 | 1510 END IF; |
jbe@0 | 1511 RETURN NULL; |
jbe@0 | 1512 END; |
jbe@0 | 1513 $$; |
jbe@0 | 1514 |
jbe@0 | 1515 CREATE CONSTRAINT TRIGGER "last_opinion_deletes_suggestion" |
jbe@0 | 1516 AFTER UPDATE OR DELETE ON "opinion" DEFERRABLE INITIALLY DEFERRED |
jbe@0 | 1517 FOR EACH ROW EXECUTE PROCEDURE |
jbe@0 | 1518 "last_opinion_deletes_suggestion_trigger"(); |
jbe@0 | 1519 |
jbe@0 | 1520 COMMENT ON FUNCTION "last_opinion_deletes_suggestion_trigger"() IS 'Implementation of trigger "last_opinion_deletes_suggestion" on table "opinion"'; |
jbe@0 | 1521 COMMENT ON TRIGGER "last_opinion_deletes_suggestion" ON "opinion" IS 'Removing the last opinion of a suggestion deletes the suggestion'; |
jbe@0 | 1522 |
jbe@0 | 1523 |
jbe@0 | 1524 |
jbe@20 | 1525 --------------------------------------------------------------- |
jbe@20 | 1526 -- Ensure that votes are not modified when issues are frozen -- |
jbe@20 | 1527 --------------------------------------------------------------- |
jbe@20 | 1528 |
jbe@20 | 1529 -- NOTE: Frontends should ensure this anyway, but in case of programming |
jbe@20 | 1530 -- errors the following triggers ensure data integrity. |
jbe@20 | 1531 |
jbe@20 | 1532 |
jbe@20 | 1533 CREATE FUNCTION "forbid_changes_on_closed_issue_trigger"() |
jbe@20 | 1534 RETURNS TRIGGER |
jbe@20 | 1535 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@20 | 1536 DECLARE |
jbe@32 | 1537 "issue_id_v" "issue"."id"%TYPE; |
jbe@32 | 1538 "issue_row" "issue"%ROWTYPE; |
jbe@20 | 1539 BEGIN |
jbe@32 | 1540 IF TG_OP = 'DELETE' THEN |
jbe@32 | 1541 "issue_id_v" := OLD."issue_id"; |
jbe@32 | 1542 ELSE |
jbe@32 | 1543 "issue_id_v" := NEW."issue_id"; |
jbe@32 | 1544 END IF; |
jbe@20 | 1545 SELECT INTO "issue_row" * FROM "issue" |
jbe@32 | 1546 WHERE "id" = "issue_id_v" FOR SHARE; |
jbe@20 | 1547 IF "issue_row"."closed" NOTNULL THEN |
jbe@20 | 1548 RAISE EXCEPTION 'Tried to modify data belonging to a closed issue.'; |
jbe@20 | 1549 END IF; |
jbe@20 | 1550 RETURN NULL; |
jbe@20 | 1551 END; |
jbe@20 | 1552 $$; |
jbe@20 | 1553 |
jbe@20 | 1554 CREATE TRIGGER "forbid_changes_on_closed_issue" |
jbe@20 | 1555 AFTER INSERT OR UPDATE OR DELETE ON "direct_voter" |
jbe@20 | 1556 FOR EACH ROW EXECUTE PROCEDURE |
jbe@20 | 1557 "forbid_changes_on_closed_issue_trigger"(); |
jbe@20 | 1558 |
jbe@20 | 1559 CREATE TRIGGER "forbid_changes_on_closed_issue" |
jbe@20 | 1560 AFTER INSERT OR UPDATE OR DELETE ON "delegating_voter" |
jbe@20 | 1561 FOR EACH ROW EXECUTE PROCEDURE |
jbe@20 | 1562 "forbid_changes_on_closed_issue_trigger"(); |
jbe@20 | 1563 |
jbe@20 | 1564 CREATE TRIGGER "forbid_changes_on_closed_issue" |
jbe@20 | 1565 AFTER INSERT OR UPDATE OR DELETE ON "vote" |
jbe@20 | 1566 FOR EACH ROW EXECUTE PROCEDURE |
jbe@20 | 1567 "forbid_changes_on_closed_issue_trigger"(); |
jbe@20 | 1568 |
jbe@20 | 1569 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"'; |
jbe@20 | 1570 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'; |
jbe@20 | 1571 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'; |
jbe@20 | 1572 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'; |
jbe@20 | 1573 |
jbe@20 | 1574 |
jbe@20 | 1575 |
jbe@0 | 1576 -------------------------------------------------------------------- |
jbe@0 | 1577 -- Auto-retrieval of fields only needed for referential integrity -- |
jbe@0 | 1578 -------------------------------------------------------------------- |
jbe@0 | 1579 |
jbe@20 | 1580 |
jbe@0 | 1581 CREATE FUNCTION "autofill_issue_id_trigger"() |
jbe@0 | 1582 RETURNS TRIGGER |
jbe@0 | 1583 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 1584 BEGIN |
jbe@0 | 1585 IF NEW."issue_id" ISNULL THEN |
jbe@0 | 1586 SELECT "issue_id" INTO NEW."issue_id" |
jbe@0 | 1587 FROM "initiative" WHERE "id" = NEW."initiative_id"; |
jbe@0 | 1588 END IF; |
jbe@0 | 1589 RETURN NEW; |
jbe@0 | 1590 END; |
jbe@0 | 1591 $$; |
jbe@0 | 1592 |
jbe@0 | 1593 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "supporter" |
jbe@0 | 1594 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"(); |
jbe@0 | 1595 |
jbe@0 | 1596 CREATE TRIGGER "autofill_issue_id" BEFORE INSERT ON "vote" |
jbe@0 | 1597 FOR EACH ROW EXECUTE PROCEDURE "autofill_issue_id_trigger"(); |
jbe@0 | 1598 |
jbe@0 | 1599 COMMENT ON FUNCTION "autofill_issue_id_trigger"() IS 'Implementation of triggers "autofill_issue_id" on tables "supporter" and "vote"'; |
jbe@0 | 1600 COMMENT ON TRIGGER "autofill_issue_id" ON "supporter" IS 'Set "issue_id" field automatically, if NULL'; |
jbe@0 | 1601 COMMENT ON TRIGGER "autofill_issue_id" ON "vote" IS 'Set "issue_id" field automatically, if NULL'; |
jbe@0 | 1602 |
jbe@0 | 1603 |
jbe@0 | 1604 CREATE FUNCTION "autofill_initiative_id_trigger"() |
jbe@0 | 1605 RETURNS TRIGGER |
jbe@0 | 1606 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 1607 BEGIN |
jbe@0 | 1608 IF NEW."initiative_id" ISNULL THEN |
jbe@0 | 1609 SELECT "initiative_id" INTO NEW."initiative_id" |
jbe@0 | 1610 FROM "suggestion" WHERE "id" = NEW."suggestion_id"; |
jbe@0 | 1611 END IF; |
jbe@0 | 1612 RETURN NEW; |
jbe@0 | 1613 END; |
jbe@0 | 1614 $$; |
jbe@0 | 1615 |
jbe@0 | 1616 CREATE TRIGGER "autofill_initiative_id" BEFORE INSERT ON "opinion" |
jbe@0 | 1617 FOR EACH ROW EXECUTE PROCEDURE "autofill_initiative_id_trigger"(); |
jbe@0 | 1618 |
jbe@0 | 1619 COMMENT ON FUNCTION "autofill_initiative_id_trigger"() IS 'Implementation of trigger "autofill_initiative_id" on table "opinion"'; |
jbe@0 | 1620 COMMENT ON TRIGGER "autofill_initiative_id" ON "opinion" IS 'Set "initiative_id" field automatically, if NULL'; |
jbe@0 | 1621 |
jbe@0 | 1622 |
jbe@0 | 1623 |
jbe@4 | 1624 ----------------------------------------------------- |
jbe@4 | 1625 -- Automatic calculation of certain default values -- |
jbe@4 | 1626 ----------------------------------------------------- |
jbe@0 | 1627 |
jbe@22 | 1628 |
jbe@22 | 1629 CREATE FUNCTION "copy_timings_trigger"() |
jbe@22 | 1630 RETURNS TRIGGER |
jbe@22 | 1631 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@22 | 1632 DECLARE |
jbe@22 | 1633 "policy_row" "policy"%ROWTYPE; |
jbe@22 | 1634 BEGIN |
jbe@22 | 1635 SELECT * INTO "policy_row" FROM "policy" |
jbe@22 | 1636 WHERE "id" = NEW."policy_id"; |
jbe@22 | 1637 IF NEW."admission_time" ISNULL THEN |
jbe@22 | 1638 NEW."admission_time" := "policy_row"."admission_time"; |
jbe@22 | 1639 END IF; |
jbe@22 | 1640 IF NEW."discussion_time" ISNULL THEN |
jbe@22 | 1641 NEW."discussion_time" := "policy_row"."discussion_time"; |
jbe@22 | 1642 END IF; |
jbe@22 | 1643 IF NEW."verification_time" ISNULL THEN |
jbe@22 | 1644 NEW."verification_time" := "policy_row"."verification_time"; |
jbe@22 | 1645 END IF; |
jbe@22 | 1646 IF NEW."voting_time" ISNULL THEN |
jbe@22 | 1647 NEW."voting_time" := "policy_row"."voting_time"; |
jbe@22 | 1648 END IF; |
jbe@22 | 1649 RETURN NEW; |
jbe@22 | 1650 END; |
jbe@22 | 1651 $$; |
jbe@22 | 1652 |
jbe@22 | 1653 CREATE TRIGGER "copy_timings" BEFORE INSERT OR UPDATE ON "issue" |
jbe@22 | 1654 FOR EACH ROW EXECUTE PROCEDURE "copy_timings_trigger"(); |
jbe@22 | 1655 |
jbe@22 | 1656 COMMENT ON FUNCTION "copy_timings_trigger"() IS 'Implementation of trigger "copy_timings" on table "issue"'; |
jbe@22 | 1657 COMMENT ON TRIGGER "copy_timings" ON "issue" IS 'If timing fields are NULL, copy values from policy.'; |
jbe@22 | 1658 |
jbe@22 | 1659 |
jbe@160 | 1660 CREATE FUNCTION "default_for_draft_id_trigger"() |
jbe@2 | 1661 RETURNS TRIGGER |
jbe@2 | 1662 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@2 | 1663 BEGIN |
jbe@2 | 1664 IF NEW."draft_id" ISNULL THEN |
jbe@2 | 1665 SELECT "id" INTO NEW."draft_id" FROM "current_draft" |
jbe@2 | 1666 WHERE "initiative_id" = NEW."initiative_id"; |
jbe@2 | 1667 END IF; |
jbe@2 | 1668 RETURN NEW; |
jbe@2 | 1669 END; |
jbe@2 | 1670 $$; |
jbe@2 | 1671 |
jbe@160 | 1672 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion" |
jbe@160 | 1673 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"(); |
jbe@2 | 1674 CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter" |
jbe@160 | 1675 FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"(); |
jbe@160 | 1676 |
jbe@160 | 1677 COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"'; |
jbe@160 | 1678 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'; |
jbe@160 | 1679 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'; |
jbe@2 | 1680 |
jbe@2 | 1681 |
jbe@0 | 1682 |
jbe@0 | 1683 ---------------------------------------- |
jbe@0 | 1684 -- Automatic creation of dependencies -- |
jbe@0 | 1685 ---------------------------------------- |
jbe@0 | 1686 |
jbe@22 | 1687 |
jbe@0 | 1688 CREATE FUNCTION "autocreate_interest_trigger"() |
jbe@0 | 1689 RETURNS TRIGGER |
jbe@0 | 1690 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 1691 BEGIN |
jbe@0 | 1692 IF NOT EXISTS ( |
jbe@0 | 1693 SELECT NULL FROM "initiative" JOIN "interest" |
jbe@0 | 1694 ON "initiative"."issue_id" = "interest"."issue_id" |
jbe@0 | 1695 WHERE "initiative"."id" = NEW."initiative_id" |
jbe@0 | 1696 AND "interest"."member_id" = NEW."member_id" |
jbe@0 | 1697 ) THEN |
jbe@0 | 1698 BEGIN |
jbe@0 | 1699 INSERT INTO "interest" ("issue_id", "member_id") |
jbe@0 | 1700 SELECT "issue_id", NEW."member_id" |
jbe@0 | 1701 FROM "initiative" WHERE "id" = NEW."initiative_id"; |
jbe@0 | 1702 EXCEPTION WHEN unique_violation THEN END; |
jbe@0 | 1703 END IF; |
jbe@0 | 1704 RETURN NEW; |
jbe@0 | 1705 END; |
jbe@0 | 1706 $$; |
jbe@0 | 1707 |
jbe@0 | 1708 CREATE TRIGGER "autocreate_interest" BEFORE INSERT ON "supporter" |
jbe@0 | 1709 FOR EACH ROW EXECUTE PROCEDURE "autocreate_interest_trigger"(); |
jbe@0 | 1710 |
jbe@0 | 1711 COMMENT ON FUNCTION "autocreate_interest_trigger"() IS 'Implementation of trigger "autocreate_interest" on table "supporter"'; |
jbe@0 | 1712 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'; |
jbe@0 | 1713 |
jbe@0 | 1714 |
jbe@0 | 1715 CREATE FUNCTION "autocreate_supporter_trigger"() |
jbe@0 | 1716 RETURNS TRIGGER |
jbe@0 | 1717 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 1718 BEGIN |
jbe@0 | 1719 IF NOT EXISTS ( |
jbe@0 | 1720 SELECT NULL FROM "suggestion" JOIN "supporter" |
jbe@0 | 1721 ON "suggestion"."initiative_id" = "supporter"."initiative_id" |
jbe@0 | 1722 WHERE "suggestion"."id" = NEW."suggestion_id" |
jbe@0 | 1723 AND "supporter"."member_id" = NEW."member_id" |
jbe@0 | 1724 ) THEN |
jbe@0 | 1725 BEGIN |
jbe@0 | 1726 INSERT INTO "supporter" ("initiative_id", "member_id") |
jbe@0 | 1727 SELECT "initiative_id", NEW."member_id" |
jbe@0 | 1728 FROM "suggestion" WHERE "id" = NEW."suggestion_id"; |
jbe@0 | 1729 EXCEPTION WHEN unique_violation THEN END; |
jbe@0 | 1730 END IF; |
jbe@0 | 1731 RETURN NEW; |
jbe@0 | 1732 END; |
jbe@0 | 1733 $$; |
jbe@0 | 1734 |
jbe@0 | 1735 CREATE TRIGGER "autocreate_supporter" BEFORE INSERT ON "opinion" |
jbe@0 | 1736 FOR EACH ROW EXECUTE PROCEDURE "autocreate_supporter_trigger"(); |
jbe@0 | 1737 |
jbe@0 | 1738 COMMENT ON FUNCTION "autocreate_supporter_trigger"() IS 'Implementation of trigger "autocreate_supporter" on table "opinion"'; |
jbe@0 | 1739 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.'; |
jbe@0 | 1740 |
jbe@0 | 1741 |
jbe@0 | 1742 |
jbe@0 | 1743 ------------------------------------------ |
jbe@0 | 1744 -- Views and helper functions for views -- |
jbe@0 | 1745 ------------------------------------------ |
jbe@0 | 1746 |
jbe@5 | 1747 |
jbe@97 | 1748 CREATE VIEW "unit_delegation" AS |
jbe@97 | 1749 SELECT |
jbe@97 | 1750 "unit"."id" AS "unit_id", |
jbe@97 | 1751 "delegation"."id", |
jbe@97 | 1752 "delegation"."truster_id", |
jbe@97 | 1753 "delegation"."trustee_id", |
jbe@97 | 1754 "delegation"."scope" |
jbe@97 | 1755 FROM "unit" |
jbe@97 | 1756 JOIN "delegation" |
jbe@97 | 1757 ON "delegation"."unit_id" = "unit"."id" |
jbe@97 | 1758 JOIN "member" |
jbe@97 | 1759 ON "delegation"."truster_id" = "member"."id" |
jbe@97 | 1760 JOIN "privilege" |
jbe@97 | 1761 ON "delegation"."unit_id" = "privilege"."unit_id" |
jbe@97 | 1762 AND "delegation"."truster_id" = "privilege"."member_id" |
jbe@97 | 1763 WHERE "member"."active" AND "privilege"."voting_right"; |
jbe@97 | 1764 |
jbe@97 | 1765 COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right'; |
jbe@5 | 1766 |
jbe@5 | 1767 |
jbe@5 | 1768 CREATE VIEW "area_delegation" AS |
jbe@70 | 1769 SELECT DISTINCT ON ("area"."id", "delegation"."truster_id") |
jbe@70 | 1770 "area"."id" AS "area_id", |
jbe@70 | 1771 "delegation"."id", |
jbe@70 | 1772 "delegation"."truster_id", |
jbe@70 | 1773 "delegation"."trustee_id", |
jbe@70 | 1774 "delegation"."scope" |
jbe@97 | 1775 FROM "area" |
jbe@97 | 1776 JOIN "delegation" |
jbe@97 | 1777 ON "delegation"."unit_id" = "area"."unit_id" |
jbe@97 | 1778 OR "delegation"."area_id" = "area"."id" |
jbe@97 | 1779 JOIN "member" |
jbe@97 | 1780 ON "delegation"."truster_id" = "member"."id" |
jbe@97 | 1781 JOIN "privilege" |
jbe@97 | 1782 ON "area"."unit_id" = "privilege"."unit_id" |
jbe@97 | 1783 AND "delegation"."truster_id" = "privilege"."member_id" |
jbe@97 | 1784 WHERE "member"."active" AND "privilege"."voting_right" |
jbe@70 | 1785 ORDER BY |
jbe@70 | 1786 "area"."id", |
jbe@70 | 1787 "delegation"."truster_id", |
jbe@70 | 1788 "delegation"."scope" DESC; |
jbe@70 | 1789 |
jbe@97 | 1790 COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right'; |
jbe@5 | 1791 |
jbe@5 | 1792 |
jbe@5 | 1793 CREATE VIEW "issue_delegation" AS |
jbe@70 | 1794 SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id") |
jbe@70 | 1795 "issue"."id" AS "issue_id", |
jbe@70 | 1796 "delegation"."id", |
jbe@70 | 1797 "delegation"."truster_id", |
jbe@70 | 1798 "delegation"."trustee_id", |
jbe@70 | 1799 "delegation"."scope" |
jbe@97 | 1800 FROM "issue" |
jbe@97 | 1801 JOIN "area" |
jbe@97 | 1802 ON "area"."id" = "issue"."area_id" |
jbe@97 | 1803 JOIN "delegation" |
jbe@97 | 1804 ON "delegation"."unit_id" = "area"."unit_id" |
jbe@97 | 1805 OR "delegation"."area_id" = "area"."id" |
jbe@97 | 1806 OR "delegation"."issue_id" = "issue"."id" |
jbe@97 | 1807 JOIN "member" |
jbe@97 | 1808 ON "delegation"."truster_id" = "member"."id" |
jbe@97 | 1809 JOIN "privilege" |
jbe@97 | 1810 ON "area"."unit_id" = "privilege"."unit_id" |
jbe@97 | 1811 AND "delegation"."truster_id" = "privilege"."member_id" |
jbe@97 | 1812 WHERE "member"."active" AND "privilege"."voting_right" |
jbe@70 | 1813 ORDER BY |
jbe@70 | 1814 "issue"."id", |
jbe@70 | 1815 "delegation"."truster_id", |
jbe@70 | 1816 "delegation"."scope" DESC; |
jbe@70 | 1817 |
jbe@97 | 1818 COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right'; |
jbe@5 | 1819 |
jbe@5 | 1820 |
jbe@5 | 1821 CREATE FUNCTION "membership_weight_with_skipping" |
jbe@5 | 1822 ( "area_id_p" "area"."id"%TYPE, |
jbe@5 | 1823 "member_id_p" "member"."id"%TYPE, |
jbe@5 | 1824 "skip_member_ids_p" INT4[] ) -- "member"."id"%TYPE[] |
jbe@5 | 1825 RETURNS INT4 |
jbe@5 | 1826 LANGUAGE 'plpgsql' STABLE AS $$ |
jbe@5 | 1827 DECLARE |
jbe@5 | 1828 "sum_v" INT4; |
jbe@5 | 1829 "delegation_row" "area_delegation"%ROWTYPE; |
jbe@5 | 1830 BEGIN |
jbe@5 | 1831 "sum_v" := 1; |
jbe@5 | 1832 FOR "delegation_row" IN |
jbe@5 | 1833 SELECT "area_delegation".* |
jbe@5 | 1834 FROM "area_delegation" LEFT JOIN "membership" |
jbe@5 | 1835 ON "membership"."area_id" = "area_id_p" |
jbe@5 | 1836 AND "membership"."member_id" = "area_delegation"."truster_id" |
jbe@5 | 1837 WHERE "area_delegation"."area_id" = "area_id_p" |
jbe@5 | 1838 AND "area_delegation"."trustee_id" = "member_id_p" |
jbe@5 | 1839 AND "membership"."member_id" ISNULL |
jbe@5 | 1840 LOOP |
jbe@5 | 1841 IF NOT |
jbe@5 | 1842 "skip_member_ids_p" @> ARRAY["delegation_row"."truster_id"] |
jbe@5 | 1843 THEN |
jbe@5 | 1844 "sum_v" := "sum_v" + "membership_weight_with_skipping"( |
jbe@5 | 1845 "area_id_p", |
jbe@5 | 1846 "delegation_row"."truster_id", |
jbe@5 | 1847 "skip_member_ids_p" || "delegation_row"."truster_id" |
jbe@5 | 1848 ); |
jbe@5 | 1849 END IF; |
jbe@5 | 1850 END LOOP; |
jbe@5 | 1851 RETURN "sum_v"; |
jbe@5 | 1852 END; |
jbe@5 | 1853 $$; |
jbe@5 | 1854 |
jbe@8 | 1855 COMMENT ON FUNCTION "membership_weight_with_skipping" |
jbe@8 | 1856 ( "area"."id"%TYPE, |
jbe@8 | 1857 "member"."id"%TYPE, |
jbe@8 | 1858 INT4[] ) |
jbe@8 | 1859 IS 'Helper function for "membership_weight" function'; |
jbe@8 | 1860 |
jbe@8 | 1861 |
jbe@5 | 1862 CREATE FUNCTION "membership_weight" |
jbe@5 | 1863 ( "area_id_p" "area"."id"%TYPE, |
jbe@5 | 1864 "member_id_p" "member"."id"%TYPE ) -- "member"."id"%TYPE[] |
jbe@5 | 1865 RETURNS INT4 |
jbe@5 | 1866 LANGUAGE 'plpgsql' STABLE AS $$ |
jbe@5 | 1867 BEGIN |
jbe@5 | 1868 RETURN "membership_weight_with_skipping"( |
jbe@5 | 1869 "area_id_p", |
jbe@5 | 1870 "member_id_p", |
jbe@5 | 1871 ARRAY["member_id_p"] |
jbe@5 | 1872 ); |
jbe@5 | 1873 END; |
jbe@5 | 1874 $$; |
jbe@5 | 1875 |
jbe@8 | 1876 COMMENT ON FUNCTION "membership_weight" |
jbe@8 | 1877 ( "area"."id"%TYPE, |
jbe@8 | 1878 "member"."id"%TYPE ) |
jbe@8 | 1879 IS 'Calculates the potential voting weight of a member in a given area'; |
jbe@8 | 1880 |
jbe@5 | 1881 |
jbe@4 | 1882 CREATE VIEW "member_count_view" AS |
jbe@5 | 1883 SELECT count(1) AS "total_count" FROM "member" WHERE "active"; |
jbe@4 | 1884 |
jbe@4 | 1885 COMMENT ON VIEW "member_count_view" IS 'View used to update "member_count" table'; |
jbe@4 | 1886 |
jbe@4 | 1887 |
jbe@97 | 1888 CREATE VIEW "unit_member_count" AS |
jbe@97 | 1889 SELECT |
jbe@97 | 1890 "unit"."id" AS "unit_id", |
jbe@97 | 1891 sum("member"."id") AS "member_count" |
jbe@97 | 1892 FROM "unit" |
jbe@97 | 1893 LEFT JOIN "privilege" |
jbe@97 | 1894 ON "privilege"."unit_id" = "unit"."id" |
jbe@97 | 1895 AND "privilege"."voting_right" |
jbe@97 | 1896 LEFT JOIN "member" |
jbe@97 | 1897 ON "member"."id" = "privilege"."member_id" |
jbe@97 | 1898 AND "member"."active" |
jbe@97 | 1899 GROUP BY "unit"."id"; |
jbe@97 | 1900 |
jbe@97 | 1901 COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table'; |
jbe@97 | 1902 |
jbe@97 | 1903 |
jbe@4 | 1904 CREATE VIEW "area_member_count" AS |
jbe@5 | 1905 SELECT |
jbe@5 | 1906 "area"."id" AS "area_id", |
jbe@5 | 1907 count("member"."id") AS "direct_member_count", |
jbe@5 | 1908 coalesce( |
jbe@5 | 1909 sum( |
jbe@5 | 1910 CASE WHEN "member"."id" NOTNULL THEN |
jbe@5 | 1911 "membership_weight"("area"."id", "member"."id") |
jbe@5 | 1912 ELSE 0 END |
jbe@5 | 1913 ) |
jbe@169 | 1914 ) AS "member_weight" |
jbe@4 | 1915 FROM "area" |
jbe@4 | 1916 LEFT JOIN "membership" |
jbe@4 | 1917 ON "area"."id" = "membership"."area_id" |
jbe@97 | 1918 LEFT JOIN "privilege" |
jbe@97 | 1919 ON "privilege"."unit_id" = "area"."unit_id" |
jbe@97 | 1920 AND "privilege"."member_id" = "membership"."member_id" |
jbe@97 | 1921 AND "privilege"."voting_right" |
jbe@4 | 1922 LEFT JOIN "member" |
jbe@97 | 1923 ON "member"."id" = "privilege"."member_id" -- NOTE: no membership here! |
jbe@4 | 1924 AND "member"."active" |
jbe@4 | 1925 GROUP BY "area"."id"; |
jbe@4 | 1926 |
jbe@169 | 1927 COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"'; |
jbe@4 | 1928 |
jbe@4 | 1929 |
jbe@9 | 1930 CREATE VIEW "opening_draft" AS |
jbe@9 | 1931 SELECT "draft".* FROM ( |
jbe@9 | 1932 SELECT |
jbe@9 | 1933 "initiative"."id" AS "initiative_id", |
jbe@9 | 1934 min("draft"."id") AS "draft_id" |
jbe@9 | 1935 FROM "initiative" JOIN "draft" |
jbe@9 | 1936 ON "initiative"."id" = "draft"."initiative_id" |
jbe@9 | 1937 GROUP BY "initiative"."id" |
jbe@9 | 1938 ) AS "subquery" |
jbe@9 | 1939 JOIN "draft" ON "subquery"."draft_id" = "draft"."id"; |
jbe@9 | 1940 |
jbe@9 | 1941 COMMENT ON VIEW "opening_draft" IS 'First drafts of all initiatives'; |
jbe@9 | 1942 |
jbe@9 | 1943 |
jbe@0 | 1944 CREATE VIEW "current_draft" AS |
jbe@0 | 1945 SELECT "draft".* FROM ( |
jbe@0 | 1946 SELECT |
jbe@0 | 1947 "initiative"."id" AS "initiative_id", |
jbe@0 | 1948 max("draft"."id") AS "draft_id" |
jbe@0 | 1949 FROM "initiative" JOIN "draft" |
jbe@0 | 1950 ON "initiative"."id" = "draft"."initiative_id" |
jbe@0 | 1951 GROUP BY "initiative"."id" |
jbe@0 | 1952 ) AS "subquery" |
jbe@0 | 1953 JOIN "draft" ON "subquery"."draft_id" = "draft"."id"; |
jbe@0 | 1954 |
jbe@0 | 1955 COMMENT ON VIEW "current_draft" IS 'All latest drafts for each initiative'; |
jbe@0 | 1956 |
jbe@0 | 1957 |
jbe@0 | 1958 CREATE VIEW "critical_opinion" AS |
jbe@0 | 1959 SELECT * FROM "opinion" |
jbe@0 | 1960 WHERE ("degree" = 2 AND "fulfilled" = FALSE) |
jbe@0 | 1961 OR ("degree" = -2 AND "fulfilled" = TRUE); |
jbe@0 | 1962 |
jbe@0 | 1963 COMMENT ON VIEW "critical_opinion" IS 'Opinions currently causing dissatisfaction'; |
jbe@0 | 1964 |
jbe@0 | 1965 |
jbe@126 | 1966 CREATE VIEW "battle_participant" AS |
jbe@126 | 1967 SELECT "initiative"."id", "initiative"."issue_id" |
jbe@126 | 1968 FROM "issue" JOIN "initiative" |
jbe@126 | 1969 ON "issue"."id" = "initiative"."issue_id" |
jbe@126 | 1970 WHERE "initiative"."admitted" |
jbe@126 | 1971 UNION ALL |
jbe@126 | 1972 SELECT NULL, "id" AS "issue_id" |
jbe@126 | 1973 FROM "issue"; |
jbe@126 | 1974 |
jbe@126 | 1975 COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference'; |
jbe@126 | 1976 |
jbe@126 | 1977 |
jbe@61 | 1978 CREATE VIEW "battle_view" AS |
jbe@0 | 1979 SELECT |
jbe@0 | 1980 "issue"."id" AS "issue_id", |
jbe@10 | 1981 "winning_initiative"."id" AS "winning_initiative_id", |
jbe@10 | 1982 "losing_initiative"."id" AS "losing_initiative_id", |
jbe@0 | 1983 sum( |
jbe@0 | 1984 CASE WHEN |
jbe@0 | 1985 coalesce("better_vote"."grade", 0) > |
jbe@0 | 1986 coalesce("worse_vote"."grade", 0) |
jbe@0 | 1987 THEN "direct_voter"."weight" ELSE 0 END |
jbe@0 | 1988 ) AS "count" |
jbe@0 | 1989 FROM "issue" |
jbe@0 | 1990 LEFT JOIN "direct_voter" |
jbe@0 | 1991 ON "issue"."id" = "direct_voter"."issue_id" |
jbe@126 | 1992 JOIN "battle_participant" AS "winning_initiative" |
jbe@10 | 1993 ON "issue"."id" = "winning_initiative"."issue_id" |
jbe@126 | 1994 JOIN "battle_participant" AS "losing_initiative" |
jbe@10 | 1995 ON "issue"."id" = "losing_initiative"."issue_id" |
jbe@0 | 1996 LEFT JOIN "vote" AS "better_vote" |
jbe@10 | 1997 ON "direct_voter"."member_id" = "better_vote"."member_id" |
jbe@10 | 1998 AND "winning_initiative"."id" = "better_vote"."initiative_id" |
jbe@0 | 1999 LEFT JOIN "vote" AS "worse_vote" |
jbe@10 | 2000 ON "direct_voter"."member_id" = "worse_vote"."member_id" |
jbe@10 | 2001 AND "losing_initiative"."id" = "worse_vote"."initiative_id" |
jbe@61 | 2002 WHERE "issue"."closed" NOTNULL |
jbe@61 | 2003 AND "issue"."cleaned" ISNULL |
jbe@126 | 2004 AND ( |
jbe@126 | 2005 "winning_initiative"."id" != "losing_initiative"."id" OR |
jbe@126 | 2006 ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR |
jbe@126 | 2007 ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) ) |
jbe@0 | 2008 GROUP BY |
jbe@0 | 2009 "issue"."id", |
jbe@10 | 2010 "winning_initiative"."id", |
jbe@10 | 2011 "losing_initiative"."id"; |
jbe@0 | 2012 |
jbe@126 | 2013 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'; |
jbe@1 | 2014 |
jbe@1 | 2015 |
jbe@235 | 2016 CREATE VIEW "expired_session" AS |
jbe@235 | 2017 SELECT * FROM "session" WHERE now() > "expiry"; |
jbe@235 | 2018 |
jbe@235 | 2019 CREATE RULE "delete" AS ON DELETE TO "expired_session" DO INSTEAD |
jbe@235 | 2020 DELETE FROM "session" WHERE "ident" = OLD."ident"; |
jbe@235 | 2021 |
jbe@235 | 2022 COMMENT ON VIEW "expired_session" IS 'View containing all expired sessions where DELETE is possible'; |
jbe@235 | 2023 COMMENT ON RULE "delete" ON "expired_session" IS 'Rule allowing DELETE on rows in "expired_session" view, i.e. DELETE FROM "expired_session"'; |
jbe@235 | 2024 |
jbe@235 | 2025 |
jbe@0 | 2026 CREATE VIEW "open_issue" AS |
jbe@0 | 2027 SELECT * FROM "issue" WHERE "closed" ISNULL; |
jbe@0 | 2028 |
jbe@0 | 2029 COMMENT ON VIEW "open_issue" IS 'All open issues'; |
jbe@0 | 2030 |
jbe@0 | 2031 |
jbe@0 | 2032 CREATE VIEW "issue_with_ranks_missing" AS |
jbe@0 | 2033 SELECT * FROM "issue" |
jbe@3 | 2034 WHERE "fully_frozen" NOTNULL |
jbe@0 | 2035 AND "closed" NOTNULL |
jbe@0 | 2036 AND "ranks_available" = FALSE; |
jbe@0 | 2037 |
jbe@0 | 2038 COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet'; |
jbe@0 | 2039 |
jbe@0 | 2040 |
jbe@9 | 2041 CREATE VIEW "member_contingent" AS |
jbe@9 | 2042 SELECT |
jbe@9 | 2043 "member"."id" AS "member_id", |
jbe@9 | 2044 "contingent"."time_frame", |
jbe@9 | 2045 CASE WHEN "contingent"."text_entry_limit" NOTNULL THEN |
jbe@9 | 2046 ( |
jbe@9 | 2047 SELECT count(1) FROM "draft" |
jbe@9 | 2048 WHERE "draft"."author_id" = "member"."id" |
jbe@9 | 2049 AND "draft"."created" > now() - "contingent"."time_frame" |
jbe@9 | 2050 ) + ( |
jbe@9 | 2051 SELECT count(1) FROM "suggestion" |
jbe@9 | 2052 WHERE "suggestion"."author_id" = "member"."id" |
jbe@9 | 2053 AND "suggestion"."created" > now() - "contingent"."time_frame" |
jbe@9 | 2054 ) |
jbe@9 | 2055 ELSE NULL END AS "text_entry_count", |
jbe@9 | 2056 "contingent"."text_entry_limit", |
jbe@9 | 2057 CASE WHEN "contingent"."initiative_limit" NOTNULL THEN ( |
jbe@9 | 2058 SELECT count(1) FROM "opening_draft" |
jbe@9 | 2059 WHERE "opening_draft"."author_id" = "member"."id" |
jbe@9 | 2060 AND "opening_draft"."created" > now() - "contingent"."time_frame" |
jbe@9 | 2061 ) ELSE NULL END AS "initiative_count", |
jbe@9 | 2062 "contingent"."initiative_limit" |
jbe@9 | 2063 FROM "member" CROSS JOIN "contingent"; |
jbe@9 | 2064 |
jbe@9 | 2065 COMMENT ON VIEW "member_contingent" IS 'Actual counts of text entries and initiatives are calculated per member for each limit in the "contingent" table.'; |
jbe@9 | 2066 |
jbe@9 | 2067 COMMENT ON COLUMN "member_contingent"."text_entry_count" IS 'Only calculated when "text_entry_limit" is not null in the same row'; |
jbe@9 | 2068 COMMENT ON COLUMN "member_contingent"."initiative_count" IS 'Only calculated when "initiative_limit" is not null in the same row'; |
jbe@9 | 2069 |
jbe@9 | 2070 |
jbe@9 | 2071 CREATE VIEW "member_contingent_left" AS |
jbe@9 | 2072 SELECT |
jbe@9 | 2073 "member_id", |
jbe@9 | 2074 max("text_entry_limit" - "text_entry_count") AS "text_entries_left", |
jbe@9 | 2075 max("initiative_limit" - "initiative_count") AS "initiatives_left" |
jbe@9 | 2076 FROM "member_contingent" GROUP BY "member_id"; |
jbe@9 | 2077 |
jbe@9 | 2078 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.'; |
jbe@9 | 2079 |
jbe@9 | 2080 |
jbe@113 | 2081 CREATE VIEW "event_seen_by_member" AS |
jbe@113 | 2082 SELECT |
jbe@113 | 2083 "member"."id" AS "seen_by_member_id", |
jbe@113 | 2084 CASE WHEN "event"."state" IN ( |
jbe@113 | 2085 'voting', |
jbe@113 | 2086 'finished_without_winner', |
jbe@113 | 2087 'finished_with_winner' |
jbe@113 | 2088 ) THEN |
jbe@113 | 2089 'voting'::"notify_level" |
jbe@113 | 2090 ELSE |
jbe@113 | 2091 CASE WHEN "event"."state" IN ( |
jbe@113 | 2092 'verification', |
jbe@113 | 2093 'canceled_after_revocation_during_verification', |
jbe@113 | 2094 'canceled_no_initiative_admitted' |
jbe@113 | 2095 ) THEN |
jbe@113 | 2096 'verification'::"notify_level" |
jbe@113 | 2097 ELSE |
jbe@113 | 2098 CASE WHEN "event"."state" IN ( |
jbe@113 | 2099 'discussion', |
jbe@113 | 2100 'canceled_after_revocation_during_discussion' |
jbe@113 | 2101 ) THEN |
jbe@113 | 2102 'discussion'::"notify_level" |
jbe@113 | 2103 ELSE |
jbe@113 | 2104 'all'::"notify_level" |
jbe@113 | 2105 END |
jbe@113 | 2106 END |
jbe@113 | 2107 END AS "notify_level", |
jbe@113 | 2108 "event".* |
jbe@113 | 2109 FROM "member" CROSS JOIN "event" |
jbe@113 | 2110 LEFT JOIN "issue" |
jbe@113 | 2111 ON "event"."issue_id" = "issue"."id" |
jbe@113 | 2112 LEFT JOIN "membership" |
jbe@113 | 2113 ON "member"."id" = "membership"."member_id" |
jbe@113 | 2114 AND "issue"."area_id" = "membership"."area_id" |
jbe@113 | 2115 LEFT JOIN "interest" |
jbe@113 | 2116 ON "member"."id" = "interest"."member_id" |
jbe@113 | 2117 AND "event"."issue_id" = "interest"."issue_id" |
jbe@113 | 2118 LEFT JOIN "supporter" |
jbe@113 | 2119 ON "member"."id" = "supporter"."member_id" |
jbe@113 | 2120 AND "event"."initiative_id" = "supporter"."initiative_id" |
jbe@113 | 2121 LEFT JOIN "ignored_member" |
jbe@113 | 2122 ON "member"."id" = "ignored_member"."member_id" |
jbe@113 | 2123 AND "event"."member_id" = "ignored_member"."other_member_id" |
jbe@113 | 2124 LEFT JOIN "ignored_initiative" |
jbe@113 | 2125 ON "member"."id" = "ignored_initiative"."member_id" |
jbe@113 | 2126 AND "event"."initiative_id" = "ignored_initiative"."initiative_id" |
jbe@113 | 2127 WHERE ( |
jbe@113 | 2128 "supporter"."member_id" NOTNULL OR |
jbe@113 | 2129 "interest"."member_id" NOTNULL OR |
jbe@113 | 2130 ( "membership"."member_id" NOTNULL AND |
jbe@113 | 2131 "event"."event" IN ( |
jbe@113 | 2132 'issue_state_changed', |
jbe@113 | 2133 'initiative_created_in_new_issue', |
jbe@113 | 2134 'initiative_created_in_existing_issue', |
jbe@113 | 2135 'initiative_revoked' ) ) ) |
jbe@113 | 2136 AND "ignored_member"."member_id" ISNULL |
jbe@113 | 2137 AND "ignored_initiative"."member_id" ISNULL; |
jbe@113 | 2138 |
jbe@222 | 2139 COMMENT ON VIEW "event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests and support, but ignoring members "notify_level"'; |
jbe@222 | 2140 |
jbe@222 | 2141 |
jbe@222 | 2142 CREATE VIEW "selected_event_seen_by_member" AS |
jbe@113 | 2143 SELECT |
jbe@113 | 2144 "member"."id" AS "seen_by_member_id", |
jbe@222 | 2145 CASE WHEN "event"."state" IN ( |
jbe@222 | 2146 'voting', |
jbe@222 | 2147 'finished_without_winner', |
jbe@222 | 2148 'finished_with_winner' |
jbe@222 | 2149 ) THEN |
jbe@222 | 2150 'voting'::"notify_level" |
jbe@222 | 2151 ELSE |
jbe@222 | 2152 CASE WHEN "event"."state" IN ( |
jbe@222 | 2153 'verification', |
jbe@222 | 2154 'canceled_after_revocation_during_verification', |
jbe@222 | 2155 'canceled_no_initiative_admitted' |
jbe@222 | 2156 ) THEN |
jbe@222 | 2157 'verification'::"notify_level" |
jbe@222 | 2158 ELSE |
jbe@222 | 2159 CASE WHEN "event"."state" IN ( |
jbe@222 | 2160 'discussion', |
jbe@222 | 2161 'canceled_after_revocation_during_discussion' |
jbe@222 | 2162 ) THEN |
jbe@222 | 2163 'discussion'::"notify_level" |
jbe@222 | 2164 ELSE |
jbe@222 | 2165 'all'::"notify_level" |
jbe@222 | 2166 END |
jbe@222 | 2167 END |
jbe@222 | 2168 END AS "notify_level", |
jbe@113 | 2169 "event".* |
jbe@113 | 2170 FROM "member" CROSS JOIN "event" |
jbe@113 | 2171 LEFT JOIN "issue" |
jbe@113 | 2172 ON "event"."issue_id" = "issue"."id" |
jbe@113 | 2173 LEFT JOIN "membership" |
jbe@113 | 2174 ON "member"."id" = "membership"."member_id" |
jbe@113 | 2175 AND "issue"."area_id" = "membership"."area_id" |
jbe@113 | 2176 LEFT JOIN "interest" |
jbe@113 | 2177 ON "member"."id" = "interest"."member_id" |
jbe@113 | 2178 AND "event"."issue_id" = "interest"."issue_id" |
jbe@113 | 2179 LEFT JOIN "supporter" |
jbe@113 | 2180 ON "member"."id" = "supporter"."member_id" |
jbe@113 | 2181 AND "event"."initiative_id" = "supporter"."initiative_id" |
jbe@113 | 2182 LEFT JOIN "ignored_member" |
jbe@113 | 2183 ON "member"."id" = "ignored_member"."member_id" |
jbe@113 | 2184 AND "event"."member_id" = "ignored_member"."other_member_id" |
jbe@113 | 2185 LEFT JOIN "ignored_initiative" |
jbe@113 | 2186 ON "member"."id" = "ignored_initiative"."member_id" |
jbe@113 | 2187 AND "event"."initiative_id" = "ignored_initiative"."initiative_id" |
jbe@113 | 2188 WHERE ( |
jbe@113 | 2189 ( "member"."notify_level" >= 'all' ) OR |
jbe@113 | 2190 ( "member"."notify_level" >= 'voting' AND |
jbe@113 | 2191 "event"."state" IN ( |
jbe@113 | 2192 'voting', |
jbe@113 | 2193 'finished_without_winner', |
jbe@113 | 2194 'finished_with_winner' ) ) OR |
jbe@113 | 2195 ( "member"."notify_level" >= 'verification' AND |
jbe@113 | 2196 "event"."state" IN ( |
jbe@113 | 2197 'verification', |
jbe@113 | 2198 'canceled_after_revocation_during_verification', |
jbe@113 | 2199 'canceled_no_initiative_admitted' ) ) OR |
jbe@113 | 2200 ( "member"."notify_level" >= 'discussion' AND |
jbe@113 | 2201 "event"."state" IN ( |
jbe@113 | 2202 'discussion', |
jbe@113 | 2203 'canceled_after_revocation_during_discussion' ) ) ) |
jbe@113 | 2204 AND ( |
jbe@113 | 2205 "supporter"."member_id" NOTNULL OR |
jbe@113 | 2206 "interest"."member_id" NOTNULL OR |
jbe@113 | 2207 ( "membership"."member_id" NOTNULL AND |
jbe@113 | 2208 "event"."event" IN ( |
jbe@113 | 2209 'issue_state_changed', |
jbe@113 | 2210 'initiative_created_in_new_issue', |
jbe@113 | 2211 'initiative_created_in_existing_issue', |
jbe@113 | 2212 'initiative_revoked' ) ) ) |
jbe@113 | 2213 AND "ignored_member"."member_id" ISNULL |
jbe@113 | 2214 AND "ignored_initiative"."member_id" ISNULL; |
jbe@113 | 2215 |
jbe@222 | 2216 COMMENT ON VIEW "selected_event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests, support and members "notify_level"'; |
jbe@113 | 2217 |
jbe@113 | 2218 |
jbe@16 | 2219 CREATE TYPE "timeline_event" AS ENUM ( |
jbe@16 | 2220 'issue_created', |
jbe@16 | 2221 'issue_canceled', |
jbe@16 | 2222 'issue_accepted', |
jbe@16 | 2223 'issue_half_frozen', |
jbe@16 | 2224 'issue_finished_without_voting', |
jbe@16 | 2225 'issue_voting_started', |
jbe@16 | 2226 'issue_finished_after_voting', |
jbe@16 | 2227 'initiative_created', |
jbe@16 | 2228 'initiative_revoked', |
jbe@16 | 2229 'draft_created', |
jbe@16 | 2230 'suggestion_created'); |
jbe@16 | 2231 |
jbe@112 | 2232 COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)'; |
jbe@16 | 2233 |
jbe@16 | 2234 |
jbe@16 | 2235 CREATE VIEW "timeline_issue" AS |
jbe@16 | 2236 SELECT |
jbe@16 | 2237 "created" AS "occurrence", |
jbe@16 | 2238 'issue_created'::"timeline_event" AS "event", |
jbe@16 | 2239 "id" AS "issue_id" |
jbe@16 | 2240 FROM "issue" |
jbe@16 | 2241 UNION ALL |
jbe@16 | 2242 SELECT |
jbe@16 | 2243 "closed" AS "occurrence", |
jbe@16 | 2244 'issue_canceled'::"timeline_event" AS "event", |
jbe@16 | 2245 "id" AS "issue_id" |
jbe@16 | 2246 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" ISNULL |
jbe@16 | 2247 UNION ALL |
jbe@16 | 2248 SELECT |
jbe@16 | 2249 "accepted" AS "occurrence", |
jbe@16 | 2250 'issue_accepted'::"timeline_event" AS "event", |
jbe@16 | 2251 "id" AS "issue_id" |
jbe@16 | 2252 FROM "issue" WHERE "accepted" NOTNULL |
jbe@16 | 2253 UNION ALL |
jbe@16 | 2254 SELECT |
jbe@16 | 2255 "half_frozen" AS "occurrence", |
jbe@16 | 2256 'issue_half_frozen'::"timeline_event" AS "event", |
jbe@16 | 2257 "id" AS "issue_id" |
jbe@16 | 2258 FROM "issue" WHERE "half_frozen" NOTNULL |
jbe@16 | 2259 UNION ALL |
jbe@16 | 2260 SELECT |
jbe@16 | 2261 "fully_frozen" AS "occurrence", |
jbe@16 | 2262 'issue_voting_started'::"timeline_event" AS "event", |
jbe@16 | 2263 "id" AS "issue_id" |
jbe@16 | 2264 FROM "issue" |
jbe@17 | 2265 WHERE "fully_frozen" NOTNULL |
jbe@17 | 2266 AND ("closed" ISNULL OR "closed" != "fully_frozen") |
jbe@16 | 2267 UNION ALL |
jbe@16 | 2268 SELECT |
jbe@16 | 2269 "closed" AS "occurrence", |
jbe@16 | 2270 CASE WHEN "fully_frozen" = "closed" THEN |
jbe@16 | 2271 'issue_finished_without_voting'::"timeline_event" |
jbe@16 | 2272 ELSE |
jbe@16 | 2273 'issue_finished_after_voting'::"timeline_event" |
jbe@16 | 2274 END AS "event", |
jbe@16 | 2275 "id" AS "issue_id" |
jbe@16 | 2276 FROM "issue" WHERE "closed" NOTNULL AND "fully_frozen" NOTNULL; |
jbe@16 | 2277 |
jbe@112 | 2278 COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)'; |
jbe@16 | 2279 |
jbe@16 | 2280 |
jbe@16 | 2281 CREATE VIEW "timeline_initiative" AS |
jbe@16 | 2282 SELECT |
jbe@16 | 2283 "created" AS "occurrence", |
jbe@16 | 2284 'initiative_created'::"timeline_event" AS "event", |
jbe@16 | 2285 "id" AS "initiative_id" |
jbe@16 | 2286 FROM "initiative" |
jbe@16 | 2287 UNION ALL |
jbe@16 | 2288 SELECT |
jbe@16 | 2289 "revoked" AS "occurrence", |
jbe@16 | 2290 'initiative_revoked'::"timeline_event" AS "event", |
jbe@16 | 2291 "id" AS "initiative_id" |
jbe@16 | 2292 FROM "initiative" WHERE "revoked" NOTNULL; |
jbe@16 | 2293 |
jbe@112 | 2294 COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)'; |
jbe@16 | 2295 |
jbe@16 | 2296 |
jbe@16 | 2297 CREATE VIEW "timeline_draft" AS |
jbe@16 | 2298 SELECT |
jbe@16 | 2299 "created" AS "occurrence", |
jbe@16 | 2300 'draft_created'::"timeline_event" AS "event", |
jbe@16 | 2301 "id" AS "draft_id" |
jbe@16 | 2302 FROM "draft"; |
jbe@16 | 2303 |
jbe@112 | 2304 COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)'; |
jbe@16 | 2305 |
jbe@16 | 2306 |
jbe@16 | 2307 CREATE VIEW "timeline_suggestion" AS |
jbe@16 | 2308 SELECT |
jbe@16 | 2309 "created" AS "occurrence", |
jbe@16 | 2310 'suggestion_created'::"timeline_event" AS "event", |
jbe@16 | 2311 "id" AS "suggestion_id" |
jbe@16 | 2312 FROM "suggestion"; |
jbe@16 | 2313 |
jbe@112 | 2314 COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)'; |
jbe@16 | 2315 |
jbe@16 | 2316 |
jbe@16 | 2317 CREATE VIEW "timeline" AS |
jbe@16 | 2318 SELECT |
jbe@16 | 2319 "occurrence", |
jbe@16 | 2320 "event", |
jbe@16 | 2321 "issue_id", |
jbe@16 | 2322 NULL AS "initiative_id", |
jbe@16 | 2323 NULL::INT8 AS "draft_id", -- TODO: Why do we need a type-cast here? Is this due to 32 bit architecture? |
jbe@16 | 2324 NULL::INT8 AS "suggestion_id" |
jbe@16 | 2325 FROM "timeline_issue" |
jbe@16 | 2326 UNION ALL |
jbe@16 | 2327 SELECT |
jbe@16 | 2328 "occurrence", |
jbe@16 | 2329 "event", |
jbe@16 | 2330 NULL AS "issue_id", |
jbe@16 | 2331 "initiative_id", |
jbe@16 | 2332 NULL AS "draft_id", |
jbe@16 | 2333 NULL AS "suggestion_id" |
jbe@16 | 2334 FROM "timeline_initiative" |
jbe@16 | 2335 UNION ALL |
jbe@16 | 2336 SELECT |
jbe@16 | 2337 "occurrence", |
jbe@16 | 2338 "event", |
jbe@16 | 2339 NULL AS "issue_id", |
jbe@16 | 2340 NULL AS "initiative_id", |
jbe@16 | 2341 "draft_id", |
jbe@16 | 2342 NULL AS "suggestion_id" |
jbe@16 | 2343 FROM "timeline_draft" |
jbe@16 | 2344 UNION ALL |
jbe@16 | 2345 SELECT |
jbe@16 | 2346 "occurrence", |
jbe@16 | 2347 "event", |
jbe@16 | 2348 NULL AS "issue_id", |
jbe@16 | 2349 NULL AS "initiative_id", |
jbe@16 | 2350 NULL AS "draft_id", |
jbe@16 | 2351 "suggestion_id" |
jbe@16 | 2352 FROM "timeline_suggestion"; |
jbe@16 | 2353 |
jbe@112 | 2354 COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)'; |
jbe@16 | 2355 |
jbe@16 | 2356 |
jbe@0 | 2357 |
jbe@5 | 2358 -------------------------------------------------- |
jbe@5 | 2359 -- Set returning function for delegation chains -- |
jbe@5 | 2360 -------------------------------------------------- |
jbe@5 | 2361 |
jbe@5 | 2362 |
jbe@5 | 2363 CREATE TYPE "delegation_chain_loop_tag" AS ENUM |
jbe@5 | 2364 ('first', 'intermediate', 'last', 'repetition'); |
jbe@5 | 2365 |
jbe@5 | 2366 COMMENT ON TYPE "delegation_chain_loop_tag" IS 'Type for loop tags in "delegation_chain_row" type'; |
jbe@5 | 2367 |
jbe@5 | 2368 |
jbe@5 | 2369 CREATE TYPE "delegation_chain_row" AS ( |
jbe@5 | 2370 "index" INT4, |
jbe@5 | 2371 "member_id" INT4, |
jbe@97 | 2372 "member_valid" BOOLEAN, |
jbe@5 | 2373 "participation" BOOLEAN, |
jbe@5 | 2374 "overridden" BOOLEAN, |
jbe@5 | 2375 "scope_in" "delegation_scope", |
jbe@5 | 2376 "scope_out" "delegation_scope", |
jbe@86 | 2377 "disabled_out" BOOLEAN, |
jbe@5 | 2378 "loop" "delegation_chain_loop_tag" ); |
jbe@5 | 2379 |
jbe@5 | 2380 COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain"(...) functions'; |
jbe@5 | 2381 |
jbe@5 | 2382 COMMENT ON COLUMN "delegation_chain_row"."index" IS 'Index starting with 0 and counting up'; |
jbe@5 | 2383 COMMENT ON COLUMN "delegation_chain_row"."participation" IS 'In case of delegation chains for issues: interest, for areas: membership, for global delegation chains: always null'; |
jbe@5 | 2384 COMMENT ON COLUMN "delegation_chain_row"."overridden" IS 'True, if an entry with lower index has "participation" set to true'; |
jbe@5 | 2385 COMMENT ON COLUMN "delegation_chain_row"."scope_in" IS 'Scope of used incoming delegation'; |
jbe@5 | 2386 COMMENT ON COLUMN "delegation_chain_row"."scope_out" IS 'Scope of used outgoing delegation'; |
jbe@86 | 2387 COMMENT ON COLUMN "delegation_chain_row"."disabled_out" IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL'; |
jbe@5 | 2388 COMMENT ON COLUMN "delegation_chain_row"."loop" IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type'; |
jbe@5 | 2389 |
jbe@5 | 2390 |
jbe@5 | 2391 CREATE FUNCTION "delegation_chain" |
jbe@5 | 2392 ( "member_id_p" "member"."id"%TYPE, |
jbe@97 | 2393 "unit_id_p" "unit"."id"%TYPE, |
jbe@5 | 2394 "area_id_p" "area"."id"%TYPE, |
jbe@5 | 2395 "issue_id_p" "issue"."id"%TYPE, |
jbe@5 | 2396 "simulate_trustee_id_p" "member"."id"%TYPE ) |
jbe@5 | 2397 RETURNS SETOF "delegation_chain_row" |
jbe@5 | 2398 LANGUAGE 'plpgsql' STABLE AS $$ |
jbe@5 | 2399 DECLARE |
jbe@97 | 2400 "scope_v" "delegation_scope"; |
jbe@97 | 2401 "unit_id_v" "unit"."id"%TYPE; |
jbe@97 | 2402 "area_id_v" "area"."id"%TYPE; |
jbe@5 | 2403 "visited_member_ids" INT4[]; -- "member"."id"%TYPE[] |
jbe@5 | 2404 "loop_member_id_v" "member"."id"%TYPE; |
jbe@5 | 2405 "output_row" "delegation_chain_row"; |
jbe@5 | 2406 "output_rows" "delegation_chain_row"[]; |
jbe@5 | 2407 "delegation_row" "delegation"%ROWTYPE; |
jbe@5 | 2408 "row_count" INT4; |
jbe@5 | 2409 "i" INT4; |
jbe@5 | 2410 "loop_v" BOOLEAN; |
jbe@5 | 2411 BEGIN |
jbe@97 | 2412 IF |
jbe@97 | 2413 "unit_id_p" NOTNULL AND |
jbe@97 | 2414 "area_id_p" ISNULL AND |
jbe@97 | 2415 "issue_id_p" ISNULL |
jbe@97 | 2416 THEN |
jbe@97 | 2417 "scope_v" := 'unit'; |
jbe@97 | 2418 "unit_id_v" := "unit_id_p"; |
jbe@97 | 2419 ELSIF |
jbe@97 | 2420 "unit_id_p" ISNULL AND |
jbe@97 | 2421 "area_id_p" NOTNULL AND |
jbe@97 | 2422 "issue_id_p" ISNULL |
jbe@97 | 2423 THEN |
jbe@97 | 2424 "scope_v" := 'area'; |
jbe@97 | 2425 "area_id_v" := "area_id_p"; |
jbe@97 | 2426 SELECT "unit_id" INTO "unit_id_v" |
jbe@97 | 2427 FROM "area" WHERE "id" = "area_id_v"; |
jbe@97 | 2428 ELSIF |
jbe@97 | 2429 "unit_id_p" ISNULL AND |
jbe@97 | 2430 "area_id_p" ISNULL AND |
jbe@97 | 2431 "issue_id_p" NOTNULL |
jbe@97 | 2432 THEN |
jbe@97 | 2433 "scope_v" := 'issue'; |
jbe@97 | 2434 SELECT "area_id" INTO "area_id_v" |
jbe@97 | 2435 FROM "issue" WHERE "id" = "issue_id_p"; |
jbe@97 | 2436 SELECT "unit_id" INTO "unit_id_v" |
jbe@97 | 2437 FROM "area" WHERE "id" = "area_id_v"; |
jbe@97 | 2438 ELSE |
jbe@97 | 2439 RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.'; |
jbe@97 | 2440 END IF; |
jbe@5 | 2441 "visited_member_ids" := '{}'; |
jbe@5 | 2442 "loop_member_id_v" := NULL; |
jbe@5 | 2443 "output_rows" := '{}'; |
jbe@5 | 2444 "output_row"."index" := 0; |
jbe@5 | 2445 "output_row"."member_id" := "member_id_p"; |
jbe@97 | 2446 "output_row"."member_valid" := TRUE; |
jbe@5 | 2447 "output_row"."participation" := FALSE; |
jbe@5 | 2448 "output_row"."overridden" := FALSE; |
jbe@86 | 2449 "output_row"."disabled_out" := FALSE; |
jbe@5 | 2450 "output_row"."scope_out" := NULL; |
jbe@5 | 2451 LOOP |
jbe@5 | 2452 IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN |
jbe@5 | 2453 "loop_member_id_v" := "output_row"."member_id"; |
jbe@5 | 2454 ELSE |
jbe@5 | 2455 "visited_member_ids" := |
jbe@5 | 2456 "visited_member_ids" || "output_row"."member_id"; |
jbe@5 | 2457 END IF; |
jbe@5 | 2458 IF "output_row"."participation" THEN |
jbe@5 | 2459 "output_row"."overridden" := TRUE; |
jbe@5 | 2460 END IF; |
jbe@5 | 2461 "output_row"."scope_in" := "output_row"."scope_out"; |
jbe@5 | 2462 IF EXISTS ( |
jbe@97 | 2463 SELECT NULL FROM "member" JOIN "privilege" |
jbe@97 | 2464 ON "privilege"."member_id" = "member"."id" |
jbe@97 | 2465 AND "privilege"."unit_id" = "unit_id_v" |
jbe@97 | 2466 WHERE "id" = "output_row"."member_id" |
jbe@97 | 2467 AND "member"."active" AND "privilege"."voting_right" |
jbe@5 | 2468 ) THEN |
jbe@97 | 2469 IF "scope_v" = 'unit' THEN |
jbe@5 | 2470 SELECT * INTO "delegation_row" FROM "delegation" |
jbe@5 | 2471 WHERE "truster_id" = "output_row"."member_id" |
jbe@97 | 2472 AND "unit_id" = "unit_id_v"; |
jbe@97 | 2473 ELSIF "scope_v" = 'area' THEN |
jbe@5 | 2474 "output_row"."participation" := EXISTS ( |
jbe@5 | 2475 SELECT NULL FROM "membership" |
jbe@5 | 2476 WHERE "area_id" = "area_id_p" |
jbe@5 | 2477 AND "member_id" = "output_row"."member_id" |
jbe@5 | 2478 ); |
jbe@5 | 2479 SELECT * INTO "delegation_row" FROM "delegation" |
jbe@5 | 2480 WHERE "truster_id" = "output_row"."member_id" |
jbe@97 | 2481 AND ( |
jbe@97 | 2482 "unit_id" = "unit_id_v" OR |
jbe@97 | 2483 "area_id" = "area_id_v" |
jbe@97 | 2484 ) |
jbe@10 | 2485 ORDER BY "scope" DESC; |
jbe@97 | 2486 ELSIF "scope_v" = 'issue' THEN |
jbe@5 | 2487 "output_row"."participation" := EXISTS ( |
jbe@5 | 2488 SELECT NULL FROM "interest" |
jbe@5 | 2489 WHERE "issue_id" = "issue_id_p" |
jbe@5 | 2490 AND "member_id" = "output_row"."member_id" |
jbe@5 | 2491 ); |
jbe@5 | 2492 SELECT * INTO "delegation_row" FROM "delegation" |
jbe@5 | 2493 WHERE "truster_id" = "output_row"."member_id" |
jbe@97 | 2494 AND ( |
jbe@97 | 2495 "unit_id" = "unit_id_v" OR |
jbe@97 | 2496 "area_id" = "area_id_v" OR |
jbe@10 | 2497 "issue_id" = "issue_id_p" |
jbe@10 | 2498 ) |
jbe@10 | 2499 ORDER BY "scope" DESC; |
jbe@5 | 2500 END IF; |
jbe@5 | 2501 ELSE |
jbe@97 | 2502 "output_row"."member_valid" := FALSE; |
jbe@5 | 2503 "output_row"."participation" := FALSE; |
jbe@5 | 2504 "output_row"."scope_out" := NULL; |
jbe@5 | 2505 "delegation_row" := ROW(NULL); |
jbe@5 | 2506 END IF; |
jbe@5 | 2507 IF |
jbe@5 | 2508 "output_row"."member_id" = "member_id_p" AND |
jbe@5 | 2509 "simulate_trustee_id_p" NOTNULL |
jbe@5 | 2510 THEN |
jbe@97 | 2511 "output_row"."scope_out" := "scope_v"; |
jbe@5 | 2512 "output_rows" := "output_rows" || "output_row"; |
jbe@5 | 2513 "output_row"."member_id" := "simulate_trustee_id_p"; |
jbe@5 | 2514 ELSIF "delegation_row"."trustee_id" NOTNULL THEN |
jbe@10 | 2515 "output_row"."scope_out" := "delegation_row"."scope"; |
jbe@5 | 2516 "output_rows" := "output_rows" || "output_row"; |
jbe@5 | 2517 "output_row"."member_id" := "delegation_row"."trustee_id"; |
jbe@86 | 2518 ELSIF "delegation_row"."scope" NOTNULL THEN |
jbe@86 | 2519 "output_row"."scope_out" := "delegation_row"."scope"; |
jbe@86 | 2520 "output_row"."disabled_out" := TRUE; |
jbe@86 | 2521 "output_rows" := "output_rows" || "output_row"; |
jbe@86 | 2522 EXIT; |
jbe@5 | 2523 ELSE |
jbe@5 | 2524 "output_row"."scope_out" := NULL; |
jbe@5 | 2525 "output_rows" := "output_rows" || "output_row"; |
jbe@5 | 2526 EXIT; |
jbe@5 | 2527 END IF; |
jbe@5 | 2528 EXIT WHEN "loop_member_id_v" NOTNULL; |
jbe@5 | 2529 "output_row"."index" := "output_row"."index" + 1; |
jbe@5 | 2530 END LOOP; |
jbe@5 | 2531 "row_count" := array_upper("output_rows", 1); |
jbe@5 | 2532 "i" := 1; |
jbe@5 | 2533 "loop_v" := FALSE; |
jbe@5 | 2534 LOOP |
jbe@5 | 2535 "output_row" := "output_rows"["i"]; |
jbe@98 | 2536 EXIT WHEN "output_row" ISNULL; -- NOTE: ISNULL and NOT ... NOTNULL produce different results! |
jbe@5 | 2537 IF "loop_v" THEN |
jbe@5 | 2538 IF "i" + 1 = "row_count" THEN |
jbe@5 | 2539 "output_row"."loop" := 'last'; |
jbe@5 | 2540 ELSIF "i" = "row_count" THEN |
jbe@5 | 2541 "output_row"."loop" := 'repetition'; |
jbe@5 | 2542 ELSE |
jbe@5 | 2543 "output_row"."loop" := 'intermediate'; |
jbe@5 | 2544 END IF; |
jbe@5 | 2545 ELSIF "output_row"."member_id" = "loop_member_id_v" THEN |
jbe@5 | 2546 "output_row"."loop" := 'first'; |
jbe@5 | 2547 "loop_v" := TRUE; |
jbe@5 | 2548 END IF; |
jbe@97 | 2549 IF "scope_v" = 'unit' THEN |
jbe@5 | 2550 "output_row"."participation" := NULL; |
jbe@5 | 2551 END IF; |
jbe@5 | 2552 RETURN NEXT "output_row"; |
jbe@5 | 2553 "i" := "i" + 1; |
jbe@5 | 2554 END LOOP; |
jbe@5 | 2555 RETURN; |
jbe@5 | 2556 END; |
jbe@5 | 2557 $$; |
jbe@5 | 2558 |
jbe@5 | 2559 COMMENT ON FUNCTION "delegation_chain" |
jbe@5 | 2560 ( "member"."id"%TYPE, |
jbe@97 | 2561 "unit"."id"%TYPE, |
jbe@5 | 2562 "area"."id"%TYPE, |
jbe@5 | 2563 "issue"."id"%TYPE, |
jbe@5 | 2564 "member"."id"%TYPE ) |
jbe@5 | 2565 IS 'Helper function for frontends to display delegation chains; Not part of internal voting logic'; |
jbe@5 | 2566 |
jbe@97 | 2567 |
jbe@5 | 2568 CREATE FUNCTION "delegation_chain" |
jbe@5 | 2569 ( "member_id_p" "member"."id"%TYPE, |
jbe@97 | 2570 "unit_id_p" "unit"."id"%TYPE, |
jbe@5 | 2571 "area_id_p" "area"."id"%TYPE, |
jbe@5 | 2572 "issue_id_p" "issue"."id"%TYPE ) |
jbe@5 | 2573 RETURNS SETOF "delegation_chain_row" |
jbe@5 | 2574 LANGUAGE 'plpgsql' STABLE AS $$ |
jbe@5 | 2575 DECLARE |
jbe@5 | 2576 "result_row" "delegation_chain_row"; |
jbe@5 | 2577 BEGIN |
jbe@5 | 2578 FOR "result_row" IN |
jbe@5 | 2579 SELECT * FROM "delegation_chain"( |
jbe@123 | 2580 "member_id_p", "unit_id_p", "area_id_p", "issue_id_p", NULL |
jbe@5 | 2581 ) |
jbe@5 | 2582 LOOP |
jbe@5 | 2583 RETURN NEXT "result_row"; |
jbe@5 | 2584 END LOOP; |
jbe@5 | 2585 RETURN; |
jbe@5 | 2586 END; |
jbe@5 | 2587 $$; |
jbe@5 | 2588 |
jbe@5 | 2589 COMMENT ON FUNCTION "delegation_chain" |
jbe@5 | 2590 ( "member"."id"%TYPE, |
jbe@97 | 2591 "unit"."id"%TYPE, |
jbe@5 | 2592 "area"."id"%TYPE, |
jbe@5 | 2593 "issue"."id"%TYPE ) |
jbe@5 | 2594 IS 'Shortcut for "delegation_chain"(...) function where 4th parameter is null'; |
jbe@5 | 2595 |
jbe@5 | 2596 |
jbe@5 | 2597 |
jbe@0 | 2598 ------------------------------ |
jbe@0 | 2599 -- Comparison by vote count -- |
jbe@0 | 2600 ------------------------------ |
jbe@0 | 2601 |
jbe@0 | 2602 CREATE FUNCTION "vote_ratio" |
jbe@0 | 2603 ( "positive_votes_p" "initiative"."positive_votes"%TYPE, |
jbe@0 | 2604 "negative_votes_p" "initiative"."negative_votes"%TYPE ) |
jbe@0 | 2605 RETURNS FLOAT8 |
jbe@0 | 2606 LANGUAGE 'plpgsql' STABLE AS $$ |
jbe@0 | 2607 BEGIN |
jbe@30 | 2608 IF "positive_votes_p" > 0 AND "negative_votes_p" > 0 THEN |
jbe@30 | 2609 RETURN |
jbe@30 | 2610 "positive_votes_p"::FLOAT8 / |
jbe@30 | 2611 ("positive_votes_p" + "negative_votes_p")::FLOAT8; |
jbe@30 | 2612 ELSIF "positive_votes_p" > 0 THEN |
jbe@30 | 2613 RETURN "positive_votes_p"; |
jbe@30 | 2614 ELSIF "negative_votes_p" > 0 THEN |
jbe@30 | 2615 RETURN 1 - "negative_votes_p"; |
jbe@0 | 2616 ELSE |
jbe@0 | 2617 RETURN 0.5; |
jbe@0 | 2618 END IF; |
jbe@0 | 2619 END; |
jbe@0 | 2620 $$; |
jbe@0 | 2621 |
jbe@0 | 2622 COMMENT ON FUNCTION "vote_ratio" |
jbe@0 | 2623 ( "initiative"."positive_votes"%TYPE, |
jbe@0 | 2624 "initiative"."negative_votes"%TYPE ) |
jbe@30 | 2625 IS 'Returns a number, which can be used for comparison of initiatives based on count of approvals and disapprovals. Greater numbers indicate a better result. This function is NOT injective.'; |
jbe@0 | 2626 |
jbe@0 | 2627 |
jbe@0 | 2628 |
jbe@0 | 2629 ------------------------------------------------ |
jbe@0 | 2630 -- Locking for snapshots and voting procedure -- |
jbe@0 | 2631 ------------------------------------------------ |
jbe@0 | 2632 |
jbe@67 | 2633 |
jbe@67 | 2634 CREATE FUNCTION "share_row_lock_issue_trigger"() |
jbe@67 | 2635 RETURNS TRIGGER |
jbe@67 | 2636 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@67 | 2637 BEGIN |
jbe@67 | 2638 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN |
jbe@67 | 2639 PERFORM NULL FROM "issue" WHERE "id" = OLD."issue_id" FOR SHARE; |
jbe@67 | 2640 END IF; |
jbe@67 | 2641 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN |
jbe@67 | 2642 PERFORM NULL FROM "issue" WHERE "id" = NEW."issue_id" FOR SHARE; |
jbe@67 | 2643 RETURN NEW; |
jbe@67 | 2644 ELSE |
jbe@67 | 2645 RETURN OLD; |
jbe@67 | 2646 END IF; |
jbe@67 | 2647 END; |
jbe@67 | 2648 $$; |
jbe@67 | 2649 |
jbe@67 | 2650 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of triggers "share_row_lock_issue" on multiple tables'; |
jbe@67 | 2651 |
jbe@67 | 2652 |
jbe@67 | 2653 CREATE FUNCTION "share_row_lock_issue_via_initiative_trigger"() |
jbe@67 | 2654 RETURNS TRIGGER |
jbe@0 | 2655 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 2656 BEGIN |
jbe@67 | 2657 IF TG_OP = 'UPDATE' OR TG_OP = 'DELETE' THEN |
jbe@67 | 2658 PERFORM NULL FROM "issue" |
jbe@67 | 2659 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id" |
jbe@67 | 2660 WHERE "initiative"."id" = OLD."initiative_id" |
jbe@67 | 2661 FOR SHARE OF "issue"; |
jbe@67 | 2662 END IF; |
jbe@67 | 2663 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN |
jbe@67 | 2664 PERFORM NULL FROM "issue" |
jbe@67 | 2665 JOIN "initiative" ON "issue"."id" = "initiative"."issue_id" |
jbe@67 | 2666 WHERE "initiative"."id" = NEW."initiative_id" |
jbe@67 | 2667 FOR SHARE OF "issue"; |
jbe@67 | 2668 RETURN NEW; |
jbe@67 | 2669 ELSE |
jbe@67 | 2670 RETURN OLD; |
jbe@67 | 2671 END IF; |
jbe@67 | 2672 END; |
jbe@67 | 2673 $$; |
jbe@67 | 2674 |
jbe@67 | 2675 COMMENT ON FUNCTION "share_row_lock_issue_trigger"() IS 'Implementation of trigger "share_row_lock_issue_via_initiative" on table "opinion"'; |
jbe@67 | 2676 |
jbe@67 | 2677 |
jbe@67 | 2678 CREATE TRIGGER "share_row_lock_issue" |
jbe@67 | 2679 BEFORE INSERT OR UPDATE OR DELETE ON "initiative" |
jbe@67 | 2680 FOR EACH ROW EXECUTE PROCEDURE |
jbe@67 | 2681 "share_row_lock_issue_trigger"(); |
jbe@67 | 2682 |
jbe@67 | 2683 CREATE TRIGGER "share_row_lock_issue" |
jbe@67 | 2684 BEFORE INSERT OR UPDATE OR DELETE ON "interest" |
jbe@67 | 2685 FOR EACH ROW EXECUTE PROCEDURE |
jbe@67 | 2686 "share_row_lock_issue_trigger"(); |
jbe@67 | 2687 |
jbe@67 | 2688 CREATE TRIGGER "share_row_lock_issue" |
jbe@67 | 2689 BEFORE INSERT OR UPDATE OR DELETE ON "supporter" |
jbe@67 | 2690 FOR EACH ROW EXECUTE PROCEDURE |
jbe@67 | 2691 "share_row_lock_issue_trigger"(); |
jbe@67 | 2692 |
jbe@67 | 2693 CREATE TRIGGER "share_row_lock_issue_via_initiative" |
jbe@67 | 2694 BEFORE INSERT OR UPDATE OR DELETE ON "opinion" |
jbe@67 | 2695 FOR EACH ROW EXECUTE PROCEDURE |
jbe@67 | 2696 "share_row_lock_issue_via_initiative_trigger"(); |
jbe@67 | 2697 |
jbe@67 | 2698 CREATE TRIGGER "share_row_lock_issue" |
jbe@67 | 2699 BEFORE INSERT OR UPDATE OR DELETE ON "direct_voter" |
jbe@67 | 2700 FOR EACH ROW EXECUTE PROCEDURE |
jbe@67 | 2701 "share_row_lock_issue_trigger"(); |
jbe@67 | 2702 |
jbe@67 | 2703 CREATE TRIGGER "share_row_lock_issue" |
jbe@67 | 2704 BEFORE INSERT OR UPDATE OR DELETE ON "delegating_voter" |
jbe@67 | 2705 FOR EACH ROW EXECUTE PROCEDURE |
jbe@67 | 2706 "share_row_lock_issue_trigger"(); |
jbe@67 | 2707 |
jbe@67 | 2708 CREATE TRIGGER "share_row_lock_issue" |
jbe@67 | 2709 BEFORE INSERT OR UPDATE OR DELETE ON "vote" |
jbe@67 | 2710 FOR EACH ROW EXECUTE PROCEDURE |
jbe@67 | 2711 "share_row_lock_issue_trigger"(); |
jbe@67 | 2712 |
jbe@67 | 2713 COMMENT ON TRIGGER "share_row_lock_issue" ON "initiative" IS 'See "lock_issue" function'; |
jbe@67 | 2714 COMMENT ON TRIGGER "share_row_lock_issue" ON "interest" IS 'See "lock_issue" function'; |
jbe@67 | 2715 COMMENT ON TRIGGER "share_row_lock_issue" ON "supporter" IS 'See "lock_issue" function'; |
jbe@67 | 2716 COMMENT ON TRIGGER "share_row_lock_issue_via_initiative" ON "opinion" IS 'See "lock_issue" function'; |
jbe@67 | 2717 COMMENT ON TRIGGER "share_row_lock_issue" ON "direct_voter" IS 'See "lock_issue" function'; |
jbe@67 | 2718 COMMENT ON TRIGGER "share_row_lock_issue" ON "delegating_voter" IS 'See "lock_issue" function'; |
jbe@67 | 2719 COMMENT ON TRIGGER "share_row_lock_issue" ON "vote" IS 'See "lock_issue" function'; |
jbe@67 | 2720 |
jbe@67 | 2721 |
jbe@67 | 2722 CREATE FUNCTION "lock_issue" |
jbe@67 | 2723 ( "issue_id_p" "issue"."id"%TYPE ) |
jbe@67 | 2724 RETURNS VOID |
jbe@67 | 2725 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@67 | 2726 BEGIN |
jbe@67 | 2727 LOCK TABLE "member" IN SHARE MODE; |
jbe@97 | 2728 LOCK TABLE "privilege" IN SHARE MODE; |
jbe@67 | 2729 LOCK TABLE "membership" IN SHARE MODE; |
jbe@67 | 2730 LOCK TABLE "policy" IN SHARE MODE; |
jbe@67 | 2731 PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE; |
jbe@67 | 2732 -- NOTE: The row-level exclusive lock in combination with the |
jbe@67 | 2733 -- share_row_lock_issue(_via_initiative)_trigger functions (which |
jbe@67 | 2734 -- acquire a row-level share lock on the issue) ensure that no data |
jbe@67 | 2735 -- is changed, which could affect calculation of snapshots or |
jbe@67 | 2736 -- counting of votes. Table "delegation" must be table-level-locked, |
jbe@67 | 2737 -- as it also contains issue- and global-scope delegations. |
jbe@67 | 2738 LOCK TABLE "delegation" IN SHARE MODE; |
jbe@0 | 2739 LOCK TABLE "direct_population_snapshot" IN EXCLUSIVE MODE; |
jbe@0 | 2740 LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE; |
jbe@0 | 2741 LOCK TABLE "direct_interest_snapshot" IN EXCLUSIVE MODE; |
jbe@0 | 2742 LOCK TABLE "delegating_interest_snapshot" IN EXCLUSIVE MODE; |
jbe@0 | 2743 LOCK TABLE "direct_supporter_snapshot" IN EXCLUSIVE MODE; |
jbe@0 | 2744 RETURN; |
jbe@0 | 2745 END; |
jbe@0 | 2746 $$; |
jbe@0 | 2747 |
jbe@67 | 2748 COMMENT ON FUNCTION "lock_issue" |
jbe@67 | 2749 ( "issue"."id"%TYPE ) |
jbe@67 | 2750 IS 'Locks the issue and all other data which is used for calculating snapshots or counting votes.'; |
jbe@0 | 2751 |
jbe@0 | 2752 |
jbe@0 | 2753 |
jbe@103 | 2754 ------------------------------------------------------------------------ |
jbe@103 | 2755 -- Regular tasks, except calculcation of snapshots and voting results -- |
jbe@103 | 2756 ------------------------------------------------------------------------ |
jbe@103 | 2757 |
jbe@184 | 2758 CREATE FUNCTION "check_activity"() |
jbe@103 | 2759 RETURNS VOID |
jbe@103 | 2760 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@104 | 2761 DECLARE |
jbe@104 | 2762 "system_setting_row" "system_setting"%ROWTYPE; |
jbe@103 | 2763 BEGIN |
jbe@104 | 2764 SELECT * INTO "system_setting_row" FROM "system_setting"; |
jbe@103 | 2765 LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE; |
jbe@104 | 2766 IF "system_setting_row"."member_ttl" NOTNULL THEN |
jbe@104 | 2767 UPDATE "member" SET "active" = FALSE |
jbe@104 | 2768 WHERE "active" = TRUE |
jbe@184 | 2769 AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE; |
jbe@104 | 2770 END IF; |
jbe@103 | 2771 RETURN; |
jbe@103 | 2772 END; |
jbe@103 | 2773 $$; |
jbe@103 | 2774 |
jbe@184 | 2775 COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".'; |
jbe@103 | 2776 |
jbe@4 | 2777 |
jbe@4 | 2778 CREATE FUNCTION "calculate_member_counts"() |
jbe@4 | 2779 RETURNS VOID |
jbe@4 | 2780 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@4 | 2781 BEGIN |
jbe@67 | 2782 LOCK TABLE "member" IN SHARE MODE; |
jbe@67 | 2783 LOCK TABLE "member_count" IN EXCLUSIVE MODE; |
jbe@97 | 2784 LOCK TABLE "unit" IN EXCLUSIVE MODE; |
jbe@67 | 2785 LOCK TABLE "area" IN EXCLUSIVE MODE; |
jbe@97 | 2786 LOCK TABLE "privilege" IN SHARE MODE; |
jbe@67 | 2787 LOCK TABLE "membership" IN SHARE MODE; |
jbe@4 | 2788 DELETE FROM "member_count"; |
jbe@5 | 2789 INSERT INTO "member_count" ("total_count") |
jbe@5 | 2790 SELECT "total_count" FROM "member_count_view"; |
jbe@97 | 2791 UPDATE "unit" SET "member_count" = "view"."member_count" |
jbe@97 | 2792 FROM "unit_member_count" AS "view" |
jbe@97 | 2793 WHERE "view"."unit_id" = "unit"."id"; |
jbe@5 | 2794 UPDATE "area" SET |
jbe@5 | 2795 "direct_member_count" = "view"."direct_member_count", |
jbe@169 | 2796 "member_weight" = "view"."member_weight" |
jbe@5 | 2797 FROM "area_member_count" AS "view" |
jbe@5 | 2798 WHERE "view"."area_id" = "area"."id"; |
jbe@4 | 2799 RETURN; |
jbe@4 | 2800 END; |
jbe@4 | 2801 $$; |
jbe@4 | 2802 |
jbe@4 | 2803 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 "area_member_count"'; |
jbe@4 | 2804 |
jbe@4 | 2805 |
jbe@4 | 2806 |
jbe@0 | 2807 ------------------------------ |
jbe@0 | 2808 -- Calculation of snapshots -- |
jbe@0 | 2809 ------------------------------ |
jbe@0 | 2810 |
jbe@0 | 2811 CREATE FUNCTION "weight_of_added_delegations_for_population_snapshot" |
jbe@0 | 2812 ( "issue_id_p" "issue"."id"%TYPE, |
jbe@0 | 2813 "member_id_p" "member"."id"%TYPE, |
jbe@0 | 2814 "delegate_member_ids_p" "delegating_population_snapshot"."delegate_member_ids"%TYPE ) |
jbe@0 | 2815 RETURNS "direct_population_snapshot"."weight"%TYPE |
jbe@0 | 2816 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 2817 DECLARE |
jbe@0 | 2818 "issue_delegation_row" "issue_delegation"%ROWTYPE; |
jbe@0 | 2819 "delegate_member_ids_v" "delegating_population_snapshot"."delegate_member_ids"%TYPE; |
jbe@0 | 2820 "weight_v" INT4; |
jbe@8 | 2821 "sub_weight_v" INT4; |
jbe@0 | 2822 BEGIN |
jbe@0 | 2823 "weight_v" := 0; |
jbe@0 | 2824 FOR "issue_delegation_row" IN |
jbe@0 | 2825 SELECT * FROM "issue_delegation" |
jbe@0 | 2826 WHERE "trustee_id" = "member_id_p" |
jbe@0 | 2827 AND "issue_id" = "issue_id_p" |
jbe@0 | 2828 LOOP |
jbe@0 | 2829 IF NOT EXISTS ( |
jbe@0 | 2830 SELECT NULL FROM "direct_population_snapshot" |
jbe@0 | 2831 WHERE "issue_id" = "issue_id_p" |
jbe@0 | 2832 AND "event" = 'periodic' |
jbe@0 | 2833 AND "member_id" = "issue_delegation_row"."truster_id" |
jbe@0 | 2834 ) AND NOT EXISTS ( |
jbe@0 | 2835 SELECT NULL FROM "delegating_population_snapshot" |
jbe@0 | 2836 WHERE "issue_id" = "issue_id_p" |
jbe@0 | 2837 AND "event" = 'periodic' |
jbe@0 | 2838 AND "member_id" = "issue_delegation_row"."truster_id" |
jbe@0 | 2839 ) THEN |
jbe@0 | 2840 "delegate_member_ids_v" := |
jbe@0 | 2841 "member_id_p" || "delegate_member_ids_p"; |
jbe@10 | 2842 INSERT INTO "delegating_population_snapshot" ( |
jbe@10 | 2843 "issue_id", |
jbe@10 | 2844 "event", |
jbe@10 | 2845 "member_id", |
jbe@10 | 2846 "scope", |
jbe@10 | 2847 "delegate_member_ids" |
jbe@10 | 2848 ) VALUES ( |
jbe@0 | 2849 "issue_id_p", |
jbe@0 | 2850 'periodic', |
jbe@0 | 2851 "issue_delegation_row"."truster_id", |
jbe@10 | 2852 "issue_delegation_row"."scope", |
jbe@0 | 2853 "delegate_member_ids_v" |
jbe@0 | 2854 ); |
jbe@8 | 2855 "sub_weight_v" := 1 + |
jbe@0 | 2856 "weight_of_added_delegations_for_population_snapshot"( |
jbe@0 | 2857 "issue_id_p", |
jbe@0 | 2858 "issue_delegation_row"."truster_id", |
jbe@0 | 2859 "delegate_member_ids_v" |
jbe@0 | 2860 ); |
jbe@8 | 2861 UPDATE "delegating_population_snapshot" |
jbe@8 | 2862 SET "weight" = "sub_weight_v" |
jbe@8 | 2863 WHERE "issue_id" = "issue_id_p" |
jbe@8 | 2864 AND "event" = 'periodic' |
jbe@8 | 2865 AND "member_id" = "issue_delegation_row"."truster_id"; |
jbe@8 | 2866 "weight_v" := "weight_v" + "sub_weight_v"; |
jbe@0 | 2867 END IF; |
jbe@0 | 2868 END LOOP; |
jbe@0 | 2869 RETURN "weight_v"; |
jbe@0 | 2870 END; |
jbe@0 | 2871 $$; |
jbe@0 | 2872 |
jbe@0 | 2873 COMMENT ON FUNCTION "weight_of_added_delegations_for_population_snapshot" |
jbe@0 | 2874 ( "issue"."id"%TYPE, |
jbe@0 | 2875 "member"."id"%TYPE, |
jbe@0 | 2876 "delegating_population_snapshot"."delegate_member_ids"%TYPE ) |
jbe@0 | 2877 IS 'Helper function for "create_population_snapshot" function'; |
jbe@0 | 2878 |
jbe@0 | 2879 |
jbe@0 | 2880 CREATE FUNCTION "create_population_snapshot" |
jbe@0 | 2881 ( "issue_id_p" "issue"."id"%TYPE ) |
jbe@0 | 2882 RETURNS VOID |
jbe@0 | 2883 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 2884 DECLARE |
jbe@0 | 2885 "member_id_v" "member"."id"%TYPE; |
jbe@0 | 2886 BEGIN |
jbe@0 | 2887 DELETE FROM "direct_population_snapshot" |
jbe@0 | 2888 WHERE "issue_id" = "issue_id_p" |
jbe@0 | 2889 AND "event" = 'periodic'; |
jbe@0 | 2890 DELETE FROM "delegating_population_snapshot" |
jbe@0 | 2891 WHERE "issue_id" = "issue_id_p" |
jbe@0 | 2892 AND "event" = 'periodic'; |
jbe@0 | 2893 INSERT INTO "direct_population_snapshot" |
jbe@54 | 2894 ("issue_id", "event", "member_id") |
jbe@54 | 2895 SELECT |
jbe@54 | 2896 "issue_id_p" AS "issue_id", |
jbe@54 | 2897 'periodic'::"snapshot_event" AS "event", |
jbe@54 | 2898 "member"."id" AS "member_id" |
jbe@54 | 2899 FROM "issue" |
jbe@54 | 2900 JOIN "area" ON "issue"."area_id" = "area"."id" |
jbe@54 | 2901 JOIN "membership" ON "area"."id" = "membership"."area_id" |
jbe@54 | 2902 JOIN "member" ON "membership"."member_id" = "member"."id" |
jbe@97 | 2903 JOIN "privilege" |
jbe@97 | 2904 ON "privilege"."unit_id" = "area"."unit_id" |
jbe@97 | 2905 AND "privilege"."member_id" = "member"."id" |
jbe@54 | 2906 WHERE "issue"."id" = "issue_id_p" |
jbe@97 | 2907 AND "member"."active" AND "privilege"."voting_right" |
jbe@54 | 2908 UNION |
jbe@54 | 2909 SELECT |
jbe@54 | 2910 "issue_id_p" AS "issue_id", |
jbe@54 | 2911 'periodic'::"snapshot_event" AS "event", |
jbe@54 | 2912 "member"."id" AS "member_id" |
jbe@97 | 2913 FROM "issue" |
jbe@97 | 2914 JOIN "area" ON "issue"."area_id" = "area"."id" |
jbe@97 | 2915 JOIN "interest" ON "issue"."id" = "interest"."issue_id" |
jbe@97 | 2916 JOIN "member" ON "interest"."member_id" = "member"."id" |
jbe@97 | 2917 JOIN "privilege" |
jbe@97 | 2918 ON "privilege"."unit_id" = "area"."unit_id" |
jbe@97 | 2919 AND "privilege"."member_id" = "member"."id" |
jbe@97 | 2920 WHERE "issue"."id" = "issue_id_p" |
jbe@97 | 2921 AND "member"."active" AND "privilege"."voting_right"; |
jbe@0 | 2922 FOR "member_id_v" IN |
jbe@0 | 2923 SELECT "member_id" FROM "direct_population_snapshot" |
jbe@0 | 2924 WHERE "issue_id" = "issue_id_p" |
jbe@0 | 2925 AND "event" = 'periodic' |
jbe@0 | 2926 LOOP |
jbe@0 | 2927 UPDATE "direct_population_snapshot" SET |
jbe@0 | 2928 "weight" = 1 + |
jbe@0 | 2929 "weight_of_added_delegations_for_population_snapshot"( |
jbe@0 | 2930 "issue_id_p", |
jbe@0 | 2931 "member_id_v", |
jbe@0 | 2932 '{}' |
jbe@0 | 2933 ) |
jbe@0 | 2934 WHERE "issue_id" = "issue_id_p" |
jbe@0 | 2935 AND "event" = 'periodic' |
jbe@0 | 2936 AND "member_id" = "member_id_v"; |
jbe@0 | 2937 END LOOP; |
jbe@0 | 2938 RETURN; |
jbe@0 | 2939 END; |
jbe@0 | 2940 $$; |
jbe@0 | 2941 |
jbe@0 | 2942 COMMENT ON FUNCTION "create_population_snapshot" |
jbe@67 | 2943 ( "issue"."id"%TYPE ) |
jbe@0 | 2944 IS 'This function creates a new ''periodic'' population snapshot for the given issue. It does neither lock any tables, nor updates precalculated values in other tables.'; |
jbe@0 | 2945 |
jbe@0 | 2946 |
jbe@0 | 2947 CREATE FUNCTION "weight_of_added_delegations_for_interest_snapshot" |
jbe@0 | 2948 ( "issue_id_p" "issue"."id"%TYPE, |
jbe@0 | 2949 "member_id_p" "member"."id"%TYPE, |
jbe@0 | 2950 "delegate_member_ids_p" "delegating_interest_snapshot"."delegate_member_ids"%TYPE ) |
jbe@0 | 2951 RETURNS "direct_interest_snapshot"."weight"%TYPE |
jbe@0 | 2952 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 2953 DECLARE |
jbe@0 | 2954 "issue_delegation_row" "issue_delegation"%ROWTYPE; |
jbe@0 | 2955 "delegate_member_ids_v" "delegating_interest_snapshot"."delegate_member_ids"%TYPE; |
jbe@0 | 2956 "weight_v" INT4; |
jbe@8 | 2957 "sub_weight_v" INT4; |
jbe@0 | 2958 BEGIN |
jbe@0 | 2959 "weight_v" := 0; |
jbe@0 | 2960 FOR "issue_delegation_row" IN |
jbe@0 | 2961 SELECT * FROM "issue_delegation" |
jbe@0 | 2962 WHERE "trustee_id" = "member_id_p" |
jbe@0 | 2963 AND "issue_id" = "issue_id_p" |
jbe@0 | 2964 LOOP |
jbe@0 | 2965 IF NOT EXISTS ( |
jbe@0 | 2966 SELECT NULL FROM "direct_interest_snapshot" |
jbe@0 | 2967 WHERE "issue_id" = "issue_id_p" |
jbe@0 | 2968 AND "event" = 'periodic' |
jbe@0 | 2969 AND "member_id" = "issue_delegation_row"."truster_id" |
jbe@0 | 2970 ) AND NOT EXISTS ( |
jbe@0 | 2971 SELECT NULL FROM "delegating_interest_snapshot" |
jbe@0 | 2972 WHERE "issue_id" = "issue_id_p" |
jbe@0 | 2973 AND "event" = 'periodic' |
jbe@0 | 2974 AND "member_id" = "issue_delegation_row"."truster_id" |
jbe@0 | 2975 ) THEN |
jbe@0 | 2976 "delegate_member_ids_v" := |
jbe@0 | 2977 "member_id_p" || "delegate_member_ids_p"; |
jbe@10 | 2978 INSERT INTO "delegating_interest_snapshot" ( |
jbe@10 | 2979 "issue_id", |
jbe@10 | 2980 "event", |
jbe@10 | 2981 "member_id", |
jbe@10 | 2982 "scope", |
jbe@10 | 2983 "delegate_member_ids" |
jbe@10 | 2984 ) VALUES ( |
jbe@0 | 2985 "issue_id_p", |
jbe@0 | 2986 'periodic', |
jbe@0 | 2987 "issue_delegation_row"."truster_id", |
jbe@10 | 2988 "issue_delegation_row"."scope", |
jbe@0 | 2989 "delegate_member_ids_v" |
jbe@0 | 2990 ); |
jbe@8 | 2991 "sub_weight_v" := 1 + |
jbe@0 | 2992 "weight_of_added_delegations_for_interest_snapshot"( |
jbe@0 | 2993 "issue_id_p", |
jbe@0 | 2994 "issue_delegation_row"."truster_id", |
jbe@0 | 2995 "delegate_member_ids_v" |
jbe@0 | 2996 ); |
jbe@8 | 2997 UPDATE "delegating_interest_snapshot" |
jbe@8 | 2998 SET "weight" = "sub_weight_v" |
jbe@8 | 2999 WHERE "issue_id" = "issue_id_p" |
jbe@8 | 3000 AND "event" = 'periodic' |
jbe@8 | 3001 AND "member_id" = "issue_delegation_row"."truster_id"; |
jbe@8 | 3002 "weight_v" := "weight_v" + "sub_weight_v"; |
jbe@0 | 3003 END IF; |
jbe@0 | 3004 END LOOP; |
jbe@0 | 3005 RETURN "weight_v"; |
jbe@0 | 3006 END; |
jbe@0 | 3007 $$; |
jbe@0 | 3008 |
jbe@0 | 3009 COMMENT ON FUNCTION "weight_of_added_delegations_for_interest_snapshot" |
jbe@0 | 3010 ( "issue"."id"%TYPE, |
jbe@0 | 3011 "member"."id"%TYPE, |
jbe@0 | 3012 "delegating_interest_snapshot"."delegate_member_ids"%TYPE ) |
jbe@0 | 3013 IS 'Helper function for "create_interest_snapshot" function'; |
jbe@0 | 3014 |
jbe@0 | 3015 |
jbe@0 | 3016 CREATE FUNCTION "create_interest_snapshot" |
jbe@0 | 3017 ( "issue_id_p" "issue"."id"%TYPE ) |
jbe@0 | 3018 RETURNS VOID |
jbe@0 | 3019 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 3020 DECLARE |
jbe@0 | 3021 "member_id_v" "member"."id"%TYPE; |
jbe@0 | 3022 BEGIN |
jbe@0 | 3023 DELETE FROM "direct_interest_snapshot" |
jbe@0 | 3024 WHERE "issue_id" = "issue_id_p" |
jbe@0 | 3025 AND "event" = 'periodic'; |
jbe@0 | 3026 DELETE FROM "delegating_interest_snapshot" |
jbe@0 | 3027 WHERE "issue_id" = "issue_id_p" |
jbe@0 | 3028 AND "event" = 'periodic'; |
jbe@0 | 3029 DELETE FROM "direct_supporter_snapshot" |
jbe@0 | 3030 WHERE "issue_id" = "issue_id_p" |
jbe@0 | 3031 AND "event" = 'periodic'; |
jbe@0 | 3032 INSERT INTO "direct_interest_snapshot" |
jbe@144 | 3033 ("issue_id", "event", "member_id") |
jbe@0 | 3034 SELECT |
jbe@0 | 3035 "issue_id_p" AS "issue_id", |
jbe@0 | 3036 'periodic' AS "event", |
jbe@144 | 3037 "member"."id" AS "member_id" |
jbe@97 | 3038 FROM "issue" |
jbe@97 | 3039 JOIN "area" ON "issue"."area_id" = "area"."id" |
jbe@97 | 3040 JOIN "interest" ON "issue"."id" = "interest"."issue_id" |
jbe@97 | 3041 JOIN "member" ON "interest"."member_id" = "member"."id" |
jbe@97 | 3042 JOIN "privilege" |
jbe@97 | 3043 ON "privilege"."unit_id" = "area"."unit_id" |
jbe@97 | 3044 AND "privilege"."member_id" = "member"."id" |
jbe@97 | 3045 WHERE "issue"."id" = "issue_id_p" |
jbe@97 | 3046 AND "member"."active" AND "privilege"."voting_right"; |
jbe@0 | 3047 FOR "member_id_v" IN |
jbe@0 | 3048 SELECT "member_id" FROM "direct_interest_snapshot" |
jbe@0 | 3049 WHERE "issue_id" = "issue_id_p" |
jbe@0 | 3050 AND "event" = 'periodic' |
jbe@0 | 3051 LOOP |
jbe@0 | 3052 UPDATE "direct_interest_snapshot" SET |
jbe@0 | 3053 "weight" = 1 + |
jbe@0 | 3054 "weight_of_added_delegations_for_interest_snapshot"( |
jbe@0 | 3055 "issue_id_p", |
jbe@0 | 3056 "member_id_v", |
jbe@0 | 3057 '{}' |
jbe@0 | 3058 ) |
jbe@0 | 3059 WHERE "issue_id" = "issue_id_p" |
jbe@0 | 3060 AND "event" = 'periodic' |
jbe@0 | 3061 AND "member_id" = "member_id_v"; |
jbe@0 | 3062 END LOOP; |
jbe@0 | 3063 INSERT INTO "direct_supporter_snapshot" |
jbe@0 | 3064 ( "issue_id", "initiative_id", "event", "member_id", |
jbe@204 | 3065 "draft_id", "informed", "satisfied" ) |
jbe@0 | 3066 SELECT |
jbe@96 | 3067 "issue_id_p" AS "issue_id", |
jbe@96 | 3068 "initiative"."id" AS "initiative_id", |
jbe@96 | 3069 'periodic' AS "event", |
jbe@96 | 3070 "supporter"."member_id" AS "member_id", |
jbe@204 | 3071 "supporter"."draft_id" AS "draft_id", |
jbe@0 | 3072 "supporter"."draft_id" = "current_draft"."id" AS "informed", |
jbe@0 | 3073 NOT EXISTS ( |
jbe@0 | 3074 SELECT NULL FROM "critical_opinion" |
jbe@0 | 3075 WHERE "initiative_id" = "initiative"."id" |
jbe@96 | 3076 AND "member_id" = "supporter"."member_id" |
jbe@0 | 3077 ) AS "satisfied" |
jbe@96 | 3078 FROM "initiative" |
jbe@96 | 3079 JOIN "supporter" |
jbe@0 | 3080 ON "supporter"."initiative_id" = "initiative"."id" |
jbe@0 | 3081 JOIN "current_draft" |
jbe@0 | 3082 ON "initiative"."id" = "current_draft"."initiative_id" |
jbe@0 | 3083 JOIN "direct_interest_snapshot" |
jbe@96 | 3084 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id" |
jbe@0 | 3085 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id" |
jbe@3 | 3086 AND "event" = 'periodic' |
jbe@96 | 3087 WHERE "initiative"."issue_id" = "issue_id_p"; |
jbe@0 | 3088 RETURN; |
jbe@0 | 3089 END; |
jbe@0 | 3090 $$; |
jbe@0 | 3091 |
jbe@0 | 3092 COMMENT ON FUNCTION "create_interest_snapshot" |
jbe@0 | 3093 ( "issue"."id"%TYPE ) |
jbe@0 | 3094 IS 'This function creates a new ''periodic'' interest/supporter snapshot for the given issue. It does neither lock any tables, nor updates precalculated values in other tables.'; |
jbe@0 | 3095 |
jbe@0 | 3096 |
jbe@0 | 3097 CREATE FUNCTION "create_snapshot" |
jbe@0 | 3098 ( "issue_id_p" "issue"."id"%TYPE ) |
jbe@0 | 3099 RETURNS VOID |
jbe@0 | 3100 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 3101 DECLARE |
jbe@0 | 3102 "initiative_id_v" "initiative"."id"%TYPE; |
jbe@0 | 3103 "suggestion_id_v" "suggestion"."id"%TYPE; |
jbe@0 | 3104 BEGIN |
jbe@67 | 3105 PERFORM "lock_issue"("issue_id_p"); |
jbe@0 | 3106 PERFORM "create_population_snapshot"("issue_id_p"); |
jbe@0 | 3107 PERFORM "create_interest_snapshot"("issue_id_p"); |
jbe@0 | 3108 UPDATE "issue" SET |
jbe@8 | 3109 "snapshot" = now(), |
jbe@8 | 3110 "latest_snapshot_event" = 'periodic', |
jbe@0 | 3111 "population" = ( |
jbe@0 | 3112 SELECT coalesce(sum("weight"), 0) |
jbe@0 | 3113 FROM "direct_population_snapshot" |
jbe@0 | 3114 WHERE "issue_id" = "issue_id_p" |
jbe@0 | 3115 AND "event" = 'periodic' |
jbe@0 | 3116 ) |
jbe@0 | 3117 WHERE "id" = "issue_id_p"; |
jbe@0 | 3118 FOR "initiative_id_v" IN |
jbe@0 | 3119 SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p" |
jbe@0 | 3120 LOOP |
jbe@0 | 3121 UPDATE "initiative" SET |
jbe@0 | 3122 "supporter_count" = ( |
jbe@0 | 3123 SELECT coalesce(sum("di"."weight"), 0) |
jbe@0 | 3124 FROM "direct_interest_snapshot" AS "di" |
jbe@0 | 3125 JOIN "direct_supporter_snapshot" AS "ds" |
jbe@0 | 3126 ON "di"."member_id" = "ds"."member_id" |
jbe@0 | 3127 WHERE "di"."issue_id" = "issue_id_p" |
jbe@0 | 3128 AND "di"."event" = 'periodic' |
jbe@0 | 3129 AND "ds"."initiative_id" = "initiative_id_v" |
jbe@0 | 3130 AND "ds"."event" = 'periodic' |
jbe@0 | 3131 ), |
jbe@0 | 3132 "informed_supporter_count" = ( |
jbe@0 | 3133 SELECT coalesce(sum("di"."weight"), 0) |
jbe@0 | 3134 FROM "direct_interest_snapshot" AS "di" |
jbe@0 | 3135 JOIN "direct_supporter_snapshot" AS "ds" |
jbe@0 | 3136 ON "di"."member_id" = "ds"."member_id" |
jbe@0 | 3137 WHERE "di"."issue_id" = "issue_id_p" |
jbe@0 | 3138 AND "di"."event" = 'periodic' |
jbe@0 | 3139 AND "ds"."initiative_id" = "initiative_id_v" |
jbe@0 | 3140 AND "ds"."event" = 'periodic' |
jbe@0 | 3141 AND "ds"."informed" |
jbe@0 | 3142 ), |
jbe@0 | 3143 "satisfied_supporter_count" = ( |
jbe@0 | 3144 SELECT coalesce(sum("di"."weight"), 0) |
jbe@0 | 3145 FROM "direct_interest_snapshot" AS "di" |
jbe@0 | 3146 JOIN "direct_supporter_snapshot" AS "ds" |
jbe@0 | 3147 ON "di"."member_id" = "ds"."member_id" |
jbe@0 | 3148 WHERE "di"."issue_id" = "issue_id_p" |
jbe@0 | 3149 AND "di"."event" = 'periodic' |
jbe@0 | 3150 AND "ds"."initiative_id" = "initiative_id_v" |
jbe@0 | 3151 AND "ds"."event" = 'periodic' |
jbe@0 | 3152 AND "ds"."satisfied" |
jbe@0 | 3153 ), |
jbe@0 | 3154 "satisfied_informed_supporter_count" = ( |
jbe@0 | 3155 SELECT coalesce(sum("di"."weight"), 0) |
jbe@0 | 3156 FROM "direct_interest_snapshot" AS "di" |
jbe@0 | 3157 JOIN "direct_supporter_snapshot" AS "ds" |
jbe@0 | 3158 ON "di"."member_id" = "ds"."member_id" |
jbe@0 | 3159 WHERE "di"."issue_id" = "issue_id_p" |
jbe@0 | 3160 AND "di"."event" = 'periodic' |
jbe@0 | 3161 AND "ds"."initiative_id" = "initiative_id_v" |
jbe@0 | 3162 AND "ds"."event" = 'periodic' |
jbe@0 | 3163 AND "ds"."informed" |
jbe@0 | 3164 AND "ds"."satisfied" |
jbe@0 | 3165 ) |
jbe@0 | 3166 WHERE "id" = "initiative_id_v"; |
jbe@0 | 3167 FOR "suggestion_id_v" IN |
jbe@0 | 3168 SELECT "id" FROM "suggestion" |
jbe@0 | 3169 WHERE "initiative_id" = "initiative_id_v" |
jbe@0 | 3170 LOOP |
jbe@0 | 3171 UPDATE "suggestion" SET |
jbe@0 | 3172 "minus2_unfulfilled_count" = ( |
jbe@0 | 3173 SELECT coalesce(sum("snapshot"."weight"), 0) |
jbe@36 | 3174 FROM "issue" CROSS JOIN "opinion" |
jbe@36 | 3175 JOIN "direct_interest_snapshot" AS "snapshot" |
jbe@36 | 3176 ON "snapshot"."issue_id" = "issue"."id" |
jbe@36 | 3177 AND "snapshot"."event" = "issue"."latest_snapshot_event" |
jbe@36 | 3178 AND "snapshot"."member_id" = "opinion"."member_id" |
jbe@36 | 3179 WHERE "issue"."id" = "issue_id_p" |
jbe@36 | 3180 AND "opinion"."suggestion_id" = "suggestion_id_v" |
jbe@0 | 3181 AND "opinion"."degree" = -2 |
jbe@0 | 3182 AND "opinion"."fulfilled" = FALSE |
jbe@0 | 3183 ), |
jbe@0 | 3184 "minus2_fulfilled_count" = ( |
jbe@0 | 3185 SELECT coalesce(sum("snapshot"."weight"), 0) |
jbe@36 | 3186 FROM "issue" CROSS JOIN "opinion" |
jbe@36 | 3187 JOIN "direct_interest_snapshot" AS "snapshot" |
jbe@36 | 3188 ON "snapshot"."issue_id" = "issue"."id" |
jbe@36 | 3189 AND "snapshot"."event" = "issue"."latest_snapshot_event" |
jbe@36 | 3190 AND "snapshot"."member_id" = "opinion"."member_id" |
jbe@36 | 3191 WHERE "issue"."id" = "issue_id_p" |
jbe@36 | 3192 AND "opinion"."suggestion_id" = "suggestion_id_v" |
jbe@0 | 3193 AND "opinion"."degree" = -2 |
jbe@0 | 3194 AND "opinion"."fulfilled" = TRUE |
jbe@0 | 3195 ), |
jbe@0 | 3196 "minus1_unfulfilled_count" = ( |
jbe@0 | 3197 SELECT coalesce(sum("snapshot"."weight"), 0) |
jbe@36 | 3198 FROM "issue" CROSS JOIN "opinion" |
jbe@36 | 3199 JOIN "direct_interest_snapshot" AS "snapshot" |
jbe@36 | 3200 ON "snapshot"."issue_id" = "issue"."id" |
jbe@36 | 3201 AND "snapshot"."event" = "issue"."latest_snapshot_event" |
jbe@36 | 3202 AND "snapshot"."member_id" = "opinion"."member_id" |
jbe@36 | 3203 WHERE "issue"."id" = "issue_id_p" |
jbe@36 | 3204 AND "opinion"."suggestion_id" = "suggestion_id_v" |
jbe@0 | 3205 AND "opinion"."degree" = -1 |
jbe@0 | 3206 AND "opinion"."fulfilled" = FALSE |
jbe@0 | 3207 ), |
jbe@0 | 3208 "minus1_fulfilled_count" = ( |
jbe@0 | 3209 SELECT coalesce(sum("snapshot"."weight"), 0) |
jbe@36 | 3210 FROM "issue" CROSS JOIN "opinion" |
jbe@36 | 3211 JOIN "direct_interest_snapshot" AS "snapshot" |
jbe@36 | 3212 ON "snapshot"."issue_id" = "issue"."id" |
jbe@36 | 3213 AND "snapshot"."event" = "issue"."latest_snapshot_event" |
jbe@36 | 3214 AND "snapshot"."member_id" = "opinion"."member_id" |
jbe@36 | 3215 WHERE "issue"."id" = "issue_id_p" |
jbe@36 | 3216 AND "opinion"."suggestion_id" = "suggestion_id_v" |
jbe@0 | 3217 AND "opinion"."degree" = -1 |
jbe@0 | 3218 AND "opinion"."fulfilled" = TRUE |
jbe@0 | 3219 ), |
jbe@0 | 3220 "plus1_unfulfilled_count" = ( |
jbe@0 | 3221 SELECT coalesce(sum("snapshot"."weight"), 0) |
jbe@36 | 3222 FROM "issue" CROSS JOIN "opinion" |
jbe@36 | 3223 JOIN "direct_interest_snapshot" AS "snapshot" |
jbe@36 | 3224 ON "snapshot"."issue_id" = "issue"."id" |
jbe@36 | 3225 AND "snapshot"."event" = "issue"."latest_snapshot_event" |
jbe@36 | 3226 AND "snapshot"."member_id" = "opinion"."member_id" |
jbe@36 | 3227 WHERE "issue"."id" = "issue_id_p" |
jbe@36 | 3228 AND "opinion"."suggestion_id" = "suggestion_id_v" |
jbe@0 | 3229 AND "opinion"."degree" = 1 |
jbe@0 | 3230 AND "opinion"."fulfilled" = FALSE |
jbe@0 | 3231 ), |
jbe@0 | 3232 "plus1_fulfilled_count" = ( |
jbe@0 | 3233 SELECT coalesce(sum("snapshot"."weight"), 0) |
jbe@36 | 3234 FROM "issue" CROSS JOIN "opinion" |
jbe@36 | 3235 JOIN "direct_interest_snapshot" AS "snapshot" |
jbe@36 | 3236 ON "snapshot"."issue_id" = "issue"."id" |
jbe@36 | 3237 AND "snapshot"."event" = "issue"."latest_snapshot_event" |
jbe@36 | 3238 AND "snapshot"."member_id" = "opinion"."member_id" |
jbe@36 | 3239 WHERE "issue"."id" = "issue_id_p" |
jbe@36 | 3240 AND "opinion"."suggestion_id" = "suggestion_id_v" |
jbe@0 | 3241 AND "opinion"."degree" = 1 |
jbe@0 | 3242 AND "opinion"."fulfilled" = TRUE |
jbe@0 | 3243 ), |
jbe@0 | 3244 "plus2_unfulfilled_count" = ( |
jbe@0 | 3245 SELECT coalesce(sum("snapshot"."weight"), 0) |
jbe@36 | 3246 FROM "issue" CROSS JOIN "opinion" |
jbe@36 | 3247 JOIN "direct_interest_snapshot" AS "snapshot" |
jbe@36 | 3248 ON "snapshot"."issue_id" = "issue"."id" |
jbe@36 | 3249 AND "snapshot"."event" = "issue"."latest_snapshot_event" |
jbe@36 | 3250 AND "snapshot"."member_id" = "opinion"."member_id" |
jbe@36 | 3251 WHERE "issue"."id" = "issue_id_p" |
jbe@36 | 3252 AND "opinion"."suggestion_id" = "suggestion_id_v" |
jbe@0 | 3253 AND "opinion"."degree" = 2 |
jbe@0 | 3254 AND "opinion"."fulfilled" = FALSE |
jbe@0 | 3255 ), |
jbe@0 | 3256 "plus2_fulfilled_count" = ( |
jbe@0 | 3257 SELECT coalesce(sum("snapshot"."weight"), 0) |
jbe@36 | 3258 FROM "issue" CROSS JOIN "opinion" |
jbe@36 | 3259 JOIN "direct_interest_snapshot" AS "snapshot" |
jbe@36 | 3260 ON "snapshot"."issue_id" = "issue"."id" |
jbe@36 | 3261 AND "snapshot"."event" = "issue"."latest_snapshot_event" |
jbe@36 | 3262 AND "snapshot"."member_id" = "opinion"."member_id" |
jbe@36 | 3263 WHERE "issue"."id" = "issue_id_p" |
jbe@36 | 3264 AND "opinion"."suggestion_id" = "suggestion_id_v" |
jbe@0 | 3265 AND "opinion"."degree" = 2 |
jbe@0 | 3266 AND "opinion"."fulfilled" = TRUE |
jbe@0 | 3267 ) |
jbe@0 | 3268 WHERE "suggestion"."id" = "suggestion_id_v"; |
jbe@0 | 3269 END LOOP; |
jbe@0 | 3270 END LOOP; |
jbe@0 | 3271 RETURN; |
jbe@0 | 3272 END; |
jbe@0 | 3273 $$; |
jbe@0 | 3274 |
jbe@0 | 3275 COMMENT ON FUNCTION "create_snapshot" |
jbe@0 | 3276 ( "issue"."id"%TYPE ) |
jbe@0 | 3277 IS 'This function creates a complete new ''periodic'' snapshot of population, interest and support for the given issue. All involved tables are locked, and after completion precalculated values in the source tables are updated.'; |
jbe@0 | 3278 |
jbe@0 | 3279 |
jbe@0 | 3280 CREATE FUNCTION "set_snapshot_event" |
jbe@0 | 3281 ( "issue_id_p" "issue"."id"%TYPE, |
jbe@0 | 3282 "event_p" "snapshot_event" ) |
jbe@0 | 3283 RETURNS VOID |
jbe@0 | 3284 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@21 | 3285 DECLARE |
jbe@21 | 3286 "event_v" "issue"."latest_snapshot_event"%TYPE; |
jbe@0 | 3287 BEGIN |
jbe@21 | 3288 SELECT "latest_snapshot_event" INTO "event_v" FROM "issue" |
jbe@21 | 3289 WHERE "id" = "issue_id_p" FOR UPDATE; |
jbe@8 | 3290 UPDATE "issue" SET "latest_snapshot_event" = "event_p" |
jbe@8 | 3291 WHERE "id" = "issue_id_p"; |
jbe@3 | 3292 UPDATE "direct_population_snapshot" SET "event" = "event_p" |
jbe@21 | 3293 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v"; |
jbe@3 | 3294 UPDATE "delegating_population_snapshot" SET "event" = "event_p" |
jbe@21 | 3295 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v"; |
jbe@3 | 3296 UPDATE "direct_interest_snapshot" SET "event" = "event_p" |
jbe@21 | 3297 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v"; |
jbe@3 | 3298 UPDATE "delegating_interest_snapshot" SET "event" = "event_p" |
jbe@21 | 3299 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v"; |
jbe@3 | 3300 UPDATE "direct_supporter_snapshot" SET "event" = "event_p" |
jbe@21 | 3301 WHERE "issue_id" = "issue_id_p" AND "event" = "event_v"; |
jbe@0 | 3302 RETURN; |
jbe@0 | 3303 END; |
jbe@0 | 3304 $$; |
jbe@0 | 3305 |
jbe@0 | 3306 COMMENT ON FUNCTION "set_snapshot_event" |
jbe@0 | 3307 ( "issue"."id"%TYPE, |
jbe@0 | 3308 "snapshot_event" ) |
jbe@0 | 3309 IS 'Change "event" attribute of the previous ''periodic'' snapshot'; |
jbe@0 | 3310 |
jbe@0 | 3311 |
jbe@0 | 3312 |
jbe@0 | 3313 --------------------- |
jbe@0 | 3314 -- Freezing issues -- |
jbe@0 | 3315 --------------------- |
jbe@0 | 3316 |
jbe@0 | 3317 CREATE FUNCTION "freeze_after_snapshot" |
jbe@0 | 3318 ( "issue_id_p" "issue"."id"%TYPE ) |
jbe@0 | 3319 RETURNS VOID |
jbe@0 | 3320 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 3321 DECLARE |
jbe@0 | 3322 "issue_row" "issue"%ROWTYPE; |
jbe@0 | 3323 "policy_row" "policy"%ROWTYPE; |
jbe@0 | 3324 "initiative_row" "initiative"%ROWTYPE; |
jbe@0 | 3325 BEGIN |
jbe@0 | 3326 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"; |
jbe@0 | 3327 SELECT * INTO "policy_row" |
jbe@0 | 3328 FROM "policy" WHERE "id" = "issue_row"."policy_id"; |
jbe@21 | 3329 PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze'); |
jbe@0 | 3330 FOR "initiative_row" IN |
jbe@15 | 3331 SELECT * FROM "initiative" |
jbe@15 | 3332 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL |
jbe@0 | 3333 LOOP |
jbe@0 | 3334 IF |
jbe@0 | 3335 "initiative_row"."satisfied_supporter_count" > 0 AND |
jbe@0 | 3336 "initiative_row"."satisfied_supporter_count" * |
jbe@0 | 3337 "policy_row"."initiative_quorum_den" >= |
jbe@0 | 3338 "issue_row"."population" * "policy_row"."initiative_quorum_num" |
jbe@0 | 3339 THEN |
jbe@0 | 3340 UPDATE "initiative" SET "admitted" = TRUE |
jbe@0 | 3341 WHERE "id" = "initiative_row"."id"; |
jbe@0 | 3342 ELSE |
jbe@0 | 3343 UPDATE "initiative" SET "admitted" = FALSE |
jbe@0 | 3344 WHERE "id" = "initiative_row"."id"; |
jbe@0 | 3345 END IF; |
jbe@0 | 3346 END LOOP; |
jbe@113 | 3347 IF EXISTS ( |
jbe@9 | 3348 SELECT NULL FROM "initiative" |
jbe@9 | 3349 WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE |
jbe@9 | 3350 ) THEN |
jbe@113 | 3351 UPDATE "issue" SET |
jbe@113 | 3352 "state" = 'voting', |
jbe@113 | 3353 "accepted" = coalesce("accepted", now()), |
jbe@113 | 3354 "half_frozen" = coalesce("half_frozen", now()), |
jbe@113 | 3355 "fully_frozen" = now() |
jbe@113 | 3356 WHERE "id" = "issue_id_p"; |
jbe@113 | 3357 ELSE |
jbe@113 | 3358 UPDATE "issue" SET |
jbe@121 | 3359 "state" = 'canceled_no_initiative_admitted', |
jbe@121 | 3360 "accepted" = coalesce("accepted", now()), |
jbe@121 | 3361 "half_frozen" = coalesce("half_frozen", now()), |
jbe@121 | 3362 "fully_frozen" = now(), |
jbe@121 | 3363 "closed" = now(), |
jbe@121 | 3364 "ranks_available" = TRUE |
jbe@113 | 3365 WHERE "id" = "issue_id_p"; |
jbe@113 | 3366 -- NOTE: The following DELETE statements have effect only when |
jbe@113 | 3367 -- issue state has been manipulated |
jbe@113 | 3368 DELETE FROM "direct_voter" WHERE "issue_id" = "issue_id_p"; |
jbe@113 | 3369 DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p"; |
jbe@113 | 3370 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p"; |
jbe@9 | 3371 END IF; |
jbe@0 | 3372 RETURN; |
jbe@0 | 3373 END; |
jbe@0 | 3374 $$; |
jbe@0 | 3375 |
jbe@0 | 3376 COMMENT ON FUNCTION "freeze_after_snapshot" |
jbe@0 | 3377 ( "issue"."id"%TYPE ) |
jbe@9 | 3378 IS 'This function freezes an issue (fully) and starts voting, but must only be called when "create_snapshot" was called in the same transaction.'; |
jbe@0 | 3379 |
jbe@0 | 3380 |
jbe@0 | 3381 CREATE FUNCTION "manual_freeze"("issue_id_p" "issue"."id"%TYPE) |
jbe@0 | 3382 RETURNS VOID |
jbe@0 | 3383 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 3384 DECLARE |
jbe@0 | 3385 "issue_row" "issue"%ROWTYPE; |
jbe@0 | 3386 BEGIN |
jbe@0 | 3387 PERFORM "create_snapshot"("issue_id_p"); |
jbe@0 | 3388 PERFORM "freeze_after_snapshot"("issue_id_p"); |
jbe@0 | 3389 RETURN; |
jbe@0 | 3390 END; |
jbe@0 | 3391 $$; |
jbe@0 | 3392 |
jbe@55 | 3393 COMMENT ON FUNCTION "manual_freeze" |
jbe@0 | 3394 ( "issue"."id"%TYPE ) |
jbe@3 | 3395 IS 'Freeze an issue manually (fully) and start voting'; |
jbe@0 | 3396 |
jbe@0 | 3397 |
jbe@0 | 3398 |
jbe@0 | 3399 ----------------------- |
jbe@0 | 3400 -- Counting of votes -- |
jbe@0 | 3401 ----------------------- |
jbe@0 | 3402 |
jbe@0 | 3403 |
jbe@5 | 3404 CREATE FUNCTION "weight_of_added_vote_delegations" |
jbe@0 | 3405 ( "issue_id_p" "issue"."id"%TYPE, |
jbe@0 | 3406 "member_id_p" "member"."id"%TYPE, |
jbe@0 | 3407 "delegate_member_ids_p" "delegating_voter"."delegate_member_ids"%TYPE ) |
jbe@0 | 3408 RETURNS "direct_voter"."weight"%TYPE |
jbe@0 | 3409 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 3410 DECLARE |
jbe@0 | 3411 "issue_delegation_row" "issue_delegation"%ROWTYPE; |
jbe@0 | 3412 "delegate_member_ids_v" "delegating_voter"."delegate_member_ids"%TYPE; |
jbe@0 | 3413 "weight_v" INT4; |
jbe@8 | 3414 "sub_weight_v" INT4; |
jbe@0 | 3415 BEGIN |
jbe@0 | 3416 "weight_v" := 0; |
jbe@0 | 3417 FOR "issue_delegation_row" IN |
jbe@0 | 3418 SELECT * FROM "issue_delegation" |
jbe@0 | 3419 WHERE "trustee_id" = "member_id_p" |
jbe@0 | 3420 AND "issue_id" = "issue_id_p" |
jbe@0 | 3421 LOOP |
jbe@0 | 3422 IF NOT EXISTS ( |
jbe@0 | 3423 SELECT NULL FROM "direct_voter" |
jbe@0 | 3424 WHERE "member_id" = "issue_delegation_row"."truster_id" |
jbe@0 | 3425 AND "issue_id" = "issue_id_p" |
jbe@0 | 3426 ) AND NOT EXISTS ( |
jbe@0 | 3427 SELECT NULL FROM "delegating_voter" |
jbe@0 | 3428 WHERE "member_id" = "issue_delegation_row"."truster_id" |
jbe@0 | 3429 AND "issue_id" = "issue_id_p" |
jbe@0 | 3430 ) THEN |
jbe@0 | 3431 "delegate_member_ids_v" := |
jbe@0 | 3432 "member_id_p" || "delegate_member_ids_p"; |
jbe@10 | 3433 INSERT INTO "delegating_voter" ( |
jbe@10 | 3434 "issue_id", |
jbe@10 | 3435 "member_id", |
jbe@10 | 3436 "scope", |
jbe@10 | 3437 "delegate_member_ids" |
jbe@10 | 3438 ) VALUES ( |
jbe@5 | 3439 "issue_id_p", |
jbe@5 | 3440 "issue_delegation_row"."truster_id", |
jbe@10 | 3441 "issue_delegation_row"."scope", |
jbe@5 | 3442 "delegate_member_ids_v" |
jbe@5 | 3443 ); |
jbe@8 | 3444 "sub_weight_v" := 1 + |
jbe@8 | 3445 "weight_of_added_vote_delegations"( |
jbe@8 | 3446 "issue_id_p", |
jbe@8 | 3447 "issue_delegation_row"."truster_id", |
jbe@8 | 3448 "delegate_member_ids_v" |
jbe@8 | 3449 ); |
jbe@8 | 3450 UPDATE "delegating_voter" |
jbe@8 | 3451 SET "weight" = "sub_weight_v" |
jbe@8 | 3452 WHERE "issue_id" = "issue_id_p" |
jbe@8 | 3453 AND "member_id" = "issue_delegation_row"."truster_id"; |
jbe@8 | 3454 "weight_v" := "weight_v" + "sub_weight_v"; |
jbe@0 | 3455 END IF; |
jbe@0 | 3456 END LOOP; |
jbe@0 | 3457 RETURN "weight_v"; |
jbe@0 | 3458 END; |
jbe@0 | 3459 $$; |
jbe@0 | 3460 |
jbe@5 | 3461 COMMENT ON FUNCTION "weight_of_added_vote_delegations" |
jbe@0 | 3462 ( "issue"."id"%TYPE, |
jbe@0 | 3463 "member"."id"%TYPE, |
jbe@0 | 3464 "delegating_voter"."delegate_member_ids"%TYPE ) |
jbe@0 | 3465 IS 'Helper function for "add_vote_delegations" function'; |
jbe@0 | 3466 |
jbe@0 | 3467 |
jbe@0 | 3468 CREATE FUNCTION "add_vote_delegations" |
jbe@0 | 3469 ( "issue_id_p" "issue"."id"%TYPE ) |
jbe@0 | 3470 RETURNS VOID |
jbe@0 | 3471 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 3472 DECLARE |
jbe@0 | 3473 "member_id_v" "member"."id"%TYPE; |
jbe@0 | 3474 BEGIN |
jbe@0 | 3475 FOR "member_id_v" IN |
jbe@0 | 3476 SELECT "member_id" FROM "direct_voter" |
jbe@0 | 3477 WHERE "issue_id" = "issue_id_p" |
jbe@0 | 3478 LOOP |
jbe@0 | 3479 UPDATE "direct_voter" SET |
jbe@5 | 3480 "weight" = "weight" + "weight_of_added_vote_delegations"( |
jbe@0 | 3481 "issue_id_p", |
jbe@0 | 3482 "member_id_v", |
jbe@0 | 3483 '{}' |
jbe@0 | 3484 ) |
jbe@0 | 3485 WHERE "member_id" = "member_id_v" |
jbe@0 | 3486 AND "issue_id" = "issue_id_p"; |
jbe@0 | 3487 END LOOP; |
jbe@0 | 3488 RETURN; |
jbe@0 | 3489 END; |
jbe@0 | 3490 $$; |
jbe@0 | 3491 |
jbe@0 | 3492 COMMENT ON FUNCTION "add_vote_delegations" |
jbe@0 | 3493 ( "issue_id_p" "issue"."id"%TYPE ) |
jbe@0 | 3494 IS 'Helper function for "close_voting" function'; |
jbe@0 | 3495 |
jbe@0 | 3496 |
jbe@0 | 3497 CREATE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE) |
jbe@0 | 3498 RETURNS VOID |
jbe@0 | 3499 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 3500 DECLARE |
jbe@97 | 3501 "area_id_v" "area"."id"%TYPE; |
jbe@97 | 3502 "unit_id_v" "unit"."id"%TYPE; |
jbe@0 | 3503 "member_id_v" "member"."id"%TYPE; |
jbe@0 | 3504 BEGIN |
jbe@67 | 3505 PERFORM "lock_issue"("issue_id_p"); |
jbe@129 | 3506 SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p"; |
jbe@129 | 3507 SELECT "unit_id" INTO "unit_id_v" FROM "area" WHERE "id" = "area_id_v"; |
jbe@169 | 3508 -- delete delegating votes (in cases of manual reset of issue state): |
jbe@0 | 3509 DELETE FROM "delegating_voter" |
jbe@0 | 3510 WHERE "issue_id" = "issue_id_p"; |
jbe@169 | 3511 -- delete votes from non-privileged voters: |
jbe@97 | 3512 DELETE FROM "direct_voter" |
jbe@97 | 3513 USING ( |
jbe@97 | 3514 SELECT |
jbe@97 | 3515 "direct_voter"."member_id" |
jbe@97 | 3516 FROM "direct_voter" |
jbe@97 | 3517 JOIN "member" ON "direct_voter"."member_id" = "member"."id" |
jbe@97 | 3518 LEFT JOIN "privilege" |
jbe@97 | 3519 ON "privilege"."unit_id" = "unit_id_v" |
jbe@97 | 3520 AND "privilege"."member_id" = "direct_voter"."member_id" |
jbe@97 | 3521 WHERE "direct_voter"."issue_id" = "issue_id_p" AND ( |
jbe@97 | 3522 "member"."active" = FALSE OR |
jbe@97 | 3523 "privilege"."voting_right" ISNULL OR |
jbe@97 | 3524 "privilege"."voting_right" = FALSE |
jbe@97 | 3525 ) |
jbe@97 | 3526 ) AS "subquery" |
jbe@97 | 3527 WHERE "direct_voter"."issue_id" = "issue_id_p" |
jbe@97 | 3528 AND "direct_voter"."member_id" = "subquery"."member_id"; |
jbe@169 | 3529 -- consider delegations: |
jbe@0 | 3530 UPDATE "direct_voter" SET "weight" = 1 |
jbe@0 | 3531 WHERE "issue_id" = "issue_id_p"; |
jbe@0 | 3532 PERFORM "add_vote_delegations"("issue_id_p"); |
jbe@137 | 3533 -- set voter count and mark issue as being calculated: |
jbe@4 | 3534 UPDATE "issue" SET |
jbe@111 | 3535 "state" = 'calculation', |
jbe@61 | 3536 "closed" = now(), |
jbe@4 | 3537 "voter_count" = ( |
jbe@4 | 3538 SELECT coalesce(sum("weight"), 0) |
jbe@4 | 3539 FROM "direct_voter" WHERE "issue_id" = "issue_id_p" |
jbe@6 | 3540 ) |
jbe@6 | 3541 WHERE "id" = "issue_id_p"; |
jbe@137 | 3542 -- materialize battle_view: |
jbe@61 | 3543 -- NOTE: "closed" column of issue must be set at this point |
jbe@61 | 3544 DELETE FROM "battle" WHERE "issue_id" = "issue_id_p"; |
jbe@61 | 3545 INSERT INTO "battle" ( |
jbe@61 | 3546 "issue_id", |
jbe@61 | 3547 "winning_initiative_id", "losing_initiative_id", |
jbe@61 | 3548 "count" |
jbe@61 | 3549 ) SELECT |
jbe@61 | 3550 "issue_id", |
jbe@61 | 3551 "winning_initiative_id", "losing_initiative_id", |
jbe@61 | 3552 "count" |
jbe@61 | 3553 FROM "battle_view" WHERE "issue_id" = "issue_id_p"; |
jbe@155 | 3554 -- copy "positive_votes" and "negative_votes" from "battle" table: |
jbe@155 | 3555 UPDATE "initiative" SET |
jbe@155 | 3556 "positive_votes" = "battle_win"."count", |
jbe@155 | 3557 "negative_votes" = "battle_lose"."count" |
jbe@155 | 3558 FROM "battle" AS "battle_win", "battle" AS "battle_lose" |
jbe@155 | 3559 WHERE |
jbe@155 | 3560 "battle_win"."issue_id" = "issue_id_p" AND |
jbe@155 | 3561 "battle_win"."winning_initiative_id" = "initiative"."id" AND |
jbe@155 | 3562 "battle_win"."losing_initiative_id" ISNULL AND |
jbe@155 | 3563 "battle_lose"."issue_id" = "issue_id_p" AND |
jbe@155 | 3564 "battle_lose"."losing_initiative_id" = "initiative"."id" AND |
jbe@155 | 3565 "battle_lose"."winning_initiative_id" ISNULL; |
jbe@0 | 3566 END; |
jbe@0 | 3567 $$; |
jbe@0 | 3568 |
jbe@0 | 3569 COMMENT ON FUNCTION "close_voting" |
jbe@0 | 3570 ( "issue"."id"%TYPE ) |
jbe@0 | 3571 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.'; |
jbe@0 | 3572 |
jbe@0 | 3573 |
jbe@30 | 3574 CREATE FUNCTION "defeat_strength" |
jbe@30 | 3575 ( "positive_votes_p" INT4, "negative_votes_p" INT4 ) |
jbe@30 | 3576 RETURNS INT8 |
jbe@30 | 3577 LANGUAGE 'plpgsql' IMMUTABLE AS $$ |
jbe@30 | 3578 BEGIN |
jbe@30 | 3579 IF "positive_votes_p" > "negative_votes_p" THEN |
jbe@30 | 3580 RETURN ("positive_votes_p"::INT8 << 31) - "negative_votes_p"::INT8; |
jbe@30 | 3581 ELSIF "positive_votes_p" = "negative_votes_p" THEN |
jbe@30 | 3582 RETURN 0; |
jbe@30 | 3583 ELSE |
jbe@30 | 3584 RETURN -1; |
jbe@30 | 3585 END IF; |
jbe@30 | 3586 END; |
jbe@30 | 3587 $$; |
jbe@30 | 3588 |
jbe@30 | 3589 COMMENT ON FUNCTION "defeat_strength"(INT4, INT4) IS 'Calculates defeat strength (INT8!) of a pairwise defeat primarily by the absolute number of votes for the winner and secondarily by the absolute number of votes for the loser'; |
jbe@30 | 3590 |
jbe@30 | 3591 |
jbe@0 | 3592 CREATE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE) |
jbe@0 | 3593 RETURNS VOID |
jbe@0 | 3594 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 3595 DECLARE |
jbe@155 | 3596 "issue_row" "issue"%ROWTYPE; |
jbe@155 | 3597 "policy_row" "policy"%ROWTYPE; |
jbe@134 | 3598 "dimension_v" INTEGER; |
jbe@134 | 3599 "vote_matrix" INT4[][]; -- absolute votes |
jbe@134 | 3600 "matrix" INT8[][]; -- defeat strength / best paths |
jbe@134 | 3601 "i" INTEGER; |
jbe@134 | 3602 "j" INTEGER; |
jbe@134 | 3603 "k" INTEGER; |
jbe@134 | 3604 "battle_row" "battle"%ROWTYPE; |
jbe@134 | 3605 "rank_ary" INT4[]; |
jbe@134 | 3606 "rank_v" INT4; |
jbe@134 | 3607 "done_v" INTEGER; |
jbe@134 | 3608 "winners_ary" INTEGER[]; |
jbe@134 | 3609 "initiative_id_v" "initiative"."id"%TYPE; |
jbe@0 | 3610 BEGIN |
jbe@155 | 3611 SELECT * INTO "issue_row" |
jbe@155 | 3612 FROM "issue" WHERE "id" = "issue_id_p" |
jbe@155 | 3613 FOR UPDATE; |
jbe@155 | 3614 SELECT * INTO "policy_row" |
jbe@155 | 3615 FROM "policy" WHERE "id" = "issue_row"."policy_id"; |
jbe@126 | 3616 SELECT count(1) INTO "dimension_v" |
jbe@126 | 3617 FROM "battle_participant" WHERE "issue_id" = "issue_id_p"; |
jbe@170 | 3618 -- Create "vote_matrix" with absolute number of votes in pairwise |
jbe@170 | 3619 -- comparison: |
jbe@170 | 3620 "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]); |
jbe@170 | 3621 "i" := 1; |
jbe@170 | 3622 "j" := 2; |
jbe@170 | 3623 FOR "battle_row" IN |
jbe@170 | 3624 SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p" |
jbe@170 | 3625 ORDER BY |
jbe@170 | 3626 "winning_initiative_id" NULLS LAST, |
jbe@170 | 3627 "losing_initiative_id" NULLS LAST |
jbe@170 | 3628 LOOP |
jbe@170 | 3629 "vote_matrix"["i"]["j"] := "battle_row"."count"; |
jbe@170 | 3630 IF "j" = "dimension_v" THEN |
jbe@170 | 3631 "i" := "i" + 1; |
jbe@170 | 3632 "j" := 1; |
jbe@170 | 3633 ELSE |
jbe@170 | 3634 "j" := "j" + 1; |
jbe@170 | 3635 IF "j" = "i" THEN |
jbe@170 | 3636 "j" := "j" + 1; |
jbe@170 | 3637 END IF; |
jbe@170 | 3638 END IF; |
jbe@170 | 3639 END LOOP; |
jbe@170 | 3640 IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN |
jbe@170 | 3641 RAISE EXCEPTION 'Wrong battle count (should not happen)'; |
jbe@170 | 3642 END IF; |
jbe@170 | 3643 -- Store defeat strengths in "matrix" using "defeat_strength" |
jbe@170 | 3644 -- function: |
jbe@170 | 3645 "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]); |
jbe@170 | 3646 "i" := 1; |
jbe@170 | 3647 LOOP |
jbe@170 | 3648 "j" := 1; |
jbe@0 | 3649 LOOP |
jbe@170 | 3650 IF "i" != "j" THEN |
jbe@170 | 3651 "matrix"["i"]["j"] := "defeat_strength"( |
jbe@170 | 3652 "vote_matrix"["i"]["j"], |
jbe@170 | 3653 "vote_matrix"["j"]["i"] |
jbe@170 | 3654 ); |
jbe@0 | 3655 END IF; |
jbe@170 | 3656 EXIT WHEN "j" = "dimension_v"; |
jbe@170 | 3657 "j" := "j" + 1; |
jbe@0 | 3658 END LOOP; |
jbe@170 | 3659 EXIT WHEN "i" = "dimension_v"; |
jbe@170 | 3660 "i" := "i" + 1; |
jbe@170 | 3661 END LOOP; |
jbe@170 | 3662 -- Find best paths: |
jbe@170 | 3663 "i" := 1; |
jbe@170 | 3664 LOOP |
jbe@170 | 3665 "j" := 1; |
jbe@170 | 3666 LOOP |
jbe@170 | 3667 IF "i" != "j" THEN |
jbe@170 | 3668 "k" := 1; |
jbe@170 | 3669 LOOP |
jbe@170 | 3670 IF "i" != "k" AND "j" != "k" THEN |
jbe@170 | 3671 IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN |
jbe@170 | 3672 IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN |
jbe@170 | 3673 "matrix"["j"]["k"] := "matrix"["j"]["i"]; |
jbe@170 | 3674 END IF; |
jbe@170 | 3675 ELSE |
jbe@170 | 3676 IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN |
jbe@170 | 3677 "matrix"["j"]["k"] := "matrix"["i"]["k"]; |
jbe@170 | 3678 END IF; |
jbe@170 | 3679 END IF; |
jbe@170 | 3680 END IF; |
jbe@170 | 3681 EXIT WHEN "k" = "dimension_v"; |
jbe@170 | 3682 "k" := "k" + 1; |
jbe@170 | 3683 END LOOP; |
jbe@170 | 3684 END IF; |
jbe@170 | 3685 EXIT WHEN "j" = "dimension_v"; |
jbe@170 | 3686 "j" := "j" + 1; |
jbe@170 | 3687 END LOOP; |
jbe@170 | 3688 EXIT WHEN "i" = "dimension_v"; |
jbe@170 | 3689 "i" := "i" + 1; |
jbe@170 | 3690 END LOOP; |
jbe@170 | 3691 -- Determine order of winners: |
jbe@170 | 3692 "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]); |
jbe@170 | 3693 "rank_v" := 1; |
jbe@170 | 3694 "done_v" := 0; |
jbe@170 | 3695 LOOP |
jbe@170 | 3696 "winners_ary" := '{}'; |
jbe@0 | 3697 "i" := 1; |
jbe@0 | 3698 LOOP |
jbe@170 | 3699 IF "rank_ary"["i"] ISNULL THEN |
jbe@170 | 3700 "j" := 1; |
jbe@170 | 3701 LOOP |
jbe@170 | 3702 IF |
jbe@170 | 3703 "i" != "j" AND |
jbe@170 | 3704 "rank_ary"["j"] ISNULL AND |
jbe@170 | 3705 "matrix"["j"]["i"] > "matrix"["i"]["j"] |
jbe@170 | 3706 THEN |
jbe@170 | 3707 -- someone else is better |
jbe@170 | 3708 EXIT; |
jbe@170 | 3709 END IF; |
jbe@170 | 3710 IF "j" = "dimension_v" THEN |
jbe@170 | 3711 -- noone is better |
jbe@170 | 3712 "winners_ary" := "winners_ary" || "i"; |
jbe@170 | 3713 EXIT; |
jbe@170 | 3714 END IF; |
jbe@170 | 3715 "j" := "j" + 1; |
jbe@170 | 3716 END LOOP; |
jbe@170 | 3717 END IF; |
jbe@30 | 3718 EXIT WHEN "i" = "dimension_v"; |
jbe@0 | 3719 "i" := "i" + 1; |
jbe@0 | 3720 END LOOP; |
jbe@0 | 3721 "i" := 1; |
jbe@0 | 3722 LOOP |
jbe@170 | 3723 "rank_ary"["winners_ary"["i"]] := "rank_v"; |
jbe@170 | 3724 "done_v" := "done_v" + 1; |
jbe@170 | 3725 EXIT WHEN "i" = array_upper("winners_ary", 1); |
jbe@0 | 3726 "i" := "i" + 1; |
jbe@0 | 3727 END LOOP; |
jbe@170 | 3728 EXIT WHEN "done_v" = "dimension_v"; |
jbe@170 | 3729 "rank_v" := "rank_v" + 1; |
jbe@170 | 3730 END LOOP; |
jbe@170 | 3731 -- write preliminary results: |
jbe@170 | 3732 "i" := 1; |
jbe@170 | 3733 FOR "initiative_id_v" IN |
jbe@170 | 3734 SELECT "id" FROM "initiative" |
jbe@170 | 3735 WHERE "issue_id" = "issue_id_p" AND "admitted" |
jbe@170 | 3736 ORDER BY "id" |
jbe@170 | 3737 LOOP |
jbe@170 | 3738 UPDATE "initiative" SET |
jbe@170 | 3739 "direct_majority" = |
jbe@170 | 3740 CASE WHEN "policy_row"."direct_majority_strict" THEN |
jbe@170 | 3741 "positive_votes" * "policy_row"."direct_majority_den" > |
jbe@170 | 3742 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes") |
jbe@170 | 3743 ELSE |
jbe@170 | 3744 "positive_votes" * "policy_row"."direct_majority_den" >= |
jbe@170 | 3745 "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes") |
jbe@170 | 3746 END |
jbe@170 | 3747 AND "positive_votes" >= "policy_row"."direct_majority_positive" |
jbe@170 | 3748 AND "issue_row"."voter_count"-"negative_votes" >= |
jbe@170 | 3749 "policy_row"."direct_majority_non_negative", |
jbe@170 | 3750 "indirect_majority" = |
jbe@170 | 3751 CASE WHEN "policy_row"."indirect_majority_strict" THEN |
jbe@170 | 3752 "positive_votes" * "policy_row"."indirect_majority_den" > |
jbe@170 | 3753 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes") |
jbe@170 | 3754 ELSE |
jbe@170 | 3755 "positive_votes" * "policy_row"."indirect_majority_den" >= |
jbe@170 | 3756 "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes") |
jbe@170 | 3757 END |
jbe@170 | 3758 AND "positive_votes" >= "policy_row"."indirect_majority_positive" |
jbe@170 | 3759 AND "issue_row"."voter_count"-"negative_votes" >= |
jbe@170 | 3760 "policy_row"."indirect_majority_non_negative", |
jbe@171 | 3761 "schulze_rank" = "rank_ary"["i"], |
jbe@170 | 3762 "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"], |
jbe@170 | 3763 "worse_than_status_quo" = "rank_ary"["i"] > "rank_ary"["dimension_v"], |
jbe@170 | 3764 "multistage_majority" = "rank_ary"["i"] >= "rank_ary"["dimension_v"], |
jbe@172 | 3765 "reverse_beat_path" = "matrix"["dimension_v"]["i"] >= 0, |
jbe@216 | 3766 "eligible" = FALSE, |
jbe@172 | 3767 "winner" = FALSE |
jbe@170 | 3768 WHERE "id" = "initiative_id_v"; |
jbe@170 | 3769 "i" := "i" + 1; |
jbe@170 | 3770 END LOOP; |
jbe@170 | 3771 IF "i" != "dimension_v" THEN |
jbe@170 | 3772 RAISE EXCEPTION 'Wrong winner count (should not happen)'; |
jbe@0 | 3773 END IF; |
jbe@170 | 3774 -- take indirect majorities into account: |
jbe@170 | 3775 LOOP |
jbe@170 | 3776 UPDATE "initiative" SET "indirect_majority" = TRUE |
jbe@139 | 3777 FROM ( |
jbe@170 | 3778 SELECT "new_initiative"."id" AS "initiative_id" |
jbe@170 | 3779 FROM "initiative" "old_initiative" |
jbe@170 | 3780 JOIN "initiative" "new_initiative" |
jbe@170 | 3781 ON "new_initiative"."issue_id" = "issue_id_p" |
jbe@170 | 3782 AND "new_initiative"."indirect_majority" = FALSE |
jbe@139 | 3783 JOIN "battle" "battle_win" |
jbe@139 | 3784 ON "battle_win"."issue_id" = "issue_id_p" |
jbe@170 | 3785 AND "battle_win"."winning_initiative_id" = "new_initiative"."id" |
jbe@170 | 3786 AND "battle_win"."losing_initiative_id" = "old_initiative"."id" |
jbe@139 | 3787 JOIN "battle" "battle_lose" |
jbe@139 | 3788 ON "battle_lose"."issue_id" = "issue_id_p" |
jbe@170 | 3789 AND "battle_lose"."losing_initiative_id" = "new_initiative"."id" |
jbe@170 | 3790 AND "battle_lose"."winning_initiative_id" = "old_initiative"."id" |
jbe@170 | 3791 WHERE "old_initiative"."issue_id" = "issue_id_p" |
jbe@170 | 3792 AND "old_initiative"."indirect_majority" = TRUE |
jbe@170 | 3793 AND CASE WHEN "policy_row"."indirect_majority_strict" THEN |
jbe@170 | 3794 "battle_win"."count" * "policy_row"."indirect_majority_den" > |
jbe@170 | 3795 "policy_row"."indirect_majority_num" * |
jbe@170 | 3796 ("battle_win"."count"+"battle_lose"."count") |
jbe@170 | 3797 ELSE |
jbe@170 | 3798 "battle_win"."count" * "policy_row"."indirect_majority_den" >= |
jbe@170 | 3799 "policy_row"."indirect_majority_num" * |
jbe@170 | 3800 ("battle_win"."count"+"battle_lose"."count") |
jbe@170 | 3801 END |
jbe@170 | 3802 AND "battle_win"."count" >= "policy_row"."indirect_majority_positive" |
jbe@170 | 3803 AND "issue_row"."voter_count"-"battle_lose"."count" >= |
jbe@170 | 3804 "policy_row"."indirect_majority_non_negative" |
jbe@139 | 3805 ) AS "subquery" |
jbe@139 | 3806 WHERE "id" = "subquery"."initiative_id"; |
jbe@170 | 3807 EXIT WHEN NOT FOUND; |
jbe@170 | 3808 END LOOP; |
jbe@170 | 3809 -- set "multistage_majority" for remaining matching initiatives: |
jbe@216 | 3810 UPDATE "initiative" SET "multistage_majority" = TRUE |
jbe@170 | 3811 FROM ( |
jbe@170 | 3812 SELECT "losing_initiative"."id" AS "initiative_id" |
jbe@170 | 3813 FROM "initiative" "losing_initiative" |
jbe@170 | 3814 JOIN "initiative" "winning_initiative" |
jbe@170 | 3815 ON "winning_initiative"."issue_id" = "issue_id_p" |
jbe@170 | 3816 AND "winning_initiative"."admitted" |
jbe@170 | 3817 JOIN "battle" "battle_win" |
jbe@170 | 3818 ON "battle_win"."issue_id" = "issue_id_p" |
jbe@170 | 3819 AND "battle_win"."winning_initiative_id" = "winning_initiative"."id" |
jbe@170 | 3820 AND "battle_win"."losing_initiative_id" = "losing_initiative"."id" |
jbe@170 | 3821 JOIN "battle" "battle_lose" |
jbe@170 | 3822 ON "battle_lose"."issue_id" = "issue_id_p" |
jbe@170 | 3823 AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id" |
jbe@170 | 3824 AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id" |
jbe@170 | 3825 WHERE "losing_initiative"."issue_id" = "issue_id_p" |
jbe@170 | 3826 AND "losing_initiative"."admitted" |
jbe@170 | 3827 AND "winning_initiative"."schulze_rank" < |
jbe@170 | 3828 "losing_initiative"."schulze_rank" |
jbe@170 | 3829 AND "battle_win"."count" > "battle_lose"."count" |
jbe@170 | 3830 AND ( |
jbe@170 | 3831 "battle_win"."count" > "winning_initiative"."positive_votes" OR |
jbe@170 | 3832 "battle_lose"."count" < "losing_initiative"."negative_votes" ) |
jbe@170 | 3833 ) AS "subquery" |
jbe@170 | 3834 WHERE "id" = "subquery"."initiative_id"; |
jbe@170 | 3835 -- mark eligible initiatives: |
jbe@170 | 3836 UPDATE "initiative" SET "eligible" = TRUE |
jbe@171 | 3837 WHERE "issue_id" = "issue_id_p" |
jbe@171 | 3838 AND "initiative"."direct_majority" |
jbe@171 | 3839 AND "initiative"."indirect_majority" |
jbe@171 | 3840 AND "initiative"."better_than_status_quo" |
jbe@171 | 3841 AND ( |
jbe@171 | 3842 "policy_row"."no_multistage_majority" = FALSE OR |
jbe@171 | 3843 "initiative"."multistage_majority" = FALSE ) |
jbe@171 | 3844 AND ( |
jbe@171 | 3845 "policy_row"."no_reverse_beat_path" = FALSE OR |
jbe@171 | 3846 "initiative"."reverse_beat_path" = FALSE ); |
jbe@170 | 3847 -- mark final winner: |
jbe@170 | 3848 UPDATE "initiative" SET "winner" = TRUE |
jbe@170 | 3849 FROM ( |
jbe@170 | 3850 SELECT "id" AS "initiative_id" |
jbe@170 | 3851 FROM "initiative" |
jbe@170 | 3852 WHERE "issue_id" = "issue_id_p" AND "eligible" |
jbe@217 | 3853 ORDER BY |
jbe@217 | 3854 "schulze_rank", |
jbe@217 | 3855 "vote_ratio"("positive_votes", "negative_votes"), |
jbe@217 | 3856 "id" |
jbe@170 | 3857 LIMIT 1 |
jbe@170 | 3858 ) AS "subquery" |
jbe@170 | 3859 WHERE "id" = "subquery"."initiative_id"; |
jbe@173 | 3860 -- write (final) ranks: |
jbe@173 | 3861 "rank_v" := 1; |
jbe@173 | 3862 FOR "initiative_id_v" IN |
jbe@173 | 3863 SELECT "id" |
jbe@173 | 3864 FROM "initiative" |
jbe@173 | 3865 WHERE "issue_id" = "issue_id_p" AND "admitted" |
jbe@174 | 3866 ORDER BY |
jbe@174 | 3867 "winner" DESC, |
jbe@217 | 3868 "eligible" DESC, |
jbe@174 | 3869 "schulze_rank", |
jbe@217 | 3870 "vote_ratio"("positive_votes", "negative_votes"), |
jbe@174 | 3871 "id" |
jbe@173 | 3872 LOOP |
jbe@173 | 3873 UPDATE "initiative" SET "rank" = "rank_v" |
jbe@173 | 3874 WHERE "id" = "initiative_id_v"; |
jbe@173 | 3875 "rank_v" := "rank_v" + 1; |
jbe@173 | 3876 END LOOP; |
jbe@170 | 3877 -- set schulze rank of status quo and mark issue as finished: |
jbe@111 | 3878 UPDATE "issue" SET |
jbe@170 | 3879 "status_quo_schulze_rank" = "rank_ary"["dimension_v"], |
jbe@111 | 3880 "state" = |
jbe@139 | 3881 CASE WHEN EXISTS ( |
jbe@139 | 3882 SELECT NULL FROM "initiative" |
jbe@139 | 3883 WHERE "issue_id" = "issue_id_p" AND "winner" |
jbe@139 | 3884 ) THEN |
jbe@139 | 3885 'finished_with_winner'::"issue_state" |
jbe@139 | 3886 ELSE |
jbe@121 | 3887 'finished_without_winner'::"issue_state" |
jbe@111 | 3888 END, |
jbe@111 | 3889 "ranks_available" = TRUE |
jbe@0 | 3890 WHERE "id" = "issue_id_p"; |
jbe@0 | 3891 RETURN; |
jbe@0 | 3892 END; |
jbe@0 | 3893 $$; |
jbe@0 | 3894 |
jbe@0 | 3895 COMMENT ON FUNCTION "calculate_ranks" |
jbe@0 | 3896 ( "issue"."id"%TYPE ) |
jbe@0 | 3897 IS 'Determine ranking (Votes have to be counted first)'; |
jbe@0 | 3898 |
jbe@0 | 3899 |
jbe@0 | 3900 |
jbe@0 | 3901 ----------------------------- |
jbe@0 | 3902 -- Automatic state changes -- |
jbe@0 | 3903 ----------------------------- |
jbe@0 | 3904 |
jbe@0 | 3905 |
jbe@0 | 3906 CREATE FUNCTION "check_issue" |
jbe@0 | 3907 ( "issue_id_p" "issue"."id"%TYPE ) |
jbe@0 | 3908 RETURNS VOID |
jbe@0 | 3909 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 3910 DECLARE |
jbe@0 | 3911 "issue_row" "issue"%ROWTYPE; |
jbe@0 | 3912 "policy_row" "policy"%ROWTYPE; |
jbe@0 | 3913 BEGIN |
jbe@67 | 3914 PERFORM "lock_issue"("issue_id_p"); |
jbe@0 | 3915 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"; |
jbe@24 | 3916 -- only process open issues: |
jbe@0 | 3917 IF "issue_row"."closed" ISNULL THEN |
jbe@0 | 3918 SELECT * INTO "policy_row" FROM "policy" |
jbe@0 | 3919 WHERE "id" = "issue_row"."policy_id"; |
jbe@24 | 3920 -- create a snapshot, unless issue is already fully frozen: |
jbe@3 | 3921 IF "issue_row"."fully_frozen" ISNULL THEN |
jbe@0 | 3922 PERFORM "create_snapshot"("issue_id_p"); |
jbe@0 | 3923 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"; |
jbe@0 | 3924 END IF; |
jbe@24 | 3925 -- eventually close or accept issues, which have not been accepted: |
jbe@0 | 3926 IF "issue_row"."accepted" ISNULL THEN |
jbe@0 | 3927 IF EXISTS ( |
jbe@0 | 3928 SELECT NULL FROM "initiative" |
jbe@0 | 3929 WHERE "issue_id" = "issue_id_p" |
jbe@0 | 3930 AND "supporter_count" > 0 |
jbe@0 | 3931 AND "supporter_count" * "policy_row"."issue_quorum_den" |
jbe@0 | 3932 >= "issue_row"."population" * "policy_row"."issue_quorum_num" |
jbe@0 | 3933 ) THEN |
jbe@24 | 3934 -- accept issues, if supporter count is high enough |
jbe@3 | 3935 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission'); |
jbe@111 | 3936 -- NOTE: "issue_row" used later |
jbe@111 | 3937 "issue_row"."state" := 'discussion'; |
jbe@111 | 3938 "issue_row"."accepted" := now(); |
jbe@111 | 3939 UPDATE "issue" SET |
jbe@111 | 3940 "state" = "issue_row"."state", |
jbe@111 | 3941 "accepted" = "issue_row"."accepted" |
jbe@0 | 3942 WHERE "id" = "issue_row"."id"; |
jbe@0 | 3943 ELSIF |
jbe@22 | 3944 now() >= "issue_row"."created" + "issue_row"."admission_time" |
jbe@0 | 3945 THEN |
jbe@24 | 3946 -- close issues, if admission time has expired |
jbe@0 | 3947 PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission'); |
jbe@111 | 3948 UPDATE "issue" SET |
jbe@111 | 3949 "state" = 'canceled_issue_not_accepted', |
jbe@111 | 3950 "closed" = now() |
jbe@0 | 3951 WHERE "id" = "issue_row"."id"; |
jbe@0 | 3952 END IF; |
jbe@0 | 3953 END IF; |
jbe@24 | 3954 -- eventually half freeze issues: |
jbe@0 | 3955 IF |
jbe@24 | 3956 -- NOTE: issue can't be closed at this point, if it has been accepted |
jbe@0 | 3957 "issue_row"."accepted" NOTNULL AND |
jbe@3 | 3958 "issue_row"."half_frozen" ISNULL |
jbe@0 | 3959 THEN |
jbe@0 | 3960 IF |
jbe@144 | 3961 now() >= "issue_row"."accepted" + "issue_row"."discussion_time" |
jbe@0 | 3962 THEN |
jbe@21 | 3963 PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze'); |
jbe@111 | 3964 -- NOTE: "issue_row" used later |
jbe@111 | 3965 "issue_row"."state" := 'verification'; |
jbe@111 | 3966 "issue_row"."half_frozen" := now(); |
jbe@111 | 3967 UPDATE "issue" SET |
jbe@111 | 3968 "state" = "issue_row"."state", |
jbe@111 | 3969 "half_frozen" = "issue_row"."half_frozen" |
jbe@3 | 3970 WHERE "id" = "issue_row"."id"; |
jbe@0 | 3971 END IF; |
jbe@0 | 3972 END IF; |
jbe@24 | 3973 -- close issues after some time, if all initiatives have been revoked: |
jbe@24 | 3974 IF |
jbe@24 | 3975 "issue_row"."closed" ISNULL AND |
jbe@24 | 3976 NOT EXISTS ( |
jbe@24 | 3977 -- all initiatives are revoked |
jbe@24 | 3978 SELECT NULL FROM "initiative" |
jbe@24 | 3979 WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL |
jbe@24 | 3980 ) AND ( |
jbe@111 | 3981 -- and issue has not been accepted yet |
jbe@111 | 3982 "issue_row"."accepted" ISNULL OR |
jbe@24 | 3983 NOT EXISTS ( |
jbe@111 | 3984 -- or no initiatives have been revoked lately |
jbe@24 | 3985 SELECT NULL FROM "initiative" |
jbe@24 | 3986 WHERE "issue_id" = "issue_id_p" |
jbe@24 | 3987 AND now() < "revoked" + "issue_row"."verification_time" |
jbe@24 | 3988 ) OR ( |
jbe@24 | 3989 -- or verification time has elapsed |
jbe@24 | 3990 "issue_row"."half_frozen" NOTNULL AND |
jbe@24 | 3991 "issue_row"."fully_frozen" ISNULL AND |
jbe@24 | 3992 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time" |
jbe@24 | 3993 ) |
jbe@24 | 3994 ) |
jbe@24 | 3995 THEN |
jbe@111 | 3996 -- NOTE: "issue_row" used later |
jbe@113 | 3997 IF "issue_row"."accepted" ISNULL THEN |
jbe@113 | 3998 "issue_row"."state" := 'canceled_revoked_before_accepted'; |
jbe@113 | 3999 ELSIF "issue_row"."half_frozen" ISNULL THEN |
jbe@113 | 4000 "issue_row"."state" := 'canceled_after_revocation_during_discussion'; |
jbe@113 | 4001 ELSE |
jbe@113 | 4002 "issue_row"."state" := 'canceled_after_revocation_during_verification'; |
jbe@113 | 4003 END IF; |
jbe@111 | 4004 "issue_row"."closed" := now(); |
jbe@111 | 4005 UPDATE "issue" SET |
jbe@111 | 4006 "state" = "issue_row"."state", |
jbe@111 | 4007 "closed" = "issue_row"."closed" |
jbe@24 | 4008 WHERE "id" = "issue_row"."id"; |
jbe@24 | 4009 END IF; |
jbe@24 | 4010 -- fully freeze issue after verification time: |
jbe@0 | 4011 IF |
jbe@3 | 4012 "issue_row"."half_frozen" NOTNULL AND |
jbe@3 | 4013 "issue_row"."fully_frozen" ISNULL AND |
jbe@24 | 4014 "issue_row"."closed" ISNULL AND |
jbe@22 | 4015 now() >= "issue_row"."half_frozen" + "issue_row"."verification_time" |
jbe@3 | 4016 THEN |
jbe@3 | 4017 PERFORM "freeze_after_snapshot"("issue_id_p"); |
jbe@24 | 4018 -- NOTE: "issue" might change, thus "issue_row" has to be updated below |
jbe@3 | 4019 END IF; |
jbe@9 | 4020 SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p"; |
jbe@24 | 4021 -- close issue by calling close_voting(...) after voting time: |
jbe@3 | 4022 IF |
jbe@9 | 4023 "issue_row"."closed" ISNULL AND |
jbe@3 | 4024 "issue_row"."fully_frozen" NOTNULL AND |
jbe@22 | 4025 now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time" |
jbe@0 | 4026 THEN |
jbe@0 | 4027 PERFORM "close_voting"("issue_id_p"); |
jbe@111 | 4028 -- calculate ranks will not consume much time and can be done now |
jbe@111 | 4029 PERFORM "calculate_ranks"("issue_id_p"); |
jbe@0 | 4030 END IF; |
jbe@0 | 4031 END IF; |
jbe@0 | 4032 RETURN; |
jbe@0 | 4033 END; |
jbe@0 | 4034 $$; |
jbe@0 | 4035 |
jbe@0 | 4036 COMMENT ON FUNCTION "check_issue" |
jbe@0 | 4037 ( "issue"."id"%TYPE ) |
jbe@0 | 4038 IS 'Precalculate supporter counts etc. for a given issue, and check, if status change is required; At end of voting the ranking is not calculated by this function, but must be calculated in a seperate transaction using the "calculate_ranks" function.'; |
jbe@0 | 4039 |
jbe@0 | 4040 |
jbe@0 | 4041 CREATE FUNCTION "check_everything"() |
jbe@0 | 4042 RETURNS VOID |
jbe@0 | 4043 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@0 | 4044 DECLARE |
jbe@0 | 4045 "issue_id_v" "issue"."id"%TYPE; |
jbe@0 | 4046 BEGIN |
jbe@235 | 4047 DELETE FROM "expired_session"; |
jbe@184 | 4048 PERFORM "check_activity"(); |
jbe@4 | 4049 PERFORM "calculate_member_counts"(); |
jbe@4 | 4050 FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP |
jbe@0 | 4051 PERFORM "check_issue"("issue_id_v"); |
jbe@0 | 4052 END LOOP; |
jbe@4 | 4053 FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP |
jbe@0 | 4054 PERFORM "calculate_ranks"("issue_id_v"); |
jbe@0 | 4055 END LOOP; |
jbe@0 | 4056 RETURN; |
jbe@0 | 4057 END; |
jbe@0 | 4058 $$; |
jbe@0 | 4059 |
jbe@103 | 4060 COMMENT ON FUNCTION "check_everything"() IS 'Amongst other regular tasks this function performs "check_issue" for every open issue, and if possible, automatically calculates ranks. Use this function only for development and debugging purposes, as long transactions with exclusive locking may result. In productive environments you should call the lf_update program instead.'; |
jbe@0 | 4061 |
jbe@0 | 4062 |
jbe@0 | 4063 |
jbe@59 | 4064 ---------------------- |
jbe@59 | 4065 -- Deletion of data -- |
jbe@59 | 4066 ---------------------- |
jbe@59 | 4067 |
jbe@59 | 4068 |
jbe@59 | 4069 CREATE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE) |
jbe@59 | 4070 RETURNS VOID |
jbe@59 | 4071 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@59 | 4072 DECLARE |
jbe@59 | 4073 "issue_row" "issue"%ROWTYPE; |
jbe@59 | 4074 BEGIN |
jbe@59 | 4075 SELECT * INTO "issue_row" |
jbe@59 | 4076 FROM "issue" WHERE "id" = "issue_id_p" |
jbe@59 | 4077 FOR UPDATE; |
jbe@59 | 4078 IF "issue_row"."cleaned" ISNULL THEN |
jbe@59 | 4079 UPDATE "issue" SET |
jbe@152 | 4080 "state" = 'voting', |
jbe@152 | 4081 "closed" = NULL, |
jbe@59 | 4082 "ranks_available" = FALSE |
jbe@59 | 4083 WHERE "id" = "issue_id_p"; |
jbe@163 | 4084 DELETE FROM "issue_comment" |
jbe@163 | 4085 WHERE "issue_id" = "issue_id_p"; |
jbe@163 | 4086 DELETE FROM "voting_comment" |
jbe@163 | 4087 WHERE "issue_id" = "issue_id_p"; |
jbe@59 | 4088 DELETE FROM "delegating_voter" |
jbe@59 | 4089 WHERE "issue_id" = "issue_id_p"; |
jbe@59 | 4090 DELETE FROM "direct_voter" |
jbe@59 | 4091 WHERE "issue_id" = "issue_id_p"; |
jbe@59 | 4092 DELETE FROM "delegating_interest_snapshot" |
jbe@59 | 4093 WHERE "issue_id" = "issue_id_p"; |
jbe@59 | 4094 DELETE FROM "direct_interest_snapshot" |
jbe@59 | 4095 WHERE "issue_id" = "issue_id_p"; |
jbe@59 | 4096 DELETE FROM "delegating_population_snapshot" |
jbe@59 | 4097 WHERE "issue_id" = "issue_id_p"; |
jbe@59 | 4098 DELETE FROM "direct_population_snapshot" |
jbe@59 | 4099 WHERE "issue_id" = "issue_id_p"; |
jbe@113 | 4100 DELETE FROM "non_voter" |
jbe@94 | 4101 WHERE "issue_id" = "issue_id_p"; |
jbe@59 | 4102 DELETE FROM "delegation" |
jbe@59 | 4103 WHERE "issue_id" = "issue_id_p"; |
jbe@59 | 4104 DELETE FROM "supporter" |
jbe@59 | 4105 WHERE "issue_id" = "issue_id_p"; |
jbe@59 | 4106 UPDATE "issue" SET |
jbe@152 | 4107 "state" = "issue_row"."state", |
jbe@59 | 4108 "closed" = "issue_row"."closed", |
jbe@59 | 4109 "ranks_available" = "issue_row"."ranks_available", |
jbe@59 | 4110 "cleaned" = now() |
jbe@59 | 4111 WHERE "id" = "issue_id_p"; |
jbe@59 | 4112 END IF; |
jbe@59 | 4113 RETURN; |
jbe@59 | 4114 END; |
jbe@59 | 4115 $$; |
jbe@59 | 4116 |
jbe@59 | 4117 COMMENT ON FUNCTION "clean_issue"("issue"."id"%TYPE) IS 'Delete discussion data and votes belonging to an issue'; |
jbe@8 | 4118 |
jbe@8 | 4119 |
jbe@54 | 4120 CREATE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE) |
jbe@8 | 4121 RETURNS VOID |
jbe@8 | 4122 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@8 | 4123 BEGIN |
jbe@9 | 4124 UPDATE "member" SET |
jbe@57 | 4125 "last_login" = NULL, |
jbe@45 | 4126 "login" = NULL, |
jbe@11 | 4127 "password" = NULL, |
jbe@101 | 4128 "locked" = TRUE, |
jbe@54 | 4129 "active" = FALSE, |
jbe@11 | 4130 "notify_email" = NULL, |
jbe@11 | 4131 "notify_email_unconfirmed" = NULL, |
jbe@11 | 4132 "notify_email_secret" = NULL, |
jbe@11 | 4133 "notify_email_secret_expiry" = NULL, |
jbe@57 | 4134 "notify_email_lock_expiry" = NULL, |
jbe@11 | 4135 "password_reset_secret" = NULL, |
jbe@11 | 4136 "password_reset_secret_expiry" = NULL, |
jbe@11 | 4137 "organizational_unit" = NULL, |
jbe@11 | 4138 "internal_posts" = NULL, |
jbe@11 | 4139 "realname" = NULL, |
jbe@11 | 4140 "birthday" = NULL, |
jbe@11 | 4141 "address" = NULL, |
jbe@11 | 4142 "email" = NULL, |
jbe@11 | 4143 "xmpp_address" = NULL, |
jbe@11 | 4144 "website" = NULL, |
jbe@11 | 4145 "phone" = NULL, |
jbe@11 | 4146 "mobile_phone" = NULL, |
jbe@11 | 4147 "profession" = NULL, |
jbe@11 | 4148 "external_memberships" = NULL, |
jbe@11 | 4149 "external_posts" = NULL, |
jbe@45 | 4150 "statement" = NULL |
jbe@45 | 4151 WHERE "id" = "member_id_p"; |
jbe@11 | 4152 -- "text_search_data" is updated by triggers |
jbe@45 | 4153 DELETE FROM "setting" WHERE "member_id" = "member_id_p"; |
jbe@45 | 4154 DELETE FROM "setting_map" WHERE "member_id" = "member_id_p"; |
jbe@45 | 4155 DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p"; |
jbe@45 | 4156 DELETE FROM "member_image" WHERE "member_id" = "member_id_p"; |
jbe@45 | 4157 DELETE FROM "contact" WHERE "member_id" = "member_id_p"; |
jbe@113 | 4158 DELETE FROM "ignored_member" WHERE "member_id" = "member_id_p"; |
jbe@235 | 4159 DELETE FROM "session" WHERE "member_id" = "member_id_p"; |
jbe@45 | 4160 DELETE FROM "area_setting" WHERE "member_id" = "member_id_p"; |
jbe@45 | 4161 DELETE FROM "issue_setting" WHERE "member_id" = "member_id_p"; |
jbe@113 | 4162 DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p"; |
jbe@45 | 4163 DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p"; |
jbe@45 | 4164 DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p"; |
jbe@54 | 4165 DELETE FROM "membership" WHERE "member_id" = "member_id_p"; |
jbe@54 | 4166 DELETE FROM "delegation" WHERE "truster_id" = "member_id_p"; |
jbe@113 | 4167 DELETE FROM "non_voter" WHERE "member_id" = "member_id_p"; |
jbe@57 | 4168 DELETE FROM "direct_voter" USING "issue" |
jbe@57 | 4169 WHERE "direct_voter"."issue_id" = "issue"."id" |
jbe@57 | 4170 AND "issue"."closed" ISNULL |
jbe@57 | 4171 AND "member_id" = "member_id_p"; |
jbe@45 | 4172 RETURN; |
jbe@45 | 4173 END; |
jbe@45 | 4174 $$; |
jbe@45 | 4175 |
jbe@57 | 4176 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)'; |
jbe@45 | 4177 |
jbe@45 | 4178 |
jbe@45 | 4179 CREATE FUNCTION "delete_private_data"() |
jbe@45 | 4180 RETURNS VOID |
jbe@45 | 4181 LANGUAGE 'plpgsql' VOLATILE AS $$ |
jbe@45 | 4182 BEGIN |
jbe@226 | 4183 DELETE FROM "member" WHERE "activated" ISNULL; |
jbe@50 | 4184 UPDATE "member" SET |
jbe@206 | 4185 "invite_code" = NULL, |
jbe@232 | 4186 "invite_code_expiry" = NULL, |
jbe@228 | 4187 "admin_comment" = NULL, |
jbe@57 | 4188 "last_login" = NULL, |
jbe@50 | 4189 "login" = NULL, |
jbe@50 | 4190 "password" = NULL, |
jbe@50 | 4191 "notify_email" = NULL, |
jbe@50 | 4192 "notify_email_unconfirmed" = NULL, |
jbe@50 | 4193 "notify_email_secret" = NULL, |
jbe@50 | 4194 "notify_email_secret_expiry" = NULL, |
jbe@57 | 4195 "notify_email_lock_expiry" = NULL, |
jbe@50 | 4196 "password_reset_secret" = NULL, |
jbe@50 | 4197 "password_reset_secret_expiry" = NULL, |
jbe@50 | 4198 "organizational_unit" = NULL, |
jbe@50 | 4199 "internal_posts" = NULL, |
jbe@50 | 4200 "realname" = NULL, |
jbe@50 | 4201 "birthday" = NULL, |
jbe@50 | 4202 "address" = NULL, |
jbe@50 | 4203 "email" = NULL, |
jbe@50 | 4204 "xmpp_address" = NULL, |
jbe@50 | 4205 "website" = NULL, |
jbe@50 | 4206 "phone" = NULL, |
jbe@50 | 4207 "mobile_phone" = NULL, |
jbe@50 | 4208 "profession" = NULL, |
jbe@50 | 4209 "external_memberships" = NULL, |
jbe@50 | 4210 "external_posts" = NULL, |
jbe@50 | 4211 "statement" = NULL; |
jbe@50 | 4212 -- "text_search_data" is updated by triggers |
jbe@50 | 4213 DELETE FROM "setting"; |
jbe@50 | 4214 DELETE FROM "setting_map"; |
jbe@50 | 4215 DELETE FROM "member_relation_setting"; |
jbe@50 | 4216 DELETE FROM "member_image"; |
jbe@50 | 4217 DELETE FROM "contact"; |
jbe@113 | 4218 DELETE FROM "ignored_member"; |
jbe@235 | 4219 DELETE FROM "session"; |
jbe@50 | 4220 DELETE FROM "area_setting"; |
jbe@50 | 4221 DELETE FROM "issue_setting"; |
jbe@113 | 4222 DELETE FROM "ignored_initiative"; |
jbe@50 | 4223 DELETE FROM "initiative_setting"; |
jbe@50 | 4224 DELETE FROM "suggestion_setting"; |
jbe@113 | 4225 DELETE FROM "non_voter"; |
jbe@8 | 4226 DELETE FROM "direct_voter" USING "issue" |
jbe@8 | 4227 WHERE "direct_voter"."issue_id" = "issue"."id" |
jbe@8 | 4228 AND "issue"."closed" ISNULL; |
jbe@8 | 4229 RETURN; |
jbe@8 | 4230 END; |
jbe@8 | 4231 $$; |
jbe@8 | 4232 |
jbe@103 | 4233 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.'; |
jbe@8 | 4234 |
jbe@8 | 4235 |
jbe@8 | 4236 |
jbe@0 | 4237 COMMIT; |