Skip to content

Commit

Permalink
Schema changes
Browse files Browse the repository at this point in the history
user table: make it more close to telegram user object: add photo and make lang nullable
comment unused tables to prevent schema migrations later

Signed-off-by: Yan Minari <yangm97@gmail.com>
  • Loading branch information
yangm97 committed Sep 28, 2018
1 parent f415fe2 commit f46b97e
Showing 1 changed file with 102 additions and 71 deletions.
173 changes: 102 additions & 71 deletions schema/1.sql
Original file line number Diff line number Diff line change
@@ -1,3 +1,10 @@
--
-- Types
--

-- CREATE TYPE chat_type AS ENUM ('group', 'supergroup', 'channel'); -- private chats live under the "user" table
-- CREATE TYPE chat_user_status AS ENUM ('creator', 'administrator', 'member', 'restricted', 'left', 'kicked');

--
-- Tables
--
Expand All @@ -6,99 +13,123 @@ CREATE TABLE "user" (
id integer NOT NULL,
is_bot boolean NOT NULL,
first_name text NOT NULL,

last_name text,
username text,
language_code varchar(35) DEFAULT 'en-gb' NOT NULL,
created_at timestamptz DEFAULT now() NOT NULL,
updated_at timestamptz DEFAULT now() NOT NULL
);
language_code varchar(35), -- BCP47/RFC5646 section 4.4.1 recommended maximum IETF tag length
photo jsonb,

CREATE TABLE "chat" (
id bigint NOT NULL,
type varchar(10) NOT NULL,
title text NOT NULL, -- Only private chats don't have titles, and we already store private info under "user"
username text,
invite_link text,
created_at timestamptz DEFAULT now() NOT NULL,
updated_at timestamptz DEFAULT now() NOT NULL
);

CREATE TABLE "chat_user" (
chat_id bigint NOT NULL,
user_id integer NOT NULL,
status varchar(13) NOT NULL,
until_date timestamptz,

can_be_edited boolean DEFAULT false NOT NULL, -- Administrators only
can_change_info boolean DEFAULT false NOT NULL, -- Administrators only
can_post_messages boolean DEFAULT false NOT NULL, -- Administrators only, channels only
can_edit_messages boolean DEFAULT false NOT NULL, -- Administrators only, channels only
can_delete_messages boolean DEFAULT false NOT NULL, -- Administrators only
can_invite_users boolean DEFAULT false NOT NULL, -- Administrators only
can_restrict_members boolean DEFAULT false NOT NULL, -- Administrators only
can_pin_messages boolean DEFAULT false NOT NULL, -- Administrators only
can_promote_members boolean DEFAULT false NOT NULL, -- Administrators only

can_send_messages boolean DEFAULT true NOT NULL, -- Restricted only
can_send_media_messages boolean DEFAULT true NOT NULL, -- Restricted only, implies can_send_messages
can_send_other_messages boolean DEFAULT true NOT NULL, -- Restricted only, implies can_send_media_messages
can_add_web_page_previews boolean DEFAULT true NOT NULL, -- Restricted only, implies can_send_media_messages
updated_at timestamptz DEFAULT now() NOT NULL,

created_at timestamptz DEFAULT now() NOT NULL,
updated_at timestamptz DEFAULT now() NOT NULL
CONSTRAINT user_pkey PRIMARY KEY (id)
);

-- CREATE TABLE "chat" (
-- id bigint NOT NULL,
-- type chat_type NOT NULL,
-- title text NOT NULL, -- Only private chats don't have titles, and we already store private info under "user"

-- username text, -- Supergroups and channels only
-- all_members_are_administrators boolean, -- Normal groups only
-- photo jsonb,
-- description text, -- Supergroups and channels only
-- invite_link text, -- Supergroups and channels only
-- pinned_message jsonb, -- Supergroups and channels only
-- sticker_set_name text, -- Supergroups only
-- can_set_sticker_set bool, -- Supergroups only

-- created_at timestamptz DEFAULT now() NOT NULL,
-- updated_at timestamptz DEFAULT now() NOT NULL,

-- CONSTRAINT chat_pkey PRIMARY KEY (id)
-- );

-- CREATE TABLE "chat_user" (
-- chat_id bigint NOT NULL REFERENCES "chat"(id),
-- user_id integer NOT NULL REFERENCES "user"(id),
-- status chat_user_status NOT NULL,

-- created_at timestamptz DEFAULT now() NOT NULL,
-- updated_at timestamptz DEFAULT now() NOT NULL,

-- CONSTRAINT chat_user_pkey PRIMARY KEY (chat_id, user_id)
-- );

