pgsql/update_tables_0.5.x-0.6.pgsql
changeset 760 b678a1c43027
parent 748 659c4476c57c
child 761 e4e656f19771
equal deleted inserted replaced
748:659c4476c57c 760:b678a1c43027
     1 SET client_encoding = 'UTF8';
       
     2 SET client_min_messages = warning;
       
     3 
       
     4 -- ---
       
     5 -- Create the new service_set table and insert all possible combinations
       
     6 -- --
       
     7 CREATE SEQUENCE service_set_id;
       
     8 
       
     9 CREATE TABLE service_set (
       
    10     ssid        bigint NOT NULL DEFAULT nextval('service_set_id'),
       
    11     smtp        boolean NOT NULL DEFAULT TRUE,
       
    12     pop3        boolean NOT NULL DEFAULT TRUE,
       
    13     imap        boolean NOT NULL DEFAULT TRUE,
       
    14     managesieve boolean NOT NULL DEFAULT TRUE,
       
    15     CONSTRAINT  pkey_service_set PRIMARY KEY (ssid),
       
    16     CONSTRAINT  ukey_service_set UNIQUE (smtp, pop3, imap, managesieve)
       
    17 );
       
    18 
       
    19 COPY service_set (smtp, pop3, imap, managesieve) FROM stdin;
       
    20 TRUE	TRUE	TRUE	TRUE
       
    21 FALSE	TRUE	TRUE	TRUE
       
    22 TRUE	FALSE	TRUE	TRUE
       
    23 FALSE	FALSE	TRUE	TRUE
       
    24 TRUE	TRUE	FALSE	TRUE
       
    25 FALSE	TRUE	FALSE	TRUE
       
    26 TRUE	FALSE	FALSE	TRUE
       
    27 FALSE	FALSE	FALSE	TRUE
       
    28 TRUE	TRUE	TRUE	FALSE
       
    29 FALSE	TRUE	TRUE	FALSE
       
    30 TRUE	FALSE	TRUE	FALSE
       
    31 FALSE	FALSE	TRUE	FALSE
       
    32 TRUE	TRUE	FALSE	FALSE
       
    33 FALSE	TRUE	FALSE	FALSE
       
    34 TRUE	FALSE	FALSE	FALSE
       
    35 FALSE	FALSE	FALSE	FALSE
       
    36 \.
       
    37 
       
    38 -- ---
       
    39 -- Drop the obsolete VIEWs, we've functions now.
       
    40 -- ---
       
    41 DROP VIEW dovecot_user;
       
    42 DROP VIEW dovecot_password;
       
    43 DROP VIEW postfix_alias;
       
    44 DROP VIEW postfix_maildir;
       
    45 DROP VIEW postfix_relocated;
       
    46 DROP VIEW postfix_transport;
       
    47 DROP VIEW postfix_uid;
       
    48 -- the vmm_domain_info view will be restored later
       
    49 DROP VIEW vmm_domain_info;
       
    50 
       
    51 CREATE SEQUENCE mailboxformat_id;
       
    52 CREATE SEQUENCE quotalimit_id;
       
    53 
       
    54 CREATE TABLE mailboxformat (
       
    55     fid         bigint NOT NULL DEFAULT nextval('mailboxformat_id'),
       
    56     format      varchar(20) NOT NULL,
       
    57     CONSTRAINT  pkey_mailboxformat PRIMARY KEY (fid),
       
    58     CONSTRAINT  ukey_mailboxformat UNIQUE (format)
       
    59 );
       
    60 -- Insert supported mailbox formats
       
    61 INSERT INTO mailboxformat(format) VALUES ('maildir');
       
    62 INSERT INTO mailboxformat(format) VALUES ('mdbox');
       
    63 INSERT INTO mailboxformat(format) VALUES ('sdbox');
       
    64 
       
    65 -- Adjust maillocation table
       
    66 ALTER TABLE maillocation DROP CONSTRAINT ukey_maillocation;
       
    67 ALTER TABLE maillocation RENAME COLUMN maillocation TO directory;
       
    68 ALTER TABLE maillocation
       
    69     ADD COLUMN fid bigint NOT NULL DEFAULT 1,
       
    70     ADD COLUMN extra varchar(1024);
       
    71 ALTER TABLE maillocation ADD CONSTRAINT fkey_maillocation_fid_mailboxformat
       
    72     FOREIGN KEY (fid) REFERENCES mailboxformat (fid);
       
    73 
       
    74 ALTER TABLE users ALTER COLUMN passwd TYPE varchar(270);
       
    75 
       
    76 -- ---
       
    77 -- Add quota stuff
       
    78 -- ---
       
    79 CREATE TABLE quotalimit (
       
    80     qid         bigint NOT NULL DEFAULT nextval('quotalimit_id'),
       
    81     bytes       bigint NOT NULL,
       
    82     messages    integer NOT NULL DEFAULT 0,
       
    83     CONSTRAINT  pkey_quotalimit PRIMARY KEY (qid),
       
    84     CONSTRAINT  ukey_quotalimit UNIQUE (bytes, messages)
       
    85 );
       
    86 -- Insert default (non) quota limit
       
    87 INSERT INTO quotalimit(bytes, messages) VALUES (0, 0);
       
    88 
       
    89 -- Adjust tables (quota)
       
    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
       
    92     FOREIGN KEY (qid) REFERENCES quotalimit (qid);
       
    93 
       
    94 ALTER TABLE users ADD COLUMN qid bigint NULL DEFAULT NULL;
       
    95 ALTER TABLE users ADD CONSTRAINT fkey_users_qid_quotalimit
       
    96     FOREIGN KEY (qid) REFERENCES quotalimit (qid);
       
    97 
       
    98 CREATE TABLE userquota_11 (
       
    99     uid         bigint NOT NULL,
       
   100     path        varchar(16) NOT NULL,
       
   101     current     bigint NOT NULL DEFAULT 0,
       
   102     CONSTRAINT  pkey_userquota_11 PRIMARY KEY (uid, path),
       
   103     CONSTRAINT  fkey_userquota_11_uid_users FOREIGN KEY (uid)
       
   104         REFERENCES users (uid) ON DELETE CASCADE
       
   105 );
       
   106 
       
   107 CREATE OR REPLACE FUNCTION merge_userquota_11() RETURNS TRIGGER AS $$
       
   108 BEGIN
       
   109     UPDATE userquota_11
       
   110        SET current = current + NEW.current
       
   111      WHERE uid = NEW.uid AND path = NEW.path;
       
   112     IF found THEN
       
   113         RETURN NULL;
       
   114     ELSE
       
   115         RETURN NEW;
       
   116     END IF;
       
   117 END;
       
   118 $$ LANGUAGE plpgsql;
       
   119 
       
   120 CREATE TRIGGER mergeuserquota_11 BEFORE INSERT ON userquota_11
       
   121     FOR EACH ROW EXECUTE PROCEDURE merge_userquota_11();
       
   122 
       
   123 -- Adjust tables (services)
       
   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
       
   126     FOREIGN KEY (ssid) REFERENCES service_set (ssid);
       
   127 
       
   128 ALTER TABLE users ADD COLUMN ssid bigint NULL DEFAULT NULL;
       
   129 -- save current service sets
       
   130 UPDATE users u
       
   131    SET ssid = ss.ssid
       
   132   FROM service_set ss
       
   133  WHERE ss.smtp = u.smtp
       
   134    AND ss.pop3 = u.pop3
       
   135    AND ss.imap = u.imap
       
   136    AND ss.managesieve = u.managesieve;
       
   137 
       
   138 ALTER TABLE users DROP COLUMN smtp;
       
   139 ALTER TABLE users DROP COLUMN pop3;
       
   140 ALTER TABLE users DROP COLUMN imap;
       
   141 ALTER TABLE users DROP COLUMN managesieve;
       
   142 ALTER TABLE users ADD CONSTRAINT fkey_users_ssid_service_set
       
   143     FOREIGN KEY (ssid) REFERENCES service_set (ssid);
       
   144 
       
   145 -- ---
       
   146 -- Catchall
       
   147 -- ---
       
   148 -- Quota/Service/Transport inheritance
       
   149 -- ---
       
   150 ALTER TABLE users ALTER COLUMN tid DROP NOT 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 -- ---
       
   166 
       
   167 CREATE TABLE catchall (
       
   168     gid         bigint NOT NULL,
       
   169     destination varchar(320) NOT NULL,
       
   170     CONSTRAINT  pkey_catchall PRIMARY KEY (gid, destination),
       
   171     CONSTRAINT  fkey_catchall_gid_domain_data FOREIGN KEY (gid)
       
   172         REFERENCES domain_data (gid)
       
   173 );
       
   174 
       
   175 -- ---
       
   176 -- Account/domain notes
       
   177 -- ---
       
   178 
       
   179 ALTER TABLE users ADD COLUMN note text NULL DEFAULT NULL;
       
   180 ALTER TABLE domain_data ADD COLUMN note text NULL DEFAULT NULL;
       
   181 
       
   182 -- ---
       
   183 -- Restore view
       
   184 -- ---
       
   185 CREATE VIEW vmm_domain_info AS
       
   186     SELECT gid, count(uid) AS accounts,
       
   187            (SELECT count(DISTINCT address)
       
   188               FROM alias
       
   189              WHERE alias.gid = domain_data.gid) AS aliases,
       
   190            (SELECT count(gid)
       
   191               FROM relocated
       
   192              WHERE relocated.gid = domain_data.gid) AS relocated,
       
   193            (SELECT count(gid)
       
   194               FROM domain_name
       
   195              WHERE domain_name.gid = domain_data.gid
       
   196                AND NOT domain_name.is_primary) AS aliasdomains,
       
   197            (SELECT count(gid)
       
   198               FROM catchall
       
   199              WHERE catchall.gid = domain_data.gid) AS catchall
       
   200       FROM domain_data
       
   201            LEFT JOIN domain_name USING (gid)
       
   202            LEFT JOIN users USING (gid)
       
   203      WHERE domain_name.is_primary
       
   204   GROUP BY gid;
       
   205 
       
   206 -- ---
       
   207 -- Drop all known v0.5 types (the dirty way)
       
   208 -- ---
       
   209 DROP TYPE address_maildir CASCADE;
       
   210 DROP TYPE dovecotpassword CASCADE;
       
   211 DROP TYPE dovecotuser CASCADE;
       
   212 DROP TYPE recipient_destination CASCADE;
       
   213 DROP TYPE recipient_transport CASCADE;
       
   214 DROP TYPE recipient_uid CASCADE;
       
   215 DROP TYPE sender_login CASCADE;
       
   216 
       
   217 -- ######################## TYPEs ########################################### --
       
   218 
       
   219 -- ---
       
   220 -- Data type for function postfix_virtual_mailbox(varchar, varchar)
       
   221 -- ---
       
   222 CREATE TYPE address_maildir AS (
       
   223     address varchar(320),
       
   224     maildir text
       
   225 );
       
   226 -- ---
       
   227 -- Data type for function dovecotpassword(varchar, varchar)
       
   228 -- ---
       
   229 CREATE TYPE dovecotpassword AS (
       
   230     userid      varchar(320),
       
   231     password    varchar(270),
       
   232     smtp        boolean,
       
   233     pop3        boolean,
       
   234     imap        boolean,
       
   235     managesieve boolean
       
   236 );
       
   237 -- ---
       
   238 -- Data type for function dovecotquotauser(varchar, varchar)
       
   239 -- ---
       
   240 CREATE TYPE dovecotquotauser AS (
       
   241     userid      varchar(320),
       
   242     uid         bigint,
       
   243     gid         bigint,
       
   244     home        text,
       
   245     mail        text,
       
   246     quota_rule  text
       
   247 );
       
   248 -- ---
       
   249 -- Data type for function dovecotuser(varchar, varchar)
       
   250 -- ---
       
   251 CREATE TYPE dovecotuser AS (
       
   252     userid      varchar(320),
       
   253     uid         bigint,
       
   254     gid         bigint,
       
   255     home        text,
       
   256     mail        text
       
   257 );
       
   258 -- ---
       
   259 -- Data type for functions: postfix_relocated_map(varchar, varchar)
       
   260 --                          postfix_virtual_alias_map(varchar, varchar)
       
   261 -- ---
       
   262 CREATE TYPE recipient_destination AS (
       
   263     recipient   varchar(320),
       
   264     destination text
       
   265 );
       
   266 -- ---
       
   267 -- Data type for function postfix_transport_map(varchar, varchar)
       
   268 -- ---
       
   269 CREATE TYPE recipient_transport AS (
       
   270     recipient   varchar(320),
       
   271     transport   text
       
   272 );
       
   273 -- ---
       
   274 -- Data type for function postfix_virtual_uid_map(varchar, varchar)
       
   275 -- ---
       
   276 CREATE TYPE recipient_uid AS (
       
   277     recipient   varchar(320),
       
   278     uid         bigint
       
   279 );
       
   280 -- ---
       
   281 -- Data type for function postfix_smtpd_sender_login_map(varchar, varchar)
       
   282 -- ---
       
   283 CREATE TYPE sender_login AS (
       
   284     sender  varchar(320),
       
   285     login   text
       
   286 );
       
   287 
       
   288 -- ######################## FUNCTIONs ####################################### --
       
   289 
       
   290 -- ---
       
   291 -- Parameters (from login name [localpart@the_domain]):
       
   292 --      varchar localpart
       
   293 --      varchar the_domain
       
   294 -- Returns: dovecotpassword records
       
   295 -- ---
       
   296 CREATE OR REPLACE FUNCTION dovecotpassword(
       
   297     IN localpart varchar, IN the_domain varchar) RETURNS SETOF dovecotpassword
       
   298 AS $$
       
   299     DECLARE
       
   300         record dovecotpassword;
       
   301         userid varchar(320) := localpart || '@' || the_domain;
       
   302     BEGIN
       
   303         FOR record IN
       
   304             SELECT userid, passwd, smtp, pop3, imap, managesieve
       
   305               FROM users, service_set, domain_data
       
   306              WHERE users.gid = (SELECT gid
       
   307                                   FROM domain_name
       
   308                                  WHERE domainname = the_domain)
       
   309                AND local_part = localpart
       
   310                AND users.gid = domain_data.gid
       
   311                AND CASE WHEN
       
   312                   users.ssid IS NOT NULL
       
   313                   THEN
       
   314                     service_set.ssid = users.ssid
       
   315                   ELSE
       
   316                     service_set.ssid = domain_data.ssid
       
   317                   END
       
   318             LOOP
       
   319                 RETURN NEXT record;
       
   320             END LOOP;
       
   321         RETURN;
       
   322     END;
       
   323 $$ LANGUAGE plpgsql STABLE
       
   324 RETURNS NULL ON NULL INPUT
       
   325 EXTERNAL SECURITY INVOKER;
       
   326 -- ---
       
   327 -- Nearly the same as function dovecotuser below. It returns additionally the
       
   328 -- field quota_rule.
       
   329 -- ---
       
   330 CREATE OR REPLACE FUNCTION dovecotquotauser(
       
   331     IN localpart varchar, IN the_domain varchar) RETURNS SETOF dovecotquotauser
       
   332 AS $$
       
   333     DECLARE
       
   334         record dovecotquotauser;
       
   335         userid varchar(320) := localpart || '@' || the_domain;
       
   336         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   337     BEGIN
       
   338         FOR record IN
       
   339             SELECT userid, uid, did, domaindir || '/' || uid AS home,
       
   340                    format || ':~/' || directory AS mail, '*:bytes=' ||
       
   341                    bytes || ':messages=' || messages AS quota_rule
       
   342               FROM users, domain_data, mailboxformat, maillocation, quotalimit
       
   343              WHERE users.gid = did
       
   344                AND users.local_part = localpart
       
   345                AND maillocation.mid = users.mid
       
   346                AND mailboxformat.fid = maillocation.fid
       
   347                AND domain_data.gid = did
       
   348                AND CASE WHEN
       
   349                      users.qid IS NOT NULL
       
   350                    THEN
       
   351                      quotalimit.qid = users.qid
       
   352                    ELSE
       
   353                      quotalimit.qid = domain_data.qid
       
   354                    END
       
   355             LOOP
       
   356                 RETURN NEXT record;
       
   357             END LOOP;
       
   358         RETURN;
       
   359     END;
       
   360 $$ LANGUAGE plpgsql STABLE
       
   361 RETURNS NULL ON NULL INPUT
       
   362 EXTERNAL SECURITY INVOKER;
       
   363 -- ---
       
   364 -- Parameters (from login name [localpart@the_domain]):
       
   365 --      varchar localpart
       
   366 --      varchar the_domain
       
   367 -- Returns: dovecotuser records
       
   368 -- ---
       
   369 CREATE OR REPLACE FUNCTION dovecotuser(
       
   370     IN localpart varchar, IN the_domain varchar) RETURNS SETOF dovecotuser
       
   371 AS $$
       
   372     DECLARE
       
   373         record dovecotuser;
       
   374         userid varchar(320) := localpart || '@' || the_domain;
       
   375         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   376     BEGIN
       
   377         FOR record IN
       
   378             SELECT userid, uid, did, domaindir || '/' || uid AS home,
       
   379                    format || ':~/' || directory AS mail
       
   380               FROM users, domain_data, mailboxformat, maillocation
       
   381              WHERE users.gid = did
       
   382                AND users.local_part = localpart
       
   383                AND maillocation.mid = users.mid
       
   384                AND mailboxformat.fid = maillocation.fid
       
   385                AND domain_data.gid = did
       
   386             LOOP
       
   387                 RETURN NEXT record;
       
   388             END LOOP;
       
   389         RETURN;
       
   390     END;
       
   391 $$ LANGUAGE plpgsql STABLE
       
   392 RETURNS NULL ON NULL INPUT
       
   393 EXTERNAL SECURITY INVOKER;
       
   394 -- ---
       
   395 -- Parameters (from recipients address (MAIL TO) [localpart@the_domain]):
       
   396 --      varchar localpart
       
   397 --      varchar the_domain
       
   398 -- Returns: recipient_destination records
       
   399 -- ---
       
   400 CREATE OR REPLACE FUNCTION postfix_relocated_map(
       
   401     IN localpart varchar, IN the_domain varchar)
       
   402     RETURNS SETOF recipient_destination
       
   403 AS $$
       
   404     DECLARE
       
   405         record recipient_destination;
       
   406         recipient varchar(320) := localpart || '@' || the_domain;
       
   407         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   408     BEGIN
       
   409         FOR record IN
       
   410             SELECT recipient, destination
       
   411               FROM relocated
       
   412              WHERE gid = did
       
   413                AND address = localpart
       
   414             LOOP
       
   415                 RETURN NEXT record;
       
   416             END LOOP;
       
   417         RETURN;
       
   418     END;
       
   419 $$ LANGUAGE plpgsql STABLE
       
   420 RETURNS NULL ON NULL INPUT
       
   421 EXTERNAL SECURITY INVOKER;
       
   422 -- ---
       
   423 -- Parameters (from _sender_ address (MAIL FROM) [localpart@the_domain]):
       
   424 --      varchar localpart
       
   425 --      varchar the_domain
       
   426 -- Returns: SASL _login_ names that own _sender_ addresses (MAIL FROM):
       
   427 --      set of sender_login records.
       
   428 -- ---
       
   429 CREATE OR REPLACE FUNCTION postfix_smtpd_sender_login_map(
       
   430     IN localpart varchar, IN the_domain varchar) RETURNS SETOF sender_login
       
   431 AS $$
       
   432     DECLARE
       
   433         rec sender_login;
       
   434         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   435         sender varchar(320) := localpart || '@' || the_domain;
       
   436     BEGIN
       
   437         -- Get all addresses for 'localpart' in the primary and aliased domains
       
   438         FOR rec IN
       
   439             SELECT sender, local_part || '@' || domainname
       
   440               FROM domain_name, users
       
   441              WHERE domain_name.gid = did
       
   442                AND users.gid = did
       
   443                AND users.local_part = localpart
       
   444             LOOP
       
   445                 RETURN NEXT rec;
       
   446             END LOOP;
       
   447         IF NOT FOUND THEN
       
   448             -- Loop over the alias addresses for localpart@the_domain
       
   449             FOR rec IN
       
   450                 SELECT DISTINCT sender, destination
       
   451                   FROM alias
       
   452                  WHERE alias.gid = did
       
   453                    AND alias.address = localpart
       
   454                 LOOP
       
   455                     RETURN NEXT rec;
       
   456                 END LOOP;
       
   457         END IF;
       
   458         RETURN;
       
   459     END;
       
   460 $$ LANGUAGE plpgsql STABLE
       
   461 RETURNS NULL ON NULL INPUT
       
   462 EXTERNAL SECURITY INVOKER;
       
   463 -- ---
       
   464 -- Parameters (from recipients address (MAIL TO) [localpart@the_domain]):
       
   465 --      varchar localpart
       
   466 --      varchar the_domain
       
   467 -- Returns: recipient_transport records
       
   468 -- ---
       
   469 CREATE OR REPLACE FUNCTION postfix_transport_map(
       
   470     IN localpart varchar, IN the_domain varchar)
       
   471     RETURNS SETOF recipient_transport
       
   472 AS $$
       
   473     DECLARE
       
   474         record recipient_transport;
       
   475         recipient varchar(320) := localpart || '@' || the_domain;
       
   476         did bigint := (SELECT gid FROM domain_name WHERE domainname = the_domain);
       
   477         transport_id bigint;
       
   478     BEGIN
       
   479         IF did IS NULL THEN
       
   480             RETURN;
       
   481         END IF;
       
   482 
       
   483         SELECT tid INTO transport_id
       
   484           FROM users
       
   485          WHERE gid = did AND local_part = localpart;
       
   486 
       
   487         IF transport_id IS NULL THEN
       
   488             SELECT tid INTO STRICT transport_id
       
   489               FROM domain_data
       
   490              WHERE gid = did;
       
   491         END IF;
       
   492 
       
   493         FOR record IN
       
   494             SELECT recipient, transport
       
   495               FROM transport
       
   496              WHERE tid = transport_id
       
   497             LOOP
       
   498                 RETURN NEXT record;
       
   499             END LOOP;
       
   500         RETURN;
       
   501     END;
       
   502 $$ LANGUAGE plpgsql STABLE
       
   503 RETURNS NULL ON NULL INPUT
       
   504 EXTERNAL SECURITY INVOKER;
       
   505 -- ---
       
   506 -- Parameters (from recipients address (MAIL TO) [localpart@the_domain]):
       
   507 --      varchar localpart
       
   508 --      varchar the_domain
       
   509 -- Returns: recipient_destination records
       
   510 -- ---
       
   511 CREATE OR REPLACE FUNCTION _interpolate_destination(
       
   512     IN destination varchar, localpart varchar, IN the_domain varchar)
       
   513     RETURNS varchar
       
   514 AS $$
       
   515     DECLARE
       
   516         result varchar(320);
       
   517     BEGIN
       
   518         IF position('%' in destination) = 0 THEN
       
   519             RETURN destination;
       
   520         END IF;
       
   521         result := replace(destination, '%n', localpart);
       
   522         result := replace(result, '%d', the_domain);
       
   523         result := replace(result, '%=', localpart || '=' || the_domain);
       
   524         RETURN result;
       
   525     END;
       
   526 $$ LANGUAGE plpgsql STABLE
       
   527 RETURNS NULL ON NULL INPUT
       
   528 EXTERNAL SECURITY INVOKER;
       
   529 
       
   530 CREATE OR REPLACE FUNCTION postfix_virtual_alias_map(
       
   531     IN localpart varchar, IN the_domain varchar)
       
   532     RETURNS SETOF recipient_destination
       
   533 AS $$
       
   534     DECLARE
       
   535         recordc recipient_destination;
       
   536         record recipient_destination;
       
   537         catchall_cursor refcursor;
       
   538         recipient varchar(320) := localpart || '@' || the_domain;
       
   539         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   540     BEGIN
       
   541         FOR record IN
       
   542             SELECT recipient,
       
   543                 _interpolate_destination(destination, localpart, the_domain)
       
   544               FROM alias
       
   545              WHERE gid = did
       
   546                AND address = localpart
       
   547             LOOP
       
   548                 RETURN NEXT record;
       
   549             END LOOP;
       
   550 
       
   551         IF NOT FOUND THEN
       
   552             -- There is no matching virtual_alias. If there are no catchall
       
   553             -- records for this domain, we can just return NULL since Postfix
       
   554             -- will then later consult mailboxes/relocated itself. But if
       
   555             -- there is a catchall destination, then it would take precedence
       
   556             -- over mailboxes/relocated, which is not what we want. Therefore,
       
   557             -- we must first find out if the query is for an existing mailbox
       
   558             -- or relocated entry and return the identity mapping if that is
       
   559             -- the case
       
   560             OPEN catchall_cursor FOR
       
   561                 SELECT recipient,
       
   562                     _interpolate_destination(destination, localpart, the_domain)
       
   563                   FROM catchall
       
   564                  WHERE gid = did;
       
   565             FETCH NEXT FROM catchall_cursor INTO recordc;
       
   566 
       
   567             IF recordc IS NOT NULL THEN
       
   568                 -- Since there are catchall records for this domain
       
   569                 -- check the mailbox and relocated records and return identity
       
   570                 -- if a matching record exists.
       
   571                 FOR record IN
       
   572                     SELECT recipient, recipient as destination
       
   573                       FROM users
       
   574                     WHERE gid = did
       
   575                       AND local_part = localpart
       
   576                     UNION SELECT recipient, recipient as destination
       
   577                       FROM relocated
       
   578                     WHERE gid = did
       
   579                       AND address = localpart
       
   580                     LOOP
       
   581                         RETURN NEXT record;
       
   582                     END LOOP;
       
   583 
       
   584                 IF NOT FOUND THEN
       
   585                     -- There were no records found for mailboxes/relocated,
       
   586                     -- so now we can actually iterate the cursor and populate
       
   587                     -- the return set
       
   588                     LOOP
       
   589                         RETURN NEXT recordc;
       
   590                         FETCH NEXT FROM catchall_cursor INTO recordc;
       
   591                         EXIT WHEN recordc IS NULL;
       
   592                     END LOOP;
       
   593                 END IF;
       
   594             END IF;
       
   595             CLOSE catchall_cursor;
       
   596         END IF;
       
   597         RETURN;
       
   598     END;
       
   599 $$ LANGUAGE plpgsql STABLE
       
   600 RETURNS NULL ON NULL INPUT
       
   601 EXTERNAL SECURITY INVOKER;
       
   602 -- ---
       
   603 -- Parameters (from recipients address (MAIL TO) [localpart@the_domain]):
       
   604 --      varchar localpart
       
   605 --      varchar the_domain
       
   606 -- Returns: address_maildir records
       
   607 -- ---
       
   608 CREATE OR REPLACE FUNCTION postfix_virtual_mailbox_map(
       
   609    IN localpart varchar, IN the_domain varchar) RETURNS SETOF address_maildir
       
   610 AS $$
       
   611     DECLARE
       
   612         rec address_maildir;
       
   613         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   614         address varchar(320) := localpart || '@' || the_domain;
       
   615     BEGIN
       
   616         FOR rec IN
       
   617             SELECT address, domaindir||'/'||users.uid||'/'||directory||'/'
       
   618               FROM domain_data, users, maillocation
       
   619              WHERE domain_data.gid = did
       
   620                AND users.gid = did
       
   621                AND users.local_part = localpart
       
   622                AND maillocation.mid = users.mid
       
   623             LOOP
       
   624                 RETURN NEXT rec;
       
   625             END LOOP;
       
   626         RETURN;
       
   627     END;
       
   628 $$ LANGUAGE plpgsql STABLE
       
   629 RETURNS NULL ON NULL INPUT
       
   630 EXTERNAL SECURITY INVOKER;
       
   631 -- ---
       
   632 -- Parameters (from recipients address (MAIL TO) [localpart@the_domain]):
       
   633 --      varchar localpart
       
   634 --      varchar the_domain
       
   635 -- Returns: recipient_uid records
       
   636 -- ---
       
   637 CREATE OR REPLACE FUNCTION postfix_virtual_uid_map(
       
   638     IN localpart varchar, IN the_domain varchar) RETURNS SETOF recipient_uid
       
   639 AS $$
       
   640     DECLARE
       
   641         record recipient_uid;
       
   642         recipient varchar(320) := localpart || '@' || the_domain;
       
   643     BEGIN
       
   644         FOR record IN
       
   645             SELECT recipient, uid
       
   646               FROM users
       
   647              WHERE gid = (SELECT gid
       
   648                             FROM domain_name
       
   649                            WHERE domainname = the_domain)
       
   650                AND local_part = localpart
       
   651             LOOP
       
   652                 RETURN NEXT record;
       
   653             END LOOP;
       
   654         RETURN;
       
   655     END;
       
   656 $$ LANGUAGE plpgsql STABLE
       
   657 RETURNS NULL ON NULL INPUT
       
   658 EXTERNAL SECURITY INVOKER;