liquid_feedback_core

changeset 194:5d89f5fcdcfc

v1.4.0_rc4 gets v1.4.0
author jbe
date Sat Sep 10 22:42:51 2011 +0200 (2011-09-10)
parents 055d232404d6
children e8c6035b03f3
files update/core-update.v1.3.1-v1.4.0.sql update/core-update.v1.3.1-v1.4.0_rc4.sql update/core-update.v1.4.0-v2.0.0.sql update/core-update.v1.4.0_rc4-v1.4.0.sql update/core-update.v1.4.0_rc4-v2.0.0.sql
line diff
     1.1 --- /dev/null	Thu Jan 01 00:00:00 1970 +0000
     1.2 +++ b/update/core-update.v1.3.1-v1.4.0.sql	Sat Sep 10 22:42:51 2011 +0200
     1.3 @@ -0,0 +1,2232 @@
     1.4 +BEGIN;  -- NOTE: file contains additional statements AFTER this BEGIN/COMMIT block!
     1.5 +
     1.6 +
     1.7 +-- Update version information:
     1.8 +
     1.9 +CREATE OR REPLACE VIEW "liquid_feedback_version" AS
    1.10 +  SELECT * FROM (VALUES ('1.4.0', 1, 4, 0))
    1.11 +  AS "subquery"("string", "major", "minor", "revision");
    1.12 +
    1.13 +
    1.14 +-- New columns "notify_level" and "notify_event_id" in "member" table:
    1.15 +
    1.16 +CREATE TYPE "notify_level" AS ENUM
    1.17 +  ('none', 'voting', 'verification', 'discussion', 'all');
    1.18 +
    1.19 +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';
    1.20 +
    1.21 +ALTER TABLE "member" ADD "notify_level" "notify_level" NOT NULL DEFAULT 'none';
    1.22 +ALTER TABLE "member" ADD "notify_event_id" INT8;
    1.23 +
    1.24 +COMMENT ON COLUMN "member"."notify_level"    IS 'Selects which event notifications are to be sent to the "notify_email" mail address';
    1.25 +COMMENT ON COLUMN "member"."notify_event_id" IS 'Latest "id" of an "event" the member was notified about';
    1.26 +
    1.27 +
    1.28 +-- Add primary key with type SERIAL8 (INT8) for "invite_code" table:
    1.29 +
    1.30 +ALTER TABLE "invite_code" DROP CONSTRAINT "invite_code_pkey";
    1.31 +ALTER TABLE "invite_code" ALTER "code" SET NOT NULL;
    1.32 +ALTER TABLE "invite_code" ADD UNIQUE ("code");
    1.33 +ALTER TABLE "invite_code" ADD "id" SERIAL8 PRIMARY KEY;
    1.34 +
    1.35 +
    1.36 +-- Add index for "other_member_id" column of "contact" table:
    1.37 +
    1.38 +CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
    1.39 +
    1.40 +
    1.41 +-- New table "ignored_member":
    1.42 +
    1.43 +CREATE TABLE "ignored_member" (
    1.44 +        PRIMARY KEY ("member_id", "other_member_id"),
    1.45 +        "member_id"             INT4            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
    1.46 +        "other_member_id"       INT4            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
    1.47 +CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
    1.48 +
    1.49 +COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
    1.50 +
    1.51 +COMMENT ON COLUMN "ignored_member"."member_id"       IS 'Member ignoring someone';
    1.52 +COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
    1.53 +
    1.54 +
    1.55 +-- New table "unit" with default entry:
    1.56 +
    1.57 +CREATE TABLE "unit" (
    1.58 +        "id"                    SERIAL4         PRIMARY KEY,
    1.59 +        "parent_id"             INT4            REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
    1.60 +        "active"                BOOLEAN         NOT NULL DEFAULT TRUE,
    1.61 +        "name"                  TEXT            NOT NULL,
    1.62 +        "description"           TEXT            NOT NULL DEFAULT '',
    1.63 +        "member_count"          INT4,
    1.64 +        "text_search_data"      TSVECTOR );
    1.65 +CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
    1.66 +CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
    1.67 +CREATE INDEX "unit_active_idx" ON "unit" ("active");
    1.68 +CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
    1.69 +CREATE TRIGGER "update_text_search_data"
    1.70 +  BEFORE INSERT OR UPDATE ON "unit"
    1.71 +  FOR EACH ROW EXECUTE PROCEDURE
    1.72 +  tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
    1.73 +    "name", "description" );
    1.74 +
    1.75 +COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
    1.76 +
    1.77 +COMMENT ON COLUMN "unit"."parent_id"    IS 'Parent id of tree node; Multiple roots allowed';
    1.78 +COMMENT ON COLUMN "unit"."active"       IS 'TRUE means new issues can be created in units of this area';
    1.79 +COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
    1.80 +
    1.81 +INSERT INTO "unit" ("name") VALUES ('Main');  -- NOTE: gets id 1
    1.82 +
    1.83 +
    1.84 +-- New column "unit_id" in table "area":
    1.85 +
    1.86 +ALTER TABLE "area" ADD "unit_id" INT4 DEFAULT 1
    1.87 +  NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE;
    1.88 +ALTER TABLE "area" ALTER "unit_id" DROP DEFAULT;
    1.89 +
    1.90 +CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
    1.91 +
    1.92 +
    1.93 +-- Issue states:
    1.94 +
    1.95 +CREATE TYPE "issue_state" AS ENUM (
    1.96 +        'admission', 'discussion', 'verification', 'voting',
    1.97 +        'canceled_revoked_before_accepted',
    1.98 +        'canceled_issue_not_accepted',
    1.99 +        'canceled_after_revocation_during_discussion',
   1.100 +        'canceled_after_revocation_during_verification',
   1.101 +        'calculation',
   1.102 +        'canceled_no_initiative_admitted',
   1.103 +        'finished_without_winner', 'finished_with_winner');
   1.104 +
   1.105 +COMMENT ON TYPE "issue_state" IS 'State of issues';
   1.106 +
   1.107 +ALTER TABLE "issue" ADD "state" "issue_state";
   1.108 +
   1.109 +-- NOTE: Filling new column with values is done after this transaction (see below)
   1.110 +
   1.111 +
   1.112 +-- New column "revoked_by_member_id" in table "initiative":
   1.113 +
   1.114 +ALTER TABLE "initiative" ADD "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE;
   1.115 +
   1.116 +COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoked the initiative';
   1.117 +
   1.118 +-- NOTE: Filling new column with values is done after this transaction (see below)
   1.119 +
   1.120 +
   1.121 +-- New table "ignored_initiative":
   1.122 +
   1.123 +CREATE TABLE "ignored_initiative" (
   1.124 +        PRIMARY KEY ("initiative_id", "member_id"),
   1.125 +        "initiative_id"         INT4            REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   1.126 +        "member_id"             INT4            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
   1.127 +CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
   1.128 +
   1.129 +COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
   1.130 +
   1.131 +
   1.132 +-- New table "invite_code_unit":
   1.133 +
   1.134 +CREATE TABLE "invite_code_unit" (
   1.135 +        PRIMARY KEY ("invite_code_id", "unit_id"),
   1.136 +        "invite_code_id"        INT8            REFERENCES "invite_code" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   1.137 +        "unit_id"               INT4            REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
   1.138 +
   1.139 +COMMENT ON TABLE "invite_code_unit" IS 'Units where accounts created with a given invite codes get voting rights';
   1.140 +
   1.141 +INSERT INTO "invite_code_unit" ("invite_code_id", "unit_id")
   1.142 +  SELECT "id" AS "invite_code_id", 1 AS "unit_id" FROM "invite_code";
   1.143 +
   1.144 +
   1.145 +-- New table "privilege":
   1.146 +
   1.147 +CREATE TABLE "privilege" (
   1.148 +        PRIMARY KEY ("unit_id", "member_id"),
   1.149 +        "unit_id"               INT4            REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   1.150 +        "member_id"             INT4            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   1.151 +        "admin_manager"         BOOLEAN         NOT NULL DEFAULT FALSE,
   1.152 +        "unit_manager"          BOOLEAN         NOT NULL DEFAULT FALSE,
   1.153 +        "area_manager"          BOOLEAN         NOT NULL DEFAULT FALSE,
   1.154 +        "voting_right_manager"  BOOLEAN         NOT NULL DEFAULT FALSE,
   1.155 +        "voting_right"          BOOLEAN         NOT NULL DEFAULT TRUE );
   1.156 +
   1.157 +COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
   1.158 +
   1.159 +COMMENT ON COLUMN "privilege"."admin_manager"        IS 'Grant/revoke admin privileges to/from other users';
   1.160 +COMMENT ON COLUMN "privilege"."unit_manager"         IS 'Create or lock sub units';
   1.161 +COMMENT ON COLUMN "privilege"."area_manager"         IS 'Create or lock areas and set area parameters';
   1.162 +COMMENT ON COLUMN "privilege"."voting_right_manager" IS 'Select which members are allowed to discuss and vote inside the unit';
   1.163 +COMMENT ON COLUMN "privilege"."voting_right"         IS 'Right to discuss and vote';
   1.164 +
   1.165 +INSERT INTO "privilege" ("unit_id", "member_id", "voting_right")
   1.166 +  SELECT 1 AS "unit_id", "id" AS "member_id", TRUE AS "voting_right"
   1.167 +  FROM "member";
   1.168 +
   1.169 +
   1.170 +-- Remove table "ignored_issue", which is no longer existent:
   1.171 +
   1.172 +DROP TABLE "ignored_issue";
   1.173 +
   1.174 +
   1.175 +-- Replace TYPE "delegation_scope" with a new type, where 'global' is replaced by 'unit':
   1.176 +
   1.177 +ALTER TYPE "delegation_scope" RENAME TO "delegation_scope_old";  -- NOTE: dropped later
   1.178 +CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
   1.179 +COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
   1.180 +
   1.181 +
   1.182 +-- Delete views and functions being dependent on type "delegation_scope":
   1.183 +
   1.184 +DROP FUNCTION "delegation_chain"
   1.185 +  ( "member_id_p" "member"."id"%TYPE,
   1.186 +    "area_id_p"   "area"."id"%TYPE,
   1.187 +    "issue_id_p"  "issue"."id"%TYPE );
   1.188 +
   1.189 +DROP FUNCTION "delegation_chain"
   1.190 +  ( "member_id_p"           "member"."id"%TYPE,
   1.191 +    "area_id_p"             "area"."id"%TYPE,
   1.192 +    "issue_id_p"            "issue"."id"%TYPE,
   1.193 +    "simulate_trustee_id_p" "member"."id"%TYPE );
   1.194 +
   1.195 +DROP TYPE "delegation_chain_row";
   1.196 +
   1.197 +DROP VIEW "issue_delegation";
   1.198 +DROP VIEW "area_delegation";
   1.199 +DROP VIEW "global_delegation";
   1.200 +DROP VIEW "active_delegation";
   1.201 +
   1.202 +
   1.203 +-- Modify "delegation" table to use new "delegation_scope" type:
   1.204 +
   1.205 +ALTER TABLE "delegation" DROP CONSTRAINT "no_global_delegation_to_null";
   1.206 +ALTER TABLE "delegation" DROP CONSTRAINT "area_id_and_issue_id_set_according_to_scope";
   1.207 +
   1.208 +DROP INDEX "delegation_global_truster_id_unique_idx";
   1.209 +
   1.210 +ALTER TABLE "delegation" ALTER "scope" TYPE "delegation_scope"
   1.211 +  USING CASE WHEN "scope" = 'global'
   1.212 +  THEN 'unit'::"delegation_scope"
   1.213 +  ELSE "scope"::text::"delegation_scope" END;
   1.214 +
   1.215 +ALTER TABLE "delegation" ADD "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE;
   1.216 +
   1.217 +ALTER TABLE "delegation" ADD CONSTRAINT "no_unit_delegation_to_null"
   1.218 +  CHECK ("trustee_id" NOTNULL OR "scope" != 'unit');
   1.219 +
   1.220 +ALTER TABLE "delegation" ADD UNIQUE ("unit_id", "truster_id");
   1.221 +
   1.222 +COMMENT ON COLUMN "delegation"."unit_id"  IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
   1.223 +
   1.224 +-- NOTE: Column "unit_id" filled after transaction (see below)
   1.225 +
   1.226 +
   1.227 +-- Modify snapshot tables to use new "delegation_scope" type:
   1.228 +
   1.229 +ALTER TABLE "delegating_population_snapshot" ALTER "scope" TYPE "delegation_scope"
   1.230 +  USING CASE WHEN "scope" = 'global'
   1.231 +  THEN 'unit'::"delegation_scope"
   1.232 +  ELSE "scope"::text::"delegation_scope" END;
   1.233 +
   1.234 +ALTER TABLE "delegating_interest_snapshot" ALTER "scope" TYPE "delegation_scope"
   1.235 +  USING CASE WHEN "scope" = 'global'
   1.236 +  THEN 'unit'::"delegation_scope"
   1.237 +  ELSE "scope"::text::"delegation_scope" END;
   1.238 +
   1.239 +ALTER TABLE "delegating_voter" ALTER "scope" TYPE "delegation_scope"
   1.240 +  USING CASE WHEN "scope" = 'global'
   1.241 +  THEN 'unit'::"delegation_scope"
   1.242 +  ELSE "scope"::text::"delegation_scope" END;
   1.243 +
   1.244 +
   1.245 +-- New table "non_voter":
   1.246 +
   1.247 +CREATE TABLE "non_voter" (
   1.248 +        PRIMARY KEY ("issue_id", "member_id"),
   1.249 +        "issue_id"              INT4            REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   1.250 +        "member_id"             INT4            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
   1.251 +CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
   1.252 +
   1.253 +COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
   1.254 +
   1.255 +
   1.256 +-- New tables "issue_comment" and "rendered_issue_comment":
   1.257 +
   1.258 +CREATE TABLE "issue_comment" (
   1.259 +        PRIMARY KEY ("issue_id", "member_id"),
   1.260 +        "issue_id"              INT4            REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   1.261 +        "member_id"             INT4            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   1.262 +        "changed"               TIMESTAMPTZ     NOT NULL DEFAULT now(),
   1.263 +        "formatting_engine"     TEXT,
   1.264 +        "content"               TEXT            NOT NULL,
   1.265 +        "text_search_data"      TSVECTOR );
   1.266 +CREATE INDEX "issue_comment_member_id_idx" ON "issue_comment" ("member_id");
   1.267 +CREATE INDEX "issue_comment_text_search_data_idx" ON "issue_comment" USING gin ("text_search_data");
   1.268 +CREATE TRIGGER "update_text_search_data"
   1.269 +  BEFORE INSERT OR UPDATE ON "issue_comment"
   1.270 +  FOR EACH ROW EXECUTE PROCEDURE
   1.271 +  tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
   1.272 +
   1.273 +COMMENT ON TABLE "issue_comment" IS 'Place to store free comments of members related to issues';
   1.274 +
   1.275 +COMMENT ON COLUMN "issue_comment"."changed" IS 'Time the comment was last changed';
   1.276 +
   1.277 +CREATE TABLE "rendered_issue_comment" (
   1.278 +        PRIMARY KEY ("issue_id", "member_id", "format"),
   1.279 +        FOREIGN KEY ("issue_id", "member_id")
   1.280 +          REFERENCES "issue_comment" ("issue_id", "member_id")
   1.281 +          ON DELETE CASCADE ON UPDATE CASCADE,
   1.282 +        "issue_id"              INT4,
   1.283 +        "member_id"             INT4,
   1.284 +        "format"                TEXT,
   1.285 +        "content"               TEXT            NOT NULL );
   1.286 +
   1.287 +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)';
   1.288 +
   1.289 +
   1.290 +-- New tables "voting_comment" and "rendered_voting_comment":
   1.291 +
   1.292 +CREATE TABLE "voting_comment" (
   1.293 +        PRIMARY KEY ("issue_id", "member_id"),
   1.294 +        "issue_id"              INT4            REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   1.295 +        "member_id"             INT4            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   1.296 +        "changed"               TIMESTAMPTZ,
   1.297 +        "formatting_engine"     TEXT,
   1.298 +        "content"               TEXT            NOT NULL,
   1.299 +        "text_search_data"      TSVECTOR );
   1.300 +CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id");
   1.301 +CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data");
   1.302 +CREATE TRIGGER "update_text_search_data"
   1.303 +  BEFORE INSERT OR UPDATE ON "voting_comment"
   1.304 +  FOR EACH ROW EXECUTE PROCEDURE
   1.305 +  tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
   1.306 +
   1.307 +COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.';
   1.308 +
   1.309 +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.';
   1.310 +
   1.311 +CREATE TABLE "rendered_voting_comment" (
   1.312 +        PRIMARY KEY ("issue_id", "member_id", "format"),
   1.313 +        FOREIGN KEY ("issue_id", "member_id")
   1.314 +          REFERENCES "voting_comment" ("issue_id", "member_id")
   1.315 +          ON DELETE CASCADE ON UPDATE CASCADE,
   1.316 +        "issue_id"              INT4,
   1.317 +        "member_id"             INT4,
   1.318 +        "format"                TEXT,
   1.319 +        "content"               TEXT            NOT NULL );
   1.320 +
   1.321 +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)';
   1.322 +
   1.323 +
   1.324 +-- New table "event":
   1.325 +
   1.326 +CREATE TYPE "event_type" AS ENUM (
   1.327 +        'issue_state_changed',
   1.328 +        'initiative_created_in_new_issue',
   1.329 +        'initiative_created_in_existing_issue',
   1.330 +        'initiative_revoked',
   1.331 +        'new_draft_created',
   1.332 +        'suggestion_created');
   1.333 +
   1.334 +COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
   1.335 +
   1.336 +CREATE TABLE "event" (
   1.337 +        "id"                    SERIAL8         PRIMARY KEY,
   1.338 +        "occurrence"            TIMESTAMPTZ     NOT NULL DEFAULT now(),
   1.339 +        "event"                 "event_type"    NOT NULL,
   1.340 +        "member_id"             INT4            REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
   1.341 +        "issue_id"              INT4            REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   1.342 +        "state"                 "issue_state"   CHECK ("state" != 'calculation'),
   1.343 +        "initiative_id"         INT4,
   1.344 +        "draft_id"              INT8,
   1.345 +        "suggestion_id"         INT8,
   1.346 +        FOREIGN KEY ("issue_id", "initiative_id")
   1.347 +          REFERENCES "initiative" ("issue_id", "id")
   1.348 +          ON DELETE CASCADE ON UPDATE CASCADE,
   1.349 +        FOREIGN KEY ("initiative_id", "draft_id")
   1.350 +          REFERENCES "draft" ("initiative_id", "id")
   1.351 +          ON DELETE CASCADE ON UPDATE CASCADE,
   1.352 +        FOREIGN KEY ("initiative_id", "suggestion_id")
   1.353 +          REFERENCES "suggestion" ("initiative_id", "id")
   1.354 +          ON DELETE CASCADE ON UPDATE CASCADE,
   1.355 +        CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
   1.356 +          "event" != 'issue_state_changed' OR (
   1.357 +            "member_id"     ISNULL  AND
   1.358 +            "issue_id"      NOTNULL AND
   1.359 +            "state"         NOTNULL AND
   1.360 +            "initiative_id" ISNULL  AND
   1.361 +            "draft_id"      ISNULL  AND
   1.362 +            "suggestion_id" ISNULL  )),
   1.363 +        CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
   1.364 +          "event" NOT IN (
   1.365 +            'initiative_created_in_new_issue',
   1.366 +            'initiative_created_in_existing_issue',
   1.367 +            'initiative_revoked',
   1.368 +            'new_draft_created'
   1.369 +          ) OR (
   1.370 +            "member_id"     NOTNULL AND
   1.371 +            "issue_id"      NOTNULL AND
   1.372 +            "state"         NOTNULL AND
   1.373 +            "initiative_id" NOTNULL AND
   1.374 +            "draft_id"      NOTNULL AND
   1.375 +            "suggestion_id" ISNULL  )),
   1.376 +        CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
   1.377 +          "event" != 'suggestion_created' OR (
   1.378 +            "member_id"     NOTNULL AND
   1.379 +            "issue_id"      NOTNULL AND
   1.380 +            "state"         NOTNULL AND
   1.381 +            "initiative_id" NOTNULL AND
   1.382 +            "draft_id"      ISNULL  AND
   1.383 +            "suggestion_id" NOTNULL )) );
   1.384 +
   1.385 +COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
   1.386 +
   1.387 +COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
   1.388 +COMMENT ON COLUMN "event"."event"      IS 'Type of event (see TYPE "event_type")';
   1.389 +COMMENT ON COLUMN "event"."member_id"  IS 'Member who caused the event, if applicable';
   1.390 +COMMENT ON COLUMN "event"."state"      IS 'If issue_id is set: state of affected issue; If state changed: new state';
   1.391 +
   1.392 +
   1.393 +-- Triggers to fill "event" table:
   1.394 +
   1.395 +CREATE FUNCTION "write_event_issue_state_changed_trigger"()
   1.396 +  RETURNS TRIGGER
   1.397 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   1.398 +    BEGIN
   1.399 +      IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
   1.400 +        INSERT INTO "event" ("event", "issue_id", "state")
   1.401 +          VALUES ('issue_state_changed', NEW."id", NEW."state");
   1.402 +      END IF;
   1.403 +      RETURN NULL;
   1.404 +    END;
   1.405 +  $$;
   1.406 +
   1.407 +CREATE TRIGGER "write_event_issue_state_changed"
   1.408 +  AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
   1.409 +  "write_event_issue_state_changed_trigger"();
   1.410 +
   1.411 +COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
   1.412 +COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
   1.413 +
   1.414 +CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
   1.415 +  RETURNS TRIGGER
   1.416 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   1.417 +    DECLARE
   1.418 +      "initiative_row" "initiative"%ROWTYPE;
   1.419 +      "issue_row"      "issue"%ROWTYPE;
   1.420 +      "event_v"        "event_type";
   1.421 +    BEGIN
   1.422 +      SELECT * INTO "initiative_row" FROM "initiative"
   1.423 +        WHERE "id" = NEW."initiative_id";
   1.424 +      SELECT * INTO "issue_row" FROM "issue"
   1.425 +        WHERE "id" = "initiative_row"."issue_id";
   1.426 +      IF EXISTS (
   1.427 +        SELECT NULL FROM "draft"
   1.428 +        WHERE "initiative_id" = NEW."initiative_id"
   1.429 +        AND "id" != NEW."id"
   1.430 +      ) THEN
   1.431 +        "event_v" := 'new_draft_created';
   1.432 +      ELSE
   1.433 +        IF EXISTS (
   1.434 +          SELECT NULL FROM "initiative"
   1.435 +          WHERE "issue_id" = "initiative_row"."issue_id"
   1.436 +          AND "id" != "initiative_row"."id"
   1.437 +        ) THEN
   1.438 +          "event_v" := 'initiative_created_in_existing_issue';
   1.439 +        ELSE
   1.440 +          "event_v" := 'initiative_created_in_new_issue';
   1.441 +        END IF;
   1.442 +      END IF;
   1.443 +      INSERT INTO "event" (
   1.444 +          "event", "member_id",
   1.445 +          "issue_id", "state", "initiative_id", "draft_id"
   1.446 +        ) VALUES (
   1.447 +          "event_v",
   1.448 +          NEW."author_id",
   1.449 +          "initiative_row"."issue_id",
   1.450 +          "issue_row"."state",
   1.451 +          "initiative_row"."id",
   1.452 +          NEW."id" );
   1.453 +      RETURN NULL;
   1.454 +    END;
   1.455 +  $$;
   1.456 +
   1.457 +CREATE TRIGGER "write_event_initiative_or_draft_created"
   1.458 +  AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
   1.459 +  "write_event_initiative_or_draft_created_trigger"();
   1.460 +
   1.461 +COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
   1.462 +COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
   1.463 +
   1.464 +CREATE FUNCTION "write_event_initiative_revoked_trigger"()
   1.465 +  RETURNS TRIGGER
   1.466 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   1.467 +    DECLARE
   1.468 +      "issue_row"      "issue"%ROWTYPE;
   1.469 +    BEGIN
   1.470 +      SELECT * INTO "issue_row" FROM "issue"
   1.471 +        WHERE "id" = NEW."issue_id";
   1.472 +      IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
   1.473 +        INSERT INTO "event" (
   1.474 +            "event", "member_id", "issue_id", "state", "initiative_id"
   1.475 +          ) VALUES (
   1.476 +            'initiative_revoked',
   1.477 +            NEW."revoked_by_member_id",
   1.478 +            NEW."issue_id",
   1.479 +            "issue_row"."state",
   1.480 +            NEW."id" );
   1.481 +      END IF;
   1.482 +      RETURN NULL;
   1.483 +    END;
   1.484 +  $$;
   1.485 +
   1.486 +CREATE TRIGGER "write_event_initiative_revoked"
   1.487 +  AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
   1.488 +  "write_event_initiative_revoked_trigger"();
   1.489 +
   1.490 +COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"()      IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
   1.491 +COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
   1.492 +
   1.493 +CREATE FUNCTION "write_event_suggestion_created_trigger"()
   1.494 +  RETURNS TRIGGER
   1.495 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   1.496 +    DECLARE
   1.497 +      "initiative_row" "initiative"%ROWTYPE;
   1.498 +      "issue_row"      "issue"%ROWTYPE;
   1.499 +    BEGIN
   1.500 +      SELECT * INTO "initiative_row" FROM "initiative"
   1.501 +        WHERE "id" = NEW."initiative_id";
   1.502 +      SELECT * INTO "issue_row" FROM "issue"
   1.503 +        WHERE "id" = "initiative_row"."issue_id";
   1.504 +      INSERT INTO "event" (
   1.505 +          "event", "member_id",
   1.506 +          "issue_id", "state", "initiative_id", "suggestion_id"
   1.507 +        ) VALUES (
   1.508 +          'suggestion_created',
   1.509 +          NEW."author_id",
   1.510 +          "initiative_row"."issue_id",
   1.511 +          "issue_row"."state",
   1.512 +          "initiative_row"."id",
   1.513 +          NEW."id" );
   1.514 +      RETURN NULL;
   1.515 +    END;
   1.516 +  $$;
   1.517 +
   1.518 +CREATE TRIGGER "write_event_suggestion_created"
   1.519 +  AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
   1.520 +  "write_event_suggestion_created_trigger"();
   1.521 +
   1.522 +COMMENT ON FUNCTION "write_event_suggestion_created_trigger"()      IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
   1.523 +COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
   1.524 +
   1.525 +
   1.526 +-- Modified views:
   1.527 +
   1.528 +CREATE VIEW "unit_delegation" AS
   1.529 +  SELECT
   1.530 +    "unit"."id" AS "unit_id",
   1.531 +    "delegation"."id",
   1.532 +    "delegation"."truster_id",
   1.533 +    "delegation"."trustee_id",
   1.534 +    "delegation"."scope"
   1.535 +  FROM "unit"
   1.536 +  JOIN "delegation"
   1.537 +    ON "delegation"."unit_id" = "unit"."id"
   1.538 +  JOIN "member"
   1.539 +    ON "delegation"."truster_id" = "member"."id"
   1.540 +  JOIN "privilege"
   1.541 +    ON "delegation"."unit_id" = "privilege"."unit_id"
   1.542 +    AND "delegation"."truster_id" = "privilege"."member_id"
   1.543 +  WHERE "member"."active" AND "privilege"."voting_right";
   1.544 +
   1.545 +COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
   1.546 +
   1.547 +CREATE VIEW "area_delegation" AS
   1.548 +  SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
   1.549 +    "area"."id" AS "area_id",
   1.550 +    "delegation"."id",
   1.551 +    "delegation"."truster_id",
   1.552 +    "delegation"."trustee_id",
   1.553 +    "delegation"."scope"
   1.554 +  FROM "area"
   1.555 +  JOIN "delegation"
   1.556 +    ON "delegation"."unit_id" = "area"."unit_id"
   1.557 +    OR "delegation"."area_id" = "area"."id"
   1.558 +  JOIN "member"
   1.559 +    ON "delegation"."truster_id" = "member"."id"
   1.560 +  JOIN "privilege"
   1.561 +    ON "area"."unit_id" = "privilege"."unit_id"
   1.562 +    AND "delegation"."truster_id" = "privilege"."member_id"
   1.563 +  WHERE "member"."active" AND "privilege"."voting_right"
   1.564 +  ORDER BY
   1.565 +    "area"."id",
   1.566 +    "delegation"."truster_id",
   1.567 +    "delegation"."scope" DESC;
   1.568 +
   1.569 +COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
   1.570 +
   1.571 +CREATE VIEW "issue_delegation" AS
   1.572 +  SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
   1.573 +    "issue"."id" AS "issue_id",
   1.574 +    "delegation"."id",
   1.575 +    "delegation"."truster_id",
   1.576 +    "delegation"."trustee_id",
   1.577 +    "delegation"."scope"
   1.578 +  FROM "issue"
   1.579 +  JOIN "area"
   1.580 +    ON "area"."id" = "issue"."area_id"
   1.581 +  JOIN "delegation"
   1.582 +    ON "delegation"."unit_id" = "area"."unit_id"
   1.583 +    OR "delegation"."area_id" = "area"."id"
   1.584 +    OR "delegation"."issue_id" = "issue"."id"
   1.585 +  JOIN "member"
   1.586 +    ON "delegation"."truster_id" = "member"."id"
   1.587 +  JOIN "privilege"
   1.588 +    ON "area"."unit_id" = "privilege"."unit_id"
   1.589 +    AND "delegation"."truster_id" = "privilege"."member_id"
   1.590 +  WHERE "member"."active" AND "privilege"."voting_right"
   1.591 +  ORDER BY
   1.592 +    "issue"."id",
   1.593 +    "delegation"."truster_id",
   1.594 +    "delegation"."scope" DESC;
   1.595 +
   1.596 +COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
   1.597 +
   1.598 +CREATE VIEW "unit_member_count" AS
   1.599 +  SELECT
   1.600 +    "unit"."id" AS "unit_id",
   1.601 +    sum("member"."id") AS "member_count"
   1.602 +  FROM "unit"
   1.603 +  LEFT JOIN "privilege"
   1.604 +  ON "privilege"."unit_id" = "unit"."id" 
   1.605 +  AND "privilege"."voting_right"
   1.606 +  LEFT JOIN "member"
   1.607 +  ON "member"."id" = "privilege"."member_id"
   1.608 +  AND "member"."active"
   1.609 +  GROUP BY "unit"."id";
   1.610 +
   1.611 +COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
   1.612 +
   1.613 +DROP VIEW "area_member_count";
   1.614 +CREATE VIEW "area_member_count" AS
   1.615 +  SELECT
   1.616 +    "area"."id" AS "area_id",
   1.617 +    count("member"."id") AS "direct_member_count",
   1.618 +    coalesce(
   1.619 +      sum(
   1.620 +        CASE WHEN "member"."id" NOTNULL THEN
   1.621 +          "membership_weight"("area"."id", "member"."id")
   1.622 +        ELSE 0 END
   1.623 +      )
   1.624 +    ) AS "member_weight",
   1.625 +    coalesce(
   1.626 +      sum(
   1.627 +        CASE WHEN "member"."id" NOTNULL AND "membership"."autoreject" THEN
   1.628 +          "membership_weight"("area"."id", "member"."id")
   1.629 +        ELSE 0 END
   1.630 +      )
   1.631 +    ) AS "autoreject_weight"
   1.632 +  FROM "area"
   1.633 +  LEFT JOIN "membership"
   1.634 +  ON "area"."id" = "membership"."area_id"
   1.635 +  LEFT JOIN "privilege"
   1.636 +  ON "privilege"."unit_id" = "area"."unit_id"
   1.637 +  AND "privilege"."member_id" = "membership"."member_id"
   1.638 +  AND "privilege"."voting_right"
   1.639 +  LEFT JOIN "member"
   1.640 +  ON "member"."id" = "privilege"."member_id"  -- NOTE: no membership here!
   1.641 +  AND "member"."active"
   1.642 +  GROUP BY "area"."id";
   1.643 +
   1.644 +COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count", "member_weight" and "autoreject_weight" columns of table "area"';
   1.645 +
   1.646 +
   1.647 +-- New view "event_seen_by_member":
   1.648 +
   1.649 +CREATE VIEW "event_seen_by_member" AS
   1.650 +  SELECT
   1.651 +    "member"."id" AS "seen_by_member_id",
   1.652 +    CASE WHEN "event"."state" IN (
   1.653 +      'voting',
   1.654 +      'finished_without_winner',
   1.655 +      'finished_with_winner'
   1.656 +    ) THEN
   1.657 +      'voting'::"notify_level"
   1.658 +    ELSE
   1.659 +      CASE WHEN "event"."state" IN (
   1.660 +        'verification',
   1.661 +        'canceled_after_revocation_during_verification',
   1.662 +        'canceled_no_initiative_admitted'
   1.663 +      ) THEN
   1.664 +        'verification'::"notify_level"
   1.665 +      ELSE
   1.666 +        CASE WHEN "event"."state" IN (
   1.667 +          'discussion',
   1.668 +          'canceled_after_revocation_during_discussion'
   1.669 +        ) THEN
   1.670 +          'discussion'::"notify_level"
   1.671 +        ELSE
   1.672 +          'all'::"notify_level"
   1.673 +        END
   1.674 +      END
   1.675 +    END AS "notify_level",
   1.676 +    "event".*
   1.677 +  FROM "member" CROSS JOIN "event"
   1.678 +  LEFT JOIN "issue"
   1.679 +    ON "event"."issue_id" = "issue"."id"
   1.680 +  LEFT JOIN "membership"
   1.681 +    ON "member"."id" = "membership"."member_id"
   1.682 +    AND "issue"."area_id" = "membership"."area_id"
   1.683 +  LEFT JOIN "interest"
   1.684 +    ON "member"."id" = "interest"."member_id"
   1.685 +    AND "event"."issue_id" = "interest"."issue_id"
   1.686 +  LEFT JOIN "supporter"
   1.687 +    ON "member"."id" = "supporter"."member_id"
   1.688 +    AND "event"."initiative_id" = "supporter"."initiative_id"
   1.689 +  LEFT JOIN "ignored_member"
   1.690 +    ON "member"."id" = "ignored_member"."member_id"
   1.691 +    AND "event"."member_id" = "ignored_member"."other_member_id"
   1.692 +  LEFT JOIN "ignored_initiative"
   1.693 +    ON "member"."id" = "ignored_initiative"."member_id"
   1.694 +    AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
   1.695 +  WHERE (
   1.696 +    "supporter"."member_id" NOTNULL OR
   1.697 +    "interest"."member_id" NOTNULL OR
   1.698 +    ( "membership"."member_id" NOTNULL AND
   1.699 +      "event"."event" IN (
   1.700 +        'issue_state_changed',
   1.701 +        'initiative_created_in_new_issue',
   1.702 +        'initiative_created_in_existing_issue',
   1.703 +        'initiative_revoked' ) ) )
   1.704 +  AND "ignored_member"."member_id" ISNULL
   1.705 +  AND "ignored_initiative"."member_id" ISNULL;
   1.706 +
   1.707 +COMMENT ON VIEW "event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests and support';
   1.708 +
   1.709 +
   1.710 +-- New view "pending_notification":
   1.711 +
   1.712 +CREATE VIEW "pending_notification" AS
   1.713 +  SELECT
   1.714 +    "member"."id" AS "seen_by_member_id",
   1.715 +    "event".*
   1.716 +  FROM "member" CROSS JOIN "event"
   1.717 +  LEFT JOIN "issue"
   1.718 +    ON "event"."issue_id" = "issue"."id"
   1.719 +  LEFT JOIN "membership"
   1.720 +    ON "member"."id" = "membership"."member_id"
   1.721 +    AND "issue"."area_id" = "membership"."area_id"
   1.722 +  LEFT JOIN "interest"
   1.723 +    ON "member"."id" = "interest"."member_id"
   1.724 +    AND "event"."issue_id" = "interest"."issue_id"
   1.725 +  LEFT JOIN "supporter"
   1.726 +    ON "member"."id" = "supporter"."member_id"
   1.727 +    AND "event"."initiative_id" = "supporter"."initiative_id"
   1.728 +  LEFT JOIN "ignored_member"
   1.729 +    ON "member"."id" = "ignored_member"."member_id"
   1.730 +    AND "event"."member_id" = "ignored_member"."other_member_id"
   1.731 +  LEFT JOIN "ignored_initiative"
   1.732 +    ON "member"."id" = "ignored_initiative"."member_id"
   1.733 +    AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
   1.734 +  WHERE (
   1.735 +    "member"."notify_event_id" ISNULL OR
   1.736 +    ( "member"."notify_event_id" NOTNULL AND
   1.737 +      "member"."notify_event_id" < "event"."id" ) )
   1.738 +  AND (
   1.739 +    ( "member"."notify_level" >= 'all' ) OR
   1.740 +    ( "member"."notify_level" >= 'voting' AND
   1.741 +      "event"."state" IN (
   1.742 +        'voting',
   1.743 +        'finished_without_winner',
   1.744 +        'finished_with_winner' ) ) OR
   1.745 +    ( "member"."notify_level" >= 'verification' AND
   1.746 +      "event"."state" IN (
   1.747 +        'verification',
   1.748 +        'canceled_after_revocation_during_verification',
   1.749 +        'canceled_no_initiative_admitted' ) ) OR
   1.750 +    ( "member"."notify_level" >= 'discussion' AND
   1.751 +      "event"."state" IN (
   1.752 +        'discussion',
   1.753 +        'canceled_after_revocation_during_discussion' ) ) )
   1.754 +  AND (
   1.755 +    "supporter"."member_id" NOTNULL OR
   1.756 +    "interest"."member_id" NOTNULL OR
   1.757 +    ( "membership"."member_id" NOTNULL AND
   1.758 +      "event"."event" IN (
   1.759 +        'issue_state_changed',
   1.760 +        'initiative_created_in_new_issue',
   1.761 +        'initiative_created_in_existing_issue',
   1.762 +        'initiative_revoked' ) ) )
   1.763 +  AND "ignored_member"."member_id" ISNULL
   1.764 +  AND "ignored_initiative"."member_id" ISNULL;
   1.765 +
   1.766 +COMMENT ON VIEW "pending_notification" IS 'Events to be sent to "notify_email" address of member referred to by "seen_by_member_id"';
   1.767 +
   1.768 +
   1.769 +COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
   1.770 +COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
   1.771 +COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
   1.772 +COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
   1.773 +COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
   1.774 +COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
   1.775 +
   1.776 +
   1.777 +-- Modified "delegation_chain" functions:
   1.778 +
   1.779 +CREATE TYPE "delegation_chain_row" AS (
   1.780 +        "index"                 INT4,
   1.781 +        "member_id"             INT4,
   1.782 +        "member_valid"          BOOLEAN,
   1.783 +        "participation"         BOOLEAN,
   1.784 +        "overridden"            BOOLEAN,
   1.785 +        "scope_in"              "delegation_scope",
   1.786 +        "scope_out"             "delegation_scope",
   1.787 +        "disabled_out"          BOOLEAN,
   1.788 +        "loop"                  "delegation_chain_loop_tag" );
   1.789 +
   1.790 +COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain"(...) functions';
   1.791 +
   1.792 +COMMENT ON COLUMN "delegation_chain_row"."index"         IS 'Index starting with 0 and counting up';
   1.793 +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';
   1.794 +COMMENT ON COLUMN "delegation_chain_row"."overridden"    IS 'True, if an entry with lower index has "participation" set to true';
   1.795 +COMMENT ON COLUMN "delegation_chain_row"."scope_in"      IS 'Scope of used incoming delegation';
   1.796 +COMMENT ON COLUMN "delegation_chain_row"."scope_out"     IS 'Scope of used outgoing delegation';
   1.797 +COMMENT ON COLUMN "delegation_chain_row"."disabled_out"  IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
   1.798 +COMMENT ON COLUMN "delegation_chain_row"."loop"          IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
   1.799 +
   1.800 +
   1.801 +CREATE FUNCTION "delegation_chain"
   1.802 +  ( "member_id_p"           "member"."id"%TYPE,
   1.803 +    "unit_id_p"             "unit"."id"%TYPE,
   1.804 +    "area_id_p"             "area"."id"%TYPE,
   1.805 +    "issue_id_p"            "issue"."id"%TYPE,
   1.806 +    "simulate_trustee_id_p" "member"."id"%TYPE )
   1.807 +  RETURNS SETOF "delegation_chain_row"
   1.808 +  LANGUAGE 'plpgsql' STABLE AS $$
   1.809 +    DECLARE
   1.810 +      "scope_v"            "delegation_scope";
   1.811 +      "unit_id_v"          "unit"."id"%TYPE;
   1.812 +      "area_id_v"          "area"."id"%TYPE;
   1.813 +      "visited_member_ids" INT4[];  -- "member"."id"%TYPE[]
   1.814 +      "loop_member_id_v"   "member"."id"%TYPE;
   1.815 +      "output_row"         "delegation_chain_row";
   1.816 +      "output_rows"        "delegation_chain_row"[];
   1.817 +      "delegation_row"     "delegation"%ROWTYPE;
   1.818 +      "row_count"          INT4;
   1.819 +      "i"                  INT4;
   1.820 +      "loop_v"             BOOLEAN;
   1.821 +    BEGIN
   1.822 +      IF
   1.823 +        "unit_id_p" NOTNULL AND
   1.824 +        "area_id_p" ISNULL AND
   1.825 +        "issue_id_p" ISNULL
   1.826 +      THEN
   1.827 +        "scope_v" := 'unit';
   1.828 +        "unit_id_v" := "unit_id_p";
   1.829 +      ELSIF
   1.830 +        "unit_id_p" ISNULL AND
   1.831 +        "area_id_p" NOTNULL AND
   1.832 +        "issue_id_p" ISNULL
   1.833 +      THEN
   1.834 +        "scope_v" := 'area';
   1.835 +        "area_id_v" := "area_id_p";
   1.836 +        SELECT "unit_id" INTO "unit_id_v"
   1.837 +          FROM "area" WHERE "id" = "area_id_v";
   1.838 +      ELSIF
   1.839 +        "unit_id_p" ISNULL AND
   1.840 +        "area_id_p" ISNULL AND
   1.841 +        "issue_id_p" NOTNULL
   1.842 +      THEN
   1.843 +        "scope_v" := 'issue';
   1.844 +        SELECT "area_id" INTO "area_id_v"
   1.845 +          FROM "issue" WHERE "id" = "issue_id_p";
   1.846 +        SELECT "unit_id" INTO "unit_id_v"
   1.847 +          FROM "area"  WHERE "id" = "area_id_v";
   1.848 +      ELSE
   1.849 +        RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
   1.850 +      END IF;
   1.851 +      "visited_member_ids" := '{}';
   1.852 +      "loop_member_id_v"   := NULL;
   1.853 +      "output_rows"        := '{}';
   1.854 +      "output_row"."index"         := 0;
   1.855 +      "output_row"."member_id"     := "member_id_p";
   1.856 +      "output_row"."member_valid"  := TRUE;
   1.857 +      "output_row"."participation" := FALSE;
   1.858 +      "output_row"."overridden"    := FALSE;
   1.859 +      "output_row"."disabled_out"  := FALSE;
   1.860 +      "output_row"."scope_out"     := NULL;
   1.861 +      LOOP
   1.862 +        IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
   1.863 +          "loop_member_id_v" := "output_row"."member_id";
   1.864 +        ELSE
   1.865 +          "visited_member_ids" :=
   1.866 +            "visited_member_ids" || "output_row"."member_id";
   1.867 +        END IF;
   1.868 +        IF "output_row"."participation" THEN
   1.869 +          "output_row"."overridden" := TRUE;
   1.870 +        END IF;
   1.871 +        "output_row"."scope_in" := "output_row"."scope_out";
   1.872 +        IF EXISTS (
   1.873 +          SELECT NULL FROM "member" JOIN "privilege"
   1.874 +          ON "privilege"."member_id" = "member"."id"
   1.875 +          AND "privilege"."unit_id" = "unit_id_v"
   1.876 +          WHERE "id" = "output_row"."member_id"
   1.877 +          AND "member"."active" AND "privilege"."voting_right"
   1.878 +        ) THEN
   1.879 +          IF "scope_v" = 'unit' THEN
   1.880 +            SELECT * INTO "delegation_row" FROM "delegation"
   1.881 +              WHERE "truster_id" = "output_row"."member_id"
   1.882 +              AND "unit_id" = "unit_id_v";
   1.883 +          ELSIF "scope_v" = 'area' THEN
   1.884 +            "output_row"."participation" := EXISTS (
   1.885 +              SELECT NULL FROM "membership"
   1.886 +              WHERE "area_id" = "area_id_p"
   1.887 +              AND "member_id" = "output_row"."member_id"
   1.888 +            );
   1.889 +            SELECT * INTO "delegation_row" FROM "delegation"
   1.890 +              WHERE "truster_id" = "output_row"."member_id"
   1.891 +              AND (
   1.892 +                "unit_id" = "unit_id_v" OR
   1.893 +                "area_id" = "area_id_v"
   1.894 +              )
   1.895 +              ORDER BY "scope" DESC;
   1.896 +          ELSIF "scope_v" = 'issue' THEN
   1.897 +            "output_row"."participation" := EXISTS (
   1.898 +              SELECT NULL FROM "interest"
   1.899 +              WHERE "issue_id" = "issue_id_p"
   1.900 +              AND "member_id" = "output_row"."member_id"
   1.901 +            );
   1.902 +            SELECT * INTO "delegation_row" FROM "delegation"
   1.903 +              WHERE "truster_id" = "output_row"."member_id"
   1.904 +              AND (
   1.905 +                "unit_id" = "unit_id_v" OR
   1.906 +                "area_id" = "area_id_v" OR
   1.907 +                "issue_id" = "issue_id_p"
   1.908 +              )
   1.909 +              ORDER BY "scope" DESC;
   1.910 +          END IF;
   1.911 +        ELSE
   1.912 +          "output_row"."member_valid"  := FALSE;
   1.913 +          "output_row"."participation" := FALSE;
   1.914 +          "output_row"."scope_out"     := NULL;
   1.915 +          "delegation_row" := ROW(NULL);
   1.916 +        END IF;
   1.917 +        IF
   1.918 +          "output_row"."member_id" = "member_id_p" AND
   1.919 +          "simulate_trustee_id_p" NOTNULL
   1.920 +        THEN
   1.921 +          "output_row"."scope_out" := "scope_v";
   1.922 +          "output_rows" := "output_rows" || "output_row";
   1.923 +          "output_row"."member_id" := "simulate_trustee_id_p";
   1.924 +        ELSIF "delegation_row"."trustee_id" NOTNULL THEN
   1.925 +          "output_row"."scope_out" := "delegation_row"."scope";
   1.926 +          "output_rows" := "output_rows" || "output_row";
   1.927 +          "output_row"."member_id" := "delegation_row"."trustee_id";
   1.928 +        ELSIF "delegation_row"."scope" NOTNULL THEN
   1.929 +          "output_row"."scope_out" := "delegation_row"."scope";
   1.930 +          "output_row"."disabled_out" := TRUE;
   1.931 +          "output_rows" := "output_rows" || "output_row";
   1.932 +          EXIT;
   1.933 +        ELSE
   1.934 +          "output_row"."scope_out" := NULL;
   1.935 +          "output_rows" := "output_rows" || "output_row";
   1.936 +          EXIT;
   1.937 +        END IF;
   1.938 +        EXIT WHEN "loop_member_id_v" NOTNULL;
   1.939 +        "output_row"."index" := "output_row"."index" + 1;
   1.940 +      END LOOP;
   1.941 +      "row_count" := array_upper("output_rows", 1);
   1.942 +      "i"      := 1;
   1.943 +      "loop_v" := FALSE;
   1.944 +      LOOP
   1.945 +        "output_row" := "output_rows"["i"];
   1.946 +        EXIT WHEN "output_row" ISNULL;  -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
   1.947 +        IF "loop_v" THEN
   1.948 +          IF "i" + 1 = "row_count" THEN
   1.949 +            "output_row"."loop" := 'last';
   1.950 +          ELSIF "i" = "row_count" THEN
   1.951 +            "output_row"."loop" := 'repetition';
   1.952 +          ELSE
   1.953 +            "output_row"."loop" := 'intermediate';
   1.954 +          END IF;
   1.955 +        ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
   1.956 +          "output_row"."loop" := 'first';
   1.957 +          "loop_v" := TRUE;
   1.958 +        END IF;
   1.959 +        IF "scope_v" = 'unit' THEN
   1.960 +          "output_row"."participation" := NULL;
   1.961 +        END IF;
   1.962 +        RETURN NEXT "output_row";
   1.963 +        "i" := "i" + 1;
   1.964 +      END LOOP;
   1.965 +      RETURN;
   1.966 +    END;
   1.967 +  $$;
   1.968 +
   1.969 +COMMENT ON FUNCTION "delegation_chain"
   1.970 +  ( "member"."id"%TYPE,
   1.971 +    "unit"."id"%TYPE,
   1.972 +    "area"."id"%TYPE,
   1.973 +    "issue"."id"%TYPE,
   1.974 +    "member"."id"%TYPE )
   1.975 +  IS 'Helper function for frontends to display delegation chains; Not part of internal voting logic';
   1.976 +
   1.977 +
   1.978 +CREATE FUNCTION "delegation_chain"
   1.979 +  ( "member_id_p" "member"."id"%TYPE,
   1.980 +    "unit_id_p"   "unit"."id"%TYPE,
   1.981 +    "area_id_p"   "area"."id"%TYPE,
   1.982 +    "issue_id_p"  "issue"."id"%TYPE )
   1.983 +  RETURNS SETOF "delegation_chain_row"
   1.984 +  LANGUAGE 'plpgsql' STABLE AS $$
   1.985 +    DECLARE
   1.986 +      "result_row" "delegation_chain_row";
   1.987 +    BEGIN
   1.988 +      FOR "result_row" IN
   1.989 +        SELECT * FROM "delegation_chain"(
   1.990 +          "member_id_p", "unit_id_p", "area_id_p", "issue_id_p", NULL
   1.991 +        )
   1.992 +      LOOP
   1.993 +        RETURN NEXT "result_row";
   1.994 +      END LOOP;
   1.995 +      RETURN;
   1.996 +    END;
   1.997 +  $$;
   1.998 +
   1.999 +COMMENT ON FUNCTION "delegation_chain"
  1.1000 +  ( "member"."id"%TYPE,
  1.1001 +    "unit"."id"%TYPE,
  1.1002 +    "area"."id"%TYPE,
  1.1003 +    "issue"."id"%TYPE )
  1.1004 +  IS 'Shortcut for "delegation_chain"(...) function where 4th parameter is null';
  1.1005 +
  1.1006 +
  1.1007 +-- Other modified functions:
  1.1008 +
  1.1009 +CREATE OR REPLACE FUNCTION "lock_issue"
  1.1010 +  ( "issue_id_p" "issue"."id"%TYPE )
  1.1011 +  RETURNS VOID
  1.1012 +  LANGUAGE 'plpgsql' VOLATILE AS $$
  1.1013 +    BEGIN
  1.1014 +      LOCK TABLE "member"     IN SHARE MODE;
  1.1015 +      LOCK TABLE "privilege"  IN SHARE MODE;
  1.1016 +      LOCK TABLE "membership" IN SHARE MODE;
  1.1017 +      LOCK TABLE "policy"     IN SHARE MODE;
  1.1018 +      PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
  1.1019 +      -- NOTE: The row-level exclusive lock in combination with the
  1.1020 +      -- share_row_lock_issue(_via_initiative)_trigger functions (which
  1.1021 +      -- acquire a row-level share lock on the issue) ensure that no data
  1.1022 +      -- is changed, which could affect calculation of snapshots or
  1.1023 +      -- counting of votes. Table "delegation" must be table-level-locked,
  1.1024 +      -- as it also contains issue- and global-scope delegations.
  1.1025 +      LOCK TABLE "delegation" IN SHARE MODE;
  1.1026 +      LOCK TABLE "direct_population_snapshot"     IN EXCLUSIVE MODE;
  1.1027 +      LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
  1.1028 +      LOCK TABLE "direct_interest_snapshot"       IN EXCLUSIVE MODE;
  1.1029 +      LOCK TABLE "delegating_interest_snapshot"   IN EXCLUSIVE MODE;
  1.1030 +      LOCK TABLE "direct_supporter_snapshot"      IN EXCLUSIVE MODE;
  1.1031 +      RETURN;
  1.1032 +    END;
  1.1033 +  $$;
  1.1034 +
  1.1035 +CREATE OR REPLACE FUNCTION "calculate_member_counts"()
  1.1036 +  RETURNS VOID
  1.1037 +  LANGUAGE 'plpgsql' VOLATILE AS $$
  1.1038 +    BEGIN
  1.1039 +      LOCK TABLE "member"       IN SHARE MODE;
  1.1040 +      LOCK TABLE "member_count" IN EXCLUSIVE MODE;
  1.1041 +      LOCK TABLE "unit"         IN EXCLUSIVE MODE;
  1.1042 +      LOCK TABLE "area"         IN EXCLUSIVE MODE;
  1.1043 +      LOCK TABLE "privilege"    IN SHARE MODE;
  1.1044 +      LOCK TABLE "membership"   IN SHARE MODE;
  1.1045 +      DELETE FROM "member_count";
  1.1046 +      INSERT INTO "member_count" ("total_count")
  1.1047 +        SELECT "total_count" FROM "member_count_view";
  1.1048 +      UPDATE "unit" SET "member_count" = "view"."member_count"
  1.1049 +        FROM "unit_member_count" AS "view"
  1.1050 +        WHERE "view"."unit_id" = "unit"."id";
  1.1051 +      UPDATE "area" SET
  1.1052 +        "direct_member_count" = "view"."direct_member_count",
  1.1053 +        "member_weight"       = "view"."member_weight",
  1.1054 +        "autoreject_weight"   = "view"."autoreject_weight"
  1.1055 +        FROM "area_member_count" AS "view"
  1.1056 +        WHERE "view"."area_id" = "area"."id";
  1.1057 +      RETURN;
  1.1058 +    END;
  1.1059 +  $$;
  1.1060 +
  1.1061 +CREATE OR REPLACE FUNCTION "create_population_snapshot"
  1.1062 +  ( "issue_id_p" "issue"."id"%TYPE )
  1.1063 +  RETURNS VOID
  1.1064 +  LANGUAGE 'plpgsql' VOLATILE AS $$
  1.1065 +    DECLARE
  1.1066 +      "member_id_v" "member"."id"%TYPE;
  1.1067 +    BEGIN
  1.1068 +      DELETE FROM "direct_population_snapshot"
  1.1069 +        WHERE "issue_id" = "issue_id_p"
  1.1070 +        AND "event" = 'periodic';
  1.1071 +      DELETE FROM "delegating_population_snapshot"
  1.1072 +        WHERE "issue_id" = "issue_id_p"
  1.1073 +        AND "event" = 'periodic';
  1.1074 +      INSERT INTO "direct_population_snapshot"
  1.1075 +        ("issue_id", "event", "member_id")
  1.1076 +        SELECT
  1.1077 +          "issue_id_p"                 AS "issue_id",
  1.1078 +          'periodic'::"snapshot_event" AS "event",
  1.1079 +          "member"."id"                AS "member_id"
  1.1080 +        FROM "issue"
  1.1081 +        JOIN "area" ON "issue"."area_id" = "area"."id"
  1.1082 +        JOIN "membership" ON "area"."id" = "membership"."area_id"
  1.1083 +        JOIN "member" ON "membership"."member_id" = "member"."id"
  1.1084 +        JOIN "privilege"
  1.1085 +          ON "privilege"."unit_id" = "area"."unit_id"
  1.1086 +          AND "privilege"."member_id" = "member"."id"
  1.1087 +        WHERE "issue"."id" = "issue_id_p"
  1.1088 +        AND "member"."active" AND "privilege"."voting_right"
  1.1089 +        UNION
  1.1090 +        SELECT
  1.1091 +          "issue_id_p"                 AS "issue_id",
  1.1092 +          'periodic'::"snapshot_event" AS "event",
  1.1093 +          "member"."id"                AS "member_id"
  1.1094 +        FROM "issue"
  1.1095 +        JOIN "area" ON "issue"."area_id" = "area"."id"
  1.1096 +        JOIN "interest" ON "issue"."id" = "interest"."issue_id"
  1.1097 +        JOIN "member" ON "interest"."member_id" = "member"."id"
  1.1098 +        JOIN "privilege"
  1.1099 +          ON "privilege"."unit_id" = "area"."unit_id"
  1.1100 +          AND "privilege"."member_id" = "member"."id"
  1.1101 +        WHERE "issue"."id" = "issue_id_p"
  1.1102 +        AND "member"."active" AND "privilege"."voting_right";
  1.1103 +      FOR "member_id_v" IN
  1.1104 +        SELECT "member_id" FROM "direct_population_snapshot"
  1.1105 +        WHERE "issue_id" = "issue_id_p"
  1.1106 +        AND "event" = 'periodic'
  1.1107 +      LOOP
  1.1108 +        UPDATE "direct_population_snapshot" SET
  1.1109 +          "weight" = 1 +
  1.1110 +            "weight_of_added_delegations_for_population_snapshot"(
  1.1111 +              "issue_id_p",
  1.1112 +              "member_id_v",
  1.1113 +              '{}'
  1.1114 +            )
  1.1115 +          WHERE "issue_id" = "issue_id_p"
  1.1116 +          AND "event" = 'periodic'
  1.1117 +          AND "member_id" = "member_id_v";
  1.1118 +      END LOOP;
  1.1119 +      RETURN;
  1.1120 +    END;
  1.1121 +  $$;
  1.1122 +
  1.1123 +CREATE OR REPLACE FUNCTION "create_interest_snapshot"
  1.1124 +  ( "issue_id_p" "issue"."id"%TYPE )
  1.1125 +  RETURNS VOID
  1.1126 +  LANGUAGE 'plpgsql' VOLATILE AS $$
  1.1127 +    DECLARE
  1.1128 +      "member_id_v" "member"."id"%TYPE;
  1.1129 +    BEGIN
  1.1130 +      DELETE FROM "direct_interest_snapshot"
  1.1131 +        WHERE "issue_id" = "issue_id_p"
  1.1132 +        AND "event" = 'periodic';
  1.1133 +      DELETE FROM "delegating_interest_snapshot"
  1.1134 +        WHERE "issue_id" = "issue_id_p"
  1.1135 +        AND "event" = 'periodic';
  1.1136 +      DELETE FROM "direct_supporter_snapshot"
  1.1137 +        WHERE "issue_id" = "issue_id_p"
  1.1138 +        AND "event" = 'periodic';
  1.1139 +      INSERT INTO "direct_interest_snapshot"
  1.1140 +        ("issue_id", "event", "member_id", "voting_requested")
  1.1141 +        SELECT
  1.1142 +          "issue_id_p"  AS "issue_id",
  1.1143 +          'periodic'    AS "event",
  1.1144 +          "member"."id" AS "member_id",
  1.1145 +          "interest"."voting_requested"
  1.1146 +        FROM "issue"
  1.1147 +        JOIN "area" ON "issue"."area_id" = "area"."id"
  1.1148 +        JOIN "interest" ON "issue"."id" = "interest"."issue_id"
  1.1149 +        JOIN "member" ON "interest"."member_id" = "member"."id"
  1.1150 +        JOIN "privilege"
  1.1151 +          ON "privilege"."unit_id" = "area"."unit_id"
  1.1152 +          AND "privilege"."member_id" = "member"."id"
  1.1153 +        WHERE "issue"."id" = "issue_id_p"
  1.1154 +        AND "member"."active" AND "privilege"."voting_right";
  1.1155 +      FOR "member_id_v" IN
  1.1156 +        SELECT "member_id" FROM "direct_interest_snapshot"
  1.1157 +        WHERE "issue_id" = "issue_id_p"
  1.1158 +        AND "event" = 'periodic'
  1.1159 +      LOOP
  1.1160 +        UPDATE "direct_interest_snapshot" SET
  1.1161 +          "weight" = 1 +
  1.1162 +            "weight_of_added_delegations_for_interest_snapshot"(
  1.1163 +              "issue_id_p",
  1.1164 +              "member_id_v",
  1.1165 +              '{}'
  1.1166 +            )
  1.1167 +          WHERE "issue_id" = "issue_id_p"
  1.1168 +          AND "event" = 'periodic'
  1.1169 +          AND "member_id" = "member_id_v";
  1.1170 +      END LOOP;
  1.1171 +      INSERT INTO "direct_supporter_snapshot"
  1.1172 +        ( "issue_id", "initiative_id", "event", "member_id",
  1.1173 +          "informed", "satisfied" )
  1.1174 +        SELECT
  1.1175 +          "issue_id_p"            AS "issue_id",
  1.1176 +          "initiative"."id"       AS "initiative_id",
  1.1177 +          'periodic'              AS "event",
  1.1178 +          "supporter"."member_id" AS "member_id",
  1.1179 +          "supporter"."draft_id" = "current_draft"."id" AS "informed",
  1.1180 +          NOT EXISTS (
  1.1181 +            SELECT NULL FROM "critical_opinion"
  1.1182 +            WHERE "initiative_id" = "initiative"."id"
  1.1183 +            AND "member_id" = "supporter"."member_id"
  1.1184 +          ) AS "satisfied"
  1.1185 +        FROM "initiative"
  1.1186 +        JOIN "supporter"
  1.1187 +        ON "supporter"."initiative_id" = "initiative"."id"
  1.1188 +        JOIN "current_draft"
  1.1189 +        ON "initiative"."id" = "current_draft"."initiative_id"
  1.1190 +        JOIN "direct_interest_snapshot"
  1.1191 +        ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
  1.1192 +        AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
  1.1193 +        AND "event" = 'periodic'
  1.1194 +        WHERE "initiative"."issue_id" = "issue_id_p";
  1.1195 +      RETURN;
  1.1196 +    END;
  1.1197 +  $$;
  1.1198 +
  1.1199 +CREATE OR REPLACE FUNCTION "freeze_after_snapshot"
  1.1200 +  ( "issue_id_p" "issue"."id"%TYPE )
  1.1201 +  RETURNS VOID
  1.1202 +  LANGUAGE 'plpgsql' VOLATILE AS $$
  1.1203 +    DECLARE
  1.1204 +      "issue_row"      "issue"%ROWTYPE;
  1.1205 +      "policy_row"     "policy"%ROWTYPE;
  1.1206 +      "initiative_row" "initiative"%ROWTYPE;
  1.1207 +    BEGIN
  1.1208 +      SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  1.1209 +      SELECT * INTO "policy_row"
  1.1210 +        FROM "policy" WHERE "id" = "issue_row"."policy_id";
  1.1211 +      PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
  1.1212 +      FOR "initiative_row" IN
  1.1213 +        SELECT * FROM "initiative"
  1.1214 +        WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
  1.1215 +      LOOP
  1.1216 +        IF
  1.1217 +          "initiative_row"."satisfied_supporter_count" > 0 AND
  1.1218 +          "initiative_row"."satisfied_supporter_count" *
  1.1219 +          "policy_row"."initiative_quorum_den" >=
  1.1220 +          "issue_row"."population" * "policy_row"."initiative_quorum_num"
  1.1221 +        THEN
  1.1222 +          UPDATE "initiative" SET "admitted" = TRUE
  1.1223 +            WHERE "id" = "initiative_row"."id";
  1.1224 +        ELSE
  1.1225 +          UPDATE "initiative" SET "admitted" = FALSE
  1.1226 +            WHERE "id" = "initiative_row"."id";
  1.1227 +        END IF;
  1.1228 +      END LOOP;
  1.1229 +      IF EXISTS (
  1.1230 +        SELECT NULL FROM "initiative"
  1.1231 +        WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
  1.1232 +      ) THEN
  1.1233 +        UPDATE "issue" SET
  1.1234 +          "state"        = 'voting',
  1.1235 +          "accepted"     = coalesce("accepted", now()),
  1.1236 +          "half_frozen"  = coalesce("half_frozen", now()),
  1.1237 +          "fully_frozen" = now()
  1.1238 +          WHERE "id" = "issue_id_p";
  1.1239 +      ELSE
  1.1240 +        UPDATE "issue" SET
  1.1241 +          "state"           = 'canceled_no_initiative_admitted',
  1.1242 +          "accepted"        = coalesce("accepted", now()),
  1.1243 +          "half_frozen"     = coalesce("half_frozen", now()),
  1.1244 +          "fully_frozen"    = now(),
  1.1245 +          "closed"          = now(),
  1.1246 +          "ranks_available" = TRUE
  1.1247 +          WHERE "id" = "issue_id_p";
  1.1248 +        -- NOTE: The following DELETE statements have effect only when
  1.1249 +        --       issue state has been manipulated
  1.1250 +        DELETE FROM "direct_voter"     WHERE "issue_id" = "issue_id_p";
  1.1251 +        DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
  1.1252 +        DELETE FROM "battle"           WHERE "issue_id" = "issue_id_p";
  1.1253 +      END IF;
  1.1254 +      RETURN;
  1.1255 +    END;
  1.1256 +  $$;
  1.1257 +
  1.1258 +CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
  1.1259 +  RETURNS VOID
  1.1260 +  LANGUAGE 'plpgsql' VOLATILE AS $$
  1.1261 +    DECLARE
  1.1262 +      "area_id_v"   "area"."id"%TYPE;
  1.1263 +      "unit_id_v"   "unit"."id"%TYPE;
  1.1264 +      "member_id_v" "member"."id"%TYPE;
  1.1265 +    BEGIN
  1.1266 +      PERFORM "lock_issue"("issue_id_p");
  1.1267 +      SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
  1.1268 +      SELECT "unit_id" INTO "unit_id_v" FROM "area"  WHERE "id" = "area_id_v";
  1.1269 +      DELETE FROM "delegating_voter"
  1.1270 +        WHERE "issue_id" = "issue_id_p";
  1.1271 +      DELETE FROM "direct_voter"
  1.1272 +        WHERE "issue_id" = "issue_id_p"
  1.1273 +        AND "autoreject" = TRUE;
  1.1274 +      DELETE FROM "direct_voter"
  1.1275 +        USING (
  1.1276 +          SELECT
  1.1277 +            "direct_voter"."member_id"
  1.1278 +          FROM "direct_voter"
  1.1279 +          JOIN "member" ON "direct_voter"."member_id" = "member"."id"
  1.1280 +          LEFT JOIN "privilege"
  1.1281 +          ON "privilege"."unit_id" = "unit_id_v"
  1.1282 +          AND "privilege"."member_id" = "direct_voter"."member_id"
  1.1283 +          WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
  1.1284 +            "member"."active" = FALSE OR
  1.1285 +            "privilege"."voting_right" ISNULL OR
  1.1286 +            "privilege"."voting_right" = FALSE
  1.1287 +          )
  1.1288 +        ) AS "subquery"
  1.1289 +        WHERE "direct_voter"."issue_id" = "issue_id_p"
  1.1290 +        AND "direct_voter"."member_id" = "subquery"."member_id";
  1.1291 +      UPDATE "direct_voter" SET "weight" = 1
  1.1292 +        WHERE "issue_id" = "issue_id_p";
  1.1293 +      PERFORM "add_vote_delegations"("issue_id_p");
  1.1294 +      FOR "member_id_v" IN
  1.1295 +        SELECT "interest"."member_id"
  1.1296 +          FROM "interest"
  1.1297 +          JOIN "member"
  1.1298 +            ON "interest"."member_id" = "member"."id"
  1.1299 +          JOIN "privilege"
  1.1300 +            ON "privilege"."unit_id" = "unit_id_v"
  1.1301 +            AND "privilege"."member_id" = "member"."id"
  1.1302 +          LEFT JOIN "direct_voter"
  1.1303 +            ON "interest"."member_id" = "direct_voter"."member_id"
  1.1304 +            AND "interest"."issue_id" = "direct_voter"."issue_id"
  1.1305 +          LEFT JOIN "delegating_voter"
  1.1306 +            ON "interest"."member_id" = "delegating_voter"."member_id"
  1.1307 +            AND "interest"."issue_id" = "delegating_voter"."issue_id"
  1.1308 +          WHERE "interest"."issue_id" = "issue_id_p"
  1.1309 +          AND "interest"."autoreject" = TRUE
  1.1310 +          AND "member"."active"
  1.1311 +          AND "privilege"."voting_right"
  1.1312 +          AND "direct_voter"."member_id" ISNULL
  1.1313 +          AND "delegating_voter"."member_id" ISNULL
  1.1314 +        UNION SELECT "membership"."member_id"
  1.1315 +          FROM "membership"
  1.1316 +          JOIN "member"
  1.1317 +            ON "membership"."member_id" = "member"."id"
  1.1318 +          JOIN "privilege"
  1.1319 +            ON "privilege"."unit_id" = "unit_id_v"
  1.1320 +            AND "privilege"."member_id" = "member"."id"
  1.1321 +          LEFT JOIN "interest"
  1.1322 +            ON "membership"."member_id" = "interest"."member_id"
  1.1323 +            AND "interest"."issue_id" = "issue_id_p"
  1.1324 +          LEFT JOIN "direct_voter"
  1.1325 +            ON "membership"."member_id" = "direct_voter"."member_id"
  1.1326 +            AND "direct_voter"."issue_id" = "issue_id_p"
  1.1327 +          LEFT JOIN "delegating_voter"
  1.1328 +            ON "membership"."member_id" = "delegating_voter"."member_id"
  1.1329 +            AND "delegating_voter"."issue_id" = "issue_id_p"
  1.1330 +          WHERE "membership"."area_id" = "area_id_v"
  1.1331 +          AND "membership"."autoreject" = TRUE
  1.1332 +          AND "member"."active"
  1.1333 +          AND "privilege"."voting_right"
  1.1334 +          AND "interest"."autoreject" ISNULL
  1.1335 +          AND "direct_voter"."member_id" ISNULL
  1.1336 +          AND "delegating_voter"."member_id" ISNULL
  1.1337 +      LOOP
  1.1338 +        INSERT INTO "direct_voter"
  1.1339 +          ("member_id", "issue_id", "weight", "autoreject") VALUES
  1.1340 +          ("member_id_v", "issue_id_p", 1, TRUE);
  1.1341 +        INSERT INTO "vote" (
  1.1342 +          "member_id",
  1.1343 +          "issue_id",
  1.1344 +          "initiative_id",
  1.1345 +          "grade"
  1.1346 +          ) SELECT
  1.1347 +            "member_id_v" AS "member_id",
  1.1348 +            "issue_id_p"  AS "issue_id",
  1.1349 +            "id"          AS "initiative_id",
  1.1350 +            -1            AS "grade"
  1.1351 +          FROM "initiative"
  1.1352 +          WHERE "issue_id" = "issue_id_p" AND "admitted";
  1.1353 +      END LOOP;
  1.1354 +      PERFORM "add_vote_delegations"("issue_id_p");
  1.1355 +      UPDATE "issue" SET
  1.1356 +        "state"  = 'calculation',
  1.1357 +        "closed" = now(),
  1.1358 +        "voter_count" = (
  1.1359 +          SELECT coalesce(sum("weight"), 0)
  1.1360 +          FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
  1.1361 +        )
  1.1362 +        WHERE "id" = "issue_id_p";
  1.1363 +      UPDATE "initiative" SET
  1.1364 +        "positive_votes" = "vote_counts"."positive_votes",
  1.1365 +        "negative_votes" = "vote_counts"."negative_votes",
  1.1366 +        "agreed" = CASE WHEN "majority_strict" THEN
  1.1367 +          "vote_counts"."positive_votes" * "majority_den" >
  1.1368 +          "majority_num" *
  1.1369 +          ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
  1.1370 +        ELSE
  1.1371 +          "vote_counts"."positive_votes" * "majority_den" >=
  1.1372 +          "majority_num" *
  1.1373 +          ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
  1.1374 +        END
  1.1375 +        FROM
  1.1376 +          ( SELECT
  1.1377 +              "initiative"."id" AS "initiative_id",
  1.1378 +              coalesce(
  1.1379 +                sum(
  1.1380 +                  CASE WHEN "grade" > 0 THEN "direct_voter"."weight" ELSE 0 END
  1.1381 +                ),
  1.1382 +                0
  1.1383 +              ) AS "positive_votes",
  1.1384 +              coalesce(
  1.1385 +                sum(
  1.1386 +                  CASE WHEN "grade" < 0 THEN "direct_voter"."weight" ELSE 0 END
  1.1387 +                ),
  1.1388 +                0
  1.1389 +              ) AS "negative_votes"
  1.1390 +            FROM "initiative"
  1.1391 +            JOIN "issue" ON "initiative"."issue_id" = "issue"."id"
  1.1392 +            JOIN "policy" ON "issue"."policy_id" = "policy"."id"
  1.1393 +            LEFT JOIN "direct_voter"
  1.1394 +              ON "direct_voter"."issue_id" = "initiative"."issue_id"
  1.1395 +            LEFT JOIN "vote"
  1.1396 +              ON "vote"."initiative_id" = "initiative"."id"
  1.1397 +              AND "vote"."member_id" = "direct_voter"."member_id"
  1.1398 +            WHERE "initiative"."issue_id" = "issue_id_p"
  1.1399 +            AND "initiative"."admitted"  -- NOTE: NULL case is handled too
  1.1400 +            GROUP BY "initiative"."id"
  1.1401 +          ) AS "vote_counts",
  1.1402 +          "issue",
  1.1403 +          "policy"
  1.1404 +        WHERE "vote_counts"."initiative_id" = "initiative"."id"
  1.1405 +        AND "issue"."id" = "initiative"."issue_id"
  1.1406 +        AND "policy"."id" = "issue"."policy_id";
  1.1407 +      -- NOTE: "closed" column of issue must be set at this point
  1.1408 +      DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
  1.1409 +      INSERT INTO "battle" (
  1.1410 +        "issue_id",
  1.1411 +        "winning_initiative_id", "losing_initiative_id",
  1.1412 +        "count"
  1.1413 +      ) SELECT
  1.1414 +        "issue_id",
  1.1415 +        "winning_initiative_id", "losing_initiative_id",
  1.1416 +        "count"
  1.1417 +        FROM "battle_view" WHERE "issue_id" = "issue_id_p";
  1.1418 +    END;
  1.1419 +  $$;
  1.1420 +
  1.1421 +CREATE OR REPLACE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
  1.1422 +  RETURNS VOID
  1.1423 +  LANGUAGE 'plpgsql' VOLATILE AS $$
  1.1424 +    DECLARE
  1.1425 +      "dimension_v"     INTEGER;
  1.1426 +      "vote_matrix"     INT4[][];  -- absolute votes
  1.1427 +      "matrix"          INT8[][];  -- defeat strength / best paths
  1.1428 +      "i"               INTEGER;
  1.1429 +      "j"               INTEGER;
  1.1430 +      "k"               INTEGER;
  1.1431 +      "battle_row"      "battle"%ROWTYPE;
  1.1432 +      "rank_ary"        INT4[];
  1.1433 +      "rank_v"          INT4;
  1.1434 +      "done_v"          INTEGER;
  1.1435 +      "winners_ary"     INTEGER[];
  1.1436 +      "initiative_id_v" "initiative"."id"%TYPE;
  1.1437 +    BEGIN
  1.1438 +      PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
  1.1439 +      SELECT count(1) INTO "dimension_v" FROM "initiative"
  1.1440 +        WHERE "issue_id" = "issue_id_p" AND "agreed";
  1.1441 +      IF "dimension_v" = 1 THEN
  1.1442 +        UPDATE "initiative" SET "rank" = 1
  1.1443 +          WHERE "issue_id" = "issue_id_p" AND "agreed";
  1.1444 +      ELSIF "dimension_v" > 1 THEN
  1.1445 +        -- Create "vote_matrix" with absolute number of votes in pairwise
  1.1446 +        -- comparison:
  1.1447 +        "vote_matrix" := "square_matrix_init_string"("dimension_v");  -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
  1.1448 +        "i" := 1;
  1.1449 +        "j" := 2;
  1.1450 +        FOR "battle_row" IN
  1.1451 +          SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
  1.1452 +          ORDER BY "winning_initiative_id", "losing_initiative_id"
  1.1453 +        LOOP
  1.1454 +          "vote_matrix"["i"]["j"] := "battle_row"."count";
  1.1455 +          IF "j" = "dimension_v" THEN
  1.1456 +            "i" := "i" + 1;
  1.1457 +            "j" := 1;
  1.1458 +          ELSE
  1.1459 +            "j" := "j" + 1;
  1.1460 +            IF "j" = "i" THEN
  1.1461 +              "j" := "j" + 1;
  1.1462 +            END IF;
  1.1463 +          END IF;
  1.1464 +        END LOOP;
  1.1465 +        IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
  1.1466 +          RAISE EXCEPTION 'Wrong battle count (should not happen)';
  1.1467 +        END IF;
  1.1468 +        -- Store defeat strengths in "matrix" using "defeat_strength"
  1.1469 +        -- function:
  1.1470 +        "matrix" := "square_matrix_init_string"("dimension_v");  -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
  1.1471 +        "i" := 1;
  1.1472 +        LOOP
  1.1473 +          "j" := 1;
  1.1474 +          LOOP
  1.1475 +            IF "i" != "j" THEN
  1.1476 +              "matrix"["i"]["j"] := "defeat_strength"(
  1.1477 +                "vote_matrix"["i"]["j"],
  1.1478 +                "vote_matrix"["j"]["i"]
  1.1479 +              );
  1.1480 +            END IF;
  1.1481 +            EXIT WHEN "j" = "dimension_v";
  1.1482 +            "j" := "j" + 1;
  1.1483 +          END LOOP;
  1.1484 +          EXIT WHEN "i" = "dimension_v";
  1.1485 +          "i" := "i" + 1;
  1.1486 +        END LOOP;
  1.1487 +        -- Find best paths:
  1.1488 +        "i" := 1;
  1.1489 +        LOOP
  1.1490 +          "j" := 1;
  1.1491 +          LOOP
  1.1492 +            IF "i" != "j" THEN
  1.1493 +              "k" := 1;
  1.1494 +              LOOP
  1.1495 +                IF "i" != "k" AND "j" != "k" THEN
  1.1496 +                  IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
  1.1497 +                    IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
  1.1498 +                      "matrix"["j"]["k"] := "matrix"["j"]["i"];
  1.1499 +                    END IF;
  1.1500 +                  ELSE
  1.1501 +                    IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
  1.1502 +                      "matrix"["j"]["k"] := "matrix"["i"]["k"];
  1.1503 +                    END IF;
  1.1504 +                  END IF;
  1.1505 +                END IF;
  1.1506 +                EXIT WHEN "k" = "dimension_v";
  1.1507 +                "k" := "k" + 1;
  1.1508 +              END LOOP;
  1.1509 +            END IF;
  1.1510 +            EXIT WHEN "j" = "dimension_v";
  1.1511 +            "j" := "j" + 1;
  1.1512 +          END LOOP;
  1.1513 +          EXIT WHEN "i" = "dimension_v";
  1.1514 +          "i" := "i" + 1;
  1.1515 +        END LOOP;
  1.1516 +        -- Determine order of winners:
  1.1517 +        "rank_ary" := "array_init_string"("dimension_v");  -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
  1.1518 +        "rank_v" := 1;
  1.1519 +        "done_v" := 0;
  1.1520 +        LOOP
  1.1521 +          "winners_ary" := '{}';
  1.1522 +          "i" := 1;
  1.1523 +          LOOP
  1.1524 +            IF "rank_ary"["i"] ISNULL THEN
  1.1525 +              "j" := 1;
  1.1526 +              LOOP
  1.1527 +                IF
  1.1528 +                  "i" != "j" AND
  1.1529 +                  "rank_ary"["j"] ISNULL AND
  1.1530 +                  "matrix"["j"]["i"] > "matrix"["i"]["j"]
  1.1531 +                THEN
  1.1532 +                  -- someone else is better
  1.1533 +                  EXIT;
  1.1534 +                END IF;
  1.1535 +                IF "j" = "dimension_v" THEN
  1.1536 +                  -- noone is better
  1.1537 +                  "winners_ary" := "winners_ary" || "i";
  1.1538 +                  EXIT;
  1.1539 +                END IF;
  1.1540 +                "j" := "j" + 1;
  1.1541 +              END LOOP;
  1.1542 +            END IF;
  1.1543 +            EXIT WHEN "i" = "dimension_v";
  1.1544 +            "i" := "i" + 1;
  1.1545 +          END LOOP;
  1.1546 +          "i" := 1;
  1.1547 +          LOOP
  1.1548 +            "rank_ary"["winners_ary"["i"]] := "rank_v";
  1.1549 +            "done_v" := "done_v" + 1;
  1.1550 +            EXIT WHEN "i" = array_upper("winners_ary", 1);
  1.1551 +            "i" := "i" + 1;
  1.1552 +          END LOOP;
  1.1553 +          EXIT WHEN "done_v" = "dimension_v";
  1.1554 +          "rank_v" := "rank_v" + 1;
  1.1555 +        END LOOP;
  1.1556 +        -- write preliminary ranks:
  1.1557 +        "i" := 1;
  1.1558 +        FOR "initiative_id_v" IN
  1.1559 +          SELECT "id" FROM "initiative"
  1.1560 +          WHERE "issue_id" = "issue_id_p" AND "agreed"
  1.1561 +          ORDER BY "id"
  1.1562 +        LOOP
  1.1563 +          UPDATE "initiative" SET "rank" = "rank_ary"["i"]
  1.1564 +            WHERE "id" = "initiative_id_v";
  1.1565 +          "i" := "i" + 1;
  1.1566 +        END LOOP;
  1.1567 +        IF "i" != "dimension_v" + 1 THEN
  1.1568 +          RAISE EXCEPTION 'Wrong winner count (should not happen)';
  1.1569 +        END IF;
  1.1570 +        -- straighten ranks (start counting with 1, no equal ranks):
  1.1571 +        "rank_v" := 1;
  1.1572 +        FOR "initiative_id_v" IN
  1.1573 +          SELECT "id" FROM "initiative"
  1.1574 +          WHERE "issue_id" = "issue_id_p" AND "rank" NOTNULL
  1.1575 +          ORDER BY
  1.1576 +            "rank",
  1.1577 +            "vote_ratio"("positive_votes", "negative_votes") DESC,
  1.1578 +            "id"
  1.1579 +        LOOP
  1.1580 +          UPDATE "initiative" SET "rank" = "rank_v"
  1.1581 +            WHERE "id" = "initiative_id_v";
  1.1582 +          "rank_v" := "rank_v" + 1;
  1.1583 +        END LOOP;
  1.1584 +      END IF;
  1.1585 +      -- mark issue as finished
  1.1586 +      UPDATE "issue" SET
  1.1587 +        "state" =
  1.1588 +          CASE WHEN "dimension_v" = 0 THEN
  1.1589 +            'finished_without_winner'::"issue_state"
  1.1590 +          ELSE
  1.1591 +            'finished_with_winner'::"issue_state"
  1.1592 +          END,
  1.1593 +        "ranks_available" = TRUE
  1.1594 +        WHERE "id" = "issue_id_p";
  1.1595 +      RETURN;
  1.1596 +    END;
  1.1597 +  $$;
  1.1598 +
  1.1599 +CREATE OR REPLACE FUNCTION "check_issue"
  1.1600 +  ( "issue_id_p" "issue"."id"%TYPE )
  1.1601 +  RETURNS VOID
  1.1602 +  LANGUAGE 'plpgsql' VOLATILE AS $$
  1.1603 +    DECLARE
  1.1604 +      "issue_row"         "issue"%ROWTYPE;
  1.1605 +      "policy_row"        "policy"%ROWTYPE;
  1.1606 +      "voting_requested_v" BOOLEAN;
  1.1607 +    BEGIN
  1.1608 +      PERFORM "lock_issue"("issue_id_p");
  1.1609 +      SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  1.1610 +      -- only process open issues:
  1.1611 +      IF "issue_row"."closed" ISNULL THEN
  1.1612 +        SELECT * INTO "policy_row" FROM "policy"
  1.1613 +          WHERE "id" = "issue_row"."policy_id";
  1.1614 +        -- create a snapshot, unless issue is already fully frozen:
  1.1615 +        IF "issue_row"."fully_frozen" ISNULL THEN
  1.1616 +          PERFORM "create_snapshot"("issue_id_p");
  1.1617 +          SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  1.1618 +        END IF;
  1.1619 +        -- eventually close or accept issues, which have not been accepted:
  1.1620 +        IF "issue_row"."accepted" ISNULL THEN
  1.1621 +          IF EXISTS (
  1.1622 +            SELECT NULL FROM "initiative"
  1.1623 +            WHERE "issue_id" = "issue_id_p"
  1.1624 +            AND "supporter_count" > 0
  1.1625 +            AND "supporter_count" * "policy_row"."issue_quorum_den"
  1.1626 +            >= "issue_row"."population" * "policy_row"."issue_quorum_num"
  1.1627 +          ) THEN
  1.1628 +            -- accept issues, if supporter count is high enough
  1.1629 +            PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
  1.1630 +            -- NOTE: "issue_row" used later
  1.1631 +            "issue_row"."state" := 'discussion';
  1.1632 +            "issue_row"."accepted" := now();
  1.1633 +            UPDATE "issue" SET
  1.1634 +              "state"    = "issue_row"."state",
  1.1635 +              "accepted" = "issue_row"."accepted"
  1.1636 +              WHERE "id" = "issue_row"."id";
  1.1637 +          ELSIF
  1.1638 +            now() >= "issue_row"."created" + "issue_row"."admission_time"
  1.1639 +          THEN
  1.1640 +            -- close issues, if admission time has expired
  1.1641 +            PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
  1.1642 +            UPDATE "issue" SET
  1.1643 +              "state" = 'canceled_issue_not_accepted',
  1.1644 +              "closed" = now()
  1.1645 +              WHERE "id" = "issue_row"."id";
  1.1646 +          END IF;
  1.1647 +        END IF;
  1.1648 +        -- eventually half freeze issues:
  1.1649 +        IF
  1.1650 +          -- NOTE: issue can't be closed at this point, if it has been accepted
  1.1651 +          "issue_row"."accepted" NOTNULL AND
  1.1652 +          "issue_row"."half_frozen" ISNULL
  1.1653 +        THEN
  1.1654 +          SELECT
  1.1655 +            CASE
  1.1656 +              WHEN "vote_now" * 2 > "issue_row"."population" THEN
  1.1657 +                TRUE
  1.1658 +              WHEN "vote_later" * 2 > "issue_row"."population" THEN
  1.1659 +                FALSE
  1.1660 +              ELSE NULL
  1.1661 +            END
  1.1662 +            INTO "voting_requested_v"
  1.1663 +            FROM "issue" WHERE "id" = "issue_id_p";
  1.1664 +          IF
  1.1665 +            "voting_requested_v" OR (
  1.1666 +              "voting_requested_v" ISNULL AND
  1.1667 +              now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
  1.1668 +            )
  1.1669 +          THEN
  1.1670 +            PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
  1.1671 +            -- NOTE: "issue_row" used later
  1.1672 +            "issue_row"."state" := 'verification';
  1.1673 +            "issue_row"."half_frozen" := now();
  1.1674 +            UPDATE "issue" SET
  1.1675 +              "state"       = "issue_row"."state",
  1.1676 +              "half_frozen" = "issue_row"."half_frozen"
  1.1677 +              WHERE "id" = "issue_row"."id";
  1.1678 +          END IF;
  1.1679 +        END IF;
  1.1680 +        -- close issues after some time, if all initiatives have been revoked:
  1.1681 +        IF
  1.1682 +          "issue_row"."closed" ISNULL AND
  1.1683 +          NOT EXISTS (
  1.1684 +            -- all initiatives are revoked
  1.1685 +            SELECT NULL FROM "initiative"
  1.1686 +            WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
  1.1687 +          ) AND (
  1.1688 +            -- and issue has not been accepted yet
  1.1689 +            "issue_row"."accepted" ISNULL OR
  1.1690 +            NOT EXISTS (
  1.1691 +              -- or no initiatives have been revoked lately
  1.1692 +              SELECT NULL FROM "initiative"
  1.1693 +              WHERE "issue_id" = "issue_id_p"
  1.1694 +              AND now() < "revoked" + "issue_row"."verification_time"
  1.1695 +            ) OR (
  1.1696 +              -- or verification time has elapsed
  1.1697 +              "issue_row"."half_frozen" NOTNULL AND
  1.1698 +              "issue_row"."fully_frozen" ISNULL AND
  1.1699 +              now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
  1.1700 +            )
  1.1701 +          )
  1.1702 +        THEN
  1.1703 +          -- NOTE: "issue_row" used later
  1.1704 +          IF "issue_row"."accepted" ISNULL THEN
  1.1705 +            "issue_row"."state" := 'canceled_revoked_before_accepted';
  1.1706 +          ELSIF "issue_row"."half_frozen" ISNULL THEN
  1.1707 +            "issue_row"."state" := 'canceled_after_revocation_during_discussion';
  1.1708 +          ELSE
  1.1709 +            "issue_row"."state" := 'canceled_after_revocation_during_verification';
  1.1710 +          END IF;
  1.1711 +          "issue_row"."closed" := now();
  1.1712 +          UPDATE "issue" SET
  1.1713 +            "state"  = "issue_row"."state",
  1.1714 +            "closed" = "issue_row"."closed"
  1.1715 +            WHERE "id" = "issue_row"."id";
  1.1716 +        END IF;
  1.1717 +        -- fully freeze issue after verification time:
  1.1718 +        IF
  1.1719 +          "issue_row"."half_frozen" NOTNULL AND
  1.1720 +          "issue_row"."fully_frozen" ISNULL AND
  1.1721 +          "issue_row"."closed" ISNULL AND
  1.1722 +          now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
  1.1723 +        THEN
  1.1724 +          PERFORM "freeze_after_snapshot"("issue_id_p");
  1.1725 +          -- NOTE: "issue" might change, thus "issue_row" has to be updated below
  1.1726 +        END IF;
  1.1727 +        SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  1.1728 +        -- close issue by calling close_voting(...) after voting time:
  1.1729 +        IF
  1.1730 +          "issue_row"."closed" ISNULL AND
  1.1731 +          "issue_row"."fully_frozen" NOTNULL AND
  1.1732 +          now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
  1.1733 +        THEN
  1.1734 +          PERFORM "close_voting"("issue_id_p");
  1.1735 +          -- calculate ranks will not consume much time and can be done now
  1.1736 +          PERFORM "calculate_ranks"("issue_id_p");
  1.1737 +        END IF;
  1.1738 +      END IF;
  1.1739 +      RETURN;
  1.1740 +    END;
  1.1741 +  $$;
  1.1742 +
  1.1743 +CREATE OR REPLACE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
  1.1744 +  RETURNS VOID
  1.1745 +  LANGUAGE 'plpgsql' VOLATILE AS $$
  1.1746 +    DECLARE
  1.1747 +      "issue_row" "issue"%ROWTYPE;
  1.1748 +    BEGIN
  1.1749 +      SELECT * INTO "issue_row"
  1.1750 +        FROM "issue" WHERE "id" = "issue_id_p"
  1.1751 +        FOR UPDATE;
  1.1752 +      IF "issue_row"."cleaned" ISNULL THEN
  1.1753 +        UPDATE "issue" SET
  1.1754 +          "state"           = 'voting',
  1.1755 +          "closed"          = NULL,
  1.1756 +          "ranks_available" = FALSE
  1.1757 +          WHERE "id" = "issue_id_p";
  1.1758 +        DELETE FROM "issue_comment"
  1.1759 +          WHERE "issue_id" = "issue_id_p";
  1.1760 +        DELETE FROM "voting_comment"
  1.1761 +          WHERE "issue_id" = "issue_id_p";
  1.1762 +        DELETE FROM "delegating_voter"
  1.1763 +          WHERE "issue_id" = "issue_id_p";
  1.1764 +        DELETE FROM "direct_voter"
  1.1765 +          WHERE "issue_id" = "issue_id_p";
  1.1766 +        DELETE FROM "delegating_interest_snapshot"
  1.1767 +          WHERE "issue_id" = "issue_id_p";
  1.1768 +        DELETE FROM "direct_interest_snapshot"
  1.1769 +          WHERE "issue_id" = "issue_id_p";
  1.1770 +        DELETE FROM "delegating_population_snapshot"
  1.1771 +          WHERE "issue_id" = "issue_id_p";
  1.1772 +        DELETE FROM "direct_population_snapshot"
  1.1773 +          WHERE "issue_id" = "issue_id_p";
  1.1774 +        DELETE FROM "non_voter"
  1.1775 +          WHERE "issue_id" = "issue_id_p";
  1.1776 +        DELETE FROM "delegation"
  1.1777 +          WHERE "issue_id" = "issue_id_p";
  1.1778 +        DELETE FROM "supporter"
  1.1779 +          WHERE "issue_id" = "issue_id_p";
  1.1780 +        UPDATE "issue" SET
  1.1781 +          "state"           = "issue_row"."state",
  1.1782 +          "closed"          = "issue_row"."closed",
  1.1783 +          "ranks_available" = "issue_row"."ranks_available",
  1.1784 +          "cleaned"         = now()
  1.1785 +          WHERE "id" = "issue_id_p";
  1.1786 +      END IF;
  1.1787 +      RETURN;
  1.1788 +    END;
  1.1789 +  $$;
  1.1790 +
  1.1791 +CREATE OR REPLACE FUNCTION "check_issue"
  1.1792 +  ( "issue_id_p" "issue"."id"%TYPE )
  1.1793 +  RETURNS VOID
  1.1794 +  LANGUAGE 'plpgsql' VOLATILE AS $$
  1.1795 +    DECLARE
  1.1796 +      "issue_row"         "issue"%ROWTYPE;
  1.1797 +      "policy_row"        "policy"%ROWTYPE;
  1.1798 +      "voting_requested_v" BOOLEAN;
  1.1799 +    BEGIN
  1.1800 +      PERFORM "lock_issue"("issue_id_p");
  1.1801 +      SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  1.1802 +      -- only process open issues:
  1.1803 +      IF "issue_row"."closed" ISNULL THEN
  1.1804 +        SELECT * INTO "policy_row" FROM "policy"
  1.1805 +          WHERE "id" = "issue_row"."policy_id";
  1.1806 +        -- create a snapshot, unless issue is already fully frozen:
  1.1807 +        IF "issue_row"."fully_frozen" ISNULL THEN
  1.1808 +          PERFORM "create_snapshot"("issue_id_p");
  1.1809 +          SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  1.1810 +        END IF;
  1.1811 +        -- eventually close or accept issues, which have not been accepted:
  1.1812 +        IF "issue_row"."accepted" ISNULL THEN
  1.1813 +          IF EXISTS (
  1.1814 +            SELECT NULL FROM "initiative"
  1.1815 +            WHERE "issue_id" = "issue_id_p"
  1.1816 +            AND "supporter_count" > 0
  1.1817 +            AND "supporter_count" * "policy_row"."issue_quorum_den"
  1.1818 +            >= "issue_row"."population" * "policy_row"."issue_quorum_num"
  1.1819 +          ) THEN
  1.1820 +            -- accept issues, if supporter count is high enough
  1.1821 +            PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
  1.1822 +            -- NOTE: "issue_row" used later
  1.1823 +            "issue_row"."state" := 'discussion';
  1.1824 +            "issue_row"."accepted" := now();
  1.1825 +            UPDATE "issue" SET
  1.1826 +              "state"    = "issue_row"."state",
  1.1827 +              "accepted" = "issue_row"."accepted"
  1.1828 +              WHERE "id" = "issue_row"."id";
  1.1829 +          ELSIF
  1.1830 +            now() >= "issue_row"."created" + "issue_row"."admission_time"
  1.1831 +          THEN
  1.1832 +            -- close issues, if admission time has expired
  1.1833 +            PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
  1.1834 +            UPDATE "issue" SET
  1.1835 +              "state" = 'canceled_issue_not_accepted',
  1.1836 +              "closed" = now()
  1.1837 +              WHERE "id" = "issue_row"."id";
  1.1838 +          END IF;
  1.1839 +        END IF;
  1.1840 +        -- eventually half freeze issues:
  1.1841 +        IF
  1.1842 +          -- NOTE: issue can't be closed at this point, if it has been accepted
  1.1843 +          "issue_row"."accepted" NOTNULL AND
  1.1844 +          "issue_row"."half_frozen" ISNULL
  1.1845 +        THEN
  1.1846 +          SELECT
  1.1847 +            CASE
  1.1848 +              WHEN "vote_now" * 2 > "issue_row"."population" THEN
  1.1849 +                TRUE
  1.1850 +              WHEN "vote_later" * 2 > "issue_row"."population" THEN
  1.1851 +                FALSE
  1.1852 +              ELSE NULL
  1.1853 +            END
  1.1854 +            INTO "voting_requested_v"
  1.1855 +            FROM "issue" WHERE "id" = "issue_id_p";
  1.1856 +          IF
  1.1857 +            "voting_requested_v" OR (
  1.1858 +              "voting_requested_v" ISNULL AND
  1.1859 +              now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
  1.1860 +            )
  1.1861 +          THEN
  1.1862 +            PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
  1.1863 +            -- NOTE: "issue_row" used later
  1.1864 +            "issue_row"."state" := 'verification';
  1.1865 +            "issue_row"."half_frozen" := now();
  1.1866 +            UPDATE "issue" SET
  1.1867 +              "state"       = "issue_row"."state",
  1.1868 +              "half_frozen" = "issue_row"."half_frozen"
  1.1869 +              WHERE "id" = "issue_row"."id";
  1.1870 +          END IF;
  1.1871 +        END IF;
  1.1872 +        -- close issues after some time, if all initiatives have been revoked:
  1.1873 +        IF
  1.1874 +          "issue_row"."closed" ISNULL AND
  1.1875 +          NOT EXISTS (
  1.1876 +            -- all initiatives are revoked
  1.1877 +            SELECT NULL FROM "initiative"
  1.1878 +            WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
  1.1879 +          ) AND (
  1.1880 +            -- and issue has not been accepted yet
  1.1881 +            "issue_row"."accepted" ISNULL OR
  1.1882 +            NOT EXISTS (
  1.1883 +              -- or no initiatives have been revoked lately
  1.1884 +              SELECT NULL FROM "initiative"
  1.1885 +              WHERE "issue_id" = "issue_id_p"
  1.1886 +              AND now() < "revoked" + "issue_row"."verification_time"
  1.1887 +            ) OR (
  1.1888 +              -- or verification time has elapsed
  1.1889 +              "issue_row"."half_frozen" NOTNULL AND
  1.1890 +              "issue_row"."fully_frozen" ISNULL AND
  1.1891 +              now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
  1.1892 +            )
  1.1893 +          )
  1.1894 +        THEN
  1.1895 +          -- NOTE: "issue_row" used later
  1.1896 +          IF "issue_row"."accepted" ISNULL THEN
  1.1897 +            "issue_row"."state" := 'canceled_revoked_before_accepted';
  1.1898 +          ELSIF "issue_row"."half_frozen" ISNULL THEN
  1.1899 +            "issue_row"."state" := 'canceled_after_revocation_during_discussion';
  1.1900 +          ELSE
  1.1901 +            "issue_row"."state" := 'canceled_after_revocation_during_verification';
  1.1902 +          END IF;
  1.1903 +          "issue_row"."closed" := now();
  1.1904 +          UPDATE "issue" SET
  1.1905 +            "state"  = "issue_row"."state",
  1.1906 +            "closed" = "issue_row"."closed"
  1.1907 +            WHERE "id" = "issue_row"."id";
  1.1908 +        END IF;
  1.1909 +        -- fully freeze issue after verification time:
  1.1910 +        IF
  1.1911 +          "issue_row"."half_frozen" NOTNULL AND
  1.1912 +          "issue_row"."fully_frozen" ISNULL AND
  1.1913 +          "issue_row"."closed" ISNULL AND
  1.1914 +          now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
  1.1915 +        THEN
  1.1916 +          PERFORM "freeze_after_snapshot"("issue_id_p");
  1.1917 +          -- NOTE: "issue" might change, thus "issue_row" has to be updated below
  1.1918 +        END IF;
  1.1919 +        SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  1.1920 +        -- close issue by calling close_voting(...) after voting time:
  1.1921 +        IF
  1.1922 +          "issue_row"."closed" ISNULL AND
  1.1923 +          "issue_row"."fully_frozen" NOTNULL AND
  1.1924 +          now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
  1.1925 +        THEN
  1.1926 +          PERFORM "close_voting"("issue_id_p");
  1.1927 +          -- calculate ranks will not consume much time and can be done now
  1.1928 +          PERFORM "calculate_ranks"("issue_id_p");
  1.1929 +        END IF;
  1.1930 +      END IF;
  1.1931 +      RETURN;
  1.1932 +    END;
  1.1933 +  $$;
  1.1934 +
  1.1935 +CREATE OR REPLACE FUNCTION "delete_private_data"()
  1.1936 +  RETURNS VOID
  1.1937 +  LANGUAGE 'plpgsql' VOLATILE AS $$
  1.1938 +    BEGIN
  1.1939 +      UPDATE "member" SET
  1.1940 +        "last_login"                   = NULL,
  1.1941 +        "login"                        = NULL,
  1.1942 +        "password"                     = NULL,
  1.1943 +        "notify_email"                 = NULL,
  1.1944 +        "notify_email_unconfirmed"     = NULL,
  1.1945 +        "notify_email_secret"          = NULL,
  1.1946 +        "notify_email_secret_expiry"   = NULL,
  1.1947 +        "notify_email_lock_expiry"     = NULL,
  1.1948 +        "password_reset_secret"        = NULL,
  1.1949 +        "password_reset_secret_expiry" = NULL,
  1.1950 +        "organizational_unit"          = NULL,
  1.1951 +        "internal_posts"               = NULL,
  1.1952 +        "realname"                     = NULL,
  1.1953 +        "birthday"                     = NULL,
  1.1954 +        "address"                      = NULL,
  1.1955 +        "email"                        = NULL,
  1.1956 +        "xmpp_address"                 = NULL,
  1.1957 +        "website"                      = NULL,
  1.1958 +        "phone"                        = NULL,
  1.1959 +        "mobile_phone"                 = NULL,
  1.1960 +        "profession"                   = NULL,
  1.1961 +        "external_memberships"         = NULL,
  1.1962 +        "external_posts"               = NULL,
  1.1963 +        "statement"                    = NULL;
  1.1964 +      -- "text_search_data" is updated by triggers
  1.1965 +      DELETE FROM "invite_code";
  1.1966 +      DELETE FROM "setting";
  1.1967 +      DELETE FROM "setting_map";
  1.1968 +      DELETE FROM "member_relation_setting";
  1.1969 +      DELETE FROM "member_image";
  1.1970 +      DELETE FROM "contact";
  1.1971 +      DELETE FROM "ignored_member";
  1.1972 +      DELETE FROM "session";
  1.1973 +      DELETE FROM "area_setting";
  1.1974 +      DELETE FROM "issue_setting";
  1.1975 +      DELETE FROM "ignored_initiative";
  1.1976 +      DELETE FROM "initiative_setting";
  1.1977 +      DELETE FROM "suggestion_setting";
  1.1978 +      DELETE FROM "non_voter";
  1.1979 +      DELETE FROM "direct_voter" USING "issue"
  1.1980 +        WHERE "direct_voter"."issue_id" = "issue"."id"
  1.1981 +        AND "issue"."closed" ISNULL;
  1.1982 +      RETURN;
  1.1983 +    END;
  1.1984 +  $$;
  1.1985 +
  1.1986 +
  1.1987 +-- Delete old "delegation_scope" TYPE:
  1.1988 +
  1.1989 +DROP TYPE "delegation_scope_old";
  1.1990 +
  1.1991 +
  1.1992 +COMMIT;
  1.1993 +
  1.1994 +
  1.1995 +-- Generate issue states and add constraints:
  1.1996 +
  1.1997 +UPDATE "issue" SET "state" =
  1.1998 +  CASE
  1.1999 +  WHEN "closed" ISNULL THEN
  1.2000 +    CASE
  1.2001 +    WHEN "accepted" ISNULL THEN
  1.2002 +      'admission'::"issue_state"
  1.2003 +    WHEN "half_frozen" ISNULL THEN
  1.2004 +      'discussion'::"issue_state"
  1.2005 +    WHEN "fully_frozen" ISNULL THEN
  1.2006 +      'verification'::"issue_state"
  1.2007 +    ELSE
  1.2008 +      'voting'::"issue_state"
  1.2009 +    END
  1.2010 +  WHEN "fully_frozen" NOTNULL THEN
  1.2011 +    CASE
  1.2012 +    WHEN "fully_frozen" = "closed" THEN
  1.2013 +      'canceled_no_initiative_admitted'::"issue_state"
  1.2014 +    ELSE
  1.2015 +      'finished_without_winner'::"issue_state"  -- NOTE: corrected later
  1.2016 +    END
  1.2017 +  WHEN "half_frozen" NOTNULL THEN
  1.2018 +    'canceled_after_revocation_during_verification'::"issue_state"
  1.2019 +  WHEN "accepted" NOTNULL THEN
  1.2020 +    'canceled_after_revocation_during_discussion'::"issue_state"
  1.2021 +  ELSE
  1.2022 +    'canceled_revoked_before_accepted'::"issue_state"  -- NOTE: corrected later
  1.2023 +  END;
  1.2024 +UPDATE "issue" SET "state" = 'finished_with_winner'
  1.2025 +  FROM "initiative"
  1.2026 +  WHERE "issue"."id" = "initiative"."issue_id"
  1.2027 +  AND "issue"."state" = 'finished_without_winner'
  1.2028 +  AND "initiative"."agreed";
  1.2029 +UPDATE "issue" SET "state" = 'canceled_issue_not_accepted'
  1.2030 +  FROM "initiative"
  1.2031 +  WHERE "issue"."id" = "initiative"."issue_id"
  1.2032 +  AND "issue"."state" = 'canceled_revoked_before_accepted'
  1.2033 +  AND "initiative"."revoked" ISNULL;
  1.2034 +
  1.2035 +ALTER TABLE "issue" ALTER "state" SET NOT NULL;
  1.2036 +
  1.2037 +ALTER TABLE "issue" DROP CONSTRAINT "valid_state";
  1.2038 +ALTER TABLE "issue" ADD CONSTRAINT "valid_state" CHECK ((
  1.2039 +    ("accepted" ISNULL  AND "half_frozen" ISNULL  AND "fully_frozen" ISNULL  AND "closed" ISNULL  AND "ranks_available" = FALSE) OR
  1.2040 +    ("accepted" ISNULL  AND "half_frozen" ISNULL  AND "fully_frozen" ISNULL  AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
  1.2041 +    ("accepted" NOTNULL AND "half_frozen" ISNULL  AND "fully_frozen" ISNULL  AND "closed" ISNULL  AND "ranks_available" = FALSE) OR
  1.2042 +    ("accepted" NOTNULL AND "half_frozen" ISNULL  AND "fully_frozen" ISNULL  AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
  1.2043 +    ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL  AND "closed" ISNULL  AND "ranks_available" = FALSE) OR
  1.2044 +    ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL  AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
  1.2045 +    ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL  AND "ranks_available" = FALSE) OR
  1.2046 +    ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
  1.2047 +    ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE)
  1.2048 +  ) AND (
  1.2049 +    ("state" = 'admission'    AND "closed" ISNULL AND "accepted" ISNULL) OR
  1.2050 +    ("state" = 'discussion'   AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
  1.2051 +    ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
  1.2052 +    ("state" = 'voting'       AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
  1.2053 +    ("state" = 'canceled_revoked_before_accepted'              AND "closed" NOTNULL AND "accepted" ISNULL) OR
  1.2054 +    ("state" = 'canceled_issue_not_accepted'                   AND "closed" NOTNULL AND "accepted" ISNULL) OR
  1.2055 +    ("state" = 'canceled_after_revocation_during_discussion'   AND "closed" NOTNULL AND "half_frozen"  ISNULL) OR
  1.2056 +    ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
  1.2057 +    ("state" = 'calculation'                     AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = FALSE) OR
  1.2058 +    ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
  1.2059 +    ("state" = 'finished_without_winner'         AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
  1.2060 +    ("state" = 'finished_with_winner'            AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE)
  1.2061 +  ));
  1.2062 +
  1.2063 +
  1.2064 +-- Guess "revoked_by_member_id" values based on author of current draft and add constraint:
  1.2065 +
  1.2066 +UPDATE "initiative" SET "revoked_by_member_id" = "author_id"
  1.2067 +  FROM "current_draft"
  1.2068 +  WHERE "initiative"."id" = "current_draft"."initiative_id"
  1.2069 +  AND "initiative"."revoked" NOTNULL;
  1.2070 +
  1.2071 +ALTER TABLE "initiative" ADD
  1.2072 +  CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
  1.2073 +  CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL);
  1.2074 +
  1.2075 +
  1.2076 +-- Fill "unit_id" column with default value where neccessary and add constraints:
  1.2077 +
  1.2078 +UPDATE "delegation" SET "unit_id" = 1 WHERE "scope" = 'unit';
  1.2079 +
  1.2080 +ALTER TABLE "delegation" ADD CONSTRAINT "area_id_and_issue_id_set_according_to_scope"
  1.2081 +  CHECK (
  1.2082 +    ("scope" = 'unit'  AND "unit_id" NOTNULL AND "area_id" ISNULL  AND "issue_id" ISNULL ) OR
  1.2083 +    ("scope" = 'area'  AND "unit_id" ISNULL  AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
  1.2084 +    ("scope" = 'issue' AND "unit_id" ISNULL  AND "area_id" ISNULL  AND "issue_id" NOTNULL) );
  1.2085 +
  1.2086 +
  1.2087 +-- Filling of "event" table with old (reconstructed) events:
  1.2088 +
  1.2089 +DELETE FROM "event";
  1.2090 +SELECT setval('event_id_seq', 1, false);
  1.2091 +
  1.2092 +INSERT INTO "event"
  1.2093 +  ( "occurrence", "event", "member_id", "issue_id", "state",
  1.2094 +    "initiative_id", "draft_id", "suggestion_id" )
  1.2095 +  SELECT * FROM (
  1.2096 +    SELECT * FROM (
  1.2097 +      SELECT DISTINCT ON ("initiative"."id")
  1.2098 +        "timeline"."occurrence",
  1.2099 +        CASE WHEN "issue_creation"."issue_id" NOTNULL THEN
  1.2100 +          'initiative_created_in_new_issue'::"event_type"
  1.2101 +        ELSE
  1.2102 +          'initiative_created_in_existing_issue'::"event_type"
  1.2103 +        END,
  1.2104 +        "draft"."author_id",
  1.2105 +        "issue"."id",
  1.2106 +        CASE
  1.2107 +          WHEN "timeline"."occurrence" < "issue"."accepted" THEN
  1.2108 +            'admission'::"issue_state"
  1.2109 +          WHEN "timeline"."occurrence" < "issue"."half_frozen" THEN
  1.2110 +            'discussion'::"issue_state"
  1.2111 +          ELSE
  1.2112 +            'verification'::"issue_state"
  1.2113 +        END,
  1.2114 +        "initiative"."id",
  1.2115 +        "draft"."id",
  1.2116 +        NULL::INT8
  1.2117 +      FROM "timeline"
  1.2118 +      JOIN "initiative" ON "timeline"."initiative_id" = "initiative"."id"
  1.2119 +      JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
  1.2120 +      LEFT JOIN "timeline" AS "issue_creation"
  1.2121 +        ON "initiative"."issue_id" = "issue_creation"."issue_id"
  1.2122 +        AND "issue_creation"."event" = 'issue_created'
  1.2123 +        AND "timeline"."occurrence" = "issue_creation"."occurrence"
  1.2124 +      JOIN "draft"
  1.2125 +        ON "initiative"."id" = "draft"."initiative_id"
  1.2126 +      WHERE "timeline"."event" = 'initiative_created'
  1.2127 +      ORDER BY "initiative"."id", "draft"."id"
  1.2128 +    ) AS "subquery"  -- NOTE: subquery needed due to DISTINCT/ORDER
  1.2129 +  UNION ALL
  1.2130 +    SELECT
  1.2131 +      "timeline"."occurrence",
  1.2132 +      'issue_state_changed'::"event_type",
  1.2133 +      NULL,
  1.2134 +      "issue"."id",
  1.2135 +      CASE
  1.2136 +        WHEN "timeline"."event" IN (
  1.2137 +          'issue_canceled',
  1.2138 +          'issue_finished_without_voting',
  1.2139 +          'issue_finished_after_voting'
  1.2140 +        ) THEN
  1.2141 +          "issue"."state"
  1.2142 +        WHEN "timeline"."event" = 'issue_accepted' THEN
  1.2143 +          'discussion'::"issue_state"
  1.2144 +        WHEN "timeline"."event" = 'issue_half_frozen' THEN
  1.2145 +          'verification'::"issue_state"
  1.2146 +        WHEN "timeline"."event" = 'issue_voting_started' THEN
  1.2147 +          'voting'::"issue_state"
  1.2148 +      END,
  1.2149 +      NULL,
  1.2150 +      NULL,
  1.2151 +      NULL
  1.2152 +    FROM "timeline"
  1.2153 +    JOIN "issue" ON "timeline"."issue_id" = "issue"."id"
  1.2154 +    WHERE "timeline"."event" IN (
  1.2155 +      'issue_canceled',
  1.2156 +      'issue_accepted',
  1.2157 +      'issue_half_frozen',
  1.2158 +      'issue_finished_without_voting',
  1.2159 +      'issue_voting_started',
  1.2160 +      'issue_finished_after_voting' )
  1.2161 +  UNION ALL
  1.2162 +    SELECT
  1.2163 +      "timeline"."occurrence",
  1.2164 +      'initiative_revoked'::"event_type",
  1.2165 +      "initiative"."revoked_by_member_id",
  1.2166 +      "issue"."id",
  1.2167 +      CASE
  1.2168 +        WHEN "timeline"."occurrence" < "issue"."accepted" THEN
  1.2169 +          'admission'::"issue_state"
  1.2170 +        WHEN "timeline"."occurrence" < "issue"."half_frozen" THEN
  1.2171 +          'discussion'::"issue_state"
  1.2172 +        ELSE
  1.2173 +          'verification'::"issue_state"
  1.2174 +      END,
  1.2175 +      "initiative"."id",
  1.2176 +      "current_draft"."id",
  1.2177 +      NULL
  1.2178 +    FROM "timeline"
  1.2179 +    JOIN "initiative" ON "timeline"."initiative_id" = "initiative"."id"
  1.2180 +    JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
  1.2181 +    JOIN "current_draft" ON "initiative"."id" = "current_draft"."initiative_id"
  1.2182 +    WHERE "timeline"."event" = 'initiative_revoked'
  1.2183 +  UNION ALL
  1.2184 +    SELECT
  1.2185 +      "timeline"."occurrence",
  1.2186 +      'new_draft_created'::"event_type",
  1.2187 +      "draft"."author_id",
  1.2188 +      "issue"."id",
  1.2189 +      CASE
  1.2190 +        WHEN "timeline"."occurrence" < "issue"."accepted" THEN
  1.2191 +          'admission'::"issue_state"
  1.2192 +        WHEN "timeline"."occurrence" < "issue"."half_frozen" THEN
  1.2193 +          'discussion'::"issue_state"
  1.2194 +        ELSE
  1.2195 +          'verification'::"issue_state"
  1.2196 +      END,
  1.2197 +      "initiative"."id",
  1.2198 +      "draft"."id",
  1.2199 +      NULL
  1.2200 +    FROM "timeline"
  1.2201 +    JOIN "draft" ON "timeline"."draft_id" = "draft"."id"
  1.2202 +    JOIN "initiative" ON "draft"."initiative_id" = "initiative"."id"
  1.2203 +    JOIN "issue" ON "initiative"."issue_id" = "issue"."id"
  1.2204 +    LEFT JOIN "timeline" AS "initiative_creation"
  1.2205 +      ON "initiative"."id" = "initiative_creation"."initiative_id"
  1.2206 +      AND "initiative_creation"."event" = 'initiative_created'
  1.2207 +      AND "timeline"."occurrence" = "initiative_creation"."occurrence"
  1.2208 +    WHERE "timeline"."event" = 'draft_created'
  1.2209 +    AND "initiative_creation"."initiative_id" ISNULL
  1.2210 +  UNION ALL
  1.2211 +    SELECT
  1.2212 +      "timeline"."occurrence",
  1.2213 +      'suggestion_created'::"event_type",
  1.2214 +      "suggestion"."author_id",
  1.2215 +      "issue"."id",
  1.2216 +      CASE
  1.2217 +        WHEN "timeline"."occurrence" < "issue"."accepted" THEN
  1.2218 +          'admission'::"issue_state"
  1.2219 +        WHEN "timeline"."occurrence" < "issue"."half_frozen" THEN
  1.2220 +          'discussion'::"issue_state"
  1.2221 +        ELSE
  1.2222 +          'verification'::"issue_state"
  1.2223 +      END,
  1.2224 +      "initiative"."id",
  1.2225 +      NULL,
  1.2226 +      "suggestion"."id"
  1.2227 +    FROM "timeline"
  1.2228 +    JOIN "suggestion" ON "timeline"."suggestion_id" = "suggestion"."id"
  1.2229 +    JOIN "initiative" ON "suggestion"."initiative_id" = "initiative"."id"
  1.2230 +    JOIN "issue" ON "initiative"."issue_id" = "issue"."id"
  1.2231 +    WHERE "timeline"."event" = 'suggestion_created'
  1.2232 +  ) AS "subquery"
  1.2233 +  ORDER BY "occurrence";
  1.2234 +
  1.2235 +
     2.1 --- a/update/core-update.v1.3.1-v1.4.0_rc4.sql	Sat Sep 10 22:39:06 2011 +0200
     2.2 +++ /dev/null	Thu Jan 01 00:00:00 1970 +0000
     2.3 @@ -1,2232 +0,0 @@
     2.4 -BEGIN;  -- NOTE: file contains additional statements AFTER this BEGIN/COMMIT block!
     2.5 -
     2.6 -
     2.7 --- Update version information:
     2.8 -
     2.9 -CREATE OR REPLACE VIEW "liquid_feedback_version" AS
    2.10 -  SELECT * FROM (VALUES ('1.4.0_rc4', 1, 4, -1))
    2.11 -  AS "subquery"("string", "major", "minor", "revision");
    2.12 -
    2.13 -
    2.14 --- New columns "notify_level" and "notify_event_id" in "member" table:
    2.15 -
    2.16 -CREATE TYPE "notify_level" AS ENUM
    2.17 -  ('none', 'voting', 'verification', 'discussion', 'all');
    2.18 -
    2.19 -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';
    2.20 -
    2.21 -ALTER TABLE "member" ADD "notify_level" "notify_level" NOT NULL DEFAULT 'none';
    2.22 -ALTER TABLE "member" ADD "notify_event_id" INT8;
    2.23 -
    2.24 -COMMENT ON COLUMN "member"."notify_level"    IS 'Selects which event notifications are to be sent to the "notify_email" mail address';
    2.25 -COMMENT ON COLUMN "member"."notify_event_id" IS 'Latest "id" of an "event" the member was notified about';
    2.26 -
    2.27 -
    2.28 --- Add primary key with type SERIAL8 (INT8) for "invite_code" table:
    2.29 -
    2.30 -ALTER TABLE "invite_code" DROP CONSTRAINT "invite_code_pkey";
    2.31 -ALTER TABLE "invite_code" ALTER "code" SET NOT NULL;
    2.32 -ALTER TABLE "invite_code" ADD UNIQUE ("code");
    2.33 -ALTER TABLE "invite_code" ADD "id" SERIAL8 PRIMARY KEY;
    2.34 -
    2.35 -
    2.36 --- Add index for "other_member_id" column of "contact" table:
    2.37 -
    2.38 -CREATE INDEX "contact_other_member_id_idx" ON "contact" ("other_member_id");
    2.39 -
    2.40 -
    2.41 --- New table "ignored_member":
    2.42 -
    2.43 -CREATE TABLE "ignored_member" (
    2.44 -        PRIMARY KEY ("member_id", "other_member_id"),
    2.45 -        "member_id"             INT4            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
    2.46 -        "other_member_id"       INT4            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
    2.47 -CREATE INDEX "ignored_member_other_member_id_idx" ON "ignored_member" ("other_member_id");
    2.48 -
    2.49 -COMMENT ON TABLE "ignored_member" IS 'Possibility to filter other members';
    2.50 -
    2.51 -COMMENT ON COLUMN "ignored_member"."member_id"       IS 'Member ignoring someone';
    2.52 -COMMENT ON COLUMN "ignored_member"."other_member_id" IS 'Member being ignored';
    2.53 -
    2.54 -
    2.55 --- New table "unit" with default entry:
    2.56 -
    2.57 -CREATE TABLE "unit" (
    2.58 -        "id"                    SERIAL4         PRIMARY KEY,
    2.59 -        "parent_id"             INT4            REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
    2.60 -        "active"                BOOLEAN         NOT NULL DEFAULT TRUE,
    2.61 -        "name"                  TEXT            NOT NULL,
    2.62 -        "description"           TEXT            NOT NULL DEFAULT '',
    2.63 -        "member_count"          INT4,
    2.64 -        "text_search_data"      TSVECTOR );
    2.65 -CREATE INDEX "unit_root_idx" ON "unit" ("id") WHERE "parent_id" ISNULL;
    2.66 -CREATE INDEX "unit_parent_id_idx" ON "unit" ("parent_id");
    2.67 -CREATE INDEX "unit_active_idx" ON "unit" ("active");
    2.68 -CREATE INDEX "unit_text_search_data_idx" ON "unit" USING gin ("text_search_data");
    2.69 -CREATE TRIGGER "update_text_search_data"
    2.70 -  BEFORE INSERT OR UPDATE ON "unit"
    2.71 -  FOR EACH ROW EXECUTE PROCEDURE
    2.72 -  tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
    2.73 -    "name", "description" );
    2.74 -
    2.75 -COMMENT ON TABLE "unit" IS 'Organizational units organized as trees; Delegations are not inherited through these trees.';
    2.76 -
    2.77 -COMMENT ON COLUMN "unit"."parent_id"    IS 'Parent id of tree node; Multiple roots allowed';
    2.78 -COMMENT ON COLUMN "unit"."active"       IS 'TRUE means new issues can be created in units of this area';
    2.79 -COMMENT ON COLUMN "unit"."member_count" IS 'Count of members as determined by column "voting_right" in table "privilege"';
    2.80 -
    2.81 -INSERT INTO "unit" ("name") VALUES ('Main');  -- NOTE: gets id 1
    2.82 -
    2.83 -
    2.84 --- New column "unit_id" in table "area":
    2.85 -
    2.86 -ALTER TABLE "area" ADD "unit_id" INT4 DEFAULT 1
    2.87 -  NOT NULL REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE;
    2.88 -ALTER TABLE "area" ALTER "unit_id" DROP DEFAULT;
    2.89 -
    2.90 -CREATE INDEX "area_unit_id_idx" ON "area" ("unit_id");
    2.91 -
    2.92 -
    2.93 --- Issue states:
    2.94 -
    2.95 -CREATE TYPE "issue_state" AS ENUM (
    2.96 -        'admission', 'discussion', 'verification', 'voting',
    2.97 -        'canceled_revoked_before_accepted',
    2.98 -        'canceled_issue_not_accepted',
    2.99 -        'canceled_after_revocation_during_discussion',
   2.100 -        'canceled_after_revocation_during_verification',
   2.101 -        'calculation',
   2.102 -        'canceled_no_initiative_admitted',
   2.103 -        'finished_without_winner', 'finished_with_winner');
   2.104 -
   2.105 -COMMENT ON TYPE "issue_state" IS 'State of issues';
   2.106 -
   2.107 -ALTER TABLE "issue" ADD "state" "issue_state";
   2.108 -
   2.109 --- NOTE: Filling new column with values is done after this transaction (see below)
   2.110 -
   2.111 -
   2.112 --- New column "revoked_by_member_id" in table "initiative":
   2.113 -
   2.114 -ALTER TABLE "initiative" ADD "revoked_by_member_id" INT4 REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE;
   2.115 -
   2.116 -COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoked the initiative';
   2.117 -
   2.118 --- NOTE: Filling new column with values is done after this transaction (see below)
   2.119 -
   2.120 -
   2.121 --- New table "ignored_initiative":
   2.122 -
   2.123 -CREATE TABLE "ignored_initiative" (
   2.124 -        PRIMARY KEY ("initiative_id", "member_id"),
   2.125 -        "initiative_id"         INT4            REFERENCES "initiative" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   2.126 -        "member_id"             INT4            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
   2.127 -CREATE INDEX "ignored_initiative_member_id_idx" ON "ignored_initiative" ("member_id");
   2.128 -
   2.129 -COMMENT ON TABLE "ignored_initiative" IS 'Possibility to filter initiatives';
   2.130 -
   2.131 -
   2.132 --- New table "invite_code_unit":
   2.133 -
   2.134 -CREATE TABLE "invite_code_unit" (
   2.135 -        PRIMARY KEY ("invite_code_id", "unit_id"),
   2.136 -        "invite_code_id"        INT8            REFERENCES "invite_code" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   2.137 -        "unit_id"               INT4            REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
   2.138 -
   2.139 -COMMENT ON TABLE "invite_code_unit" IS 'Units where accounts created with a given invite codes get voting rights';
   2.140 -
   2.141 -INSERT INTO "invite_code_unit" ("invite_code_id", "unit_id")
   2.142 -  SELECT "id" AS "invite_code_id", 1 AS "unit_id" FROM "invite_code";
   2.143 -
   2.144 -
   2.145 --- New table "privilege":
   2.146 -
   2.147 -CREATE TABLE "privilege" (
   2.148 -        PRIMARY KEY ("unit_id", "member_id"),
   2.149 -        "unit_id"               INT4            REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   2.150 -        "member_id"             INT4            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   2.151 -        "admin_manager"         BOOLEAN         NOT NULL DEFAULT FALSE,
   2.152 -        "unit_manager"          BOOLEAN         NOT NULL DEFAULT FALSE,
   2.153 -        "area_manager"          BOOLEAN         NOT NULL DEFAULT FALSE,
   2.154 -        "voting_right_manager"  BOOLEAN         NOT NULL DEFAULT FALSE,
   2.155 -        "voting_right"          BOOLEAN         NOT NULL DEFAULT TRUE );
   2.156 -
   2.157 -COMMENT ON TABLE "privilege" IS 'Members rights related to each unit';
   2.158 -
   2.159 -COMMENT ON COLUMN "privilege"."admin_manager"        IS 'Grant/revoke admin privileges to/from other users';
   2.160 -COMMENT ON COLUMN "privilege"."unit_manager"         IS 'Create or lock sub units';
   2.161 -COMMENT ON COLUMN "privilege"."area_manager"         IS 'Create or lock areas and set area parameters';
   2.162 -COMMENT ON COLUMN "privilege"."voting_right_manager" IS 'Select which members are allowed to discuss and vote inside the unit';
   2.163 -COMMENT ON COLUMN "privilege"."voting_right"         IS 'Right to discuss and vote';
   2.164 -
   2.165 -INSERT INTO "privilege" ("unit_id", "member_id", "voting_right")
   2.166 -  SELECT 1 AS "unit_id", "id" AS "member_id", TRUE AS "voting_right"
   2.167 -  FROM "member";
   2.168 -
   2.169 -
   2.170 --- Remove table "ignored_issue", which is no longer existent:
   2.171 -
   2.172 -DROP TABLE "ignored_issue";
   2.173 -
   2.174 -
   2.175 --- Replace TYPE "delegation_scope" with a new type, where 'global' is replaced by 'unit':
   2.176 -
   2.177 -ALTER TYPE "delegation_scope" RENAME TO "delegation_scope_old";  -- NOTE: dropped later
   2.178 -CREATE TYPE "delegation_scope" AS ENUM ('unit', 'area', 'issue');
   2.179 -COMMENT ON TYPE "delegation_scope" IS 'Scope for delegations: ''unit'', ''area'', or ''issue'' (order is relevant)';
   2.180 -
   2.181 -
   2.182 --- Delete views and functions being dependent on type "delegation_scope":
   2.183 -
   2.184 -DROP FUNCTION "delegation_chain"
   2.185 -  ( "member_id_p" "member"."id"%TYPE,
   2.186 -    "area_id_p"   "area"."id"%TYPE,
   2.187 -    "issue_id_p"  "issue"."id"%TYPE );
   2.188 -
   2.189 -DROP FUNCTION "delegation_chain"
   2.190 -  ( "member_id_p"           "member"."id"%TYPE,
   2.191 -    "area_id_p"             "area"."id"%TYPE,
   2.192 -    "issue_id_p"            "issue"."id"%TYPE,
   2.193 -    "simulate_trustee_id_p" "member"."id"%TYPE );
   2.194 -
   2.195 -DROP TYPE "delegation_chain_row";
   2.196 -
   2.197 -DROP VIEW "issue_delegation";
   2.198 -DROP VIEW "area_delegation";
   2.199 -DROP VIEW "global_delegation";
   2.200 -DROP VIEW "active_delegation";
   2.201 -
   2.202 -
   2.203 --- Modify "delegation" table to use new "delegation_scope" type:
   2.204 -
   2.205 -ALTER TABLE "delegation" DROP CONSTRAINT "no_global_delegation_to_null";
   2.206 -ALTER TABLE "delegation" DROP CONSTRAINT "area_id_and_issue_id_set_according_to_scope";
   2.207 -
   2.208 -DROP INDEX "delegation_global_truster_id_unique_idx";
   2.209 -
   2.210 -ALTER TABLE "delegation" ALTER "scope" TYPE "delegation_scope"
   2.211 -  USING CASE WHEN "scope" = 'global'
   2.212 -  THEN 'unit'::"delegation_scope"
   2.213 -  ELSE "scope"::text::"delegation_scope" END;
   2.214 -
   2.215 -ALTER TABLE "delegation" ADD "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE;
   2.216 -
   2.217 -ALTER TABLE "delegation" ADD CONSTRAINT "no_unit_delegation_to_null"
   2.218 -  CHECK ("trustee_id" NOTNULL OR "scope" != 'unit');
   2.219 -
   2.220 -ALTER TABLE "delegation" ADD UNIQUE ("unit_id", "truster_id");
   2.221 -
   2.222 -COMMENT ON COLUMN "delegation"."unit_id"  IS 'Reference to unit, if delegation is unit-wide, otherwise NULL';
   2.223 -
   2.224 --- NOTE: Column "unit_id" filled after transaction (see below)
   2.225 -
   2.226 -
   2.227 --- Modify snapshot tables to use new "delegation_scope" type:
   2.228 -
   2.229 -ALTER TABLE "delegating_population_snapshot" ALTER "scope" TYPE "delegation_scope"
   2.230 -  USING CASE WHEN "scope" = 'global'
   2.231 -  THEN 'unit'::"delegation_scope"
   2.232 -  ELSE "scope"::text::"delegation_scope" END;
   2.233 -
   2.234 -ALTER TABLE "delegating_interest_snapshot" ALTER "scope" TYPE "delegation_scope"
   2.235 -  USING CASE WHEN "scope" = 'global'
   2.236 -  THEN 'unit'::"delegation_scope"
   2.237 -  ELSE "scope"::text::"delegation_scope" END;
   2.238 -
   2.239 -ALTER TABLE "delegating_voter" ALTER "scope" TYPE "delegation_scope"
   2.240 -  USING CASE WHEN "scope" = 'global'
   2.241 -  THEN 'unit'::"delegation_scope"
   2.242 -  ELSE "scope"::text::"delegation_scope" END;
   2.243 -
   2.244 -
   2.245 --- New table "non_voter":
   2.246 -
   2.247 -CREATE TABLE "non_voter" (
   2.248 -        PRIMARY KEY ("issue_id", "member_id"),
   2.249 -        "issue_id"              INT4            REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   2.250 -        "member_id"             INT4            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE );
   2.251 -CREATE INDEX "non_voter_member_id_idx" ON "non_voter" ("member_id");
   2.252 -
   2.253 -COMMENT ON TABLE "non_voter" IS 'Members who decided to not vote directly on an issue';
   2.254 -
   2.255 -
   2.256 --- New tables "issue_comment" and "rendered_issue_comment":
   2.257 -
   2.258 -CREATE TABLE "issue_comment" (
   2.259 -        PRIMARY KEY ("issue_id", "member_id"),
   2.260 -        "issue_id"              INT4            REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   2.261 -        "member_id"             INT4            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   2.262 -        "changed"               TIMESTAMPTZ     NOT NULL DEFAULT now(),
   2.263 -        "formatting_engine"     TEXT,
   2.264 -        "content"               TEXT            NOT NULL,
   2.265 -        "text_search_data"      TSVECTOR );
   2.266 -CREATE INDEX "issue_comment_member_id_idx" ON "issue_comment" ("member_id");
   2.267 -CREATE INDEX "issue_comment_text_search_data_idx" ON "issue_comment" USING gin ("text_search_data");
   2.268 -CREATE TRIGGER "update_text_search_data"
   2.269 -  BEFORE INSERT OR UPDATE ON "issue_comment"
   2.270 -  FOR EACH ROW EXECUTE PROCEDURE
   2.271 -  tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
   2.272 -
   2.273 -COMMENT ON TABLE "issue_comment" IS 'Place to store free comments of members related to issues';
   2.274 -
   2.275 -COMMENT ON COLUMN "issue_comment"."changed" IS 'Time the comment was last changed';
   2.276 -
   2.277 -CREATE TABLE "rendered_issue_comment" (
   2.278 -        PRIMARY KEY ("issue_id", "member_id", "format"),
   2.279 -        FOREIGN KEY ("issue_id", "member_id")
   2.280 -          REFERENCES "issue_comment" ("issue_id", "member_id")
   2.281 -          ON DELETE CASCADE ON UPDATE CASCADE,
   2.282 -        "issue_id"              INT4,
   2.283 -        "member_id"             INT4,
   2.284 -        "format"                TEXT,
   2.285 -        "content"               TEXT            NOT NULL );
   2.286 -
   2.287 -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)';
   2.288 -
   2.289 -
   2.290 --- New tables "voting_comment" and "rendered_voting_comment":
   2.291 -
   2.292 -CREATE TABLE "voting_comment" (
   2.293 -        PRIMARY KEY ("issue_id", "member_id"),
   2.294 -        "issue_id"              INT4            REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   2.295 -        "member_id"             INT4            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   2.296 -        "changed"               TIMESTAMPTZ,
   2.297 -        "formatting_engine"     TEXT,
   2.298 -        "content"               TEXT            NOT NULL,
   2.299 -        "text_search_data"      TSVECTOR );
   2.300 -CREATE INDEX "voting_comment_member_id_idx" ON "voting_comment" ("member_id");
   2.301 -CREATE INDEX "voting_comment_text_search_data_idx" ON "voting_comment" USING gin ("text_search_data");
   2.302 -CREATE TRIGGER "update_text_search_data"
   2.303 -  BEFORE INSERT OR UPDATE ON "voting_comment"
   2.304 -  FOR EACH ROW EXECUTE PROCEDURE
   2.305 -  tsvector_update_trigger('text_search_data', 'pg_catalog.simple', "content");
   2.306 -
   2.307 -COMMENT ON TABLE "voting_comment" IS 'Storage for comments of voters to be published after voting has finished.';
   2.308 -
   2.309 -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.';
   2.310 -
   2.311 -CREATE TABLE "rendered_voting_comment" (
   2.312 -        PRIMARY KEY ("issue_id", "member_id", "format"),
   2.313 -        FOREIGN KEY ("issue_id", "member_id")
   2.314 -          REFERENCES "voting_comment" ("issue_id", "member_id")
   2.315 -          ON DELETE CASCADE ON UPDATE CASCADE,
   2.316 -        "issue_id"              INT4,
   2.317 -        "member_id"             INT4,
   2.318 -        "format"                TEXT,
   2.319 -        "content"               TEXT            NOT NULL );
   2.320 -
   2.321 -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)';
   2.322 -
   2.323 -
   2.324 --- New table "event":
   2.325 -
   2.326 -CREATE TYPE "event_type" AS ENUM (
   2.327 -        'issue_state_changed',
   2.328 -        'initiative_created_in_new_issue',
   2.329 -        'initiative_created_in_existing_issue',
   2.330 -        'initiative_revoked',
   2.331 -        'new_draft_created',
   2.332 -        'suggestion_created');
   2.333 -
   2.334 -COMMENT ON TYPE "event_type" IS 'Type used for column "event" of table "event"';
   2.335 -
   2.336 -CREATE TABLE "event" (
   2.337 -        "id"                    SERIAL8         PRIMARY KEY,
   2.338 -        "occurrence"            TIMESTAMPTZ     NOT NULL DEFAULT now(),
   2.339 -        "event"                 "event_type"    NOT NULL,
   2.340 -        "member_id"             INT4            REFERENCES "member" ("id") ON DELETE RESTRICT ON UPDATE CASCADE,
   2.341 -        "issue_id"              INT4            REFERENCES "issue" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   2.342 -        "state"                 "issue_state"   CHECK ("state" != 'calculation'),
   2.343 -        "initiative_id"         INT4,
   2.344 -        "draft_id"              INT8,
   2.345 -        "suggestion_id"         INT8,
   2.346 -        FOREIGN KEY ("issue_id", "initiative_id")
   2.347 -          REFERENCES "initiative" ("issue_id", "id")
   2.348 -          ON DELETE CASCADE ON UPDATE CASCADE,
   2.349 -        FOREIGN KEY ("initiative_id", "draft_id")
   2.350 -          REFERENCES "draft" ("initiative_id", "id")
   2.351 -          ON DELETE CASCADE ON UPDATE CASCADE,
   2.352 -        FOREIGN KEY ("initiative_id", "suggestion_id")
   2.353 -          REFERENCES "suggestion" ("initiative_id", "id")
   2.354 -          ON DELETE CASCADE ON UPDATE CASCADE,
   2.355 -        CONSTRAINT "null_constraints_for_issue_state_changed" CHECK (
   2.356 -          "event" != 'issue_state_changed' OR (
   2.357 -            "member_id"     ISNULL  AND
   2.358 -            "issue_id"      NOTNULL AND
   2.359 -            "state"         NOTNULL AND
   2.360 -            "initiative_id" ISNULL  AND
   2.361 -            "draft_id"      ISNULL  AND
   2.362 -            "suggestion_id" ISNULL  )),
   2.363 -        CONSTRAINT "null_constraints_for_initiative_creation_or_revocation_or_new_draft" CHECK (
   2.364 -          "event" NOT IN (
   2.365 -            'initiative_created_in_new_issue',
   2.366 -            'initiative_created_in_existing_issue',
   2.367 -            'initiative_revoked',
   2.368 -            'new_draft_created'
   2.369 -          ) OR (
   2.370 -            "member_id"     NOTNULL AND
   2.371 -            "issue_id"      NOTNULL AND
   2.372 -            "state"         NOTNULL AND
   2.373 -            "initiative_id" NOTNULL AND
   2.374 -            "draft_id"      NOTNULL AND
   2.375 -            "suggestion_id" ISNULL  )),
   2.376 -        CONSTRAINT "null_constraints_for_suggestion_creation" CHECK (
   2.377 -          "event" != 'suggestion_created' OR (
   2.378 -            "member_id"     NOTNULL AND
   2.379 -            "issue_id"      NOTNULL AND
   2.380 -            "state"         NOTNULL AND
   2.381 -            "initiative_id" NOTNULL AND
   2.382 -            "draft_id"      ISNULL  AND
   2.383 -            "suggestion_id" NOTNULL )) );
   2.384 -
   2.385 -COMMENT ON TABLE "event" IS 'Event table, automatically filled by triggers';
   2.386 -
   2.387 -COMMENT ON COLUMN "event"."occurrence" IS 'Point in time, when event occurred';
   2.388 -COMMENT ON COLUMN "event"."event"      IS 'Type of event (see TYPE "event_type")';
   2.389 -COMMENT ON COLUMN "event"."member_id"  IS 'Member who caused the event, if applicable';
   2.390 -COMMENT ON COLUMN "event"."state"      IS 'If issue_id is set: state of affected issue; If state changed: new state';
   2.391 -
   2.392 -
   2.393 --- Triggers to fill "event" table:
   2.394 -
   2.395 -CREATE FUNCTION "write_event_issue_state_changed_trigger"()
   2.396 -  RETURNS TRIGGER
   2.397 -  LANGUAGE 'plpgsql' VOLATILE AS $$
   2.398 -    BEGIN
   2.399 -      IF NEW."state" != OLD."state" AND NEW."state" != 'calculation' THEN
   2.400 -        INSERT INTO "event" ("event", "issue_id", "state")
   2.401 -          VALUES ('issue_state_changed', NEW."id", NEW."state");
   2.402 -      END IF;
   2.403 -      RETURN NULL;
   2.404 -    END;
   2.405 -  $$;
   2.406 -
   2.407 -CREATE TRIGGER "write_event_issue_state_changed"
   2.408 -  AFTER UPDATE ON "issue" FOR EACH ROW EXECUTE PROCEDURE
   2.409 -  "write_event_issue_state_changed_trigger"();
   2.410 -
   2.411 -COMMENT ON FUNCTION "write_event_issue_state_changed_trigger"() IS 'Implementation of trigger "write_event_issue_state_changed" on table "issue"';
   2.412 -COMMENT ON TRIGGER "write_event_issue_state_changed" ON "issue" IS 'Create entry in "event" table on "state" change';
   2.413 -
   2.414 -CREATE FUNCTION "write_event_initiative_or_draft_created_trigger"()
   2.415 -  RETURNS TRIGGER
   2.416 -  LANGUAGE 'plpgsql' VOLATILE AS $$
   2.417 -    DECLARE
   2.418 -      "initiative_row" "initiative"%ROWTYPE;
   2.419 -      "issue_row"      "issue"%ROWTYPE;
   2.420 -      "event_v"        "event_type";
   2.421 -    BEGIN
   2.422 -      SELECT * INTO "initiative_row" FROM "initiative"
   2.423 -        WHERE "id" = NEW."initiative_id";
   2.424 -      SELECT * INTO "issue_row" FROM "issue"
   2.425 -        WHERE "id" = "initiative_row"."issue_id";
   2.426 -      IF EXISTS (
   2.427 -        SELECT NULL FROM "draft"
   2.428 -        WHERE "initiative_id" = NEW."initiative_id"
   2.429 -        AND "id" != NEW."id"
   2.430 -      ) THEN
   2.431 -        "event_v" := 'new_draft_created';
   2.432 -      ELSE
   2.433 -        IF EXISTS (
   2.434 -          SELECT NULL FROM "initiative"
   2.435 -          WHERE "issue_id" = "initiative_row"."issue_id"
   2.436 -          AND "id" != "initiative_row"."id"
   2.437 -        ) THEN
   2.438 -          "event_v" := 'initiative_created_in_existing_issue';
   2.439 -        ELSE
   2.440 -          "event_v" := 'initiative_created_in_new_issue';
   2.441 -        END IF;
   2.442 -      END IF;
   2.443 -      INSERT INTO "event" (
   2.444 -          "event", "member_id",
   2.445 -          "issue_id", "state", "initiative_id", "draft_id"
   2.446 -        ) VALUES (
   2.447 -          "event_v",
   2.448 -          NEW."author_id",
   2.449 -          "initiative_row"."issue_id",
   2.450 -          "issue_row"."state",
   2.451 -          "initiative_row"."id",
   2.452 -          NEW."id" );
   2.453 -      RETURN NULL;
   2.454 -    END;
   2.455 -  $$;
   2.456 -
   2.457 -CREATE TRIGGER "write_event_initiative_or_draft_created"
   2.458 -  AFTER INSERT ON "draft" FOR EACH ROW EXECUTE PROCEDURE
   2.459 -  "write_event_initiative_or_draft_created_trigger"();
   2.460 -
   2.461 -COMMENT ON FUNCTION "write_event_initiative_or_draft_created_trigger"() IS 'Implementation of trigger "write_event_initiative_or_draft_created" on table "issue"';
   2.462 -COMMENT ON TRIGGER "write_event_initiative_or_draft_created" ON "draft" IS 'Create entry in "event" table on draft creation';
   2.463 -
   2.464 -CREATE FUNCTION "write_event_initiative_revoked_trigger"()
   2.465 -  RETURNS TRIGGER
   2.466 -  LANGUAGE 'plpgsql' VOLATILE AS $$
   2.467 -    DECLARE
   2.468 -      "issue_row"      "issue"%ROWTYPE;
   2.469 -    BEGIN
   2.470 -      SELECT * INTO "issue_row" FROM "issue"
   2.471 -        WHERE "id" = NEW."issue_id";
   2.472 -      IF OLD."revoked" ISNULL AND NEW."revoked" NOTNULL THEN
   2.473 -        INSERT INTO "event" (
   2.474 -            "event", "member_id", "issue_id", "state", "initiative_id"
   2.475 -          ) VALUES (
   2.476 -            'initiative_revoked',
   2.477 -            NEW."revoked_by_member_id",
   2.478 -            NEW."issue_id",
   2.479 -            "issue_row"."state",
   2.480 -            NEW."id" );
   2.481 -      END IF;
   2.482 -      RETURN NULL;
   2.483 -    END;
   2.484 -  $$;
   2.485 -
   2.486 -CREATE TRIGGER "write_event_initiative_revoked"
   2.487 -  AFTER UPDATE ON "initiative" FOR EACH ROW EXECUTE PROCEDURE
   2.488 -  "write_event_initiative_revoked_trigger"();
   2.489 -
   2.490 -COMMENT ON FUNCTION "write_event_initiative_revoked_trigger"()      IS 'Implementation of trigger "write_event_initiative_revoked" on table "issue"';
   2.491 -COMMENT ON TRIGGER "write_event_initiative_revoked" ON "initiative" IS 'Create entry in "event" table, when an initiative is revoked';
   2.492 -
   2.493 -CREATE FUNCTION "write_event_suggestion_created_trigger"()
   2.494 -  RETURNS TRIGGER
   2.495 -  LANGUAGE 'plpgsql' VOLATILE AS $$
   2.496 -    DECLARE
   2.497 -      "initiative_row" "initiative"%ROWTYPE;
   2.498 -      "issue_row"      "issue"%ROWTYPE;
   2.499 -    BEGIN
   2.500 -      SELECT * INTO "initiative_row" FROM "initiative"
   2.501 -        WHERE "id" = NEW."initiative_id";
   2.502 -      SELECT * INTO "issue_row" FROM "issue"
   2.503 -        WHERE "id" = "initiative_row"."issue_id";
   2.504 -      INSERT INTO "event" (
   2.505 -          "event", "member_id",
   2.506 -          "issue_id", "state", "initiative_id", "suggestion_id"
   2.507 -        ) VALUES (
   2.508 -          'suggestion_created',
   2.509 -          NEW."author_id",
   2.510 -          "initiative_row"."issue_id",
   2.511 -          "issue_row"."state",
   2.512 -          "initiative_row"."id",
   2.513 -          NEW."id" );
   2.514 -      RETURN NULL;
   2.515 -    END;
   2.516 -  $$;
   2.517 -
   2.518 -CREATE TRIGGER "write_event_suggestion_created"
   2.519 -  AFTER INSERT ON "suggestion" FOR EACH ROW EXECUTE PROCEDURE
   2.520 -  "write_event_suggestion_created_trigger"();
   2.521 -
   2.522 -COMMENT ON FUNCTION "write_event_suggestion_created_trigger"()      IS 'Implementation of trigger "write_event_suggestion_created" on table "issue"';
   2.523 -COMMENT ON TRIGGER "write_event_suggestion_created" ON "suggestion" IS 'Create entry in "event" table on suggestion creation';
   2.524 -
   2.525 -
   2.526 --- Modified views:
   2.527 -
   2.528 -CREATE VIEW "unit_delegation" AS
   2.529 -  SELECT
   2.530 -    "unit"."id" AS "unit_id",
   2.531 -    "delegation"."id",
   2.532 -    "delegation"."truster_id",
   2.533 -    "delegation"."trustee_id",
   2.534 -    "delegation"."scope"
   2.535 -  FROM "unit"
   2.536 -  JOIN "delegation"
   2.537 -    ON "delegation"."unit_id" = "unit"."id"
   2.538 -  JOIN "member"
   2.539 -    ON "delegation"."truster_id" = "member"."id"
   2.540 -  JOIN "privilege"
   2.541 -    ON "delegation"."unit_id" = "privilege"."unit_id"
   2.542 -    AND "delegation"."truster_id" = "privilege"."member_id"
   2.543 -  WHERE "member"."active" AND "privilege"."voting_right";
   2.544 -
   2.545 -COMMENT ON VIEW "unit_delegation" IS 'Unit delegations where trusters are active and have voting right';
   2.546 -
   2.547 -CREATE VIEW "area_delegation" AS
   2.548 -  SELECT DISTINCT ON ("area"."id", "delegation"."truster_id")
   2.549 -    "area"."id" AS "area_id",
   2.550 -    "delegation"."id",
   2.551 -    "delegation"."truster_id",
   2.552 -    "delegation"."trustee_id",
   2.553 -    "delegation"."scope"
   2.554 -  FROM "area"
   2.555 -  JOIN "delegation"
   2.556 -    ON "delegation"."unit_id" = "area"."unit_id"
   2.557 -    OR "delegation"."area_id" = "area"."id"
   2.558 -  JOIN "member"
   2.559 -    ON "delegation"."truster_id" = "member"."id"
   2.560 -  JOIN "privilege"
   2.561 -    ON "area"."unit_id" = "privilege"."unit_id"
   2.562 -    AND "delegation"."truster_id" = "privilege"."member_id"
   2.563 -  WHERE "member"."active" AND "privilege"."voting_right"
   2.564 -  ORDER BY
   2.565 -    "area"."id",
   2.566 -    "delegation"."truster_id",
   2.567 -    "delegation"."scope" DESC;
   2.568 -
   2.569 -COMMENT ON VIEW "area_delegation" IS 'Area delegations where trusters are active and have voting right';
   2.570 -
   2.571 -CREATE VIEW "issue_delegation" AS
   2.572 -  SELECT DISTINCT ON ("issue"."id", "delegation"."truster_id")
   2.573 -    "issue"."id" AS "issue_id",
   2.574 -    "delegation"."id",
   2.575 -    "delegation"."truster_id",
   2.576 -    "delegation"."trustee_id",
   2.577 -    "delegation"."scope"
   2.578 -  FROM "issue"
   2.579 -  JOIN "area"
   2.580 -    ON "area"."id" = "issue"."area_id"
   2.581 -  JOIN "delegation"
   2.582 -    ON "delegation"."unit_id" = "area"."unit_id"
   2.583 -    OR "delegation"."area_id" = "area"."id"
   2.584 -    OR "delegation"."issue_id" = "issue"."id"
   2.585 -  JOIN "member"
   2.586 -    ON "delegation"."truster_id" = "member"."id"
   2.587 -  JOIN "privilege"
   2.588 -    ON "area"."unit_id" = "privilege"."unit_id"
   2.589 -    AND "delegation"."truster_id" = "privilege"."member_id"
   2.590 -  WHERE "member"."active" AND "privilege"."voting_right"
   2.591 -  ORDER BY
   2.592 -    "issue"."id",
   2.593 -    "delegation"."truster_id",
   2.594 -    "delegation"."scope" DESC;
   2.595 -
   2.596 -COMMENT ON VIEW "issue_delegation" IS 'Issue delegations where trusters are active and have voting right';
   2.597 -
   2.598 -CREATE VIEW "unit_member_count" AS
   2.599 -  SELECT
   2.600 -    "unit"."id" AS "unit_id",
   2.601 -    sum("member"."id") AS "member_count"
   2.602 -  FROM "unit"
   2.603 -  LEFT JOIN "privilege"
   2.604 -  ON "privilege"."unit_id" = "unit"."id" 
   2.605 -  AND "privilege"."voting_right"
   2.606 -  LEFT JOIN "member"
   2.607 -  ON "member"."id" = "privilege"."member_id"
   2.608 -  AND "member"."active"
   2.609 -  GROUP BY "unit"."id";
   2.610 -
   2.611 -COMMENT ON VIEW "unit_member_count" IS 'View used to update "member_count" column of "unit" table';
   2.612 -
   2.613 -DROP VIEW "area_member_count";
   2.614 -CREATE VIEW "area_member_count" AS
   2.615 -  SELECT
   2.616 -    "area"."id" AS "area_id",
   2.617 -    count("member"."id") AS "direct_member_count",
   2.618 -    coalesce(
   2.619 -      sum(
   2.620 -        CASE WHEN "member"."id" NOTNULL THEN
   2.621 -          "membership_weight"("area"."id", "member"."id")
   2.622 -        ELSE 0 END
   2.623 -      )
   2.624 -    ) AS "member_weight",
   2.625 -    coalesce(
   2.626 -      sum(
   2.627 -        CASE WHEN "member"."id" NOTNULL AND "membership"."autoreject" THEN
   2.628 -          "membership_weight"("area"."id", "member"."id")
   2.629 -        ELSE 0 END
   2.630 -      )
   2.631 -    ) AS "autoreject_weight"
   2.632 -  FROM "area"
   2.633 -  LEFT JOIN "membership"
   2.634 -  ON "area"."id" = "membership"."area_id"
   2.635 -  LEFT JOIN "privilege"
   2.636 -  ON "privilege"."unit_id" = "area"."unit_id"
   2.637 -  AND "privilege"."member_id" = "membership"."member_id"
   2.638 -  AND "privilege"."voting_right"
   2.639 -  LEFT JOIN "member"
   2.640 -  ON "member"."id" = "privilege"."member_id"  -- NOTE: no membership here!
   2.641 -  AND "member"."active"
   2.642 -  GROUP BY "area"."id";
   2.643 -
   2.644 -COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count", "member_weight" and "autoreject_weight" columns of table "area"';
   2.645 -
   2.646 -
   2.647 --- New view "event_seen_by_member":
   2.648 -
   2.649 -CREATE VIEW "event_seen_by_member" AS
   2.650 -  SELECT
   2.651 -    "member"."id" AS "seen_by_member_id",
   2.652 -    CASE WHEN "event"."state" IN (
   2.653 -      'voting',
   2.654 -      'finished_without_winner',
   2.655 -      'finished_with_winner'
   2.656 -    ) THEN
   2.657 -      'voting'::"notify_level"
   2.658 -    ELSE
   2.659 -      CASE WHEN "event"."state" IN (
   2.660 -        'verification',
   2.661 -        'canceled_after_revocation_during_verification',
   2.662 -        'canceled_no_initiative_admitted'
   2.663 -      ) THEN
   2.664 -        'verification'::"notify_level"
   2.665 -      ELSE
   2.666 -        CASE WHEN "event"."state" IN (
   2.667 -          'discussion',
   2.668 -          'canceled_after_revocation_during_discussion'
   2.669 -        ) THEN
   2.670 -          'discussion'::"notify_level"
   2.671 -        ELSE
   2.672 -          'all'::"notify_level"
   2.673 -        END
   2.674 -      END
   2.675 -    END AS "notify_level",
   2.676 -    "event".*
   2.677 -  FROM "member" CROSS JOIN "event"
   2.678 -  LEFT JOIN "issue"
   2.679 -    ON "event"."issue_id" = "issue"."id"
   2.680 -  LEFT JOIN "membership"
   2.681 -    ON "member"."id" = "membership"."member_id"
   2.682 -    AND "issue"."area_id" = "membership"."area_id"
   2.683 -  LEFT JOIN "interest"
   2.684 -    ON "member"."id" = "interest"."member_id"
   2.685 -    AND "event"."issue_id" = "interest"."issue_id"
   2.686 -  LEFT JOIN "supporter"
   2.687 -    ON "member"."id" = "supporter"."member_id"
   2.688 -    AND "event"."initiative_id" = "supporter"."initiative_id"
   2.689 -  LEFT JOIN "ignored_member"
   2.690 -    ON "member"."id" = "ignored_member"."member_id"
   2.691 -    AND "event"."member_id" = "ignored_member"."other_member_id"
   2.692 -  LEFT JOIN "ignored_initiative"
   2.693 -    ON "member"."id" = "ignored_initiative"."member_id"
   2.694 -    AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
   2.695 -  WHERE (
   2.696 -    "supporter"."member_id" NOTNULL OR
   2.697 -    "interest"."member_id" NOTNULL OR
   2.698 -    ( "membership"."member_id" NOTNULL AND
   2.699 -      "event"."event" IN (
   2.700 -        'issue_state_changed',
   2.701 -        'initiative_created_in_new_issue',
   2.702 -        'initiative_created_in_existing_issue',
   2.703 -        'initiative_revoked' ) ) )
   2.704 -  AND "ignored_member"."member_id" ISNULL
   2.705 -  AND "ignored_initiative"."member_id" ISNULL;
   2.706 -
   2.707 -COMMENT ON VIEW "event_seen_by_member" IS 'Events as seen by a member, depending on its memberships, interests and support';
   2.708 -
   2.709 -
   2.710 --- New view "pending_notification":
   2.711 -
   2.712 -CREATE VIEW "pending_notification" AS
   2.713 -  SELECT
   2.714 -    "member"."id" AS "seen_by_member_id",
   2.715 -    "event".*
   2.716 -  FROM "member" CROSS JOIN "event"
   2.717 -  LEFT JOIN "issue"
   2.718 -    ON "event"."issue_id" = "issue"."id"
   2.719 -  LEFT JOIN "membership"
   2.720 -    ON "member"."id" = "membership"."member_id"
   2.721 -    AND "issue"."area_id" = "membership"."area_id"
   2.722 -  LEFT JOIN "interest"
   2.723 -    ON "member"."id" = "interest"."member_id"
   2.724 -    AND "event"."issue_id" = "interest"."issue_id"
   2.725 -  LEFT JOIN "supporter"
   2.726 -    ON "member"."id" = "supporter"."member_id"
   2.727 -    AND "event"."initiative_id" = "supporter"."initiative_id"
   2.728 -  LEFT JOIN "ignored_member"
   2.729 -    ON "member"."id" = "ignored_member"."member_id"
   2.730 -    AND "event"."member_id" = "ignored_member"."other_member_id"
   2.731 -  LEFT JOIN "ignored_initiative"
   2.732 -    ON "member"."id" = "ignored_initiative"."member_id"
   2.733 -    AND "event"."initiative_id" = "ignored_initiative"."initiative_id"
   2.734 -  WHERE (
   2.735 -    "member"."notify_event_id" ISNULL OR
   2.736 -    ( "member"."notify_event_id" NOTNULL AND
   2.737 -      "member"."notify_event_id" < "event"."id" ) )
   2.738 -  AND (
   2.739 -    ( "member"."notify_level" >= 'all' ) OR
   2.740 -    ( "member"."notify_level" >= 'voting' AND
   2.741 -      "event"."state" IN (
   2.742 -        'voting',
   2.743 -        'finished_without_winner',
   2.744 -        'finished_with_winner' ) ) OR
   2.745 -    ( "member"."notify_level" >= 'verification' AND
   2.746 -      "event"."state" IN (
   2.747 -        'verification',
   2.748 -        'canceled_after_revocation_during_verification',
   2.749 -        'canceled_no_initiative_admitted' ) ) OR
   2.750 -    ( "member"."notify_level" >= 'discussion' AND
   2.751 -      "event"."state" IN (
   2.752 -        'discussion',
   2.753 -        'canceled_after_revocation_during_discussion' ) ) )
   2.754 -  AND (
   2.755 -    "supporter"."member_id" NOTNULL OR
   2.756 -    "interest"."member_id" NOTNULL OR
   2.757 -    ( "membership"."member_id" NOTNULL AND
   2.758 -      "event"."event" IN (
   2.759 -        'issue_state_changed',
   2.760 -        'initiative_created_in_new_issue',
   2.761 -        'initiative_created_in_existing_issue',
   2.762 -        'initiative_revoked' ) ) )
   2.763 -  AND "ignored_member"."member_id" ISNULL
   2.764 -  AND "ignored_initiative"."member_id" ISNULL;
   2.765 -
   2.766 -COMMENT ON VIEW "pending_notification" IS 'Events to be sent to "notify_email" address of member referred to by "seen_by_member_id"';
   2.767 -
   2.768 -
   2.769 -COMMENT ON TYPE "timeline_event" IS 'Types of event in timeline tables (DEPRECATED)';
   2.770 -COMMENT ON VIEW "timeline_issue" IS 'Helper view for "timeline" view (DEPRECATED)';
   2.771 -COMMENT ON VIEW "timeline_initiative" IS 'Helper view for "timeline" view (DEPRECATED)';
   2.772 -COMMENT ON VIEW "timeline_draft" IS 'Helper view for "timeline" view (DEPRECATED)';
   2.773 -COMMENT ON VIEW "timeline_suggestion" IS 'Helper view for "timeline" view (DEPRECATED)';
   2.774 -COMMENT ON VIEW "timeline" IS 'Aggregation of different events in the system (DEPRECATED)';
   2.775 -
   2.776 -
   2.777 --- Modified "delegation_chain" functions:
   2.778 -
   2.779 -CREATE TYPE "delegation_chain_row" AS (
   2.780 -        "index"                 INT4,
   2.781 -        "member_id"             INT4,
   2.782 -        "member_valid"          BOOLEAN,
   2.783 -        "participation"         BOOLEAN,
   2.784 -        "overridden"            BOOLEAN,
   2.785 -        "scope_in"              "delegation_scope",
   2.786 -        "scope_out"             "delegation_scope",
   2.787 -        "disabled_out"          BOOLEAN,
   2.788 -        "loop"                  "delegation_chain_loop_tag" );
   2.789 -
   2.790 -COMMENT ON TYPE "delegation_chain_row" IS 'Type of rows returned by "delegation_chain"(...) functions';
   2.791 -
   2.792 -COMMENT ON COLUMN "delegation_chain_row"."index"         IS 'Index starting with 0 and counting up';
   2.793 -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';
   2.794 -COMMENT ON COLUMN "delegation_chain_row"."overridden"    IS 'True, if an entry with lower index has "participation" set to true';
   2.795 -COMMENT ON COLUMN "delegation_chain_row"."scope_in"      IS 'Scope of used incoming delegation';
   2.796 -COMMENT ON COLUMN "delegation_chain_row"."scope_out"     IS 'Scope of used outgoing delegation';
   2.797 -COMMENT ON COLUMN "delegation_chain_row"."disabled_out"  IS 'Outgoing delegation is explicitly disabled by a delegation with trustee_id set to NULL';
   2.798 -COMMENT ON COLUMN "delegation_chain_row"."loop"          IS 'Not null, if member is part of a loop, see "delegation_chain_loop_tag" type';
   2.799 -
   2.800 -
   2.801 -CREATE FUNCTION "delegation_chain"
   2.802 -  ( "member_id_p"           "member"."id"%TYPE,
   2.803 -    "unit_id_p"             "unit"."id"%TYPE,
   2.804 -    "area_id_p"             "area"."id"%TYPE,
   2.805 -    "issue_id_p"            "issue"."id"%TYPE,
   2.806 -    "simulate_trustee_id_p" "member"."id"%TYPE )
   2.807 -  RETURNS SETOF "delegation_chain_row"
   2.808 -  LANGUAGE 'plpgsql' STABLE AS $$
   2.809 -    DECLARE
   2.810 -      "scope_v"            "delegation_scope";
   2.811 -      "unit_id_v"          "unit"."id"%TYPE;
   2.812 -      "area_id_v"          "area"."id"%TYPE;
   2.813 -      "visited_member_ids" INT4[];  -- "member"."id"%TYPE[]
   2.814 -      "loop_member_id_v"   "member"."id"%TYPE;
   2.815 -      "output_row"         "delegation_chain_row";
   2.816 -      "output_rows"        "delegation_chain_row"[];
   2.817 -      "delegation_row"     "delegation"%ROWTYPE;
   2.818 -      "row_count"          INT4;
   2.819 -      "i"                  INT4;
   2.820 -      "loop_v"             BOOLEAN;
   2.821 -    BEGIN
   2.822 -      IF
   2.823 -        "unit_id_p" NOTNULL AND
   2.824 -        "area_id_p" ISNULL AND
   2.825 -        "issue_id_p" ISNULL
   2.826 -      THEN
   2.827 -        "scope_v" := 'unit';
   2.828 -        "unit_id_v" := "unit_id_p";
   2.829 -      ELSIF
   2.830 -        "unit_id_p" ISNULL AND
   2.831 -        "area_id_p" NOTNULL AND
   2.832 -        "issue_id_p" ISNULL
   2.833 -      THEN
   2.834 -        "scope_v" := 'area';
   2.835 -        "area_id_v" := "area_id_p";
   2.836 -        SELECT "unit_id" INTO "unit_id_v"
   2.837 -          FROM "area" WHERE "id" = "area_id_v";
   2.838 -      ELSIF
   2.839 -        "unit_id_p" ISNULL AND
   2.840 -        "area_id_p" ISNULL AND
   2.841 -        "issue_id_p" NOTNULL
   2.842 -      THEN
   2.843 -        "scope_v" := 'issue';
   2.844 -        SELECT "area_id" INTO "area_id_v"
   2.845 -          FROM "issue" WHERE "id" = "issue_id_p";
   2.846 -        SELECT "unit_id" INTO "unit_id_v"
   2.847 -          FROM "area"  WHERE "id" = "area_id_v";
   2.848 -      ELSE
   2.849 -        RAISE EXCEPTION 'Exactly one of unit_id_p, area_id_p, or issue_id_p must be NOTNULL.';
   2.850 -      END IF;
   2.851 -      "visited_member_ids" := '{}';
   2.852 -      "loop_member_id_v"   := NULL;
   2.853 -      "output_rows"        := '{}';
   2.854 -      "output_row"."index"         := 0;
   2.855 -      "output_row"."member_id"     := "member_id_p";
   2.856 -      "output_row"."member_valid"  := TRUE;
   2.857 -      "output_row"."participation" := FALSE;
   2.858 -      "output_row"."overridden"    := FALSE;
   2.859 -      "output_row"."disabled_out"  := FALSE;
   2.860 -      "output_row"."scope_out"     := NULL;
   2.861 -      LOOP
   2.862 -        IF "visited_member_ids" @> ARRAY["output_row"."member_id"] THEN
   2.863 -          "loop_member_id_v" := "output_row"."member_id";
   2.864 -        ELSE
   2.865 -          "visited_member_ids" :=
   2.866 -            "visited_member_ids" || "output_row"."member_id";
   2.867 -        END IF;
   2.868 -        IF "output_row"."participation" THEN
   2.869 -          "output_row"."overridden" := TRUE;
   2.870 -        END IF;
   2.871 -        "output_row"."scope_in" := "output_row"."scope_out";
   2.872 -        IF EXISTS (
   2.873 -          SELECT NULL FROM "member" JOIN "privilege"
   2.874 -          ON "privilege"."member_id" = "member"."id"
   2.875 -          AND "privilege"."unit_id" = "unit_id_v"
   2.876 -          WHERE "id" = "output_row"."member_id"
   2.877 -          AND "member"."active" AND "privilege"."voting_right"
   2.878 -        ) THEN
   2.879 -          IF "scope_v" = 'unit' THEN
   2.880 -            SELECT * INTO "delegation_row" FROM "delegation"
   2.881 -              WHERE "truster_id" = "output_row"."member_id"
   2.882 -              AND "unit_id" = "unit_id_v";
   2.883 -          ELSIF "scope_v" = 'area' THEN
   2.884 -            "output_row"."participation" := EXISTS (
   2.885 -              SELECT NULL FROM "membership"
   2.886 -              WHERE "area_id" = "area_id_p"
   2.887 -              AND "member_id" = "output_row"."member_id"
   2.888 -            );
   2.889 -            SELECT * INTO "delegation_row" FROM "delegation"
   2.890 -              WHERE "truster_id" = "output_row"."member_id"
   2.891 -              AND (
   2.892 -                "unit_id" = "unit_id_v" OR
   2.893 -                "area_id" = "area_id_v"
   2.894 -              )
   2.895 -              ORDER BY "scope" DESC;
   2.896 -          ELSIF "scope_v" = 'issue' THEN
   2.897 -            "output_row"."participation" := EXISTS (
   2.898 -              SELECT NULL FROM "interest"
   2.899 -              WHERE "issue_id" = "issue_id_p"
   2.900 -              AND "member_id" = "output_row"."member_id"
   2.901 -            );
   2.902 -            SELECT * INTO "delegation_row" FROM "delegation"
   2.903 -              WHERE "truster_id" = "output_row"."member_id"
   2.904 -              AND (
   2.905 -                "unit_id" = "unit_id_v" OR
   2.906 -                "area_id" = "area_id_v" OR
   2.907 -                "issue_id" = "issue_id_p"
   2.908 -              )
   2.909 -              ORDER BY "scope" DESC;
   2.910 -          END IF;
   2.911 -        ELSE
   2.912 -          "output_row"."member_valid"  := FALSE;
   2.913 -          "output_row"."participation" := FALSE;
   2.914 -          "output_row"."scope_out"     := NULL;
   2.915 -          "delegation_row" := ROW(NULL);
   2.916 -        END IF;
   2.917 -        IF
   2.918 -          "output_row"."member_id" = "member_id_p" AND
   2.919 -          "simulate_trustee_id_p" NOTNULL
   2.920 -        THEN
   2.921 -          "output_row"."scope_out" := "scope_v";
   2.922 -          "output_rows" := "output_rows" || "output_row";
   2.923 -          "output_row"."member_id" := "simulate_trustee_id_p";
   2.924 -        ELSIF "delegation_row"."trustee_id" NOTNULL THEN
   2.925 -          "output_row"."scope_out" := "delegation_row"."scope";
   2.926 -          "output_rows" := "output_rows" || "output_row";
   2.927 -          "output_row"."member_id" := "delegation_row"."trustee_id";
   2.928 -        ELSIF "delegation_row"."scope" NOTNULL THEN
   2.929 -          "output_row"."scope_out" := "delegation_row"."scope";
   2.930 -          "output_row"."disabled_out" := TRUE;
   2.931 -          "output_rows" := "output_rows" || "output_row";
   2.932 -          EXIT;
   2.933 -        ELSE
   2.934 -          "output_row"."scope_out" := NULL;
   2.935 -          "output_rows" := "output_rows" || "output_row";
   2.936 -          EXIT;
   2.937 -        END IF;
   2.938 -        EXIT WHEN "loop_member_id_v" NOTNULL;
   2.939 -        "output_row"."index" := "output_row"."index" + 1;
   2.940 -      END LOOP;
   2.941 -      "row_count" := array_upper("output_rows", 1);
   2.942 -      "i"      := 1;
   2.943 -      "loop_v" := FALSE;
   2.944 -      LOOP
   2.945 -        "output_row" := "output_rows"["i"];
   2.946 -        EXIT WHEN "output_row" ISNULL;  -- NOTE: ISNULL and NOT ... NOTNULL produce different results!
   2.947 -        IF "loop_v" THEN
   2.948 -          IF "i" + 1 = "row_count" THEN
   2.949 -            "output_row"."loop" := 'last';
   2.950 -          ELSIF "i" = "row_count" THEN
   2.951 -            "output_row"."loop" := 'repetition';
   2.952 -          ELSE
   2.953 -            "output_row"."loop" := 'intermediate';
   2.954 -          END IF;
   2.955 -        ELSIF "output_row"."member_id" = "loop_member_id_v" THEN
   2.956 -          "output_row"."loop" := 'first';
   2.957 -          "loop_v" := TRUE;
   2.958 -        END IF;
   2.959 -        IF "scope_v" = 'unit' THEN
   2.960 -          "output_row"."participation" := NULL;
   2.961 -        END IF;
   2.962 -        RETURN NEXT "output_row";
   2.963 -        "i" := "i" + 1;
   2.964 -      END LOOP;
   2.965 -      RETURN;
   2.966 -    END;
   2.967 -  $$;
   2.968 -
   2.969 -COMMENT ON FUNCTION "delegation_chain"
   2.970 -  ( "member"."id"%TYPE,
   2.971 -    "unit"."id"%TYPE,
   2.972 -    "area"."id"%TYPE,
   2.973 -    "issue"."id"%TYPE,
   2.974 -    "member"."id"%TYPE )
   2.975 -  IS 'Helper function for frontends to display delegation chains; Not part of internal voting logic';
   2.976 -
   2.977 -
   2.978 -CREATE FUNCTION "delegation_chain"
   2.979 -  ( "member_id_p" "member"."id"%TYPE,
   2.980 -    "unit_id_p"   "unit"."id"%TYPE,
   2.981 -    "area_id_p"   "area"."id"%TYPE,
   2.982 -    "issue_id_p"  "issue"."id"%TYPE )
   2.983 -  RETURNS SETOF "delegation_chain_row"
   2.984 -  LANGUAGE 'plpgsql' STABLE AS $$
   2.985 -    DECLARE
   2.986 -      "result_row" "delegation_chain_row";
   2.987 -    BEGIN
   2.988 -      FOR "result_row" IN
   2.989 -        SELECT * FROM "delegation_chain"(
   2.990 -          "member_id_p", "unit_id_p", "area_id_p", "issue_id_p", NULL
   2.991 -        )
   2.992 -      LOOP
   2.993 -        RETURN NEXT "result_row";
   2.994 -      END LOOP;
   2.995 -      RETURN;
   2.996 -    END;
   2.997 -  $$;
   2.998 -
   2.999 -COMMENT ON FUNCTION "delegation_chain"
  2.1000 -  ( "member"."id"%TYPE,
  2.1001 -    "unit"."id"%TYPE,
  2.1002 -    "area"."id"%TYPE,
  2.1003 -    "issue"."id"%TYPE )
  2.1004 -  IS 'Shortcut for "delegation_chain"(...) function where 4th parameter is null';
  2.1005 -
  2.1006 -
  2.1007 --- Other modified functions:
  2.1008 -
  2.1009 -CREATE OR REPLACE FUNCTION "lock_issue"
  2.1010 -  ( "issue_id_p" "issue"."id"%TYPE )
  2.1011 -  RETURNS VOID
  2.1012 -  LANGUAGE 'plpgsql' VOLATILE AS $$
  2.1013 -    BEGIN
  2.1014 -      LOCK TABLE "member"     IN SHARE MODE;
  2.1015 -      LOCK TABLE "privilege"  IN SHARE MODE;
  2.1016 -      LOCK TABLE "membership" IN SHARE MODE;
  2.1017 -      LOCK TABLE "policy"     IN SHARE MODE;
  2.1018 -      PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
  2.1019 -      -- NOTE: The row-level exclusive lock in combination with the
  2.1020 -      -- share_row_lock_issue(_via_initiative)_trigger functions (which
  2.1021 -      -- acquire a row-level share lock on the issue) ensure that no data
  2.1022 -      -- is changed, which could affect calculation of snapshots or
  2.1023 -      -- counting of votes. Table "delegation" must be table-level-locked,
  2.1024 -      -- as it also contains issue- and global-scope delegations.
  2.1025 -      LOCK TABLE "delegation" IN SHARE MODE;
  2.1026 -      LOCK TABLE "direct_population_snapshot"     IN EXCLUSIVE MODE;
  2.1027 -      LOCK TABLE "delegating_population_snapshot" IN EXCLUSIVE MODE;
  2.1028 -      LOCK TABLE "direct_interest_snapshot"       IN EXCLUSIVE MODE;
  2.1029 -      LOCK TABLE "delegating_interest_snapshot"   IN EXCLUSIVE MODE;
  2.1030 -      LOCK TABLE "direct_supporter_snapshot"      IN EXCLUSIVE MODE;
  2.1031 -      RETURN;
  2.1032 -    END;
  2.1033 -  $$;
  2.1034 -
  2.1035 -CREATE OR REPLACE FUNCTION "calculate_member_counts"()
  2.1036 -  RETURNS VOID
  2.1037 -  LANGUAGE 'plpgsql' VOLATILE AS $$
  2.1038 -    BEGIN
  2.1039 -      LOCK TABLE "member"       IN SHARE MODE;
  2.1040 -      LOCK TABLE "member_count" IN EXCLUSIVE MODE;
  2.1041 -      LOCK TABLE "unit"         IN EXCLUSIVE MODE;
  2.1042 -      LOCK TABLE "area"         IN EXCLUSIVE MODE;
  2.1043 -      LOCK TABLE "privilege"    IN SHARE MODE;
  2.1044 -      LOCK TABLE "membership"   IN SHARE MODE;
  2.1045 -      DELETE FROM "member_count";
  2.1046 -      INSERT INTO "member_count" ("total_count")
  2.1047 -        SELECT "total_count" FROM "member_count_view";
  2.1048 -      UPDATE "unit" SET "member_count" = "view"."member_count"
  2.1049 -        FROM "unit_member_count" AS "view"
  2.1050 -        WHERE "view"."unit_id" = "unit"."id";
  2.1051 -      UPDATE "area" SET
  2.1052 -        "direct_member_count" = "view"."direct_member_count",
  2.1053 -        "member_weight"       = "view"."member_weight",
  2.1054 -        "autoreject_weight"   = "view"."autoreject_weight"
  2.1055 -        FROM "area_member_count" AS "view"
  2.1056 -        WHERE "view"."area_id" = "area"."id";
  2.1057 -      RETURN;
  2.1058 -    END;
  2.1059 -  $$;
  2.1060 -
  2.1061 -CREATE OR REPLACE FUNCTION "create_population_snapshot"
  2.1062 -  ( "issue_id_p" "issue"."id"%TYPE )
  2.1063 -  RETURNS VOID
  2.1064 -  LANGUAGE 'plpgsql' VOLATILE AS $$
  2.1065 -    DECLARE
  2.1066 -      "member_id_v" "member"."id"%TYPE;
  2.1067 -    BEGIN
  2.1068 -      DELETE FROM "direct_population_snapshot"
  2.1069 -        WHERE "issue_id" = "issue_id_p"
  2.1070 -        AND "event" = 'periodic';
  2.1071 -      DELETE FROM "delegating_population_snapshot"
  2.1072 -        WHERE "issue_id" = "issue_id_p"
  2.1073 -        AND "event" = 'periodic';
  2.1074 -      INSERT INTO "direct_population_snapshot"
  2.1075 -        ("issue_id", "event", "member_id")
  2.1076 -        SELECT
  2.1077 -          "issue_id_p"                 AS "issue_id",
  2.1078 -          'periodic'::"snapshot_event" AS "event",
  2.1079 -          "member"."id"                AS "member_id"
  2.1080 -        FROM "issue"
  2.1081 -        JOIN "area" ON "issue"."area_id" = "area"."id"
  2.1082 -        JOIN "membership" ON "area"."id" = "membership"."area_id"
  2.1083 -        JOIN "member" ON "membership"."member_id" = "member"."id"
  2.1084 -        JOIN "privilege"
  2.1085 -          ON "privilege"."unit_id" = "area"."unit_id"
  2.1086 -          AND "privilege"."member_id" = "member"."id"
  2.1087 -        WHERE "issue"."id" = "issue_id_p"
  2.1088 -        AND "member"."active" AND "privilege"."voting_right"
  2.1089 -        UNION
  2.1090 -        SELECT
  2.1091 -          "issue_id_p"                 AS "issue_id",
  2.1092 -          'periodic'::"snapshot_event" AS "event",
  2.1093 -          "member"."id"                AS "member_id"
  2.1094 -        FROM "issue"
  2.1095 -        JOIN "area" ON "issue"."area_id" = "area"."id"
  2.1096 -        JOIN "interest" ON "issue"."id" = "interest"."issue_id"
  2.1097 -        JOIN "member" ON "interest"."member_id" = "member"."id"
  2.1098 -        JOIN "privilege"
  2.1099 -          ON "privilege"."unit_id" = "area"."unit_id"
  2.1100 -          AND "privilege"."member_id" = "member"."id"
  2.1101 -        WHERE "issue"."id" = "issue_id_p"
  2.1102 -        AND "member"."active" AND "privilege"."voting_right";
  2.1103 -      FOR "member_id_v" IN
  2.1104 -        SELECT "member_id" FROM "direct_population_snapshot"
  2.1105 -        WHERE "issue_id" = "issue_id_p"
  2.1106 -        AND "event" = 'periodic'
  2.1107 -      LOOP
  2.1108 -        UPDATE "direct_population_snapshot" SET
  2.1109 -          "weight" = 1 +
  2.1110 -            "weight_of_added_delegations_for_population_snapshot"(
  2.1111 -              "issue_id_p",
  2.1112 -              "member_id_v",
  2.1113 -              '{}'
  2.1114 -            )
  2.1115 -          WHERE "issue_id" = "issue_id_p"
  2.1116 -          AND "event" = 'periodic'
  2.1117 -          AND "member_id" = "member_id_v";
  2.1118 -      END LOOP;
  2.1119 -      RETURN;
  2.1120 -    END;
  2.1121 -  $$;
  2.1122 -
  2.1123 -CREATE OR REPLACE FUNCTION "create_interest_snapshot"
  2.1124 -  ( "issue_id_p" "issue"."id"%TYPE )
  2.1125 -  RETURNS VOID
  2.1126 -  LANGUAGE 'plpgsql' VOLATILE AS $$
  2.1127 -    DECLARE
  2.1128 -      "member_id_v" "member"."id"%TYPE;
  2.1129 -    BEGIN
  2.1130 -      DELETE FROM "direct_interest_snapshot"
  2.1131 -        WHERE "issue_id" = "issue_id_p"
  2.1132 -        AND "event" = 'periodic';
  2.1133 -      DELETE FROM "delegating_interest_snapshot"
  2.1134 -        WHERE "issue_id" = "issue_id_p"
  2.1135 -        AND "event" = 'periodic';
  2.1136 -      DELETE FROM "direct_supporter_snapshot"
  2.1137 -        WHERE "issue_id" = "issue_id_p"
  2.1138 -        AND "event" = 'periodic';
  2.1139 -      INSERT INTO "direct_interest_snapshot"
  2.1140 -        ("issue_id", "event", "member_id", "voting_requested")
  2.1141 -        SELECT
  2.1142 -          "issue_id_p"  AS "issue_id",
  2.1143 -          'periodic'    AS "event",
  2.1144 -          "member"."id" AS "member_id",
  2.1145 -          "interest"."voting_requested"
  2.1146 -        FROM "issue"
  2.1147 -        JOIN "area" ON "issue"."area_id" = "area"."id"
  2.1148 -        JOIN "interest" ON "issue"."id" = "interest"."issue_id"
  2.1149 -        JOIN "member" ON "interest"."member_id" = "member"."id"
  2.1150 -        JOIN "privilege"
  2.1151 -          ON "privilege"."unit_id" = "area"."unit_id"
  2.1152 -          AND "privilege"."member_id" = "member"."id"
  2.1153 -        WHERE "issue"."id" = "issue_id_p"
  2.1154 -        AND "member"."active" AND "privilege"."voting_right";
  2.1155 -      FOR "member_id_v" IN
  2.1156 -        SELECT "member_id" FROM "direct_interest_snapshot"
  2.1157 -        WHERE "issue_id" = "issue_id_p"
  2.1158 -        AND "event" = 'periodic'
  2.1159 -      LOOP
  2.1160 -        UPDATE "direct_interest_snapshot" SET
  2.1161 -          "weight" = 1 +
  2.1162 -            "weight_of_added_delegations_for_interest_snapshot"(
  2.1163 -              "issue_id_p",
  2.1164 -              "member_id_v",
  2.1165 -              '{}'
  2.1166 -            )
  2.1167 -          WHERE "issue_id" = "issue_id_p"
  2.1168 -          AND "event" = 'periodic'
  2.1169 -          AND "member_id" = "member_id_v";
  2.1170 -      END LOOP;
  2.1171 -      INSERT INTO "direct_supporter_snapshot"
  2.1172 -        ( "issue_id", "initiative_id", "event", "member_id",
  2.1173 -          "informed", "satisfied" )
  2.1174 -        SELECT
  2.1175 -          "issue_id_p"            AS "issue_id",
  2.1176 -          "initiative"."id"       AS "initiative_id",
  2.1177 -          'periodic'              AS "event",
  2.1178 -          "supporter"."member_id" AS "member_id",
  2.1179 -          "supporter"."draft_id" = "current_draft"."id" AS "informed",
  2.1180 -          NOT EXISTS (
  2.1181 -            SELECT NULL FROM "critical_opinion"
  2.1182 -            WHERE "initiative_id" = "initiative"."id"
  2.1183 -            AND "member_id" = "supporter"."member_id"
  2.1184 -          ) AS "satisfied"
  2.1185 -        FROM "initiative"
  2.1186 -        JOIN "supporter"
  2.1187 -        ON "supporter"."initiative_id" = "initiative"."id"
  2.1188 -        JOIN "current_draft"
  2.1189 -        ON "initiative"."id" = "current_draft"."initiative_id"
  2.1190 -        JOIN "direct_interest_snapshot"
  2.1191 -        ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
  2.1192 -        AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
  2.1193 -        AND "event" = 'periodic'
  2.1194 -        WHERE "initiative"."issue_id" = "issue_id_p";
  2.1195 -      RETURN;
  2.1196 -    END;
  2.1197 -  $$;
  2.1198 -
  2.1199 -CREATE OR REPLACE FUNCTION "freeze_after_snapshot"
  2.1200 -  ( "issue_id_p" "issue"."id"%TYPE )
  2.1201 -  RETURNS VOID
  2.1202 -  LANGUAGE 'plpgsql' VOLATILE AS $$
  2.1203 -    DECLARE
  2.1204 -      "issue_row"      "issue"%ROWTYPE;
  2.1205 -      "policy_row"     "policy"%ROWTYPE;
  2.1206 -      "initiative_row" "initiative"%ROWTYPE;
  2.1207 -    BEGIN
  2.1208 -      SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  2.1209 -      SELECT * INTO "policy_row"
  2.1210 -        FROM "policy" WHERE "id" = "issue_row"."policy_id";
  2.1211 -      PERFORM "set_snapshot_event"("issue_id_p", 'full_freeze');
  2.1212 -      FOR "initiative_row" IN
  2.1213 -        SELECT * FROM "initiative"
  2.1214 -        WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
  2.1215 -      LOOP
  2.1216 -        IF
  2.1217 -          "initiative_row"."satisfied_supporter_count" > 0 AND
  2.1218 -          "initiative_row"."satisfied_supporter_count" *
  2.1219 -          "policy_row"."initiative_quorum_den" >=
  2.1220 -          "issue_row"."population" * "policy_row"."initiative_quorum_num"
  2.1221 -        THEN
  2.1222 -          UPDATE "initiative" SET "admitted" = TRUE
  2.1223 -            WHERE "id" = "initiative_row"."id";
  2.1224 -        ELSE
  2.1225 -          UPDATE "initiative" SET "admitted" = FALSE
  2.1226 -            WHERE "id" = "initiative_row"."id";
  2.1227 -        END IF;
  2.1228 -      END LOOP;
  2.1229 -      IF EXISTS (
  2.1230 -        SELECT NULL FROM "initiative"
  2.1231 -        WHERE "issue_id" = "issue_id_p" AND "admitted" = TRUE
  2.1232 -      ) THEN
  2.1233 -        UPDATE "issue" SET
  2.1234 -          "state"        = 'voting',
  2.1235 -          "accepted"     = coalesce("accepted", now()),
  2.1236 -          "half_frozen"  = coalesce("half_frozen", now()),
  2.1237 -          "fully_frozen" = now()
  2.1238 -          WHERE "id" = "issue_id_p";
  2.1239 -      ELSE
  2.1240 -        UPDATE "issue" SET
  2.1241 -          "state"           = 'canceled_no_initiative_admitted',
  2.1242 -          "accepted"        = coalesce("accepted", now()),
  2.1243 -          "half_frozen"     = coalesce("half_frozen", now()),
  2.1244 -          "fully_frozen"    = now(),
  2.1245 -          "closed"          = now(),
  2.1246 -          "ranks_available" = TRUE
  2.1247 -          WHERE "id" = "issue_id_p";
  2.1248 -        -- NOTE: The following DELETE statements have effect only when
  2.1249 -        --       issue state has been manipulated
  2.1250 -        DELETE FROM "direct_voter"     WHERE "issue_id" = "issue_id_p";
  2.1251 -        DELETE FROM "delegating_voter" WHERE "issue_id" = "issue_id_p";
  2.1252 -        DELETE FROM "battle"           WHERE "issue_id" = "issue_id_p";
  2.1253 -      END IF;
  2.1254 -      RETURN;
  2.1255 -    END;
  2.1256 -  $$;
  2.1257 -
  2.1258 -CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
  2.1259 -  RETURNS VOID
  2.1260 -  LANGUAGE 'plpgsql' VOLATILE AS $$
  2.1261 -    DECLARE
  2.1262 -      "area_id_v"   "area"."id"%TYPE;
  2.1263 -      "unit_id_v"   "unit"."id"%TYPE;
  2.1264 -      "member_id_v" "member"."id"%TYPE;
  2.1265 -    BEGIN
  2.1266 -      PERFORM "lock_issue"("issue_id_p");
  2.1267 -      SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
  2.1268 -      SELECT "unit_id" INTO "unit_id_v" FROM "area"  WHERE "id" = "area_id_v";
  2.1269 -      DELETE FROM "delegating_voter"
  2.1270 -        WHERE "issue_id" = "issue_id_p";
  2.1271 -      DELETE FROM "direct_voter"
  2.1272 -        WHERE "issue_id" = "issue_id_p"
  2.1273 -        AND "autoreject" = TRUE;
  2.1274 -      DELETE FROM "direct_voter"
  2.1275 -        USING (
  2.1276 -          SELECT
  2.1277 -            "direct_voter"."member_id"
  2.1278 -          FROM "direct_voter"
  2.1279 -          JOIN "member" ON "direct_voter"."member_id" = "member"."id"
  2.1280 -          LEFT JOIN "privilege"
  2.1281 -          ON "privilege"."unit_id" = "unit_id_v"
  2.1282 -          AND "privilege"."member_id" = "direct_voter"."member_id"
  2.1283 -          WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
  2.1284 -            "member"."active" = FALSE OR
  2.1285 -            "privilege"."voting_right" ISNULL OR
  2.1286 -            "privilege"."voting_right" = FALSE
  2.1287 -          )
  2.1288 -        ) AS "subquery"
  2.1289 -        WHERE "direct_voter"."issue_id" = "issue_id_p"
  2.1290 -        AND "direct_voter"."member_id" = "subquery"."member_id";
  2.1291 -      UPDATE "direct_voter" SET "weight" = 1
  2.1292 -        WHERE "issue_id" = "issue_id_p";
  2.1293 -      PERFORM "add_vote_delegations"("issue_id_p");
  2.1294 -      FOR "member_id_v" IN
  2.1295 -        SELECT "interest"."member_id"
  2.1296 -          FROM "interest"
  2.1297 -          JOIN "member"
  2.1298 -            ON "interest"."member_id" = "member"."id"
  2.1299 -          JOIN "privilege"
  2.1300 -            ON "privilege"."unit_id" = "unit_id_v"
  2.1301 -            AND "privilege"."member_id" = "member"."id"
  2.1302 -          LEFT JOIN "direct_voter"
  2.1303 -            ON "interest"."member_id" = "direct_voter"."member_id"
  2.1304 -            AND "interest"."issue_id" = "direct_voter"."issue_id"
  2.1305 -          LEFT JOIN "delegating_voter"
  2.1306 -            ON "interest"."member_id" = "delegating_voter"."member_id"
  2.1307 -            AND "interest"."issue_id" = "delegating_voter"."issue_id"
  2.1308 -          WHERE "interest"."issue_id" = "issue_id_p"
  2.1309 -          AND "interest"."autoreject" = TRUE
  2.1310 -          AND "member"."active"
  2.1311 -          AND "privilege"."voting_right"
  2.1312 -          AND "direct_voter"."member_id" ISNULL
  2.1313 -          AND "delegating_voter"."member_id" ISNULL
  2.1314 -        UNION SELECT "membership"."member_id"
  2.1315 -          FROM "membership"
  2.1316 -          JOIN "member"
  2.1317 -            ON "membership"."member_id" = "member"."id"
  2.1318 -          JOIN "privilege"
  2.1319 -            ON "privilege"."unit_id" = "unit_id_v"
  2.1320 -            AND "privilege"."member_id" = "member"."id"
  2.1321 -          LEFT JOIN "interest"
  2.1322 -            ON "membership"."member_id" = "interest"."member_id"
  2.1323 -            AND "interest"."issue_id" = "issue_id_p"
  2.1324 -          LEFT JOIN "direct_voter"
  2.1325 -            ON "membership"."member_id" = "direct_voter"."member_id"
  2.1326 -            AND "direct_voter"."issue_id" = "issue_id_p"
  2.1327 -          LEFT JOIN "delegating_voter"
  2.1328 -            ON "membership"."member_id" = "delegating_voter"."member_id"
  2.1329 -            AND "delegating_voter"."issue_id" = "issue_id_p"
  2.1330 -          WHERE "membership"."area_id" = "area_id_v"
  2.1331 -          AND "membership"."autoreject" = TRUE
  2.1332 -          AND "member"."active"
  2.1333 -          AND "privilege"."voting_right"
  2.1334 -          AND "interest"."autoreject" ISNULL
  2.1335 -          AND "direct_voter"."member_id" ISNULL
  2.1336 -          AND "delegating_voter"."member_id" ISNULL
  2.1337 -      LOOP
  2.1338 -        INSERT INTO "direct_voter"
  2.1339 -          ("member_id", "issue_id", "weight", "autoreject") VALUES
  2.1340 -          ("member_id_v", "issue_id_p", 1, TRUE);
  2.1341 -        INSERT INTO "vote" (
  2.1342 -          "member_id",
  2.1343 -          "issue_id",
  2.1344 -          "initiative_id",
  2.1345 -          "grade"
  2.1346 -          ) SELECT
  2.1347 -            "member_id_v" AS "member_id",
  2.1348 -            "issue_id_p"  AS "issue_id",
  2.1349 -            "id"          AS "initiative_id",
  2.1350 -            -1            AS "grade"
  2.1351 -          FROM "initiative"
  2.1352 -          WHERE "issue_id" = "issue_id_p" AND "admitted";
  2.1353 -      END LOOP;
  2.1354 -      PERFORM "add_vote_delegations"("issue_id_p");
  2.1355 -      UPDATE "issue" SET
  2.1356 -        "state"  = 'calculation',
  2.1357 -        "closed" = now(),
  2.1358 -        "voter_count" = (
  2.1359 -          SELECT coalesce(sum("weight"), 0)
  2.1360 -          FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
  2.1361 -        )
  2.1362 -        WHERE "id" = "issue_id_p";
  2.1363 -      UPDATE "initiative" SET
  2.1364 -        "positive_votes" = "vote_counts"."positive_votes",
  2.1365 -        "negative_votes" = "vote_counts"."negative_votes",
  2.1366 -        "agreed" = CASE WHEN "majority_strict" THEN
  2.1367 -          "vote_counts"."positive_votes" * "majority_den" >
  2.1368 -          "majority_num" *
  2.1369 -          ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
  2.1370 -        ELSE
  2.1371 -          "vote_counts"."positive_votes" * "majority_den" >=
  2.1372 -          "majority_num" *
  2.1373 -          ("vote_counts"."positive_votes"+"vote_counts"."negative_votes")
  2.1374 -        END
  2.1375 -        FROM
  2.1376 -          ( SELECT
  2.1377 -              "initiative"."id" AS "initiative_id",
  2.1378 -              coalesce(
  2.1379 -                sum(
  2.1380 -                  CASE WHEN "grade" > 0 THEN "direct_voter"."weight" ELSE 0 END
  2.1381 -                ),
  2.1382 -                0
  2.1383 -              ) AS "positive_votes",
  2.1384 -              coalesce(
  2.1385 -                sum(
  2.1386 -                  CASE WHEN "grade" < 0 THEN "direct_voter"."weight" ELSE 0 END
  2.1387 -                ),
  2.1388 -                0
  2.1389 -              ) AS "negative_votes"
  2.1390 -            FROM "initiative"
  2.1391 -            JOIN "issue" ON "initiative"."issue_id" = "issue"."id"
  2.1392 -            JOIN "policy" ON "issue"."policy_id" = "policy"."id"
  2.1393 -            LEFT JOIN "direct_voter"
  2.1394 -              ON "direct_voter"."issue_id" = "initiative"."issue_id"
  2.1395 -            LEFT JOIN "vote"
  2.1396 -              ON "vote"."initiative_id" = "initiative"."id"
  2.1397 -              AND "vote"."member_id" = "direct_voter"."member_id"
  2.1398 -            WHERE "initiative"."issue_id" = "issue_id_p"
  2.1399 -            AND "initiative"."admitted"  -- NOTE: NULL case is handled too
  2.1400 -            GROUP BY "initiative"."id"
  2.1401 -          ) AS "vote_counts",
  2.1402 -          "issue",
  2.1403 -          "policy"
  2.1404 -        WHERE "vote_counts"."initiative_id" = "initiative"."id"
  2.1405 -        AND "issue"."id" = "initiative"."issue_id"
  2.1406 -        AND "policy"."id" = "issue"."policy_id";
  2.1407 -      -- NOTE: "closed" column of issue must be set at this point
  2.1408 -      DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
  2.1409 -      INSERT INTO "battle" (
  2.1410 -        "issue_id",
  2.1411 -        "winning_initiative_id", "losing_initiative_id",
  2.1412 -        "count"
  2.1413 -      ) SELECT
  2.1414 -        "issue_id",
  2.1415 -        "winning_initiative_id", "losing_initiative_id",
  2.1416 -        "count"
  2.1417 -        FROM "battle_view" WHERE "issue_id" = "issue_id_p";
  2.1418 -    END;
  2.1419 -  $$;
  2.1420 -
  2.1421 -CREATE OR REPLACE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
  2.1422 -  RETURNS VOID
  2.1423 -  LANGUAGE 'plpgsql' VOLATILE AS $$
  2.1424 -    DECLARE
  2.1425 -      "dimension_v"     INTEGER;
  2.1426 -      "vote_matrix"     INT4[][];  -- absolute votes
  2.1427 -      "matrix"          INT8[][];  -- defeat strength / best paths
  2.1428 -      "i"               INTEGER;
  2.1429 -      "j"               INTEGER;
  2.1430 -      "k"               INTEGER;
  2.1431 -      "battle_row"      "battle"%ROWTYPE;
  2.1432 -      "rank_ary"        INT4[];
  2.1433 -      "rank_v"          INT4;
  2.1434 -      "done_v"          INTEGER;
  2.1435 -      "winners_ary"     INTEGER[];
  2.1436 -      "initiative_id_v" "initiative"."id"%TYPE;
  2.1437 -    BEGIN
  2.1438 -      PERFORM NULL FROM "issue" WHERE "id" = "issue_id_p" FOR UPDATE;
  2.1439 -      SELECT count(1) INTO "dimension_v" FROM "initiative"
  2.1440 -        WHERE "issue_id" = "issue_id_p" AND "agreed";
  2.1441 -      IF "dimension_v" = 1 THEN
  2.1442 -        UPDATE "initiative" SET "rank" = 1
  2.1443 -          WHERE "issue_id" = "issue_id_p" AND "agreed";
  2.1444 -      ELSIF "dimension_v" > 1 THEN
  2.1445 -        -- Create "vote_matrix" with absolute number of votes in pairwise
  2.1446 -        -- comparison:
  2.1447 -        "vote_matrix" := "square_matrix_init_string"("dimension_v");  -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
  2.1448 -        "i" := 1;
  2.1449 -        "j" := 2;
  2.1450 -        FOR "battle_row" IN
  2.1451 -          SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
  2.1452 -          ORDER BY "winning_initiative_id", "losing_initiative_id"
  2.1453 -        LOOP
  2.1454 -          "vote_matrix"["i"]["j"] := "battle_row"."count";
  2.1455 -          IF "j" = "dimension_v" THEN
  2.1456 -            "i" := "i" + 1;
  2.1457 -            "j" := 1;
  2.1458 -          ELSE
  2.1459 -            "j" := "j" + 1;
  2.1460 -            IF "j" = "i" THEN
  2.1461 -              "j" := "j" + 1;
  2.1462 -            END IF;
  2.1463 -          END IF;
  2.1464 -        END LOOP;
  2.1465 -        IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
  2.1466 -          RAISE EXCEPTION 'Wrong battle count (should not happen)';
  2.1467 -        END IF;
  2.1468 -        -- Store defeat strengths in "matrix" using "defeat_strength"
  2.1469 -        -- function:
  2.1470 -        "matrix" := "square_matrix_init_string"("dimension_v");  -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
  2.1471 -        "i" := 1;
  2.1472 -        LOOP
  2.1473 -          "j" := 1;
  2.1474 -          LOOP
  2.1475 -            IF "i" != "j" THEN
  2.1476 -              "matrix"["i"]["j"] := "defeat_strength"(
  2.1477 -                "vote_matrix"["i"]["j"],
  2.1478 -                "vote_matrix"["j"]["i"]
  2.1479 -              );
  2.1480 -            END IF;
  2.1481 -            EXIT WHEN "j" = "dimension_v";
  2.1482 -            "j" := "j" + 1;
  2.1483 -          END LOOP;
  2.1484 -          EXIT WHEN "i" = "dimension_v";
  2.1485 -          "i" := "i" + 1;
  2.1486 -        END LOOP;
  2.1487 -        -- Find best paths:
  2.1488 -        "i" := 1;
  2.1489 -        LOOP
  2.1490 -          "j" := 1;
  2.1491 -          LOOP
  2.1492 -            IF "i" != "j" THEN
  2.1493 -              "k" := 1;
  2.1494 -              LOOP
  2.1495 -                IF "i" != "k" AND "j" != "k" THEN
  2.1496 -                  IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
  2.1497 -                    IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
  2.1498 -                      "matrix"["j"]["k"] := "matrix"["j"]["i"];
  2.1499 -                    END IF;
  2.1500 -                  ELSE
  2.1501 -                    IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
  2.1502 -                      "matrix"["j"]["k"] := "matrix"["i"]["k"];
  2.1503 -                    END IF;
  2.1504 -                  END IF;
  2.1505 -                END IF;
  2.1506 -                EXIT WHEN "k" = "dimension_v";
  2.1507 -                "k" := "k" + 1;
  2.1508 -              END LOOP;
  2.1509 -            END IF;
  2.1510 -            EXIT WHEN "j" = "dimension_v";
  2.1511 -            "j" := "j" + 1;
  2.1512 -          END LOOP;
  2.1513 -          EXIT WHEN "i" = "dimension_v";
  2.1514 -          "i" := "i" + 1;
  2.1515 -        END LOOP;
  2.1516 -        -- Determine order of winners:
  2.1517 -        "rank_ary" := "array_init_string"("dimension_v");  -- TODO: replace by "array_fill" function (PostgreSQL 8.4)
  2.1518 -        "rank_v" := 1;
  2.1519 -        "done_v" := 0;
  2.1520 -        LOOP
  2.1521 -          "winners_ary" := '{}';
  2.1522 -          "i" := 1;
  2.1523 -          LOOP
  2.1524 -            IF "rank_ary"["i"] ISNULL THEN
  2.1525 -              "j" := 1;
  2.1526 -              LOOP
  2.1527 -                IF
  2.1528 -                  "i" != "j" AND
  2.1529 -                  "rank_ary"["j"] ISNULL AND
  2.1530 -                  "matrix"["j"]["i"] > "matrix"["i"]["j"]
  2.1531 -                THEN
  2.1532 -                  -- someone else is better
  2.1533 -                  EXIT;
  2.1534 -                END IF;
  2.1535 -                IF "j" = "dimension_v" THEN
  2.1536 -                  -- noone is better
  2.1537 -                  "winners_ary" := "winners_ary" || "i";
  2.1538 -                  EXIT;
  2.1539 -                END IF;
  2.1540 -                "j" := "j" + 1;
  2.1541 -              END LOOP;
  2.1542 -            END IF;
  2.1543 -            EXIT WHEN "i" = "dimension_v";
  2.1544 -            "i" := "i" + 1;
  2.1545 -          END LOOP;
  2.1546 -          "i" := 1;
  2.1547 -          LOOP
  2.1548 -            "rank_ary"["winners_ary"["i"]] := "rank_v";
  2.1549 -            "done_v" := "done_v" + 1;
  2.1550 -            EXIT WHEN "i" = array_upper("winners_ary", 1);
  2.1551 -            "i" := "i" + 1;
  2.1552 -          END LOOP;
  2.1553 -          EXIT WHEN "done_v" = "dimension_v";
  2.1554 -          "rank_v" := "rank_v" + 1;
  2.1555 -        END LOOP;
  2.1556 -        -- write preliminary ranks:
  2.1557 -        "i" := 1;
  2.1558 -        FOR "initiative_id_v" IN
  2.1559 -          SELECT "id" FROM "initiative"
  2.1560 -          WHERE "issue_id" = "issue_id_p" AND "agreed"
  2.1561 -          ORDER BY "id"
  2.1562 -        LOOP
  2.1563 -          UPDATE "initiative" SET "rank" = "rank_ary"["i"]
  2.1564 -            WHERE "id" = "initiative_id_v";
  2.1565 -          "i" := "i" + 1;
  2.1566 -        END LOOP;
  2.1567 -        IF "i" != "dimension_v" + 1 THEN
  2.1568 -          RAISE EXCEPTION 'Wrong winner count (should not happen)';
  2.1569 -        END IF;
  2.1570 -        -- straighten ranks (start counting with 1, no equal ranks):
  2.1571 -        "rank_v" := 1;
  2.1572 -        FOR "initiative_id_v" IN
  2.1573 -          SELECT "id" FROM "initiative"
  2.1574 -          WHERE "issue_id" = "issue_id_p" AND "rank" NOTNULL
  2.1575 -          ORDER BY
  2.1576 -            "rank",
  2.1577 -            "vote_ratio"("positive_votes", "negative_votes") DESC,
  2.1578 -            "id"
  2.1579 -        LOOP
  2.1580 -          UPDATE "initiative" SET "rank" = "rank_v"
  2.1581 -            WHERE "id" = "initiative_id_v";
  2.1582 -          "rank_v" := "rank_v" + 1;
  2.1583 -        END LOOP;
  2.1584 -      END IF;
  2.1585 -      -- mark issue as finished
  2.1586 -      UPDATE "issue" SET
  2.1587 -        "state" =
  2.1588 -          CASE WHEN "dimension_v" = 0 THEN
  2.1589 -            'finished_without_winner'::"issue_state"
  2.1590 -          ELSE
  2.1591 -            'finished_with_winner'::"issue_state"
  2.1592 -          END,
  2.1593 -        "ranks_available" = TRUE
  2.1594 -        WHERE "id" = "issue_id_p";
  2.1595 -      RETURN;
  2.1596 -    END;
  2.1597 -  $$;
  2.1598 -
  2.1599 -CREATE OR REPLACE FUNCTION "check_issue"
  2.1600 -  ( "issue_id_p" "issue"."id"%TYPE )
  2.1601 -  RETURNS VOID
  2.1602 -  LANGUAGE 'plpgsql' VOLATILE AS $$
  2.1603 -    DECLARE
  2.1604 -      "issue_row"         "issue"%ROWTYPE;
  2.1605 -      "policy_row"        "policy"%ROWTYPE;
  2.1606 -      "voting_requested_v" BOOLEAN;
  2.1607 -    BEGIN
  2.1608 -      PERFORM "lock_issue"("issue_id_p");
  2.1609 -      SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  2.1610 -      -- only process open issues:
  2.1611 -      IF "issue_row"."closed" ISNULL THEN
  2.1612 -        SELECT * INTO "policy_row" FROM "policy"
  2.1613 -          WHERE "id" = "issue_row"."policy_id";
  2.1614 -        -- create a snapshot, unless issue is already fully frozen:
  2.1615 -        IF "issue_row"."fully_frozen" ISNULL THEN
  2.1616 -          PERFORM "create_snapshot"("issue_id_p");
  2.1617 -          SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  2.1618 -        END IF;
  2.1619 -        -- eventually close or accept issues, which have not been accepted:
  2.1620 -        IF "issue_row"."accepted" ISNULL THEN
  2.1621 -          IF EXISTS (
  2.1622 -            SELECT NULL FROM "initiative"
  2.1623 -            WHERE "issue_id" = "issue_id_p"
  2.1624 -            AND "supporter_count" > 0
  2.1625 -            AND "supporter_count" * "policy_row"."issue_quorum_den"
  2.1626 -            >= "issue_row"."population" * "policy_row"."issue_quorum_num"
  2.1627 -          ) THEN
  2.1628 -            -- accept issues, if supporter count is high enough
  2.1629 -            PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
  2.1630 -            -- NOTE: "issue_row" used later
  2.1631 -            "issue_row"."state" := 'discussion';
  2.1632 -            "issue_row"."accepted" := now();
  2.1633 -            UPDATE "issue" SET
  2.1634 -              "state"    = "issue_row"."state",
  2.1635 -              "accepted" = "issue_row"."accepted"
  2.1636 -              WHERE "id" = "issue_row"."id";
  2.1637 -          ELSIF
  2.1638 -            now() >= "issue_row"."created" + "issue_row"."admission_time"
  2.1639 -          THEN
  2.1640 -            -- close issues, if admission time has expired
  2.1641 -            PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
  2.1642 -            UPDATE "issue" SET
  2.1643 -              "state" = 'canceled_issue_not_accepted',
  2.1644 -              "closed" = now()
  2.1645 -              WHERE "id" = "issue_row"."id";
  2.1646 -          END IF;
  2.1647 -        END IF;
  2.1648 -        -- eventually half freeze issues:
  2.1649 -        IF
  2.1650 -          -- NOTE: issue can't be closed at this point, if it has been accepted
  2.1651 -          "issue_row"."accepted" NOTNULL AND
  2.1652 -          "issue_row"."half_frozen" ISNULL
  2.1653 -        THEN
  2.1654 -          SELECT
  2.1655 -            CASE
  2.1656 -              WHEN "vote_now" * 2 > "issue_row"."population" THEN
  2.1657 -                TRUE
  2.1658 -              WHEN "vote_later" * 2 > "issue_row"."population" THEN
  2.1659 -                FALSE
  2.1660 -              ELSE NULL
  2.1661 -            END
  2.1662 -            INTO "voting_requested_v"
  2.1663 -            FROM "issue" WHERE "id" = "issue_id_p";
  2.1664 -          IF
  2.1665 -            "voting_requested_v" OR (
  2.1666 -              "voting_requested_v" ISNULL AND
  2.1667 -              now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
  2.1668 -            )
  2.1669 -          THEN
  2.1670 -            PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
  2.1671 -            -- NOTE: "issue_row" used later
  2.1672 -            "issue_row"."state" := 'verification';
  2.1673 -            "issue_row"."half_frozen" := now();
  2.1674 -            UPDATE "issue" SET
  2.1675 -              "state"       = "issue_row"."state",
  2.1676 -              "half_frozen" = "issue_row"."half_frozen"
  2.1677 -              WHERE "id" = "issue_row"."id";
  2.1678 -          END IF;
  2.1679 -        END IF;
  2.1680 -        -- close issues after some time, if all initiatives have been revoked:
  2.1681 -        IF
  2.1682 -          "issue_row"."closed" ISNULL AND
  2.1683 -          NOT EXISTS (
  2.1684 -            -- all initiatives are revoked
  2.1685 -            SELECT NULL FROM "initiative"
  2.1686 -            WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
  2.1687 -          ) AND (
  2.1688 -            -- and issue has not been accepted yet
  2.1689 -            "issue_row"."accepted" ISNULL OR
  2.1690 -            NOT EXISTS (
  2.1691 -              -- or no initiatives have been revoked lately
  2.1692 -              SELECT NULL FROM "initiative"
  2.1693 -              WHERE "issue_id" = "issue_id_p"
  2.1694 -              AND now() < "revoked" + "issue_row"."verification_time"
  2.1695 -            ) OR (
  2.1696 -              -- or verification time has elapsed
  2.1697 -              "issue_row"."half_frozen" NOTNULL AND
  2.1698 -              "issue_row"."fully_frozen" ISNULL AND
  2.1699 -              now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
  2.1700 -            )
  2.1701 -          )
  2.1702 -        THEN
  2.1703 -          -- NOTE: "issue_row" used later
  2.1704 -          IF "issue_row"."accepted" ISNULL THEN
  2.1705 -            "issue_row"."state" := 'canceled_revoked_before_accepted';
  2.1706 -          ELSIF "issue_row"."half_frozen" ISNULL THEN
  2.1707 -            "issue_row"."state" := 'canceled_after_revocation_during_discussion';
  2.1708 -          ELSE
  2.1709 -            "issue_row"."state" := 'canceled_after_revocation_during_verification';
  2.1710 -          END IF;
  2.1711 -          "issue_row"."closed" := now();
  2.1712 -          UPDATE "issue" SET
  2.1713 -            "state"  = "issue_row"."state",
  2.1714 -            "closed" = "issue_row"."closed"
  2.1715 -            WHERE "id" = "issue_row"."id";
  2.1716 -        END IF;
  2.1717 -        -- fully freeze issue after verification time:
  2.1718 -        IF
  2.1719 -          "issue_row"."half_frozen" NOTNULL AND
  2.1720 -          "issue_row"."fully_frozen" ISNULL AND
  2.1721 -          "issue_row"."closed" ISNULL AND
  2.1722 -          now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
  2.1723 -        THEN
  2.1724 -          PERFORM "freeze_after_snapshot"("issue_id_p");
  2.1725 -          -- NOTE: "issue" might change, thus "issue_row" has to be updated below
  2.1726 -        END IF;
  2.1727 -        SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  2.1728 -        -- close issue by calling close_voting(...) after voting time:
  2.1729 -        IF
  2.1730 -          "issue_row"."closed" ISNULL AND
  2.1731 -          "issue_row"."fully_frozen" NOTNULL AND
  2.1732 -          now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
  2.1733 -        THEN
  2.1734 -          PERFORM "close_voting"("issue_id_p");
  2.1735 -          -- calculate ranks will not consume much time and can be done now
  2.1736 -          PERFORM "calculate_ranks"("issue_id_p");
  2.1737 -        END IF;
  2.1738 -      END IF;
  2.1739 -      RETURN;
  2.1740 -    END;
  2.1741 -  $$;
  2.1742 -
  2.1743 -CREATE OR REPLACE FUNCTION "clean_issue"("issue_id_p" "issue"."id"%TYPE)
  2.1744 -  RETURNS VOID
  2.1745 -  LANGUAGE 'plpgsql' VOLATILE AS $$
  2.1746 -    DECLARE
  2.1747 -      "issue_row" "issue"%ROWTYPE;
  2.1748 -    BEGIN
  2.1749 -      SELECT * INTO "issue_row"
  2.1750 -        FROM "issue" WHERE "id" = "issue_id_p"
  2.1751 -        FOR UPDATE;
  2.1752 -      IF "issue_row"."cleaned" ISNULL THEN
  2.1753 -        UPDATE "issue" SET
  2.1754 -          "state"           = 'voting',
  2.1755 -          "closed"          = NULL,
  2.1756 -          "ranks_available" = FALSE
  2.1757 -          WHERE "id" = "issue_id_p";
  2.1758 -        DELETE FROM "issue_comment"
  2.1759 -          WHERE "issue_id" = "issue_id_p";
  2.1760 -        DELETE FROM "voting_comment"
  2.1761 -          WHERE "issue_id" = "issue_id_p";
  2.1762 -        DELETE FROM "delegating_voter"
  2.1763 -          WHERE "issue_id" = "issue_id_p";
  2.1764 -        DELETE FROM "direct_voter"
  2.1765 -          WHERE "issue_id" = "issue_id_p";
  2.1766 -        DELETE FROM "delegating_interest_snapshot"
  2.1767 -          WHERE "issue_id" = "issue_id_p";
  2.1768 -        DELETE FROM "direct_interest_snapshot"
  2.1769 -          WHERE "issue_id" = "issue_id_p";
  2.1770 -        DELETE FROM "delegating_population_snapshot"
  2.1771 -          WHERE "issue_id" = "issue_id_p";
  2.1772 -        DELETE FROM "direct_population_snapshot"
  2.1773 -          WHERE "issue_id" = "issue_id_p";
  2.1774 -        DELETE FROM "non_voter"
  2.1775 -          WHERE "issue_id" = "issue_id_p";
  2.1776 -        DELETE FROM "delegation"
  2.1777 -          WHERE "issue_id" = "issue_id_p";
  2.1778 -        DELETE FROM "supporter"
  2.1779 -          WHERE "issue_id" = "issue_id_p";
  2.1780 -        UPDATE "issue" SET
  2.1781 -          "state"           = "issue_row"."state",
  2.1782 -          "closed"          = "issue_row"."closed",
  2.1783 -          "ranks_available" = "issue_row"."ranks_available",
  2.1784 -          "cleaned"         = now()
  2.1785 -          WHERE "id" = "issue_id_p";
  2.1786 -      END IF;
  2.1787 -      RETURN;
  2.1788 -    END;
  2.1789 -  $$;
  2.1790 -
  2.1791 -CREATE OR REPLACE FUNCTION "check_issue"
  2.1792 -  ( "issue_id_p" "issue"."id"%TYPE )
  2.1793 -  RETURNS VOID
  2.1794 -  LANGUAGE 'plpgsql' VOLATILE AS $$
  2.1795 -    DECLARE
  2.1796 -      "issue_row"         "issue"%ROWTYPE;
  2.1797 -      "policy_row"        "policy"%ROWTYPE;
  2.1798 -      "voting_requested_v" BOOLEAN;
  2.1799 -    BEGIN
  2.1800 -      PERFORM "lock_issue"("issue_id_p");
  2.1801 -      SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  2.1802 -      -- only process open issues:
  2.1803 -      IF "issue_row"."closed" ISNULL THEN
  2.1804 -        SELECT * INTO "policy_row" FROM "policy"
  2.1805 -          WHERE "id" = "issue_row"."policy_id";
  2.1806 -        -- create a snapshot, unless issue is already fully frozen:
  2.1807 -        IF "issue_row"."fully_frozen" ISNULL THEN
  2.1808 -          PERFORM "create_snapshot"("issue_id_p");
  2.1809 -          SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  2.1810 -        END IF;
  2.1811 -        -- eventually close or accept issues, which have not been accepted:
  2.1812 -        IF "issue_row"."accepted" ISNULL THEN
  2.1813 -          IF EXISTS (
  2.1814 -            SELECT NULL FROM "initiative"
  2.1815 -            WHERE "issue_id" = "issue_id_p"
  2.1816 -            AND "supporter_count" > 0
  2.1817 -            AND "supporter_count" * "policy_row"."issue_quorum_den"
  2.1818 -            >= "issue_row"."population" * "policy_row"."issue_quorum_num"
  2.1819 -          ) THEN
  2.1820 -            -- accept issues, if supporter count is high enough
  2.1821 -            PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
  2.1822 -            -- NOTE: "issue_row" used later
  2.1823 -            "issue_row"."state" := 'discussion';
  2.1824 -            "issue_row"."accepted" := now();
  2.1825 -            UPDATE "issue" SET
  2.1826 -              "state"    = "issue_row"."state",
  2.1827 -              "accepted" = "issue_row"."accepted"
  2.1828 -              WHERE "id" = "issue_row"."id";
  2.1829 -          ELSIF
  2.1830 -            now() >= "issue_row"."created" + "issue_row"."admission_time"
  2.1831 -          THEN
  2.1832 -            -- close issues, if admission time has expired
  2.1833 -            PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
  2.1834 -            UPDATE "issue" SET
  2.1835 -              "state" = 'canceled_issue_not_accepted',
  2.1836 -              "closed" = now()
  2.1837 -              WHERE "id" = "issue_row"."id";
  2.1838 -          END IF;
  2.1839 -        END IF;
  2.1840 -        -- eventually half freeze issues:
  2.1841 -        IF
  2.1842 -          -- NOTE: issue can't be closed at this point, if it has been accepted
  2.1843 -          "issue_row"."accepted" NOTNULL AND
  2.1844 -          "issue_row"."half_frozen" ISNULL
  2.1845 -        THEN
  2.1846 -          SELECT
  2.1847 -            CASE
  2.1848 -              WHEN "vote_now" * 2 > "issue_row"."population" THEN
  2.1849 -                TRUE
  2.1850 -              WHEN "vote_later" * 2 > "issue_row"."population" THEN
  2.1851 -                FALSE
  2.1852 -              ELSE NULL
  2.1853 -            END
  2.1854 -            INTO "voting_requested_v"
  2.1855 -            FROM "issue" WHERE "id" = "issue_id_p";
  2.1856 -          IF
  2.1857 -            "voting_requested_v" OR (
  2.1858 -              "voting_requested_v" ISNULL AND
  2.1859 -              now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
  2.1860 -            )
  2.1861 -          THEN
  2.1862 -            PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
  2.1863 -            -- NOTE: "issue_row" used later
  2.1864 -            "issue_row"."state" := 'verification';
  2.1865 -            "issue_row"."half_frozen" := now();
  2.1866 -            UPDATE "issue" SET
  2.1867 -              "state"       = "issue_row"."state",
  2.1868 -              "half_frozen" = "issue_row"."half_frozen"
  2.1869 -              WHERE "id" = "issue_row"."id";
  2.1870 -          END IF;
  2.1871 -        END IF;
  2.1872 -        -- close issues after some time, if all initiatives have been revoked:
  2.1873 -        IF
  2.1874 -          "issue_row"."closed" ISNULL AND
  2.1875 -          NOT EXISTS (
  2.1876 -            -- all initiatives are revoked
  2.1877 -            SELECT NULL FROM "initiative"
  2.1878 -            WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
  2.1879 -          ) AND (
  2.1880 -            -- and issue has not been accepted yet
  2.1881 -            "issue_row"."accepted" ISNULL OR
  2.1882 -            NOT EXISTS (
  2.1883 -              -- or no initiatives have been revoked lately
  2.1884 -              SELECT NULL FROM "initiative"
  2.1885 -              WHERE "issue_id" = "issue_id_p"
  2.1886 -              AND now() < "revoked" + "issue_row"."verification_time"
  2.1887 -            ) OR (
  2.1888 -              -- or verification time has elapsed
  2.1889 -              "issue_row"."half_frozen" NOTNULL AND
  2.1890 -              "issue_row"."fully_frozen" ISNULL AND
  2.1891 -              now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
  2.1892 -            )
  2.1893 -          )
  2.1894 -        THEN
  2.1895 -          -- NOTE: "issue_row" used later
  2.1896 -          IF "issue_row"."accepted" ISNULL THEN
  2.1897 -            "issue_row"."state" := 'canceled_revoked_before_accepted';
  2.1898 -          ELSIF "issue_row"."half_frozen" ISNULL THEN
  2.1899 -            "issue_row"."state" := 'canceled_after_revocation_during_discussion';
  2.1900 -          ELSE
  2.1901 -            "issue_row"."state" := 'canceled_after_revocation_during_verification';
  2.1902 -          END IF;
  2.1903 -          "issue_row"."closed" := now();
  2.1904 -          UPDATE "issue" SET
  2.1905 -            "state"  = "issue_row"."state",
  2.1906 -            "closed" = "issue_row"."closed"
  2.1907 -            WHERE "id" = "issue_row"."id";
  2.1908 -        END IF;
  2.1909 -        -- fully freeze issue after verification time:
  2.1910 -        IF
  2.1911 -          "issue_row"."half_frozen" NOTNULL AND
  2.1912 -          "issue_row"."fully_frozen" ISNULL AND
  2.1913 -          "issue_row"."closed" ISNULL AND
  2.1914 -          now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
  2.1915 -        THEN
  2.1916 -          PERFORM "freeze_after_snapshot"("issue_id_p");
  2.1917 -          -- NOTE: "issue" might change, thus "issue_row" has to be updated below
  2.1918 -        END IF;
  2.1919 -        SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  2.1920 -        -- close issue by calling close_voting(...) after voting time:
  2.1921 -        IF
  2.1922 -          "issue_row"."closed" ISNULL AND
  2.1923 -          "issue_row"."fully_frozen" NOTNULL AND
  2.1924 -          now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
  2.1925 -        THEN
  2.1926 -          PERFORM "close_voting"("issue_id_p");
  2.1927 -          -- calculate ranks will not consume much time and can be done now
  2.1928 -          PERFORM "calculate_ranks"("issue_id_p");
  2.1929 -        END IF;
  2.1930 -      END IF;
  2.1931 -      RETURN;
  2.1932 -    END;
  2.1933 -  $$;
  2.1934 -
  2.1935 -CREATE OR REPLACE FUNCTION "delete_private_data"()
  2.1936 -  RETURNS VOID
  2.1937 -  LANGUAGE 'plpgsql' VOLATILE AS $$
  2.1938 -    BEGIN
  2.1939 -      UPDATE "member" SET
  2.1940 -        "last_login"                   = NULL,
  2.1941 -        "login"                        = NULL,
  2.1942 -        "password"                     = NULL,
  2.1943 -        "notify_email"                 = NULL,
  2.1944 -        "notify_email_unconfirmed"     = NULL,
  2.1945 -        "notify_email_secret"          = NULL,
  2.1946 -        "notify_email_secret_expiry"   = NULL,
  2.1947 -        "notify_email_lock_expiry"     = NULL,
  2.1948 -        "password_reset_secret"        = NULL,
  2.1949 -        "password_reset_secret_expiry" = NULL,
  2.1950 -        "organizational_unit"          = NULL,
  2.1951 -        "internal_posts"               = NULL,
  2.1952 -        "realname"                     = NULL,
  2.1953 -        "birthday"                     = NULL,
  2.1954 -        "address"                      = NULL,
  2.1955 -        "email"                        = NULL,
  2.1956 -        "xmpp_address"                 = NULL,
  2.1957 -        "website"                      = NULL,
  2.1958 -        "phone"                        = NULL,
  2.1959 -        "mobile_phone"                 = NULL,
  2.1960 -        "profession"                   = NULL,
  2.1961 -        "external_memberships"         = NULL,
  2.1962 -        "external_posts"               = NULL,
  2.1963 -        "statement"                    = NULL;
  2.1964 -      -- "text_search_data" is updated by triggers
  2.1965 -      DELETE FROM "invite_code";
  2.1966 -      DELETE FROM "setting";
  2.1967 -      DELETE FROM "setting_map";
  2.1968 -      DELETE FROM "member_relation_setting";
  2.1969 -      DELETE FROM "member_image";
  2.1970 -      DELETE FROM "contact";
  2.1971 -      DELETE FROM "ignored_member";
  2.1972 -      DELETE FROM "session";
  2.1973 -      DELETE FROM "area_setting";
  2.1974 -      DELETE FROM "issue_setting";
  2.1975 -      DELETE FROM "ignored_initiative";
  2.1976 -      DELETE FROM "initiative_setting";
  2.1977 -      DELETE FROM "suggestion_setting";
  2.1978 -      DELETE FROM "non_voter";
  2.1979 -      DELETE FROM "direct_voter" USING "issue"
  2.1980 -        WHERE "direct_voter"."issue_id" = "issue"."id"
  2.1981 -        AND "issue"."closed" ISNULL;
  2.1982 -      RETURN;
  2.1983 -    END;
  2.1984 -  $$;
  2.1985 -
  2.1986 -
  2.1987 --- Delete old "delegation_scope" TYPE:
  2.1988 -
  2.1989 -DROP TYPE "delegation_scope_old";
  2.1990 -
  2.1991 -
  2.1992 -COMMIT;
  2.1993 -
  2.1994 -
  2.1995 --- Generate issue states and add constraints:
  2.1996 -
  2.1997 -UPDATE "issue" SET "state" =
  2.1998 -  CASE
  2.1999 -  WHEN "closed" ISNULL THEN
  2.2000 -    CASE
  2.2001 -    WHEN "accepted" ISNULL THEN
  2.2002 -      'admission'::"issue_state"
  2.2003 -    WHEN "half_frozen" ISNULL THEN
  2.2004 -      'discussion'::"issue_state"
  2.2005 -    WHEN "fully_frozen" ISNULL THEN
  2.2006 -      'verification'::"issue_state"
  2.2007 -    ELSE
  2.2008 -      'voting'::"issue_state"
  2.2009 -    END
  2.2010 -  WHEN "fully_frozen" NOTNULL THEN
  2.2011 -    CASE
  2.2012 -    WHEN "fully_frozen" = "closed" THEN
  2.2013 -      'canceled_no_initiative_admitted'::"issue_state"
  2.2014 -    ELSE
  2.2015 -      'finished_without_winner'::"issue_state"  -- NOTE: corrected later
  2.2016 -    END
  2.2017 -  WHEN "half_frozen" NOTNULL THEN
  2.2018 -    'canceled_after_revocation_during_verification'::"issue_state"
  2.2019 -  WHEN "accepted" NOTNULL THEN
  2.2020 -    'canceled_after_revocation_during_discussion'::"issue_state"
  2.2021 -  ELSE
  2.2022 -    'canceled_revoked_before_accepted'::"issue_state"  -- NOTE: corrected later
  2.2023 -  END;
  2.2024 -UPDATE "issue" SET "state" = 'finished_with_winner'
  2.2025 -  FROM "initiative"
  2.2026 -  WHERE "issue"."id" = "initiative"."issue_id"
  2.2027 -  AND "issue"."state" = 'finished_without_winner'
  2.2028 -  AND "initiative"."agreed";
  2.2029 -UPDATE "issue" SET "state" = 'canceled_issue_not_accepted'
  2.2030 -  FROM "initiative"
  2.2031 -  WHERE "issue"."id" = "initiative"."issue_id"
  2.2032 -  AND "issue"."state" = 'canceled_revoked_before_accepted'
  2.2033 -  AND "initiative"."revoked" ISNULL;
  2.2034 -
  2.2035 -ALTER TABLE "issue" ALTER "state" SET NOT NULL;
  2.2036 -
  2.2037 -ALTER TABLE "issue" DROP CONSTRAINT "valid_state";
  2.2038 -ALTER TABLE "issue" ADD CONSTRAINT "valid_state" CHECK ((
  2.2039 -    ("accepted" ISNULL  AND "half_frozen" ISNULL  AND "fully_frozen" ISNULL  AND "closed" ISNULL  AND "ranks_available" = FALSE) OR
  2.2040 -    ("accepted" ISNULL  AND "half_frozen" ISNULL  AND "fully_frozen" ISNULL  AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
  2.2041 -    ("accepted" NOTNULL AND "half_frozen" ISNULL  AND "fully_frozen" ISNULL  AND "closed" ISNULL  AND "ranks_available" = FALSE) OR
  2.2042 -    ("accepted" NOTNULL AND "half_frozen" ISNULL  AND "fully_frozen" ISNULL  AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
  2.2043 -    ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL  AND "closed" ISNULL  AND "ranks_available" = FALSE) OR
  2.2044 -    ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL  AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
  2.2045 -    ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" ISNULL  AND "ranks_available" = FALSE) OR
  2.2046 -    ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = FALSE) OR
  2.2047 -    ("accepted" NOTNULL AND "half_frozen" NOTNULL AND "fully_frozen" NOTNULL AND "closed" NOTNULL AND "ranks_available" = TRUE)
  2.2048 -  ) AND (
  2.2049 -    ("state" = 'admission'    AND "closed" ISNULL AND "accepted" ISNULL) OR
  2.2050 -    ("state" = 'discussion'   AND "closed" ISNULL AND "accepted" NOTNULL AND "half_frozen" ISNULL) OR
  2.2051 -    ("state" = 'verification' AND "closed" ISNULL AND "half_frozen" NOTNULL AND "fully_frozen" ISNULL) OR
  2.2052 -    ("state" = 'voting'       AND "closed" ISNULL AND "fully_frozen" NOTNULL) OR
  2.2053 -    ("state" = 'canceled_revoked_before_accepted'              AND "closed" NOTNULL AND "accepted" ISNULL) OR
  2.2054 -    ("state" = 'canceled_issue_not_accepted'                   AND "closed" NOTNULL AND "accepted" ISNULL) OR
  2.2055 -    ("state" = 'canceled_after_revocation_during_discussion'   AND "closed" NOTNULL AND "half_frozen"  ISNULL) OR
  2.2056 -    ("state" = 'canceled_after_revocation_during_verification' AND "closed" NOTNULL AND "fully_frozen" ISNULL) OR
  2.2057 -    ("state" = 'calculation'                     AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = FALSE) OR
  2.2058 -    ("state" = 'canceled_no_initiative_admitted' AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
  2.2059 -    ("state" = 'finished_without_winner'         AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE) OR
  2.2060 -    ("state" = 'finished_with_winner'            AND "closed" NOTNULL AND "fully_frozen" NOTNULL AND "ranks_available" = TRUE)
  2.2061 -  ));
  2.2062 -
  2.2063 -
  2.2064 --- Guess "revoked_by_member_id" values based on author of current draft and add constraint:
  2.2065 -
  2.2066 -UPDATE "initiative" SET "revoked_by_member_id" = "author_id"
  2.2067 -  FROM "current_draft"
  2.2068 -  WHERE "initiative"."id" = "current_draft"."initiative_id"
  2.2069 -  AND "initiative"."revoked" NOTNULL;
  2.2070 -
  2.2071 -ALTER TABLE "initiative" ADD
  2.2072 -  CONSTRAINT "all_or_none_of_revoked_and_revoked_by_member_id_must_be_null"
  2.2073 -  CHECK ("revoked" NOTNULL = "revoked_by_member_id" NOTNULL);
  2.2074 -
  2.2075 -
  2.2076 --- Fill "unit_id" column with default value where neccessary and add constraints:
  2.2077 -
  2.2078 -UPDATE "delegation" SET "unit_id" = 1 WHERE "scope" = 'unit';
  2.2079 -
  2.2080 -ALTER TABLE "delegation" ADD CONSTRAINT "area_id_and_issue_id_set_according_to_scope"
  2.2081 -  CHECK (
  2.2082 -    ("scope" = 'unit'  AND "unit_id" NOTNULL AND "area_id" ISNULL  AND "issue_id" ISNULL ) OR
  2.2083 -    ("scope" = 'area'  AND "unit_id" ISNULL  AND "area_id" NOTNULL AND "issue_id" ISNULL ) OR
  2.2084 -    ("scope" = 'issue' AND "unit_id" ISNULL  AND "area_id" ISNULL  AND "issue_id" NOTNULL) );
  2.2085 -
  2.2086 -
  2.2087 --- Filling of "event" table with old (reconstructed) events:
  2.2088 -
  2.2089 -DELETE FROM "event";
  2.2090 -SELECT setval('event_id_seq', 1, false);
  2.2091 -
  2.2092 -INSERT INTO "event"
  2.2093 -  ( "occurrence", "event", "member_id", "issue_id", "state",
  2.2094 -    "initiative_id", "draft_id", "suggestion_id" )
  2.2095 -  SELECT * FROM (
  2.2096 -    SELECT * FROM (
  2.2097 -      SELECT DISTINCT ON ("initiative"."id")
  2.2098 -        "timeline"."occurrence",
  2.2099 -        CASE WHEN "issue_creation"."issue_id" NOTNULL THEN
  2.2100 -          'initiative_created_in_new_issue'::"event_type"
  2.2101 -        ELSE
  2.2102 -          'initiative_created_in_existing_issue'::"event_type"
  2.2103 -        END,
  2.2104 -        "draft"."author_id",
  2.2105 -        "issue"."id",
  2.2106 -        CASE
  2.2107 -          WHEN "timeline"."occurrence" < "issue"."accepted" THEN
  2.2108 -            'admission'::"issue_state"
  2.2109 -          WHEN "timeline"."occurrence" < "issue"."half_frozen" THEN
  2.2110 -            'discussion'::"issue_state"
  2.2111 -          ELSE
  2.2112 -            'verification'::"issue_state"
  2.2113 -        END,
  2.2114 -        "initiative"."id",
  2.2115 -        "draft"."id",
  2.2116 -        NULL::INT8
  2.2117 -      FROM "timeline"
  2.2118 -      JOIN "initiative" ON "timeline"."initiative_id" = "initiative"."id"
  2.2119 -      JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
  2.2120 -      LEFT JOIN "timeline" AS "issue_creation"
  2.2121 -        ON "initiative"."issue_id" = "issue_creation"."issue_id"
  2.2122 -        AND "issue_creation"."event" = 'issue_created'
  2.2123 -        AND "timeline"."occurrence" = "issue_creation"."occurrence"
  2.2124 -      JOIN "draft"
  2.2125 -        ON "initiative"."id" = "draft"."initiative_id"
  2.2126 -      WHERE "timeline"."event" = 'initiative_created'
  2.2127 -      ORDER BY "initiative"."id", "draft"."id"
  2.2128 -    ) AS "subquery"  -- NOTE: subquery needed due to DISTINCT/ORDER
  2.2129 -  UNION ALL
  2.2130 -    SELECT
  2.2131 -      "timeline"."occurrence",
  2.2132 -      'issue_state_changed'::"event_type",
  2.2133 -      NULL,
  2.2134 -      "issue"."id",
  2.2135 -      CASE
  2.2136 -        WHEN "timeline"."event" IN (
  2.2137 -          'issue_canceled',
  2.2138 -          'issue_finished_without_voting',
  2.2139 -          'issue_finished_after_voting'
  2.2140 -        ) THEN
  2.2141 -          "issue"."state"
  2.2142 -        WHEN "timeline"."event" = 'issue_accepted' THEN
  2.2143 -          'discussion'::"issue_state"
  2.2144 -        WHEN "timeline"."event" = 'issue_half_frozen' THEN
  2.2145 -          'verification'::"issue_state"
  2.2146 -        WHEN "timeline"."event" = 'issue_voting_started' THEN
  2.2147 -          'voting'::"issue_state"
  2.2148 -      END,
  2.2149 -      NULL,
  2.2150 -      NULL,
  2.2151 -      NULL
  2.2152 -    FROM "timeline"
  2.2153 -    JOIN "issue" ON "timeline"."issue_id" = "issue"."id"
  2.2154 -    WHERE "timeline"."event" IN (
  2.2155 -      'issue_canceled',
  2.2156 -      'issue_accepted',
  2.2157 -      'issue_half_frozen',
  2.2158 -      'issue_finished_without_voting',
  2.2159 -      'issue_voting_started',
  2.2160 -      'issue_finished_after_voting' )
  2.2161 -  UNION ALL
  2.2162 -    SELECT
  2.2163 -      "timeline"."occurrence",
  2.2164 -      'initiative_revoked'::"event_type",
  2.2165 -      "initiative"."revoked_by_member_id",
  2.2166 -      "issue"."id",
  2.2167 -      CASE
  2.2168 -        WHEN "timeline"."occurrence" < "issue"."accepted" THEN
  2.2169 -          'admission'::"issue_state"
  2.2170 -        WHEN "timeline"."occurrence" < "issue"."half_frozen" THEN
  2.2171 -          'discussion'::"issue_state"
  2.2172 -        ELSE
  2.2173 -          'verification'::"issue_state"
  2.2174 -      END,
  2.2175 -      "initiative"."id",
  2.2176 -      "current_draft"."id",
  2.2177 -      NULL
  2.2178 -    FROM "timeline"
  2.2179 -    JOIN "initiative" ON "timeline"."initiative_id" = "initiative"."id"
  2.2180 -    JOIN "issue" ON "issue"."id" = "initiative"."issue_id"
  2.2181 -    JOIN "current_draft" ON "initiative"."id" = "current_draft"."initiative_id"
  2.2182 -    WHERE "timeline"."event" = 'initiative_revoked'
  2.2183 -  UNION ALL
  2.2184 -    SELECT
  2.2185 -      "timeline"."occurrence",
  2.2186 -      'new_draft_created'::"event_type",
  2.2187 -      "draft"."author_id",
  2.2188 -      "issue"."id",
  2.2189 -      CASE
  2.2190 -        WHEN "timeline"."occurrence" < "issue"."accepted" THEN
  2.2191 -          'admission'::"issue_state"
  2.2192 -        WHEN "timeline"."occurrence" < "issue"."half_frozen" THEN
  2.2193 -          'discussion'::"issue_state"
  2.2194 -        ELSE
  2.2195 -          'verification'::"issue_state"
  2.2196 -      END,
  2.2197 -      "initiative"."id",
  2.2198 -      "draft"."id",
  2.2199 -      NULL
  2.2200 -    FROM "timeline"
  2.2201 -    JOIN "draft" ON "timeline"."draft_id" = "draft"."id"
  2.2202 -    JOIN "initiative" ON "draft"."initiative_id" = "initiative"."id"
  2.2203 -    JOIN "issue" ON "initiative"."issue_id" = "issue"."id"
  2.2204 -    LEFT JOIN "timeline" AS "initiative_creation"
  2.2205 -      ON "initiative"."id" = "initiative_creation"."initiative_id"
  2.2206 -      AND "initiative_creation"."event" = 'initiative_created'
  2.2207 -      AND "timeline"."occurrence" = "initiative_creation"."occurrence"
  2.2208 -    WHERE "timeline"."event" = 'draft_created'
  2.2209 -    AND "initiative_creation"."initiative_id" ISNULL
  2.2210 -  UNION ALL
  2.2211 -    SELECT
  2.2212 -      "timeline"."occurrence",
  2.2213 -      'suggestion_created'::"event_type",
  2.2214 -      "suggestion"."author_id",
  2.2215 -      "issue"."id",
  2.2216 -      CASE
  2.2217 -        WHEN "timeline"."occurrence" < "issue"."accepted" THEN
  2.2218 -          'admission'::"issue_state"
  2.2219 -        WHEN "timeline"."occurrence" < "issue"."half_frozen" THEN
  2.2220 -          'discussion'::"issue_state"
  2.2221 -        ELSE
  2.2222 -          'verification'::"issue_state"
  2.2223 -      END,
  2.2224 -      "initiative"."id",
  2.2225 -      NULL,
  2.2226 -      "suggestion"."id"
  2.2227 -    FROM "timeline"
  2.2228 -    JOIN "suggestion" ON "timeline"."suggestion_id" = "suggestion"."id"
  2.2229 -    JOIN "initiative" ON "suggestion"."initiative_id" = "initiative"."id"
  2.2230 -    JOIN "issue" ON "initiative"."issue_id" = "issue"."id"
  2.2231 -    WHERE "timeline"."event" = 'suggestion_created'
  2.2232 -  ) AS "subquery"
  2.2233 -  ORDER BY "occurrence";
  2.2234 -
  2.2235 -
     3.1 --- /dev/null	Thu Jan 01 00:00:00 1970 +0000
     3.2 +++ b/update/core-update.v1.4.0-v2.0.0.sql	Sat Sep 10 22:42:51 2011 +0200
     3.3 @@ -0,0 +1,1330 @@
     3.4 +SELECT "calculate_ranks"("id") FROM "issue_with_ranks_missing";
     3.5 +
     3.6 +BEGIN;
     3.7 +
     3.8 +CREATE OR REPLACE VIEW "liquid_feedback_version" AS
     3.9 +  SELECT * FROM (VALUES ('2.0.0', 2, 0, 0))
    3.10 +  AS "subquery"("string", "major", "minor", "revision");
    3.11 +
    3.12 +ALTER TABLE "member" ADD COLUMN "invite_code" TEXT UNIQUE;
    3.13 +ALTER TABLE "member" ADD COLUMN "admin_comment" TEXT;
    3.14 +ALTER TABLE "member" ADD COLUMN "activated" TIMESTAMPTZ;
    3.15 +ALTER TABLE "member" ADD COLUMN "last_activity" DATE;
    3.16 +ALTER TABLE "member" DROP COLUMN "last_login_public";
    3.17 +ALTER TABLE "member" ALTER COLUMN "active" SET DEFAULT FALSE;
    3.18 +ALTER TABLE "member" ADD COLUMN "formatting_engine" TEXT;
    3.19 +
    3.20 +COMMENT ON COLUMN "member"."created"           IS 'Creation of member record and/or invite code';
    3.21 +COMMENT ON COLUMN "member"."invite_code"       IS 'Optional invite code, to allow a member to initialize his/her account the first time';
    3.22 +COMMENT ON COLUMN "member"."admin_comment"     IS 'Hidden comment for administrative purposes';
    3.23 +COMMENT ON COLUMN "member"."activated"         IS 'Timestamp of activation of account (i.e. usage of "invite_code"); required to be set for "active" members';
    3.24 +COMMENT ON COLUMN "member"."last_activity"     IS 'Date of last activity of member; required to be set for "active" members';
    3.25 +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".';
    3.26 +COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
    3.27 +
    3.28 +CREATE TYPE "application_access_level" AS ENUM
    3.29 +  ('member', 'full', 'pseudonymous', 'anonymous');
    3.30 +
    3.31 +COMMENT ON TYPE "application_access_level" IS 'Access privileges for applications using the API';
    3.32 +
    3.33 +CREATE TABLE "member_application" (
    3.34 +        "id"                    SERIAL8         PRIMARY KEY,
    3.35 +        UNIQUE ("member_id", "name"),
    3.36 +        "member_id"             INT4            NOT NULL REFERENCES "member" ("id")
    3.37 +                                                ON DELETE CASCADE ON UPDATE CASCADE,
    3.38 +        "name"                  TEXT            NOT NULL,
    3.39 +        "comment"               TEXT,
    3.40 +        "access_level" "application_access_level" NOT NULL,
    3.41 +        "key"                   TEXT            NOT NULL UNIQUE,
    3.42 +        "last_usage"            TIMESTAMPTZ );
    3.43 +
    3.44 +COMMENT ON TABLE "member_application" IS 'Registered application being allowed to use the API';
    3.45 +
    3.46 +CREATE TABLE "rendered_member_statement" (
    3.47 +        PRIMARY KEY ("member_id", "format"),
    3.48 +        "member_id"             INT8            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
    3.49 +        "format"                TEXT,
    3.50 +        "content"               TEXT            NOT NULL );
    3.51 +
    3.52 +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)';
    3.53 +
    3.54 +DROP VIEW "expired_session";
    3.55 +DROP TABLE "session";
    3.56 +
    3.57 +ALTER TABLE "policy" ADD COLUMN "direct_majority_num"            INT4    NOT NULL DEFAULT 1;
    3.58 +ALTER TABLE "policy" ADD COLUMN "direct_majority_den"            INT4    NOT NULL DEFAULT 2;
    3.59 +ALTER TABLE "policy" ADD COLUMN "direct_majority_strict"         BOOLEAN NOT NULL DEFAULT TRUE;
    3.60 +ALTER TABLE "policy" ADD COLUMN "direct_majority_positive"       INT4    NOT NULL DEFAULT 0;
    3.61 +ALTER TABLE "policy" ADD COLUMN "direct_majority_non_negative"   INT4    NOT NULL DEFAULT 0;
    3.62 +ALTER TABLE "policy" ADD COLUMN "indirect_majority_num"          INT4    NOT NULL DEFAULT 1;
    3.63 +ALTER TABLE "policy" ADD COLUMN "indirect_majority_den"          INT4    NOT NULL DEFAULT 2;
    3.64 +ALTER TABLE "policy" ADD COLUMN "indirect_majority_strict"       BOOLEAN NOT NULL DEFAULT TRUE;
    3.65 +ALTER TABLE "policy" ADD COLUMN "indirect_majority_positive"     INT4    NOT NULL DEFAULT 0;
    3.66 +ALTER TABLE "policy" ADD COLUMN "indirect_majority_non_negative" INT4    NOT NULL DEFAULT 0;
    3.67 +ALTER TABLE "policy" ADD COLUMN "no_reverse_beat_path"           BOOLEAN NOT NULL DEFAULT TRUE;
    3.68 +ALTER TABLE "policy" ADD COLUMN "no_multistage_majority"         BOOLEAN NOT NULL DEFAULT FALSE;
    3.69 +
    3.70 +UPDATE "policy" SET
    3.71 +  "direct_majority_num"      = "majority_num",
    3.72 +  "direct_majority_den"      = "majority_den",
    3.73 +  "direct_majority_strict"   = "majority_strict",
    3.74 +  "indirect_majority_num"    = "majority_num",
    3.75 +  "indirect_majority_den"    = "majority_den",
    3.76 +  "indirect_majority_strict" = "majority_strict";
    3.77 +
    3.78 +ALTER TABLE "policy" DROP COLUMN "majority_num";
    3.79 +ALTER TABLE "policy" DROP COLUMN "majority_den";
    3.80 +ALTER TABLE "policy" DROP COLUMN "majority_strict";
    3.81 +
    3.82 +COMMENT ON COLUMN "policy"."direct_majority_num"            IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
    3.83 +COMMENT ON COLUMN "policy"."direct_majority_den"            IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
    3.84 +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.';
    3.85 +COMMENT ON COLUMN "policy"."direct_majority_positive"       IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
    3.86 +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';
    3.87 +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';
    3.88 +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';
    3.89 +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.';
    3.90 +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';
    3.91 +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';
    3.92 +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.';
    3.93 +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").';
    3.94 +
    3.95 +ALTER TABLE "area" DROP COLUMN "autoreject_weight";
    3.96 +
    3.97 +DROP VIEW "open_issue";
    3.98 +DROP VIEW "issue_with_ranks_missing";
    3.99 +
   3.100 +ALTER TABLE "issue" DROP COLUMN "vote_now";
   3.101 +ALTER TABLE "issue" DROP COLUMN "vote_later";
   3.102 +ALTER TABLE "issue" ADD COLUMN "status_quo_schulze_rank" INT4;
   3.103 +
   3.104 +CREATE VIEW "open_issue" AS
   3.105 +  SELECT * FROM "issue" WHERE "closed" ISNULL;
   3.106 +
   3.107 +COMMENT ON VIEW "open_issue" IS 'All open issues';
   3.108 +
   3.109 +CREATE VIEW "issue_with_ranks_missing" AS
   3.110 +  SELECT * FROM "issue"
   3.111 +  WHERE "fully_frozen" NOTNULL
   3.112 +  AND "closed" NOTNULL
   3.113 +  AND "ranks_available" = FALSE;
   3.114 +
   3.115 +COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
   3.116 +
   3.117 +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.';
   3.118 +COMMENT ON COLUMN "issue"."snapshot"                IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
   3.119 +COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
   3.120 +
   3.121 +DROP VIEW "battle_view";
   3.122 +
   3.123 +ALTER TABLE "initiative" DROP CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results";
   3.124 +ALTER TABLE "initiative" DROP CONSTRAINT "all_or_none_of_positive_votes_negative_votes_and_agreed_must_be_null";
   3.125 +ALTER TABLE "initiative" DROP CONSTRAINT "non_agreed_initiatives_cant_get_a_rank";
   3.126 +
   3.127 +ALTER TABLE "initiative" DROP COLUMN "agreed";
   3.128 +ALTER TABLE "initiative" ADD COLUMN "direct_majority"        BOOLEAN;
   3.129 +ALTER TABLE "initiative" ADD COLUMN "indirect_majority"      BOOLEAN;
   3.130 +ALTER TABLE "initiative" ADD COLUMN "schulze_rank"           INT4;
   3.131 +ALTER TABLE "initiative" ADD COLUMN "better_than_status_quo" BOOLEAN;
   3.132 +ALTER TABLE "initiative" ADD COLUMN "worse_than_status_quo"  BOOLEAN;
   3.133 +ALTER TABLE "initiative" ADD COLUMN "reverse_beat_path"      BOOLEAN;
   3.134 +ALTER TABLE "initiative" ADD COLUMN "multistage_majority"    BOOLEAN;
   3.135 +ALTER TABLE "initiative" ADD COLUMN "eligible"               BOOLEAN;
   3.136 +ALTER TABLE "initiative" ADD COLUMN "winner"                 BOOLEAN;
   3.137 +
   3.138 +ALTER TABLE "initiative" ADD CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
   3.139 +  ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
   3.140 +  ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
   3.141 +    "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
   3.142 +    "schulze_rank" ISNULL AND
   3.143 +    "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
   3.144 +    "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
   3.145 +    "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) );
   3.146 +ALTER TABLE "initiative" ADD CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo"));
   3.147 +ALTER TABLE "initiative" ADD CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
   3.148 +  "eligible" = FALSE OR
   3.149 +("direct_majority" AND "indirect_majority" AND "better_than_status_quo") );
   3.150 +ALTER TABLE "initiative" ADD CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE);
   3.151 +ALTER TABLE "initiative" ADD CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1);
   3.152 +ALTER TABLE "initiative" ADD CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE);
   3.153 +ALTER TABLE "initiative" ADD CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank");
   3.154 +
   3.155 +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"';
   3.156 +COMMENT ON COLUMN "initiative"."indirect_majority"       IS 'Same as "direct_majority", but also considering indirect beat paths';
   3.157 +COMMENT ON COLUMN "initiative"."schulze_rank"            IS 'Schulze-Ranking without tie-breaking';
   3.158 +COMMENT ON COLUMN "initiative"."better_than_status_quo"  IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
   3.159 +COMMENT ON COLUMN "initiative"."worse_than_status_quo"   IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
   3.160 +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';
   3.161 +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';
   3.162 +COMMENT ON COLUMN "initiative"."eligible"                IS 'Initiative is "attainable" and depending on selected policy has no "reverse_beat_path" or "multistage_majority"';
   3.163 +COMMENT ON COLUMN "initiative"."winner"                  IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
   3.164 +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';
   3.165 +
   3.166 +ALTER TABLE "battle" DROP CONSTRAINT "battle_pkey";
   3.167 +ALTER TABLE "battle" ALTER COLUMN "issue_id" SET NOT NULL;
   3.168 +ALTER TABLE "battle" ADD CONSTRAINT "initiative_ids_not_equal" CHECK (
   3.169 +  "winning_initiative_id" != "losing_initiative_id" OR
   3.170 +  ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
   3.171 +    ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) );
   3.172 +
   3.173 +CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
   3.174 +CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
   3.175 +CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
   3.176 +
   3.177 +ALTER TABLE "suggestion" ADD COLUMN "draft_id" INT8;
   3.178 +ALTER TABLE "suggestion" ADD FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE;
   3.179 +ALTER TABLE "suggestion" ADD COLUMN "formatting_engine" TEXT;
   3.180 +ALTER TABLE "suggestion" RENAME COLUMN "description" TO "content";
   3.181 +
   3.182 +DROP TRIGGER "update_text_search_data" ON "suggestion";
   3.183 +
   3.184 +CREATE TRIGGER "update_text_search_data"
   3.185 +  BEFORE INSERT OR UPDATE ON "suggestion"
   3.186 +  FOR EACH ROW EXECUTE PROCEDURE
   3.187 +  tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
   3.188 +    "name", "content");
   3.189 +
   3.190 +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")';
   3.191 +
   3.192 +CREATE TABLE "rendered_suggestion" (
   3.193 +        PRIMARY KEY ("suggestion_id", "format"),
   3.194 +        "suggestion_id"         INT8            REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   3.195 +        "format"                TEXT,
   3.196 +        "content"               TEXT            NOT NULL );
   3.197 +
   3.198 +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)';
   3.199 +
   3.200 +DROP TABLE "invite_code_unit";
   3.201 +
   3.202 +DROP VIEW "area_member_count";
   3.203 +
   3.204 +ALTER TABLE "membership" DROP COLUMN "autoreject";
   3.205 +
   3.206 +ALTER TABLE "interest" DROP COLUMN "autoreject";
   3.207 +ALTER TABLE "interest" DROP COLUMN "voting_requested";
   3.208 +
   3.209 +ALTER TABLE "supporter" DROP CONSTRAINT "supporter_initiative_id_fkey";
   3.210 +ALTER TABLE "supporter" ADD FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE;
   3.211 +
   3.212 +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")';
   3.213 +
   3.214 +ALTER TABLE "direct_interest_snapshot" DROP COLUMN "voting_requested";
   3.215 +ALTER TABLE "direct_voter" DROP COLUMN "autoreject";
   3.216 +
   3.217 +DROP TRIGGER "default_for_draft_id" ON "supporter";
   3.218 +DROP FUNCTION "supporter_default_for_draft_id_trigger"();
   3.219 +
   3.220 +CREATE FUNCTION "default_for_draft_id_trigger"()
   3.221 +  RETURNS TRIGGER
   3.222 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   3.223 +    BEGIN
   3.224 +      IF NEW."draft_id" ISNULL THEN
   3.225 +        SELECT "id" INTO NEW."draft_id" FROM "current_draft"
   3.226 +          WHERE "initiative_id" = NEW."initiative_id";
   3.227 +      END IF;
   3.228 +      RETURN NEW;
   3.229 +    END;
   3.230 +  $$;
   3.231 +
   3.232 +CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
   3.233 +  FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
   3.234 +CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
   3.235 +  FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
   3.236 +
   3.237 +COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
   3.238 +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';
   3.239 +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';
   3.240 +
   3.241 +CREATE VIEW "area_member_count" AS
   3.242 +  SELECT
   3.243 +    "area"."id" AS "area_id",
   3.244 +    count("member"."id") AS "direct_member_count",
   3.245 +    coalesce(
   3.246 +      sum(
   3.247 +        CASE WHEN "member"."id" NOTNULL THEN
   3.248 +          "membership_weight"("area"."id", "member"."id")
   3.249 +        ELSE 0 END
   3.250 +      )
   3.251 +    ) AS "member_weight"
   3.252 +  FROM "area"
   3.253 +  LEFT JOIN "membership"
   3.254 +  ON "area"."id" = "membership"."area_id"
   3.255 +  LEFT JOIN "privilege"
   3.256 +  ON "privilege"."unit_id" = "area"."unit_id"
   3.257 +  AND "privilege"."member_id" = "membership"."member_id"
   3.258 +  AND "privilege"."voting_right"
   3.259 +  LEFT JOIN "member"
   3.260 +  ON "member"."id" = "privilege"."member_id"  -- NOTE: no membership here!
   3.261 +  AND "member"."active"
   3.262 +  GROUP BY "area"."id";
   3.263 +
   3.264 +COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
   3.265 +
   3.266 +CREATE VIEW "battle_participant" AS
   3.267 +    SELECT "initiative"."id", "initiative"."issue_id"
   3.268 +    FROM "issue" JOIN "initiative"
   3.269 +    ON "issue"."id" = "initiative"."issue_id"
   3.270 +    WHERE "initiative"."admitted"
   3.271 +  UNION ALL
   3.272 +    SELECT NULL, "id" AS "issue_id"
   3.273 +    FROM "issue";
   3.274 +
   3.275 +COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
   3.276 +
   3.277 +CREATE VIEW "battle_view" AS
   3.278 +  SELECT
   3.279 +    "issue"."id" AS "issue_id",
   3.280 +    "winning_initiative"."id" AS "winning_initiative_id",
   3.281 +    "losing_initiative"."id" AS "losing_initiative_id",
   3.282 +    sum(
   3.283 +      CASE WHEN
   3.284 +        coalesce("better_vote"."grade", 0) >
   3.285 +        coalesce("worse_vote"."grade", 0)
   3.286 +      THEN "direct_voter"."weight" ELSE 0 END
   3.287 +    ) AS "count"
   3.288 +  FROM "issue"
   3.289 +  LEFT JOIN "direct_voter"
   3.290 +  ON "issue"."id" = "direct_voter"."issue_id"
   3.291 +  JOIN "battle_participant" AS "winning_initiative"
   3.292 +    ON "issue"."id" = "winning_initiative"."issue_id"
   3.293 +  JOIN "battle_participant" AS "losing_initiative"
   3.294 +    ON "issue"."id" = "losing_initiative"."issue_id"
   3.295 +  LEFT JOIN "vote" AS "better_vote"
   3.296 +    ON "direct_voter"."member_id" = "better_vote"."member_id"
   3.297 +    AND "winning_initiative"."id" = "better_vote"."initiative_id"
   3.298 +  LEFT JOIN "vote" AS "worse_vote"
   3.299 +    ON "direct_voter"."member_id" = "worse_vote"."member_id"
   3.300 +    AND "losing_initiative"."id" = "worse_vote"."initiative_id"
   3.301 +  WHERE "issue"."closed" NOTNULL
   3.302 +  AND "issue"."cleaned" ISNULL
   3.303 +  AND (
   3.304 +    "winning_initiative"."id" != "losing_initiative"."id" OR
   3.305 +    ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
   3.306 +      ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
   3.307 +  GROUP BY
   3.308 +    "issue"."id",
   3.309 +    "winning_initiative"."id",
   3.310 +    "losing_initiative"."id";
   3.311 +
   3.312 +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';
   3.313 +
   3.314 +DROP FUNCTION "check_last_login"();
   3.315 +
   3.316 +CREATE FUNCTION "check_activity"()
   3.317 +  RETURNS VOID
   3.318 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   3.319 +    DECLARE
   3.320 +      "system_setting_row" "system_setting"%ROWTYPE;
   3.321 +    BEGIN
   3.322 +      SELECT * INTO "system_setting_row" FROM "system_setting";
   3.323 +      LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
   3.324 +      IF "system_setting_row"."member_ttl" NOTNULL THEN
   3.325 +        UPDATE "member" SET "active" = FALSE
   3.326 +          WHERE "active" = TRUE
   3.327 +          AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
   3.328 +      END IF;
   3.329 +      RETURN;
   3.330 +    END;
   3.331 +  $$;
   3.332 +
   3.333 +COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
   3.334 +
   3.335 +CREATE OR REPLACE FUNCTION "calculate_member_counts"()
   3.336 +  RETURNS VOID
   3.337 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   3.338 +    BEGIN
   3.339 +      LOCK TABLE "member"       IN SHARE MODE;
   3.340 +      LOCK TABLE "member_count" IN EXCLUSIVE MODE;
   3.341 +      LOCK TABLE "unit"         IN EXCLUSIVE MODE;
   3.342 +      LOCK TABLE "area"         IN EXCLUSIVE MODE;
   3.343 +      LOCK TABLE "privilege"    IN SHARE MODE;
   3.344 +      LOCK TABLE "membership"   IN SHARE MODE;
   3.345 +      DELETE FROM "member_count";
   3.346 +      INSERT INTO "member_count" ("total_count")
   3.347 +        SELECT "total_count" FROM "member_count_view";
   3.348 +      UPDATE "unit" SET "member_count" = "view"."member_count"
   3.349 +        FROM "unit_member_count" AS "view"
   3.350 +        WHERE "view"."unit_id" = "unit"."id";
   3.351 +      UPDATE "area" SET
   3.352 +        "direct_member_count" = "view"."direct_member_count",
   3.353 +        "member_weight"       = "view"."member_weight"
   3.354 +        FROM "area_member_count" AS "view"
   3.355 +        WHERE "view"."area_id" = "area"."id";
   3.356 +      RETURN;
   3.357 +    END;
   3.358 +  $$;
   3.359 +
   3.360 +CREATE OR REPLACE FUNCTION "create_interest_snapshot"
   3.361 +  ( "issue_id_p" "issue"."id"%TYPE )
   3.362 +  RETURNS VOID
   3.363 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   3.364 +    DECLARE
   3.365 +      "member_id_v" "member"."id"%TYPE;
   3.366 +    BEGIN
   3.367 +      DELETE FROM "direct_interest_snapshot"
   3.368 +        WHERE "issue_id" = "issue_id_p"
   3.369 +        AND "event" = 'periodic';
   3.370 +      DELETE FROM "delegating_interest_snapshot"
   3.371 +        WHERE "issue_id" = "issue_id_p"
   3.372 +        AND "event" = 'periodic';
   3.373 +      DELETE FROM "direct_supporter_snapshot"
   3.374 +        WHERE "issue_id" = "issue_id_p"
   3.375 +        AND "event" = 'periodic';
   3.376 +      INSERT INTO "direct_interest_snapshot"
   3.377 +        ("issue_id", "event", "member_id")
   3.378 +        SELECT
   3.379 +          "issue_id_p"  AS "issue_id",
   3.380 +          'periodic'    AS "event",
   3.381 +          "member"."id" AS "member_id"
   3.382 +        FROM "issue"
   3.383 +        JOIN "area" ON "issue"."area_id" = "area"."id"
   3.384 +        JOIN "interest" ON "issue"."id" = "interest"."issue_id"
   3.385 +        JOIN "member" ON "interest"."member_id" = "member"."id"
   3.386 +        JOIN "privilege"
   3.387 +          ON "privilege"."unit_id" = "area"."unit_id"
   3.388 +          AND "privilege"."member_id" = "member"."id"
   3.389 +        WHERE "issue"."id" = "issue_id_p"
   3.390 +        AND "member"."active" AND "privilege"."voting_right";
   3.391 +      FOR "member_id_v" IN
   3.392 +        SELECT "member_id" FROM "direct_interest_snapshot"
   3.393 +        WHERE "issue_id" = "issue_id_p"
   3.394 +        AND "event" = 'periodic'
   3.395 +      LOOP
   3.396 +        UPDATE "direct_interest_snapshot" SET
   3.397 +          "weight" = 1 +
   3.398 +            "weight_of_added_delegations_for_interest_snapshot"(
   3.399 +              "issue_id_p",
   3.400 +              "member_id_v",
   3.401 +              '{}'
   3.402 +            )
   3.403 +          WHERE "issue_id" = "issue_id_p"
   3.404 +          AND "event" = 'periodic'
   3.405 +          AND "member_id" = "member_id_v";
   3.406 +      END LOOP;
   3.407 +      INSERT INTO "direct_supporter_snapshot"
   3.408 +        ( "issue_id", "initiative_id", "event", "member_id",
   3.409 +          "informed", "satisfied" )
   3.410 +        SELECT
   3.411 +          "issue_id_p"            AS "issue_id",
   3.412 +          "initiative"."id"       AS "initiative_id",
   3.413 +          'periodic'              AS "event",
   3.414 +          "supporter"."member_id" AS "member_id",
   3.415 +          "supporter"."draft_id" = "current_draft"."id" AS "informed",
   3.416 +          NOT EXISTS (
   3.417 +            SELECT NULL FROM "critical_opinion"
   3.418 +            WHERE "initiative_id" = "initiative"."id"
   3.419 +            AND "member_id" = "supporter"."member_id"
   3.420 +          ) AS "satisfied"
   3.421 +        FROM "initiative"
   3.422 +        JOIN "supporter"
   3.423 +        ON "supporter"."initiative_id" = "initiative"."id"
   3.424 +        JOIN "current_draft"
   3.425 +        ON "initiative"."id" = "current_draft"."initiative_id"
   3.426 +        JOIN "direct_interest_snapshot"
   3.427 +        ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
   3.428 +        AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
   3.429 +        AND "event" = 'periodic'
   3.430 +        WHERE "initiative"."issue_id" = "issue_id_p";
   3.431 +      RETURN;
   3.432 +    END;
   3.433 +  $$;
   3.434 +
   3.435 +CREATE OR REPLACE FUNCTION "create_snapshot"
   3.436 +  ( "issue_id_p" "issue"."id"%TYPE )
   3.437 +  RETURNS VOID
   3.438 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   3.439 +    DECLARE
   3.440 +      "initiative_id_v"    "initiative"."id"%TYPE;
   3.441 +      "suggestion_id_v"    "suggestion"."id"%TYPE;
   3.442 +    BEGIN
   3.443 +      PERFORM "lock_issue"("issue_id_p");
   3.444 +      PERFORM "create_population_snapshot"("issue_id_p");
   3.445 +      PERFORM "create_interest_snapshot"("issue_id_p");
   3.446 +      UPDATE "issue" SET
   3.447 +        "snapshot" = now(),
   3.448 +        "latest_snapshot_event" = 'periodic',
   3.449 +        "population" = (
   3.450 +          SELECT coalesce(sum("weight"), 0)
   3.451 +          FROM "direct_population_snapshot"
   3.452 +          WHERE "issue_id" = "issue_id_p"
   3.453 +          AND "event" = 'periodic'
   3.454 +        )
   3.455 +        WHERE "id" = "issue_id_p";
   3.456 +      FOR "initiative_id_v" IN
   3.457 +        SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
   3.458 +      LOOP
   3.459 +        UPDATE "initiative" SET
   3.460 +          "supporter_count" = (
   3.461 +            SELECT coalesce(sum("di"."weight"), 0)
   3.462 +            FROM "direct_interest_snapshot" AS "di"
   3.463 +            JOIN "direct_supporter_snapshot" AS "ds"
   3.464 +            ON "di"."member_id" = "ds"."member_id"
   3.465 +            WHERE "di"."issue_id" = "issue_id_p"
   3.466 +            AND "di"."event" = 'periodic'
   3.467 +            AND "ds"."initiative_id" = "initiative_id_v"
   3.468 +            AND "ds"."event" = 'periodic'
   3.469 +          ),
   3.470 +          "informed_supporter_count" = (
   3.471 +            SELECT coalesce(sum("di"."weight"), 0)
   3.472 +            FROM "direct_interest_snapshot" AS "di"
   3.473 +            JOIN "direct_supporter_snapshot" AS "ds"
   3.474 +            ON "di"."member_id" = "ds"."member_id"
   3.475 +            WHERE "di"."issue_id" = "issue_id_p"
   3.476 +            AND "di"."event" = 'periodic'
   3.477 +            AND "ds"."initiative_id" = "initiative_id_v"
   3.478 +            AND "ds"."event" = 'periodic'
   3.479 +            AND "ds"."informed"
   3.480 +          ),
   3.481 +          "satisfied_supporter_count" = (
   3.482 +            SELECT coalesce(sum("di"."weight"), 0)
   3.483 +            FROM "direct_interest_snapshot" AS "di"
   3.484 +            JOIN "direct_supporter_snapshot" AS "ds"
   3.485 +            ON "di"."member_id" = "ds"."member_id"
   3.486 +            WHERE "di"."issue_id" = "issue_id_p"
   3.487 +            AND "di"."event" = 'periodic'
   3.488 +            AND "ds"."initiative_id" = "initiative_id_v"
   3.489 +            AND "ds"."event" = 'periodic'
   3.490 +            AND "ds"."satisfied"
   3.491 +          ),
   3.492 +          "satisfied_informed_supporter_count" = (
   3.493 +            SELECT coalesce(sum("di"."weight"), 0)
   3.494 +            FROM "direct_interest_snapshot" AS "di"
   3.495 +            JOIN "direct_supporter_snapshot" AS "ds"
   3.496 +            ON "di"."member_id" = "ds"."member_id"
   3.497 +            WHERE "di"."issue_id" = "issue_id_p"
   3.498 +            AND "di"."event" = 'periodic'
   3.499 +            AND "ds"."initiative_id" = "initiative_id_v"
   3.500 +            AND "ds"."event" = 'periodic'
   3.501 +            AND "ds"."informed"
   3.502 +            AND "ds"."satisfied"
   3.503 +          )
   3.504 +          WHERE "id" = "initiative_id_v";
   3.505 +        FOR "suggestion_id_v" IN
   3.506 +          SELECT "id" FROM "suggestion"
   3.507 +          WHERE "initiative_id" = "initiative_id_v"
   3.508 +        LOOP
   3.509 +          UPDATE "suggestion" SET
   3.510 +            "minus2_unfulfilled_count" = (
   3.511 +              SELECT coalesce(sum("snapshot"."weight"), 0)
   3.512 +              FROM "issue" CROSS JOIN "opinion"
   3.513 +              JOIN "direct_interest_snapshot" AS "snapshot"
   3.514 +              ON "snapshot"."issue_id" = "issue"."id"
   3.515 +              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   3.516 +              AND "snapshot"."member_id" = "opinion"."member_id"
   3.517 +              WHERE "issue"."id" = "issue_id_p"
   3.518 +              AND "opinion"."suggestion_id" = "suggestion_id_v"
   3.519 +              AND "opinion"."degree" = -2
   3.520 +              AND "opinion"."fulfilled" = FALSE
   3.521 +            ),
   3.522 +            "minus2_fulfilled_count" = (
   3.523 +              SELECT coalesce(sum("snapshot"."weight"), 0)
   3.524 +              FROM "issue" CROSS JOIN "opinion"
   3.525 +              JOIN "direct_interest_snapshot" AS "snapshot"
   3.526 +              ON "snapshot"."issue_id" = "issue"."id"
   3.527 +              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   3.528 +              AND "snapshot"."member_id" = "opinion"."member_id"
   3.529 +              WHERE "issue"."id" = "issue_id_p"
   3.530 +              AND "opinion"."suggestion_id" = "suggestion_id_v"
   3.531 +              AND "opinion"."degree" = -2
   3.532 +              AND "opinion"."fulfilled" = TRUE
   3.533 +            ),
   3.534 +            "minus1_unfulfilled_count" = (
   3.535 +              SELECT coalesce(sum("snapshot"."weight"), 0)
   3.536 +              FROM "issue" CROSS JOIN "opinion"
   3.537 +              JOIN "direct_interest_snapshot" AS "snapshot"
   3.538 +              ON "snapshot"."issue_id" = "issue"."id"
   3.539 +              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   3.540 +              AND "snapshot"."member_id" = "opinion"."member_id"
   3.541 +              WHERE "issue"."id" = "issue_id_p"
   3.542 +              AND "opinion"."suggestion_id" = "suggestion_id_v"
   3.543 +              AND "opinion"."degree" = -1
   3.544 +              AND "opinion"."fulfilled" = FALSE
   3.545 +            ),
   3.546 +            "minus1_fulfilled_count" = (
   3.547 +              SELECT coalesce(sum("snapshot"."weight"), 0)
   3.548 +              FROM "issue" CROSS JOIN "opinion"
   3.549 +              JOIN "direct_interest_snapshot" AS "snapshot"
   3.550 +              ON "snapshot"."issue_id" = "issue"."id"
   3.551 +              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   3.552 +              AND "snapshot"."member_id" = "opinion"."member_id"
   3.553 +              WHERE "issue"."id" = "issue_id_p"
   3.554 +              AND "opinion"."suggestion_id" = "suggestion_id_v"
   3.555 +              AND "opinion"."degree" = -1
   3.556 +              AND "opinion"."fulfilled" = TRUE
   3.557 +            ),
   3.558 +            "plus1_unfulfilled_count" = (
   3.559 +              SELECT coalesce(sum("snapshot"."weight"), 0)
   3.560 +              FROM "issue" CROSS JOIN "opinion"
   3.561 +              JOIN "direct_interest_snapshot" AS "snapshot"
   3.562 +              ON "snapshot"."issue_id" = "issue"."id"
   3.563 +              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   3.564 +              AND "snapshot"."member_id" = "opinion"."member_id"
   3.565 +              WHERE "issue"."id" = "issue_id_p"
   3.566 +              AND "opinion"."suggestion_id" = "suggestion_id_v"
   3.567 +              AND "opinion"."degree" = 1
   3.568 +              AND "opinion"."fulfilled" = FALSE
   3.569 +            ),
   3.570 +            "plus1_fulfilled_count" = (
   3.571 +              SELECT coalesce(sum("snapshot"."weight"), 0)
   3.572 +              FROM "issue" CROSS JOIN "opinion"
   3.573 +              JOIN "direct_interest_snapshot" AS "snapshot"
   3.574 +              ON "snapshot"."issue_id" = "issue"."id"
   3.575 +              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   3.576 +              AND "snapshot"."member_id" = "opinion"."member_id"
   3.577 +              WHERE "issue"."id" = "issue_id_p"
   3.578 +              AND "opinion"."suggestion_id" = "suggestion_id_v"
   3.579 +              AND "opinion"."degree" = 1
   3.580 +              AND "opinion"."fulfilled" = TRUE
   3.581 +            ),
   3.582 +            "plus2_unfulfilled_count" = (
   3.583 +              SELECT coalesce(sum("snapshot"."weight"), 0)
   3.584 +              FROM "issue" CROSS JOIN "opinion"
   3.585 +              JOIN "direct_interest_snapshot" AS "snapshot"
   3.586 +              ON "snapshot"."issue_id" = "issue"."id"
   3.587 +              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   3.588 +              AND "snapshot"."member_id" = "opinion"."member_id"
   3.589 +              WHERE "issue"."id" = "issue_id_p"
   3.590 +              AND "opinion"."suggestion_id" = "suggestion_id_v"
   3.591 +              AND "opinion"."degree" = 2
   3.592 +              AND "opinion"."fulfilled" = FALSE
   3.593 +            ),
   3.594 +            "plus2_fulfilled_count" = (
   3.595 +              SELECT coalesce(sum("snapshot"."weight"), 0)
   3.596 +              FROM "issue" CROSS JOIN "opinion"
   3.597 +              JOIN "direct_interest_snapshot" AS "snapshot"
   3.598 +              ON "snapshot"."issue_id" = "issue"."id"
   3.599 +              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   3.600 +              AND "snapshot"."member_id" = "opinion"."member_id"
   3.601 +              WHERE "issue"."id" = "issue_id_p"
   3.602 +              AND "opinion"."suggestion_id" = "suggestion_id_v"
   3.603 +              AND "opinion"."degree" = 2
   3.604 +              AND "opinion"."fulfilled" = TRUE
   3.605 +            )
   3.606 +            WHERE "suggestion"."id" = "suggestion_id_v";
   3.607 +        END LOOP;
   3.608 +      END LOOP;
   3.609 +      RETURN;
   3.610 +    END;
   3.611 +  $$;
   3.612 +
   3.613 +CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
   3.614 +  RETURNS VOID
   3.615 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   3.616 +    DECLARE
   3.617 +      "area_id_v"   "area"."id"%TYPE;
   3.618 +      "unit_id_v"   "unit"."id"%TYPE;
   3.619 +      "member_id_v" "member"."id"%TYPE;
   3.620 +    BEGIN
   3.621 +      PERFORM "lock_issue"("issue_id_p");
   3.622 +      SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
   3.623 +      SELECT "unit_id" INTO "unit_id_v" FROM "area"  WHERE "id" = "area_id_v";
   3.624 +      -- delete delegating votes (in cases of manual reset of issue state):
   3.625 +      DELETE FROM "delegating_voter"
   3.626 +        WHERE "issue_id" = "issue_id_p";
   3.627 +      -- delete votes from non-privileged voters:
   3.628 +      DELETE FROM "direct_voter"
   3.629 +        USING (
   3.630 +          SELECT
   3.631 +            "direct_voter"."member_id"
   3.632 +          FROM "direct_voter"
   3.633 +          JOIN "member" ON "direct_voter"."member_id" = "member"."id"
   3.634 +          LEFT JOIN "privilege"
   3.635 +          ON "privilege"."unit_id" = "unit_id_v"
   3.636 +          AND "privilege"."member_id" = "direct_voter"."member_id"
   3.637 +          WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
   3.638 +            "member"."active" = FALSE OR
   3.639 +            "privilege"."voting_right" ISNULL OR
   3.640 +            "privilege"."voting_right" = FALSE
   3.641 +          )
   3.642 +        ) AS "subquery"
   3.643 +        WHERE "direct_voter"."issue_id" = "issue_id_p"
   3.644 +        AND "direct_voter"."member_id" = "subquery"."member_id";
   3.645 +      -- consider delegations:
   3.646 +      UPDATE "direct_voter" SET "weight" = 1
   3.647 +        WHERE "issue_id" = "issue_id_p";
   3.648 +      PERFORM "add_vote_delegations"("issue_id_p");
   3.649 +      -- set voter count and mark issue as being calculated:
   3.650 +      UPDATE "issue" SET
   3.651 +        "state"  = 'calculation',
   3.652 +        "closed" = now(),
   3.653 +        "voter_count" = (
   3.654 +          SELECT coalesce(sum("weight"), 0)
   3.655 +          FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
   3.656 +        )
   3.657 +        WHERE "id" = "issue_id_p";
   3.658 +      -- materialize battle_view:
   3.659 +      -- NOTE: "closed" column of issue must be set at this point
   3.660 +      DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
   3.661 +      INSERT INTO "battle" (
   3.662 +        "issue_id",
   3.663 +        "winning_initiative_id", "losing_initiative_id",
   3.664 +        "count"
   3.665 +      ) SELECT
   3.666 +        "issue_id",
   3.667 +        "winning_initiative_id", "losing_initiative_id",
   3.668 +        "count"
   3.669 +        FROM "battle_view" WHERE "issue_id" = "issue_id_p";
   3.670 +      -- copy "positive_votes" and "negative_votes" from "battle" table:
   3.671 +      UPDATE "initiative" SET
   3.672 +        "positive_votes" = "battle_win"."count",
   3.673 +        "negative_votes" = "battle_lose"."count"
   3.674 +        FROM "battle" AS "battle_win", "battle" AS "battle_lose"
   3.675 +        WHERE
   3.676 +          "battle_win"."issue_id" = "issue_id_p" AND
   3.677 +          "battle_win"."winning_initiative_id" = "initiative"."id" AND
   3.678 +          "battle_win"."losing_initiative_id" ISNULL AND
   3.679 +          "battle_lose"."issue_id" = "issue_id_p" AND
   3.680 +          "battle_lose"."losing_initiative_id" = "initiative"."id" AND
   3.681 +          "battle_lose"."winning_initiative_id" ISNULL;
   3.682 +    END;
   3.683 +  $$;
   3.684 +
   3.685 +DROP FUNCTION "array_init_string"(INTEGER);
   3.686 +DROP FUNCTION "square_matrix_init_string"(INTEGER);
   3.687 +
   3.688 +CREATE OR REPLACE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
   3.689 +  RETURNS VOID
   3.690 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   3.691 +    DECLARE
   3.692 +      "issue_row"         "issue"%ROWTYPE;
   3.693 +      "policy_row"        "policy"%ROWTYPE;
   3.694 +      "dimension_v"       INTEGER;
   3.695 +      "vote_matrix"       INT4[][];  -- absolute votes
   3.696 +      "matrix"            INT8[][];  -- defeat strength / best paths
   3.697 +      "i"                 INTEGER;
   3.698 +      "j"                 INTEGER;
   3.699 +      "k"                 INTEGER;
   3.700 +      "battle_row"        "battle"%ROWTYPE;
   3.701 +      "rank_ary"          INT4[];
   3.702 +      "rank_v"            INT4;
   3.703 +      "done_v"            INTEGER;
   3.704 +      "winners_ary"       INTEGER[];
   3.705 +      "initiative_id_v"   "initiative"."id"%TYPE;
   3.706 +    BEGIN
   3.707 +      SELECT * INTO "issue_row"
   3.708 +        FROM "issue" WHERE "id" = "issue_id_p"
   3.709 +        FOR UPDATE;
   3.710 +      SELECT * INTO "policy_row"
   3.711 +        FROM "policy" WHERE "id" = "issue_row"."policy_id";
   3.712 +      SELECT count(1) INTO "dimension_v"
   3.713 +        FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
   3.714 +      -- Create "vote_matrix" with absolute number of votes in pairwise
   3.715 +      -- comparison:
   3.716 +      "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
   3.717 +      "i" := 1;
   3.718 +      "j" := 2;
   3.719 +      FOR "battle_row" IN
   3.720 +        SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
   3.721 +        ORDER BY
   3.722 +        "winning_initiative_id" NULLS LAST,
   3.723 +        "losing_initiative_id" NULLS LAST
   3.724 +      LOOP
   3.725 +        "vote_matrix"["i"]["j"] := "battle_row"."count";
   3.726 +        IF "j" = "dimension_v" THEN
   3.727 +          "i" := "i" + 1;
   3.728 +          "j" := 1;
   3.729 +        ELSE
   3.730 +          "j" := "j" + 1;
   3.731 +          IF "j" = "i" THEN
   3.732 +            "j" := "j" + 1;
   3.733 +          END IF;
   3.734 +        END IF;
   3.735 +      END LOOP;
   3.736 +      IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
   3.737 +        RAISE EXCEPTION 'Wrong battle count (should not happen)';
   3.738 +      END IF;
   3.739 +      -- Store defeat strengths in "matrix" using "defeat_strength"
   3.740 +      -- function:
   3.741 +      "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
   3.742 +      "i" := 1;
   3.743 +      LOOP
   3.744 +        "j" := 1;
   3.745 +        LOOP
   3.746 +          IF "i" != "j" THEN
   3.747 +            "matrix"["i"]["j"] := "defeat_strength"(
   3.748 +              "vote_matrix"["i"]["j"],
   3.749 +              "vote_matrix"["j"]["i"]
   3.750 +            );
   3.751 +          END IF;
   3.752 +          EXIT WHEN "j" = "dimension_v";
   3.753 +          "j" := "j" + 1;
   3.754 +        END LOOP;
   3.755 +        EXIT WHEN "i" = "dimension_v";
   3.756 +        "i" := "i" + 1;
   3.757 +      END LOOP;
   3.758 +      -- Find best paths:
   3.759 +      "i" := 1;
   3.760 +      LOOP
   3.761 +        "j" := 1;
   3.762 +        LOOP
   3.763 +          IF "i" != "j" THEN
   3.764 +            "k" := 1;
   3.765 +            LOOP
   3.766 +              IF "i" != "k" AND "j" != "k" THEN
   3.767 +                IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
   3.768 +                  IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
   3.769 +                    "matrix"["j"]["k"] := "matrix"["j"]["i"];
   3.770 +                  END IF;
   3.771 +                ELSE
   3.772 +                  IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
   3.773 +                    "matrix"["j"]["k"] := "matrix"["i"]["k"];
   3.774 +                  END IF;
   3.775 +                END IF;
   3.776 +              END IF;
   3.777 +              EXIT WHEN "k" = "dimension_v";
   3.778 +              "k" := "k" + 1;
   3.779 +            END LOOP;
   3.780 +          END IF;
   3.781 +          EXIT WHEN "j" = "dimension_v";
   3.782 +          "j" := "j" + 1;
   3.783 +        END LOOP;
   3.784 +        EXIT WHEN "i" = "dimension_v";
   3.785 +        "i" := "i" + 1;
   3.786 +      END LOOP;
   3.787 +      -- Determine order of winners:
   3.788 +      "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
   3.789 +      "rank_v" := 1;
   3.790 +      "done_v" := 0;
   3.791 +      LOOP
   3.792 +        "winners_ary" := '{}';
   3.793 +        "i" := 1;
   3.794 +        LOOP
   3.795 +          IF "rank_ary"["i"] ISNULL THEN
   3.796 +            "j" := 1;
   3.797 +            LOOP
   3.798 +              IF
   3.799 +                "i" != "j" AND
   3.800 +                "rank_ary"["j"] ISNULL AND
   3.801 +                "matrix"["j"]["i"] > "matrix"["i"]["j"]
   3.802 +              THEN
   3.803 +                -- someone else is better
   3.804 +                EXIT;
   3.805 +              END IF;
   3.806 +              IF "j" = "dimension_v" THEN
   3.807 +                -- noone is better
   3.808 +                "winners_ary" := "winners_ary" || "i";
   3.809 +                EXIT;
   3.810 +              END IF;
   3.811 +              "j" := "j" + 1;
   3.812 +            END LOOP;
   3.813 +          END IF;
   3.814 +          EXIT WHEN "i" = "dimension_v";
   3.815 +          "i" := "i" + 1;
   3.816 +        END LOOP;
   3.817 +        "i" := 1;
   3.818 +        LOOP
   3.819 +          "rank_ary"["winners_ary"["i"]] := "rank_v";
   3.820 +          "done_v" := "done_v" + 1;
   3.821 +          EXIT WHEN "i" = array_upper("winners_ary", 1);
   3.822 +          "i" := "i" + 1;
   3.823 +        END LOOP;
   3.824 +        EXIT WHEN "done_v" = "dimension_v";
   3.825 +        "rank_v" := "rank_v" + 1;
   3.826 +      END LOOP;
   3.827 +      -- write preliminary results:
   3.828 +      "i" := 1;
   3.829 +      FOR "initiative_id_v" IN
   3.830 +        SELECT "id" FROM "initiative"
   3.831 +        WHERE "issue_id" = "issue_id_p" AND "admitted"
   3.832 +        ORDER BY "id"
   3.833 +      LOOP
   3.834 +        UPDATE "initiative" SET
   3.835 +          "direct_majority" =
   3.836 +            CASE WHEN "policy_row"."direct_majority_strict" THEN
   3.837 +              "positive_votes" * "policy_row"."direct_majority_den" >
   3.838 +              "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
   3.839 +            ELSE
   3.840 +              "positive_votes" * "policy_row"."direct_majority_den" >=
   3.841 +              "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
   3.842 +            END
   3.843 +            AND "positive_votes" >= "policy_row"."direct_majority_positive"
   3.844 +            AND "issue_row"."voter_count"-"negative_votes" >=
   3.845 +                "policy_row"."direct_majority_non_negative",
   3.846 +            "indirect_majority" =
   3.847 +            CASE WHEN "policy_row"."indirect_majority_strict" THEN
   3.848 +              "positive_votes" * "policy_row"."indirect_majority_den" >
   3.849 +              "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
   3.850 +            ELSE
   3.851 +              "positive_votes" * "policy_row"."indirect_majority_den" >=
   3.852 +              "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
   3.853 +            END
   3.854 +            AND "positive_votes" >= "policy_row"."indirect_majority_positive"
   3.855 +            AND "issue_row"."voter_count"-"negative_votes" >=
   3.856 +                "policy_row"."indirect_majority_non_negative",
   3.857 +          "schulze_rank"           = "rank_ary"["i"],
   3.858 +          "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
   3.859 +          "worse_than_status_quo"  = "rank_ary"["i"] > "rank_ary"["dimension_v"],
   3.860 +          "multistage_majority"    = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
   3.861 +          "reverse_beat_path"      = "matrix"["dimension_v"]["i"] >= 0,
   3.862 +          "winner"                 = FALSE
   3.863 +          WHERE "id" = "initiative_id_v";
   3.864 +        "i" := "i" + 1;
   3.865 +      END LOOP;
   3.866 +      IF "i" != "dimension_v" THEN
   3.867 +        RAISE EXCEPTION 'Wrong winner count (should not happen)';
   3.868 +      END IF;
   3.869 +      -- take indirect majorities into account:
   3.870 +      LOOP
   3.871 +        UPDATE "initiative" SET "indirect_majority" = TRUE
   3.872 +          FROM (
   3.873 +            SELECT "new_initiative"."id" AS "initiative_id"
   3.874 +            FROM "initiative" "old_initiative"
   3.875 +            JOIN "initiative" "new_initiative"
   3.876 +              ON "new_initiative"."issue_id" = "issue_id_p"
   3.877 +              AND "new_initiative"."indirect_majority" = FALSE
   3.878 +            JOIN "battle" "battle_win"
   3.879 +              ON "battle_win"."issue_id" = "issue_id_p"
   3.880 +              AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
   3.881 +              AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
   3.882 +            JOIN "battle" "battle_lose"
   3.883 +              ON "battle_lose"."issue_id" = "issue_id_p"
   3.884 +              AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
   3.885 +              AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
   3.886 +            WHERE "old_initiative"."issue_id" = "issue_id_p"
   3.887 +            AND "old_initiative"."indirect_majority" = TRUE
   3.888 +            AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
   3.889 +              "battle_win"."count" * "policy_row"."indirect_majority_den" >
   3.890 +              "policy_row"."indirect_majority_num" *
   3.891 +              ("battle_win"."count"+"battle_lose"."count")
   3.892 +            ELSE
   3.893 +              "battle_win"."count" * "policy_row"."indirect_majority_den" >=
   3.894 +              "policy_row"."indirect_majority_num" *
   3.895 +              ("battle_win"."count"+"battle_lose"."count")
   3.896 +            END
   3.897 +            AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
   3.898 +            AND "issue_row"."voter_count"-"battle_lose"."count" >=
   3.899 +                "policy_row"."indirect_majority_non_negative"
   3.900 +          ) AS "subquery"
   3.901 +          WHERE "id" = "subquery"."initiative_id";
   3.902 +        EXIT WHEN NOT FOUND;
   3.903 +      END LOOP;
   3.904 +      -- set "multistage_majority" for remaining matching initiatives:
   3.905 +       UPDATE "initiative" SET "multistage_majority" = TRUE
   3.906 +        FROM (
   3.907 +          SELECT "losing_initiative"."id" AS "initiative_id"
   3.908 +          FROM "initiative" "losing_initiative"
   3.909 +          JOIN "initiative" "winning_initiative"
   3.910 +            ON "winning_initiative"."issue_id" = "issue_id_p"
   3.911 +            AND "winning_initiative"."admitted"
   3.912 +          JOIN "battle" "battle_win"
   3.913 +            ON "battle_win"."issue_id" = "issue_id_p"
   3.914 +            AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
   3.915 +            AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
   3.916 +          JOIN "battle" "battle_lose"
   3.917 +            ON "battle_lose"."issue_id" = "issue_id_p"
   3.918 +            AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
   3.919 +            AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
   3.920 +          WHERE "losing_initiative"."issue_id" = "issue_id_p"
   3.921 +          AND "losing_initiative"."admitted"
   3.922 +          AND "winning_initiative"."schulze_rank" <
   3.923 +              "losing_initiative"."schulze_rank"
   3.924 +          AND "battle_win"."count" > "battle_lose"."count"
   3.925 +          AND (
   3.926 +            "battle_win"."count" > "winning_initiative"."positive_votes" OR
   3.927 +            "battle_lose"."count" < "losing_initiative"."negative_votes" )
   3.928 +        ) AS "subquery"
   3.929 +        WHERE "id" = "subquery"."initiative_id";
   3.930 +      -- mark eligible initiatives:
   3.931 +      UPDATE "initiative" SET "eligible" = TRUE
   3.932 +        WHERE "issue_id" = "issue_id_p"
   3.933 +        AND "initiative"."direct_majority"
   3.934 +        AND "initiative"."indirect_majority"
   3.935 +        AND "initiative"."better_than_status_quo"
   3.936 +        AND (
   3.937 +          "policy_row"."no_multistage_majority" = FALSE OR
   3.938 +          "initiative"."multistage_majority" = FALSE )
   3.939 +        AND (
   3.940 +          "policy_row"."no_reverse_beat_path" = FALSE OR
   3.941 +          "initiative"."reverse_beat_path" = FALSE );
   3.942 +      -- mark final winner:
   3.943 +      UPDATE "initiative" SET "winner" = TRUE
   3.944 +        FROM (
   3.945 +          SELECT "id" AS "initiative_id"
   3.946 +          FROM "initiative"
   3.947 +          WHERE "issue_id" = "issue_id_p" AND "eligible"
   3.948 +          ORDER BY "schulze_rank", "id"
   3.949 +          LIMIT 1
   3.950 +        ) AS "subquery"
   3.951 +        WHERE "id" = "subquery"."initiative_id";
   3.952 +      -- write (final) ranks:
   3.953 +      "rank_v" := 1;
   3.954 +      FOR "initiative_id_v" IN
   3.955 +        SELECT "id"
   3.956 +        FROM "initiative"
   3.957 +        WHERE "issue_id" = "issue_id_p" AND "admitted"
   3.958 +        ORDER BY
   3.959 +          "winner" DESC,
   3.960 +          ("direct_majority" AND "indirect_majority") DESC,
   3.961 +          "schulze_rank",
   3.962 +          "id"
   3.963 +      LOOP
   3.964 +        UPDATE "initiative" SET "rank" = "rank_v"
   3.965 +          WHERE "id" = "initiative_id_v";
   3.966 +        "rank_v" := "rank_v" + 1;
   3.967 +      END LOOP;
   3.968 +      -- set schulze rank of status quo and mark issue as finished:
   3.969 +      UPDATE "issue" SET
   3.970 +        "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
   3.971 +        "state" =
   3.972 +          CASE WHEN EXISTS (
   3.973 +            SELECT NULL FROM "initiative"
   3.974 +            WHERE "issue_id" = "issue_id_p" AND "winner"
   3.975 +          ) THEN
   3.976 +            'finished_with_winner'::"issue_state"
   3.977 +          ELSE
   3.978 +            'finished_without_winner'::"issue_state"
   3.979 +          END,
   3.980 +        "ranks_available" = TRUE
   3.981 +        WHERE "id" = "issue_id_p";
   3.982 +      RETURN;
   3.983 +    END;
   3.984 +  $$;
   3.985 +
   3.986 +CREATE OR REPLACE FUNCTION "check_issue"
   3.987 +  ( "issue_id_p" "issue"."id"%TYPE )
   3.988 +  RETURNS VOID
   3.989 +  LANGUAGE 'plpgsql' VOLATILE AS $$
   3.990 +    DECLARE
   3.991 +      "issue_row"         "issue"%ROWTYPE;
   3.992 +      "policy_row"        "policy"%ROWTYPE;
   3.993 +    BEGIN
   3.994 +      PERFORM "lock_issue"("issue_id_p");
   3.995 +      SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
   3.996 +      -- only process open issues:
   3.997 +      IF "issue_row"."closed" ISNULL THEN
   3.998 +        SELECT * INTO "policy_row" FROM "policy"
   3.999 +          WHERE "id" = "issue_row"."policy_id";
  3.1000 +        -- create a snapshot, unless issue is already fully frozen:
  3.1001 +        IF "issue_row"."fully_frozen" ISNULL THEN
  3.1002 +          PERFORM "create_snapshot"("issue_id_p");
  3.1003 +          SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  3.1004 +        END IF;
  3.1005 +        -- eventually close or accept issues, which have not been accepted:
  3.1006 +        IF "issue_row"."accepted" ISNULL THEN
  3.1007 +          IF EXISTS (
  3.1008 +            SELECT NULL FROM "initiative"
  3.1009 +            WHERE "issue_id" = "issue_id_p"
  3.1010 +            AND "supporter_count" > 0
  3.1011 +            AND "supporter_count" * "policy_row"."issue_quorum_den"
  3.1012 +            >= "issue_row"."population" * "policy_row"."issue_quorum_num"
  3.1013 +          ) THEN
  3.1014 +            -- accept issues, if supporter count is high enough
  3.1015 +            PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
  3.1016 +            -- NOTE: "issue_row" used later
  3.1017 +            "issue_row"."state" := 'discussion';
  3.1018 +            "issue_row"."accepted" := now();
  3.1019 +            UPDATE "issue" SET
  3.1020 +              "state"    = "issue_row"."state",
  3.1021 +              "accepted" = "issue_row"."accepted"
  3.1022 +              WHERE "id" = "issue_row"."id";
  3.1023 +          ELSIF
  3.1024 +            now() >= "issue_row"."created" + "issue_row"."admission_time"
  3.1025 +          THEN
  3.1026 +            -- close issues, if admission time has expired
  3.1027 +            PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
  3.1028 +            UPDATE "issue" SET
  3.1029 +              "state" = 'canceled_issue_not_accepted',
  3.1030 +              "closed" = now()
  3.1031 +              WHERE "id" = "issue_row"."id";
  3.1032 +          END IF;
  3.1033 +        END IF;
  3.1034 +        -- eventually half freeze issues:
  3.1035 +        IF
  3.1036 +          -- NOTE: issue can't be closed at this point, if it has been accepted
  3.1037 +          "issue_row"."accepted" NOTNULL AND
  3.1038 +          "issue_row"."half_frozen" ISNULL
  3.1039 +        THEN
  3.1040 +          IF
  3.1041 +            now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
  3.1042 +          THEN
  3.1043 +            PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
  3.1044 +            -- NOTE: "issue_row" used later
  3.1045 +            "issue_row"."state" := 'verification';
  3.1046 +            "issue_row"."half_frozen" := now();
  3.1047 +            UPDATE "issue" SET
  3.1048 +              "state"       = "issue_row"."state",
  3.1049 +              "half_frozen" = "issue_row"."half_frozen"
  3.1050 +              WHERE "id" = "issue_row"."id";
  3.1051 +          END IF;
  3.1052 +        END IF;
  3.1053 +        -- close issues after some time, if all initiatives have been revoked:
  3.1054 +        IF
  3.1055 +          "issue_row"."closed" ISNULL AND
  3.1056 +          NOT EXISTS (
  3.1057 +            -- all initiatives are revoked
  3.1058 +            SELECT NULL FROM "initiative"
  3.1059 +            WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
  3.1060 +          ) AND (
  3.1061 +            -- and issue has not been accepted yet
  3.1062 +            "issue_row"."accepted" ISNULL OR
  3.1063 +            NOT EXISTS (
  3.1064 +              -- or no initiatives have been revoked lately
  3.1065 +              SELECT NULL FROM "initiative"
  3.1066 +              WHERE "issue_id" = "issue_id_p"
  3.1067 +              AND now() < "revoked" + "issue_row"."verification_time"
  3.1068 +            ) OR (
  3.1069 +              -- or verification time has elapsed
  3.1070 +              "issue_row"."half_frozen" NOTNULL AND
  3.1071 +              "issue_row"."fully_frozen" ISNULL AND
  3.1072 +              now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
  3.1073 +            )
  3.1074 +          )
  3.1075 +        THEN
  3.1076 +          -- NOTE: "issue_row" used later
  3.1077 +          IF "issue_row"."accepted" ISNULL THEN
  3.1078 +            "issue_row"."state" := 'canceled_revoked_before_accepted';
  3.1079 +          ELSIF "issue_row"."half_frozen" ISNULL THEN
  3.1080 +            "issue_row"."state" := 'canceled_after_revocation_during_discussion';
  3.1081 +          ELSE
  3.1082 +            "issue_row"."state" := 'canceled_after_revocation_during_verification';
  3.1083 +          END IF;
  3.1084 +          "issue_row"."closed" := now();
  3.1085 +          UPDATE "issue" SET
  3.1086 +            "state"  = "issue_row"."state",
  3.1087 +            "closed" = "issue_row"."closed"
  3.1088 +            WHERE "id" = "issue_row"."id";
  3.1089 +        END IF;
  3.1090 +        -- fully freeze issue after verification time:
  3.1091 +        IF
  3.1092 +          "issue_row"."half_frozen" NOTNULL AND
  3.1093 +          "issue_row"."fully_frozen" ISNULL AND
  3.1094 +          "issue_row"."closed" ISNULL AND
  3.1095 +          now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
  3.1096 +        THEN
  3.1097 +          PERFORM "freeze_after_snapshot"("issue_id_p");
  3.1098 +          -- NOTE: "issue" might change, thus "issue_row" has to be updated below
  3.1099 +        END IF;
  3.1100 +        SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  3.1101 +        -- close issue by calling close_voting(...) after voting time:
  3.1102 +        IF
  3.1103 +          "issue_row"."closed" ISNULL AND
  3.1104 +          "issue_row"."fully_frozen" NOTNULL AND
  3.1105 +          now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
  3.1106 +        THEN
  3.1107 +          PERFORM "close_voting"("issue_id_p");
  3.1108 +          -- calculate ranks will not consume much time and can be done now
  3.1109 +          PERFORM "calculate_ranks"("issue_id_p");
  3.1110 +        END IF;
  3.1111 +      END IF;
  3.1112 +      RETURN;
  3.1113 +    END;
  3.1114 +  $$;
  3.1115 +
  3.1116 +CREATE OR REPLACE FUNCTION "check_everything"()
  3.1117 +  RETURNS VOID
  3.1118 +  LANGUAGE 'plpgsql' VOLATILE AS $$
  3.1119 +    DECLARE
  3.1120 +      "issue_id_v" "issue"."id"%TYPE;
  3.1121 +    BEGIN
  3.1122 +      PERFORM "check_activity"();
  3.1123 +      PERFORM "calculate_member_counts"();
  3.1124 +      FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
  3.1125 +        PERFORM "check_issue"("issue_id_v");
  3.1126 +      END LOOP;
  3.1127 +      FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
  3.1128 +        PERFORM "calculate_ranks"("issue_id_v");
  3.1129 +      END LOOP;
  3.1130 +      RETURN;
  3.1131 +    END;
  3.1132 +  $$;
  3.1133 +
  3.1134 +CREATE OR REPLACE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
  3.1135 +  RETURNS VOID
  3.1136 +  LANGUAGE 'plpgsql' VOLATILE AS $$
  3.1137 +    BEGIN
  3.1138 +      UPDATE "member" SET
  3.1139 +        "last_login"                   = NULL,
  3.1140 +        "login"                        = NULL,
  3.1141 +        "password"                     = NULL,
  3.1142 +        "locked"                       = TRUE,
  3.1143 +        "active"                       = FALSE,
  3.1144 +        "notify_email"                 = NULL,
  3.1145 +        "notify_email_unconfirmed"     = NULL,
  3.1146 +        "notify_email_secret"          = NULL,
  3.1147 +        "notify_email_secret_expiry"   = NULL,
  3.1148 +        "notify_email_lock_expiry"     = NULL,
  3.1149 +        "password_reset_secret"        = NULL,
  3.1150 +        "password_reset_secret_expiry" = NULL,
  3.1151 +        "organizational_unit"          = NULL,
  3.1152 +        "internal_posts"               = NULL,
  3.1153 +        "realname"                     = NULL,
  3.1154 +        "birthday"                     = NULL,
  3.1155 +        "address"                      = NULL,
  3.1156 +        "email"                        = NULL,
  3.1157 +        "xmpp_address"                 = NULL,
  3.1158 +        "website"                      = NULL,
  3.1159 +        "phone"                        = NULL,
  3.1160 +        "mobile_phone"                 = NULL,
  3.1161 +        "profession"                   = NULL,
  3.1162 +        "external_memberships"         = NULL,
  3.1163 +        "external_posts"               = NULL,
  3.1164 +        "statement"                    = NULL
  3.1165 +        WHERE "id" = "member_id_p";
  3.1166 +      -- "text_search_data" is updated by triggers
  3.1167 +      DELETE FROM "setting"            WHERE "member_id" = "member_id_p";
  3.1168 +      DELETE FROM "setting_map"        WHERE "member_id" = "member_id_p";
  3.1169 +      DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
  3.1170 +      DELETE FROM "member_image"       WHERE "member_id" = "member_id_p";
  3.1171 +      DELETE FROM "contact"            WHERE "member_id" = "member_id_p";
  3.1172 +      DELETE FROM "ignored_member"     WHERE "member_id" = "member_id_p";
  3.1173 +      DELETE FROM "area_setting"       WHERE "member_id" = "member_id_p";
  3.1174 +      DELETE FROM "issue_setting"      WHERE "member_id" = "member_id_p";
  3.1175 +      DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
  3.1176 +      DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
  3.1177 +      DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
  3.1178 +      DELETE FROM "membership"         WHERE "member_id" = "member_id_p";
  3.1179 +      DELETE FROM "delegation"         WHERE "truster_id" = "member_id_p";
  3.1180 +      DELETE FROM "non_voter"          WHERE "member_id" = "member_id_p";
  3.1181 +      DELETE FROM "direct_voter" USING "issue"
  3.1182 +        WHERE "direct_voter"."issue_id" = "issue"."id"
  3.1183 +        AND "issue"."closed" ISNULL
  3.1184 +        AND "member_id" = "member_id_p";
  3.1185 +      RETURN;
  3.1186 +    END;
  3.1187 +  $$;
  3.1188 +
  3.1189 +CREATE OR REPLACE FUNCTION "delete_private_data"()
  3.1190 +  RETURNS VOID
  3.1191 +  LANGUAGE 'plpgsql' VOLATILE AS $$
  3.1192 +    BEGIN
  3.1193 +      UPDATE "member" SET
  3.1194 +        "last_login"                   = NULL,
  3.1195 +        "login"                        = NULL,
  3.1196 +        "password"                     = NULL,
  3.1197 +        "notify_email"                 = NULL,
  3.1198 +        "notify_email_unconfirmed"     = NULL,
  3.1199 +        "notify_email_secret"          = NULL,
  3.1200 +        "notify_email_secret_expiry"   = NULL,
  3.1201 +        "notify_email_lock_expiry"     = NULL,
  3.1202 +        "password_reset_secret"        = NULL,
  3.1203 +        "password_reset_secret_expiry" = NULL,
  3.1204 +        "organizational_unit"          = NULL,
  3.1205 +        "internal_posts"               = NULL,
  3.1206 +        "realname"                     = NULL,
  3.1207 +        "birthday"                     = NULL,
  3.1208 +        "address"                      = NULL,
  3.1209 +        "email"                        = NULL,
  3.1210 +        "xmpp_address"                 = NULL,
  3.1211 +        "website"                      = NULL,
  3.1212 +        "phone"                        = NULL,
  3.1213 +        "mobile_phone"                 = NULL,
  3.1214 +        "profession"                   = NULL,
  3.1215 +        "external_memberships"         = NULL,
  3.1216 +        "external_posts"               = NULL,
  3.1217 +        "statement"                    = NULL;
  3.1218 +      -- "text_search_data" is updated by triggers
  3.1219 +      DELETE FROM "invite_code";
  3.1220 +      DELETE FROM "setting";
  3.1221 +      DELETE FROM "setting_map";
  3.1222 +      DELETE FROM "member_relation_setting";
  3.1223 +      DELETE FROM "member_image";
  3.1224 +      DELETE FROM "contact";
  3.1225 +      DELETE FROM "ignored_member";
  3.1226 +      DELETE FROM "area_setting";
  3.1227 +      DELETE FROM "issue_setting";
  3.1228 +      DELETE FROM "ignored_initiative";
  3.1229 +      DELETE FROM "initiative_setting";
  3.1230 +      DELETE FROM "suggestion_setting";
  3.1231 +      DELETE FROM "non_voter";
  3.1232 +      DELETE FROM "direct_voter" USING "issue"
  3.1233 +        WHERE "direct_voter"."issue_id" = "issue"."id"
  3.1234 +        AND "issue"."closed" ISNULL;
  3.1235 +      RETURN;
  3.1236 +    END;
  3.1237 +  $$;
  3.1238 +
  3.1239 +COMMIT;
  3.1240 +
  3.1241 +BEGIN;
  3.1242 +
  3.1243 +UPDATE "member" SET
  3.1244 +  "activated" = "created",
  3.1245 +  "last_activity" = CASE WHEN "active" THEN
  3.1246 +    coalesce("last_login"::DATE, now())
  3.1247 +  ELSE
  3.1248 +    "last_login"::DATE
  3.1249 +  END;
  3.1250 +
  3.1251 +UPDATE "member" SET
  3.1252 +  "created" = "invite_code"."created",
  3.1253 +  "invite_code" = "invite_code"."code",
  3.1254 +  "admin_comment" = "invite_code"."comment"
  3.1255 +  FROM "invite_code"
  3.1256 +  WHERE "member"."id" = "invite_code"."member_id";
  3.1257 +
  3.1258 +DROP TABLE "invite_code";
  3.1259 +
  3.1260 +UPDATE "initiative" SET
  3.1261 +    "direct_majority"        = "rank" NOTNULL,
  3.1262 +    "indirect_majority"      = "rank" NOTNULL,
  3.1263 +    "schulze_rank"           = "rank",
  3.1264 +    "better_than_status_quo" = "rank" NOTNULL,
  3.1265 +    "worse_than_status_quo"  = "rank" ISNULL,
  3.1266 +    "reverse_beat_path"      = "rank" ISNULL,
  3.1267 +    "multistage_majority"    = "rank" ISNULL,
  3.1268 +    "eligible"               = "rank" NOTNULL,
  3.1269 +    "winner"                 = ("rank" = 1)
  3.1270 +  FROM "issue"
  3.1271 +  WHERE "issue"."id" = "initiative"."issue_id"
  3.1272 +  AND "issue"."state" IN ('finished_without_winner', 'finished_with_winner')
  3.1273 +  AND "initiative"."admitted";
  3.1274 +
  3.1275 +UPDATE "issue" SET "status_quo_schulze_rank" = "subquery"."rank"
  3.1276 +  FROM (
  3.1277 +    SELECT
  3.1278 +      "issue"."id" AS "issue_id",
  3.1279 +      COALESCE(max("initiative"."rank") + 1, 1) AS "rank"
  3.1280 +    FROM "issue" JOIN "initiative"
  3.1281 +    ON "issue"."id" = "initiative"."issue_id"
  3.1282 +    WHERE "issue"."state" IN ('finished_without_winner', 'finished_with_winner')
  3.1283 +    AND "initiative"."admitted"
  3.1284 +    GROUP BY "issue"."id"
  3.1285 +  ) AS "subquery"
  3.1286 +  WHERE "issue"."id" = "subquery"."issue_id";
  3.1287 +
  3.1288 +CREATE FUNCTION "update__set_remaining_ranks"("issue_id_p" "issue"."id"%TYPE)
  3.1289 +  RETURNS VOID
  3.1290 +  LANGUAGE 'plpgsql' AS $$
  3.1291 +    DECLARE
  3.1292 +      "rank_v"          INT4;
  3.1293 +      "initiative_id_v" INT4;
  3.1294 +    BEGIN
  3.1295 +      SELECT "status_quo_schulze_rank" INTO "rank_v"
  3.1296 +        FROM "issue" WHERE "id" = "issue_id_p";
  3.1297 +      FOR "initiative_id_v" IN
  3.1298 +        SELECT "id" FROM "initiative"
  3.1299 +        WHERE "issue_id" = "issue_id_p" AND "admitted" AND "rank" ISNULL
  3.1300 +        ORDER BY "vote_ratio"("positive_votes", "negative_votes") DESC
  3.1301 +      LOOP
  3.1302 +        UPDATE "initiative" SET
  3.1303 +          "schulze_rank" = "rank_v" + 1,
  3.1304 +          "rank"         = "rank_v"
  3.1305 +          WHERE "id" = "initiative_id_v";
  3.1306 +        "rank_v" := "rank_v" + 1;
  3.1307 +      END LOOP;
  3.1308 +      RETURN;
  3.1309 +    END;
  3.1310 +  $$;
  3.1311 +
  3.1312 +SELECT "update__set_remaining_ranks"("id") FROM "issue"
  3.1313 +  WHERE "state" IN ('finished_without_winner', 'finished_with_winner');
  3.1314 +
  3.1315 +DROP FUNCTION "update__set_remaining_ranks"("issue"."id"%TYPE);
  3.1316 +
  3.1317 +UPDATE "suggestion" SET "draft_id" = "subquery"."draft_id"
  3.1318 +  FROM (
  3.1319 +    SELECT DISTINCT ON ("suggestion"."id")
  3.1320 +      "suggestion"."id" AS "suggestion_id",
  3.1321 +      "draft"."id" AS "draft_id"
  3.1322 +    FROM "suggestion" JOIN "draft"
  3.1323 +    ON "suggestion"."initiative_id" = "draft"."initiative_id"
  3.1324 +    WHERE "draft"."created" <= "suggestion"."created"
  3.1325 +    ORDER BY "suggestion"."id", "draft"."created" DESC
  3.1326 +  ) AS "subquery"
  3.1327 +  WHERE "suggestion"."id" = "subquery"."suggestion_id";
  3.1328 +
  3.1329 +COMMIT;
  3.1330 +
  3.1331 +ALTER TABLE "member" ADD CONSTRAINT "active_requires_activated_and_last_activity"
  3.1332 +  CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL));
  3.1333 +ALTER TABLE "suggestion" ALTER COLUMN "draft_id" SET NOT NULL;
     4.1 --- /dev/null	Thu Jan 01 00:00:00 1970 +0000
     4.2 +++ b/update/core-update.v1.4.0_rc4-v1.4.0.sql	Sat Sep 10 22:42:51 2011 +0200
     4.3 @@ -0,0 +1,3 @@
     4.4 +CREATE OR REPLACE VIEW "liquid_feedback_version" AS
     4.5 +  SELECT * FROM (VALUES ('1.4.0', 1, 4, 0))
     4.6 +  AS "subquery"("string", "major", "minor", "revision");
     5.1 --- a/update/core-update.v1.4.0_rc4-v2.0.0.sql	Sat Sep 10 22:39:06 2011 +0200
     5.2 +++ /dev/null	Thu Jan 01 00:00:00 1970 +0000
     5.3 @@ -1,1330 +0,0 @@
     5.4 -SELECT "calculate_ranks"("id") FROM "issue_with_ranks_missing";
     5.5 -
     5.6 -BEGIN;
     5.7 -
     5.8 -CREATE OR REPLACE VIEW "liquid_feedback_version" AS
     5.9 -  SELECT * FROM (VALUES ('2.0.0', 2, 0, 0))
    5.10 -  AS "subquery"("string", "major", "minor", "revision");
    5.11 -
    5.12 -ALTER TABLE "member" ADD COLUMN "invite_code" TEXT UNIQUE;
    5.13 -ALTER TABLE "member" ADD COLUMN "admin_comment" TEXT;
    5.14 -ALTER TABLE "member" ADD COLUMN "activated" TIMESTAMPTZ;
    5.15 -ALTER TABLE "member" ADD COLUMN "last_activity" DATE;
    5.16 -ALTER TABLE "member" DROP COLUMN "last_login_public";
    5.17 -ALTER TABLE "member" ALTER COLUMN "active" SET DEFAULT FALSE;
    5.18 -ALTER TABLE "member" ADD COLUMN "formatting_engine" TEXT;
    5.19 -
    5.20 -COMMENT ON COLUMN "member"."created"           IS 'Creation of member record and/or invite code';
    5.21 -COMMENT ON COLUMN "member"."invite_code"       IS 'Optional invite code, to allow a member to initialize his/her account the first time';
    5.22 -COMMENT ON COLUMN "member"."admin_comment"     IS 'Hidden comment for administrative purposes';
    5.23 -COMMENT ON COLUMN "member"."activated"         IS 'Timestamp of activation of account (i.e. usage of "invite_code"); required to be set for "active" members';
    5.24 -COMMENT ON COLUMN "member"."last_activity"     IS 'Date of last activity of member; required to be set for "active" members';
    5.25 -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".';
    5.26 -COMMENT ON COLUMN "member"."formatting_engine" IS 'Allows different formatting engines (i.e. wiki formats) to be used for "member"."statement"';
    5.27 -
    5.28 -CREATE TYPE "application_access_level" AS ENUM
    5.29 -  ('member', 'full', 'pseudonymous', 'anonymous');
    5.30 -
    5.31 -COMMENT ON TYPE "application_access_level" IS 'Access privileges for applications using the API';
    5.32 -
    5.33 -CREATE TABLE "member_application" (
    5.34 -        "id"                    SERIAL8         PRIMARY KEY,
    5.35 -        UNIQUE ("member_id", "name"),
    5.36 -        "member_id"             INT4            NOT NULL REFERENCES "member" ("id")
    5.37 -                                                ON DELETE CASCADE ON UPDATE CASCADE,
    5.38 -        "name"                  TEXT            NOT NULL,
    5.39 -        "comment"               TEXT,
    5.40 -        "access_level" "application_access_level" NOT NULL,
    5.41 -        "key"                   TEXT            NOT NULL UNIQUE,
    5.42 -        "last_usage"            TIMESTAMPTZ );
    5.43 -
    5.44 -COMMENT ON TABLE "member_application" IS 'Registered application being allowed to use the API';
    5.45 -
    5.46 -CREATE TABLE "rendered_member_statement" (
    5.47 -        PRIMARY KEY ("member_id", "format"),
    5.48 -        "member_id"             INT8            REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
    5.49 -        "format"                TEXT,
    5.50 -        "content"               TEXT            NOT NULL );
    5.51 -
    5.52 -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)';
    5.53 -
    5.54 -DROP VIEW "expired_session";
    5.55 -DROP TABLE "session";
    5.56 -
    5.57 -ALTER TABLE "policy" ADD COLUMN "direct_majority_num"            INT4    NOT NULL DEFAULT 1;
    5.58 -ALTER TABLE "policy" ADD COLUMN "direct_majority_den"            INT4    NOT NULL DEFAULT 2;
    5.59 -ALTER TABLE "policy" ADD COLUMN "direct_majority_strict"         BOOLEAN NOT NULL DEFAULT TRUE;
    5.60 -ALTER TABLE "policy" ADD COLUMN "direct_majority_positive"       INT4    NOT NULL DEFAULT 0;
    5.61 -ALTER TABLE "policy" ADD COLUMN "direct_majority_non_negative"   INT4    NOT NULL DEFAULT 0;
    5.62 -ALTER TABLE "policy" ADD COLUMN "indirect_majority_num"          INT4    NOT NULL DEFAULT 1;
    5.63 -ALTER TABLE "policy" ADD COLUMN "indirect_majority_den"          INT4    NOT NULL DEFAULT 2;
    5.64 -ALTER TABLE "policy" ADD COLUMN "indirect_majority_strict"       BOOLEAN NOT NULL DEFAULT TRUE;
    5.65 -ALTER TABLE "policy" ADD COLUMN "indirect_majority_positive"     INT4    NOT NULL DEFAULT 0;
    5.66 -ALTER TABLE "policy" ADD COLUMN "indirect_majority_non_negative" INT4    NOT NULL DEFAULT 0;
    5.67 -ALTER TABLE "policy" ADD COLUMN "no_reverse_beat_path"           BOOLEAN NOT NULL DEFAULT TRUE;
    5.68 -ALTER TABLE "policy" ADD COLUMN "no_multistage_majority"         BOOLEAN NOT NULL DEFAULT FALSE;
    5.69 -
    5.70 -UPDATE "policy" SET
    5.71 -  "direct_majority_num"      = "majority_num",
    5.72 -  "direct_majority_den"      = "majority_den",
    5.73 -  "direct_majority_strict"   = "majority_strict",
    5.74 -  "indirect_majority_num"    = "majority_num",
    5.75 -  "indirect_majority_den"    = "majority_den",
    5.76 -  "indirect_majority_strict" = "majority_strict";
    5.77 -
    5.78 -ALTER TABLE "policy" DROP COLUMN "majority_num";
    5.79 -ALTER TABLE "policy" DROP COLUMN "majority_den";
    5.80 -ALTER TABLE "policy" DROP COLUMN "majority_strict";
    5.81 -
    5.82 -COMMENT ON COLUMN "policy"."direct_majority_num"            IS 'Numerator of fraction of neccessary direct majority for initiatives to be attainable as winner';
    5.83 -COMMENT ON COLUMN "policy"."direct_majority_den"            IS 'Denominator of fraction of neccessary direct majority for initaitives to be attainable as winner';
    5.84 -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.';
    5.85 -COMMENT ON COLUMN "policy"."direct_majority_positive"       IS 'Absolute number of "positive_votes" neccessary for an initiative to be attainable as winner';
    5.86 -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';
    5.87 -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';
    5.88 -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';
    5.89 -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.';
    5.90 -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';
    5.91 -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';
    5.92 -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.';
    5.93 -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").';
    5.94 -
    5.95 -ALTER TABLE "area" DROP COLUMN "autoreject_weight";
    5.96 -
    5.97 -DROP VIEW "open_issue";
    5.98 -DROP VIEW "issue_with_ranks_missing";
    5.99 -
   5.100 -ALTER TABLE "issue" DROP COLUMN "vote_now";
   5.101 -ALTER TABLE "issue" DROP COLUMN "vote_later";
   5.102 -ALTER TABLE "issue" ADD COLUMN "status_quo_schulze_rank" INT4;
   5.103 -
   5.104 -CREATE VIEW "open_issue" AS
   5.105 -  SELECT * FROM "issue" WHERE "closed" ISNULL;
   5.106 -
   5.107 -COMMENT ON VIEW "open_issue" IS 'All open issues';
   5.108 -
   5.109 -CREATE VIEW "issue_with_ranks_missing" AS
   5.110 -  SELECT * FROM "issue"
   5.111 -  WHERE "fully_frozen" NOTNULL
   5.112 -  AND "closed" NOTNULL
   5.113 -  AND "ranks_available" = FALSE;
   5.114 -
   5.115 -COMMENT ON VIEW "issue_with_ranks_missing" IS 'Issues where voting was finished, but no ranks have been calculated yet';
   5.116 -
   5.117 -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.';
   5.118 -COMMENT ON COLUMN "issue"."snapshot"                IS 'Point in time, when snapshot tables have been updated and "population" and *_count values were precalculated';
   5.119 -COMMENT ON COLUMN "issue"."status_quo_schulze_rank" IS 'Schulze rank of status quo, as calculated by "calculate_ranks" function';
   5.120 -
   5.121 -DROP VIEW "battle_view";
   5.122 -
   5.123 -ALTER TABLE "initiative" DROP CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results";
   5.124 -ALTER TABLE "initiative" DROP CONSTRAINT "all_or_none_of_positive_votes_negative_votes_and_agreed_must_be_null";
   5.125 -ALTER TABLE "initiative" DROP CONSTRAINT "non_agreed_initiatives_cant_get_a_rank";
   5.126 -
   5.127 -ALTER TABLE "initiative" DROP COLUMN "agreed";
   5.128 -ALTER TABLE "initiative" ADD COLUMN "direct_majority"        BOOLEAN;
   5.129 -ALTER TABLE "initiative" ADD COLUMN "indirect_majority"      BOOLEAN;
   5.130 -ALTER TABLE "initiative" ADD COLUMN "schulze_rank"           INT4;
   5.131 -ALTER TABLE "initiative" ADD COLUMN "better_than_status_quo" BOOLEAN;
   5.132 -ALTER TABLE "initiative" ADD COLUMN "worse_than_status_quo"  BOOLEAN;
   5.133 -ALTER TABLE "initiative" ADD COLUMN "reverse_beat_path"      BOOLEAN;
   5.134 -ALTER TABLE "initiative" ADD COLUMN "multistage_majority"    BOOLEAN;
   5.135 -ALTER TABLE "initiative" ADD COLUMN "eligible"               BOOLEAN;
   5.136 -ALTER TABLE "initiative" ADD COLUMN "winner"                 BOOLEAN;
   5.137 -
   5.138 -ALTER TABLE "initiative" ADD CONSTRAINT "non_admitted_initiatives_cant_contain_voting_results" CHECK (
   5.139 -  ( "admitted" NOTNULL AND "admitted" = TRUE ) OR
   5.140 -  ( "positive_votes" ISNULL AND "negative_votes" ISNULL AND
   5.141 -    "direct_majority" ISNULL AND "indirect_majority" ISNULL AND
   5.142 -    "schulze_rank" ISNULL AND
   5.143 -    "better_than_status_quo" ISNULL AND "worse_than_status_quo" ISNULL AND
   5.144 -    "reverse_beat_path" ISNULL AND "multistage_majority" ISNULL AND
   5.145 -    "eligible" ISNULL AND "winner" ISNULL AND "rank" ISNULL ) );
   5.146 -ALTER TABLE "initiative" ADD CONSTRAINT "better_excludes_worse" CHECK (NOT ("better_than_status_quo" AND "worse_than_status_quo"));
   5.147 -ALTER TABLE "initiative" ADD CONSTRAINT "minimum_requirement_to_be_eligible" CHECK (
   5.148 -  "eligible" = FALSE OR
   5.149 -("direct_majority" AND "indirect_majority" AND "better_than_status_quo") );
   5.150 -ALTER TABLE "initiative" ADD CONSTRAINT "winner_must_be_eligible" CHECK ("winner"=FALSE OR "eligible"=TRUE);
   5.151 -ALTER TABLE "initiative" ADD CONSTRAINT "winner_must_have_first_rank" CHECK ("winner"=FALSE OR "rank"=1);
   5.152 -ALTER TABLE "initiative" ADD CONSTRAINT "eligible_at_first_rank_is_winner" CHECK ("eligible"=FALSE OR "rank"!=1 OR "winner"=TRUE);
   5.153 -ALTER TABLE "initiative" ADD CONSTRAINT "unique_rank_per_issue" UNIQUE ("issue_id", "rank");
   5.154 -
   5.155 -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"';
   5.156 -COMMENT ON COLUMN "initiative"."indirect_majority"       IS 'Same as "direct_majority", but also considering indirect beat paths';
   5.157 -COMMENT ON COLUMN "initiative"."schulze_rank"            IS 'Schulze-Ranking without tie-breaking';
   5.158 -COMMENT ON COLUMN "initiative"."better_than_status_quo"  IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
   5.159 -COMMENT ON COLUMN "initiative"."worse_than_status_quo"   IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
   5.160 -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';
   5.161 -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';
   5.162 -COMMENT ON COLUMN "initiative"."eligible"                IS 'Initiative is "attainable" and depending on selected policy has no "reverse_beat_path" or "multistage_majority"';
   5.163 -COMMENT ON COLUMN "initiative"."winner"                  IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
   5.164 -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';
   5.165 -
   5.166 -ALTER TABLE "battle" DROP CONSTRAINT "battle_pkey";
   5.167 -ALTER TABLE "battle" ALTER COLUMN "issue_id" SET NOT NULL;
   5.168 -ALTER TABLE "battle" ADD CONSTRAINT "initiative_ids_not_equal" CHECK (
   5.169 -  "winning_initiative_id" != "losing_initiative_id" OR
   5.170 -  ( ("winning_initiative_id" NOTNULL AND "losing_initiative_id" ISNULL) OR
   5.171 -    ("winning_initiative_id" ISNULL AND "losing_initiative_id" NOTNULL) ) );
   5.172 -
   5.173 -CREATE UNIQUE INDEX "battle_winning_losing_idx" ON "battle" ("issue_id", "winning_initiative_id", "losing_initiative_id");
   5.174 -CREATE UNIQUE INDEX "battle_winning_null_idx" ON "battle" ("issue_id", "winning_initiative_id") WHERE "losing_initiative_id" ISNULL;
   5.175 -CREATE UNIQUE INDEX "battle_null_losing_idx" ON "battle" ("issue_id", "losing_initiative_id") WHERE "winning_initiative_id" ISNULL;
   5.176 -
   5.177 -ALTER TABLE "suggestion" ADD COLUMN "draft_id" INT8;
   5.178 -ALTER TABLE "suggestion" ADD FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE;
   5.179 -ALTER TABLE "suggestion" ADD COLUMN "formatting_engine" TEXT;
   5.180 -ALTER TABLE "suggestion" RENAME COLUMN "description" TO "content";
   5.181 -
   5.182 -DROP TRIGGER "update_text_search_data" ON "suggestion";
   5.183 -
   5.184 -CREATE TRIGGER "update_text_search_data"
   5.185 -  BEFORE INSERT OR UPDATE ON "suggestion"
   5.186 -  FOR EACH ROW EXECUTE PROCEDURE
   5.187 -  tsvector_update_trigger('text_search_data', 'pg_catalog.simple',
   5.188 -    "name", "content");
   5.189 -
   5.190 -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")';
   5.191 -
   5.192 -CREATE TABLE "rendered_suggestion" (
   5.193 -        PRIMARY KEY ("suggestion_id", "format"),
   5.194 -        "suggestion_id"         INT8            REFERENCES "suggestion" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
   5.195 -        "format"                TEXT,
   5.196 -        "content"               TEXT            NOT NULL );
   5.197 -
   5.198 -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)';
   5.199 -
   5.200 -DROP TABLE "invite_code_unit";
   5.201 -
   5.202 -DROP VIEW "area_member_count";
   5.203 -
   5.204 -ALTER TABLE "membership" DROP COLUMN "autoreject";
   5.205 -
   5.206 -ALTER TABLE "interest" DROP COLUMN "autoreject";
   5.207 -ALTER TABLE "interest" DROP COLUMN "voting_requested";
   5.208 -
   5.209 -ALTER TABLE "supporter" DROP CONSTRAINT "supporter_initiative_id_fkey";
   5.210 -ALTER TABLE "supporter" ADD FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE;
   5.211 -
   5.212 -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")';
   5.213 -
   5.214 -ALTER TABLE "direct_interest_snapshot" DROP COLUMN "voting_requested";
   5.215 -ALTER TABLE "direct_voter" DROP COLUMN "autoreject";
   5.216 -
   5.217 -DROP TRIGGER "default_for_draft_id" ON "supporter";
   5.218 -DROP FUNCTION "supporter_default_for_draft_id_trigger"();
   5.219 -
   5.220 -CREATE FUNCTION "default_for_draft_id_trigger"()
   5.221 -  RETURNS TRIGGER
   5.222 -  LANGUAGE 'plpgsql' VOLATILE AS $$
   5.223 -    BEGIN
   5.224 -      IF NEW."draft_id" ISNULL THEN
   5.225 -        SELECT "id" INTO NEW."draft_id" FROM "current_draft"
   5.226 -          WHERE "initiative_id" = NEW."initiative_id";
   5.227 -      END IF;
   5.228 -      RETURN NEW;
   5.229 -    END;
   5.230 -  $$;
   5.231 -
   5.232 -CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "suggestion"
   5.233 -  FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
   5.234 -CREATE TRIGGER "default_for_draft_id" BEFORE INSERT OR UPDATE ON "supporter"
   5.235 -  FOR EACH ROW EXECUTE PROCEDURE "default_for_draft_id_trigger"();
   5.236 -
   5.237 -COMMENT ON FUNCTION "default_for_draft_id_trigger"() IS 'Implementation of trigger "default_for_draft" on tables "supporter" and "suggestion"';
   5.238 -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';
   5.239 -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';
   5.240 -
   5.241 -CREATE VIEW "area_member_count" AS
   5.242 -  SELECT
   5.243 -    "area"."id" AS "area_id",
   5.244 -    count("member"."id") AS "direct_member_count",
   5.245 -    coalesce(
   5.246 -      sum(
   5.247 -        CASE WHEN "member"."id" NOTNULL THEN
   5.248 -          "membership_weight"("area"."id", "member"."id")
   5.249 -        ELSE 0 END
   5.250 -      )
   5.251 -    ) AS "member_weight"
   5.252 -  FROM "area"
   5.253 -  LEFT JOIN "membership"
   5.254 -  ON "area"."id" = "membership"."area_id"
   5.255 -  LEFT JOIN "privilege"
   5.256 -  ON "privilege"."unit_id" = "area"."unit_id"
   5.257 -  AND "privilege"."member_id" = "membership"."member_id"
   5.258 -  AND "privilege"."voting_right"
   5.259 -  LEFT JOIN "member"
   5.260 -  ON "member"."id" = "privilege"."member_id"  -- NOTE: no membership here!
   5.261 -  AND "member"."active"
   5.262 -  GROUP BY "area"."id";
   5.263 -
   5.264 -COMMENT ON VIEW "area_member_count" IS 'View used to update "direct_member_count" and "member_weight" columns of table "area"';
   5.265 -
   5.266 -CREATE VIEW "battle_participant" AS
   5.267 -    SELECT "initiative"."id", "initiative"."issue_id"
   5.268 -    FROM "issue" JOIN "initiative"
   5.269 -    ON "issue"."id" = "initiative"."issue_id"
   5.270 -    WHERE "initiative"."admitted"
   5.271 -  UNION ALL
   5.272 -    SELECT NULL, "id" AS "issue_id"
   5.273 -    FROM "issue";
   5.274 -
   5.275 -COMMENT ON VIEW "battle_participant" IS 'Helper view for "battle_view" containing admitted initiatives plus virtual "status-quo" initiative denoted by NULL reference';
   5.276 -
   5.277 -CREATE VIEW "battle_view" AS
   5.278 -  SELECT
   5.279 -    "issue"."id" AS "issue_id",
   5.280 -    "winning_initiative"."id" AS "winning_initiative_id",
   5.281 -    "losing_initiative"."id" AS "losing_initiative_id",
   5.282 -    sum(
   5.283 -      CASE WHEN
   5.284 -        coalesce("better_vote"."grade", 0) >
   5.285 -        coalesce("worse_vote"."grade", 0)
   5.286 -      THEN "direct_voter"."weight" ELSE 0 END
   5.287 -    ) AS "count"
   5.288 -  FROM "issue"
   5.289 -  LEFT JOIN "direct_voter"
   5.290 -  ON "issue"."id" = "direct_voter"."issue_id"
   5.291 -  JOIN "battle_participant" AS "winning_initiative"
   5.292 -    ON "issue"."id" = "winning_initiative"."issue_id"
   5.293 -  JOIN "battle_participant" AS "losing_initiative"
   5.294 -    ON "issue"."id" = "losing_initiative"."issue_id"
   5.295 -  LEFT JOIN "vote" AS "better_vote"
   5.296 -    ON "direct_voter"."member_id" = "better_vote"."member_id"
   5.297 -    AND "winning_initiative"."id" = "better_vote"."initiative_id"
   5.298 -  LEFT JOIN "vote" AS "worse_vote"
   5.299 -    ON "direct_voter"."member_id" = "worse_vote"."member_id"
   5.300 -    AND "losing_initiative"."id" = "worse_vote"."initiative_id"
   5.301 -  WHERE "issue"."closed" NOTNULL
   5.302 -  AND "issue"."cleaned" ISNULL
   5.303 -  AND (
   5.304 -    "winning_initiative"."id" != "losing_initiative"."id" OR
   5.305 -    ( ("winning_initiative"."id" NOTNULL AND "losing_initiative"."id" ISNULL) OR
   5.306 -      ("winning_initiative"."id" ISNULL AND "losing_initiative"."id" NOTNULL) ) )
   5.307 -  GROUP BY
   5.308 -    "issue"."id",
   5.309 -    "winning_initiative"."id",
   5.310 -    "losing_initiative"."id";
   5.311 -
   5.312 -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';
   5.313 -
   5.314 -DROP FUNCTION "check_last_login"();
   5.315 -
   5.316 -CREATE FUNCTION "check_activity"()
   5.317 -  RETURNS VOID
   5.318 -  LANGUAGE 'plpgsql' VOLATILE AS $$
   5.319 -    DECLARE
   5.320 -      "system_setting_row" "system_setting"%ROWTYPE;
   5.321 -    BEGIN
   5.322 -      SELECT * INTO "system_setting_row" FROM "system_setting";
   5.323 -      LOCK TABLE "member" IN SHARE ROW EXCLUSIVE MODE;
   5.324 -      IF "system_setting_row"."member_ttl" NOTNULL THEN
   5.325 -        UPDATE "member" SET "active" = FALSE
   5.326 -          WHERE "active" = TRUE
   5.327 -          AND "last_activity" < (now() - "system_setting_row"."member_ttl")::DATE;
   5.328 -      END IF;
   5.329 -      RETURN;
   5.330 -    END;
   5.331 -  $$;
   5.332 -
   5.333 -COMMENT ON FUNCTION "check_activity"() IS 'Deactivates members when "last_activity" is older than "system_setting"."member_ttl".';
   5.334 -
   5.335 -CREATE OR REPLACE FUNCTION "calculate_member_counts"()
   5.336 -  RETURNS VOID
   5.337 -  LANGUAGE 'plpgsql' VOLATILE AS $$
   5.338 -    BEGIN
   5.339 -      LOCK TABLE "member"       IN SHARE MODE;
   5.340 -      LOCK TABLE "member_count" IN EXCLUSIVE MODE;
   5.341 -      LOCK TABLE "unit"         IN EXCLUSIVE MODE;
   5.342 -      LOCK TABLE "area"         IN EXCLUSIVE MODE;
   5.343 -      LOCK TABLE "privilege"    IN SHARE MODE;
   5.344 -      LOCK TABLE "membership"   IN SHARE MODE;
   5.345 -      DELETE FROM "member_count";
   5.346 -      INSERT INTO "member_count" ("total_count")
   5.347 -        SELECT "total_count" FROM "member_count_view";
   5.348 -      UPDATE "unit" SET "member_count" = "view"."member_count"
   5.349 -        FROM "unit_member_count" AS "view"
   5.350 -        WHERE "view"."unit_id" = "unit"."id";
   5.351 -      UPDATE "area" SET
   5.352 -        "direct_member_count" = "view"."direct_member_count",
   5.353 -        "member_weight"       = "view"."member_weight"
   5.354 -        FROM "area_member_count" AS "view"
   5.355 -        WHERE "view"."area_id" = "area"."id";
   5.356 -      RETURN;
   5.357 -    END;
   5.358 -  $$;
   5.359 -
   5.360 -CREATE OR REPLACE FUNCTION "create_interest_snapshot"
   5.361 -  ( "issue_id_p" "issue"."id"%TYPE )
   5.362 -  RETURNS VOID
   5.363 -  LANGUAGE 'plpgsql' VOLATILE AS $$
   5.364 -    DECLARE
   5.365 -      "member_id_v" "member"."id"%TYPE;
   5.366 -    BEGIN
   5.367 -      DELETE FROM "direct_interest_snapshot"
   5.368 -        WHERE "issue_id" = "issue_id_p"
   5.369 -        AND "event" = 'periodic';
   5.370 -      DELETE FROM "delegating_interest_snapshot"
   5.371 -        WHERE "issue_id" = "issue_id_p"
   5.372 -        AND "event" = 'periodic';
   5.373 -      DELETE FROM "direct_supporter_snapshot"
   5.374 -        WHERE "issue_id" = "issue_id_p"
   5.375 -        AND "event" = 'periodic';
   5.376 -      INSERT INTO "direct_interest_snapshot"
   5.377 -        ("issue_id", "event", "member_id")
   5.378 -        SELECT
   5.379 -          "issue_id_p"  AS "issue_id",
   5.380 -          'periodic'    AS "event",
   5.381 -          "member"."id" AS "member_id"
   5.382 -        FROM "issue"
   5.383 -        JOIN "area" ON "issue"."area_id" = "area"."id"
   5.384 -        JOIN "interest" ON "issue"."id" = "interest"."issue_id"
   5.385 -        JOIN "member" ON "interest"."member_id" = "member"."id"
   5.386 -        JOIN "privilege"
   5.387 -          ON "privilege"."unit_id" = "area"."unit_id"
   5.388 -          AND "privilege"."member_id" = "member"."id"
   5.389 -        WHERE "issue"."id" = "issue_id_p"
   5.390 -        AND "member"."active" AND "privilege"."voting_right";
   5.391 -      FOR "member_id_v" IN
   5.392 -        SELECT "member_id" FROM "direct_interest_snapshot"
   5.393 -        WHERE "issue_id" = "issue_id_p"
   5.394 -        AND "event" = 'periodic'
   5.395 -      LOOP
   5.396 -        UPDATE "direct_interest_snapshot" SET
   5.397 -          "weight" = 1 +
   5.398 -            "weight_of_added_delegations_for_interest_snapshot"(
   5.399 -              "issue_id_p",
   5.400 -              "member_id_v",
   5.401 -              '{}'
   5.402 -            )
   5.403 -          WHERE "issue_id" = "issue_id_p"
   5.404 -          AND "event" = 'periodic'
   5.405 -          AND "member_id" = "member_id_v";
   5.406 -      END LOOP;
   5.407 -      INSERT INTO "direct_supporter_snapshot"
   5.408 -        ( "issue_id", "initiative_id", "event", "member_id",
   5.409 -          "informed", "satisfied" )
   5.410 -        SELECT
   5.411 -          "issue_id_p"            AS "issue_id",
   5.412 -          "initiative"."id"       AS "initiative_id",
   5.413 -          'periodic'              AS "event",
   5.414 -          "supporter"."member_id" AS "member_id",
   5.415 -          "supporter"."draft_id" = "current_draft"."id" AS "informed",
   5.416 -          NOT EXISTS (
   5.417 -            SELECT NULL FROM "critical_opinion"
   5.418 -            WHERE "initiative_id" = "initiative"."id"
   5.419 -            AND "member_id" = "supporter"."member_id"
   5.420 -          ) AS "satisfied"
   5.421 -        FROM "initiative"
   5.422 -        JOIN "supporter"
   5.423 -        ON "supporter"."initiative_id" = "initiative"."id"
   5.424 -        JOIN "current_draft"
   5.425 -        ON "initiative"."id" = "current_draft"."initiative_id"
   5.426 -        JOIN "direct_interest_snapshot"
   5.427 -        ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
   5.428 -        AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
   5.429 -        AND "event" = 'periodic'
   5.430 -        WHERE "initiative"."issue_id" = "issue_id_p";
   5.431 -      RETURN;
   5.432 -    END;
   5.433 -  $$;
   5.434 -
   5.435 -CREATE OR REPLACE FUNCTION "create_snapshot"
   5.436 -  ( "issue_id_p" "issue"."id"%TYPE )
   5.437 -  RETURNS VOID
   5.438 -  LANGUAGE 'plpgsql' VOLATILE AS $$
   5.439 -    DECLARE
   5.440 -      "initiative_id_v"    "initiative"."id"%TYPE;
   5.441 -      "suggestion_id_v"    "suggestion"."id"%TYPE;
   5.442 -    BEGIN
   5.443 -      PERFORM "lock_issue"("issue_id_p");
   5.444 -      PERFORM "create_population_snapshot"("issue_id_p");
   5.445 -      PERFORM "create_interest_snapshot"("issue_id_p");
   5.446 -      UPDATE "issue" SET
   5.447 -        "snapshot" = now(),
   5.448 -        "latest_snapshot_event" = 'periodic',
   5.449 -        "population" = (
   5.450 -          SELECT coalesce(sum("weight"), 0)
   5.451 -          FROM "direct_population_snapshot"
   5.452 -          WHERE "issue_id" = "issue_id_p"
   5.453 -          AND "event" = 'periodic'
   5.454 -        )
   5.455 -        WHERE "id" = "issue_id_p";
   5.456 -      FOR "initiative_id_v" IN
   5.457 -        SELECT "id" FROM "initiative" WHERE "issue_id" = "issue_id_p"
   5.458 -      LOOP
   5.459 -        UPDATE "initiative" SET
   5.460 -          "supporter_count" = (
   5.461 -            SELECT coalesce(sum("di"."weight"), 0)
   5.462 -            FROM "direct_interest_snapshot" AS "di"
   5.463 -            JOIN "direct_supporter_snapshot" AS "ds"
   5.464 -            ON "di"."member_id" = "ds"."member_id"
   5.465 -            WHERE "di"."issue_id" = "issue_id_p"
   5.466 -            AND "di"."event" = 'periodic'
   5.467 -            AND "ds"."initiative_id" = "initiative_id_v"
   5.468 -            AND "ds"."event" = 'periodic'
   5.469 -          ),
   5.470 -          "informed_supporter_count" = (
   5.471 -            SELECT coalesce(sum("di"."weight"), 0)
   5.472 -            FROM "direct_interest_snapshot" AS "di"
   5.473 -            JOIN "direct_supporter_snapshot" AS "ds"
   5.474 -            ON "di"."member_id" = "ds"."member_id"
   5.475 -            WHERE "di"."issue_id" = "issue_id_p"
   5.476 -            AND "di"."event" = 'periodic'
   5.477 -            AND "ds"."initiative_id" = "initiative_id_v"
   5.478 -            AND "ds"."event" = 'periodic'
   5.479 -            AND "ds"."informed"
   5.480 -          ),
   5.481 -          "satisfied_supporter_count" = (
   5.482 -            SELECT coalesce(sum("di"."weight"), 0)
   5.483 -            FROM "direct_interest_snapshot" AS "di"
   5.484 -            JOIN "direct_supporter_snapshot" AS "ds"
   5.485 -            ON "di"."member_id" = "ds"."member_id"
   5.486 -            WHERE "di"."issue_id" = "issue_id_p"
   5.487 -            AND "di"."event" = 'periodic'
   5.488 -            AND "ds"."initiative_id" = "initiative_id_v"
   5.489 -            AND "ds"."event" = 'periodic'
   5.490 -            AND "ds"."satisfied"
   5.491 -          ),
   5.492 -          "satisfied_informed_supporter_count" = (
   5.493 -            SELECT coalesce(sum("di"."weight"), 0)
   5.494 -            FROM "direct_interest_snapshot" AS "di"
   5.495 -            JOIN "direct_supporter_snapshot" AS "ds"
   5.496 -            ON "di"."member_id" = "ds"."member_id"
   5.497 -            WHERE "di"."issue_id" = "issue_id_p"
   5.498 -            AND "di"."event" = 'periodic'
   5.499 -            AND "ds"."initiative_id" = "initiative_id_v"
   5.500 -            AND "ds"."event" = 'periodic'
   5.501 -            AND "ds"."informed"
   5.502 -            AND "ds"."satisfied"
   5.503 -          )
   5.504 -          WHERE "id" = "initiative_id_v";
   5.505 -        FOR "suggestion_id_v" IN
   5.506 -          SELECT "id" FROM "suggestion"
   5.507 -          WHERE "initiative_id" = "initiative_id_v"
   5.508 -        LOOP
   5.509 -          UPDATE "suggestion" SET
   5.510 -            "minus2_unfulfilled_count" = (
   5.511 -              SELECT coalesce(sum("snapshot"."weight"), 0)
   5.512 -              FROM "issue" CROSS JOIN "opinion"
   5.513 -              JOIN "direct_interest_snapshot" AS "snapshot"
   5.514 -              ON "snapshot"."issue_id" = "issue"."id"
   5.515 -              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   5.516 -              AND "snapshot"."member_id" = "opinion"."member_id"
   5.517 -              WHERE "issue"."id" = "issue_id_p"
   5.518 -              AND "opinion"."suggestion_id" = "suggestion_id_v"
   5.519 -              AND "opinion"."degree" = -2
   5.520 -              AND "opinion"."fulfilled" = FALSE
   5.521 -            ),
   5.522 -            "minus2_fulfilled_count" = (
   5.523 -              SELECT coalesce(sum("snapshot"."weight"), 0)
   5.524 -              FROM "issue" CROSS JOIN "opinion"
   5.525 -              JOIN "direct_interest_snapshot" AS "snapshot"
   5.526 -              ON "snapshot"."issue_id" = "issue"."id"
   5.527 -              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   5.528 -              AND "snapshot"."member_id" = "opinion"."member_id"
   5.529 -              WHERE "issue"."id" = "issue_id_p"
   5.530 -              AND "opinion"."suggestion_id" = "suggestion_id_v"
   5.531 -              AND "opinion"."degree" = -2
   5.532 -              AND "opinion"."fulfilled" = TRUE
   5.533 -            ),
   5.534 -            "minus1_unfulfilled_count" = (
   5.535 -              SELECT coalesce(sum("snapshot"."weight"), 0)
   5.536 -              FROM "issue" CROSS JOIN "opinion"
   5.537 -              JOIN "direct_interest_snapshot" AS "snapshot"
   5.538 -              ON "snapshot"."issue_id" = "issue"."id"
   5.539 -              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   5.540 -              AND "snapshot"."member_id" = "opinion"."member_id"
   5.541 -              WHERE "issue"."id" = "issue_id_p"
   5.542 -              AND "opinion"."suggestion_id" = "suggestion_id_v"
   5.543 -              AND "opinion"."degree" = -1
   5.544 -              AND "opinion"."fulfilled" = FALSE
   5.545 -            ),
   5.546 -            "minus1_fulfilled_count" = (
   5.547 -              SELECT coalesce(sum("snapshot"."weight"), 0)
   5.548 -              FROM "issue" CROSS JOIN "opinion"
   5.549 -              JOIN "direct_interest_snapshot" AS "snapshot"
   5.550 -              ON "snapshot"."issue_id" = "issue"."id"
   5.551 -              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   5.552 -              AND "snapshot"."member_id" = "opinion"."member_id"
   5.553 -              WHERE "issue"."id" = "issue_id_p"
   5.554 -              AND "opinion"."suggestion_id" = "suggestion_id_v"
   5.555 -              AND "opinion"."degree" = -1
   5.556 -              AND "opinion"."fulfilled" = TRUE
   5.557 -            ),
   5.558 -            "plus1_unfulfilled_count" = (
   5.559 -              SELECT coalesce(sum("snapshot"."weight"), 0)
   5.560 -              FROM "issue" CROSS JOIN "opinion"
   5.561 -              JOIN "direct_interest_snapshot" AS "snapshot"
   5.562 -              ON "snapshot"."issue_id" = "issue"."id"
   5.563 -              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   5.564 -              AND "snapshot"."member_id" = "opinion"."member_id"
   5.565 -              WHERE "issue"."id" = "issue_id_p"
   5.566 -              AND "opinion"."suggestion_id" = "suggestion_id_v"
   5.567 -              AND "opinion"."degree" = 1
   5.568 -              AND "opinion"."fulfilled" = FALSE
   5.569 -            ),
   5.570 -            "plus1_fulfilled_count" = (
   5.571 -              SELECT coalesce(sum("snapshot"."weight"), 0)
   5.572 -              FROM "issue" CROSS JOIN "opinion"
   5.573 -              JOIN "direct_interest_snapshot" AS "snapshot"
   5.574 -              ON "snapshot"."issue_id" = "issue"."id"
   5.575 -              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   5.576 -              AND "snapshot"."member_id" = "opinion"."member_id"
   5.577 -              WHERE "issue"."id" = "issue_id_p"
   5.578 -              AND "opinion"."suggestion_id" = "suggestion_id_v"
   5.579 -              AND "opinion"."degree" = 1
   5.580 -              AND "opinion"."fulfilled" = TRUE
   5.581 -            ),
   5.582 -            "plus2_unfulfilled_count" = (
   5.583 -              SELECT coalesce(sum("snapshot"."weight"), 0)
   5.584 -              FROM "issue" CROSS JOIN "opinion"
   5.585 -              JOIN "direct_interest_snapshot" AS "snapshot"
   5.586 -              ON "snapshot"."issue_id" = "issue"."id"
   5.587 -              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   5.588 -              AND "snapshot"."member_id" = "opinion"."member_id"
   5.589 -              WHERE "issue"."id" = "issue_id_p"
   5.590 -              AND "opinion"."suggestion_id" = "suggestion_id_v"
   5.591 -              AND "opinion"."degree" = 2
   5.592 -              AND "opinion"."fulfilled" = FALSE
   5.593 -            ),
   5.594 -            "plus2_fulfilled_count" = (
   5.595 -              SELECT coalesce(sum("snapshot"."weight"), 0)
   5.596 -              FROM "issue" CROSS JOIN "opinion"
   5.597 -              JOIN "direct_interest_snapshot" AS "snapshot"
   5.598 -              ON "snapshot"."issue_id" = "issue"."id"
   5.599 -              AND "snapshot"."event" = "issue"."latest_snapshot_event"
   5.600 -              AND "snapshot"."member_id" = "opinion"."member_id"
   5.601 -              WHERE "issue"."id" = "issue_id_p"
   5.602 -              AND "opinion"."suggestion_id" = "suggestion_id_v"
   5.603 -              AND "opinion"."degree" = 2
   5.604 -              AND "opinion"."fulfilled" = TRUE
   5.605 -            )
   5.606 -            WHERE "suggestion"."id" = "suggestion_id_v";
   5.607 -        END LOOP;
   5.608 -      END LOOP;
   5.609 -      RETURN;
   5.610 -    END;
   5.611 -  $$;
   5.612 -
   5.613 -CREATE OR REPLACE FUNCTION "close_voting"("issue_id_p" "issue"."id"%TYPE)
   5.614 -  RETURNS VOID
   5.615 -  LANGUAGE 'plpgsql' VOLATILE AS $$
   5.616 -    DECLARE
   5.617 -      "area_id_v"   "area"."id"%TYPE;
   5.618 -      "unit_id_v"   "unit"."id"%TYPE;
   5.619 -      "member_id_v" "member"."id"%TYPE;
   5.620 -    BEGIN
   5.621 -      PERFORM "lock_issue"("issue_id_p");
   5.622 -      SELECT "area_id" INTO "area_id_v" FROM "issue" WHERE "id" = "issue_id_p";
   5.623 -      SELECT "unit_id" INTO "unit_id_v" FROM "area"  WHERE "id" = "area_id_v";
   5.624 -      -- delete delegating votes (in cases of manual reset of issue state):
   5.625 -      DELETE FROM "delegating_voter"
   5.626 -        WHERE "issue_id" = "issue_id_p";
   5.627 -      -- delete votes from non-privileged voters:
   5.628 -      DELETE FROM "direct_voter"
   5.629 -        USING (
   5.630 -          SELECT
   5.631 -            "direct_voter"."member_id"
   5.632 -          FROM "direct_voter"
   5.633 -          JOIN "member" ON "direct_voter"."member_id" = "member"."id"
   5.634 -          LEFT JOIN "privilege"
   5.635 -          ON "privilege"."unit_id" = "unit_id_v"
   5.636 -          AND "privilege"."member_id" = "direct_voter"."member_id"
   5.637 -          WHERE "direct_voter"."issue_id" = "issue_id_p" AND (
   5.638 -            "member"."active" = FALSE OR
   5.639 -            "privilege"."voting_right" ISNULL OR
   5.640 -            "privilege"."voting_right" = FALSE
   5.641 -          )
   5.642 -        ) AS "subquery"
   5.643 -        WHERE "direct_voter"."issue_id" = "issue_id_p"
   5.644 -        AND "direct_voter"."member_id" = "subquery"."member_id";
   5.645 -      -- consider delegations:
   5.646 -      UPDATE "direct_voter" SET "weight" = 1
   5.647 -        WHERE "issue_id" = "issue_id_p";
   5.648 -      PERFORM "add_vote_delegations"("issue_id_p");
   5.649 -      -- set voter count and mark issue as being calculated:
   5.650 -      UPDATE "issue" SET
   5.651 -        "state"  = 'calculation',
   5.652 -        "closed" = now(),
   5.653 -        "voter_count" = (
   5.654 -          SELECT coalesce(sum("weight"), 0)
   5.655 -          FROM "direct_voter" WHERE "issue_id" = "issue_id_p"
   5.656 -        )
   5.657 -        WHERE "id" = "issue_id_p";
   5.658 -      -- materialize battle_view:
   5.659 -      -- NOTE: "closed" column of issue must be set at this point
   5.660 -      DELETE FROM "battle" WHERE "issue_id" = "issue_id_p";
   5.661 -      INSERT INTO "battle" (
   5.662 -        "issue_id",
   5.663 -        "winning_initiative_id", "losing_initiative_id",
   5.664 -        "count"
   5.665 -      ) SELECT
   5.666 -        "issue_id",
   5.667 -        "winning_initiative_id", "losing_initiative_id",
   5.668 -        "count"
   5.669 -        FROM "battle_view" WHERE "issue_id" = "issue_id_p";
   5.670 -      -- copy "positive_votes" and "negative_votes" from "battle" table:
   5.671 -      UPDATE "initiative" SET
   5.672 -        "positive_votes" = "battle_win"."count",
   5.673 -        "negative_votes" = "battle_lose"."count"
   5.674 -        FROM "battle" AS "battle_win", "battle" AS "battle_lose"
   5.675 -        WHERE
   5.676 -          "battle_win"."issue_id" = "issue_id_p" AND
   5.677 -          "battle_win"."winning_initiative_id" = "initiative"."id" AND
   5.678 -          "battle_win"."losing_initiative_id" ISNULL AND
   5.679 -          "battle_lose"."issue_id" = "issue_id_p" AND
   5.680 -          "battle_lose"."losing_initiative_id" = "initiative"."id" AND
   5.681 -          "battle_lose"."winning_initiative_id" ISNULL;
   5.682 -    END;
   5.683 -  $$;
   5.684 -
   5.685 -DROP FUNCTION "array_init_string"(INTEGER);
   5.686 -DROP FUNCTION "square_matrix_init_string"(INTEGER);
   5.687 -
   5.688 -CREATE OR REPLACE FUNCTION "calculate_ranks"("issue_id_p" "issue"."id"%TYPE)
   5.689 -  RETURNS VOID
   5.690 -  LANGUAGE 'plpgsql' VOLATILE AS $$
   5.691 -    DECLARE
   5.692 -      "issue_row"         "issue"%ROWTYPE;
   5.693 -      "policy_row"        "policy"%ROWTYPE;
   5.694 -      "dimension_v"       INTEGER;
   5.695 -      "vote_matrix"       INT4[][];  -- absolute votes
   5.696 -      "matrix"            INT8[][];  -- defeat strength / best paths
   5.697 -      "i"                 INTEGER;
   5.698 -      "j"                 INTEGER;
   5.699 -      "k"                 INTEGER;
   5.700 -      "battle_row"        "battle"%ROWTYPE;
   5.701 -      "rank_ary"          INT4[];
   5.702 -      "rank_v"            INT4;
   5.703 -      "done_v"            INTEGER;
   5.704 -      "winners_ary"       INTEGER[];
   5.705 -      "initiative_id_v"   "initiative"."id"%TYPE;
   5.706 -    BEGIN
   5.707 -      SELECT * INTO "issue_row"
   5.708 -        FROM "issue" WHERE "id" = "issue_id_p"
   5.709 -        FOR UPDATE;
   5.710 -      SELECT * INTO "policy_row"
   5.711 -        FROM "policy" WHERE "id" = "issue_row"."policy_id";
   5.712 -      SELECT count(1) INTO "dimension_v"
   5.713 -        FROM "battle_participant" WHERE "issue_id" = "issue_id_p";
   5.714 -      -- Create "vote_matrix" with absolute number of votes in pairwise
   5.715 -      -- comparison:
   5.716 -      "vote_matrix" := array_fill(NULL::INT4, ARRAY["dimension_v", "dimension_v"]);
   5.717 -      "i" := 1;
   5.718 -      "j" := 2;
   5.719 -      FOR "battle_row" IN
   5.720 -        SELECT * FROM "battle" WHERE "issue_id" = "issue_id_p"
   5.721 -        ORDER BY
   5.722 -        "winning_initiative_id" NULLS LAST,
   5.723 -        "losing_initiative_id" NULLS LAST
   5.724 -      LOOP
   5.725 -        "vote_matrix"["i"]["j"] := "battle_row"."count";
   5.726 -        IF "j" = "dimension_v" THEN
   5.727 -          "i" := "i" + 1;
   5.728 -          "j" := 1;
   5.729 -        ELSE
   5.730 -          "j" := "j" + 1;
   5.731 -          IF "j" = "i" THEN
   5.732 -            "j" := "j" + 1;
   5.733 -          END IF;
   5.734 -        END IF;
   5.735 -      END LOOP;
   5.736 -      IF "i" != "dimension_v" OR "j" != "dimension_v" + 1 THEN
   5.737 -        RAISE EXCEPTION 'Wrong battle count (should not happen)';
   5.738 -      END IF;
   5.739 -      -- Store defeat strengths in "matrix" using "defeat_strength"
   5.740 -      -- function:
   5.741 -      "matrix" := array_fill(NULL::INT8, ARRAY["dimension_v", "dimension_v"]);
   5.742 -      "i" := 1;
   5.743 -      LOOP
   5.744 -        "j" := 1;
   5.745 -        LOOP
   5.746 -          IF "i" != "j" THEN
   5.747 -            "matrix"["i"]["j"] := "defeat_strength"(
   5.748 -              "vote_matrix"["i"]["j"],
   5.749 -              "vote_matrix"["j"]["i"]
   5.750 -            );
   5.751 -          END IF;
   5.752 -          EXIT WHEN "j" = "dimension_v";
   5.753 -          "j" := "j" + 1;
   5.754 -        END LOOP;
   5.755 -        EXIT WHEN "i" = "dimension_v";
   5.756 -        "i" := "i" + 1;
   5.757 -      END LOOP;
   5.758 -      -- Find best paths:
   5.759 -      "i" := 1;
   5.760 -      LOOP
   5.761 -        "j" := 1;
   5.762 -        LOOP
   5.763 -          IF "i" != "j" THEN
   5.764 -            "k" := 1;
   5.765 -            LOOP
   5.766 -              IF "i" != "k" AND "j" != "k" THEN
   5.767 -                IF "matrix"["j"]["i"] < "matrix"["i"]["k"] THEN
   5.768 -                  IF "matrix"["j"]["i"] > "matrix"["j"]["k"] THEN
   5.769 -                    "matrix"["j"]["k"] := "matrix"["j"]["i"];
   5.770 -                  END IF;
   5.771 -                ELSE
   5.772 -                  IF "matrix"["i"]["k"] > "matrix"["j"]["k"] THEN
   5.773 -                    "matrix"["j"]["k"] := "matrix"["i"]["k"];
   5.774 -                  END IF;
   5.775 -                END IF;
   5.776 -              END IF;
   5.777 -              EXIT WHEN "k" = "dimension_v";
   5.778 -              "k" := "k" + 1;
   5.779 -            END LOOP;
   5.780 -          END IF;
   5.781 -          EXIT WHEN "j" = "dimension_v";
   5.782 -          "j" := "j" + 1;
   5.783 -        END LOOP;
   5.784 -        EXIT WHEN "i" = "dimension_v";
   5.785 -        "i" := "i" + 1;
   5.786 -      END LOOP;
   5.787 -      -- Determine order of winners:
   5.788 -      "rank_ary" := array_fill(NULL::INT4, ARRAY["dimension_v"]);
   5.789 -      "rank_v" := 1;
   5.790 -      "done_v" := 0;
   5.791 -      LOOP
   5.792 -        "winners_ary" := '{}';
   5.793 -        "i" := 1;
   5.794 -        LOOP
   5.795 -          IF "rank_ary"["i"] ISNULL THEN
   5.796 -            "j" := 1;
   5.797 -            LOOP
   5.798 -              IF
   5.799 -                "i" != "j" AND
   5.800 -                "rank_ary"["j"] ISNULL AND
   5.801 -                "matrix"["j"]["i"] > "matrix"["i"]["j"]
   5.802 -              THEN
   5.803 -                -- someone else is better
   5.804 -                EXIT;
   5.805 -              END IF;
   5.806 -              IF "j" = "dimension_v" THEN
   5.807 -                -- noone is better
   5.808 -                "winners_ary" := "winners_ary" || "i";
   5.809 -                EXIT;
   5.810 -              END IF;
   5.811 -              "j" := "j" + 1;
   5.812 -            END LOOP;
   5.813 -          END IF;
   5.814 -          EXIT WHEN "i" = "dimension_v";
   5.815 -          "i" := "i" + 1;
   5.816 -        END LOOP;
   5.817 -        "i" := 1;
   5.818 -        LOOP
   5.819 -          "rank_ary"["winners_ary"["i"]] := "rank_v";
   5.820 -          "done_v" := "done_v" + 1;
   5.821 -          EXIT WHEN "i" = array_upper("winners_ary", 1);
   5.822 -          "i" := "i" + 1;
   5.823 -        END LOOP;
   5.824 -        EXIT WHEN "done_v" = "dimension_v";
   5.825 -        "rank_v" := "rank_v" + 1;
   5.826 -      END LOOP;
   5.827 -      -- write preliminary results:
   5.828 -      "i" := 1;
   5.829 -      FOR "initiative_id_v" IN
   5.830 -        SELECT "id" FROM "initiative"
   5.831 -        WHERE "issue_id" = "issue_id_p" AND "admitted"
   5.832 -        ORDER BY "id"
   5.833 -      LOOP
   5.834 -        UPDATE "initiative" SET
   5.835 -          "direct_majority" =
   5.836 -            CASE WHEN "policy_row"."direct_majority_strict" THEN
   5.837 -              "positive_votes" * "policy_row"."direct_majority_den" >
   5.838 -              "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
   5.839 -            ELSE
   5.840 -              "positive_votes" * "policy_row"."direct_majority_den" >=
   5.841 -              "policy_row"."direct_majority_num" * ("positive_votes"+"negative_votes")
   5.842 -            END
   5.843 -            AND "positive_votes" >= "policy_row"."direct_majority_positive"
   5.844 -            AND "issue_row"."voter_count"-"negative_votes" >=
   5.845 -                "policy_row"."direct_majority_non_negative",
   5.846 -            "indirect_majority" =
   5.847 -            CASE WHEN "policy_row"."indirect_majority_strict" THEN
   5.848 -              "positive_votes" * "policy_row"."indirect_majority_den" >
   5.849 -              "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
   5.850 -            ELSE
   5.851 -              "positive_votes" * "policy_row"."indirect_majority_den" >=
   5.852 -              "policy_row"."indirect_majority_num" * ("positive_votes"+"negative_votes")
   5.853 -            END
   5.854 -            AND "positive_votes" >= "policy_row"."indirect_majority_positive"
   5.855 -            AND "issue_row"."voter_count"-"negative_votes" >=
   5.856 -                "policy_row"."indirect_majority_non_negative",
   5.857 -          "schulze_rank"           = "rank_ary"["i"],
   5.858 -          "better_than_status_quo" = "rank_ary"["i"] < "rank_ary"["dimension_v"],
   5.859 -          "worse_than_status_quo"  = "rank_ary"["i"] > "rank_ary"["dimension_v"],
   5.860 -          "multistage_majority"    = "rank_ary"["i"] >= "rank_ary"["dimension_v"],
   5.861 -          "reverse_beat_path"      = "matrix"["dimension_v"]["i"] >= 0,
   5.862 -          "winner"                 = FALSE
   5.863 -          WHERE "id" = "initiative_id_v";
   5.864 -        "i" := "i" + 1;
   5.865 -      END LOOP;
   5.866 -      IF "i" != "dimension_v" THEN
   5.867 -        RAISE EXCEPTION 'Wrong winner count (should not happen)';
   5.868 -      END IF;
   5.869 -      -- take indirect majorities into account:
   5.870 -      LOOP
   5.871 -        UPDATE "initiative" SET "indirect_majority" = TRUE
   5.872 -          FROM (
   5.873 -            SELECT "new_initiative"."id" AS "initiative_id"
   5.874 -            FROM "initiative" "old_initiative"
   5.875 -            JOIN "initiative" "new_initiative"
   5.876 -              ON "new_initiative"."issue_id" = "issue_id_p"
   5.877 -              AND "new_initiative"."indirect_majority" = FALSE
   5.878 -            JOIN "battle" "battle_win"
   5.879 -              ON "battle_win"."issue_id" = "issue_id_p"
   5.880 -              AND "battle_win"."winning_initiative_id" = "new_initiative"."id"
   5.881 -              AND "battle_win"."losing_initiative_id" = "old_initiative"."id"
   5.882 -            JOIN "battle" "battle_lose"
   5.883 -              ON "battle_lose"."issue_id" = "issue_id_p"
   5.884 -              AND "battle_lose"."losing_initiative_id" = "new_initiative"."id"
   5.885 -              AND "battle_lose"."winning_initiative_id" = "old_initiative"."id"
   5.886 -            WHERE "old_initiative"."issue_id" = "issue_id_p"
   5.887 -            AND "old_initiative"."indirect_majority" = TRUE
   5.888 -            AND CASE WHEN "policy_row"."indirect_majority_strict" THEN
   5.889 -              "battle_win"."count" * "policy_row"."indirect_majority_den" >
   5.890 -              "policy_row"."indirect_majority_num" *
   5.891 -              ("battle_win"."count"+"battle_lose"."count")
   5.892 -            ELSE
   5.893 -              "battle_win"."count" * "policy_row"."indirect_majority_den" >=
   5.894 -              "policy_row"."indirect_majority_num" *
   5.895 -              ("battle_win"."count"+"battle_lose"."count")
   5.896 -            END
   5.897 -            AND "battle_win"."count" >= "policy_row"."indirect_majority_positive"
   5.898 -            AND "issue_row"."voter_count"-"battle_lose"."count" >=
   5.899 -                "policy_row"."indirect_majority_non_negative"
   5.900 -          ) AS "subquery"
   5.901 -          WHERE "id" = "subquery"."initiative_id";
   5.902 -        EXIT WHEN NOT FOUND;
   5.903 -      END LOOP;
   5.904 -      -- set "multistage_majority" for remaining matching initiatives:
   5.905 -       UPDATE "initiative" SET "multistage_majority" = TRUE
   5.906 -        FROM (
   5.907 -          SELECT "losing_initiative"."id" AS "initiative_id"
   5.908 -          FROM "initiative" "losing_initiative"
   5.909 -          JOIN "initiative" "winning_initiative"
   5.910 -            ON "winning_initiative"."issue_id" = "issue_id_p"
   5.911 -            AND "winning_initiative"."admitted"
   5.912 -          JOIN "battle" "battle_win"
   5.913 -            ON "battle_win"."issue_id" = "issue_id_p"
   5.914 -            AND "battle_win"."winning_initiative_id" = "winning_initiative"."id"
   5.915 -            AND "battle_win"."losing_initiative_id" = "losing_initiative"."id"
   5.916 -          JOIN "battle" "battle_lose"
   5.917 -            ON "battle_lose"."issue_id" = "issue_id_p"
   5.918 -            AND "battle_lose"."losing_initiative_id" = "winning_initiative"."id"
   5.919 -            AND "battle_lose"."winning_initiative_id" = "losing_initiative"."id"
   5.920 -          WHERE "losing_initiative"."issue_id" = "issue_id_p"
   5.921 -          AND "losing_initiative"."admitted"
   5.922 -          AND "winning_initiative"."schulze_rank" <
   5.923 -              "losing_initiative"."schulze_rank"
   5.924 -          AND "battle_win"."count" > "battle_lose"."count"
   5.925 -          AND (
   5.926 -            "battle_win"."count" > "winning_initiative"."positive_votes" OR
   5.927 -            "battle_lose"."count" < "losing_initiative"."negative_votes" )
   5.928 -        ) AS "subquery"
   5.929 -        WHERE "id" = "subquery"."initiative_id";
   5.930 -      -- mark eligible initiatives:
   5.931 -      UPDATE "initiative" SET "eligible" = TRUE
   5.932 -        WHERE "issue_id" = "issue_id_p"
   5.933 -        AND "initiative"."direct_majority"
   5.934 -        AND "initiative"."indirect_majority"
   5.935 -        AND "initiative"."better_than_status_quo"
   5.936 -        AND (
   5.937 -          "policy_row"."no_multistage_majority" = FALSE OR
   5.938 -          "initiative"."multistage_majority" = FALSE )
   5.939 -        AND (
   5.940 -          "policy_row"."no_reverse_beat_path" = FALSE OR
   5.941 -          "initiative"."reverse_beat_path" = FALSE );
   5.942 -      -- mark final winner:
   5.943 -      UPDATE "initiative" SET "winner" = TRUE
   5.944 -        FROM (
   5.945 -          SELECT "id" AS "initiative_id"
   5.946 -          FROM "initiative"
   5.947 -          WHERE "issue_id" = "issue_id_p" AND "eligible"
   5.948 -          ORDER BY "schulze_rank", "id"
   5.949 -          LIMIT 1
   5.950 -        ) AS "subquery"
   5.951 -        WHERE "id" = "subquery"."initiative_id";
   5.952 -      -- write (final) ranks:
   5.953 -      "rank_v" := 1;
   5.954 -      FOR "initiative_id_v" IN
   5.955 -        SELECT "id"
   5.956 -        FROM "initiative"
   5.957 -        WHERE "issue_id" = "issue_id_p" AND "admitted"
   5.958 -        ORDER BY
   5.959 -          "winner" DESC,
   5.960 -          ("direct_majority" AND "indirect_majority") DESC,
   5.961 -          "schulze_rank",
   5.962 -          "id"
   5.963 -      LOOP
   5.964 -        UPDATE "initiative" SET "rank" = "rank_v"
   5.965 -          WHERE "id" = "initiative_id_v";
   5.966 -        "rank_v" := "rank_v" + 1;
   5.967 -      END LOOP;
   5.968 -      -- set schulze rank of status quo and mark issue as finished:
   5.969 -      UPDATE "issue" SET
   5.970 -        "status_quo_schulze_rank" = "rank_ary"["dimension_v"],
   5.971 -        "state" =
   5.972 -          CASE WHEN EXISTS (
   5.973 -            SELECT NULL FROM "initiative"
   5.974 -            WHERE "issue_id" = "issue_id_p" AND "winner"
   5.975 -          ) THEN
   5.976 -            'finished_with_winner'::"issue_state"
   5.977 -          ELSE
   5.978 -            'finished_without_winner'::"issue_state"
   5.979 -          END,
   5.980 -        "ranks_available" = TRUE
   5.981 -        WHERE "id" = "issue_id_p";
   5.982 -      RETURN;
   5.983 -    END;
   5.984 -  $$;
   5.985 -
   5.986 -CREATE OR REPLACE FUNCTION "check_issue"
   5.987 -  ( "issue_id_p" "issue"."id"%TYPE )
   5.988 -  RETURNS VOID
   5.989 -  LANGUAGE 'plpgsql' VOLATILE AS $$
   5.990 -    DECLARE
   5.991 -      "issue_row"         "issue"%ROWTYPE;
   5.992 -      "policy_row"        "policy"%ROWTYPE;
   5.993 -    BEGIN
   5.994 -      PERFORM "lock_issue"("issue_id_p");
   5.995 -      SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
   5.996 -      -- only process open issues:
   5.997 -      IF "issue_row"."closed" ISNULL THEN
   5.998 -        SELECT * INTO "policy_row" FROM "policy"
   5.999 -          WHERE "id" = "issue_row"."policy_id";
  5.1000 -        -- create a snapshot, unless issue is already fully frozen:
  5.1001 -        IF "issue_row"."fully_frozen" ISNULL THEN
  5.1002 -          PERFORM "create_snapshot"("issue_id_p");
  5.1003 -          SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  5.1004 -        END IF;
  5.1005 -        -- eventually close or accept issues, which have not been accepted:
  5.1006 -        IF "issue_row"."accepted" ISNULL THEN
  5.1007 -          IF EXISTS (
  5.1008 -            SELECT NULL FROM "initiative"
  5.1009 -            WHERE "issue_id" = "issue_id_p"
  5.1010 -            AND "supporter_count" > 0
  5.1011 -            AND "supporter_count" * "policy_row"."issue_quorum_den"
  5.1012 -            >= "issue_row"."population" * "policy_row"."issue_quorum_num"
  5.1013 -          ) THEN
  5.1014 -            -- accept issues, if supporter count is high enough
  5.1015 -            PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
  5.1016 -            -- NOTE: "issue_row" used later
  5.1017 -            "issue_row"."state" := 'discussion';
  5.1018 -            "issue_row"."accepted" := now();
  5.1019 -            UPDATE "issue" SET
  5.1020 -              "state"    = "issue_row"."state",
  5.1021 -              "accepted" = "issue_row"."accepted"
  5.1022 -              WHERE "id" = "issue_row"."id";
  5.1023 -          ELSIF
  5.1024 -            now() >= "issue_row"."created" + "issue_row"."admission_time"
  5.1025 -          THEN
  5.1026 -            -- close issues, if admission time has expired
  5.1027 -            PERFORM "set_snapshot_event"("issue_id_p", 'end_of_admission');
  5.1028 -            UPDATE "issue" SET
  5.1029 -              "state" = 'canceled_issue_not_accepted',
  5.1030 -              "closed" = now()
  5.1031 -              WHERE "id" = "issue_row"."id";
  5.1032 -          END IF;
  5.1033 -        END IF;
  5.1034 -        -- eventually half freeze issues:
  5.1035 -        IF
  5.1036 -          -- NOTE: issue can't be closed at this point, if it has been accepted
  5.1037 -          "issue_row"."accepted" NOTNULL AND
  5.1038 -          "issue_row"."half_frozen" ISNULL
  5.1039 -        THEN
  5.1040 -          IF
  5.1041 -            now() >= "issue_row"."accepted" + "issue_row"."discussion_time"
  5.1042 -          THEN
  5.1043 -            PERFORM "set_snapshot_event"("issue_id_p", 'half_freeze');
  5.1044 -            -- NOTE: "issue_row" used later
  5.1045 -            "issue_row"."state" := 'verification';
  5.1046 -            "issue_row"."half_frozen" := now();
  5.1047 -            UPDATE "issue" SET
  5.1048 -              "state"       = "issue_row"."state",
  5.1049 -              "half_frozen" = "issue_row"."half_frozen"
  5.1050 -              WHERE "id" = "issue_row"."id";
  5.1051 -          END IF;
  5.1052 -        END IF;
  5.1053 -        -- close issues after some time, if all initiatives have been revoked:
  5.1054 -        IF
  5.1055 -          "issue_row"."closed" ISNULL AND
  5.1056 -          NOT EXISTS (
  5.1057 -            -- all initiatives are revoked
  5.1058 -            SELECT NULL FROM "initiative"
  5.1059 -            WHERE "issue_id" = "issue_id_p" AND "revoked" ISNULL
  5.1060 -          ) AND (
  5.1061 -            -- and issue has not been accepted yet
  5.1062 -            "issue_row"."accepted" ISNULL OR
  5.1063 -            NOT EXISTS (
  5.1064 -              -- or no initiatives have been revoked lately
  5.1065 -              SELECT NULL FROM "initiative"
  5.1066 -              WHERE "issue_id" = "issue_id_p"
  5.1067 -              AND now() < "revoked" + "issue_row"."verification_time"
  5.1068 -            ) OR (
  5.1069 -              -- or verification time has elapsed
  5.1070 -              "issue_row"."half_frozen" NOTNULL AND
  5.1071 -              "issue_row"."fully_frozen" ISNULL AND
  5.1072 -              now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
  5.1073 -            )
  5.1074 -          )
  5.1075 -        THEN
  5.1076 -          -- NOTE: "issue_row" used later
  5.1077 -          IF "issue_row"."accepted" ISNULL THEN
  5.1078 -            "issue_row"."state" := 'canceled_revoked_before_accepted';
  5.1079 -          ELSIF "issue_row"."half_frozen" ISNULL THEN
  5.1080 -            "issue_row"."state" := 'canceled_after_revocation_during_discussion';
  5.1081 -          ELSE
  5.1082 -            "issue_row"."state" := 'canceled_after_revocation_during_verification';
  5.1083 -          END IF;
  5.1084 -          "issue_row"."closed" := now();
  5.1085 -          UPDATE "issue" SET
  5.1086 -            "state"  = "issue_row"."state",
  5.1087 -            "closed" = "issue_row"."closed"
  5.1088 -            WHERE "id" = "issue_row"."id";
  5.1089 -        END IF;
  5.1090 -        -- fully freeze issue after verification time:
  5.1091 -        IF
  5.1092 -          "issue_row"."half_frozen" NOTNULL AND
  5.1093 -          "issue_row"."fully_frozen" ISNULL AND
  5.1094 -          "issue_row"."closed" ISNULL AND
  5.1095 -          now() >= "issue_row"."half_frozen" + "issue_row"."verification_time"
  5.1096 -        THEN
  5.1097 -          PERFORM "freeze_after_snapshot"("issue_id_p");
  5.1098 -          -- NOTE: "issue" might change, thus "issue_row" has to be updated below
  5.1099 -        END IF;
  5.1100 -        SELECT * INTO "issue_row" FROM "issue" WHERE "id" = "issue_id_p";
  5.1101 -        -- close issue by calling close_voting(...) after voting time:
  5.1102 -        IF
  5.1103 -          "issue_row"."closed" ISNULL AND
  5.1104 -          "issue_row"."fully_frozen" NOTNULL AND
  5.1105 -          now() >= "issue_row"."fully_frozen" + "issue_row"."voting_time"
  5.1106 -        THEN
  5.1107 -          PERFORM "close_voting"("issue_id_p");
  5.1108 -          -- calculate ranks will not consume much time and can be done now
  5.1109 -          PERFORM "calculate_ranks"("issue_id_p");
  5.1110 -        END IF;
  5.1111 -      END IF;
  5.1112 -      RETURN;
  5.1113 -    END;
  5.1114 -  $$;
  5.1115 -
  5.1116 -CREATE OR REPLACE FUNCTION "check_everything"()
  5.1117 -  RETURNS VOID
  5.1118 -  LANGUAGE 'plpgsql' VOLATILE AS $$
  5.1119 -    DECLARE
  5.1120 -      "issue_id_v" "issue"."id"%TYPE;
  5.1121 -    BEGIN
  5.1122 -      PERFORM "check_activity"();
  5.1123 -      PERFORM "calculate_member_counts"();
  5.1124 -      FOR "issue_id_v" IN SELECT "id" FROM "open_issue" LOOP
  5.1125 -        PERFORM "check_issue"("issue_id_v");
  5.1126 -      END LOOP;
  5.1127 -      FOR "issue_id_v" IN SELECT "id" FROM "issue_with_ranks_missing" LOOP
  5.1128 -        PERFORM "calculate_ranks"("issue_id_v");
  5.1129 -      END LOOP;
  5.1130 -      RETURN;
  5.1131 -    END;
  5.1132 -  $$;
  5.1133 -
  5.1134 -CREATE OR REPLACE FUNCTION "delete_member"("member_id_p" "member"."id"%TYPE)
  5.1135 -  RETURNS VOID
  5.1136 -  LANGUAGE 'plpgsql' VOLATILE AS $$
  5.1137 -    BEGIN
  5.1138 -      UPDATE "member" SET
  5.1139 -        "last_login"                   = NULL,
  5.1140 -        "login"                        = NULL,
  5.1141 -        "password"                     = NULL,
  5.1142 -        "locked"                       = TRUE,
  5.1143 -        "active"                       = FALSE,
  5.1144 -        "notify_email"                 = NULL,
  5.1145 -        "notify_email_unconfirmed"     = NULL,
  5.1146 -        "notify_email_secret"          = NULL,
  5.1147 -        "notify_email_secret_expiry"   = NULL,
  5.1148 -        "notify_email_lock_expiry"     = NULL,
  5.1149 -        "password_reset_secret"        = NULL,
  5.1150 -        "password_reset_secret_expiry" = NULL,
  5.1151 -        "organizational_unit"          = NULL,
  5.1152 -        "internal_posts"               = NULL,
  5.1153 -        "realname"                     = NULL,
  5.1154 -        "birthday"                     = NULL,
  5.1155 -        "address"                      = NULL,
  5.1156 -        "email"                        = NULL,
  5.1157 -        "xmpp_address"                 = NULL,
  5.1158 -        "website"                      = NULL,
  5.1159 -        "phone"                        = NULL,
  5.1160 -        "mobile_phone"                 = NULL,
  5.1161 -        "profession"                   = NULL,
  5.1162 -        "external_memberships"         = NULL,
  5.1163 -        "external_posts"               = NULL,
  5.1164 -        "statement"                    = NULL
  5.1165 -        WHERE "id" = "member_id_p";
  5.1166 -      -- "text_search_data" is updated by triggers
  5.1167 -      DELETE FROM "setting"            WHERE "member_id" = "member_id_p";
  5.1168 -      DELETE FROM "setting_map"        WHERE "member_id" = "member_id_p";
  5.1169 -      DELETE FROM "member_relation_setting" WHERE "member_id" = "member_id_p";
  5.1170 -      DELETE FROM "member_image"       WHERE "member_id" = "member_id_p";
  5.1171 -      DELETE FROM "contact"            WHERE "member_id" = "member_id_p";
  5.1172 -      DELETE FROM "ignored_member"     WHERE "member_id" = "member_id_p";
  5.1173 -      DELETE FROM "area_setting"       WHERE "member_id" = "member_id_p";
  5.1174 -      DELETE FROM "issue_setting"      WHERE "member_id" = "member_id_p";
  5.1175 -      DELETE FROM "ignored_initiative" WHERE "member_id" = "member_id_p";
  5.1176 -      DELETE FROM "initiative_setting" WHERE "member_id" = "member_id_p";
  5.1177 -      DELETE FROM "suggestion_setting" WHERE "member_id" = "member_id_p";
  5.1178 -      DELETE FROM "membership"         WHERE "member_id" = "member_id_p";
  5.1179 -      DELETE FROM "delegation"         WHERE "truster_id" = "member_id_p";
  5.1180 -      DELETE FROM "non_voter"          WHERE "member_id" = "member_id_p";
  5.1181 -      DELETE FROM "direct_voter" USING "issue"
  5.1182 -        WHERE "direct_voter"."issue_id" = "issue"."id"
  5.1183 -        AND "issue"."closed" ISNULL
  5.1184 -        AND "member_id" = "member_id_p";
  5.1185 -      RETURN;
  5.1186 -    END;
  5.1187 -  $$;
  5.1188 -
  5.1189 -CREATE OR REPLACE FUNCTION "delete_private_data"()
  5.1190 -  RETURNS VOID
  5.1191 -  LANGUAGE 'plpgsql' VOLATILE AS $$
  5.1192 -    BEGIN
  5.1193 -      UPDATE "member" SET
  5.1194 -        "last_login"                   = NULL,
  5.1195 -        "login"                        = NULL,
  5.1196 -        "password"                     = NULL,
  5.1197 -        "notify_email"                 = NULL,
  5.1198 -        "notify_email_unconfirmed"     = NULL,
  5.1199 -        "notify_email_secret"          = NULL,
  5.1200 -        "notify_email_secret_expiry"   = NULL,
  5.1201 -        "notify_email_lock_expiry"     = NULL,
  5.1202 -        "password_reset_secret"        = NULL,
  5.1203 -        "password_reset_secret_expiry" = NULL,
  5.1204 -        "organizational_unit"          = NULL,
  5.1205 -        "internal_posts"               = NULL,
  5.1206 -        "realname"                     = NULL,
  5.1207 -        "birthday"                     = NULL,
  5.1208 -        "address"                      = NULL,
  5.1209 -        "email"                        = NULL,
  5.1210 -        "xmpp_address"                 = NULL,
  5.1211 -        "website"                      = NULL,
  5.1212 -        "phone"                        = NULL,
  5.1213 -        "mobile_phone"                 = NULL,
  5.1214 -        "profession"                   = NULL,
  5.1215 -        "external_memberships"         = NULL,
  5.1216 -        "external_posts"               = NULL,
  5.1217 -        "statement"                    = NULL;
  5.1218 -      -- "text_search_data" is updated by triggers
  5.1219 -      DELETE FROM "invite_code";
  5.1220 -      DELETE FROM "setting";
  5.1221 -      DELETE FROM "setting_map";
  5.1222 -      DELETE FROM "member_relation_setting";
  5.1223 -      DELETE FROM "member_image";
  5.1224 -      DELETE FROM "contact";
  5.1225 -      DELETE FROM "ignored_member";
  5.1226 -      DELETE FROM "area_setting";
  5.1227 -      DELETE FROM "issue_setting";
  5.1228 -      DELETE FROM "ignored_initiative";
  5.1229 -      DELETE FROM "initiative_setting";
  5.1230 -      DELETE FROM "suggestion_setting";
  5.1231 -      DELETE FROM "non_voter";
  5.1232 -      DELETE FROM "direct_voter" USING "issue"
  5.1233 -        WHERE "direct_voter"."issue_id" = "issue"."id"
  5.1234 -        AND "issue"."closed" ISNULL;
  5.1235 -      RETURN;
  5.1236 -    END;
  5.1237 -  $$;
  5.1238 -
  5.1239 -COMMIT;
  5.1240 -
  5.1241 -BEGIN;
  5.1242 -
  5.1243 -UPDATE "member" SET
  5.1244 -  "activated" = "created",
  5.1245 -  "last_activity" = CASE WHEN "active" THEN
  5.1246 -    coalesce("last_login"::DATE, now())
  5.1247 -  ELSE
  5.1248 -    "last_login"::DATE
  5.1249 -  END;
  5.1250 -
  5.1251 -UPDATE "member" SET
  5.1252 -  "created" = "invite_code"."created",
  5.1253 -  "invite_code" = "invite_code"."code",
  5.1254 -  "admin_comment" = "invite_code"."comment"
  5.1255 -  FROM "invite_code"
  5.1256 -  WHERE "member"."id" = "invite_code"."member_id";
  5.1257 -
  5.1258 -DROP TABLE "invite_code";
  5.1259 -
  5.1260 -UPDATE "initiative" SET
  5.1261 -    "direct_majority"        = "rank" NOTNULL,
  5.1262 -    "indirect_majority"      = "rank" NOTNULL,
  5.1263 -    "schulze_rank"           = "rank",
  5.1264 -    "better_than_status_quo" = "rank" NOTNULL,
  5.1265 -    "worse_than_status_quo"  = "rank" ISNULL,
  5.1266 -    "reverse_beat_path"      = "rank" ISNULL,
  5.1267 -    "multistage_majority"    = "rank" ISNULL,
  5.1268 -    "eligible"               = "rank" NOTNULL,
  5.1269 -    "winner"                 = ("rank" = 1)
  5.1270 -  FROM "issue"
  5.1271 -  WHERE "issue"."id" = "initiative"."issue_id"
  5.1272 -  AND "issue"."state" IN ('finished_without_winner', 'finished_with_winner')
  5.1273 -  AND "initiative"."admitted";
  5.1274 -
  5.1275 -UPDATE "issue" SET "status_quo_schulze_rank" = "subquery"."rank"
  5.1276 -  FROM (
  5.1277 -    SELECT
  5.1278 -      "issue"."id" AS "issue_id",
  5.1279 -      COALESCE(max("initiative"."rank") + 1, 1) AS "rank"
  5.1280 -    FROM "issue" JOIN "initiative"
  5.1281 -    ON "issue"."id" = "initiative"."issue_id"
  5.1282 -    WHERE "issue"."state" IN ('finished_without_winner', 'finished_with_winner')
  5.1283 -    AND "initiative"."admitted"
  5.1284 -    GROUP BY "issue"."id"
  5.1285 -  ) AS "subquery"
  5.1286 -  WHERE "issue"."id" = "subquery"."issue_id";
  5.1287 -
  5.1288 -CREATE FUNCTION "update__set_remaining_ranks"("issue_id_p" "issue"."id"%TYPE)
  5.1289 -  RETURNS VOID
  5.1290 -  LANGUAGE 'plpgsql' AS $$
  5.1291 -    DECLARE
  5.1292 -      "rank_v"          INT4;
  5.1293 -      "initiative_id_v" INT4;
  5.1294 -    BEGIN
  5.1295 -      SELECT "status_quo_schulze_rank" INTO "rank_v"
  5.1296 -        FROM "issue" WHERE "id" = "issue_id_p";
  5.1297 -      FOR "initiative_id_v" IN
  5.1298 -        SELECT "id" FROM "initiative"
  5.1299 -        WHERE "issue_id" = "issue_id_p" AND "admitted" AND "rank" ISNULL
  5.1300 -        ORDER BY "vote_ratio"("positive_votes", "negative_votes") DESC
  5.1301 -      LOOP
  5.1302 -        UPDATE "initiative" SET
  5.1303 -          "schulze_rank" = "rank_v" + 1,
  5.1304 -          "rank"         = "rank_v"
  5.1305 -          WHERE "id" = "initiative_id_v";
  5.1306 -        "rank_v" := "rank_v" + 1;
  5.1307 -      END LOOP;
  5.1308 -      RETURN;
  5.1309 -    END;
  5.1310 -  $$;
  5.1311 -
  5.1312 -SELECT "update__set_remaining_ranks"("id") FROM "issue"
  5.1313 -  WHERE "state" IN ('finished_without_winner', 'finished_with_winner');
  5.1314 -
  5.1315 -DROP FUNCTION "update__set_remaining_ranks"("issue"."id"%TYPE);
  5.1316 -
  5.1317 -UPDATE "suggestion" SET "draft_id" = "subquery"."draft_id"
  5.1318 -  FROM (
  5.1319 -    SELECT DISTINCT ON ("suggestion"."id")
  5.1320 -      "suggestion"."id" AS "suggestion_id",
  5.1321 -      "draft"."id" AS "draft_id"
  5.1322 -    FROM "suggestion" JOIN "draft"
  5.1323 -    ON "suggestion"."initiative_id" = "draft"."initiative_id"
  5.1324 -    WHERE "draft"."created" <= "suggestion"."created"
  5.1325 -    ORDER BY "suggestion"."id", "draft"."created" DESC
  5.1326 -  ) AS "subquery"
  5.1327 -  WHERE "suggestion"."id" = "subquery"."suggestion_id";
  5.1328 -
  5.1329 -COMMIT;
  5.1330 -
  5.1331 -ALTER TABLE "member" ADD CONSTRAINT "active_requires_activated_and_last_activity"
  5.1332 -  CHECK ("active" = FALSE OR ("activated" NOTNULL AND "last_activity" NOTNULL));
  5.1333 -ALTER TABLE "suggestion" ALTER COLUMN "draft_id" SET NOT NULL;

Impressum / About Us