-- CREATE TABLE "chat_user_admin" (
-- chat_id bigint NOT NULL REFERENCES "chat"(id),
-- user_id integer NOT NULL REFERENCES "user"(id),

-- can_be_edited boolean DEFAULT false NOT NULL,
-- can_change_info boolean DEFAULT false NOT NULL,
-- can_delete_messages boolean DEFAULT false NOT NULL,
-- can_invite_users boolean DEFAULT false NOT NULL,
-- can_restrict_members boolean DEFAULT false NOT NULL,
-- can_pin_messages boolean DEFAULT false NOT NULL,
-- can_promote_members boolean DEFAULT false NOT NULL,
-- can_post_messages boolean DEFAULT false NOT NULL, -- Channels only
-- can_edit_messages boolean DEFAULT false NOT NULL, -- Channels only

-- created_at timestamptz DEFAULT now() NOT NULL,
-- updated_at timestamptz DEFAULT now() NOT NULL,

-- CONSTRAINT chat_user_admin_pkey PRIMARY KEY (chat_id, user_id)
-- );

-- CREATE TABLE "chat_user_restricted" (
-- chat_id bigint NOT NULL REFERENCES "chat"(id),
-- user_id integer NOT NULL REFERENCES "user"(id),

-- until_date timestamptz, -- Date when restrictions will be lifted for this user, if ever
-- can_send_messages boolean DEFAULT true NOT NULL,
-- can_send_media_messages boolean DEFAULT true NOT NULL, -- implies can_send_messages
-- can_send_other_messages boolean DEFAULT true NOT NULL, -- implies can_send_media_messages
-- can_add_web_page_previews boolean DEFAULT true NOT NULL -- implies can_send_media_messages

-- created_at timestamptz DEFAULT now() NOT NULL,
-- updated_at timestamptz DEFAULT now() NOT NULL,

-- CONSTRAINT chat_user_restricted_pkey PRIMARY KEY (chat_id, user_id)
-- );

--
-- Triggers
--

CREATE OR REPLACE FUNCTION trigger_set_updated_at()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = now();
RETURN NEW;
END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER set_updated_at
BEFORE UPDATE ON "user"
FOR EACH ROW
EXECUTE PROCEDURE trigger_set_updated_at();

CREATE TRIGGER set_updated_at
BEFORE UPDATE ON "chat"
FOR EACH ROW
EXECUTE PROCEDURE trigger_set_updated_at();
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = now();
RETURN NEW;
END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER set_updated_at
BEFORE UPDATE ON "chat_user"
FOR EACH ROW
EXECUTE PROCEDURE trigger_set_updated_at();

--
-- Primary Keys
--

ALTER TABLE ONLY "user"
ADD CONSTRAINT user_pkey PRIMARY KEY (id);
BEFORE UPDATE ON "user"
FOR EACH ROW
EXECUTE PROCEDURE trigger_set_updated_at();

ALTER TABLE ONLY "chat"
ADD CONSTRAINT chat_pkey PRIMARY KEY (id);
-- CREATE TRIGGER set_updated_at
-- BEFORE UPDATE ON "chat"
-- FOR EACH ROW
-- EXECUTE PROCEDURE trigger_set_updated_at();

ALTER TABLE ONLY "chat_user"
ADD CONSTRAINT chat_user_pkey PRIMARY KEY (chat_id, user_id);
-- CREATE TRIGGER set_updated_at
-- BEFORE UPDATE ON "chat_user"
-- FOR EACH ROW
-- EXECUTE PROCEDURE trigger_set_updated_at();

--
-- Foreign Keys
--

ALTER TABLE ONLY chat_user
ADD CONSTRAINT chat_user_chat_id_fkey FOREIGN KEY (chat_id)
REFERENCES "chat"(id) ON UPDATE CASCADE ON DELETE CASCADE;
-- ALTER TABLE chat_user
-- ADD CONSTRAINT chat_user_chat_id_fkey FOREIGN KEY (chat_id)
-- REFERENCES "chat"(id) ON UPDATE CASCADE ON DELETE CASCADE;

ALTER TABLE ONLY chat_user
ADD CONSTRAINT chat_user_user_id_fkey FOREIGN KEY (user_id)
REFERENCES "user"(id) ON UPDATE CASCADE ON DELETE CASCADE;
-- ALTER TABLE chat_user
-- ADD CONSTRAINT chat_user_user_id_fkey FOREIGN KEY (user_id)
-- REFERENCES "user"(id) ON UPDATE CASCADE ON DELETE CASCADE;

--
-- Indexes
Expand Down

0 comments on commit f46b97e

Please sign in to comment.