From 174327c25cd68f203e0985df51b94765738c7dce Mon Sep 17 00:00:00 2001 From: Aleksander Machniak <alec@alec.pl> Date: Tue, 11 Jun 2013 03:33:21 -0400 Subject: [PATCH] Merge pull request #77 from dpc22/realnames --- SQL/postgres.initial.sql | 388 ++++++++++++++++++++++++++++++++---------------------- 1 files changed, 229 insertions(+), 159 deletions(-) diff --git a/SQL/postgres.initial.sql b/SQL/postgres.initial.sql old mode 100755 new mode 100644 index 4e74a22..f18cb6a --- a/SQL/postgres.initial.sql +++ b/SQL/postgres.initial.sql @@ -1,19 +1,31 @@ +-- Roundcube Webmail initial database structure + +-- +-- Sequence "users_seq" +-- Name: users_seq; Type: SEQUENCE; Schema: public; Owner: postgres +-- + +CREATE SEQUENCE users_seq + INCREMENT BY 1 + NO MAXVALUE + NO MINVALUE + CACHE 1; + -- -- Table "users" -- Name: users; Type: TABLE; Schema: public; Owner: postgres -- CREATE TABLE users ( - user_id integer DEFAULT nextval('user_ids'::text) NOT NULL, - username character varying(128) DEFAULT ''::character varying NOT NULL, - mail_host character varying(128) DEFAULT ''::character varying NOT NULL, - alias character varying(128) DEFAULT ''::character varying NOT NULL, + user_id integer DEFAULT nextval('users_seq'::text) PRIMARY KEY, + username varchar(128) DEFAULT '' NOT NULL, + mail_host varchar(128) DEFAULT '' NOT NULL, created timestamp with time zone DEFAULT now() NOT NULL, - last_login timestamp with time zone DEFAULT now() NOT NULL, - "language" character varying(5) DEFAULT 'en'::character varying NOT NULL, - preferences text DEFAULT ''::text NOT NULL + last_login timestamp with time zone DEFAULT NULL, + "language" varchar(5), + preferences text DEFAULT ''::text NOT NULL, + CONSTRAINT users_username_key UNIQUE (username, mail_host) ); - -- @@ -22,14 +34,27 @@ -- CREATE TABLE "session" ( - sess_id character varying(40) DEFAULT ''::character varying NOT NULL, + sess_id varchar(128) DEFAULT '' PRIMARY KEY, created timestamp with time zone DEFAULT now() NOT NULL, changed timestamp with time zone DEFAULT now() NOT NULL, - ip character varying(16) NOT NULL, + ip varchar(41) NOT NULL, vars text NOT NULL ); +CREATE INDEX session_changed_idx ON session (changed); + +-- +-- Sequence "identities_seq" +-- Name: identities_seq; Type: SEQUENCE; Schema: public; Owner: postgres +-- + +CREATE SEQUENCE identities_seq + START WITH 1 + INCREMENT BY 1 + NO MAXVALUE + NO MINVALUE + CACHE 1; -- -- Table "identities" @@ -37,18 +62,36 @@ -- CREATE TABLE identities ( - identity_id integer DEFAULT nextval('identity_ids'::text) NOT NULL, - user_id integer DEFAULT 0 NOT NULL, - del integer DEFAULT 0 NOT NULL, - standard integer DEFAULT 0 NOT NULL, - name character varying(128) NOT NULL, - organization character varying(128), - email character varying(128) NOT NULL, - "reply-to" character varying(128), - bcc character varying(128), - signature text + identity_id integer DEFAULT nextval('identities_seq'::text) PRIMARY KEY, + user_id integer NOT NULL + REFERENCES users (user_id) ON DELETE CASCADE ON UPDATE CASCADE, + changed timestamp with time zone DEFAULT now() 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 text, + 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); + + +-- +-- Sequence "contacts_seq" +-- Name: contacts_seq; Type: SEQUENCE; Schema: public; Owner: postgres +-- + +CREATE SEQUENCE contacts_seq + START WITH 1 + INCREMENT BY 1 + NO MAXVALUE + NO MINVALUE + CACHE 1; -- -- Table "contacts" @@ -56,18 +99,63 @@ -- CREATE TABLE contacts ( - contact_id integer DEFAULT nextval('contact_ids'::text) NOT NULL, - user_id integer DEFAULT 0 NOT NULL, + contact_id integer DEFAULT nextval('contacts_seq'::text) PRIMARY KEY, + user_id integer NOT NULL + REFERENCES users (user_id) ON DELETE CASCADE ON UPDATE CASCADE, changed timestamp with time zone DEFAULT now() NOT NULL, - del integer DEFAULT 0 NOT NULL, - name character varying(128) DEFAULT ''::character varying NOT NULL, - email character varying(128) DEFAULT ''::character varying NOT NULL, - firstname character varying(128) DEFAULT ''::character varying NOT NULL, - surname character varying(128) DEFAULT ''::character varying NOT NULL, - vcard text + del smallint DEFAULT 0 NOT NULL, + name varchar(128) DEFAULT '' NOT NULL, + email text DEFAULT '' NOT NULL, + firstname varchar(128) DEFAULT '' NOT NULL, + surname varchar(128) DEFAULT '' NOT NULL, + vcard text, + words text ); +CREATE INDEX contacts_user_id_idx ON contacts (user_id, del); +-- +-- Sequence "contactgroups_seq" +-- Name: contactgroups_seq; Type: SEQUENCE; Schema: public; Owner: postgres +-- + +CREATE SEQUENCE contactgroups_seq + INCREMENT BY 1 + NO MAXVALUE + NO MINVALUE + CACHE 1; + +-- +-- Table "contactgroups" +-- Name: contactgroups; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE contactgroups ( + contactgroup_id integer DEFAULT nextval('contactgroups_seq'::text) PRIMARY KEY, + user_id integer NOT NULL + REFERENCES users(user_id) ON DELETE CASCADE ON UPDATE CASCADE, + changed timestamp with time zone DEFAULT now() NOT NULL, + del smallint NOT NULL DEFAULT 0, + name varchar(128) NOT NULL DEFAULT '' +); + +CREATE INDEX contactgroups_user_id_idx ON contactgroups (user_id, del); + +-- +-- Table "contactgroupmembers" +-- Name: contactgroupmembers; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE contactgroupmembers ( + contactgroup_id integer NOT NULL + REFERENCES contactgroups(contactgroup_id) ON DELETE CASCADE ON UPDATE CASCADE, + contact_id integer NOT NULL + REFERENCES contacts(contact_id) ON DELETE CASCADE ON UPDATE CASCADE, + created timestamp with time zone DEFAULT now() NOT NULL, + PRIMARY KEY (contactgroup_id, contact_id) +); + +CREATE INDEX contactgroupmembers_contact_id_idx ON contactgroupmembers (contact_id); -- -- Table "cache" @@ -75,149 +163,131 @@ -- CREATE TABLE "cache" ( - cache_id integer DEFAULT nextval('cache_ids'::text) NOT NULL, - user_id integer DEFAULT 0 NOT NULL, - session_id character varying(40), - cache_key character varying(128) DEFAULT ''::character varying NOT NULL, + user_id integer NOT NULL + REFERENCES users (user_id) ON DELETE CASCADE ON UPDATE CASCADE, + cache_key varchar(128) DEFAULT '' NOT NULL, created timestamp with time zone DEFAULT now() NOT NULL, + expires timestamp with time zone DEFAULT NULL, data text NOT NULL ); - +CREATE INDEX cache_user_id_idx ON "cache" (user_id, cache_key); +CREATE INDEX cache_expires_idx ON "cache" (expires); -- --- Table "messages" --- Name: messages; Type: TABLE; Schema: public; Owner: postgres +-- Table "cache_shared" +-- Name: cache_shared; Type: TABLE; Schema: public; Owner: postgres -- -CREATE TABLE "messages" ( - message_id integer DEFAULT nextval('message_ids'::text) NOT NULL, - user_id integer DEFAULT 0 NOT NULL, - del integer DEFAULT 0 NOT NULL, - cache_key character varying(128) DEFAULT ''::character varying NOT NULL, - idx integer DEFAULT 0 NOT NULL, - uid integer DEFAULT 0 NOT NULL, - subject character varying(128) DEFAULT ''::character varying NOT NULL, - "from" character varying(128) DEFAULT ''::character varying NOT NULL, - "to" character varying(128) DEFAULT ''::character varying NOT NULL, - cc character varying(128) DEFAULT ''::character varying NOT NULL, - date timestamp with time zone NOT NULL, - size integer DEFAULT 0 NOT NULL, - headers text NOT NULL, - body text +CREATE TABLE "cache_shared" ( + cache_key varchar(255) NOT NULL, + created timestamp with time zone DEFAULT now() NOT NULL, + expires timestamp with time zone DEFAULT NULL, + data text NOT NULL +); + +CREATE INDEX cache_shared_cache_key_idx ON "cache_shared" (cache_key); +CREATE INDEX cache_shared_expires_idx ON "cache_shared" (expires); + +-- +-- Table "cache_index" +-- Name: cache_index; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE cache_index ( + user_id integer NOT NULL + REFERENCES users (user_id) ON DELETE CASCADE ON UPDATE CASCADE, + mailbox varchar(255) NOT NULL, + expires timestamp with time zone DEFAULT NULL, + valid smallint NOT NULL DEFAULT 0, + data text NOT NULL, + PRIMARY KEY (user_id, mailbox) +); + +CREATE INDEX cache_index_expires_idx ON cache_index (expires); + +-- +-- Table "cache_thread" +-- Name: cache_thread; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE cache_thread ( + user_id integer NOT NULL + REFERENCES users (user_id) ON DELETE CASCADE ON UPDATE CASCADE, + mailbox varchar(255) NOT NULL, + expires timestamp with time zone DEFAULT NULL, + data text NOT NULL, + PRIMARY KEY (user_id, mailbox) +); + +CREATE INDEX cache_thread_expires_idx ON cache_thread (expires); + +-- +-- Table "cache_messages" +-- Name: cache_messages; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE cache_messages ( + user_id integer NOT NULL + REFERENCES users (user_id) ON DELETE CASCADE ON UPDATE CASCADE, + mailbox varchar(255) NOT NULL, + uid integer NOT NULL, + expires timestamp with time zone DEFAULT NULL, + data text NOT NULL, + flags integer NOT NULL DEFAULT 0, + PRIMARY KEY (user_id, mailbox, uid) +); + +CREATE INDEX cache_messages_expires_idx ON cache_messages (expires); + +-- +-- Table "dictionary" +-- Name: dictionary; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE dictionary ( + user_id integer DEFAULT NULL + REFERENCES users (user_id) ON DELETE CASCADE ON UPDATE CASCADE, + "language" varchar(5) NOT NULL, + data text NOT NULL, + CONSTRAINT dictionary_user_id_language_key UNIQUE (user_id, "language") +); + +-- +-- Sequence "searches_seq" +-- Name: searches_seq; Type: SEQUENCE; Schema: public; Owner: postgres +-- + +CREATE SEQUENCE searches_seq + INCREMENT BY 1 + NO MAXVALUE + NO MINVALUE + CACHE 1; + +-- +-- Table "searches" +-- Name: searches; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE searches ( + search_id integer DEFAULT nextval('searches_seq'::text) PRIMARY KEY, + user_id integer NOT NULL + REFERENCES users (user_id) ON DELETE CASCADE ON UPDATE CASCADE, + "type" smallint DEFAULT 0 NOT NULL, + name varchar(128) NOT NULL, + data text NOT NULL, + CONSTRAINT searches_user_id_key UNIQUE (user_id, "type", name) ); - -- --- Add primary keys +-- Table "system" +-- Name: system; Type: TABLE; Schema: public; Owner: postgres -- -ALTER TABLE ONLY "cache" - ADD CONSTRAINT cache_pkey PRIMARY KEY (cache_id); +CREATE TABLE "system" ( + name varchar(64) NOT NULL PRIMARY KEY, + value text +); - -ALTER TABLE ONLY "contacts" - ADD CONSTRAINT contacts_pkey PRIMARY KEY (contact_id); - - -ALTER TABLE ONLY identities - ADD CONSTRAINT identities_pkey PRIMARY KEY (identity_id); - - -ALTER TABLE ONLY "session" - ADD CONSTRAINT session_pkey PRIMARY KEY (sess_id); - - -ALTER TABLE ONLY "users" - ADD CONSTRAINT users_pkey PRIMARY KEY (user_id); - - -ALTER TABLE ONLY "messages" - ADD CONSTRAINT messages_pkey PRIMARY KEY (message_id); - - --- --- Reference keys --- - -ALTER TABLE ONLY "cache" - ADD CONSTRAINT "$1" FOREIGN KEY (user_id) REFERENCES users(user_id); - -ALTER TABLE ONLY "cache" - ADD CONSTRAINT "$2" FOREIGN KEY (session_id) REFERENCES "session"(sess_id); - - -ALTER TABLE ONLY "contacts" - ADD CONSTRAINT "$1" FOREIGN KEY (user_id) REFERENCES users(user_id); - - -ALTER TABLE ONLY "identities" - ADD CONSTRAINT "$1" FOREIGN KEY (user_id) REFERENCES users(user_id); - - -ALTER TABLE ONLY "messages" - ADD CONSTRAINT "$1" FOREIGN KEY (user_id) REFERENCES users(user_id); - - --- --- Sequence "cache_ids" --- Name: cache_ids; Type: SEQUENCE; Schema: public; Owner: postgres --- - -CREATE SEQUENCE cache_ids - INCREMENT BY 1 - NO MAXVALUE - NO MINVALUE - CACHE 1; - - --- --- Sequence "contact_ids" --- Name: contact_ids; Type: SEQUENCE; Schema: public; Owner: postgres --- - -CREATE SEQUENCE contact_ids - START WITH 1 - INCREMENT BY 1 - NO MAXVALUE - NO MINVALUE - CACHE 1; - - --- --- Sequence "identity_ids" --- Name: identity_ids; Type: SEQUENCE; Schema: public; Owner: postgres --- - -CREATE SEQUENCE identity_ids - START WITH 1 - INCREMENT BY 1 - NO MAXVALUE - NO MINVALUE - CACHE 1; - - --- --- Sequence "user_ids" --- Name: user_ids; Type: SEQUENCE; Schema: public; Owner: postgres --- - -CREATE SEQUENCE user_ids - INCREMENT BY 1 - NO MAXVALUE - NO MINVALUE - CACHE 1; - - --- --- Sequence "message_ids" --- Name: message_ids; Type: SEQUENCE; Schema: public; Owner: postgres --- - -CREATE SEQUENCE message_ids - INCREMENT BY 1 - NO MAXVALUE - NO MINVALUE - CACHE 1; - +INSERT INTO system (name, value) VALUES ('roundcube-version', '2013061000'); -- Gitblit v1.9.1