+CREATE LANGUAGE plpgsql;
+
+
+
+---
+--- Box file garbage collection queue. The application uses a thread to
+--- clear all associated files with deleted boxes at regular intervals.
+--- box deletions cause their associated address to be appended in this table.
+---
+CREATE TABLE "box_deleted" (
+ address varchar(64) NOT NULL,
+ PRIMARY KEY (address)
+);
+
+---
+--- Mail file garbage collection queue. The application uses a thread to
+--- clear these files at regular intervals. mail and relayqueue deletions
+--- cause their associated file fullpath to be appended in this table.
+---
+CREATE TABLE "mail_deleted" (
+ file varchar(255) NOT NULL,
+ PRIMARY KEY (file)
+);
+
+
+
+---
+--- Address/domain patterns we allow mail without a FROM header from
+---
+CREATE TABLE "nofrom" (
+ pattern varchar(64) NOT NULL,
+ PRIMARY KEY (pattern)
+);
+
+---
+--- Alias addresses to local boxes.
+---
CREATE TABLE "alias" (
domain varchar(64) NOT NULL,
pattern varchar(64) NOT NULL,
PRIMARY KEY (domain, pattern, box),
);
+---
+--- Domains that are considered local (hosted by this server)
+---
+CREATE TABLE "relaylocal" (
+ pattern varchar(64) NOT NULL,
+ PRIMARY KEY (pattern)
+);
+
+---
+--- Domains we allow relaying for
+---
+CREATE TABLE "relayfrom" (
+ pattern varchar(64) NOT NULL,
+ PRIMARY KEY (pattern)
+);
+
+
+
+---
+--- Describes a user (every box must be tied to a user)
+---
+CREATE TABLE "user" (
+ id varchar(32) NOT NULL,
+ name varchar(64) NOT NULL,
+ passwd char(34) NOT NULL,
+ created timestamp NOT NULL
+ DEFAULT CURRENT_TIMESTAMP,
+ activity timestamp NOT NULL
+ DEFAULT CURRENT_TIMESTAMP,
+ logins bigint NOT NULL
+ DEFAULT 0,
+ active boolean NOT NULL
+ DEFAULT 't',
+ admin boolean NOT NULL
+ DEFAULT 'f',
+ PRIMARY KEY (id)
+);
+
+
+
+---
+--- Stores a mailbox associated to a user.
+---
CREATE TABLE "box" (
address varchar(64) NOT NULL,
---- Cannot CASCADE as we have per-box files to cleanup
user varchar(32) NOT NULL
REFERENCES user (id)
- ON DELETE RESTRICT,
+ ON DELETE CASCADE,
max_size bigint NOT NULL,
size bigint NOT NULL
DEFAULT 0,
DEFAULT CURRENT_TIMESTAMP,
out timestamp NOT NULL
DEFAULT CURRENT_TIMESTAMP,
+ delete timestamp NOT NULL
+ DEFAULT CURRENT_TIMESTAMP,
filter boolean NOT NULL
DEFAULT 'f',
description varchar(64),
PRIMARY KEY (address)
);
+CREATE FUNCTION box_delete RETURNS trigger AS $box_delete$
+BEGIN
+ INSERT INTO box_deleted VALUES(OLD.address);
+ RETURN NULL;
+END;
+$box_delete$ LANGUAGE plpgsql;
+
+CREATE TRIGGER box_delete
+ AFTER DELETE ON box FOR EACH ROW
+ EXECUTE PROCEDURE box_delete();
+
+
+
+---
+--- box-specific envelope deny/allow filter patterns
+---
CREATE TABLE "filter" (
address varchar(64) NOT NULL
REFERENCES box (address)
PRIMARY KEY (address, pattern)
);
+
+
+---
+--- Record to hold a mail post record into a box
+---
CREATE TABLE "mail" (
id bigserial NOT NULL,
box varchar(64) NOT NULL
created timestamp NOT NULL
DEFAULT CURRENT_TIMESTAMP,
size bigint NOT NULL,
-# data bytea NOT NULL,
PRIMARY KEY (id),
);
CREATE INDEX mail_box_index ON mail (box);
-CREATE TABLE "nofrom" (
- pattern varchar(64) NOT NULL,
- PRIMARY KEY (pattern)
-);
+CREATE FUNCTION mail_add RETURNS trigger AS $mail_add$
+BEGIN
+ UPDATE box SET
+ size = size + NEW.size,
+ msgs = msgs + 1,
+ in = CURRENT_TIMESTAMP
+ WHERE address = NEW.box;
+ RETURN NEW;
+END;
+$mail_add$ LANGUAGE plpgsql;
-CREATE TABLE "user" (
- id varchar(32) NOT NULL,
- name varchar(64) NOT NULL,
- passwd char(34) NOT NULL,
- created timestamp NOT NULL
- DEFAULT CURRENT_TIMESTAMP,
- activity timestamp NOT NULL
- DEFAULT CURRENT_TIMESTAMP,
- logins bigint NOT NULL
- DEFAULT 0,
- active boolean NOT NULL
- DEFAULT 't',
- admin boolean NOT NULL
- DEFAULT 'f',
- PRIMARY KEY (id)
-);
+CREATE TRIGGER mail_add
+ BEFORE INSERT ON mail FOR EACH ROW
+ EXECUTE PROCEDURE mail_add();
+
+CREATE FUNCTION mail_delete RETURNS trigger AS $mail_delete$
+BEGIN
+ UPDATE box SET
+ size = size - OLD.size,
+ msgs = msgs - 1,
+ delete = CURRENT_TIMESTAMP
+ WHERE address = OLD.box;
+ INSERT INTO mail_deleted VALUES(OLD.file);
+ RETURN NULL;
+END;
+$mail_delete$ LANGUAGE plpgsql;
-CREATE TABLE "relayqyeye" (
+CREATE TRIGGER mail_delete
+ AFTER DELETE ON mail FOR EACH ROW
+ EXECUTE PROCEDURE mail_delete();
+
+
+
+---
+--- Queue of mail to be relayed out
+---
+CREATE TABLE "relayqueue" (
id bigserial NOT NULL,
from varchar(64) NOT NULL,
ipaddr inet NOT NULL,
);
CREATE INDEX relayqueue_todomain_index ON relayqueue (todomain);
-CREATE TABLE "relaylocal" (
- pattern varchar(64) NOT NULL,
- PRIMARY KEY (pattern)
-);
+CREATE FUNCTION relayqueue_delete RETURNS trigger AS $relayqueue_delete$
+BEGIN
+ INSERT INTO mail_deleted VALUES(OLD.file);
+ RETURN NULL;
+END;
+$relayqueue_delete$ LANGUAGE plpgsql;
+
+CREATE TRIGGER relayqueue_delete
+ AFTER DELETE ON relayqueue FOR EACH ROW
+ EXECUTE PROCEDURE relayqueue_delete();
-CREATE TABLE "relayfrom" (
- pattern varchar(64) NOT NULL,
- PRIMARY KEY (pattern)
-);
+
+---
+--- Used by the HTTP administration frontend
+---
CREATE TABLE "session" (
id char(64) NOT NULL,
expires bigint NOT NULL,
data text NOT NULL,
PRIMARY KEY (id)
);
-
-CREATE TABLE "boxdelete" (
- address varchar(64) NOT NULL,
- PRIMARY KEY (address)
-);