liquid_feedback_core

annotate update/core-update.v2.0.0-v2.0.1.sql @ 211:b52a65f5b1d3

Update script from v2.0.0 to v2.0.1
author jbe
date Sat Jan 21 01:47:09 2012 +0100 (2012-01-21)
parents eee75cff3e5a
children c23b288fd771
rev   line source
jbe@205 1 BEGIN;
jbe@205 2
jbe@211 3 CREATE OR REPLACE VIEW "liquid_feedback_version" AS
jbe@211 4 SELECT * FROM (VALUES ('2.0.1', 2, 0, 1))
jbe@211 5 AS "subquery"("string", "major", "minor", "revision");
jbe@205 6
jbe@205 7 ALTER TABLE "issue" ALTER "state" SET DEFAULT 'admission'; -- fixes wrong update script from v1.3.1 to v1.4.0
jbe@205 8
jbe@211 9 COMMENT ON COLUMN "member"."activated" IS 'Timestamp of first activation of account (i.e. usage of "invite_code"); required to be set for "active" members';
jbe@211 10 COMMENT ON COLUMN "member"."statement" IS 'Freely chosen text of the member for his/her profile';
jbe@211 11
jbe@211 12 COMMENT ON COLUMN "policy"."admission_time" IS 'Maximum duration of issue state ''admission''; Maximum time an issue stays open without being "accepted"';
jbe@211 13 COMMENT ON COLUMN "policy"."discussion_time" IS 'Duration of issue state ''discussion''; Regular time until an issue is "half_frozen" after being "accepted"';
jbe@211 14 COMMENT ON COLUMN "policy"."verification_time" IS 'Duration of issue state ''verification''; Regular time until an issue is "fully_frozen" (e.g. entering issue state ''voting'') after being "half_frozen"';
jbe@211 15 COMMENT ON COLUMN "policy"."voting_time" IS 'Duration of issue state ''voting''; Time after an issue is "fully_frozen" but not "closed" (duration of issue state ''voting'')';
jbe@211 16 COMMENT ON COLUMN "policy"."issue_quorum_num" IS 'Numerator of potential supporter quorum to be reached by one initiative of an issue to be "accepted" and enter issue state ''discussion''';
jbe@211 17 COMMENT ON COLUMN "policy"."issue_quorum_den" IS 'Denominator of potential supporter quorum to be reached by one initiative of an issue to be "accepted" and enter issue state ''discussion''';
jbe@211 18
jbe@211 19 COMMENT ON COLUMN "unit"."active" IS 'TRUE means new issues can be created in areas of this area';
jbe@211 20
jbe@211 21 CREATE TABLE "unit_setting" (
jbe@211 22 PRIMARY KEY ("member_id", "key", "unit_id"),
jbe@211 23 "member_id" INT4 REFERENCES "member" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@211 24 "key" TEXT NOT NULL,
jbe@211 25 "unit_id" INT4 REFERENCES "unit" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
jbe@211 26 "value" TEXT NOT NULL );
jbe@211 27
jbe@211 28 COMMENT ON TABLE "unit_setting" IS 'Place for frontend to store unit specific settings of members as strings';
jbe@211 29
jbe@211 30 COMMENT ON COLUMN "initiative"."discussion_url" IS 'URL pointing to a discussion platform for this initiative';
jbe@211 31 COMMENT ON COLUMN "initiative"."revoked" IS 'Point in time, when one initiator decided to revoke the initiative';
jbe@211 32 COMMENT ON COLUMN "initiative"."revoked_by_member_id" IS 'Member, who decided to revoke the initiative';
jbe@211 33 COMMENT ON COLUMN "initiative"."admitted" IS 'TRUE, if initiative reaches the "initiative_quorum" when freezing the issue';
jbe@211 34 COMMENT ON COLUMN "initiative"."positive_votes" IS 'Calculated from table "direct_voter"';
jbe@211 35 COMMENT ON COLUMN "initiative"."negative_votes" IS 'Calculated from table "direct_voter"';
jbe@211 36 COMMENT ON COLUMN "initiative"."direct_majority" IS 'TRUE, if "positive_votes"/("positive_votes"+"negative_votes") is strictly greater or greater-equal than "direct_majority_num"/"direct_majority_den", and "positive_votes" is greater-equal than "direct_majority_positive", and ("positive_votes"+abstentions) is greater-equal than "direct_majority_non_negative"';
jbe@211 37 COMMENT ON COLUMN "initiative"."indirect_majority" IS 'Same as "direct_majority", but also considering indirect beat paths';
jbe@211 38 COMMENT ON COLUMN "initiative"."schulze_rank" IS 'Schulze-Ranking without tie-breaking';
jbe@211 39 COMMENT ON COLUMN "initiative"."better_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking better than the status quo (without tie-breaking)';
jbe@211 40 COMMENT ON COLUMN "initiative"."worse_than_status_quo" IS 'TRUE, if initiative has a schulze-ranking worse than the status quo (without tie-breaking)';
jbe@211 41 COMMENT ON COLUMN "initiative"."reverse_beat_path" IS 'TRUE, if there is a beat path (may include ties) from this initiative to the status quo';
jbe@211 42 COMMENT ON COLUMN "initiative"."multistage_majority" IS 'TRUE, if either (a) this initiative has no better rank than the status quo, or (b) there exists a better ranked initiative X, which directly beats this initiative, and either more voters prefer X to this initiative than voters preferring X to the status quo or less voters prefer this initiative to X than voters preferring the status quo to X';
jbe@211 43 COMMENT ON COLUMN "initiative"."eligible" IS 'Initiative has a "direct_majority" and an "indirect_majority", is "better_than_status_quo" and depending on selected policy the initiative has no "reverse_beat_path" or "multistage_majority"';
jbe@211 44 COMMENT ON COLUMN "initiative"."winner" IS 'Winner is the "eligible" initiative with best "schulze_rank" and in case of ties with lowest "id"';
jbe@211 45 COMMENT ON COLUMN "initiative"."rank" IS 'Unique ranking for all "admitted" initiatives per issue; lower rank is better; a winner always has rank 1, but rank 1 does not imply that an initiative is winner; initiatives with "direct_majority" AND "indirect_majority" always have a better (lower) rank than other initiatives';
jbe@211 46
jbe@211 47 COMMENT ON COLUMN "privilege"."admin_manager" IS 'Grant/revoke admin privileges to/from other members';
jbe@211 48 COMMENT ON COLUMN "privilege"."unit_manager" IS 'Create and disable sub units';
jbe@211 49 COMMENT ON COLUMN "privilege"."area_manager" IS 'Create and disable areas and set area parameters';
jbe@211 50 COMMENT ON COLUMN "privilege"."voting_right_manager" IS 'Select which members are allowed to discuss and vote within the unit';
jbe@211 51
jbe@211 52 COMMENT ON COLUMN "supporter"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
jbe@211 53
jbe@211 54 ALTER TABLE "direct_supporter_snapshot" ADD COLUMN "draft_id" INT8;
jbe@211 55
jbe@211 56 UPDATE "direct_supporter_snapshot" SET "draft_id" = "supporter"."draft_id" FROM "supporter" WHERE "direct_supporter_snapshot"."initiative_id" = "supporter"."initiative_id" AND "direct_supporter_snapshot"."member_id" = "supporter"."member_id";
jbe@211 57 UPDATE "direct_supporter_snapshot" SET "draft_id" = "current_draft"."id" FROM "current_draft" WHERE "direct_supporter_snapshot"."initiative_id" = "current_draft"."initiative_id" AND "direct_supporter_snapshot"."draft_id" ISNULL;
jbe@211 58
jbe@211 59 ALTER TABLE "direct_supporter_snapshot" ADD FOREIGN KEY ("initiative_id", "draft_id") REFERENCES "draft" ("initiative_id", "id") ON DELETE NO ACTION ON UPDATE CASCADE;
jbe@211 60 ALTER TABLE "direct_supporter_snapshot" ALTER COLUMN "draft_id" SET NOT NULL;
jbe@211 61
jbe@211 62 COMMENT ON COLUMN "direct_supporter_snapshot"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
jbe@211 63
jbe@211 64 COMMENT ON COLUMN "direct_voter"."weight" IS 'Weight of member (1 or higher) according to "delegating_voter" table';
jbe@211 65
jbe@211 66 COMMENT ON COLUMN "vote"."issue_id" IS 'WARNING: No index: For selections use column "initiative_id" and join via table "initiative" where neccessary';
jbe@211 67 COMMENT ON COLUMN "vote"."grade" IS 'Values smaller than zero mean reject, values greater than zero mean acceptance, zero or missing row means abstention. Preferences are expressed by different positive or negative numbers.';
jbe@211 68
jbe@211 69 CREATE OR REPLACE FUNCTION "create_interest_snapshot"
jbe@211 70 ( "issue_id_p" "issue"."id"%TYPE )
jbe@211 71 RETURNS VOID
jbe@211 72 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@211 73 DECLARE
jbe@211 74 "member_id_v" "member"."id"%TYPE;
jbe@211 75 BEGIN
jbe@211 76 DELETE FROM "direct_interest_snapshot"
jbe@211 77 WHERE "issue_id" = "issue_id_p"
jbe@211 78 AND "event" = 'periodic';
jbe@211 79 DELETE FROM "delegating_interest_snapshot"
jbe@211 80 WHERE "issue_id" = "issue_id_p"
jbe@211 81 AND "event" = 'periodic';
jbe@211 82 DELETE FROM "direct_supporter_snapshot"
jbe@211 83 WHERE "issue_id" = "issue_id_p"
jbe@211 84 AND "event" = 'periodic';
jbe@211 85 INSERT INTO "direct_interest_snapshot"
jbe@211 86 ("issue_id", "event", "member_id")
jbe@211 87 SELECT
jbe@211 88 "issue_id_p" AS "issue_id",
jbe@211 89 'periodic' AS "event",
jbe@211 90 "member"."id" AS "member_id"
jbe@211 91 FROM "issue"
jbe@211 92 JOIN "area" ON "issue"."area_id" = "area"."id"
jbe@211 93 JOIN "interest" ON "issue"."id" = "interest"."issue_id"
jbe@211 94 JOIN "member" ON "interest"."member_id" = "member"."id"
jbe@211 95 JOIN "privilege"
jbe@211 96 ON "privilege"."unit_id" = "area"."unit_id"
jbe@211 97 AND "privilege"."member_id" = "member"."id"
jbe@211 98 WHERE "issue"."id" = "issue_id_p"
jbe@211 99 AND "member"."active" AND "privilege"."voting_right";
jbe@211 100 FOR "member_id_v" IN
jbe@211 101 SELECT "member_id" FROM "direct_interest_snapshot"
jbe@211 102 WHERE "issue_id" = "issue_id_p"
jbe@211 103 AND "event" = 'periodic'
jbe@211 104 LOOP
jbe@211 105 UPDATE "direct_interest_snapshot" SET
jbe@211 106 "weight" = 1 +
jbe@211 107 "weight_of_added_delegations_for_interest_snapshot"(
jbe@211 108 "issue_id_p",
jbe@211 109 "member_id_v",
jbe@211 110 '{}'
jbe@211 111 )
jbe@211 112 WHERE "issue_id" = "issue_id_p"
jbe@211 113 AND "event" = 'periodic'
jbe@211 114 AND "member_id" = "member_id_v";
jbe@211 115 END LOOP;
jbe@211 116 INSERT INTO "direct_supporter_snapshot"
jbe@211 117 ( "issue_id", "initiative_id", "event", "member_id",
jbe@211 118 "draft_id", "informed", "satisfied" )
jbe@211 119 SELECT
jbe@211 120 "issue_id_p" AS "issue_id",
jbe@211 121 "initiative"."id" AS "initiative_id",
jbe@211 122 'periodic' AS "event",
jbe@211 123 "supporter"."member_id" AS "member_id",
jbe@211 124 "supporter"."draft_id" AS "draft_id",
jbe@211 125 "supporter"."draft_id" = "current_draft"."id" AS "informed",
jbe@211 126 NOT EXISTS (
jbe@211 127 SELECT NULL FROM "critical_opinion"
jbe@211 128 WHERE "initiative_id" = "initiative"."id"
jbe@211 129 AND "member_id" = "supporter"."member_id"
jbe@211 130 ) AS "satisfied"
jbe@211 131 FROM "initiative"
jbe@211 132 JOIN "supporter"
jbe@211 133 ON "supporter"."initiative_id" = "initiative"."id"
jbe@211 134 JOIN "current_draft"
jbe@211 135 ON "initiative"."id" = "current_draft"."initiative_id"
jbe@211 136 JOIN "direct_interest_snapshot"
jbe@211 137 ON "supporter"."member_id" = "direct_interest_snapshot"."member_id"
jbe@211 138 AND "initiative"."issue_id" = "direct_interest_snapshot"."issue_id"
jbe@211 139 AND "event" = 'periodic'
jbe@211 140 WHERE "initiative"."issue_id" = "issue_id_p";
jbe@211 141 RETURN;
jbe@211 142 END;
jbe@211 143 $$;
jbe@211 144
jbe@211 145 CREATE OR REPLACE FUNCTION "delete_private_data"()
jbe@211 146 RETURNS VOID
jbe@211 147 LANGUAGE 'plpgsql' VOLATILE AS $$
jbe@211 148 BEGIN
jbe@211 149 UPDATE "member" SET
jbe@211 150 "invite_code" = NULL,
jbe@211 151 "last_login" = NULL,
jbe@211 152 "login" = NULL,
jbe@211 153 "password" = NULL,
jbe@211 154 "notify_email" = NULL,
jbe@211 155 "notify_email_unconfirmed" = NULL,
jbe@211 156 "notify_email_secret" = NULL,
jbe@211 157 "notify_email_secret_expiry" = NULL,
jbe@211 158 "notify_email_lock_expiry" = NULL,
jbe@211 159 "password_reset_secret" = NULL,
jbe@211 160 "password_reset_secret_expiry" = NULL,
jbe@211 161 "organizational_unit" = NULL,
jbe@211 162 "internal_posts" = NULL,
jbe@211 163 "realname" = NULL,
jbe@211 164 "birthday" = NULL,
jbe@211 165 "address" = NULL,
jbe@211 166 "email" = NULL,
jbe@211 167 "xmpp_address" = NULL,
jbe@211 168 "website" = NULL,
jbe@211 169 "phone" = NULL,
jbe@211 170 "mobile_phone" = NULL,
jbe@211 171 "profession" = NULL,
jbe@211 172 "external_memberships" = NULL,
jbe@211 173 "external_posts" = NULL,
jbe@211 174 "statement" = NULL;
jbe@211 175 -- "text_search_data" is updated by triggers
jbe@211 176 DELETE FROM "setting";
jbe@211 177 DELETE FROM "setting_map";
jbe@211 178 DELETE FROM "member_relation_setting";
jbe@211 179 DELETE FROM "member_image";
jbe@211 180 DELETE FROM "contact";
jbe@211 181 DELETE FROM "ignored_member";
jbe@211 182 DELETE FROM "area_setting";
jbe@211 183 DELETE FROM "issue_setting";
jbe@211 184 DELETE FROM "ignored_initiative";
jbe@211 185 DELETE FROM "initiative_setting";
jbe@211 186 DELETE FROM "suggestion_setting";
jbe@211 187 DELETE FROM "non_voter";
jbe@211 188 DELETE FROM "direct_voter" USING "issue"
jbe@211 189 WHERE "direct_voter"."issue_id" = "issue"."id"
jbe@211 190 AND "issue"."closed" ISNULL;
jbe@211 191 RETURN;
jbe@211 192 END;
jbe@211 193 $$;
jbe@211 194
jbe@205 195 COMMIT;

Impressum / About Us