From d064fcba84e85cc744ccfa197add908294ce9b63 Mon Sep 17 00:00:00 2001 From: Matthew Saunders Brown Date: Tue, 29 Nov 2022 16:33:15 -0800 Subject: [PATCH] alter vmail db schema --- altervmail.sql | 47 +++++++++++++++++++++++++ bin/vmail-aliases-add.sh | 10 +++--- bin/vmail-aliases-del.sh | 23 ++++++------- bin/vmail-aliases-get.sh | 10 +++--- bin/vmail-autoresponders-add.sh | 22 +++++++----- bin/vmail-autoresponders-del.sh | 2 +- bin/vmail-autoresponders-get.sh | 24 ++++++------- bin/vmail-autoresponders-mod.sh | 59 +++++++++++++------------------- bin/vmail-domains-add.sh | 25 ++++++-------- bin/vmail-domains-del.sh | 8 ++--- bin/vmail-domains-get.sh | 4 +-- bin/vmail-domains-mod.sh | 2 +- bin/vmail-forwards-add.sh | 18 +++++----- bin/vmail-forwards-del.sh | 12 +++---- bin/vmail-forwards-get.sh | 12 +++---- bin/vmail-forwards-mod.sh | 50 +++++++++++++-------------- bin/vmail-mboxes-add.sh | 14 ++++---- bin/vmail-mboxes-del.sh | 8 ++--- bin/vmail-mboxes-get.sh | 34 +++++++----------- bin/vmail-mboxes-mod.sh | 27 ++++++++------- bin/vmail-purge-dirs.sh | 4 +-- etc/dovecot/dovecot-sql.conf.ext | 3 ++ etc/exim4/exim4.conf | 36 +++++++++---------- vmail.sql | 44 ++++++++++++++---------- 24 files changed, 266 insertions(+), 232 deletions(-) create mode 100644 altervmail.sql diff --git a/altervmail.sql b/altervmail.sql new file mode 100644 index 0000000..28bce76 --- /dev/null +++ b/altervmail.sql @@ -0,0 +1,47 @@ +-- add & populate new columns +ALTER TABLE vm_mboxes ADD domain VARCHAR(255) NOT NULL AFTER mbox; +UPDATE vm_mboxes SET vm_mboxes.domain = ( SELECT vm_domains.domain FROM vm_domains WHERE vm_domains.id = vm_mboxes.domain_id ); +ALTER TABLE vm_aliases ADD mbox VARCHAR(128) NOT NULL AFTER mbox_id; +ALTER TABLE vm_aliases ADD domain VARCHAR(255) NOT NULL AFTER mbox; +UPDATE vm_aliases SET vm_aliases.mbox = ( SELECT vm_mboxes.mbox FROM vm_mboxes WHERE vm_mboxes.id = vm_aliases.mbox_id ); +UPDATE vm_aliases SET vm_aliases.domain = ( SELECT vm_domains.domain FROM vm_domains, vm_mboxes WHERE vm_mboxes.id = vm_aliases.mbox_id AND vm_domains.id = vm_mboxes.domain_id ); +ALTER TABLE vm_autoresponders ADD mbox VARCHAR(128) NOT NULL AFTER mbox_id; +ALTER TABLE vm_autoresponders ADD domain VARCHAR(255) NOT NULL AFTER mbox; +UPDATE vm_autoresponders SET vm_autoresponders.mbox = ( SELECT vm_mboxes.mbox FROM vm_mboxes WHERE vm_mboxes.id = vm_autoresponders.mbox_id ); +UPDATE vm_autoresponders SET vm_autoresponders.domain = ( SELECT vm_domains.domain FROM vm_domains, vm_mboxes WHERE vm_mboxes.id = vm_autoresponders.mbox_id AND vm_domains.id = vm_mboxes.domain_id ); +ALTER TABLE vm_filters ADD mbox VARCHAR(128) NOT NULL AFTER mbox_id; +ALTER TABLE vm_filters ADD domain VARCHAR(255) NOT NULL AFTER mbox; +UPDATE vm_filters SET vm_filters.mbox = ( SELECT vm_mboxes.mbox FROM vm_mboxes WHERE vm_mboxes.id = vm_filters.mbox_id ); +UPDATE vm_filters SET vm_filters.domain = ( SELECT vm_domains.domain FROM vm_domains, vm_mboxes WHERE vm_mboxes.id = vm_filters.mbox_id AND vm_domains.id = vm_mboxes.domain_id ); +ALTER TABLE vm_forwards ADD mbox VARCHAR(128) NOT NULL AFTER mbox_id; +ALTER TABLE vm_forwards ADD domain VARCHAR(255) NOT NULL AFTER mbox; +UPDATE vm_forwards SET vm_forwards.mbox = ( SELECT vm_mboxes.mbox FROM vm_mboxes WHERE vm_mboxes.id = vm_forwards.mbox_id ); +UPDATE vm_forwards SET vm_forwards.domain = ( SELECT vm_domains.domain FROM vm_domains, vm_mboxes WHERE vm_mboxes.id = vm_forwards.mbox_id AND vm_domains.id = vm_mboxes.domain_id ); + +-- drop foreign keys +ALTER TABLE vm_mboxes DROP FOREIGN KEY domain_delete_mboxes; +ALTER TABLE vm_aliases DROP FOREIGN KEY mbox_delete_aliases; +ALTER TABLE vm_autoresponders DROP FOREIGN KEY mbox_delete_autoresponders; +ALTER TABLE vm_filters DROP FOREIGN KEY mbox_delete_filters; +ALTER TABLE vm_forwards DROP FOREIGN KEY mbox_delete_forwards; +-- update indexes +ALTER TABLE vm_domains DROP INDEX domain, ADD UNIQUE domain (domain) USING BTREE; +ALTER TABLE vm_mboxes DROP INDEX email, ADD UNIQUE email (mbox, domain) USING BTREE; +ALTER TABLE vm_aliases ADD INDEX email (mbox, domain) USING BTREE; +ALTER TABLE vm_aliases ADD UNIQUE alias (mbox, domain, alias) USING BTREE; +ALTER TABLE vm_autoresponders ADD UNIQUE email (mbox, domain) USING BTREE; +ALTER TABLE vm_filters ADD UNIQUE email (mbox, domain) USING BTREE; +ALTER TABLE vm_forwards ADD UNIQUE email (mbox, domain) USING BTREE; +-- add new foreign keys +ALTER TABLE vm_mboxes ADD CONSTRAINT domain_delete_mboxes FOREIGN KEY (domain) REFERENCES vm_domains(domain) ON DELETE CASCADE ON UPDATE NO ACTION; +ALTER TABLE vm_aliases ADD CONSTRAINT mbox_delete_aliases FOREIGN KEY (mbox, domain) REFERENCES vm_mboxes(mbox, domain) ON DELETE CASCADE ON UPDATE NO ACTION; +ALTER TABLE vm_autoresponders ADD CONSTRAINT mbox_delete_autoresponders FOREIGN KEY (mbox, domain) REFERENCES vm_mboxes(mbox, domain) ON DELETE CASCADE ON UPDATE NO ACTION; +ALTER TABLE vm_filters ADD CONSTRAINT mbox_delete_filters FOREIGN KEY (mbox, domain) REFERENCES vm_mboxes(mbox, domain) ON DELETE CASCADE ON UPDATE NO ACTION; +ALTER TABLE vm_forwards ADD CONSTRAINT mbox_delete_forwards FOREIGN KEY (mbox, domain) REFERENCES vm_mboxes(mbox, domain) ON DELETE CASCADE ON UPDATE NO ACTION; + +-- delete deprecated table columns & indexes +ALTER TABLE vm_mboxes DROP domain_id; +ALTER TABLE vm_aliases DROP mbox_id; +ALTER TABLE vm_autoresponders DROP mbox_id; +ALTER TABLE vm_filters DROP mbox_id; +ALTER TABLE vm_forwards DROP mbox_id; diff --git a/bin/vmail-aliases-add.sh b/bin/vmail-aliases-add.sh index 0006a27..0610eb2 100755 --- a/bin/vmail-aliases-add.sh +++ b/bin/vmail-aliases-add.sh @@ -48,21 +48,21 @@ if [ -z $domain_id ] ; then exit 1 fi -# get mbox id, which also verfies that email address exists -mbox_id=`mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -s -r -N -e "SELECT id FROM vm_mboxes WHERE domain_id='$domain_id' AND mbox='$mbox';"` +# get mbox id which verfies that email address exists +mbox_id=`mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -s -r -N -e "SELECT id FROM vm_mboxes WHERE mbox='$mbox' AND domain='$domain';"` if [[ -z $mbox_id ]]; then # mbox does not exist, can't create alias echo "ERROR: Address to Alias To ($email) does not exist." exit 1 elif [[ $mbox_id -gt 0 ]]; then # verified mbox, check for existing alias - existing_alias=`mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -s -r -N -e "SELECT vm_aliases.id FROM vm_aliases WHERE vm_aliases.alias='$alias' AND vm_aliases.mbox_id='$mbox_id';"` + existing_alias=`mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -s -r -N -e "SELECT vm_aliases.id FROM vm_aliases WHERE vm_aliases.alias='$alias' AND mbox='$mbox' AND domain='$domain';"` if [[ -z $existing_alias ]]; then # existing alias does not exist, make sure mbox with alias name does not exist - alias_mbox_id=`mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -s -r -N -e "SELECT id FROM vm_mboxes WHERE domain_id='$domain_id' AND mbox='$alias';"` + alias_mbox_id=`mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -s -r -N -e "SELECT id FROM vm_mboxes WHERE mbox='$alias' AND domain='$domain';"` if [[ -z $alias_mbox_id ]]; then # mailbox does not exist, add alias - dbcmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -e 'INSERT INTO vm_aliases SET vm_aliases.alias=\"$alias\", vm_aliases.mbox_id=\"$mbox_id\";'" + dbcmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -e 'INSERT INTO vm_aliases SET mbox=\"$mbox\", domain=\"$domain\", alias=\"$alias\";'" eval $dbcmd else echo "ERROR: Email account $alias@$domain exists, can't create alias with the same name." diff --git a/bin/vmail-aliases-del.sh b/bin/vmail-aliases-del.sh index 523fdd2..905d68e 100755 --- a/bin/vmail-aliases-del.sh +++ b/bin/vmail-aliases-del.sh @@ -42,14 +42,13 @@ dbcmdopts="-s -r -N -e" # if email set delete single alias if [[ -n $email ]]; then # get aliases id which also works to confirm alias exists - dbquery="SELECT vm_aliases.id FROM vm_aliases, vm_mboxes, vm_domains WHERE vm_aliases.alias='$alias' AND vm_aliases.mbox_id=vm_mboxes.id AND vm_mboxes.mbox='$mbox' AND vm_mboxes.domain_id=vm_domains.id AND vm_domains.domain='$domain'" - vm_aliases_id=`$dbcmd $dbcmdopts "$dbquery"` - if [[ -z $vm_aliases_id ]]; then + dbquery="SELECT id FROM vm_aliases WHERE alias='$alias' AND mbox='$mbox' AND domain='$domain'" + aliases_id=`$dbcmd $dbcmdopts "$dbquery"` + if [[ -z $aliases_id ]]; then echo "ERROR: Alias $alias@$domain -> $email does not exist." exit 1 - elif [ "$vm_aliases_id" -gt '0' ]; then - dbquery="DELETE FROM vm_aliases WHERE vm_aliases.id='$vm_aliases_id'" - echo $dbquery + elif [ "$aliases_id" -gt '0' ]; then + dbquery="DELETE FROM vm_aliases WHERE id='$aliases_id'" eval $dbcmd $dbcmdopts "\"$dbquery\"" echo "SUCCESS: Alias $alias@$domain -> $email removed from system." exit 0 @@ -60,14 +59,14 @@ if [[ -n $email ]]; then # if domain set then delete any and all aliases elif [[ -n $domain ]]; then # get alias id array - dbquery="SELECT vm_aliases.id FROM vm_aliases, vm_mboxes, vm_domains WHERE vm_aliases.alias='$alias' AND vm_aliases.mbox_id=vm_mboxes.id AND vm_mboxes.domain_id=vm_domains.id AND vm_domains.domain='$domain'" - mapfile -t vm_alias_ids < <( $dbcmd $dbcmdopts "$dbquery" ) - if [[ -z $vm_alias_ids ]]; then + dbquery="SELECT id FROM vm_aliases WHERE alias='$alias' AND domain='$domain'" + mapfile -t aliases_ids < <( $dbcmd $dbcmdopts "$dbquery" ) + if [[ -z $aliases_ids ]]; then echo "ERROR: Alias $alias@$domain does not exist." exit 1 - elif [[ ${#vm_alias_ids[@]} -gt '0' ]]; then - for vm_alias_id in "${vm_alias_ids[@]}"; do - dbquery="DELETE FROM vm_aliases WHERE vm_aliases.id='$vm_alias_id'" + elif [[ ${#aliases_ids[@]} -gt '0' ]]; then + for aliases_id in "${aliases_ids[@]}"; do + dbquery="DELETE FROM vm_aliases WHERE id='$aliases_id'" eval $dbcmd $dbcmdopts "\"$dbquery\"" done echo "SUCCESS: Alias(s) for $alias@$domain removed from system." diff --git a/bin/vmail-aliases-get.sh b/bin/vmail-aliases-get.sh index 18d6a81..1b59811 100755 --- a/bin/vmail-aliases-get.sh +++ b/bin/vmail-aliases-get.sh @@ -35,7 +35,7 @@ vmail:getoptions "$@" # set initial db query data dbcmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE" dbcmdopts="-e" -dbquery="SELECT vm_aliases.alias, vm_mboxes.mbox, vm_domains.domain FROM vm_aliases, vm_mboxes, vm_domains WHERE vm_aliases.mbox_id = vm_mboxes.id AND vm_mboxes.domain_id = vm_domains.id" +dbquery="SELECT alias, mbox, domain FROM vm_aliases" if [[ -n $tab ]]; then dbcmdopts="-s -N $dbcmdopts" @@ -43,22 +43,22 @@ fi if [[ -n $alias ]]; then if [[ -n $domain ]] ; then - dbquery="$dbquery AND vm_aliases.alias='$alias' AND vm_domains.domain='$domain'" + dbquery="$dbquery WHERE alias='$alias' AND domain='$domain'" else echo "ERROR: alias should be in full email address format." exit 1 fi elif [[ -n $email ]]; then - dbquery="$dbquery AND vm_mboxes.mbox='$mbox' AND vm_domains.domain='$domain'" + dbquery="$dbquery WHERE mbox='$mbox' AND domain='$domain'" elif [[ -n $domain ]]; then - dbquery="$dbquery AND vm_domains.domain='$domain'" + dbquery="$dbquery WHERE domain='$domain'" else echo "You must specify either or or ." exit 1 fi # set order by -dbquery="$dbquery ORDER BY vm_domains.domain, vm_mboxes.mbox, vm_aliases.alias;"; +dbquery="$dbquery ORDER BY domain, mbox, alias;"; # execute mysql query eval $dbcmd $dbcmdopts "\"$dbquery\"" $cvs diff --git a/bin/vmail-autoresponders-add.sh b/bin/vmail-autoresponders-add.sh index edcf581..1c2e60d 100755 --- a/bin/vmail-autoresponders-add.sh +++ b/bin/vmail-autoresponders-add.sh @@ -54,21 +54,21 @@ fi dbcmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE" dbcmdopts="-s -r -N -e" -# get mbox id, which also verfies that email address exists -dbquery="SELECT vm_mboxes.id FROM vm_mboxes, vm_domains WHERE vm_mboxes.mbox='$mbox' AND vm_mboxes.domain_id=vm_domains.id AND vm_domains.domain='$domain';" +# get mbox id, which verfies that email address exists +dbquery="SELECT id FROM vm_mboxes WHERE mbox='$mbox' AND domain='$domain';" mbox_id=`eval $dbcmd $dbcmdopts \"$dbquery\"` -if [ -z $mbox_id ]; then +if [[ -z $mbox_id ]]; then # mailbox does not exist echo "ERROR: Email account $email does not exist." exit 1 elif [ "$mbox_id" -gt '0' ]; then - # verified mbox, check for existing forward - dbquery="SELECT id FROM vm_autoresponders WHERE mbox_id='$mbox_id';" - vm_autoresponders_id=`eval $dbcmd $dbcmdopts \"$dbquery\"` - if [ -z $vm_autoresponders_id ]; then + # verified mbox, check for existing autoresponder + dbquery="SELECT id FROM vm_autoresponders WHERE mbox='$mbox' AND domain='$domain';" + autoresponder_id=`eval $dbcmd $dbcmdopts \"$dbquery\"` + if [[ -z $autoresponder_id ]]; then # no autoresponder, add new one now - dbquery="INSERT INTO vm_autoresponders SET mbox_id='$mbox_id', subject='$subject', body='$body'" + dbquery="INSERT INTO vm_autoresponders SET mbox='$mbox', domain='$domain', subject='$subject', body='$body'" if [ ! -z $mode ]; then dbquery="$dbquery, mode='$mode'" fi @@ -76,9 +76,13 @@ elif [ "$mbox_id" -gt '0' ]; then dbquery="$dbquery, status='$status'" fi eval $dbcmd $dbcmdopts \"$dbquery\;\" - else + elif [ "$autoresponder_id" -gt '0' ]; then echo "ERROR: Autoresponder for $email already exists, edit or delete and re-create instead." exit 1 + else + # db query error + echo "ERROR: System error querying database." + exit 1 fi else # db query error diff --git a/bin/vmail-autoresponders-del.sh b/bin/vmail-autoresponders-del.sh index 9386c38..f9480f8 100755 --- a/bin/vmail-autoresponders-del.sh +++ b/bin/vmail-autoresponders-del.sh @@ -34,7 +34,7 @@ dbcmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE" dbcmdopts="-s -r -N -e" # get autoresponders id which also works to confirm autoresponder exists -dbquery="SELECT vm_autoresponders.id FROM vm_autoresponders, vm_mboxes, vm_domains WHERE vm_autoresponders.mbox_id=vm_mboxes.id AND vm_mboxes.mbox='$mbox' AND vm_mboxes.domain_id=vm_domains.id AND vm_domains.domain='$domain';" +dbquery="SELECT id FROM vm_autoresponders WHERE mbox='$mbox' AND domain='$domain';" vm_autoresponders_id=`$dbcmd $dbcmdopts "$dbquery"` if [ -z "$vm_autoresponders_id" ]; then diff --git a/bin/vmail-autoresponders-get.sh b/bin/vmail-autoresponders-get.sh index 0304afb..81e3fd2 100755 --- a/bin/vmail-autoresponders-get.sh +++ b/bin/vmail-autoresponders-get.sh @@ -23,21 +23,13 @@ help() echo " -t Use tabs instead of tables for output, do not display column headers." echo "" echo " Search term is optional. If nothing specified all forwards for all email acccounts for all domains will be returned." - echo " Enter email address to get forward info for that email address." - echo " Enter forwarding address (in full email address format) with the -f option to get address(es) that forward to specified address." - echo " Enter domain name to get all forwards for all email addresses under that domain." + echo " Enter email address to get autoresponder info for that email address." + echo " Enter domain name to get all autoresponders for all email addresses under that domain." exit } - vmail:getoptions "$@" -# check for domain (which will aslo be set if email is specified) -if [[ -z $domain ]]; then - echo "Domian Name or Email is required." - exit 1 -fi - # set initial db query data dbcmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE" dbcmdopts="-e" @@ -46,13 +38,19 @@ if [[ -n $tab ]]; then dbcmdopts="-s -N $dbcmdopts" fi -dbquery="SELECT vm_mboxes.mbox, vm_domains.domain, QUOTE(vm_autoresponders.subject) AS subject, QUOTE(REPLACE(REPLACE(vm_autoresponders.body,'\r\n','\n'),'\n','\\n')) AS body, vm_autoresponders.mode, vm_autoresponders.status FROM vm_autoresponders, vm_mboxes, vm_domains WHERE vm_autoresponders.mbox_id = vm_mboxes.id AND vm_mboxes.domain_id = vm_domains.id AND vm_domains.domain='$domain'" - # build query +dbquery="SELECT mbox, domain, QUOTE(subject) AS subject, QUOTE(REPLACE(REPLACE(body,'\r\n','\n'),'\n','\\n')) AS body, mode, status FROM vm_autoresponders" + +# set search options if [[ -n $email ]]; then # search for specific autoresponder - dbquery="$dbquery AND vm_mboxes.mbox='$mbox' ORDER BY vm_mboxes.mbox" + dbquery="$dbquery WHERE mbox='$mbox' AND domain='$domain'" +elif [[ -n $domain ]]; then + # get all autoresponders for given domain + dbquery="$dbquery WHERE domain='$domain'" fi +# sort results +dbquery="$dbquery ORDER BY domain, mbox" # execute mysql query eval $dbcmd $dbcmdopts "\"$dbquery\"" $cvs diff --git a/bin/vmail-autoresponders-mod.sh b/bin/vmail-autoresponders-mod.sh index f7d396e..4d6cb04 100755 --- a/bin/vmail-autoresponders-mod.sh +++ b/bin/vmail-autoresponders-mod.sh @@ -40,7 +40,7 @@ fi # check for options if [[ -z $subject && -z $body && -z $mode && -z $status ]]; then - echo "One or more options to update must be specified" + echo "One or more options to update must be specified." exit 1 fi @@ -48,42 +48,29 @@ fi dbcmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE" dbcmdopts="-s -r -N -e" -# get mbox id, which also verfies that email address exists -dbquery="SELECT vm_mboxes.id FROM vm_mboxes, vm_domains WHERE vm_mboxes.mbox='$mbox' AND vm_mboxes.domain_id=vm_domains.id AND vm_domains.domain='$domain';" -mbox_id=`eval $dbcmd $dbcmdopts \"$dbquery\"` +# get autoresponder id, which also verfies that the autoresponder exists +dbquery="SELECT id FROM vm_autoresponders WHERE mbox='$mbox' AND domain='$domain';" +autoresponder_id=`eval $dbcmd $dbcmdopts \"$dbquery\"` -if [ -z $mbox_id ]; then - # mailbox does not exist - echo "ERROR: Email account $email does not exist." +if [[ -z $autoresponder_id ]]; then + # autoresponder does not exist + echo "ERROR: Autoresponder for $email does not exists, can't edit. Add new autoresponder instead." exit 1 -elif [ "$mbox_id" -gt '0' ]; then - # verified mbox, check for existing forward - dbquery="SELECT id FROM vm_autoresponders WHERE mbox_id='$mbox_id';" - vm_autoresponders_id=`eval $dbcmd $dbcmdopts \"$dbquery\"` - if [ -z $vm_autoresponders_id ]; then - # existing autoresponder does not exist, can't modify - echo "ERROR: Autoresponder for $email does not exists, can't edit. Add new autoresponder instead." - exit 1 - else - # start update by re-setting mbox_id, doesn't change anything, just facilitates following code - dbquery="UPDATE vm_autoresponders SET mbox_id='$mbox_id'" - if [ ! -z "$subject" ]; then - dbquery="$dbquery, subject='$subject'" - fi - if [ ! -z "$body" ]; then - dbquery="$dbquery, body='$body'" - fi - if [ ! -z $mode ]; then - dbquery="$dbquery, mode='$mode'" - fi - if [ ! -z $status ]; then - dbquery="$dbquery, status='$status'" - fi - dbquery="$dbquery WHERE vm_autoresponders.id='$vm_autoresponders_id'" - eval $dbcmd $dbcmdopts \"$dbquery\;\" - fi else - # db query error - echo "ERROR: System error querying database." - exit 1 + # build update query (set id is just to facilitate building query) + dbquery="UPDATE vm_autoresponders SET id='$autoresponder_id'" + if [ ! -z "$subject" ]; then + dbquery="$dbquery, subject='$subject'" + fi + if [ ! -z "$body" ]; then + dbquery="$dbquery, body='$body'" + fi + if [ ! -z $mode ]; then + dbquery="$dbquery, mode='$mode'" + fi + if [ ! -z $status ]; then + dbquery="$dbquery, status='$status'" + fi + dbquery="$dbquery WHERE id='$autoresponder_id'" + eval $dbcmd $dbcmdopts \"$dbquery\;\" fi diff --git a/bin/vmail-domains-add.sh b/bin/vmail-domains-add.sh index a6f103e..0ca7402 100755 --- a/bin/vmail-domains-add.sh +++ b/bin/vmail-domains-add.sh @@ -39,7 +39,6 @@ fi # set initial db query data dbcmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE" dbcmdopts=" -s -r -N -e" -dbquery="SELECT * from vm_domains" # check if vmail domain dir exits if [ -d $VMAIL_DIR/$domain ]; then @@ -48,21 +47,20 @@ if [ -d $VMAIL_DIR/$domain ]; then fi # check if domain exists in vmail database -dbquery="SELECT COUNT(*) from vm_domains WHERE domain='$domain';"; -rowcount=`$dbcmd $dbcmdopts "$dbquery"` -if [ "$rowcount" -eq '0' ] ; then +dbquery="SELECT id from vm_domains WHERE domain='$domain';"; +domains_id=`$dbcmd $dbcmdopts "$dbquery"` +if [[ -z $domains_id ]]; then # looks good, build SQL dbquery="INSERT INTO vm_domains SET domain='$domain'"; - cmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -e \"INSERT INTO vm_domains SET domain='$domain'\"" - if [ ! -z "$status" ] ; then - if [ "$status" == 0 ] || [ "$status" == 1 ]; then + if [[ ! -z "$status" ]] ; then + if [[ "$status" == 0 ]] || [[ "$status" == 1 ]]; then dbquery="$dbquery, status='$status'" else echo "ERROR: status (-s) must be 1 or 0" exit 1 fi fi - if [ ! -z "$limit" ] ; then + if [[ ! -z "$limit" ]] ; then if [[ "$limit" == "NULL" ]]; then dbquery="$dbquery, mbox_limit=NULL" elif [[ "$limit" =~ ^[0-9]+$ ]]; then @@ -72,7 +70,7 @@ if [ "$rowcount" -eq '0' ] ; then exit 1 fi fi - if [ ! -z "$quota" ] ; then + if [[ ! -z "$quota" ]] ; then if [[ "$quota" == "NULL" ]]; then dbquery="$dbquery, mbox_quota_default=NULL" elif [[ "$quota" =~ ^[0-9]+$ ]]; then @@ -82,7 +80,7 @@ if [ "$rowcount" -eq '0' ] ; then exit 1 fi fi - if [ ! -z "$ratelimit" ] ; then + if [[ ! -z "$ratelimit" ]] ; then if [[ "$ratelimit" == "NULL" ]]; then dbquery="$dbquery, mbox_ratelimit_default=NULL" elif [[ "$ratelimit" =~ ^[0-9]+$ ]]; then @@ -92,17 +90,16 @@ if [ "$rowcount" -eq '0' ] ; then exit 1 fi fi - dbquery="$dbquery;" # add domain to vmail database eval $dbcmd $dbcmdopts "\"$dbquery\"" # create vmail directory for domain - if [ ! -d "$VMAIL_DIR" ] ; then + if [[ ! -d "$VMAIL_DIR" ]] ; then install -o vmail -g vmail -m 750 -d $VMAIL_DIR fi - if [ ! -d "$VMAIL_DIR/$domain" ] ; then + if [[ ! -d "$VMAIL_DIR/$domain" ]] ; then install -o vmail -g vmail -m 750 -d $VMAIL_DIR/$domain fi -elif [ "$rowcount" -eq '1' ] ; then +elif [[ "$domains_id" -gt 0 ]] ; then echo "ERROR: $domain already exists in vmail database." exit 1 else diff --git a/bin/vmail-domains-del.sh b/bin/vmail-domains-del.sh index dbfd3ac..a0e0ecb 100755 --- a/bin/vmail-domains-del.sh +++ b/bin/vmail-domains-del.sh @@ -34,10 +34,10 @@ dbcmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE" dbcmdopts="-s -r -N -e" # check if domain exists in vmail database -dbquery="SELECT COUNT(*) FROM vm_domains WHERE domain='$domain';" -rowcount=`$dbcmd $dbcmdopts "$dbquery"` +dbquery="SELECT id FROM vm_domains WHERE domain='$domain';" +domains_id=`$dbcmd $dbcmdopts "$dbquery"` -if [ "$rowcount" -eq '1' ] ; then +if [[ "$domains_id" -gt '0' ]] ; then # domain exists, delete from all vmail tables # single delete should be sufficient for vm_* tables due to ON DELETE CASCADE foreign key references dbquery="DELETE FROM vm_domains WHERE domain='$domain';" @@ -49,7 +49,7 @@ if [ "$rowcount" -eq '1' ] ; then # this should be sufficient for rc due to ON DELETE CASCADE foreign key references dbquery="DELETE FROM rc_users WHERE username LIKE '%@$domain';" eval $dbcmd $dbcmdopts "\"$dbquery\"" -elif [ "$rowcount" -eq '0' ] ; then +elif [[ -z $domains_id ]] ; then echo "ERROR: $domain does not exist in vmail database." exit 1 else diff --git a/bin/vmail-domains-get.sh b/bin/vmail-domains-get.sh index 1768da9..3cec059 100755 --- a/bin/vmail-domains-get.sh +++ b/bin/vmail-domains-get.sh @@ -36,13 +36,13 @@ dbcmdopts="-e" if [[ -n $tab ]]; then dbcmdopts="-s -N $dbcmdopts" fi -dbquery="SELECT domain, status, mbox_limit, (SELECT COUNT(*) FROM vm_mboxes WHERE vm_mboxes.domain_id = vm_domains.id) as mbox_allocated, mbox_quota_default, mbox_ratelimit_default FROM vm_domains" +dbquery="SELECT domain, status, mbox_limit, (SELECT COUNT(*) FROM vm_mboxes WHERE vm_mboxes.domain = vm_domains.domain) as mbox_allocated, mbox_quota_default, mbox_ratelimit_default from vm_domains" # build query if [[ -n $domain ]]; then dbquery="$dbquery WHERE domain='$domain'" elif [[ -n $glob ]]; then - dbquery="$dbquery WHERE domain LIKE '%$domain%'" + dbquery="$dbquery WHERE domain LIKE '%$glob%'" fi # sort results by domain name diff --git a/bin/vmail-domains-mod.sh b/bin/vmail-domains-mod.sh index 7cf41e5..5f94c21 100755 --- a/bin/vmail-domains-mod.sh +++ b/bin/vmail-domains-mod.sh @@ -28,7 +28,7 @@ vmail:getoptions "$@" # check for domain if [[ -n $domain ]]; then - domain_id=`mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -s -r -N -e "SELECT id from vm_domains WHERE vm_domains.domain='$domain';"` + domain_id=`mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -s -r -N -e "SELECT id from vm_domains WHERE domain='$domain';"` if [ -z $domain_id ] ; then echo "ERROR: Email domain $domain does not exist." exit diff --git a/bin/vmail-forwards-add.sh b/bin/vmail-forwards-add.sh index 0c9d320..d565dca 100755 --- a/bin/vmail-forwards-add.sh +++ b/bin/vmail-forwards-add.sh @@ -47,22 +47,22 @@ fi dbcmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE" dbcmdopts="-s -r -N -e" -# get mbox id, which also verfies that email address exists -dbquery="SELECT vm_mboxes.id FROM vm_mboxes, vm_domains WHERE vm_mboxes.mbox='$mbox' AND vm_mboxes.domain_id=vm_domains.id AND vm_domains.domain='$domain';" +# get mbox id, which verfies that email address exists +dbquery="SELECT id FROM vm_mboxes WHERE mbox='$mbox' AND domain='$domain';" mbox_id=`eval $dbcmd $dbcmdopts \"$dbquery\"` -if [ -z $mbox_id ]; then +if [[ -z $mbox_id ]]; then # mbox does not exist, can't create forward echo "ERROR: Address to Forward ($email) does not exist." exit 1 -elif [ "$mbox_id" -gt '0' ]; then +elif [[ $mbox_id -gt '0' ]]; then # verified mbox, check for existing forward - dbquery="SELECT id FROM vm_forwards WHERE mbox_id='$mbox_id';" - vm_forwards_id=`eval $dbcmd $dbcmdopts \"$dbquery\"` - if [ -z $vm_forwards_id ]; then + dbquery="SELECT id FROM vm_forwards WHERE mbox='$mbox' AND domain='$domain';" + forwards_id=`eval $dbcmd $dbcmdopts \"$dbquery\"` + if [[ -z $forwards_id ]]; then # existing forward does not exist, add it now - dbquery="INSERT INTO vm_forwards SET mbox_id='$mbox_id', forward_to='$forward'" - if [ ! -z $keep ]; then + dbquery="INSERT INTO vm_forwards SET mbox='$mbox', domain='$domain', forward_to='$forward'" + if [[ ! -z $keep ]]; then dbquery="$dbquery, save_local='$keep'" fi eval $dbcmd $dbcmdopts \"$dbquery\;\" diff --git a/bin/vmail-forwards-del.sh b/bin/vmail-forwards-del.sh index c746a73..273fd31 100755 --- a/bin/vmail-forwards-del.sh +++ b/bin/vmail-forwards-del.sh @@ -33,15 +33,15 @@ fi dbcmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE" dbcmdopts="-s -r -N -e" -# get aliases id which also works to confirm alias exists -dbquery="SELECT vm_forwards.id FROM vm_forwards, vm_mboxes, vm_domains WHERE vm_forwards.mbox_id=vm_mboxes.id AND vm_mboxes.mbox='$mbox' AND vm_mboxes.domain_id=vm_domains.id AND vm_domains.domain='$domain';" -vm_forwards_id=`$dbcmd $dbcmdopts "$dbquery"` +# get forward id which also works to confirm alias exists +dbquery="SELECT id FROM vm_forwards WHERE mbox='$mbox' AND domain='$domain';" +forwards_id=`$dbcmd $dbcmdopts "$dbquery"` -if [ -z "$vm_forwards_id" ]; then +if [[ -z $forwards_id ]]; then echo "ERROR: Forward for $email does not exist." exit 1 -elif [ "$vm_forwards_id" -gt '0' ]; then - dbquery="DELETE FROM vm_forwards WHERE vm_forwards.id='$vm_forwards_id';" +elif [[ $forwards_id -gt '0' ]]; then + dbquery="DELETE FROM vm_forwards WHERE id='$forwards_id';" eval $dbcmd $dbcmdopts \"$dbquery\" echo "SUCCESS: Forward for $email removed from system." exit 0 diff --git a/bin/vmail-forwards-get.sh b/bin/vmail-forwards-get.sh index d6fb648..268f1b3 100755 --- a/bin/vmail-forwards-get.sh +++ b/bin/vmail-forwards-get.sh @@ -14,7 +14,7 @@ help() echo "$thisfilename" echo "Get email forwards data from vmail database." echo "" - echo "usage: $thisfilename [-e email|-f forward|-f domain] [-c] [-t] [-h]" + echo "usage: $thisfilename [-e email|-f forward|-d domain] [-c] [-t] [-h]" echo "" echo " -h Print this help." echo " -e Email address to get forwarding for." @@ -35,23 +35,23 @@ vmail:getoptions "$@" # set initial db query data dbcmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE" dbcmdopts="-e" -dbquery="SELECT vm_mboxes.mbox, vm_domains.domain, vm_forwards.forward_to, vm_forwards.save_local FROM vm_forwards, vm_mboxes, vm_domains WHERE vm_forwards.mbox_id = vm_mboxes.id AND vm_mboxes.domain_id = vm_domains.id" +dbquery="SELECT mbox, domain, forward_to, save_local FROM vm_forwards" # AND vm_forwards.forward_to='$mbox@$domain'" # build query if [[ -n $forward ]]; then # search for specific forward to address - dbquery="$dbquery AND vm_forwards.forward_to='$mbox@$domain'" + dbquery="$dbquery WHERE forward_to='$forward'" elif [[ -n $domain ]]; then # add specific domain - dbquery="$dbquery AND vm_domains.domain='$domain'" + dbquery="$dbquery WHERE domain='$domain'" if [[ -n "$mbox" ]]; then # search for forward for specific email address - dbquery="$dbquery AND vm_mboxes.mbox='$mbox'" + dbquery="$dbquery AND mbox='$mbox'" fi fi # set order by -dbquery="$dbquery ORDER BY vm_domains.domain, vm_mboxes.mbox, vm_forwards.forward_to;"; +dbquery="$dbquery ORDER BY domain, mbox, forward_to;"; # execute mysql query eval $dbcmd $dbcmdopts "\"$dbquery\"" $cvs diff --git a/bin/vmail-forwards-mod.sh b/bin/vmail-forwards-mod.sh index 2acc307..8317718 100755 --- a/bin/vmail-forwards-mod.sh +++ b/bin/vmail-forwards-mod.sh @@ -37,40 +37,40 @@ if [[ -z $email ]]; then exit 1 fi -# check for forward -if [[ -z $forward ]]; then - echo "forward is required" - exit 1 -fi - # build query dbcmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE" dbcmdopts="-s -r -N -e" -# get mbox id, which also verfies that email address exists -dbquery="SELECT vm_mboxes.id FROM vm_mboxes, vm_domains WHERE vm_mboxes.mbox='$mbox' AND vm_mboxes.domain_id=vm_domains.id AND vm_domains.domain='$domain';" -mbox_id=`eval $dbcmd $dbcmdopts \"$dbquery\"` +# get forward id, which also verfies that forward already exists +dbquery="SELECT id FROM vm_forwards WHERE mbox='$mbox' AND domain='$domain';" +fowards_id=`eval $dbcmd $dbcmdopts \"$dbquery\"` -if [ -z $mbox_id ]; then - # mbox does not exist, can't create forward - echo "ERROR: Address to Forward ($email) does not exist." +if [[ -z $fowards_id ]]; then + # forward does not exist, can't create forward + echo "ERROR: Existing Forward for $email does not exist. Add new forward instead." exit 1 -elif [ "$mbox_id" -gt '0' ]; then - # verified mbox, check for existing forward - dbquery="SELECT id FROM vm_forwards WHERE mbox_id='$mbox_id';" - vm_forwards_id=`eval $dbcmd $dbcmdopts \"$dbquery\"` - if [ -z $vm_forwards_id ]; then - # existing forward does not exist, can't modify - echo "ERROR: Forward for $email does not exists, can't edit. Add new forward instead." +elif [[ $fowards_id -gt '0' ]]; then + # verified forward exists, build update query + dbquery="UPDATE vm_forwards" + if [[ -z $forward ]] && [[ -z $keep ]]; then + # nothing to update + echo "ERROR: No values passed for update." exit 1 + elif [[ -n $forward ]] && [[ -n $keep ]]; then + # update forward_to & save_local + dbquery="$dbquery SET forward_to='$forward', save_local='$keep'" + elif [[ -n $forward ]] && [[ -z $keep ]]; then + # only update forward_to + dbquery="$dbquery SET forward_to='$forward'" + elif [[ -z $forward ]] && [[ -n $keep ]]; then + # only update save_local + dbquery="$dbquery SET save_local='$keep'" else - dbquery="UPDATE vm_forwards SET forward_to='$forward'" - if [ ! -z $keep ]; then - dbquery="$dbquery, save_local='$keep'" - fi - dbquery="$dbquery WHERE mbox_id='$mbox_id'" - eval $dbcmd $dbcmdopts \"$dbquery\;\" + echo "ERROR: Uknown error." + exit 1 fi + dbquery="$dbquery WHERE id='$fowards_id'" + eval $dbcmd $dbcmdopts \"$dbquery\;\" else # db query error echo "ERROR: System error querying database." diff --git a/bin/vmail-mboxes-add.sh b/bin/vmail-mboxes-add.sh index de82db5..6370453 100755 --- a/bin/vmail-mboxes-add.sh +++ b/bin/vmail-mboxes-add.sh @@ -39,28 +39,28 @@ if [[ -z $password ]]; then exit 1 fi -# get domain_id (and thus check if domain already exists) +# get domain_id to check if domain already exists domain_id=`mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -s -r -N -e "SELECT id from vm_domains WHERE domain='$domain';"` -if [ -z $domain_id ] ; then +if [[ -z $domain_id ]] ; then echo "ERROR: Domain $domain does not exist." exit 1 fi # make sure mbox doesn't already exist -rowcount=`mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -s -r -N -e "SELECT COUNT(*) FROM vm_mboxes WHERE domain_id='$domain_id' AND mbox='$mbox';"` -if [ "$rowcount" -eq '0' ] ; then +mbox_id=`mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -s -r -N -e "SELECT id FROM vm_mboxes WHERE mbox='$mbox' AND domain='$domain';"` +if [[ -z $mbox_id ]] ; then # mbox does not exist, build SQL # first encrypt password passwd=`/usr/bin/openssl passwd -6 "$password"` passwd="{SHA512-CRYPT}$passwd" - dbcmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -e 'INSERT INTO vm_mboxes SET domain_id=\"$domain_id\", mbox=\"$mbox\", passwd=\"$passwd\"" + dbcmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -e 'INSERT INTO vm_mboxes SET mbox=\"$mbox\", domain=\"$domain\", passwd=\"$passwd\"" if [[ -n $status ]] ; then dbcmd="$dbcmd, status=\"$status\"" fi if [[ -n $filter ]] ; then dbcmd="$dbcmd, filter=\"$filter\"" fi - if [ -z "$quota" ] ; then + if [[ -z "$quota" ]] ; then # get mbox_quota_default from domains table quota=`mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -s -r -N -e "SELECT mbox_quota_default from vm_domains WHERE domain='$domain';"` fi @@ -85,7 +85,7 @@ if [ "$rowcount" -eq '0' ] ; then exit 1 fi dbcmd="$dbcmd;'" -elif [ "$rowcount" -eq '1' ] ; then +elif [[ $mbox_id -gt '0' ]] ; then echo "ERROR: $email already exists in vmail database." exit 1 else diff --git a/bin/vmail-mboxes-del.sh b/bin/vmail-mboxes-del.sh index db0f561..a49da46 100755 --- a/bin/vmail-mboxes-del.sh +++ b/bin/vmail-mboxes-del.sh @@ -34,16 +34,16 @@ dbcmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE" dbcmdopts="-s -r -N -e" # get email address id which also works to confirm address exists -dbquery="SELECT vm_mboxes.id FROM vm_mboxes, vm_domains WHERE vm_mboxes.mbox='$mbox' AND vm_mboxes.domain_id=vm_domains.id AND vm_domains.domain='$domain'" +dbquery="SELECT id FROM vm_mboxes WHERE mbox='$mbox' AND domain='$domain'" mboxes_id=`$dbcmd $dbcmdopts "$dbquery"` -if [ -z "$mboxes_id" ]; then +if [[ -z $mboxes_id ]]; then echo "ERROR: Email address $email does not exist." exit 1 -elif [ "$mboxes_id" -gt '0' ]; then +elif [[ $mboxes_id -gt '0' ]]; then if [[ -n $execute ]] || vmail::yesno "Delete $email now?"; then # this should be sufficient for vm_* tables due to ON DELETE CASCADE foreign key references - dbquery="DELETE FROM vm_mboxes WHERE vm_mboxes.id='$mboxes_id';" + dbquery="DELETE FROM vm_mboxes WHERE id='$mboxes_id';" eval $dbcmd $dbcmdopts "\"$dbquery\"" dbquery="DELETE FROM sa_userpref WHERE username='$email';" eval $dbcmd $dbcmdopts "\"$dbquery\"" diff --git a/bin/vmail-mboxes-get.sh b/bin/vmail-mboxes-get.sh index 4c8e472..1a05439 100755 --- a/bin/vmail-mboxes-get.sh +++ b/bin/vmail-mboxes-get.sh @@ -23,14 +23,11 @@ help() echo " -c Output in cvs format." echo " -t Use tabs instead of tables for output, do not display column headers." echo " -v Include encrypt password in output." - echo " -g Wildcard (blog) search when searching for username." echo "" echo " Search term is optional. If nothing specified all email acccounts for all domains will be returned." - echo " By default username searches are for exact matchs." - echo " Specify -g to turn them in to a wildcard (glob) search. Examples:" + echo " Examples:" echo " $thisfilename -e joe@example.com # search for specific email address 'joe@example.com'." echo " $thisfilename -m joe # search for username 'joe' in all domains." - echo " $thisfilename -m joe -g # search for usernames containing 'joe' in all domains." echo " $thisfilename -d example.com # search for all usernames in the 'example.com' domain." exit } @@ -45,34 +42,29 @@ if [[ -n $tab ]]; then fi # build query -dbquery="SELECT vm_mboxes.mbox, vm_domains.domain" -if [ -n "$verbose" ]; then - dbquery="$dbquery, vm_mboxes.passwd" +dbquery="SELECT mbox, domain" +if [[ -n $verbose ]]; then + dbquery="$dbquery, passwd" fi -dbquery="$dbquery, vm_mboxes.status, vm_mboxes.quota, vm_mboxes.ratelimit, vm_mboxes.filter FROM vm_domains, vm_mboxes WHERE vm_domains.id=vm_mboxes.domain_id" -if [ -n "$mbox" ] && [ -n "$domain" ]; then +dbquery="$dbquery, status, quota, ratelimit, filter FROM vm_mboxes" +if [[ -n $mbox ]] && [[ -n $domain ]]; then # search for specific email address - dbquery="$dbquery AND vm_domains.domain='$domain' AND vm_mboxes.mbox='$mbox'" -elif [ -n "$mbox" ] && [ -z "$domain" ]; then + dbquery="$dbquery WHERE mbox='$mbox' AND domain='$domain'" +elif [[ -n $mbox ]] && [[ -z $domain ]]; then # search all domains for username - if [ -n "$glob" ]; then - # wildcard search - dbquery="$dbquery AND vm_mboxes.mbox LIKE '%$mbox%'" - else - # exact match - dbquery="$dbquery AND vm_mboxes.mbox='$mbox'" - fi -elif [ -z "$mbox" ] && [ -n "$domain" ]; then + dbquery="$dbquery WHERE mbox='$mbox'" +elif [[ -z $mbox ]] && [[ -n $domain ]]; then # get all usernames for domain - dbquery="$dbquery AND vm_domains.domain='$domain'" + dbquery="$dbquery WHERE domain='$domain'" # elif [ -z "$mbox" ] && [ -z "$domain" ]; then # echo "ERROR: No username or domain specified." # help # uncomment above 3 lines to force search term, otherwise all email addresses for all domains will be returned fi +echo $dbquery # set order by -dbquery="$dbquery ORDER BY vm_domains.domain, vm_mboxes.mbox;"; +dbquery="$dbquery ORDER BY domain, mbox;"; # execute mysql query eval $dbcmd $dbcmdopts "\"$dbquery\"" $cvs diff --git a/bin/vmail-mboxes-mod.sh b/bin/vmail-mboxes-mod.sh index 28383df..eba6e4a 100755 --- a/bin/vmail-mboxes-mod.sh +++ b/bin/vmail-mboxes-mod.sh @@ -35,9 +35,9 @@ if [[ -z $email ]]; then fi # get mbox id (and thus check if email account already exists) -mbox_id=`mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -s -r -N -e "SELECT vm_mboxes.id from vm_mboxes, vm_domains WHERE vm_domains.domain='$domain' AND vm_mboxes.mbox='$mbox' AND vm_domains.id=vm_mboxes.domain_id;"` +mbox_id=`mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -s -r -N -e "SELECT id from vm_mboxes WHERE mbox='$mbox' AND domain='$domain';"` -if [ -z $mbox_id ] ; then +if [[ -z $mbox_id ]] ; then echo "ERROR: Email address $email does not exist." exit fi @@ -46,11 +46,11 @@ fi dbset="" # check for quota update -if [ -n "$quota" ]; then +if [[ -n $quota ]]; then # make quota uppercase in case it is set to NULL quota=`echo $quota | tr [:lower:] [:upper:]` if [[ "$quota" =~ ^[0-9]+$ ]] || [[ "$quota" == "NULL" ]]; then - dbset=" quota=$quota" + dbset="quota=$quota" else echo "ERROR: quota (-q) must numeric or NULL" exit 1 @@ -58,10 +58,13 @@ if [ -n "$quota" ]; then fi # check for ratelimit update -if [ -n "$ratelimit" ]; then +if [[ -n $ratelimit ]]; then # make ratelimit uppercase in case it is set to NULL ratelimit=`echo $ratelimit | tr [:lower:] [:upper:]` if [[ "$ratelimit" =~ ^[0-9]+$ ]] || [[ "$ratelimit" == "NULL" ]]; then + if [[ ! -z $dbset ]]; then + dbset="$dbset," + fi dbset=" ratelimit=$ratelimit" else echo "ERROR: ratelimit (-r) must numeric or NULL" @@ -70,32 +73,32 @@ if [ -n "$ratelimit" ]; then fi # check for password update -if [ ! -z "$password" ]; then +if [[ ! -z $password ]]; then passwd=`/usr/bin/openssl passwd -6 "$password"` passwd="{SHA512-CRYPT}$passwd" - if [ ! -z "$dbset" ]; then + if [[ ! -z $dbset ]]; then dbset="$dbset," fi dbset=" $dbset passwd=\"$passwd\"" fi # check for status update -if [ ! -z "$status" ]; then - if [ ! -z "$dbset" ]; then +if [[ ! -z $status ]]; then + if [[ ! -z $dbset ]]; then dbset="$dbset," fi dbset="$dbset status=\"$status\"" fi # check for junk filter update -if [ ! -z "$filter" ]; then - if [ ! -z "$dbset" ]; then +if [[ ! -z $filter ]]; then + if [[ ! -z $dbset ]]; then dbset="$dbset," fi dbset="$dbset filter=\"$filter\"" fi -if [ -n "$dbset" ]; then +if [[ -n $dbset ]]; then # build query dbcmd="mysql --defaults-extra-file=$MYSQL_CONNECTION_INFO_FILE -e 'UPDATE vm_mboxes SET $dbset WHERE id=\"$mbox_id\";'" diff --git a/bin/vmail-purge-dirs.sh b/bin/vmail-purge-dirs.sh index 80f89e7..41e2236 100755 --- a/bin/vmail-purge-dirs.sh +++ b/bin/vmail-purge-dirs.sh @@ -29,7 +29,7 @@ if [ -d $VMAIL_DIR ]; then for vmail_domain in "${vmail_domain_array[@]}"; do # make sure domain array element is a dir if [ -d $VMAIL_DIR/$vmail_domain ]; then - # get domain id for later queries and which also works to confirm domain exists in vmail db + # get domain id which confirms domain exists in vmail db dbquery="SELECT vm_domains.id FROM vm_domains WHERE vm_domains.domain='$vmail_domain'" domain_id='' domain_id=`$dbcmd $dbcmdopts "$dbquery"` @@ -45,7 +45,7 @@ if [ -d $VMAIL_DIR ]; then # cycle thru each mailbox for this domain for mbox in "${mbox_array[@]}"; do # get email address id which works to confirm address exists - dbquery="SELECT vm_mboxes.id FROM vm_mboxes WHERE vm_mboxes.mbox='$mbox' AND vm_mboxes.domain_id='$domain_id'" + dbquery="SELECT vm_mboxes.id FROM vm_mboxes WHERE vm_mboxes.mbox='$mbox' AND vm_mboxes.domain='$vmail_domain'" mboxes_id='' mboxes_id=`$dbcmd $dbcmdopts "$dbquery"` if [ -z "$mboxes_id" ]; then diff --git a/etc/dovecot/dovecot-sql.conf.ext b/etc/dovecot/dovecot-sql.conf.ext index 728b1c6..fb5966a 100644 --- a/etc/dovecot/dovecot-sql.conf.ext +++ b/etc/dovecot/dovecot-sql.conf.ext @@ -142,5 +142,8 @@ default_pass_scheme = SHA512-CRYPT password_query = SELECT vm_mboxes.passwd AS password, CONCAT('*:bytes=', vm_mboxes.quota, 'G') AS userdb_quota_rule, '/var/vmail/%d/%n' AS userdb_home, '/var/vmail/%d/%n/Maildir' AS userdb_mail, 'vmail' AS userdb_uid, 'vmail' AS userdb_gid FROM vm_domains, vm_mboxes WHERE vm_domains.domain = '%d' AND vm_domains.id = vm_mboxes.domain_id AND vm_mboxes.mbox = '%n' AND vm_domains.status = '1' AND vm_mboxes.status > '0' + +password_query = SELECT vm_mboxes.passwd AS password, CONCAT('*:bytes=', vm_mboxes.quota, 'G') AS userdb_quota_rule, '/var/vmail/%d/%n' AS userdb_home, '/var/vmail/%d/%n/Maildir' AS userdb_mail, 'vmail' AS userdb_uid, 'vmail' AS userdb_gid FROM vm_domains, vm_mboxes WHERE vm_domains.domain = '%d' AND vm_mboxes.mbox = '%n' AND vm_mboxes.domain = '%d' AND vm_domains.status = '1' AND vm_mboxes.status > '0' + # Query to get a list of all usernames. #iterate_query = SELECT username AS user FROM users diff --git a/etc/exim4/exim4.conf b/etc/exim4/exim4.conf index 37515f9..4b63586 100644 --- a/etc/exim4/exim4.conf +++ b/etc/exim4/exim4.conf @@ -378,7 +378,7 @@ acl_rcpt_to: # compromised account, not to restrict legitimate users. Set your defaults & limits accordignly. warn authenticated = * - set acl_m_ratelimit_hourly = ${lookup mysql{SELECT IFNULL(vm_mboxes.ratelimit, 100000) FROM vm_domains, vm_mboxes WHERE vm_domains.domain="$sender_address_domain" AND vm_mboxes.mbox="$sender_address_local_part" AND vm_domains.id = vm_mboxes.domain_id}{$value}{10}} + set acl_m_ratelimit_hourly = ${lookup mysql{SELECT IFNULL(vm_mboxes.ratelimit, 100000) FROM vm_mboxes WHERE vm_mboxes.mbox="$sender_address_local_part" AND vm_mboxes.domain='$sender_address_domain'}{$value}{10}} set acl_m_ratelimit_daily = ${eval: (10 * $acl_m_ratelimit_hourly) } ratelimit = 0 / 1h / per_mail / strict / $authenticated_id log_message = Sender rate is $sender_rate/$sender_rate_period for $authenticated_id @@ -741,7 +741,7 @@ autowhitelist_filter: driver = redirect domains = ! +local_domains ignore_target_hosts = 0.0.0.0 : 127.0.0.0/8 - condition = ${lookup mysql{SELECT vm_mboxes.id FROM vm_domains, vm_mboxes WHERE vm_domains.domain = "$sender_address_domain" AND vm_mboxes.mbox = "$sender_address_local_part" AND vm_domains.id = vm_mboxes.domain_id}} + condition = ${lookup mysql{SELECT vm_mboxes.id FROM vm_mboxes WHERE vm_mboxes.mbox="$sender_address_local_part" AND vm_mboxes.domain="$sender_address_domain" }} check_local_user = false user = Debian-exim file = /etc/exim4/autowhitelist.filter @@ -799,7 +799,7 @@ virtual_alias: local_part_suffix = +* local_part_suffix_optional = true condition = ${if !eq {$received_protocol}{spam-scanned}} - data = ${lookup mysql{SELECT CONCAT(vm_mboxes.mbox,'@${domain}') FROM vm_aliases, vm_mboxes, vm_domains WHERE vm_aliases.alias='${local_part}' AND vm_aliases.mbox_id = vm_mboxes.id AND vm_mboxes.domain_id = vm_domains.id AND vm_domains.domain='${domain}' AND vm_domains.status = '1' AND vm_mboxes.status > '0'}} + data = ${lookup mysql{SELECT CONCAT(vm_aliases.mbox,'@${domain}') FROM vm_aliases, vm_mboxes, vm_domains WHERE vm_aliases.alias='${local_part}' AND vm_aliases.domain='${domain}' AND vm_aliases.mbox=vm_mboxes.mbox AND vm_mboxes.domain='${domain}' AND vm_mboxes.status > '0' AND vm_domains.domain='${domain}' AND vm_domains.status = '1'}} junk_filter: driver = accept @@ -811,7 +811,7 @@ junk_filter: { eq {$header_X-Junk-Flag:}{YES}} \ { !eq {$header_X-Whitelist-Flag:}{YES}} \ } {yes}{no}} - condition = ${lookup mysql{SELECT vm_mboxes.id FROM vm_domains, vm_mboxes WHERE vm_domains.domain='${domain}' AND vm_mboxes.mbox='${local_part}' AND vm_domains.id = vm_mboxes.domain_id AND vm_domains.status = '1' AND vm_mboxes.status > '0' AND vm_mboxes.filter > '0'}} + condition = ${lookup mysql{SELECT vm_mboxes.id FROM vm_mboxes, vm_domains WHERE vm_mboxes.mbox='${local_part}' AND vm_mboxes.domain='${domain}' AND vm_mboxes.status > '0' AND vm_mboxes.filter > '0' AND vm_domains.domain=vm_mboxes.domain AND vm_domains.status='1'}} transport = junk_delivery spam_filter: @@ -824,7 +824,7 @@ spam_filter: { eq {$header_X-Spam-Flag:}{YES}} \ { !eq {$header_X-Whitelist-Flag:}{YES}} \ } {yes}{no}} - condition = ${lookup mysql{SELECT vm_mboxes.id FROM vm_domains, vm_mboxes WHERE vm_domains.domain='${domain}' AND vm_mboxes.mbox='${local_part}' AND vm_domains.id = vm_mboxes.domain_id AND vm_domains.status = '1' AND vm_mboxes.status > '0' AND vm_mboxes.filter = '2'}} + condition = ${lookup mysql{SELECT id FROM vm_domains, vm_mboxes WHERE vm_domains.domain='${domain}' vm_domains.status='1' AND vm_mboxes.mbox='${local_part}' AND vm_mboxes.domain='${domain}' AND vm_mboxes.status>'0'}} transport = junk_delivery virtual_vacation: @@ -835,7 +835,7 @@ virtual_vacation: { !match {$h_precedence:} {(?i)junk|bulk|list}} \ { !eq {$received_protocol}{spam-scanned}} \ { !eq {$sender_address} {}} \ - { eq {${lookup mysql{SELECT vm_autoresponders.mode FROM vm_domains, vm_mboxes, vm_autoresponders WHERE vm_domains.domain='${domain}' AND vm_mboxes.mbox='${local_part}' AND vm_domains.id = vm_mboxes.domain_id AND vm_autoresponders.mbox_id = vm_mboxes.id AND vm_domains.status = '1' AND vm_mboxes.status > '0' AND vm_autoresponders.status = '1'}{$value}fail}}{Vacation}} \ + { eq {${lookup mysql{SELECT vm_autoresponders.mode FROM vm_domains, vm_mboxes, vm_autoresponders WHERE vm_domains.domain='${domain}' AND vm_domains.status = '1' AND vm_mboxes.mbox='${local_part}' AND vm_mboxes.domain='${domain}' AND vm_mboxes.status > '0' AND vm_autoresponders.mbox='${local_part}' AND vm_autoresponders.domain='${domain}' AND vm_autoresponders.status='1'}{$value}fail}}{Vacation}} \ } {yes} {no}} # add options for start & end date fields no_expn @@ -861,7 +861,7 @@ virtual_autoresponder: { !match {$h_precedence:} {(?i)junk|bulk|list}} \ { !eq {$received_protocol}{spam-scanned}} \ { !eq {$sender_address} {}} \ - { eq {${lookup mysql{SELECT vm_autoresponders.mode FROM vm_domains, vm_mboxes, vm_autoresponders WHERE vm_domains.domain='${domain}' AND vm_mboxes.mbox='${local_part}' AND vm_domains.id = vm_mboxes.domain_id AND vm_autoresponders.mbox_id = vm_mboxes.id AND vm_domains.status = '1' AND vm_mboxes.status > '0' AND vm_autoresponders.status = '1'}{$value}fail}}{Autoresponder} } \ + { eq {${lookup mysql{SELECT vm_autoresponders.mode FROM vm_domains, vm_mboxes, vm_autoresponders WHERE vm_domains.domain='${domain}' AND vm_domains.status = '1' AND vm_mboxes.mbox='${local_part}' AND vm_mboxes.domain='${domain}' AND vm_mboxes.status > '0' AND vm_autoresponders.mbox='${local_part}' AND vm_autoresponders.domain='${domain}' AND vm_autoresponders.status='1'}{$value}fail}}{Autoresponder} } \ } {yes} {no}} # add options for start & end date fields no_expn @@ -882,7 +882,7 @@ virtual_forward_and_drop: condition = ${if !eq {$received_protocol}{spam-scanned}} local_part_suffix = +* local_part_suffix_optional = true - data = ${lookup mysql{SELECT vm_forwards.forward_to FROM vm_domains, vm_mboxes, vm_forwards WHERE vm_domains.domain='${domain}' AND vm_domains.id = vm_mboxes.domain_id AND vm_mboxes.mbox='${local_part}' AND vm_mboxes.id=vm_forwards.mbox_id AND vm_domains.status = '1' AND vm_mboxes.status > '0' AND vm_forwards.save_local='0'}} + data = ${lookup mysql{SELECT vm_forwards.forward_to FROM vm_domains, vm_mboxes, vm_forwards WHERE vm_domains.domain='${domain}' AND vm_domains.status = '1' AND vm_mboxes.mbox='${local_part}' AND vm_mboxes.domain='${domain}' AND vm_mboxes.status > '0' AND vm_forwards.mbox='${local_part}' AND vm_forwards.domain='${domain}' AND vm_forwards.save_local='0'}} virtual_forward_and_keep: driver = redirect @@ -890,7 +890,7 @@ virtual_forward_and_keep: condition = ${if !eq {$received_protocol}{spam-scanned}} local_part_suffix = +* local_part_suffix_optional = true - data = ${lookup mysql{SELECT CONCAT('${local_part}@${domain}\n', vm_forwards.forward_to) FROM vm_domains, vm_mboxes, vm_forwards WHERE vm_domains.domain='${domain}' AND vm_domains.id = vm_mboxes.domain_id AND vm_mboxes.mbox='${local_part}' AND vm_mboxes.id=vm_forwards.mbox_id AND vm_domains.status = '1' AND vm_mboxes.status > '0' AND vm_forwards.save_local='1'}} + data = ${lookup mysql{SELECT CONCAT('${local_part}@${domain}\n', vm_forwards.forward_to) FROM vm_domains, vm_mboxes, vm_forwards WHERE vm_domains.domain='${domain}' AND vm_domains.status = '1' AND vm_mboxes.mbox='${local_part}' AND vm_mboxes.domain='${domain}' AND vm_mboxes.status > '0' AND vm_forwards.mbox='${local_part}' AND vm_forwards.domain='${domain}' AND vm_forwards.save_local='1'}} spamcheck_router: driver = accept @@ -903,7 +903,7 @@ spamcheck_router: { < {$message_size}{512k}} \ { !eq {$header_X-Junk-Flag:}{YES}} \ { !eq {$header_X-Whitelist-Flag:}{YES}} \ - { gt {${lookup mysql{SELECT vm_mboxes.status FROM vm_domains, vm_mboxes WHERE vm_domains.domain='${domain}' AND vm_mboxes.mbox='${local_part}' AND vm_domains.id = vm_mboxes.domain_id AND vm_domains.status = '1'}{$value}fail}}{0} } \ + { gt {${lookup mysql{SELECT vm_mboxes.filter FROM vm_domains, vm_mboxes WHERE vm_domains.domain='${domain}' AND vm_domains.status = '1' AND vm_mboxes.mbox='${local_part}' AND vm_mboxes.domain='${domain}' AND vm_mboxes.status > '0'}{$value}fail}}{0} } \ } {yes} {no}} # Check for other headers too? Blacklist, SPF, DKIM failers go directly to Spam folder without spam scan??? - actually they should go to spam folder before this router is hit? headers_remove = X-Spam-Checker-Version:X-Spam-Flag:X-Spam-Level:X-Spam-Status:X-Spam-Score:X-Spam-Report @@ -914,7 +914,7 @@ user_filter: domains = +local_domains local_part_suffix = +* local_part_suffix_optional = true - data = ${lookup mysql{SELECT vm_filters.filter FROM vm_domains, vm_mboxes, vm_filters WHERE vm_domains.domain='${domain}' AND vm_mboxes.mbox='${local_part}' AND vm_domains.id = vm_mboxes.domain_id AND vm_mboxes.id = vm_filters.mbox_id AND vm_domains.status = '1' AND vm_mboxes.status > '0' }} + data = ${lookup mysql{SELECT vm_filters.filter FROM vm_domains, vm_mboxes, vm_filters WHERE vm_domains.domain='${domain}' AND vm_domains.status = '1' AND vm_mboxes.mbox='${local_part}' AND vm_mboxes.domain='${domain}' AND vm_mboxes.status > '0' AND vm_filters.mbox='${local_part}' AND vm_filters.domain='${domain}'}} user = vmail no_verify no_expn @@ -931,7 +931,7 @@ lmtp_localuser: domains = +local_domains local_part_suffix = +* local_part_suffix_optional = true - condition = ${lookup mysql{SELECT vm_mboxes.id FROM vm_domains, vm_mboxes WHERE vm_domains.domain='${domain}' AND vm_mboxes.mbox='${local_part}' AND vm_domains.id = vm_mboxes.domain_id AND vm_domains.status = '1' AND vm_mboxes.status > '0'}} + condition = ${lookup mysql{SELECT vm_mboxes.id FROM vm_domains, vm_mboxes WHERE vm_domains.domain='${domain}' AND vm_domains.status = '1' AND vm_mboxes.mbox='${local_part}' AND vm_mboxes.domain='${domain}' AND vm_mboxes.status > '0'}} # add checks to query for domain & mbox being active transport = dovecot_lmtp cannot_route_message = Unknown user @@ -941,7 +941,7 @@ virtual_alias_catchall: driver = redirect domains = +local_domains condition = ${if !eq {$received_protocol}{spam-scanned}} - data = ${lookup mysql{SELECT CONCAT(vm_mboxes.mbox,'@${domain}') FROM vm_aliases, vm_mboxes, vm_domains WHERE vm_aliases.alias='catchall' AND vm_aliases.mbox_id = vm_mboxes.id AND vm_mboxes.domain_id = vm_domains.id AND vm_domains.domain='${domain}' AND vm_domains.status = '1' AND vm_mboxes.status > '0'}} + data = ${lookup mysql{SELECT CONCAT(vm_aliases.mbox,'@${domain}') FROM vm_aliases, vm_mboxes, vm_domains WHERE vm_aliases.alias='catchall' AND vm_aliases.domain='${domain}' AND vm_aliases.mbox=vm_mboxes.mbox AND vm_mboxes.domain='${domain} AND vm_mboxes.status > '0' AND vm_domains.domain='${domain}' AND vm_domains.status = '1'}} # This router handles aliasing using a linearly searched alias file with the # name SYSTEM_ALIASES_FILE. When this configuration is installed automatically, @@ -1082,10 +1082,8 @@ vacation_transport: return_path = ${local_part}@${domain} to = ${sender_address} from = ${local_part}@${domain} -# subject = ${lookup mysql{SELECT subject FROM vm_autoresponder WHERE local_part='${local_part}' AND domain='${domain}'}{$value}{"Auto Reply"}} -# text = ${lookup mysql{SELECT message FROM vm_autoresponder WHERE local_part='${local_part}' AND domain='${domain}'}{$value}fail} - subject = ${lookup mysql{SELECT vm_autoresponders.subject FROM vm_domains, vm_mboxes, vm_autoresponders WHERE vm_domains.domain='${domain}' AND vm_mboxes.mbox='${local_part}' AND vm_domains.id = vm_mboxes.domain_id AND vm_autoresponders.mbox_id = vm_mboxes.id}{$value}{"Auto Reply"}} - text = ${lookup mysql{SELECT vm_autoresponders.body FROM vm_domains, vm_mboxes, vm_autoresponders WHERE vm_domains.domain='${domain}' AND vm_mboxes.mbox='${local_part}' AND vm_domains.id = vm_mboxes.domain_id AND vm_autoresponders.mbox_id = vm_mboxes.id}{$value}fail} + subject = ${lookup mysql{SELECT vm_autoresponders.subject FROM vm_domains, vm_mboxes, vm_autoresponders WHERE vm_domains.domain='${domain}' AND vm_domains.status = '1' AND vm_mboxes.mbox='${local_part}' AND vm_mboxes.domain='${domain}' AND vm_mboxes.status > '0' AND vm_autoresponders.mbox='${local_part}' AND vm_autoresponders.domain='${domain}' AND vm_autoresponders.status='1' AND vm_autoresponders.mode='Vacation'}{$value}{"Auto Reply"}} + text = ${lookup mysql{SELECT vm_autoresponders.body FROM vm_domains, vm_mboxes, vm_autoresponders WHERE vm_domains.domain='${domain}' AND vm_domains.status = '1' AND vm_mboxes.mbox='${local_part}' AND vm_mboxes.domain='${domain}' AND vm_mboxes.status > '0' AND vm_autoresponders.mbox='${local_part}' AND vm_autoresponders.domain='${domain}' AND vm_autoresponders.status='1' AND vm_autoresponders.mode='Vacation'}{$value}fail} user = vmail ## for autoresponder @@ -1095,8 +1093,8 @@ autoresponder_transport: return_path = ${local_part}@${domain} to = ${sender_address} from = ${local_part}@${domain} - subject = ${lookup mysql{SELECT vm_autoresponders.subject FROM vm_domains, vm_mboxes, vm_autoresponders WHERE vm_domains.domain='${domain}' AND vm_mboxes.mbox='${local_part}' AND vm_domains.id = vm_mboxes.domain_id AND vm_autoresponders.mbox_id = vm_mboxes.id}{$value}{"Auto Reply"}} - text = ${lookup mysql{SELECT vm_autoresponders.body FROM vm_domains, vm_mboxes, vm_autoresponders WHERE vm_domains.domain='${domain}' AND vm_mboxes.mbox='${local_part}' AND vm_domains.id = vm_mboxes.domain_id AND vm_autoresponders.mbox_id = vm_mboxes.id}{$value}fail} + subject = ${lookup mysql{SELECT vm_autoresponders.subject FROM vm_domains, vm_mboxes, vm_autoresponders WHERE vm_domains.domain='${domain}' AND vm_domains.status = '1' AND vm_mboxes.mbox='${local_part}' AND vm_mboxes.domain='${domain}' AND vm_mboxes.status > '0' AND vm_autoresponders.mbox='${local_part}' AND vm_autoresponders.domain='${domain}' AND vm_autoresponders.status='1' AND vm_autoresponders.mode='Autoresponder'}{$value}{"Auto Reply"}} + text = ${lookup mysql{SELECT vm_autoresponders.body FROM vm_domains, vm_mboxes, vm_autoresponders WHERE vm_domains.domain='${domain}' AND vm_domains.status = '1' AND vm_mboxes.mbox='${local_part}' AND vm_mboxes.domain='${domain}' AND vm_mboxes.status > '0' AND vm_autoresponders.mbox='${local_part}' AND vm_autoresponders.domain='${domain}' AND vm_autoresponders.status='1' AND vm_autoresponders.mode='Autoresponder'}{$value}fail} user = vmail maildir_delivery: diff --git a/vmail.sql b/vmail.sql index b127e19..6039b38 100644 --- a/vmail.sql +++ b/vmail.sql @@ -16,7 +16,8 @@ SET time_zone = "+00:00"; CREATE TABLE `vm_aliases` ( `id` int(10) UNSIGNED NOT NULL, - `mbox_id` int(10) UNSIGNED NOT NULL, + `mbox` varchar(128) NOT NULL, + `domain` varchar(255) NOT NULL, `alias` varchar(128) NOT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; @@ -28,13 +29,14 @@ CREATE TABLE `vm_aliases` ( CREATE TABLE `vm_autoresponders` ( `id` int(10) UNSIGNED NOT NULL, - `mbox_id` int(10) UNSIGNED NOT NULL, + `mbox` varchar(128) NOT NULL, + `domain` varchar(255) NOT NULL, `subject` varchar(128) NOT NULL, `body` text NOT NULL, - `mode` enum('Vacation','Autoresponder') NOT NULL, + `mode` enum('Vacation','Autoresponder') NOT NULL DEFAULT 'Vacation', `status` tinyint(1) NOT NULL DEFAULT 1, - `start` datetime DEFAULT NULL, - `end` datetime DEFAULT NULL + `start` date DEFAULT NULL, + `end` date DEFAULT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- -------------------------------------------------------- @@ -60,7 +62,8 @@ CREATE TABLE `vm_domains` ( CREATE TABLE `vm_filters` ( `id` int(10) UNSIGNED NOT NULL, - `mbox_id` int(11) UNSIGNED NOT NULL, + `mbox` varchar(128) NOT NULL, + `domain` varchar(255) NOT NULL, `filter` text NOT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; @@ -72,7 +75,8 @@ CREATE TABLE `vm_filters` ( CREATE TABLE `vm_forwards` ( `id` int(10) UNSIGNED NOT NULL, - `mbox_id` int(10) UNSIGNED NOT NULL, + `mbox` varchar(128) NOT NULL, + `domain` varchar(255) NOT NULL, `forward_to` varchar(128) NOT NULL, `save_local` tinyint(1) NOT NULL DEFAULT 0 ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; @@ -119,8 +123,8 @@ CREATE TABLE `vm_greylisting_resenders` ( CREATE TABLE `vm_mboxes` ( `id` int(10) UNSIGNED NOT NULL, - `domain_id` int(10) UNSIGNED NOT NULL, `mbox` varchar(128) NOT NULL, + `domain` varchar(255) NOT NULL, `passwd` char(128) NOT NULL, `status` tinyint(1) NOT NULL DEFAULT 1, `quota` int(10) UNSIGNED DEFAULT NULL, @@ -137,35 +141,36 @@ CREATE TABLE `vm_mboxes` ( -- ALTER TABLE `vm_aliases` ADD PRIMARY KEY (`id`), - ADD KEY `mbox_delete_aliases` (`mbox_id`); + ADD UNIQUE KEY `alias` (`mbox`,`domain`,`alias`) USING BTREE, + ADD KEY `email` (`mbox`,`domain`) USING BTREE; -- -- Indexes for table `vm_autoresponders` -- ALTER TABLE `vm_autoresponders` ADD PRIMARY KEY (`id`), - ADD UNIQUE KEY `autoresponder` (`mbox_id`); + ADD UNIQUE KEY `email` (`mbox`,`domain`) USING BTREE; -- -- Indexes for table `vm_domains` -- ALTER TABLE `vm_domains` ADD PRIMARY KEY (`id`), - ADD KEY `domain` (`domain`(191)); + ADD UNIQUE KEY `domain` (`domain`) USING BTREE; -- -- Indexes for table `vm_filters` -- ALTER TABLE `vm_filters` ADD PRIMARY KEY (`id`), - ADD KEY `mbox_delete_filters` (`mbox_id`); + ADD UNIQUE KEY `email` (`mbox`,`domain`) USING BTREE; -- -- Indexes for table `vm_forwards` -- ALTER TABLE `vm_forwards` ADD PRIMARY KEY (`id`), - ADD UNIQUE KEY `mbox_id` (`mbox_id`); + ADD UNIQUE KEY `email` (`mbox`,`domain`) USING BTREE; -- -- Indexes for table `vm_greylisting` @@ -184,7 +189,8 @@ ALTER TABLE `vm_greylisting_resenders` -- ALTER TABLE `vm_mboxes` ADD PRIMARY KEY (`id`), - ADD KEY `email` (`domain_id`,`mbox`) USING BTREE; + ADD UNIQUE KEY `email` (`mbox`,`domain`) USING BTREE, + ADD KEY `domain_delete_mboxes` (`domain`); -- -- AUTO_INCREMENT for dumped tables @@ -246,29 +252,29 @@ ALTER TABLE `vm_mboxes` -- Constraints for table `vm_aliases` -- ALTER TABLE `vm_aliases` - ADD CONSTRAINT `mbox_delete_aliases` FOREIGN KEY (`mbox_id`) REFERENCES `vm_mboxes` (`id`) ON DELETE CASCADE ON UPDATE NO ACTION; + ADD CONSTRAINT `mbox_delete_aliases` FOREIGN KEY (`mbox`,`domain`) REFERENCES `vm_mboxes` (`mbox`, `domain`) ON DELETE CASCADE ON UPDATE NO ACTION; -- -- Constraints for table `vm_autoresponders` -- ALTER TABLE `vm_autoresponders` - ADD CONSTRAINT `mbox_delete_autoresponders` FOREIGN KEY (`mbox_id`) REFERENCES `vm_mboxes` (`id`) ON DELETE CASCADE ON UPDATE NO ACTION; + ADD CONSTRAINT `mbox_delete_autoresponders` FOREIGN KEY (`mbox`,`domain`) REFERENCES `vm_mboxes` (`mbox`, `domain`) ON DELETE CASCADE ON UPDATE NO ACTION; -- -- Constraints for table `vm_filters` -- ALTER TABLE `vm_filters` - ADD CONSTRAINT `mbox_delete_filters` FOREIGN KEY (`mbox_id`) REFERENCES `vm_mboxes` (`id`) ON DELETE CASCADE ON UPDATE NO ACTION; + ADD CONSTRAINT `mbox_delete_filters` FOREIGN KEY (`mbox`,`domain`) REFERENCES `vm_mboxes` (`mbox`, `domain`) ON DELETE CASCADE ON UPDATE NO ACTION; -- -- Constraints for table `vm_forwards` -- ALTER TABLE `vm_forwards` - ADD CONSTRAINT `mbox_delete_forwards` FOREIGN KEY (`mbox_id`) REFERENCES `vm_mboxes` (`id`) ON DELETE CASCADE ON UPDATE NO ACTION; + ADD CONSTRAINT `mbox_delete_forwards` FOREIGN KEY (`mbox`,`domain`) REFERENCES `vm_mboxes` (`mbox`, `domain`) ON DELETE CASCADE ON UPDATE NO ACTION; -- -- Constraints for table `vm_mboxes` -- ALTER TABLE `vm_mboxes` - ADD CONSTRAINT `domain_delete_mboxes` FOREIGN KEY (`domain_id`) REFERENCES `vm_domains` (`id`) ON DELETE CASCADE ON UPDATE NO ACTION; + ADD CONSTRAINT `domain_delete_mboxes` FOREIGN KEY (`domain`) REFERENCES `vm_domains` (`domain`) ON DELETE CASCADE ON UPDATE NO ACTION; COMMIT;