1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288
|
-- Roundcube Webmail initial database structure
-- This was tested with Oracle 11g
CREATE TABLE "users" (
"user_id" integer PRIMARY KEY,
"username" varchar(128) NOT NULL,
"mail_host" varchar(128) NOT NULL,
"created" timestamp with time zone DEFAULT current_timestamp NOT NULL,
"last_login" timestamp with time zone DEFAULT NULL,
"failed_login" timestamp with time zone DEFAULT NULL,
"failed_login_counter" integer DEFAULT NULL,
"language" varchar(16),
"preferences" long DEFAULT NULL,
CONSTRAINT "users_username_key" UNIQUE ("username", "mail_host")
);
CREATE SEQUENCE "users_seq"
START WITH 1 INCREMENT BY 1 NOMAXVALUE;
CREATE TRIGGER "users_seq_trig"
BEFORE INSERT ON "users" FOR EACH ROW
BEGIN
:NEW."user_id" := "users_seq".nextval;
END;
/
CREATE TABLE "session" (
"sess_id" varchar(128) NOT NULL PRIMARY KEY,
"changed" timestamp with time zone DEFAULT current_timestamp NOT NULL,
"ip" varchar(41) NOT NULL,
"vars" long NOT NULL
);
CREATE INDEX "session_changed_idx" ON "session" ("changed");
CREATE TABLE "identities" (
"identity_id" integer PRIMARY KEY,
"user_id" integer NOT NULL
REFERENCES "users" ("user_id") ON DELETE CASCADE,
"changed" timestamp with time zone DEFAULT current_timestamp NOT NULL,
"del" smallint DEFAULT 0 NOT NULL,
"standard" smallint DEFAULT 0 NOT NULL,
"name" varchar(128) NOT NULL,
"organization" varchar(128),
"email" varchar(128) NOT NULL,
"reply-to" varchar(128),
"bcc" varchar(128),
"signature" long,
"html_signature" integer DEFAULT 0 NOT NULL
);
CREATE INDEX "identities_user_id_idx" ON "identities" ("user_id", "del");
CREATE INDEX "identities_email_idx" ON "identities" ("email", "del");
CREATE SEQUENCE "identities_seq"
START WITH 1 INCREMENT BY 1 NOMAXVALUE;
CREATE TRIGGER "identities_seq_trig"
BEFORE INSERT ON "identities" FOR EACH ROW
BEGIN
:NEW."identity_id" := "identities_seq".nextval;
END;
/
CREATE TABLE "responses" (
"response_id" integer PRIMARY KEY,
"user_id" integer NOT NULL
REFERENCES "users" ("user_id") ON DELETE CASCADE,
"changed" timestamp with time zone DEFAULT current_timestamp NOT NULL,
"del" smallint DEFAULT 0 NOT NULL,
"name" varchar(128) NOT NULL,
"data" long NOT NULL,
"is_html" smallint DEFAULT 0 NOT NULL
);
CREATE INDEX "responses_user_id_idx" ON "responses" ("user_id", "del");
CREATE SEQUENCE "responses_seq"
START WITH 1 INCREMENT BY 1 NOMAXVALUE;
CREATE TRIGGER "responses_seq_trig"
BEFORE INSERT ON "responses" FOR EACH ROW
BEGIN
:NEW."response_id" := "response_seq".nextval;
END;
/
CREATE TABLE "collected_addresses" (
"address_id" integer PRIMARY KEY,
"user_id" integer NOT NULL
REFERENCES "users" ("user_id") ON DELETE CASCADE,
"changed" timestamp with time zone DEFAULT current_timestamp NOT NULL,
"name" varchar(255) DEFAULT NULL,
"email" varchar(255) DEFAULT NULL,
"type" integer NOT NULL
);
CREATE UNIQUE INDEX "collected_addresses_user_id_idx" ON "collected_addresses" ("user_id", "type", "email");
CREATE SEQUENCE "collected_addresses_seq"
START WITH 1 INCREMENT BY 1 NOMAXVALUE;
CREATE TRIGGER "collected_addresses_seq_trig"
BEFORE INSERT ON "collected_addresses" FOR EACH ROW
BEGIN
:NEW."address_id" := "collected_addresses_seq".nextval;
END;
/
CREATE TABLE "contacts" (
"contact_id" integer PRIMARY KEY,
"user_id" integer NOT NULL
REFERENCES "users" ("user_id") ON DELETE CASCADE,
"changed" timestamp with time zone DEFAULT current_timestamp NOT NULL,
"del" smallint DEFAULT 0 NOT NULL,
"name" varchar(128) DEFAULT NULL,
"email" varchar(4000) DEFAULT NULL,
"firstname" varchar(128) DEFAULT NULL,
"surname" varchar(128) DEFAULT NULL,
"vcard" long,
"words" varchar(4000)
);
CREATE INDEX "contacts_user_id_idx" ON "contacts" ("user_id", "del");
CREATE SEQUENCE "contacts_seq"
START WITH 1 INCREMENT BY 1 NOMAXVALUE;
CREATE TRIGGER "contacts_seq_trig"
BEFORE INSERT ON "contacts" FOR EACH ROW
BEGIN
:NEW."contact_id" := "contacts_seq".nextval;
END;
/
CREATE TABLE "contactgroups" (
"contactgroup_id" integer PRIMARY KEY,
"user_id" integer NOT NULL
REFERENCES "users" ("user_id") ON DELETE CASCADE,
"changed" timestamp with time zone DEFAULT current_timestamp NOT NULL,
"del" smallint DEFAULT 0 NOT NULL,
"name" varchar(128) NOT NULL
);
CREATE INDEX "contactgroups_user_id_idx" ON "contactgroups" ("user_id", "del");
CREATE SEQUENCE "contactgroups_seq"
START WITH 1 INCREMENT BY 1 NOMAXVALUE;
CREATE TRIGGER "contactgroups_seq_trig"
BEFORE INSERT ON "contactgroups" FOR EACH ROW
BEGIN
:NEW."contactgroup_id" := "contactgroups_seq".nextval;
END;
/
CREATE TABLE "contactgroupmembers" (
"contactgroup_id" integer NOT NULL
REFERENCES "contactgroups" ("contactgroup_id") ON DELETE CASCADE,
"contact_id" integer NOT NULL
REFERENCES "contacts" ("contact_id") ON DELETE CASCADE,
"created" timestamp with time zone DEFAULT current_timestamp NOT NULL,
PRIMARY KEY ("contactgroup_id", "contact_id")
);
CREATE INDEX "contactgroupmembers_idx" ON "contactgroupmembers" ("contact_id");
CREATE TABLE "cache" (
"user_id" integer NOT NULL
REFERENCES "users" ("user_id") ON DELETE CASCADE,
"cache_key" varchar(128) NOT NULL,
"expires" timestamp with time zone DEFAULT NULL,
"data" long NOT NULL,
PRIMARY KEY ("user_id", "cache_key")
);
CREATE INDEX "cache_expires_idx" ON "cache" ("expires");
CREATE TABLE "cache_shared" (
"cache_key" varchar(255) NOT NULL,
"expires" timestamp with time zone DEFAULT NULL,
"data" long NOT NULL,
PRIMARY KEY ("cache_key")
);
CREATE INDEX "cache_shared_expires_idx" ON "cache_shared" ("expires");
CREATE TABLE "cache_index" (
"user_id" integer NOT NULL
REFERENCES "users" ("user_id") ON DELETE CASCADE,
"mailbox" varchar(255) NOT NULL,
"expires" timestamp with time zone DEFAULT NULL,
"valid" smallint DEFAULT 0 NOT NULL,
"data" long NOT NULL,
PRIMARY KEY ("user_id", "mailbox")
);
CREATE INDEX "cache_index_expires_idx" ON "cache_index" ("expires");
CREATE TABLE "cache_thread" (
"user_id" integer NOT NULL
REFERENCES "users" ("user_id") ON DELETE CASCADE,
"mailbox" varchar(255) NOT NULL,
"expires" timestamp with time zone DEFAULT NULL,
"data" long NOT NULL,
PRIMARY KEY ("user_id", "mailbox")
);
CREATE INDEX "cache_thread_expires_idx" ON "cache_thread" ("expires");
CREATE TABLE "cache_messages" (
"user_id" integer NOT NULL
REFERENCES "users" ("user_id") ON DELETE CASCADE,
"mailbox" varchar(255) NOT NULL,
"uid" integer NOT NULL,
"expires" timestamp with time zone DEFAULT NULL,
"data" long NOT NULL,
"flags" integer DEFAULT 0 NOT NULL,
PRIMARY KEY ("user_id", "mailbox", "uid")
);
CREATE INDEX "cache_messages_expires_idx" ON "cache_messages" ("expires");
CREATE TABLE "dictionary" (
"user_id" integer DEFAULT NULL
REFERENCES "users" ("user_id") ON DELETE CASCADE,
"language" varchar(16) NOT NULL,
"data" long DEFAULT NULL,
CONSTRAINT "dictionary_user_id_lang_key" UNIQUE ("user_id", "language")
);
CREATE TABLE "searches" (
"search_id" integer PRIMARY KEY,
"user_id" integer NOT NULL
REFERENCES "users" ("user_id") ON DELETE CASCADE,
"type" smallint DEFAULT 0 NOT NULL,
"name" varchar(128) NOT NULL,
"data" long NOT NULL,
CONSTRAINT "searches_user_id_key" UNIQUE ("user_id", "type", "name")
);
CREATE SEQUENCE "searches_seq"
START WITH 1 INCREMENT BY 1 NOMAXVALUE;
CREATE TRIGGER "searches_seq_trig"
BEFORE INSERT ON "searches" FOR EACH ROW
BEGIN
:NEW."search_id" := "searches_seq".nextval;
END;
/
CREATE TABLE "filestore" (
"file_id" integer PRIMARY KEY,
"user_id" integer NOT NULL
REFERENCES "users" ("user_id") ON DELETE CASCADE ON UPDATE CASCADE,
"context" varchar(32) NOT NULL,
"filename" varchar(128) NOT NULL,
"mtime" integer NOT NULL,
"data" long,
CONSTRAINT "filestore_user_id_key" UNIQUE ("user_id", "context", "filename")
);
CREATE SEQUENCE "filestore_seq"
START WITH 1 INCREMENT BY 1 NOMAXVALUE;
CREATE TRIGGER "filestore_seq_trig"
BEFORE INSERT ON "filestore" FOR EACH ROW
BEGIN
:NEW."user_id" := "filestore_seq".nextval;
END;
/
CREATE TABLE "system" (
"name" varchar(64) NOT NULL PRIMARY KEY,
"value" long
);
INSERT INTO "system" ("name", "value") VALUES ('roundcube-version', '2022081200');
|