pgsql/create_tables-dovecot-1.2.x.pgsql
branchv0.7.x
changeset 723 0cdd5e37f723
parent 722 e37f60b0e3b5
child 724 348cd2cf9c18
equal deleted inserted replaced
722:e37f60b0e3b5 723:0cdd5e37f723
     1 SET client_encoding = 'UTF8';
       
     2 SET client_min_messages = warning;
       
     3 
       
     4 
       
     5 CREATE SEQUENCE transport_id;
       
     6 
       
     7 CREATE SEQUENCE mailboxformat_id;
       
     8 
       
     9 CREATE SEQUENCE maillocation_id;
       
    10 
       
    11 CREATE SEQUENCE quotalimit_id;
       
    12 
       
    13 CREATE SEQUENCE service_set_id;
       
    14 
       
    15 CREATE SEQUENCE domain_gid
       
    16     START WITH 70000
       
    17     INCREMENT BY 1
       
    18     MINVALUE 70000
       
    19     MAXVALUE 4294967294
       
    20     NO CYCLE;
       
    21 
       
    22 CREATE SEQUENCE users_uid
       
    23     START WITH 70000
       
    24     INCREMENT BY 1
       
    25     MINVALUE 70000
       
    26     MAXVALUE 4294967294
       
    27     NO CYCLE;
       
    28 
       
    29 
       
    30 CREATE TABLE transport (
       
    31     tid         bigint NOT NULL DEFAULT nextval('transport_id'),
       
    32     transport   varchar(270) NOT NULL, -- smtps:[255-char.host.name:50025]
       
    33     CONSTRAINT  pkey_transport PRIMARY KEY (tid),
       
    34     CONSTRAINT  ukey_transport UNIQUE (transport)
       
    35 );
       
    36 -- Insert default transport
       
    37 INSERT INTO transport(transport) VALUES ('dovecot:');
       
    38 
       
    39 CREATE TABLE mailboxformat (
       
    40     fid         bigint NOT NULL DEFAULT nextval('mailboxformat_id'),
       
    41     format      varchar(20) NOT NULL,
       
    42     CONSTRAINT  pkey_mailboxformat PRIMARY KEY (fid),
       
    43     CONSTRAINT  ukey_mailboxformat UNIQUE (format)
       
    44 );
       
    45 -- Insert supported mailbox formats
       
    46 INSERT INTO mailboxformat(format) VALUES ('maildir');
       
    47 INSERT INTO mailboxformat(format) VALUES ('mdbox');
       
    48 INSERT INTO mailboxformat(format) VALUES ('sdbox');
       
    49 
       
    50 CREATE TABLE maillocation (
       
    51     mid         bigint NOT NULL DEFAULT nextval('maillocation_id'),
       
    52     fid         bigint NOT NULL DEFAULT 1,
       
    53     directory   varchar(20) NOT NULL,
       
    54     extra       varchar(1024),
       
    55     CONSTRAINT  pkey_maillocation PRIMARY KEY (mid),
       
    56     CONSTRAINT  fkey_maillocation_fid_mailboxformat FOREIGN KEY (fid)
       
    57         REFERENCES mailboxformat (fid)
       
    58 );
       
    59 -- Insert default Maildir-folder name
       
    60 INSERT INTO maillocation(directory) VALUES ('Maildir');
       
    61 
       
    62 CREATE TABLE quotalimit (
       
    63     qid         bigint NOT NULL DEFAULT nextval('quotalimit_id'),
       
    64     bytes       bigint NOT NULL,
       
    65     messages    integer NOT NULL DEFAULT 0,
       
    66     CONSTRAINT  pkey_quotalimit PRIMARY KEY (qid),
       
    67     CONSTRAINT  ukey_quotalimit UNIQUE (bytes, messages)
       
    68 );
       
    69 -- Insert default (non) quota limit
       
    70 INSERT INTO quotalimit(bytes, messages) VALUES (0, 0);
       
    71 
       
    72 CREATE TABLE service_set (
       
    73     ssid        bigint NOT NULL DEFAULT nextval('service_set_id'),
       
    74     smtp        boolean NOT NULL DEFAULT TRUE,
       
    75     pop3        boolean NOT NULL DEFAULT TRUE,
       
    76     imap        boolean NOT NULL DEFAULT TRUE,
       
    77     sieve       boolean NOT NULL DEFAULT TRUE,
       
    78     CONSTRAINT  pkey_service_set PRIMARY KEY (ssid),
       
    79     CONSTRAINT  ukey_service_set UNIQUE (smtp, pop3, imap, sieve)
       
    80 );
       
    81 -- Insert all possible service combinations
       
    82 COPY service_set (smtp, pop3, imap, sieve) FROM stdin;
       
    83 TRUE	TRUE	TRUE	TRUE
       
    84 FALSE	TRUE	TRUE	TRUE
       
    85 TRUE	FALSE	TRUE	TRUE
       
    86 FALSE	FALSE	TRUE	TRUE
       
    87 TRUE	TRUE	FALSE	TRUE
       
    88 FALSE	TRUE	FALSE	TRUE
       
    89 TRUE	FALSE	FALSE	TRUE
       
    90 FALSE	FALSE	FALSE	TRUE
       
    91 TRUE	TRUE	TRUE	FALSE
       
    92 FALSE	TRUE	TRUE	FALSE
       
    93 TRUE	FALSE	TRUE	FALSE
       
    94 FALSE	FALSE	TRUE	FALSE
       
    95 TRUE	TRUE	FALSE	FALSE
       
    96 FALSE	TRUE	FALSE	FALSE
       
    97 TRUE	FALSE	FALSE	FALSE
       
    98 FALSE	FALSE	FALSE	FALSE
       
    99 \.
       
   100 
       
   101 CREATE TABLE domain_data (
       
   102     gid         bigint NOT NULL DEFAULT nextval('domain_gid'),
       
   103     qid         bigint NOT NULL DEFAULT 1, -- default quota limit
       
   104     ssid        bigint NOT NULL DEFAULT 1, -- default service set
       
   105     tid         bigint NOT NULL DEFAULT 1, -- default transport
       
   106     domaindir   varchar(40) NOT NULL, --/srv/mail/$RAND/4294967294
       
   107     note        text NULL DEFAULT NULL,
       
   108     CONSTRAINT  pkey_domain_data PRIMARY KEY (gid),
       
   109     CONSTRAINT  fkey_domain_data_qid_quotalimit FOREIGN KEY (qid)
       
   110         REFERENCES quotalimit (qid),
       
   111     CONSTRAINT  fkey_domain_data_ssid_service_set FOREIGN KEY (ssid)
       
   112         REFERENCES service_set (ssid),
       
   113     CONSTRAINT  fkey_domain_data_tid_transport FOREIGN KEY (tid)
       
   114         REFERENCES transport (tid)
       
   115 );
       
   116 
       
   117 CREATE TABLE domain_name (
       
   118     domainname  varchar(255) NOT NULL,
       
   119     gid         bigint NOT NULL,
       
   120     is_primary  boolean NOT NULL,
       
   121     CONSTRAINT  pkey_domain_name PRIMARY KEY (domainname),
       
   122     CONSTRAINT  fkey_domain_name_gid_domain_data FOREIGN KEY (gid)
       
   123         REFERENCES domain_data (gid)
       
   124 );
       
   125 
       
   126 CREATE TABLE users (
       
   127     local_part  varchar(64) NOT NULL,-- only localpart w/o '@'
       
   128     passwd      varchar(270) NOT NULL,
       
   129     name        varchar(128) NULL,
       
   130     uid         bigint NOT NULL DEFAULT nextval('users_uid'),
       
   131     gid         bigint NOT NULL,
       
   132     mid         bigint NOT NULL DEFAULT 1,
       
   133     qid         bigint NULL DEFAULT NULL,
       
   134     ssid        bigint NULL DEFAULT NULL,
       
   135     tid         bigint NULL DEFAULT NULL,
       
   136     note        text NULL DEFAULT NULL,
       
   137     CONSTRAINT  pkey_users PRIMARY KEY (local_part, gid),
       
   138     CONSTRAINT  ukey_users_uid UNIQUE (uid),
       
   139     CONSTRAINT  fkey_users_gid_domain_data FOREIGN KEY (gid)
       
   140         REFERENCES domain_data (gid),
       
   141     CONSTRAINT  fkey_users_mid_maillocation FOREIGN KEY (mid)
       
   142         REFERENCES maillocation (mid),
       
   143     CONSTRAINT  fkey_users_qid_quotalimit FOREIGN KEY (qid)
       
   144         REFERENCES quotalimit (qid),
       
   145     CONSTRAINT fkey_users_ssid_service_set FOREIGN KEY (ssid)
       
   146         REFERENCES service_set (ssid),
       
   147     CONSTRAINT  fkey_users_tid_transport FOREIGN KEY (tid)
       
   148         REFERENCES transport (tid)
       
   149 );
       
   150 
       
   151 CREATE TABLE userquota (
       
   152     uid         bigint NOT NULL,
       
   153     bytes       bigint NOT NULL DEFAULT 0,
       
   154     messages    integer NOT NULL DEFAULT 0,
       
   155     CONSTRAINT  pkey_userquota PRIMARY KEY (uid),
       
   156     CONSTRAINT  fkey_userquota_uid_users FOREIGN KEY (uid)
       
   157         REFERENCES users (uid) ON DELETE CASCADE
       
   158 );
       
   159 
       
   160 CREATE TABLE alias (
       
   161     gid         bigint NOT NULL,
       
   162     address     varchar(64) NOT NULL,-- only localpart w/o '@'
       
   163     destination varchar(320) NOT NULL,
       
   164     CONSTRAINT  pkey_alias PRIMARY KEY (gid, address, destination),
       
   165     CONSTRAINT  fkey_alias_gid_domain_data FOREIGN KEY (gid)
       
   166         REFERENCES domain_data (gid)
       
   167 );
       
   168 
       
   169 CREATE TABLE relocated (
       
   170     gid         bigint NOT NULL,
       
   171     address     varchar(64) NOT NULL,
       
   172     destination varchar(320) NOT NULL,
       
   173     CONSTRAINT  pkey_relocated PRIMARY KEY (gid, address),
       
   174     CONSTRAINT  fkey_relocated_gid_domain_data FOREIGN KEY (gid)
       
   175         REFERENCES domain_data (gid)
       
   176 );
       
   177 
       
   178 CREATE TABLE catchall (
       
   179     gid         bigint NOT NULL,
       
   180     destination varchar(320) NOT NULL,
       
   181     CONSTRAINT  pkey_catchall PRIMARY KEY (gid, destination),
       
   182     CONSTRAINT  fkey_catchall_gid_domain_data FOREIGN KEY (gid)
       
   183         REFERENCES domain_data (gid)
       
   184 );
       
   185 
       
   186 CREATE OR REPLACE VIEW postfix_gid AS
       
   187     SELECT gid, domainname
       
   188       FROM domain_name;
       
   189 
       
   190 CREATE OR REPLACE VIEW vmm_domain_info AS
       
   191     SELECT gid, count(uid) AS accounts,
       
   192            (SELECT count(DISTINCT address)
       
   193               FROM alias
       
   194              WHERE alias.gid = domain_data.gid) AS aliases,
       
   195            (SELECT count(gid)
       
   196               FROM relocated
       
   197              WHERE relocated.gid = domain_data.gid) AS relocated,
       
   198            (SELECT count(gid)
       
   199               FROM domain_name
       
   200              WHERE domain_name.gid = domain_data.gid
       
   201                AND NOT domain_name.is_primary) AS aliasdomains,
       
   202            (SELECT count(gid)
       
   203               FROM catchall
       
   204              WHERE catchall.gid = domain_data.gid) AS catchall
       
   205       FROM domain_data
       
   206            LEFT JOIN domain_name USING (gid)
       
   207            LEFT JOIN users USING (gid)
       
   208      WHERE domain_name.is_primary
       
   209   GROUP BY gid;
       
   210 
       
   211 -- ########################################################################## --
       
   212 
       
   213 CREATE LANGUAGE plpgsql;
       
   214 
       
   215 -- ######################## TYPEs ########################################### --
       
   216 
       
   217 -- ---
       
   218 -- Data type for function postfix_virtual_mailbox(varchar, varchar)
       
   219 -- ---
       
   220 CREATE TYPE address_maildir AS (
       
   221     address varchar(320),
       
   222     maildir text
       
   223 );
       
   224 -- ---
       
   225 -- Data type for function dovecotpassword(varchar, varchar)
       
   226 -- ---
       
   227 CREATE TYPE dovecotpassword AS (
       
   228     userid    varchar(320),
       
   229     password  varchar(270),
       
   230     smtp      boolean,
       
   231     pop3      boolean,
       
   232     imap      boolean,
       
   233     sieve     boolean
       
   234 );
       
   235 -- ---
       
   236 -- Data type for function dovecotquotauser(varchar, varchar)
       
   237 -- ---
       
   238 CREATE TYPE dovecotquotauser AS (
       
   239     userid      varchar(320),
       
   240     uid         bigint,
       
   241     gid         bigint,
       
   242     home        text,
       
   243     mail        text,
       
   244     quota_rule  text
       
   245 );
       
   246 -- ---
       
   247 -- Data type for function dovecotuser(varchar, varchar)
       
   248 -- ---
       
   249 CREATE TYPE dovecotuser AS (
       
   250     userid      varchar(320),
       
   251     uid         bigint,
       
   252     gid         bigint,
       
   253     home        text,
       
   254     mail        text
       
   255 );
       
   256 -- ---
       
   257 -- Data type for functions: postfix_relocated_map(varchar, varchar)
       
   258 --                          postfix_virtual_alias_map(varchar, varchar)
       
   259 -- ---
       
   260 CREATE TYPE recipient_destination AS (
       
   261     recipient   varchar(320),
       
   262     destination text
       
   263 );
       
   264 -- ---
       
   265 -- Data type for function postfix_transport_map(varchar, varchar)
       
   266 -- ---
       
   267 CREATE TYPE recipient_transport AS (
       
   268     recipient   varchar(320),
       
   269     transport   text
       
   270 );
       
   271 -- ---
       
   272 -- Data type for function postfix_virtual_uid_map(varchar, varchar)
       
   273 -- ---
       
   274 CREATE TYPE recipient_uid AS (
       
   275     recipient   varchar(320),
       
   276     uid         bigint
       
   277 );
       
   278 -- ---
       
   279 -- Data type for function postfix_smtpd_sender_login_map(varchar, varchar)
       
   280 -- ---
       
   281 CREATE TYPE sender_login AS (
       
   282     sender  varchar(320),
       
   283     login   text
       
   284 );
       
   285 
       
   286 -- ######################## TRIGGERs ######################################## --
       
   287 
       
   288 CREATE OR REPLACE FUNCTION domain_primary_trigger() RETURNS TRIGGER AS $$
       
   289 DECLARE
       
   290     primary_count bigint;
       
   291 BEGIN
       
   292     SELECT INTO primary_count count(gid) + NEW.is_primary::integer
       
   293       FROM domain_name
       
   294      WHERE domain_name.gid = NEW.gid
       
   295        AND is_primary;
       
   296 
       
   297     IF (primary_count > 1) THEN
       
   298         RAISE EXCEPTION 'There can only be one domain marked as primary.';
       
   299     END IF;
       
   300 
       
   301     RETURN NEW;
       
   302 END;
       
   303 $$ LANGUAGE plpgsql STABLE;
       
   304 
       
   305 
       
   306 CREATE TRIGGER primary_count_ins BEFORE INSERT ON domain_name
       
   307     FOR EACH ROW EXECUTE PROCEDURE domain_primary_trigger();
       
   308 
       
   309 CREATE TRIGGER primary_count_upd AFTER UPDATE ON domain_name
       
   310     FOR EACH ROW EXECUTE PROCEDURE domain_primary_trigger();
       
   311 
       
   312 
       
   313 CREATE OR REPLACE FUNCTION merge_userquota() RETURNS TRIGGER AS $$
       
   314 BEGIN
       
   315     IF NEW.messages < 0 OR NEW.messages IS NULL THEN
       
   316         IF NEW.messages IS NULL THEN
       
   317             NEW.messages = 0;
       
   318         ELSE
       
   319             NEW.messages = -NEW.messages;
       
   320         END IF;
       
   321         RETURN NEW;
       
   322     END IF;
       
   323     LOOP
       
   324         UPDATE userquota
       
   325            SET bytes = bytes + NEW.bytes, messages = messages + NEW.messages
       
   326          WHERE uid = NEW.uid;
       
   327         IF found THEN
       
   328             RETURN NULL;
       
   329         END IF;
       
   330         BEGIN
       
   331             IF NEW.messages = 0 THEN
       
   332               INSERT INTO userquota VALUES (NEW.uid, NEW.bytes, NULL);
       
   333             ELSE
       
   334               INSERT INTO userquota VALUES (NEW.uid, NEW.bytes, -NEW.messages);
       
   335             END IF;
       
   336             RETURN NULL;
       
   337         EXCEPTION
       
   338             WHEN unique_violation THEN
       
   339                 -- do nothing, and loop to try the UPDATE again
       
   340             WHEN foreign_key_violation THEN
       
   341                 -- break the loop: a non matching uid means no such user
       
   342                 RETURN NULL;
       
   343         END;
       
   344     END LOOP;
       
   345 END;
       
   346 $$ LANGUAGE plpgsql;
       
   347 
       
   348 
       
   349 CREATE TRIGGER mergeuserquota BEFORE INSERT ON userquota
       
   350     FOR EACH ROW EXECUTE PROCEDURE merge_userquota();
       
   351 
       
   352 -- ######################## FUNCTIONs ####################################### --
       
   353 
       
   354 -- ---
       
   355 -- Parameters (from login name [localpart@the_domain]):
       
   356 --      varchar localpart
       
   357 --      varchar the_domain
       
   358 -- Returns: dovecotpassword records
       
   359 --
       
   360 -- Required access privileges for your dovecot database user:
       
   361 --      GRANT SELECT ON users, domain_name, service_set TO dovecot;
       
   362 --
       
   363 -- For more details see http://wiki.dovecot.org/AuthDatabase/SQL
       
   364 -- ---
       
   365 CREATE OR REPLACE FUNCTION dovecotpassword(
       
   366     IN localpart varchar, IN the_domain varchar) RETURNS SETOF dovecotpassword
       
   367 AS $$
       
   368     DECLARE
       
   369         record dovecotpassword;
       
   370         userid varchar(320) := localpart || '@' || the_domain;
       
   371     BEGIN
       
   372         FOR record IN
       
   373             SELECT userid, passwd, smtp, pop3, imap, sieve
       
   374               FROM users, service_set, domain_data
       
   375              WHERE users.gid = (SELECT gid
       
   376                                   FROM domain_name
       
   377                                  WHERE domainname = the_domain)
       
   378                AND local_part = localpart
       
   379                AND users.gid = domain_data.gid
       
   380                AND CASE WHEN
       
   381                      users.ssid IS NOT NULL
       
   382                      THEN
       
   383                        service_set.ssid = users.ssid
       
   384                      ELSE
       
   385                        service_set.ssid = domain_data.ssid
       
   386                      END
       
   387             LOOP
       
   388                 RETURN NEXT record;
       
   389             END LOOP;
       
   390         RETURN;
       
   391     END;
       
   392 $$ LANGUAGE plpgsql STABLE
       
   393 RETURNS NULL ON NULL INPUT
       
   394 EXTERNAL SECURITY INVOKER;
       
   395 -- ---
       
   396 -- Nearly the same as function dovecotuser below. It returns additionally the
       
   397 -- field quota_rule.
       
   398 --
       
   399 -- Required access privileges for your dovecot database user:
       
   400 --      GRANT SELECT
       
   401 --          ON users, domain_data, domain_name, maillocation, mailboxformat,
       
   402 --             quotalimit
       
   403 --          TO dovecot;
       
   404 -- ---
       
   405 CREATE OR REPLACE FUNCTION dovecotquotauser(
       
   406     IN localpart varchar, IN the_domain varchar) RETURNS SETOF dovecotquotauser
       
   407 AS $$
       
   408     DECLARE
       
   409         record dovecotquotauser;
       
   410         userid varchar(320) := localpart || '@' || the_domain;
       
   411         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   412     BEGIN
       
   413         FOR record IN
       
   414             SELECT userid, uid, did, domaindir || '/' || uid AS home,
       
   415                    format || ':~/' || directory AS mail, '*:bytes=' ||
       
   416                    bytes || ':messages=' || messages AS quota_rule
       
   417               FROM users, domain_data, mailboxformat, maillocation, quotalimit
       
   418              WHERE users.gid = did
       
   419                AND users.local_part = localpart
       
   420                AND maillocation.mid = users.mid
       
   421                AND mailboxformat.fid = maillocation.fid
       
   422                AND domain_data.gid = did
       
   423                AND CASE WHEN
       
   424                      users.qid IS NOT NULL
       
   425                    THEN
       
   426                      quotalimit.qid = users.qid
       
   427                    ELSE
       
   428                      quotalimit.qid = domain_data.qid
       
   429                    END
       
   430             LOOP
       
   431                 RETURN NEXT record;
       
   432             END LOOP;
       
   433         RETURN;
       
   434     END;
       
   435 $$ LANGUAGE plpgsql STABLE
       
   436 RETURNS NULL ON NULL INPUT
       
   437 EXTERNAL SECURITY INVOKER;
       
   438 -- ---
       
   439 -- Parameters (from login name [localpart@the_domain]):
       
   440 --      varchar localpart
       
   441 --      varchar the_domain
       
   442 -- Returns: dovecotuser records
       
   443 --
       
   444 -- Required access privileges for your dovecot database user:
       
   445 --      GRANT SELECT
       
   446 --          ON users, domain_data, domain_name, maillocation, mailboxformat
       
   447 --          TO dovecot;
       
   448 --
       
   449 -- For more details see http://wiki.dovecot.org/UserDatabase
       
   450 -- ---
       
   451 CREATE OR REPLACE FUNCTION dovecotuser(
       
   452     IN localpart varchar, IN the_domain varchar) RETURNS SETOF dovecotuser
       
   453 AS $$
       
   454     DECLARE
       
   455         record dovecotuser;
       
   456         userid varchar(320) := localpart || '@' || the_domain;
       
   457         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   458     BEGIN
       
   459         FOR record IN
       
   460             SELECT userid, uid, did, domaindir || '/' || uid AS home,
       
   461                    format || ':~/' || directory AS mail
       
   462               FROM users, domain_data, mailboxformat, maillocation
       
   463              WHERE users.gid = did
       
   464                AND users.local_part = localpart
       
   465                AND maillocation.mid = users.mid
       
   466                AND mailboxformat.fid = maillocation.fid
       
   467                AND domain_data.gid = did
       
   468             LOOP
       
   469                 RETURN NEXT record;
       
   470             END LOOP;
       
   471         RETURN;
       
   472     END;
       
   473 $$ LANGUAGE plpgsql STABLE
       
   474 RETURNS NULL ON NULL INPUT
       
   475 EXTERNAL SECURITY INVOKER;
       
   476 -- ---
       
   477 -- Parameters (from recipients address (MAIL TO) [localpart@the_domain]):
       
   478 --      varchar localpart
       
   479 --      varchar the_domain
       
   480 -- Returns: recipient_destination records
       
   481 --
       
   482 -- Required access privileges for your postfix database user:
       
   483 --      GRANT SELECT ON domain_name, relocated TO postfix;
       
   484 --
       
   485 -- For more details see postconf(5) section relocated_maps and relocated(5)
       
   486 -- ---
       
   487 CREATE OR REPLACE FUNCTION postfix_relocated_map(
       
   488     IN localpart varchar, IN the_domain varchar)
       
   489     RETURNS SETOF recipient_destination
       
   490 AS $$
       
   491     DECLARE
       
   492         record recipient_destination;
       
   493         recipient varchar(320) := localpart || '@' || the_domain;
       
   494         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   495     BEGIN
       
   496         FOR record IN
       
   497             SELECT recipient, destination
       
   498               FROM relocated
       
   499              WHERE gid = did
       
   500                AND address = localpart
       
   501             LOOP
       
   502                 RETURN NEXT record;
       
   503             END LOOP;
       
   504         RETURN;
       
   505     END;
       
   506 $$ LANGUAGE plpgsql STABLE
       
   507 RETURNS NULL ON NULL INPUT
       
   508 EXTERNAL SECURITY INVOKER;
       
   509 -- ---
       
   510 -- Parameters (from _sender_ address (MAIL FROM) [localpart@the_domain]):
       
   511 --      varchar localpart
       
   512 --      varchar the_domain
       
   513 -- Returns: SASL _login_ names that own _sender_ addresses (MAIL FROM):
       
   514 --      set of sender_login records.
       
   515 --
       
   516 -- Required access privileges for your postfix database user:
       
   517 --      GRANT SELECT ON domain_name, users, alias TO postfix;
       
   518 --
       
   519 -- For more details see postconf(5) section smtpd_sender_login_maps
       
   520 -- ---
       
   521 CREATE OR REPLACE FUNCTION postfix_smtpd_sender_login_map(
       
   522     IN localpart varchar, IN the_domain varchar) RETURNS SETOF sender_login
       
   523 AS $$
       
   524     DECLARE
       
   525         rec sender_login;
       
   526         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   527         sender varchar(320) := localpart || '@' || the_domain;
       
   528     BEGIN
       
   529         -- Get all addresses for 'localpart' in the primary and aliased domains
       
   530         FOR rec IN
       
   531             SELECT sender, local_part || '@' || domainname
       
   532               FROM domain_name, users
       
   533              WHERE domain_name.gid = did
       
   534                AND users.gid = did
       
   535                AND users.local_part = localpart
       
   536             LOOP
       
   537                 RETURN NEXT rec;
       
   538             END LOOP;
       
   539         IF NOT FOUND THEN
       
   540             -- Loop over the alias addresses for localpart@the_domain
       
   541             FOR rec IN
       
   542                 SELECT DISTINCT sender, destination
       
   543                   FROM alias
       
   544                  WHERE alias.gid = did
       
   545                    AND alias.address = localpart
       
   546                 LOOP
       
   547                     RETURN NEXT rec;
       
   548                 END LOOP;
       
   549         END IF;
       
   550         RETURN;
       
   551     END;
       
   552 $$ LANGUAGE plpgsql STABLE
       
   553 RETURNS NULL ON NULL INPUT
       
   554 EXTERNAL SECURITY INVOKER;
       
   555 -- ---
       
   556 -- Parameters (from recipients address (MAIL TO) [localpart@the_domain]):
       
   557 --      varchar localpart
       
   558 --      varchar the_domain
       
   559 -- Returns: recipient_transport records
       
   560 --
       
   561 -- Required access privileges for your postfix database user:
       
   562 --      GRANT SELECT ON users, transport, domain_name TO postfix;
       
   563 --
       
   564 -- For more details see postconf(5) section transport_maps and transport(5)
       
   565 -- ---
       
   566 CREATE OR REPLACE FUNCTION postfix_transport_map(
       
   567     IN localpart varchar, IN the_domain varchar)
       
   568     RETURNS SETOF recipient_transport
       
   569 AS $$
       
   570     DECLARE
       
   571         record recipient_transport;
       
   572         recipient varchar(320) := localpart || '@' || the_domain;
       
   573         did bigint := (SELECT gid FROM domain_name WHERE domainname = the_domain);
       
   574         transport_id bigint;
       
   575     BEGIN
       
   576         IF did IS NULL THEN
       
   577             RETURN;
       
   578         END IF;
       
   579 
       
   580         SELECT tid INTO transport_id
       
   581           FROM users
       
   582          WHERE gid = did AND local_part = localpart;
       
   583 
       
   584         IF transport_id IS NULL THEN
       
   585             SELECT tid INTO STRICT transport_id
       
   586               FROM domain_data
       
   587              WHERE gid = did;
       
   588         END IF;
       
   589 
       
   590         FOR record IN
       
   591             SELECT recipient, transport
       
   592               FROM transport
       
   593              WHERE tid = transport_id
       
   594             LOOP
       
   595                 RETURN NEXT record;
       
   596             END LOOP;
       
   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: recipient_destination records
       
   607 --
       
   608 -- Required access privileges for your postfix database user:
       
   609 --      GRANT SELECT ON alias, domain_name TO postfix;
       
   610 --
       
   611 -- For more details see postconf(5) section virtual_alias_maps and virtual(5)
       
   612 -- ---
       
   613 CREATE OR REPLACE FUNCTION _interpolate_destination(
       
   614     IN destination varchar, localpart varchar, IN the_domain varchar)
       
   615     RETURNS varchar
       
   616 AS $$
       
   617     DECLARE
       
   618         result varchar(320);
       
   619     BEGIN
       
   620         IF position('%' in destination) = 0 THEN
       
   621             RETURN destination;
       
   622         END IF;
       
   623         result := replace(destination, '%n', localpart);
       
   624         result := replace(result, '%d', the_domain);
       
   625         result := replace(result, '%=', localpart || '=' || the_domain);
       
   626         RETURN result;
       
   627     END;
       
   628 $$ LANGUAGE plpgsql STABLE
       
   629 RETURNS NULL ON NULL INPUT
       
   630 EXTERNAL SECURITY INVOKER;
       
   631 
       
   632 CREATE OR REPLACE FUNCTION postfix_virtual_alias_map(
       
   633     IN localpart varchar, IN the_domain varchar)
       
   634     RETURNS SETOF recipient_destination
       
   635 AS $$
       
   636     DECLARE
       
   637         recordc recipient_destination;
       
   638         record recipient_destination;
       
   639         catchall_cursor refcursor;
       
   640         recipient varchar(320) := localpart || '@' || the_domain;
       
   641         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   642     BEGIN
       
   643         FOR record IN
       
   644             SELECT recipient,
       
   645                 _interpolate_destination(destination, localpart, the_domain)
       
   646               FROM alias
       
   647              WHERE gid = did
       
   648                AND address = localpart
       
   649             LOOP
       
   650                 RETURN NEXT record;
       
   651             END LOOP;
       
   652 
       
   653         IF NOT FOUND THEN
       
   654             -- There is no matching virtual_alias. If there are no catchall
       
   655             -- records for this domain, we can just return NULL since Postfix
       
   656             -- will then later consult mailboxes/relocated itself. But if
       
   657             -- there is a catchall destination, then it would take precedence
       
   658             -- over mailboxes/relocated, which is not what we want. Therefore,
       
   659             -- we must first find out if the query is for an existing mailbox
       
   660             -- or relocated entry and return the identity mapping if that is
       
   661             -- the case
       
   662             OPEN catchall_cursor FOR
       
   663                 SELECT recipient,
       
   664                     _interpolate_destination(destination, localpart, the_domain)
       
   665                   FROM catchall
       
   666                  WHERE gid = did;
       
   667             FETCH NEXT FROM catchall_cursor INTO recordc;
       
   668 
       
   669             IF recordc IS NOT NULL THEN
       
   670                 -- Since there are catchall records for this domain
       
   671                 -- check the mailbox and relocated records and return identity
       
   672                 -- if a matching record exists.
       
   673                 FOR record IN
       
   674                     SELECT recipient, recipient as destination
       
   675                       FROM users
       
   676                     WHERE gid = did
       
   677                       AND local_part = localpart
       
   678                     UNION SELECT recipient, recipient as destination
       
   679                       FROM relocated
       
   680                     WHERE gid = did
       
   681                       AND address = localpart
       
   682                     LOOP
       
   683                         RETURN NEXT record;
       
   684                     END LOOP;
       
   685 
       
   686                 IF NOT FOUND THEN
       
   687                     -- There were no records found for mailboxes/relocated,
       
   688                     -- so now we can actually iterate the cursor and populate
       
   689                     -- the return set
       
   690                     LOOP
       
   691                         RETURN NEXT recordc;
       
   692                         FETCH NEXT FROM catchall_cursor INTO recordc;
       
   693                         EXIT WHEN recordc IS NULL;
       
   694                     END LOOP;
       
   695                 END IF;
       
   696             END IF;
       
   697             CLOSE catchall_cursor;
       
   698         END IF;
       
   699         RETURN;
       
   700     END;
       
   701 $$ LANGUAGE plpgsql STABLE
       
   702 RETURNS NULL ON NULL INPUT
       
   703 EXTERNAL SECURITY INVOKER;
       
   704 -- ---
       
   705 -- Parameters (from recipients address (MAIL TO) [localpart@the_domain]):
       
   706 --      varchar localpart
       
   707 --      varchar the_domain
       
   708 -- Returns: address_maildir records
       
   709 --
       
   710 -- Required access privileges for your postfix database user:
       
   711 --      GRANT SELECT ON domain_data,domain_name,maillocation,users TO postfix;
       
   712 --
       
   713 -- For more details see postconf(5) section virtual_mailbox_maps
       
   714 -- ---
       
   715 CREATE OR REPLACE FUNCTION postfix_virtual_mailbox_map(
       
   716    IN localpart varchar, IN the_domain varchar) RETURNS SETOF address_maildir
       
   717 AS $$
       
   718     DECLARE
       
   719         rec address_maildir;
       
   720         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   721         address varchar(320) := localpart || '@' || the_domain;
       
   722     BEGIN
       
   723         FOR rec IN
       
   724             SELECT address, domaindir||'/'||users.uid||'/'||directory||'/'
       
   725               FROM domain_data, users, maillocation
       
   726              WHERE domain_data.gid = did
       
   727                AND users.gid = did
       
   728                AND users.local_part = localpart
       
   729                AND maillocation.mid = users.mid
       
   730             LOOP
       
   731                 RETURN NEXT rec;
       
   732             END LOOP;
       
   733         RETURN;
       
   734     END;
       
   735 $$ LANGUAGE plpgsql STABLE
       
   736 RETURNS NULL ON NULL INPUT
       
   737 EXTERNAL SECURITY INVOKER;
       
   738 -- ---
       
   739 -- Parameters (from recipients address (MAIL TO) [localpart@the_domain]):
       
   740 --      varchar localpart
       
   741 --      varchar the_domain
       
   742 -- Returns: recipient_uid records
       
   743 --
       
   744 -- Required access privileges for your postfix database user:
       
   745 --      GRANT SELECT ON users, domain_name TO postfix;
       
   746 --
       
   747 -- For more details see postconf(5) section virtual_uid_maps
       
   748 -- ---
       
   749 CREATE OR REPLACE FUNCTION postfix_virtual_uid_map(
       
   750     IN localpart varchar, IN the_domain varchar) RETURNS SETOF recipient_uid
       
   751 AS $$
       
   752     DECLARE
       
   753         record recipient_uid;
       
   754         recipient varchar(320) := localpart || '@' || the_domain;
       
   755     BEGIN
       
   756         FOR record IN
       
   757             SELECT recipient, uid
       
   758               FROM users
       
   759              WHERE gid = (SELECT gid
       
   760                             FROM domain_name
       
   761                            WHERE domainname = the_domain)
       
   762                AND local_part = localpart
       
   763             LOOP
       
   764                 RETURN NEXT record;
       
   765             END LOOP;
       
   766         RETURN;
       
   767     END;
       
   768 $$ LANGUAGE plpgsql STABLE
       
   769 RETURNS NULL ON NULL INPUT
       
   770 EXTERNAL SECURITY INVOKER;