MySQL support

This commit is contained in:
James Pattinson
2025-10-12 19:24:14 +00:00
parent b54014ac76
commit 35f710049a
10 changed files with 296 additions and 9 deletions

137
database/README.md Normal file
View 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
View 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