Browse Source

Added files

Joachim M. Giæver 6 years ago
parent
commit
e80913699e

+ 5 - 1
README.md

@@ -1,3 +1,7 @@
 # postfix-dovecot-mysql
 
-Modifies the database layout from the Linode article «Email with Postfix, Dovecot, and MySQL» to flexible layout, with less maintenance.
+Modifies the database layout from the Linode article «Email with Postfix, Dovecot, and MySQL» to flexible layout, with less maintenance.
+
+Please follow the instructions at [Linode](https://www.linode.com/docs/email/postfix/email-with-postfix-dovecot-and-mysql) (alt. [raw text on github](https://raw.githubusercontent.com/linode/docs/master/docs/email/postfix/email-with-postfix-dovecot-and-mysql.md).
+
+Also have a read in the file `postfix.sql` and every other files before you're installing this, so you will get a grip on when you have to do something differently than explained in the tutorial.

+ 23 - 0
dovecot-sql.conf.ext

@@ -0,0 +1,23 @@
+# Not complete!!
+# Covers only changes to queries
+
+password_query = SELECT \
+	CONCAT(`virtual_users`.`username`, '@', `virtual_domains`.`name`) as `user`, `virtual_users`.`password` \
+	FROM `mailserver`.`virtual_users` \
+	INNER JOIN `mailserver`.`virtual_domains` \
+	ON `virtual_domains`.`id` = `virtual_users`.`domain_id` \
+	AND `virtual_domains`.`name` = SUBSTRING_INDEX('%u', '@', -1) \
+	WHERE `virtual_users`.`username` = SUBSTRING_INDEX('%u', '@', 1);
+
+# Alternatively (suppport login as aliases) Read more about this in the tutorial
+#password_query = SELECT \
+#	CONCAT(`virtual_users`.`username`, '@', `virtual_domains`.`name`) as `user`, `virtual_users`.`password` \
+#	FROM `mailserver`.`virtual_alias` \
+#	INNER JOIN `virtual_users`.`user_id`
+#	ON `virtual_users`.`id` = `virtual_aliases`.`user_id` \
+#	INNER JOIN `mailserver`.`virtual_domains` \
+#	ON `virtual_domains`.`id` = `virtual_users`.`domain_id` \
+#	AND `virtual_domains`.`name` = SUBSTRING_INDEX('%u', '@', -1) \
+#	WHERE `virtual_alias`.`alias` = SUBSTRING_INDEX('%u', '@', 1);
+
+

+ 12 - 0
mysql-virtual-alias-maps.cf

@@ -0,0 +1,12 @@
+user = mailuser
+password = mailuserpass
+hosts = 127.0.0.1
+dbname = mailserver
+query = SELECT CONCAT(`virtual_users`.`username`, '@', `virtual_domains`.`name`) as destination 
+	FROM `mailserver`.`virtual_aliases`
+	INNER JOIN `mailserver`.`virtual_users` 
+	ON `virtual_users`.`id` = `virtual_aliases`.`user_id`
+	INNER JOIN `mailserver`.`virtual_domains` 
+	ON `virtual_domains`.`id` = `virtual_users`.`domain_id` 
+	AND `virtual_domains`.`name` = SUBSTRING_INDEX('%s', '@', -1) 
+	WHERE `virtual_aliases`.`alias` = SUBSTRING_INDEX('%s', '@', 1);

+ 10 - 0
mysql-virtual-email2email.cf

@@ -0,0 +1,10 @@
+user = mailuser
+password = mailuserpass
+hosts = 127.0.0.1
+dbname = mailserver
+query =SELECT CONCAT(`virtual_users`.`username`, '@', `virtual_domains`.`name`) as email 
+	FROM `mailserver`.`virtual_users`
+	INNER JOIN `mailserver`.`virtual_domains` 
+	ON `virtual_domains`.`id` = `virtual_users`.`domain_id` 
+	AND `virtual_domains`.`name` = SUBSTRING_INDEX('%s', '@', -1) 
+	WHERE `virtual_users`.`username` = SUBSTRING_INDEX('%s', '@', 1);

+ 6 - 0
mysql-virtual-mailbox-domains.cf

@@ -0,0 +1,6 @@
+user = mailuser
+password = mailuserpass
+hosts = 127.0.0.1
+dbname = mailserver
+query = SELECT 1 FROM `mailserver`.`virtual_domains` 
+	WHERE `virtual_domains`.`name`='%s'

+ 9 - 0
mysql-virtual-mailbox-maps.cf

@@ -0,0 +1,9 @@
+user = mailuser
+password = mailuserpass
+hosts = 127.0.0.1
+dbname = mailserver
+query = SELECT 1 FROM `mailserver`.`virtual_users`
+	INNER JOIN `mailserver`.`virtual_domains` 
+	ON `virtual_domains`.`id` = `virtual_users`.`id` 
+	AND `virtual_domains`.`name` = SUBSTRING_INDEX('%s', '@', -1)
+	WHERE `virtual_users`.`username` = SUBSTRING_INDEX('%s', '@', 1)

+ 30 - 0
postfix-test.sql

@@ -0,0 +1,30 @@
+-- CREATE TABLES IN postfix.sql FIRST 
+ 
+-- TEST domain: expect `1 = 1`
+SELECT 1 FROM `mailserver`.`virtual_domains` 
+WHERE `virtual_domains`.`name`='domain.tld';
+
+-- TEST user: expext `1 = 1`
+SELECT 1 FROM `mailserver`.`virtual_users`
+INNER JOIN `mailserver`.`virtual_domains` 
+	ON `virtual_domains`.`id` = `virtual_users`.`id` 
+	AND `virtual_domains`.`name` = SUBSTRING_INDEX('user@domain.tld', '@', -1)
+WHERE `virtual_users`.`username` = SUBSTRING_INDEX('user@domain.tld', '@', 1);
+
+-- TEST alias: expext `destination = user@domain.tld`
+SELECT CONCAT(`virtual_users`.`username`, '@', `virtual_domains`.`name`) as destination 
+FROM `mailserver`.`virtual_aliases`
+INNER JOIN `mailserver`.`virtual_users` 
+	ON `virtual_users`.`id` = `virtual_aliases`.`user_id`
+INNER JOIN `mailserver`.`virtual_domains` 
+	ON `virtual_domains`.`id` = `virtual_users`.`domain_id` 
+	AND `virtual_domains`.`name` = SUBSTRING_INDEX('alias@domain.tld', '@', -1) 
+WHERE `virtual_aliases`.`alias` = SUBSTRING_INDEX('alias@domain.tld', '@', 1);
+
+-- TEST email 2 email: expect `email = user@domain.tld`
+SELECT CONCAT(`virtual_users`.`username`, '@', `virtual_domains`.`name`) as email 
+FROM `mailserver`.`virtual_users`
+INNER JOIN `mailserver`.`virtual_domains` 
+	ON `virtual_domains`.`id` = `virtual_users`.`domain_id` 
+	AND `virtual_domains`.`name` = SUBSTRING_INDEX('user@domain.tld', '@', -1) 
+WHERE `virtual_users`.`username` = SUBSTRING_INDEX('user@domain.tld', '@', 1);

+ 80 - 0
postfix.sql

@@ -0,0 +1,80 @@
+------------------------------------------
+-- ALTERNATIVE TABLE LAYOUT FOR TUTORIAL:
+-- Email with Postfix, Dovecot, and MySQL
+--	* https://www.linode.com/docs/email/postfix/email-with-postfix-dovecot-and-mysql
+--	* Source: https://github.com/linode/docs/blob/master/docs/email/postfix/email-with-postfix-dovecot-and-mysql.md
+--
+-- This layout is more consistence and wont require as much maintanance
+-- as the one in the tutorial, e.g will the setup in the tutorial
+-- require
+-- * update on every table if the domain name changes, even though this happens rarely.
+-- * update on aliases if the main email changes, even though this happens rarely.
+--
+-- It also ensures that 
+-- 	* the child (aliases) is deleted if a user is deleted, and not just the domain. 
+-- 	  No "dangling" aliases...
+------------------------------------------
+-- Layout
+
+-- | virtual_domains	|
+-- |++++++++++++++++++++|
+-- | id | name		|
+-- | int| <domain name>	|
+-- e.g
+-- | 1 	| domain.tld 	|
+
+-- | virtual_user							|
+-- |++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++|
+-- | id	| domain_id	| password 	| username			|
+-- | int| int		| <password>	| <username withouth domain>	|
+-- e.g ------------------------------------------------------------------
+-- | 1 	| 1		| y9w2..fudh8h9	| admin				|
+
+-- | virtual_aliases							|
+-- |++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++|
+-- | id | domain_id 	| user_id	| alias 			|
+-- | int| int		| int		| <alias without domain>	|
+-- e.g ------------------------------------------------------------------
+-- | 1 	| 1		| 1		| adminalias			|
+
+-- Create table for virtual domains
+CREATE TABLE `virtual_domains` (
+	`id` int(11) NOT NULL auto_increment,
+	`name` varchar(190) NOT NULL,
+	PRIMARY KEY (`id`)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8;
+
+-- Create a table for all of the email addresses and passwords:
+CREATE TABLE `virtual_users` (
+	`id` int(11) NOT NULL auto_increment,
+	`domain_id` int(11) NOT NULL,
+	`password` varchar(106) NOT NULL,
+	`username` varchar(64) NOT NULL,
+	PRIMARY KEY (`id`),
+	UNIQUE KEY `email` (`username`, `domain_id`),
+	FOREIGN KEY (domain_id) REFERENCES virtual_domains(id) ON DELETE CASCADE
+) ENGINE=InnoDB DEFAULT CHARSET=utf8;
+
+-- Create a table for the email aliases:
+CREATE TABLE `virtual_aliases` (
+	`id` int(11) NOT NULL auto_increment,
+	`domain_id` int(11) NOT NULL,
+	`user_id` int(11) NOT NULL,
+	`alias` varchar(100) NOT NULL,
+	PRIMARY KEY (`id`),
+	UNIQUE KEY `email` (`alias`, `domain_id`),
+	FOREIGN KEY (domain_id) REFERENCES virtual_domains(id) ON DELETE CASCADE,
+	FOREIGN KEY (user_id) REFERENCES virtual_users(id) ON DELETE CASCADE
+) ENGINE=InnoDB DEFAULT CHARSET=utf8;
+
+-- Insert hostname
+INSERT INTO `mailserver`.`virtual_domains` (`name`) VALUES ('domain.tld')
+
+-- Insert a user
+INSERT INTO `mailserver`.`virtual_users` (`domain_id`, `password`, `username`)
+VALUES ('1', ENCRYPT('password', CONCAT('$6$', SUBSTRING(SHA(RAND()), -16))), 'user');
+
+-- Insert an alias for user
+INSERT INTO `mailserver`.`virtual_aliases` (`domain_id`, `user_id`, `alias`)
+VALUES ('1', '1', 'alias');
+