Mail server database configuration

As this guide is intended to describe the implementation of a mail server using Postfix and Courier IMAP, and not a tutorial on relational database management, we will assume that you have a fully functioning PostgreSQL database installed and running either on the same host as the DNS server or on another host on your network. If this is not the case then you may be interested in the guide.

Creating the database users

The first step in the process of creating a suitable database to store our mail server configuration records will be to create two PostgreSQL database users called mail_server and mail_admin so that we can assign suitable permissions to any databases and tables we create later. The first of these users will be used by the Postfix and Courier IMAP daemons to connect to the database. This user will be mostly restricted to read access to the data contained in the database so that a subverted daemon process cannot corrupt the tables. The second user will be used when we wish to update the records stored in the database and consequently will have both read and write access.

As we shall be using the PostgreSQL tools repeatedly to create users, as well as databases and tables in the following sections, we can avoid being prompted every time for the password for the postgres account by switching to this user using the su command shown below.

lisa su - postgres
postgres@lisa 

Once you have switched user to the postgres account we can create the database users using the commands below. As you can see you will be prompted for passwords for these accounts and the passwords you provide should be both different and hard to guess as they will be used to secure the database component of the mail system.

postgres@lisa createuser -S -D -R -E -P mail_admin
Enter password for new role: 
Enter it again: 
CREATE ROLE 
postgres@lisa createuser -S -D -R -E -P mail_server
Enter password for new role: 
Enter it again: 
CREATE ROLE 

When we created the above users we passed a variety of flags to the createuser command. Briefly these flags indicate that the user should not be a super-user, should not be able to create new databases, should not be able to create new roles, that the account password should be encrypted and finally that a new password should be requested from the administrator.

Creating the database

Now that we have a user to whom we can assign ownership of the mail database we can create a new database using the following command which will create a database called mail using the UTF8 character encoding owned by the mail_admin account.

postgres@lisa createdb -O mail_admin -E UNICODE mail
CREATE DATABASE 

Creating the tables

Now that we have created a database we can create some tables to store the different types of information which the mail daemons need to function. Unlike users and databases, which are most easily created and manipulated using command-line tools, tables are most easily created and manipulated using the psql application. To start the psql application and connect to the mail database as the mail_admin account issue the following command.

postgres@lisa psql mail mail_admin
Welcome to psql 8.2.6, the PostgreSQL interactive terminal. 
 
Type:  \copyright for distribution terms 
       \h for help with SQL commands 
       \? for help with psql commands 
       \g or terminate with semicolon to execute query 
       \q to quit 
 
mail=> 

When you run the psql application you should see output similar to that shown above. You may now enter SQL commands to the database server by entering them at the prompt. To create a new table called domains, which will be used to store the information relating to the domains which we manage, enter the following code. All the text shown in gray is produced by the psql application and is only reproduced so you can see that you are progressing correctly.

