1 | SET SQL_MODE="NO_AUTO_VALUE_ON_ZERO"; |
---|
2 | SET time_zone = "+00:00"; |
---|
3 | |
---|
4 | |
---|
5 | /*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */; |
---|
6 | /*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */; |
---|
7 | /*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */; |
---|
8 | /*!40101 SET NAMES utf8 */; |
---|
9 | |
---|
10 | -- |
---|
11 | -- База данных: `mail` |
---|
12 | -- |
---|
13 | |
---|
14 | CREATE TABLE IF NOT EXISTS `virtual_aliases` ( |
---|
15 | `id` int(11) NOT NULL AUTO_INCREMENT, |
---|
16 | `alias_prefix` varchar(32) NOT NULL, |
---|
17 | `domain_id` int(11) NOT NULL, |
---|
18 | `user_id` int(11) NOT NULL, |
---|
19 | PRIMARY KEY (`id`), |
---|
20 | KEY `domain_id` (`domain_id`), |
---|
21 | KEY `user_id` (`user_id`), |
---|
22 | KEY `alias_prefix` (`alias_prefix`) |
---|
23 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8 AUTO_INCREMENT=1 ; |
---|
24 | |
---|
25 | |
---|
26 | CREATE TABLE IF NOT EXISTS `virtual_domains` ( |
---|
27 | `id` int(11) NOT NULL AUTO_INCREMENT, |
---|
28 | `name` varchar(64) NOT NULL, |
---|
29 | PRIMARY KEY (`id`) |
---|
30 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8 AUTO_INCREMENT=1 ; |
---|
31 | |
---|
32 | -- |
---|
33 | -- Ограничения внешнего ключа сохраненных таблиц |
---|
34 | -- |
---|
35 | |
---|
36 | -- |
---|
37 | -- Ограничения внешнего ключа таблицы `virtual_aliases` |
---|
38 | -- |
---|
39 | ALTER TABLE `virtual_aliases` |
---|
40 | ADD CONSTRAINT `virtual_aliases_user_id` FOREIGN KEY (`user_id`) REFERENCES `multimag`.`users` (`id`), |
---|
41 | ADD CONSTRAINT `virtual_aliases_ibfk_2` FOREIGN KEY (`domain_id`) REFERENCES `virtual_domains` (`id`); |
---|
42 | -- |
---|
43 | -- Структура таблицы `virtual_domains` |
---|
44 | -- |
---|
45 | |
---|
46 | |
---|
47 | -- |
---|
48 | -- Структура для представления `view_aliases` |
---|
49 | -- |
---|
50 | DROP VIEW IF EXISTS `view_aliases`; |
---|
51 | DROP VIEW IF EXISTS `view_users`; |
---|
52 | DROP VIEW IF EXISTS `view_users_auth`; |
---|
53 | |
---|
54 | CREATE VIEW `view_first_domain` AS |
---|
55 | SELECT `id`, `name` FROM `virtual_domains` ORDER BY `id` LIMIT 1; |
---|
56 | |
---|
57 | CREATE VIEW `view_users_auth` AS |
---|
58 | SELECT `mu`.`id` AS `id`, LOWER(`mu`.`name`) AS `user`, CONCAT('{', `mu`.`pass_type`, '}',`mu`.`pass`) AS `password` |
---|
59 | FROM `multimag`.`users` AS `mu` |
---|
60 | INNER JOIN `multimag`. `users_worker_info` AS `mwi` ON `mwi`.`user_id` = `mu`.`id` |
---|
61 | AND `mwi`.`worker` = 1 |
---|
62 | WHERE `mu`.`pass_type` != '' |
---|
63 | UNION |
---|
64 | SELECT `mu`.`id` AS `id`, LOWER(`mu`.`name`) AS `user`, CONCAT('{MD5}',`mu`.`pass`) AS `password` |
---|
65 | FROM `multimag`.`users` AS `mu` |
---|
66 | INNER JOIN `multimag`. `users_worker_info` AS `mwi` ON `mwi`.`user_id` = `mu`.`id` |
---|
67 | AND `mwi`.`worker` = 1 |
---|
68 | WHERE `mu`.`pass_type` = ''; |
---|
69 | |
---|
70 | |
---|
71 | CREATE VIEW `view_aliases` AS |
---|
72 | SELECT CONCAT('all@', `vd`.`name`) AS `email`, CONCAT(LOWER(`mu`.`name`), '@', `vf`.`name`) AS `destination`, LOWER(`mu`.`name`) AS `user` |
---|
73 | FROM `mail`.`virtual_domains` AS `vd`, `mail`.`view_first_domain` AS `vf`, `multimag`.`users` AS `mu` |
---|
74 | INNER JOIN `multimag`.`users_worker_info` AS `uwi` |
---|
75 | ON `uwi`.`user_id` = `mu`.`id` AND `uwi`.`worker` = 1 |
---|
76 | UNION |
---|
77 | SELECT CONCAT(LOWER(`mu`.`name`), '@', `vd`.`name`) AS `email`, CONCAT(LOWER(`mu`.`name`), '@', `vf`.`name`) AS `destination`, LOWER(`mu`.`name`) AS `user` |
---|
78 | FROM `mail`.`virtual_domains` AS `vd`, `mail`.`view_first_domain` AS `vf`, `multimag`.`users` AS `mu` |
---|
79 | INNER JOIN `multimag`.`users_worker_info` AS `uwi` |
---|
80 | ON `uwi`.`user_id` = `mu`.`id` AND `uwi`.`worker` = 1 |
---|
81 | UNION |
---|
82 | SELECT CONCAT(`va`.`alias_prefix`, '@', `vd`.`name`) AS `email`, CONCAT(LOWER(`mu`.`name`), '@', `vf`.`name`) AS `destination`, LOWER(`mu`.`name`) AS `user` |
---|
83 | FROM `mail`.`view_first_domain` AS `vf`, `virtual_aliases` AS `va` |
---|
84 | INNER JOIN `multimag`.`users` AS `mu` |
---|
85 | ON `mu`.`id` = `va`.`user_id` |
---|
86 | INNER JOIN `multimag`.`users_worker_info` AS `uwi` |
---|
87 | ON `va`.`user_id` = `mu`.`id` AND `uwi`.`worker` = 1 |
---|
88 | INNER JOIN `virtual_domains` AS `vd` |
---|
89 | ON `vd`.`id` = `va`.`domain_id` |
---|
90 | |
---|
91 | |
---|
92 | |
---|