Skip to content
Snippets Groups Projects
Commit 76fe0b88 authored by Nigel Kukard's avatar Nigel Kukard
Browse files

* Added preliminary database schema

parent 7fa45ae5
No related branches found
No related tags found
No related merge requests found
#!/bin/bash
# Database translation/creation script
# Copyright (C) 2008, LinuxRulz
#
# This program is free software; you can redistribute it and/or modify
# it under the terms of the GNU General Public License as published by
# the Free Software Foundation; either version 2 of the License, or
# (at your option) any later version.
#
# This program is distributed in the hope that it will be useful,
# but WITHOUT ANY WARRANTY; without even the implied warranty of
# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
# GNU General Public License for more details.
#
# You should have received a copy of the GNU General Public License along
# with this program; if not, write to the Free Software Foundation, Inc.,
# 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA.
database="$1"
file="$2"
prefix="$3"
# Display usage info
display_usage() {
echo "Usage: $0 <database type> <file> [prefix]"
echo
echo "Valid database types:"
echo " mysql4 - For MySQL v4"
echo " mysql - For MySQL v5"
echo " pgsql - For PostgreSQL"
echo " sqlite - For SQLite v3"
echo
exit
}
# Check we have our params
if [ -z "$database" -o -z "$file" ]
then
display_usage
fi
# Check file exists
if [ ! -f "$file" ]
then
echo "ERROR: Cannot open file '$file'"
exit 1
fi
# Check what we converting for
case "$database" in
"mysql4")
sed \
-e "s/@PREFIX@/$prefix/g" \
-e 's/@PRELOAD@/SET FOREIGN_KEY_CHECKS=0;/' \
-e 's/@POSTLOAD@/SET FOREIGN_KEY_CHECKS=1;/' \
-e 's/@CREATE_TABLE_SUFFIX@/TYPE=InnoDB CHARACTER SET latin1 COLLATE latin1_bin/' \
-e 's/@SERIAL_TYPE@/SERIAL/' \
-e 's/@BIG_INTEGER@/BIGINT UNSIGNED/' \
-e 's/@TRACK_KEY_LEN@/255/' \
-e 's/@SERIAL_REF_TYPE@/BIGINT UNSIGNED/' < "$file"
;;
"mysql")
sed \
-e "s/@PREFIX@/$prefix/g" \
-e 's/@PRELOAD@/SET FOREIGN_KEY_CHECKS=0;/' \
-e 's/@POSTLOAD@/SET FOREIGN_KEY_CHECKS=1;/' \
-e 's/@CREATE_TABLE_SUFFIX@/TYPE=InnoDB CHARACTER SET latin1 COLLATE latin1_bin/' \
-e 's/@SERIAL_TYPE@/SERIAL/' \
-e 's/@BIG_INTEGER@/BIGINT UNSIGNED/' \
-e 's/@TRACK_KEY_LEN@/512/' \
-e 's/@SERIAL_REF_TYPE@/BIGINT UNSIGNED/' < "$file"
;;
"pgsql")
sed \
-e "s/@PREFIX@/$prefix/g" \
-e 's/@PRELOAD@/SET CONSTRAINTS ALL DEFERRED;/' \
-e 's/@POSTLOAD@//' \
-e 's/@CREATE_TABLE_SUFFIX@//' \
-e 's/@SERIAL_TYPE@/SERIAL PRIMARY KEY/' \
-e 's/@BIG_INTEGER@/INT8/' \
-e 's/@TRACK_KEY_LEN@/512/' \
-e 's/@SERIAL_REF_TYPE@/INT8/' < "$file"
;;
"sqlite")
sed \
-e "s/@PREFIX@/$prefix/g" \
-e 's/@PRELOAD@//' \
-e 's/@POSTLOAD@//' \
-e 's/@CREATE_TABLE_SUFFIX@//' \
-e 's/@SERIAL_TYPE@/INTEGER PRIMARY KEY AUTOINCREMENT/' \
-e 's/@BIG_INTEGER@/INT8/' \
-e 's/@TRACK_KEY_LEN@/512/' \
-e 's/@SERIAL_REF_TYPE@/INT8/' < "$file"
;;
*)
echo "ERROR: Invalid database type '$database'"
exit 1
;;
esac
@PRELOAD@
/* Users */
CREATE TABLE @PREFIX@users (
ID @SERIAL_TYPE@,
Username VARCHAR(255) NOT NULL,
Description TEXT,
Disabled SMALLINT NOT NULL DEFAULT '0'
UNIQUE (Username)
) @CREATE_TABLE_SUFFIX@;
CREATE INDEX @PREFIX@users_idx1 ON @PREFIX@users (Username);
/* User check items */
CREATE TABLE @PREFIX@user_check_items (
ID @SERIAL_TYPE@,
Name VARCHAR(255) NOT NULL,
Op VARCHAR(3) NOT NULL,
Value VARCHAR(255),
Disabled SMALLINT NOT NULL DEFAULT '0'
UNIQUE (Name)
) @CREATE_TABLE_SUFFIX@;
/* User reply items */
CREATE TABLE @PREFIX@user_reply_items (
ID @SERIAL_TYPE@,
Name VARCHAR(255) NOT NULL,
Op VARCHAR(3) NOT NULL,
Value VARCHAR(255),
Disabled SMALLINT NOT NULL DEFAULT '0'
UNIQUE (Name)
) @CREATE_TABLE_SUFFIX@;
/* Groups */
CREATE TABLE @PREFIX@groups (
ID @SERIAL_TYPE@,
Name VARCHAR(255) NOT NULL,
Priority SMALLINT NOT NULL,
Disabled SMALLINT NOT NULL DEFAULT '0',
Comment VARCHAR(1024),
UNIQUE (Name)
) @CREATE_TABLE_SUFFIX@;
CREATE INDEX @PREFIX@groups_idx1 ON @PREFIX@users (Name);
/* Group check items */
CREATE TABLE @PREFIX@group_check_items (
ID @SERIAL_TYPE@,
Name VARCHAR(255) NOT NULL,
Op VARCHAR(3) NOT NULL,
Value VARCHAR(255),
Disabled SMALLINT NOT NULL DEFAULT '0'
UNIQUE (Name)
) @CREATE_TABLE_SUFFIX@;
/* Group reply items */
CREATE TABLE @PREFIX@group_reply_items (
ID @SERIAL_TYPE@,
Name VARCHAR(255) NOT NULL,
Op VARCHAR(3) NOT NULL,
Value VARCHAR(255),
Disabled SMALLINT NOT NULL DEFAULT '0'
UNIQUE (Name)
) @CREATE_TABLE_SUFFIX@;
/* User to group mapping */
CREATE TABLE @PREFIX@users_to_groups (
ID @SERIAL_TYPE@,
UserID @SERIAL_REF_TYPE@ NOT NULL,
GroupID @SERIAL_REF_TYPE@ NOT NULL,
Disabled SMALLINT NOT NULL DEFAULT '0',
Comment VARCHAR(1024),
UNIQUE (UserID,GroupID),
FOREIGN KEY (UserID) REFERENCES @PREFIX@users(ID),
FOREIGN KEY (GroupID) REFERENCES @PREFIX@groups(ID)
) @CREATE_TABLE_SUFFIX@;
CREATE INDEX @PREFIX@users_to_groups_idx1 ON @PREFIX@users_to_groups (UserID,GroupID);
/* Member list for policies */
CREATE TABLE @PREFIX@policy_members (
ID @SERIAL_TYPE@,
PolicyID @SERIAL_REF_TYPE@,
/*
Format of key:
NULL = any
a.b.c.d/e = IP address with optional /e
@domain = domain specification,
%xyz = xyz group,
abc@domain = abc user specification
all options support negation using !<key>
*/
Source TEXT,
Destination TEXT,
Comment VARCHAR(1024),
Disabled SMALLINT NOT NULL DEFAULT '0',
FOREIGN KEY (PolicyID) REFERENCES @PREFIX@policies(ID)
) @CREATE_TABLE_SUFFIX@;
/* Default System Policy */
INSERT INTO @PREFIX@policy_members (PolicyID,Source,Destination) VALUES
(1,NULL,NULL);
/* Default Outbound System Policy */
INSERT INTO @PREFIX@policy_members (PolicyID,Source,Destination) VALUES
(2,'%internal_ips,%internal_domains','!%internal_domains');
/* Default Inbound System Policy */
INSERT INTO @PREFIX@policy_members (PolicyID,Source,Destination) VALUES
(3,'!%internal_ips,!%internal_domains','%internal_domains');
/* Default Internal System Policy */
INSERT INTO @PREFIX@policy_members (PolicyID,Source,Destination) VALUES
(4,'%internal_ips,%internal_domains','%internal_domains');
/* Test Policy */
INSERT INTO @PREFIX@policy_members (PolicyID,Source,Destination) VALUES
(5,'@example.net',NULL);
/* Groups usable in ACL */
CREATE TABLE @PREFIX@policy_groups (
ID @SERIAL_TYPE@,
Name VARCHAR(255) NOT NULL,
Disabled SMALLINT NOT NULL DEFAULT '0',
Comment VARCHAR(1024),
UNIQUE (Name)
) @CREATE_TABLE_SUFFIX@;
INSERT INTO @PREFIX@policy_groups (Name) VALUES ('internal_ips');
INSERT INTO @PREFIX@policy_groups (Name) VALUES ('internal_domains');
/* Group members */
CREATE TABLE @PREFIX@policy_group_members (
ID @SERIAL_TYPE@,
PolicyGroupID @SERIAL_REF_TYPE@,
/* Format of member: a.b.c.d/e = ip, @domain = domain, %xyz = xyz group, abc@domain = abc user */
Member VARCHAR(255) NOT NULL,
Disabled SMALLINT NOT NULL DEFAULT '0',
Comment VARCHAR(1024),
FOREIGN KEY (PolicyGroupID) REFERENCES @PREFIX@policy_groups(ID)
) @CREATE_TABLE_SUFFIX@;
INSERT INTO @PREFIX@policy_group_members (PolicyGroupID,Member) VALUES (1,'10.0.0.0/8');
INSERT INTO @PREFIX@policy_group_members (PolicyGroupID,Member) VALUES (2,'@example.org');
INSERT INTO @PREFIX@policy_group_members (PolicyGroupID,Member) VALUES (2,'@example.com');
/* Message session tracking */
CREATE TABLE @PREFIX@session_tracking (
Instance VARCHAR(255),
QueueID VARCHAR(255),
Timestamp BIGINT NOT NULL,
ClientAddress VARCHAR(64),
ClientName VARCHAR(255),
ClientReverseName VARCHAR(255),
Protocol VARCHAR(255),
EncryptionProtocol VARCHAR(255),
EncryptionCipher VARCHAR(255),
EncryptionKeySize VARCHAR(255),
SASLMethod VARCHAR(255),
SASLSender VARCHAR(255),
SASLUsername VARCHAR(255),
Helo VARCHAR(255),
Sender VARCHAR(255),
Size @BIG_INTEGER@,
RecipientData TEXT, /* Policy state information */
UNIQUE (Instance)
) @CREATE_TABLE_SUFFIX@;
CREATE INDEX @PREFIX@session_tracking_idx1 ON @PREFIX@session_tracking (QueueID,ClientAddress,Sender);
CREATE INDEX @PREFIX@session_tracking_idx2 ON @PREFIX@session_tracking (Timestamp);
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment