pgsql/create_tables.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 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     managesieve boolean NOT NULL DEFAULT TRUE,
       
    78     CONSTRAINT  pkey_service_set PRIMARY KEY (ssid),
       
    79     CONSTRAINT  ukey_service_set UNIQUE (smtp, pop3, imap, managesieve)
       
    80 );
       
    81 -- Insert all possible service combinations
       
    82 COPY service_set (smtp, pop3, imap, managesieve) 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_11 (
       
   152     uid         bigint NOT NULL,
       
   153     path        varchar(16) NOT NULL,
       
   154     current     bigint NOT NULL DEFAULT 0,
       
   155     CONSTRAINT  pkey_userquota_11 PRIMARY KEY (uid, path),
       
   156     CONSTRAINT  fkey_userquota_11_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     managesieve 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_11() RETURNS TRIGGER AS $$
       
   314 BEGIN
       
   315     UPDATE userquota_11
       
   316        SET current = current + NEW.current
       
   317      WHERE uid = NEW.uid AND path = NEW.path;
       
   318     IF found THEN
       
   319         RETURN NULL;
       
   320     ELSE
       
   321         RETURN NEW;
       
   322     END IF;
       
   323 END;
       
   324 $$ LANGUAGE plpgsql;
       
   325 
       
   326 CREATE TRIGGER mergeuserquota_11 BEFORE INSERT ON userquota_11
       
   327     FOR EACH ROW EXECUTE PROCEDURE merge_userquota_11();
       
   328 
       
   329 -- ######################## FUNCTIONs ####################################### --
       
   330 
       
   331 -- ---
       
   332 -- Parameters (from login name [localpart@the_domain]):
       
   333 --      varchar localpart
       
   334 --      varchar the_domain
       
   335 -- Returns: dovecotpassword records
       
   336 --
       
   337 -- Required access privileges for your dovecot database user:
       
   338 --      GRANT SELECT ON users, domain_name, service_set TO dovecot;
       
   339 --
       
   340 -- For more details see http://wiki.dovecot.org/AuthDatabase/SQL
       
   341 -- ---
       
   342 CREATE OR REPLACE FUNCTION dovecotpassword(
       
   343     IN localpart varchar, IN the_domain varchar) RETURNS SETOF dovecotpassword
       
   344 AS $$
       
   345     DECLARE
       
   346         record dovecotpassword;
       
   347         userid varchar(320) := localpart || '@' || the_domain;
       
   348     BEGIN
       
   349         FOR record IN
       
   350             SELECT userid, passwd, smtp, pop3, imap, managesieve
       
   351               FROM users, service_set, domain_data
       
   352              WHERE users.gid = (SELECT gid
       
   353                                   FROM domain_name
       
   354                                  WHERE domainname = the_domain)
       
   355                AND local_part = localpart
       
   356                AND users.gid = domain_data.gid
       
   357                AND CASE WHEN
       
   358                   users.ssid IS NOT NULL
       
   359                   THEN
       
   360                     service_set.ssid = users.ssid
       
   361                   ELSE
       
   362                     service_set.ssid = domain_data.ssid
       
   363                   END
       
   364             LOOP
       
   365                 RETURN NEXT record;
       
   366             END LOOP;
       
   367         RETURN;
       
   368     END;
       
   369 $$ LANGUAGE plpgsql STABLE
       
   370 RETURNS NULL ON NULL INPUT
       
   371 EXTERNAL SECURITY INVOKER;
       
   372 -- ---
       
   373 -- Nearly the same as function dovecotuser below. It returns additionally the
       
   374 -- field quota_rule.
       
   375 --
       
   376 -- Required access privileges for your dovecot database user:
       
   377 --      GRANT SELECT
       
   378 --          ON users, domain_data, domain_name, maillocation, mailboxformat,
       
   379 --             quotalimit
       
   380 --          TO dovecot;
       
   381 -- ---
       
   382 CREATE OR REPLACE FUNCTION dovecotquotauser(
       
   383     IN localpart varchar, IN the_domain varchar) RETURNS SETOF dovecotquotauser
       
   384 AS $$
       
   385     DECLARE
       
   386         record dovecotquotauser;
       
   387         userid varchar(320) := localpart || '@' || the_domain;
       
   388         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   389     BEGIN
       
   390         FOR record IN
       
   391             SELECT userid, uid, did, domaindir || '/' || uid AS home,
       
   392                    format || ':~/' || directory AS mail, '*:bytes=' ||
       
   393                    bytes || ':messages=' || messages AS quota_rule
       
   394               FROM users, domain_data, mailboxformat, maillocation, quotalimit
       
   395              WHERE users.gid = did
       
   396                AND users.local_part = localpart
       
   397                AND maillocation.mid = users.mid
       
   398                AND mailboxformat.fid = maillocation.fid
       
   399                AND domain_data.gid = did
       
   400                AND CASE WHEN
       
   401                      users.qid IS NOT NULL
       
   402                    THEN
       
   403                      quotalimit.qid = users.qid
       
   404                    ELSE
       
   405                      quotalimit.qid = domain_data.qid
       
   406                    END
       
   407             LOOP
       
   408                 RETURN NEXT record;
       
   409             END LOOP;
       
   410         RETURN;
       
   411     END;
       
   412 $$ LANGUAGE plpgsql STABLE
       
   413 RETURNS NULL ON NULL INPUT
       
   414 EXTERNAL SECURITY INVOKER;
       
   415 -- ---
       
   416 -- Parameters (from login name [localpart@the_domain]):
       
   417 --      varchar localpart
       
   418 --      varchar the_domain
       
   419 -- Returns: dovecotuser records
       
   420 --
       
   421 -- Required access privileges for your dovecot database user:
       
   422 --      GRANT SELECT
       
   423 --          ON users, domain_data, domain_name, maillocation, mailboxformat
       
   424 --          TO dovecot;
       
   425 --
       
   426 -- For more details see http://wiki.dovecot.org/UserDatabase
       
   427 -- ---
       
   428 CREATE OR REPLACE FUNCTION dovecotuser(
       
   429     IN localpart varchar, IN the_domain varchar) RETURNS SETOF dovecotuser
       
   430 AS $$
       
   431     DECLARE
       
   432         record dovecotuser;
       
   433         userid varchar(320) := localpart || '@' || the_domain;
       
   434         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   435     BEGIN
       
   436         FOR record IN
       
   437             SELECT userid, uid, did, domaindir || '/' || uid AS home,
       
   438                    format || ':~/' || directory AS mail
       
   439               FROM users, domain_data, mailboxformat, maillocation
       
   440              WHERE users.gid = did
       
   441                AND users.local_part = localpart
       
   442                AND maillocation.mid = users.mid
       
   443                AND mailboxformat.fid = maillocation.fid
       
   444                AND domain_data.gid = did
       
   445             LOOP
       
   446                 RETURN NEXT record;
       
   447             END LOOP;
       
   448         RETURN;
       
   449     END;
       
   450 $$ LANGUAGE plpgsql STABLE
       
   451 RETURNS NULL ON NULL INPUT
       
   452 EXTERNAL SECURITY INVOKER;
       
   453 -- ---
       
   454 -- Parameters (from recipients address (MAIL TO) [localpart@the_domain]):
       
   455 --      varchar localpart
       
   456 --      varchar the_domain
       
   457 -- Returns: recipient_destination records
       
   458 --
       
   459 -- Required access privileges for your postfix database user:
       
   460 --      GRANT SELECT ON domain_name, relocated TO postfix;
       
   461 --
       
   462 -- For more details see postconf(5) section relocated_maps and relocated(5)
       
   463 -- ---
       
   464 CREATE OR REPLACE FUNCTION postfix_relocated_map(
       
   465     IN localpart varchar, IN the_domain varchar)
       
   466     RETURNS SETOF recipient_destination
       
   467 AS $$
       
   468     DECLARE
       
   469         record recipient_destination;
       
   470         recipient varchar(320) := localpart || '@' || the_domain;
       
   471         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   472     BEGIN
       
   473         FOR record IN
       
   474             SELECT recipient, destination
       
   475               FROM relocated
       
   476              WHERE gid = did
       
   477                AND address = localpart
       
   478             LOOP
       
   479                 RETURN NEXT record;
       
   480             END LOOP;
       
   481         RETURN;
       
   482     END;
       
   483 $$ LANGUAGE plpgsql STABLE
       
   484 RETURNS NULL ON NULL INPUT
       
   485 EXTERNAL SECURITY INVOKER;
       
   486 -- ---
       
   487 -- Parameters (from _sender_ address (MAIL FROM) [localpart@the_domain]):
       
   488 --      varchar localpart
       
   489 --      varchar the_domain
       
   490 -- Returns: SASL _login_ names that own _sender_ addresses (MAIL FROM):
       
   491 --      set of sender_login records.
       
   492 --
       
   493 -- Required access privileges for your postfix database user:
       
   494 --      GRANT SELECT ON domain_name, users, alias TO postfix;
       
   495 --
       
   496 -- For more details see postconf(5) section smtpd_sender_login_maps
       
   497 -- ---
       
   498 CREATE OR REPLACE FUNCTION postfix_smtpd_sender_login_map(
       
   499     IN localpart varchar, IN the_domain varchar) RETURNS SETOF sender_login
       
   500 AS $$
       
   501     DECLARE
       
   502         rec sender_login;
       
   503         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   504         sender varchar(320) := localpart || '@' || the_domain;
       
   505     BEGIN
       
   506         -- Get all addresses for 'localpart' in the primary and aliased domains
       
   507         FOR rec IN
       
   508             SELECT sender, local_part || '@' || domainname
       
   509               FROM domain_name, users
       
   510              WHERE domain_name.gid = did
       
   511                AND users.gid = did
       
   512                AND users.local_part = localpart
       
   513             LOOP
       
   514                 RETURN NEXT rec;
       
   515             END LOOP;
       
   516         IF NOT FOUND THEN
       
   517             -- Loop over the alias addresses for localpart@the_domain
       
   518             FOR rec IN
       
   519                 SELECT DISTINCT sender, destination
       
   520                   FROM alias
       
   521                  WHERE alias.gid = did
       
   522                    AND alias.address = localpart
       
   523                 LOOP
       
   524                     RETURN NEXT rec;
       
   525                 END LOOP;
       
   526         END IF;
       
   527         RETURN;
       
   528     END;
       
   529 $$ LANGUAGE plpgsql STABLE
       
   530 RETURNS NULL ON NULL INPUT
       
   531 EXTERNAL SECURITY INVOKER;
       
   532 -- ---
       
   533 -- Parameters (from recipients address (MAIL TO) [localpart@the_domain]):
       
   534 --      varchar localpart
       
   535 --      varchar the_domain
       
   536 -- Returns: recipient_transport records
       
   537 --
       
   538 -- Required access privileges for your postfix database user:
       
   539 --      GRANT SELECT ON users, transport, domain_name TO postfix;
       
   540 --
       
   541 -- For more details see postconf(5) section transport_maps and transport(5)
       
   542 -- ---
       
   543 CREATE OR REPLACE FUNCTION postfix_transport_map(
       
   544     IN localpart varchar, IN the_domain varchar)
       
   545     RETURNS SETOF recipient_transport
       
   546 AS $$
       
   547     DECLARE
       
   548         record recipient_transport;
       
   549         recipient varchar(320) := localpart || '@' || the_domain;
       
   550         did bigint := (SELECT gid FROM domain_name WHERE domainname = the_domain);
       
   551         transport_id bigint;
       
   552     BEGIN
       
   553         IF did IS NULL THEN
       
   554             RETURN;
       
   555         END IF;
       
   556 
       
   557         SELECT tid INTO transport_id
       
   558           FROM users
       
   559          WHERE gid = did AND local_part = localpart;
       
   560 
       
   561         IF transport_id IS NULL THEN
       
   562             SELECT tid INTO STRICT transport_id
       
   563               FROM domain_data
       
   564              WHERE gid = did;
       
   565         END IF;
       
   566 
       
   567         FOR record IN
       
   568             SELECT recipient, transport
       
   569               FROM transport
       
   570              WHERE tid = transport_id
       
   571             LOOP
       
   572                 RETURN NEXT record;
       
   573             END LOOP;
       
   574         RETURN;
       
   575     END;
       
   576 $$ LANGUAGE plpgsql STABLE
       
   577 RETURNS NULL ON NULL INPUT
       
   578 EXTERNAL SECURITY INVOKER;
       
   579 -- ---
       
   580 -- Parameters (from recipients address (MAIL TO) [localpart@the_domain]):
       
   581 --      varchar localpart
       
   582 --      varchar the_domain
       
   583 -- Returns: recipient_destination records
       
   584 --
       
   585 -- Required access privileges for your postfix database user:
       
   586 --      GRANT SELECT ON alias, domain_name TO postfix;
       
   587 --
       
   588 -- For more details see postconf(5) section virtual_alias_maps and virtual(5)
       
   589 -- ---
       
   590 CREATE OR REPLACE FUNCTION _interpolate_destination(
       
   591     IN destination varchar, localpart varchar, IN the_domain varchar)
       
   592     RETURNS varchar
       
   593 AS $$
       
   594     DECLARE
       
   595         result varchar(320);
       
   596     BEGIN
       
   597         IF position('%' in destination) = 0 THEN
       
   598             RETURN destination;
       
   599         END IF;
       
   600         result := replace(destination, '%n', localpart);
       
   601         result := replace(result, '%d', the_domain);
       
   602         result := replace(result, '%=', localpart || '=' || the_domain);
       
   603         RETURN result;
       
   604     END;
       
   605 $$ LANGUAGE plpgsql STABLE
       
   606 RETURNS NULL ON NULL INPUT
       
   607 EXTERNAL SECURITY INVOKER;
       
   608 
       
   609 CREATE OR REPLACE FUNCTION postfix_virtual_alias_map(
       
   610     IN localpart varchar, IN the_domain varchar)
       
   611     RETURNS SETOF recipient_destination
       
   612 AS $$
       
   613     DECLARE
       
   614         recordc recipient_destination;
       
   615         record recipient_destination;
       
   616         catchall_cursor refcursor;
       
   617         recipient varchar(320) := localpart || '@' || the_domain;
       
   618         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   619     BEGIN
       
   620         FOR record IN
       
   621             SELECT recipient,
       
   622                 _interpolate_destination(destination, localpart, the_domain)
       
   623               FROM alias
       
   624              WHERE gid = did
       
   625                AND address = localpart
       
   626             LOOP
       
   627                 RETURN NEXT record;
       
   628             END LOOP;
       
   629 
       
   630         IF NOT FOUND THEN
       
   631             -- There is no matching virtual_alias. If there are no catchall
       
   632             -- records for this domain, we can just return NULL since Postfix
       
   633             -- will then later consult mailboxes/relocated itself. But if
       
   634             -- there is a catchall destination, then it would take precedence
       
   635             -- over mailboxes/relocated, which is not what we want. Therefore,
       
   636             -- we must first find out if the query is for an existing mailbox
       
   637             -- or relocated entry and return the identity mapping if that is
       
   638             -- the case
       
   639             OPEN catchall_cursor FOR
       
   640                 SELECT recipient,
       
   641                     _interpolate_destination(destination, localpart, the_domain)
       
   642                   FROM catchall
       
   643                  WHERE gid = did;
       
   644             FETCH NEXT FROM catchall_cursor INTO recordc;
       
   645 
       
   646             IF recordc IS NOT NULL THEN
       
   647                 -- Since there are catchall records for this domain
       
   648                 -- check the mailbox and relocated records and return identity
       
   649                 -- if a matching record exists.
       
   650                 FOR record IN
       
   651                     SELECT recipient, recipient as destination
       
   652                       FROM users
       
   653                     WHERE gid = did
       
   654                       AND local_part = localpart
       
   655                     UNION SELECT recipient, recipient as destination
       
   656                       FROM relocated
       
   657                     WHERE gid = did
       
   658                       AND address = localpart
       
   659                     LOOP
       
   660                         RETURN NEXT record;
       
   661                     END LOOP;
       
   662 
       
   663                 IF NOT FOUND THEN
       
   664                     -- There were no records found for mailboxes/relocated,
       
   665                     -- so now we can actually iterate the cursor and populate
       
   666                     -- the return set
       
   667                     LOOP
       
   668                         RETURN NEXT recordc;
       
   669                         FETCH NEXT FROM catchall_cursor INTO recordc;
       
   670                         EXIT WHEN recordc IS NULL;
       
   671                     END LOOP;
       
   672                 END IF;
       
   673             END IF;
       
   674             CLOSE catchall_cursor;
       
   675         END IF;
       
   676         RETURN;
       
   677     END;
       
   678 $$ LANGUAGE plpgsql STABLE
       
   679 RETURNS NULL ON NULL INPUT
       
   680 EXTERNAL SECURITY INVOKER;
       
   681 -- ---
       
   682 -- Parameters (from recipients address (MAIL TO) [localpart@the_domain]):
       
   683 --      varchar localpart
       
   684 --      varchar the_domain
       
   685 -- Returns: address_maildir records
       
   686 --
       
   687 -- Required access privileges for your postfix database user:
       
   688 --      GRANT SELECT ON domain_data,domain_name,maillocation,users TO postfix;
       
   689 --
       
   690 -- For more details see postconf(5) section virtual_mailbox_maps
       
   691 -- ---
       
   692 CREATE OR REPLACE FUNCTION postfix_virtual_mailbox_map(
       
   693    IN localpart varchar, IN the_domain varchar) RETURNS SETOF address_maildir
       
   694 AS $$
       
   695     DECLARE
       
   696         rec address_maildir;
       
   697         did bigint := (SELECT gid FROM domain_name WHERE domainname=the_domain);
       
   698         address varchar(320) := localpart || '@' || the_domain;
       
   699     BEGIN
       
   700         FOR rec IN
       
   701             SELECT address, domaindir||'/'||users.uid||'/'||directory||'/'
       
   702               FROM domain_data, users, maillocation
       
   703              WHERE domain_data.gid = did
       
   704                AND users.gid = did
       
   705                AND users.local_part = localpart
       
   706                AND maillocation.mid = users.mid
       
   707             LOOP
       
   708                 RETURN NEXT rec;
       
   709             END LOOP;
       
   710         RETURN;
       
   711     END;
       
   712 $$ LANGUAGE plpgsql STABLE
       
   713 RETURNS NULL ON NULL INPUT
       
   714 EXTERNAL SECURITY INVOKER;
       
   715 -- ---
       
   716 -- Parameters (from recipients address (MAIL TO) [localpart@the_domain]):
       
   717 --      varchar localpart
       
   718 --      varchar the_domain
       
   719 -- Returns: recipient_uid records
       
   720 --
       
   721 -- Required access privileges for your postfix database user:
       
   722 --      GRANT SELECT ON users, domain_name TO postfix;
       
   723 --
       
   724 -- For more details see postconf(5) section virtual_uid_maps
       
   725 -- ---
       
   726 CREATE OR REPLACE FUNCTION postfix_virtual_uid_map(
       
   727     IN localpart varchar, IN the_domain varchar) RETURNS SETOF recipient_uid
       
   728 AS $$
       
   729     DECLARE
       
   730         record recipient_uid;
       
   731         recipient varchar(320) := localpart || '@' || the_domain;
       
   732     BEGIN
       
   733         FOR record IN
       
   734             SELECT recipient, uid
       
   735               FROM users
       
   736              WHERE gid = (SELECT gid
       
   737                             FROM domain_name
       
   738                            WHERE domainname = the_domain)
       
   739                AND local_part = localpart
       
   740             LOOP
       
   741                 RETURN NEXT record;
       
   742             END LOOP;
       
   743         RETURN;
       
   744     END;
       
   745 $$ LANGUAGE plpgsql STABLE
       
   746 RETURNS NULL ON NULL INPUT
       
   747 EXTERNAL SECURITY INVOKER;