pgsql/update_tables_0.5.x-0.6.pgsql
branchv0.6.x
changeset 528 4b8c3f51d7da
parent 525 3acbff727626
child 530 95dd123b552e
equal deleted inserted replaced
527:e09139525580 528:4b8c3f51d7da
    89 -- Adjust tables (quota)
    89 -- Adjust tables (quota)
    90 ALTER TABLE domain_data ADD COLUMN qid bigint NOT NULL DEFAULT 1;
    90 ALTER TABLE domain_data ADD COLUMN qid bigint NOT NULL DEFAULT 1;
    91 ALTER TABLE domain_data ADD CONSTRAINT fkey_domain_data_qid_quotalimit
    91 ALTER TABLE domain_data ADD CONSTRAINT fkey_domain_data_qid_quotalimit
    92     FOREIGN KEY (qid) REFERENCES quotalimit (qid);
    92     FOREIGN KEY (qid) REFERENCES quotalimit (qid);
    93 
    93 
    94 ALTER TABLE users ADD COLUMN qid bigint NULL DEFAULT NULL;
    94 ALTER TABLE users ADD COLUMN qid bigint NOT NULL DEFAULT 1;
    95 ALTER TABLE users ADD CONSTRAINT fkey_users_qid_quotalimit
    95 ALTER TABLE users ADD CONSTRAINT fkey_users_qid_quotalimit
    96     FOREIGN KEY (qid) REFERENCES quotalimit (qid);
    96     FOREIGN KEY (qid) REFERENCES quotalimit (qid);
    97 
    97 
    98 CREATE TABLE userquota_11 (
    98 CREATE TABLE userquota_11 (
    99     uid         bigint NOT NULL,
    99     uid         bigint NOT NULL,
   123 -- Adjust tables (services)
   123 -- Adjust tables (services)
   124 ALTER TABLE domain_data ADD COLUMN ssid bigint NOT NULL DEFAULT 1;
   124 ALTER TABLE domain_data ADD COLUMN ssid bigint NOT NULL DEFAULT 1;
   125 ALTER TABLE domain_data ADD CONSTRAINT fkey_domain_data_ssid_service_set
   125 ALTER TABLE domain_data ADD CONSTRAINT fkey_domain_data_ssid_service_set
   126     FOREIGN KEY (ssid) REFERENCES service_set (ssid);
   126     FOREIGN KEY (ssid) REFERENCES service_set (ssid);
   127 
   127 
   128 ALTER TABLE users ADD COLUMN ssid bigint NULL DEFAULT NULL;
   128 ALTER TABLE users ADD COLUMN ssid bigint NOT NULL DEFAULT 1;
   129 -- save current service sets
   129 -- save current service sets
   130 UPDATE users u
   130 UPDATE users u
   131    SET ssid = ss.ssid
   131    SET ssid = ss.ssid
   132   FROM service_set ss
   132   FROM service_set ss
   133  WHERE ss.smtp = u.smtp
   133  WHERE ss.smtp = u.smtp
   142 ALTER TABLE users ADD CONSTRAINT fkey_users_ssid_service_set
   142 ALTER TABLE users ADD CONSTRAINT fkey_users_ssid_service_set
   143     FOREIGN KEY (ssid) REFERENCES service_set (ssid);
   143     FOREIGN KEY (ssid) REFERENCES service_set (ssid);
   144 
   144 
   145 -- ---
   145 -- ---
   146 -- Catchall
   146 -- Catchall
   147 -- ---
       
   148 -- Quota/Service/Transport inheritance
       
   149 -- ---
       
   150 ALTER TABLE users ALTER COLUMN tid DROP NULL;
       
   151 ALTER TABLE users ALTER COLUMN tid SET DEFAULT NULL;
       
   152 -- The qid and ssid columns have already been defined accordingly above.
       
   153 -- The rest of the logic will take place in the functions.
       
   154 
       
   155 -- While qid and ssid are new and it's perfectly okay for existing users to
       
   156 -- get NULL values (i.e. inherit from the domain's default), tid existed in
       
   157 -- vmm 0.5.x. A sensible way forward seems thus to NULL all user records' tid
       
   158 -- fields where the tid duplicates the value stored in the domain's record.
       
   159 UPDATE users
       
   160    SET tid = NULL
       
   161  WHERE tid = (SELECT tid
       
   162                 FROM domain_data
       
   163                WHERE domain_data.gid = users.gid);
       
   164 
       
   165 -- ---
   147 -- ---
   166 
   148 
   167 CREATE TABLE catchall (
   149 CREATE TABLE catchall (
   168     gid         bigint NOT NULL,
   150     gid         bigint NOT NULL,
   169     destination varchar(320) NOT NULL,
   151     destination varchar(320) NOT NULL,
   293         record dovecotpassword;
   275         record dovecotpassword;
   294         userid varchar(320) := localpart || '@' || the_domain;
   276         userid varchar(320) := localpart || '@' || the_domain;
   295     BEGIN
   277     BEGIN
   296         FOR record IN
   278         FOR record IN
   297             SELECT userid, passwd, smtp, pop3, imap, managesieve
   279             SELECT userid, passwd, smtp, pop3, imap, managesieve
   298               FROM users, service_set, domain_data
   280               FROM users, service_set
   299              WHERE users.gid = (SELECT gid
   281              WHERE gid = (SELECT gid
   300                                   FROM domain_name
   282                             FROM domain_name
   301                                  WHERE domainname = the_domain)
   283                            WHERE domainname = the_domain)
   302                AND local_part = localpart
   284                AND local_part = localpart
   303                AND service_set.ssid = users.ssid
   285                AND service_set.ssid = users.ssid
   304                AND users.gid = domain_data.gid
       
   305                AND CASE WHEN
       
   306                   users.ssid IS NOT NULL
       
   307                   THEN
       
   308                     service_set.ssid = users.ssid
       
   309                   ELSE
       
   310                     service_set.ssid = domain_data.ssid
       
   311                   END
       
   312             LOOP
   286             LOOP
   313                 RETURN NEXT record;
   287                 RETURN NEXT record;
   314             END LOOP;
   288             END LOOP;
   315         RETURN;
   289         RETURN;
   316     END;
   290     END;
   337              WHERE users.gid = did
   311              WHERE users.gid = did
   338                AND users.local_part = localpart
   312                AND users.local_part = localpart
   339                AND maillocation.mid = users.mid
   313                AND maillocation.mid = users.mid
   340                AND mailboxformat.fid = maillocation.fid
   314                AND mailboxformat.fid = maillocation.fid
   341                AND domain_data.gid = did
   315                AND domain_data.gid = did
   342                AND CASE WHEN
   316                AND quotalimit.qid = users.qid
   343                      users.qid IS NOT NULL
       
   344                    THEN
       
   345                      quotalimit.qid = users.qid
       
   346                    ELSE
       
   347                      quotalimit.qid = domain_data.qid
       
   348                    END
       
   349             LOOP
   317             LOOP
   350                 RETURN NEXT record;
   318                 RETURN NEXT record;
   351             END LOOP;
   319             END LOOP;
   352         RETURN;
   320         RETURN;
   353     END;
   321     END;
   465     RETURNS SETOF recipient_transport
   433     RETURNS SETOF recipient_transport
   466 AS $$
   434 AS $$
   467     DECLARE
   435     DECLARE
   468         record recipient_transport;
   436         record recipient_transport;
   469         recipient varchar(320) := localpart || '@' || the_domain;
   437         recipient varchar(320) := localpart || '@' || the_domain;
   470         did bigint := (SELECT gid FROM domain_name WHERE domainname = the_domain);
   438     BEGIN
   471         transport_id bigint := (SELECT tid FROM users
       
   472                                   WHERE gid = did AND local_part = localpart);
       
   473     BEGIN
       
   474         IF transport_id IS NULL THEN
       
   475             SELECT tid INTO STRICT transport_id
       
   476               FROM domain_data
       
   477              WHERE gid = did;
       
   478         END IF;
       
   479 
       
   480         FOR record IN
   439         FOR record IN
   481             SELECT recipient, transport
   440             SELECT recipient, transport
   482               FROM transport
   441               FROM transport
   483              WHERE tid = transport_id
   442              WHERE tid = (SELECT tid
       
   443                             FROM users
       
   444                            WHERE gid = (SELECT gid
       
   445                                           FROM domain_name
       
   446                                          WHERE domainname = the_domain)
       
   447                              AND local_part = localpart)
   484             LOOP
   448             LOOP
   485                 RETURN NEXT record;
   449                 RETURN NEXT record;
   486             END LOOP;
   450             END LOOP;
   487         RETURN;
   451         RETURN;
   488     END;
   452     END;