MySQL support
This commit is contained in:
10
.env.example
10
.env.example
@@ -8,4 +8,12 @@ SES_PASS=your_ses_secret_access_key
|
|||||||
# Optional: SMTP server configuration
|
# Optional: SMTP server configuration
|
||||||
# Default is EU West 2 - change if using different region
|
# Default is EU West 2 - change if using different region
|
||||||
SMTP_HOST=email-smtp.eu-west-2.amazonaws.com
|
SMTP_HOST=email-smtp.eu-west-2.amazonaws.com
|
||||||
SMTP_PORT=587
|
SMTP_PORT=587
|
||||||
|
|
||||||
|
# MySQL Database Configuration
|
||||||
|
MYSQL_HOST=mysql
|
||||||
|
MYSQL_PORT=3306
|
||||||
|
MYSQL_DATABASE=maillist
|
||||||
|
MYSQL_USER=maillist
|
||||||
|
MYSQL_PASSWORD=change_this_password
|
||||||
|
MYSQL_ROOT_PASSWORD=change_this_root_password
|
||||||
2
.github/copilot-instructions.md
vendored
2
.github/copilot-instructions.md
vendored
@@ -24,7 +24,7 @@ This is a containerized mailing list management system built around Postfix as a
|
|||||||
3. **Postfix Maps**: Hash databases generated at build time (virtual aliases) and runtime (SASL)
|
3. **Postfix Maps**: Hash databases generated at build time (virtual aliases) and runtime (SASL)
|
||||||
|
|
||||||
**Future (Dynamic):** Database-driven configuration:
|
**Future (Dynamic):** Database-driven configuration:
|
||||||
- Member lists stored in SQL database
|
- Member lists stored in SQL database, with members able to join multiple lists
|
||||||
- Web interface for CRUD operations on members
|
- Web interface for CRUD operations on members
|
||||||
- `virtual_aliases.cf` generated from database at runtime
|
- `virtual_aliases.cf` generated from database at runtime
|
||||||
- Postfix reload triggered by configuration changes
|
- Postfix reload triggered by configuration changes
|
||||||
|
|||||||
137
database/README.md
Normal file
137
database/README.md
Normal file
@@ -0,0 +1,137 @@
|
|||||||
|
# Database-Driven Mailing List Management
|
||||||
|
|
||||||
|
This mailing list system uses MySQL with **Postfix's native MySQL support** for real-time dynamic list management. Postfix queries the database directly for each email - no scripts or reloads needed.
|
||||||
|
|
||||||
|
## Database Schema
|
||||||
|
|
||||||
|
Three-table design with many-to-many relationships:
|
||||||
|
|
||||||
|
### Tables
|
||||||
|
|
||||||
|
**`lists`** - Mailing list definitions
|
||||||
|
- `list_id` (primary key)
|
||||||
|
- `list_name` - Display name
|
||||||
|
- `list_email` - Full email address (e.g., `community@lists.sasalliance.org`)
|
||||||
|
- `description` - Optional description
|
||||||
|
- `active` - Boolean flag to enable/disable list
|
||||||
|
|
||||||
|
**`members`** - Member information
|
||||||
|
- `member_id` (primary key)
|
||||||
|
- `name` - Display name
|
||||||
|
- `email` - Email address
|
||||||
|
- `active` - Boolean flag to enable/disable member
|
||||||
|
|
||||||
|
**`list_members`** - Subscription junction table
|
||||||
|
- `list_id` + `member_id` (composite unique key)
|
||||||
|
- `active` - Boolean flag to enable/disable subscription
|
||||||
|
- Foreign keys to `lists` and `members`
|
||||||
|
|
||||||
|
## How It Works
|
||||||
|
|
||||||
|
1. **Incoming email** arrives for `community@lists.sasalliance.org`
|
||||||
|
2. **Postfix queries MySQL** using the config in `mysql_virtual_alias_maps.cf`
|
||||||
|
3. **Database returns** comma-separated list of active member emails
|
||||||
|
4. **Postfix expands** the alias and delivers to all members
|
||||||
|
5. **Changes take effect immediately** - no restart or reload needed!
|
||||||
|
|
||||||
|
## Managing Lists and Members
|
||||||
|
|
||||||
|
### Via MySQL Client
|
||||||
|
|
||||||
|
Connect to the database:
|
||||||
|
|
||||||
|
```bash
|
||||||
|
docker-compose exec mysql mysql -u maillist -p maillist
|
||||||
|
```
|
||||||
|
|
||||||
|
### Common Operations
|
||||||
|
|
||||||
|
**View all lists:**
|
||||||
|
```sql
|
||||||
|
SELECT list_id, list_name, list_email, active FROM lists;
|
||||||
|
```
|
||||||
|
|
||||||
|
**View all members:**
|
||||||
|
```sql
|
||||||
|
SELECT member_id, name, email, active FROM members;
|
||||||
|
```
|
||||||
|
|
||||||
|
**View subscriptions for a list:**
|
||||||
|
```sql
|
||||||
|
SELECT m.name, m.email
|
||||||
|
FROM members m
|
||||||
|
JOIN list_members lm ON m.member_id = lm.member_id
|
||||||
|
JOIN lists l ON lm.list_id = l.list_id
|
||||||
|
WHERE l.list_email = 'community@lists.sasalliance.org'
|
||||||
|
AND lm.active = TRUE AND m.active = TRUE;
|
||||||
|
```
|
||||||
|
|
||||||
|
**Add a new member:**
|
||||||
|
```sql
|
||||||
|
INSERT INTO members (name, email)
|
||||||
|
VALUES ('John Doe', 'john.doe@example.com');
|
||||||
|
```
|
||||||
|
|
||||||
|
**Subscribe member to list:**
|
||||||
|
```sql
|
||||||
|
-- Method 1: Using subqueries (one step)
|
||||||
|
INSERT INTO list_members (list_id, member_id)
|
||||||
|
VALUES (
|
||||||
|
(SELECT list_id FROM lists WHERE list_email = 'community@lists.sasalliance.org'),
|
||||||
|
(SELECT member_id FROM members WHERE email = 'john.doe@example.com')
|
||||||
|
);
|
||||||
|
```
|
||||||
|
|
||||||
|
**Unsubscribe member from list:**
|
||||||
|
```sql
|
||||||
|
DELETE FROM list_members
|
||||||
|
WHERE list_id = (SELECT list_id FROM lists WHERE list_email = 'community@lists.sasalliance.org')
|
||||||
|
AND member_id = (SELECT member_id FROM members WHERE email = 'john.doe@example.com');
|
||||||
|
```
|
||||||
|
|
||||||
|
**Create a new mailing list:**
|
||||||
|
```sql
|
||||||
|
INSERT INTO lists (list_name, list_email, description)
|
||||||
|
VALUES ('Developers', 'dev@lists.sasalliance.org', 'Developer discussions');
|
||||||
|
```
|
||||||
|
|
||||||
|
**Disable a list (keeps data, stops delivery):**
|
||||||
|
```sql
|
||||||
|
UPDATE lists SET active = FALSE WHERE list_email = 'community@lists.sasalliance.org';
|
||||||
|
```
|
||||||
|
|
||||||
|
**Re-enable a list:**
|
||||||
|
```sql
|
||||||
|
UPDATE lists SET active = TRUE WHERE list_email = 'community@lists.sasalliance.org';
|
||||||
|
```
|
||||||
|
|
||||||
|
## Verification
|
||||||
|
|
||||||
|
Test that Postfix can query the database:
|
||||||
|
|
||||||
|
```bash
|
||||||
|
docker-compose exec postfix postmap -q "community@lists.sasalliance.org" mysql:/etc/postfix/mysql_virtual_alias_maps.cf
|
||||||
|
```
|
||||||
|
|
||||||
|
This should return a comma-separated list of member email addresses.
|
||||||
|
|
||||||
|
## Database Initialization
|
||||||
|
|
||||||
|
The database is automatically initialized from `database/schema.sql` when the MySQL container first starts. Sample data includes:
|
||||||
|
|
||||||
|
- 4 mailing lists (community, board, members, announcements)
|
||||||
|
- 2 sample members
|
||||||
|
- Sample subscriptions
|
||||||
|
|
||||||
|
### Reset Database
|
||||||
|
|
||||||
|
To completely reset the database (deletes all data!):
|
||||||
|
|
||||||
|
```bash
|
||||||
|
docker-compose down -v # Remove volumes
|
||||||
|
docker-compose up -d # Reinitialize from schema.sql
|
||||||
|
```
|
||||||
|
|
||||||
|
## Performance
|
||||||
|
|
||||||
|
Postfix caches MySQL query results, so the database isn't queried for every single email. The cache TTL is configurable in `mysql_virtual_alias_maps.cf` if needed.
|
||||||
75
database/schema.sql
Normal file
75
database/schema.sql
Normal file
@@ -0,0 +1,75 @@
|
|||||||
|
-- Mail List Manager Database Schema
|
||||||
|
|
||||||
|
-- Table: lists
|
||||||
|
-- Stores mailing list information
|
||||||
|
CREATE TABLE IF NOT EXISTS lists (
|
||||||
|
list_id INT AUTO_INCREMENT PRIMARY KEY,
|
||||||
|
list_name VARCHAR(100) NOT NULL UNIQUE,
|
||||||
|
list_email VARCHAR(255) NOT NULL UNIQUE,
|
||||||
|
description TEXT,
|
||||||
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||||
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||||
|
active BOOLEAN DEFAULT TRUE,
|
||||||
|
INDEX idx_list_email (list_email),
|
||||||
|
INDEX idx_active (active)
|
||||||
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
|
||||||
|
|
||||||
|
-- Table: members
|
||||||
|
-- Stores member information
|
||||||
|
CREATE TABLE IF NOT EXISTS members (
|
||||||
|
member_id INT AUTO_INCREMENT PRIMARY KEY,
|
||||||
|
name VARCHAR(255) NOT NULL,
|
||||||
|
email VARCHAR(255) NOT NULL UNIQUE,
|
||||||
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||||
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||||
|
active BOOLEAN DEFAULT TRUE,
|
||||||
|
INDEX idx_email (email),
|
||||||
|
INDEX idx_active (active)
|
||||||
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
|
||||||
|
|
||||||
|
-- Table: list_members
|
||||||
|
-- Junction table for many-to-many relationship between lists and members
|
||||||
|
CREATE TABLE IF NOT EXISTS list_members (
|
||||||
|
id INT AUTO_INCREMENT PRIMARY KEY,
|
||||||
|
list_id INT NOT NULL,
|
||||||
|
member_id INT NOT NULL,
|
||||||
|
subscribed_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||||
|
active BOOLEAN DEFAULT TRUE,
|
||||||
|
FOREIGN KEY (list_id) REFERENCES lists(list_id) ON DELETE CASCADE,
|
||||||
|
FOREIGN KEY (member_id) REFERENCES members(member_id) ON DELETE CASCADE,
|
||||||
|
UNIQUE KEY unique_list_member (list_id, member_id),
|
||||||
|
INDEX idx_list_id (list_id),
|
||||||
|
INDEX idx_member_id (member_id),
|
||||||
|
INDEX idx_active (active)
|
||||||
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
|
||||||
|
|
||||||
|
-- Insert sample data
|
||||||
|
INSERT INTO lists (list_name, list_email, description) VALUES
|
||||||
|
('Community', 'community@lists.sasalliance.org', 'General community announcements'),
|
||||||
|
('Board', 'board@lists.sasalliance.org', 'Board members only'),
|
||||||
|
('Members', 'members@lists.sasalliance.org', 'All members'),
|
||||||
|
('Announcements', 'announcements@lists.sasalliance.org', 'Important announcements');
|
||||||
|
|
||||||
|
INSERT INTO members (name, email) VALUES
|
||||||
|
('James Pattinson', 'james.pattinson@sasalliance.org'),
|
||||||
|
('James Pattinson (Personal)', 'james@pattinson.org');
|
||||||
|
|
||||||
|
-- Subscribe members to lists
|
||||||
|
-- Community list - both addresses
|
||||||
|
INSERT INTO list_members (list_id, member_id) VALUES
|
||||||
|
(1, 1), -- James (work) on Community
|
||||||
|
(1, 2); -- James (personal) on Community
|
||||||
|
|
||||||
|
-- Board list - work address only
|
||||||
|
INSERT INTO list_members (list_id, member_id) VALUES
|
||||||
|
(2, 1); -- James (work) on Board
|
||||||
|
|
||||||
|
-- Members list - both addresses
|
||||||
|
INSERT INTO list_members (list_id, member_id) VALUES
|
||||||
|
(3, 1), -- James (work) on Members
|
||||||
|
(3, 2); -- James (personal) on Members
|
||||||
|
|
||||||
|
-- Announcements list - both addresses
|
||||||
|
INSERT INTO list_members (list_id, member_id) VALUES
|
||||||
|
(4, 1), -- James (work) on Announcements
|
||||||
|
(4, 2); -- James (personal) on Announcements
|
||||||
@@ -1,8 +1,33 @@
|
|||||||
version: "3.9"
|
version: "3.9"
|
||||||
services:
|
services:
|
||||||
|
mysql:
|
||||||
|
image: mysql:8.0
|
||||||
|
container_name: maillist-mysql
|
||||||
|
environment:
|
||||||
|
MYSQL_ROOT_PASSWORD: ${MYSQL_ROOT_PASSWORD}
|
||||||
|
MYSQL_DATABASE: ${MYSQL_DATABASE:-maillist}
|
||||||
|
MYSQL_USER: ${MYSQL_USER:-maillist}
|
||||||
|
MYSQL_PASSWORD: ${MYSQL_PASSWORD}
|
||||||
|
volumes:
|
||||||
|
- mysql_data:/var/lib/mysql
|
||||||
|
- ./database/schema.sql:/docker-entrypoint-initdb.d/schema.sql
|
||||||
|
ports:
|
||||||
|
- "3307:3306"
|
||||||
|
healthcheck:
|
||||||
|
test: ["CMD", "mysqladmin", "ping", "-h", "localhost"]
|
||||||
|
interval: 10s
|
||||||
|
timeout: 5s
|
||||||
|
retries: 5
|
||||||
|
|
||||||
postfix:
|
postfix:
|
||||||
build: ./postfix
|
build: ./postfix
|
||||||
container_name: postfix
|
container_name: postfix
|
||||||
env_file: .env
|
env_file: .env
|
||||||
|
depends_on:
|
||||||
|
mysql:
|
||||||
|
condition: service_healthy
|
||||||
ports:
|
ports:
|
||||||
- "25:25"
|
- "25:25"
|
||||||
|
|
||||||
|
volumes:
|
||||||
|
mysql_data:
|
||||||
|
|||||||
@@ -4,21 +4,22 @@ FROM debian:stable-slim
|
|||||||
RUN apt-get update && \
|
RUN apt-get update && \
|
||||||
DEBIAN_FRONTEND=noninteractive apt-get install -y \
|
DEBIAN_FRONTEND=noninteractive apt-get install -y \
|
||||||
postfix \
|
postfix \
|
||||||
|
postfix-mysql \
|
||||||
libsasl2-modules \
|
libsasl2-modules \
|
||||||
mailutils \
|
mailutils \
|
||||||
gettext-base \
|
gettext-base \
|
||||||
|
netcat-openbsd \
|
||||||
&& apt-get clean && rm -rf /var/lib/apt/lists/*
|
&& apt-get clean && rm -rf /var/lib/apt/lists/*
|
||||||
|
|
||||||
# Copy configs
|
# Copy configs
|
||||||
COPY main.cf.template /etc/postfix/main.cf.template
|
COPY main.cf.template /etc/postfix/main.cf.template
|
||||||
COPY sasl_passwd.template /etc/postfix/sasl_passwd.template
|
COPY sasl_passwd.template /etc/postfix/sasl_passwd.template
|
||||||
COPY virtual_aliases.cf /etc/postfix/virtual_aliases.cf
|
COPY mysql_virtual_alias_maps.cf /etc/postfix/mysql_virtual_alias_maps.cf.template
|
||||||
COPY sender_access /etc/postfix/sender_access
|
COPY sender_access /etc/postfix/sender_access
|
||||||
COPY entrypoint.sh /entrypoint.sh
|
COPY entrypoint.sh /entrypoint.sh
|
||||||
RUN chmod +x /entrypoint.sh
|
RUN chmod +x /entrypoint.sh
|
||||||
|
|
||||||
# Generate Postfix maps for virtual aliases and sender access
|
# Generate Postfix maps for sender access
|
||||||
RUN postmap /etc/postfix/virtual_aliases.cf
|
|
||||||
RUN postmap /etc/postfix/sender_access
|
RUN postmap /etc/postfix/sender_access
|
||||||
|
|
||||||
# Expose SMTP
|
# Expose SMTP
|
||||||
|
|||||||
@@ -4,16 +4,33 @@ set -e
|
|||||||
# Generate main.cf from template with environment variables
|
# Generate main.cf from template with environment variables
|
||||||
envsubst < /etc/postfix/main.cf.template > /etc/postfix/main.cf
|
envsubst < /etc/postfix/main.cf.template > /etc/postfix/main.cf
|
||||||
|
|
||||||
|
# Generate MySQL virtual alias config from template
|
||||||
|
envsubst < /etc/postfix/mysql_virtual_alias_maps.cf.template > /etc/postfix/mysql_virtual_alias_maps.cf
|
||||||
|
|
||||||
# Generate SASL password file from environment variables
|
# Generate SASL password file from environment variables
|
||||||
envsubst < /etc/postfix/sasl_passwd.template > /etc/postfix/sasl_passwd
|
envsubst < /etc/postfix/sasl_passwd.template > /etc/postfix/sasl_passwd
|
||||||
|
|
||||||
|
# Wait for MySQL to be ready
|
||||||
|
echo "Waiting for MySQL to be ready..."
|
||||||
|
for i in $(seq 1 30); do
|
||||||
|
if nc -z ${MYSQL_HOST} ${MYSQL_PORT} 2>/dev/null; then
|
||||||
|
echo "MySQL is ready!"
|
||||||
|
break
|
||||||
|
fi
|
||||||
|
echo "Waiting for MySQL... ($i/30)"
|
||||||
|
sleep 2
|
||||||
|
done
|
||||||
|
|
||||||
# Generate Postfix hash databases
|
# Generate Postfix hash databases
|
||||||
postmap /etc/postfix/sasl_passwd
|
postmap /etc/postfix/sasl_passwd
|
||||||
chmod 600 /etc/postfix/sasl_passwd /etc/postfix/sasl_passwd.db
|
chmod 600 /etc/postfix/sasl_passwd /etc/postfix/sasl_passwd.db
|
||||||
|
|
||||||
# Regenerate sender_access database (in case of updates)
|
# Regenerate sender_access database
|
||||||
postmap /etc/postfix/sender_access
|
postmap /etc/postfix/sender_access
|
||||||
chmod 644 /etc/postfix/sender_access /etc/postfix/sender_access.db
|
chmod 644 /etc/postfix/sender_access /etc/postfix/sender_access.db
|
||||||
|
|
||||||
|
# Set permissions on MySQL config
|
||||||
|
chmod 644 /etc/postfix/mysql_virtual_alias_maps.cf
|
||||||
|
|
||||||
# Start Postfix in foreground
|
# Start Postfix in foreground
|
||||||
exec postfix start-fg
|
exec postfix start-fg
|
||||||
|
|||||||
@@ -16,8 +16,8 @@ smtp_sasl_auth_enable = yes
|
|||||||
smtp_sasl_password_maps = hash:/etc/postfix/sasl_passwd
|
smtp_sasl_password_maps = hash:/etc/postfix/sasl_passwd
|
||||||
smtp_sasl_security_options = noanonymous
|
smtp_sasl_security_options = noanonymous
|
||||||
|
|
||||||
# Virtual aliases (static for now)
|
# Virtual aliases - dynamic MySQL lookup
|
||||||
virtual_alias_maps = hash:/etc/postfix/virtual_aliases.cf
|
virtual_alias_maps = mysql:/etc/postfix/mysql_virtual_alias_maps.cf
|
||||||
|
|
||||||
# Sender restrictions - enforce whitelist
|
# Sender restrictions - enforce whitelist
|
||||||
smtpd_sender_restrictions =
|
smtpd_sender_restrictions =
|
||||||
|
|||||||
14
postfix/mysql_virtual_alias_maps.cf
Normal file
14
postfix/mysql_virtual_alias_maps.cf
Normal file
@@ -0,0 +1,14 @@
|
|||||||
|
# Postfix MySQL query for virtual aliases
|
||||||
|
# This file queries the database to expand mailing list addresses to member emails
|
||||||
|
|
||||||
|
# Database connection settings
|
||||||
|
hosts = ${MYSQL_HOST}
|
||||||
|
port = ${MYSQL_PORT}
|
||||||
|
user = ${MYSQL_USER}
|
||||||
|
password = ${MYSQL_PASSWORD}
|
||||||
|
dbname = ${MYSQL_DATABASE}
|
||||||
|
|
||||||
|
# Query to get recipients for a mailing list
|
||||||
|
# Input: full email address (e.g., community@lists.sasalliance.org)
|
||||||
|
# Output: comma-separated list of recipient emails
|
||||||
|
query = SELECT GROUP_CONCAT(m.email SEPARATOR ', ') FROM lists l INNER JOIN list_members lm ON l.list_id = lm.list_id INNER JOIN members m ON lm.member_id = m.member_id WHERE l.list_email = '%s' AND l.active = 1 AND m.active = 1 AND lm.active = 1 GROUP BY l.list_id
|
||||||
@@ -1 +1,11 @@
|
|||||||
community@lists.sasalliance.org james@pattinson.org, james.pattinson@sasalliance.org
|
# Community mailing list - general announcements
|
||||||
|
community@lists.sasalliance.org james@pattinson.org, james.pattinson@sasalliance.org
|
||||||
|
|
||||||
|
# Board members mailing list
|
||||||
|
board@lists.sasalliance.org james.pattinson@sasalliance.org
|
||||||
|
|
||||||
|
# All members mailing list
|
||||||
|
members@lists.sasalliance.org james@pattinson.org, james.pattinson@sasalliance.org
|
||||||
|
|
||||||
|
# Announcements mailing list
|
||||||
|
announcements@lists.sasalliance.org james@pattinson.org, james.pattinson@sasalliance.org
|
||||||
Reference in New Issue
Block a user