mirror of
https://github.com/christianselig/apollo-backend
synced 2024-11-12 23:17:44 +00:00
add schema
This commit is contained in:
parent
dbcda74ab8
commit
69675d4d5c
3 changed files with 75 additions and 11 deletions
64
docs/schema.sql
Normal file
64
docs/schema.sql
Normal file
|
@ -0,0 +1,64 @@
|
|||
CREATE TABLE accounts (
|
||||
id SERIAL PRIMARY KEY,
|
||||
reddit_account_id character varying(32) DEFAULT ''::character varying,
|
||||
username character varying(20) DEFAULT ''::character varying UNIQUE,
|
||||
access_token character varying(64) DEFAULT ''::character varying,
|
||||
refresh_token character varying(64) DEFAULT ''::character varying,
|
||||
token_expires_at timestamp without time zone,
|
||||
last_message_id character varying(32) DEFAULT ''::character varying,
|
||||
next_notification_check_at timestamp without time zone,
|
||||
next_stuck_notification_check_at timestamp without time zone,
|
||||
check_count integer DEFAULT 0
|
||||
);
|
||||
|
||||
CREATE TABLE devices (
|
||||
id SERIAL PRIMARY KEY,
|
||||
apns_token character varying(100) UNIQUE,
|
||||
sandbox boolean,
|
||||
expires_at timestamp without time zone,
|
||||
grace_period_expires_at timestamp without time zone
|
||||
);
|
||||
|
||||
CREATE TABLE devices_accounts (
|
||||
id SERIAL PRIMARY KEY,
|
||||
account_id integer REFERENCES accounts(id) ON DELETE CASCADE,
|
||||
device_id integer REFERENCES devices(id) ON DELETE CASCADE,
|
||||
watcher_notifiable boolean DEFAULT true,
|
||||
inbox_notifiable boolean DEFAULT true,
|
||||
global_mute boolean DEFAULT false
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX devices_accounts_account_id_device_id_idx ON devices_accounts(account_id int4_ops,device_id int4_ops);
|
||||
|
||||
CREATE TABLE subreddits (
|
||||
id SERIAL PRIMARY KEY,
|
||||
subreddit_id character varying(32) DEFAULT ''::character varying UNIQUE,
|
||||
name character varying(32) DEFAULT ''::character varying,
|
||||
next_check_at timestamp without time zone
|
||||
);
|
||||
|
||||
CREATE TABLE users (
|
||||
id SERIAL PRIMARY KEY,
|
||||
user_id character varying(32) DEFAULT ''::character varying UNIQUE,
|
||||
name character varying(32) DEFAULT ''::character varying,
|
||||
next_check_at timestamp without time zone
|
||||
);
|
||||
|
||||
CREATE TABLE watchers (
|
||||
id SERIAL PRIMARY KEY,
|
||||
created_at timestamp without time zone,
|
||||
last_notified_at timestamp without time zone,
|
||||
device_id integer REFERENCES devices(id) ON DELETE CASCADE,
|
||||
account_id integer REFERENCES accounts(id) ON DELETE CASCADE,
|
||||
watchee_id integer,
|
||||
upvotes integer DEFAULT 0,
|
||||
keyword character varying(32) DEFAULT ''::character varying,
|
||||
flair character varying(32) DEFAULT ''::character varying,
|
||||
domain character varying(32) DEFAULT ''::character varying,
|
||||
hits integer DEFAULT 0,
|
||||
type integer DEFAULT 0,
|
||||
label character varying(64) DEFAULT ''::character varying,
|
||||
author character varying(32) DEFAULT ''::character varying,
|
||||
subreddit character varying(32) DEFAULT ''::character varying
|
||||
);
|
||||
|
|
@ -49,7 +49,7 @@ func (p *postgresAccountRepository) fetch(ctx context.Context, query string, arg
|
|||
|
||||
func (p *postgresAccountRepository) GetByID(ctx context.Context, id int64) (domain.Account, error) {
|
||||
query := `
|
||||
SELECT id, username, account_id, access_token, refresh_token, token_expires_at,
|
||||
SELECT id, username, reddit_account_id, access_token, refresh_token, token_expires_at,
|
||||
last_message_id, next_notification_check_at, next_stuck_notification_check_at,
|
||||
check_count
|
||||
FROM accounts
|
||||
|
@ -68,11 +68,11 @@ func (p *postgresAccountRepository) GetByID(ctx context.Context, id int64) (doma
|
|||
|
||||
func (p *postgresAccountRepository) GetByRedditID(ctx context.Context, id string) (domain.Account, error) {
|
||||
query := `
|
||||
SELECT id, username, account_id, access_token, refresh_token, token_expires_at,
|
||||
SELECT id, username, reddit_account_id, access_token, refresh_token, token_expires_at,
|
||||
last_message_id, next_notification_check_at, next_stuck_notification_check_at,
|
||||
check_count
|
||||
FROM accounts
|
||||
WHERE account_id = $1`
|
||||
WHERE reddit_account_id = $1`
|
||||
|
||||
accs, err := p.fetch(ctx, query, id)
|
||||
if err != nil {
|
||||
|
@ -87,7 +87,7 @@ func (p *postgresAccountRepository) GetByRedditID(ctx context.Context, id string
|
|||
}
|
||||
func (p *postgresAccountRepository) CreateOrUpdate(ctx context.Context, acc *domain.Account) error {
|
||||
query := `
|
||||
INSERT INTO accounts (username, account_id, access_token, refresh_token, token_expires_at,
|
||||
INSERT INTO accounts (username, reddit_account_id, access_token, refresh_token, token_expires_at,
|
||||
last_message_id, next_notification_check_at, next_stuck_notification_check_at)
|
||||
VALUES ($1, $2, $3, $4, $5, '', NOW(), NOW())
|
||||
ON CONFLICT(username) DO
|
||||
|
@ -110,7 +110,7 @@ func (p *postgresAccountRepository) CreateOrUpdate(ctx context.Context, acc *dom
|
|||
func (p *postgresAccountRepository) Create(ctx context.Context, acc *domain.Account) error {
|
||||
query := `
|
||||
INSERT INTO accounts
|
||||
(username, account_id, access_token, refresh_token, token_expires_at,
|
||||
(username, reddit_account_id, access_token, refresh_token, token_expires_at,
|
||||
last_message_id, next_notification_check_at, next_stuck_notification_check_at)
|
||||
VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
|
||||
RETURNING id`
|
||||
|
@ -133,7 +133,7 @@ func (p *postgresAccountRepository) Update(ctx context.Context, acc *domain.Acco
|
|||
query := `
|
||||
UPDATE accounts
|
||||
SET username = $2,
|
||||
account_id = $3,
|
||||
reddit_account_id = $3,
|
||||
access_token = $4,
|
||||
refresh_token = $5,
|
||||
token_expires_at = $6,
|
||||
|
@ -196,7 +196,7 @@ func (p *postgresAccountRepository) Disassociate(ctx context.Context, acc *domai
|
|||
|
||||
func (p *postgresAccountRepository) GetByAPNSToken(ctx context.Context, token string) ([]domain.Account, error) {
|
||||
query := `
|
||||
SELECT accounts.id, username, accounts.account_id, access_token, refresh_token, token_expires_at,
|
||||
SELECT accounts.id, username, accounts.reddit_account_id, access_token, refresh_token, token_expires_at,
|
||||
last_message_id, next_notification_check_at, next_stuck_notification_check_at,
|
||||
check_count
|
||||
FROM accounts
|
||||
|
|
|
@ -93,7 +93,7 @@ func (p *postgresWatcherRepository) GetByID(ctx context.Context, id int64) (doma
|
|||
devices.apns_token,
|
||||
devices.sandbox,
|
||||
accounts.id,
|
||||
accounts.account_id,
|
||||
accounts.reddit_account_id,
|
||||
accounts.access_token,
|
||||
accounts.refresh_token,
|
||||
COALESCE(subreddits.name, '') AS subreddit_label,
|
||||
|
@ -138,7 +138,7 @@ func (p *postgresWatcherRepository) GetByTypeAndWatcheeID(ctx context.Context, t
|
|||
devices.apns_token,
|
||||
devices.sandbox,
|
||||
accounts.id,
|
||||
accounts.account_id,
|
||||
accounts.reddit_account_id,
|
||||
accounts.access_token,
|
||||
accounts.refresh_token,
|
||||
COALESCE(subreddits.name, '') AS subreddit_label,
|
||||
|
@ -191,7 +191,7 @@ func (p *postgresWatcherRepository) GetByDeviceAPNSTokenAndAccountRedditID(ctx c
|
|||
devices.apns_token,
|
||||
devices.sandbox,
|
||||
accounts.id,
|
||||
accounts.account_id,
|
||||
accounts.reddit_account_id,
|
||||
accounts.access_token,
|
||||
accounts.refresh_token,
|
||||
COALESCE(subreddits.name, '') AS subreddit_label,
|
||||
|
@ -203,7 +203,7 @@ func (p *postgresWatcherRepository) GetByDeviceAPNSTokenAndAccountRedditID(ctx c
|
|||
LEFT JOIN users ON watchers.type = 1 AND watchers.watchee_id = users.id
|
||||
WHERE
|
||||
devices.apns_token = $1 AND
|
||||
accounts.account_id = $2`
|
||||
accounts.reddit_account_id = $2`
|
||||
|
||||
return p.fetch(ctx, query, apns, rid)
|
||||
}
|
||||
|
|
Loading…
Reference in a new issue