postgres=# CREATE TABLE domains ( 
postgres(#   id           SERIAL          PRIMARY KEY, 
postgres(#   name         VARCHAR(128)    NOT NULL, 
postgres(#   primary_mx   BOOLEAN         NOT NULL      DEFAULT TRUE, 
postgres(#   active       BOOLEAN         NOT NULL      DEFAULT TRUE 
postgres(# ); 
NOTICE:  CREATE TABLE will create implicit sequence "domains_id_seq" for serial column "domains.id" 
NOTICE:  CREATE TABLE / PRIMARY KEY will create implicit index "domains_pkey" for table "domains" 
postgres=#  

Now that we have created a new database table in which we can store information about our domains it makes sense to ensure that we will only allow a single record in this table to correspond with each domain name we manage. This can be accomplished by issuing the following command.

postgres=# CREATE UNIQUE INDEX domain_name_index ON domains(name); 
CREATE INDEX 

Next we need to create a table in which we shall store the mailbox records which the server shall use to determine which addresses in a domain we host a mailbox for. We can do this using the command below.

postgres=# CREATE TABLE mailboxes ( 
postgres(#   id        SERIAL       PRIMARY KEY, 
postgres(#   domain_id INTEGER      NOT NULL, 
postgres(#   username  VARCHAR(128) NOT NULL, 
postgres(#   password  VARCHAR(128) NOT NULL, 
postgres(#   quota     INTEGER      NOT NULL     DEFAULT 0, 
postgres(#   active    BOOLEAN      NOT NULL     DEFAULT TRUE, 
postgres(#   CONSTRAINT domain_exists 
postgres(#     FOREIGN KEY(domain_id) REFERENCES domains(id) 
postgres(#   ON DELETE CASCADE 
postgres(# ); 
NOTICE:  CREATE TABLE will create implicit sequence "mailboxes_id_seq" for serial column "mailboxes.id" 
NOTICE:  CREATE TABLE / PRIMARY KEY will create implicit index "mailboxes_pkey" for table "mailboxes" 
CREATE TABLE 

As we don't want to allow the possibility of duplicate email addresses being entered into the mailboxes table, but we only store the user portion of the email address in our table in expanded form, the easiest way to achieve this end is to create a unique index on the domain_id and the email fields together as shown below. This also has the useful side effect of speeding up lookups when more than one record could fulfil the user part of the query.

postgres=# CREATE UNIQUE INDEX mailbox_email_unique ON mailboxes(domain_id, username); 
CREATE INDEX 

As this table will be very heavily used, and in some cases the mail server will need to query the table for records which have a field containing a particular value, we should create some additional indexes to further speed up this process by allowing the database engine to locate the rows we need without ever performing a table scan. This can be accomplished using the following commands.

postgres=# CREATE INDEX mailbox_domain_index ON mailboxes(domain_id); 
CREATE INDEX 
postgres=# CREATE INDEX mailbox_username ON mailboxes(username); 
CREATE INDEX 

Creating the views

To make our queries more concise, and to ensure that nothing is missed from the table join or active account check parts of the query, we shall create three views. The first of these views is used to restrict the list of domains to those for which we are the primary mail exchange host for and that are also marked as active. This view can be created using the SQL shown below.

postgres=# CREATE VIEW active_primary_domains AS 
postgres-#   SELECT name AS domain 
postgres-#     FROM domains 
postgres-#       WHERE active = TRUE      AND  
postgres-#             primary_mx = TRUE; 

The second view we shall create will be used by the Postfix server to map the username and domain name corresponding to the mail message which is being processed to the mail directory where the message should be delivered. This view can be created using the SQL presented below.

postgres=# CREATE VIEW active_mailbox_maps AS 
postgres-#   SELECT m.id, m.username, d.name AS domain, d.name || '/' || m.username || '/' AS maildir 
postgres-#     FROM domains d, mailboxes m 
postgres-#       WHERE m.domain_id = d.id AND 
postgres-#             d.active = TRUE    AND 
postgres-#             m.active = TRUE; 
CREATE VIEW 

As you can see we have created a virtual field in the view to represent the mailbox directory for this user. This field consists of the domain name and the email address separated by forward slashes with another forward slash appended to indicate that we will be using the maildir format to store the email. The resulting output will be in a format similar to hacking.co.uk/spamcatcher/ and can be used directly with the postfix daemon without additional processing. We also include a check to ensure that the mailbox and domain are both active.

The third, and final, view is used by the Courier authentication library as it requires that the data be presented in a somewhat different form to that required by Postfix. As you can see we have made heavy use of 'virtual fields' to provide information such as the mail directory and the combined user and domain name. As before the view also tests to ensure that both the domain and the mailbox are both active and filters those records which fail either check.

postgres=# CREATE VIEW authentication_view AS  
postgres-#   SELECT m.username || '@' || d.name AS address, m.username, d.name AS domain, m.password, 
postgres-#          d.name || '/' AS homedir, m.username || '/' AS maildir, m.quota 
postgres-#     FROM domains d, mailboxes m 
postgres-#       WHERE m.domain_id  = d.id AND 
postgres-#             d.primary_mx = TRUE AND 
postgres-#             d.active     = TRUE AND 
postgres-#             m.active     = TRUE; 
CREATE VIEW 

Setting permissions

All that remains to do, now that our tables and views have been created, is to set suitable permissions on these objects so that the daemon processes can read data from the tables but cannot add or modify data and the administrator can add, modify and delete data contained in the tables. As you can see from the example below the permissions currently assigned to the database objects can be displayed by issuing the \dp command as shown.

postgres=# \dp 
             Access privileges for database "mail" 
 Schema |          Name          |   Type   | Access privileges  
--------+------------------------+----------+------------------- 
 public | active_mailbox_maps    | view     |  
 public | active_primary_domains | view     |  
 public | authentication_view    | view     |  
 public | domains                | table    |  
 public | domains_id_seq         | sequence |  
 public | mailboxes              | table    |  
 public | mailboxes_id_seq       | sequence |  
(7 rows) 

By default PostgreSQL assigns an empty permission mask to newly created objects so you should see something similar to that shown above. If we are to accomplish our desired task of allowing the daemon process to read data from the tables and the administrator to update the data in the tables we will need to grant some more permissions. This can be done using the SQL given in the example below.

postgres=# GRANT ALL ON active_mailbox_maps, active_primary_domains, authentication_view, domains, 
postgres-#               domains_id_seq, mailboxes, mailboxes_id_seq TO mail_admin; 
GRANT 
postgres=# GRANT SELECT ON active_mailbox_maps, active_primary_domains, authentication_view TO mail_server; 
GRANT 

Once we have set the permissions on the relevant objects we can verify that they have indeed been set correctly by issuing the \dp command again. Assuming all has gone well you should see output similar to that shown below.

postgres=# \dp 
                                Access privileges for database "mail"  
 Schema |          Name          |   Type   |                    Access privileges                     
--------+------------------------+----------+--------------------------------------------------------- 
 public | active_mailbox_maps    | view     | {mail_admin=arwdxt/mail_admin,mail_server=r/mail_admin} 
 public | active_primary_domains | view     | {mail_admin=arwdxt/mail_admin,mail_server=r/mail_admin} 
 public | authentication_view    | view     | {mail_admin=arwdxt/mail_admin,mail_server=r/mail_admin} 
 public | domains                | table    | {mail_admin=arwdxt/mail_admin} 
 public | domains_id_seq         | sequence | {mail_admin=rwU/mail_admin} 
 public | mailboxes              | table    | {mail_admin=arwdxt/mail_admin} 
 public | mailboxes_id_seq       | sequence | {mail_admin=rwU/mail_admin} 
(7 rows)