SQL for Spot feature (#2513)

* feat(spot): added sql for spot feature

* feat(spot): added sql code to all related files

* feat(spot): added default value for created_at

* feat(spot): added spots schema

* feat(spot): applied a new spots schema to all sql requests
This commit is contained in:
Alexander 2024-09-05 15:57:39 +02:00 committed by GitHub
parent 9725bba276
commit 840f133f73
No known key found for this signature in database
GPG key ID: B5690EEEBB952194
9 changed files with 206 additions and 16 deletions

View file

@ -55,7 +55,7 @@ func (k *keysImpl) Set(spotID, expiration uint64, user *auth.User) (*Key, error)
expiredAt := now.Add(time.Duration(expiration) * time.Second)
sql := `
WITH updated AS (
UPDATE spots_keys
UPDATE spots.keys
SET
spot_key = CASE
WHEN expired_at < $1 THEN $2
@ -70,7 +70,7 @@ func (k *keysImpl) Set(spotID, expiration uint64, user *auth.User) (*Key, error)
),
inserted AS (
INSERT INTO spots_keys (spot_key, spot_id, user_id, expiration, created_at, expired_at)
INSERT INTO spots.keys (spot_key, spot_id, user_id, expiration, created_at, expired_at)
SELECT $2, $6, $3, $4, $1, $5
WHERE NOT EXISTS (SELECT 1 FROM updated)
RETURNING spot_key, expiration, expired_at
@ -99,8 +99,8 @@ func (k *keysImpl) Get(spotID uint64, user *auth.User) (*Key, error) {
key := &Key{}
sql := `SELECT k.spot_key, k.expiration, k.expired_at
FROM spots_keys k
JOIN spots s ON s.spot_id = k.spot_id
FROM spots.keys k
JOIN spots.spots s ON s.spot_id = k.spot_id
WHERE k.spot_id = $1 AND s.tenant_id = $2`
if err := k.conn.QueryRow(sql, spotID, user.TenantID).Scan(&key.Value, &key.Expiration, &key.ExpiredAt); err != nil {
k.log.Error(context.Background(), "failed to get key: %v", err)
@ -123,7 +123,7 @@ func (k *keysImpl) IsValid(key string) (*auth.User, error) {
expiredAt time.Time
)
// Get userID if key is valid
sql := `SELECT user_id, expired_at FROM spots_keys WHERE spot_key = $1`
sql := `SELECT user_id, expired_at FROM spots.keys WHERE spot_key = $1`
if err := k.conn.QueryRow(sql, key).Scan(&userID, &expiredAt); err != nil {
k.log.Error(context.Background(), "failed to get key: %v", err)
return nil, fmt.Errorf("key not found")

View file

@ -127,7 +127,7 @@ func (s *spotsImpl) encodeComment(comment *Comment) string {
}
func (s *spotsImpl) add(spot *Spot) error {
sql := `INSERT INTO spots (spot_id, name, user_id, tenant_id, duration, crop, comments, created_at)
sql := `INSERT INTO spots.spots (spot_id, name, user_id, tenant_id, duration, crop, comments, created_at)
VALUES ($1, $2, $3, $4, $5, $6, $7, $8)`
var comments []string
for _, comment := range spot.Comments {
@ -154,8 +154,8 @@ func (s *spotsImpl) GetByID(user *auth.User, spotID uint64) (*Spot, error) {
func (s *spotsImpl) getByID(spotID uint64, user *auth.User) (*Spot, error) {
sql := `SELECT s.name, u.email, s.duration, s.crop, s.comments, s.created_at
FROM spots s
JOIN users u ON s.user_id = u.user_id
FROM spots.spots s
JOIN public.users u ON s.user_id = u.user_id
WHERE s.spot_id = $1 AND s.tenant_id = $2 AND s.deleted_at IS NULL`
spot := &Spot{ID: spotID}
var comments []string
@ -202,8 +202,8 @@ func (s *spotsImpl) Get(user *auth.User, opts *GetOpts) ([]*Spot, uint64, error)
func (s *spotsImpl) getAll(user *auth.User, opts *GetOpts) ([]*Spot, uint64, error) {
sql := `SELECT COUNT(1) OVER () AS total, s.spot_id, s.name, u.email, s.duration, s.created_at
FROM spots s
JOIN users u ON s.user_id = u.user_id
FROM spots.spots s
JOIN public.users u ON s.user_id = u.user_id
WHERE s.tenant_id = $1 AND s.deleted_at IS NULL`
args := []interface{}{user.TenantID}
if opts.UserID != 0 {
@ -260,7 +260,7 @@ func (s *spotsImpl) UpdateName(user *auth.User, spotID uint64, newName string) (
func (s *spotsImpl) updateName(spotID uint64, newName string, user *auth.User) (*Spot, error) {
sql := `WITH updated AS (
UPDATE spots SET name = $1, updated_at = $2
UPDATE spots.spots SET name = $1, updated_at = $2
WHERE spot_id = $3 AND tenant_id = $4 AND deleted_at IS NULL RETURNING *)
SELECT COUNT(*) FROM updated`
updated := 0
@ -295,7 +295,7 @@ func (s *spotsImpl) AddComment(user *auth.User, spotID uint64, comment *Comment)
func (s *spotsImpl) addComment(spotID uint64, newComment *Comment, user *auth.User) (*Spot, error) {
sql := `WITH updated AS (
UPDATE spots
UPDATE spots.spots
SET comments = array_append(comments, $1), updated_at = $2
WHERE spot_id = $3 AND tenant_id = $4 AND deleted_at IS NULL AND COALESCE(array_length(comments, 1), 0) < $5
RETURNING *)
@ -325,7 +325,7 @@ func (s *spotsImpl) Delete(user *auth.User, spotIds []uint64) error {
}
func (s *spotsImpl) deleteSpots(spotIds []uint64, user *auth.User) error {
sql := `WITH updated AS (UPDATE spots SET deleted_at = NOW() WHERE tenant_id = $1 AND spot_id IN (`
sql := `WITH updated AS (UPDATE spots.spots SET deleted_at = NOW() WHERE tenant_id = $1 AND spot_id IN (`
args := []interface{}{user.TenantID}
for i, spotID := range spotIds {
sql += fmt.Sprintf("$%d,", i+2)

View file

@ -41,7 +41,7 @@ func (s *streamsImpl) Add(spotID uint64, originalStream string) error {
modifiedContent := strings.Join(lines, "\n")
now := time.Now()
// Insert playlist to DB
sql := `INSERT INTO spots_streams (spot_id, original_playlist, modified_playlist, created_at, expired_at)
sql := `INSERT INTO spots.streams (spot_id, original_playlist, modified_playlist, created_at, expired_at)
VALUES ($1, $2, $3, $4, $5) ON CONFLICT (spot_id) DO UPDATE SET original_playlist = $2, modified_playlist = $3,
created_at = $4, expired_at = $5`
if err := s.conn.Exec(sql, spotID, originalStream, modifiedContent, now, now.Add(10*time.Minute)); err != nil {
@ -63,7 +63,7 @@ func (s *streamsImpl) Get(spotID uint64) ([]byte, error) {
WHEN expired_at > $2 THEN 'modified'
ELSE 'original'
END AS playlist_type
FROM spots_streams
FROM spots.streams
WHERE spot_id = $1`
var playlist, flag string
if err := s.conn.QueryRow(sql, spotID, time.Now()).Scan(&playlist, &flag); err != nil {
@ -90,7 +90,7 @@ func (s *streamsImpl) Get(spotID uint64) ([]byte, error) {
modifiedPlaylist := strings.Join(lines, "\n")
// Save modified playlist to DB
sql = `UPDATE spots_streams SET modified_playlist = $1, expired_at = $2 WHERE spot_id = $3`
sql = `UPDATE spots.streams SET modified_playlist = $1, expired_at = $2 WHERE spot_id = $3`
if err := s.conn.Exec(sql, modifiedPlaylist, time.Now().Add(10*time.Minute), spotID); err != nil {
s.log.Warn(context.Background(), "Error updating modified playlist: %v", err)
}

View file

@ -61,6 +61,53 @@ ALTER TABLE IF EXISTS public.users
]
}'::jsonb;
CREATE SCHEMA IF NOT EXISTS spots;
CREATE TABLE IF NOT EXISTS spots.spots
(
spot_id BIGINT NOT NULL PRIMARY KEY,
name TEXT NOT NULL,
user_id BIGINT NOT NULL REFERENCES public.users (user_id) ON DELETE CASCADE,
tenant_id BIGINT NOT NULL REFERENCES public.tenants (tenant_id) ON DELETE CASCADE,
duration INT NOT NULL,
crop INT[],
comments TEXT[],
status TEXT DEFAULT 'pending',
created_at timestamp without time zone NOT NULL DEFAULT timezone('utc'::text, now()),
updated_at timestamp DEFAULT NULL,
deleted_at timestamp DEFAULT NULL
);
CREATE TABLE IF NOT EXISTS spots.keys
(
spot_key TEXT NOT NULL PRIMARY KEY,
spot_id BIGINT NOT NULL UNIQUE REFERENCES spots.spots (spot_id) ON DELETE CASCADE,
user_id BIGINT NOT NULL,
expiration BIGINT NOT NULL,
expired_at timestamp NOT NULL,
created_at timestamp NOT NULL,
updated_at timestamp DEFAULT NULL
);
CREATE TABLE IF NOT EXISTS spots.streams
(
spot_id BIGINT NOT NULL PRIMARY KEY REFERENCES spots.spots (spot_id) ON DELETE CASCADE,
original_playlist TEXT NOT NULL,
modified_playlist TEXT NOT NULL,
created_at timestamp NOT NULL,
expired_at timestamp NOT NULL
);
CREATE TABLE IF NOT EXISTS spots.tasks
(
spot_id BIGINT NOT NULL PRIMARY KEY REFERENCES spots.spots (spot_id) ON DELETE CASCADE,
duration INT NOT NULL,
crop INT[],
status TEXT NOT NULL,
error TEXT DEFAULT NULL,
added_time timestamp NOT NULL
);
COMMIT;
\elif :is_next

View file

@ -1323,5 +1323,51 @@ CREATE TABLE or_cache.autocomplete_top_values
UNIQUE NULLS NOT DISTINCT (project_id, event_type, event_key)
);
CREATE SCHEMA IF NOT EXISTS spots;
CREATE TABLE IF NOT EXISTS spots.spots
(
spot_id BIGINT NOT NULL PRIMARY KEY,
name TEXT NOT NULL,
user_id BIGINT NOT NULL REFERENCES public.users (user_id) ON DELETE CASCADE,
tenant_id BIGINT NOT NULL REFERENCES public.tenants (tenant_id) ON DELETE CASCADE,
duration INT NOT NULL,
crop INT[],
comments TEXT[],
status TEXT DEFAULT 'pending',
created_at timestamp without time zone NOT NULL DEFAULT timezone('utc'::text, now()),
updated_at timestamp DEFAULT NULL,
deleted_at timestamp DEFAULT NULL
);
CREATE TABLE IF NOT EXISTS spots.keys
(
spot_key TEXT NOT NULL PRIMARY KEY,
spot_id BIGINT NOT NULL UNIQUE REFERENCES spots.spots (spot_id) ON DELETE CASCADE,
user_id BIGINT NOT NULL,
expiration BIGINT NOT NULL,
expired_at timestamp NOT NULL,
created_at timestamp NOT NULL,
updated_at timestamp DEFAULT NULL
);
CREATE TABLE IF NOT EXISTS spots.streams
(
spot_id BIGINT NOT NULL PRIMARY KEY REFERENCES spots.spots (spot_id) ON DELETE CASCADE,
original_playlist TEXT NOT NULL,
modified_playlist TEXT NOT NULL,
created_at timestamp NOT NULL,
expired_at timestamp NOT NULL
);
CREATE TABLE IF NOT EXISTS spots.tasks
(
spot_id BIGINT NOT NULL PRIMARY KEY REFERENCES spots.spots (spot_id) ON DELETE CASCADE,
duration INT NOT NULL,
crop INT[],
status TEXT NOT NULL,
error TEXT DEFAULT NULL,
added_time timestamp NOT NULL
);
COMMIT;

View file

@ -28,6 +28,8 @@ DROP SCHEMA or_cache CASCADE;
ALTER TABLE IF EXISTS public.tenants
DROP COLUMN IF EXISTS scope_state;
DROP SCHEMA IF EXISTS spots CASCADE;
COMMIT;
\elif :is_next

View file

@ -50,6 +50,53 @@ ALTER TABLE IF EXISTS public.users
]
}'::jsonb;
CREATE SCHEMA IF NOT EXISTS spots;
CREATE TABLE IF NOT EXISTS spots.spots
(
spot_id BIGINT NOT NULL PRIMARY KEY,
name TEXT NOT NULL,
user_id BIGINT NOT NULL REFERENCES public.users (user_id) ON DELETE CASCADE,
tenant_id BIGINT NOT NULL,
duration INT NOT NULL,
crop INT[],
comments TEXT[],
status TEXT DEFAULT 'pending',
created_at timestamp without time zone NOT NULL DEFAULT timezone('utc'::text, now()),
updated_at timestamp DEFAULT NULL,
deleted_at timestamp DEFAULT NULL
);
CREATE TABLE IF NOT EXISTS spots.keys
(
spot_key TEXT NOT NULL PRIMARY KEY,
spot_id BIGINT NOT NULL UNIQUE REFERENCES spots.spots (spot_id) ON DELETE CASCADE,
user_id BIGINT NOT NULL,
expiration BIGINT NOT NULL,
expired_at timestamp NOT NULL,
created_at timestamp NOT NULL,
updated_at timestamp DEFAULT NULL
);
CREATE TABLE IF NOT EXISTS spots.streams
(
spot_id BIGINT NOT NULL PRIMARY KEY REFERENCES spots.spots (spot_id) ON DELETE CASCADE,
original_playlist TEXT NOT NULL,
modified_playlist TEXT NOT NULL,
created_at timestamp NOT NULL,
expired_at timestamp NOT NULL
);
CREATE TABLE IF NOT EXISTS spots.tasks
(
spot_id BIGINT NOT NULL PRIMARY KEY REFERENCES spots.spots (spot_id) ON DELETE CASCADE,
duration INT NOT NULL,
crop INT[],
status TEXT NOT NULL,
error TEXT DEFAULT NULL,
added_time timestamp NOT NULL
);
COMMIT;
\elif :is_next

View file

@ -1208,5 +1208,51 @@ CREATE TABLE or_cache.autocomplete_top_values
UNIQUE NULLS NOT DISTINCT (project_id, event_type, event_key)
);
CREATE SCHEMA IF NOT EXISTS spots;
CREATE TABLE IF NOT EXISTS spots.spots
(
spot_id BIGINT NOT NULL PRIMARY KEY,
name TEXT NOT NULL,
user_id BIGINT NOT NULL REFERENCES public.users (user_id) ON DELETE CASCADE,
tenant_id BIGINT NOT NULL,
duration INT NOT NULL,
crop INT[],
comments TEXT[],
status TEXT DEFAULT 'pending',
created_at timestamp without time zone NOT NULL DEFAULT timezone('utc'::text, now()),
updated_at timestamp DEFAULT NULL,
deleted_at timestamp DEFAULT NULL
);
CREATE TABLE IF NOT EXISTS spots.keys
(
spot_key TEXT NOT NULL PRIMARY KEY,
spot_id BIGINT NOT NULL UNIQUE REFERENCES spots.spots (spot_id) ON DELETE CASCADE,
user_id BIGINT NOT NULL,
expiration BIGINT NOT NULL,
expired_at timestamp NOT NULL,
created_at timestamp NOT NULL,
updated_at timestamp DEFAULT NULL
);
CREATE TABLE IF NOT EXISTS spots.streams
(
spot_id BIGINT NOT NULL PRIMARY KEY REFERENCES spots.spots (spot_id) ON DELETE CASCADE,
original_playlist TEXT NOT NULL,
modified_playlist TEXT NOT NULL,
created_at timestamp NOT NULL,
expired_at timestamp NOT NULL
);
CREATE TABLE IF NOT EXISTS spots.tasks
(
spot_id BIGINT NOT NULL PRIMARY KEY REFERENCES spots.spots (spot_id) ON DELETE CASCADE,
duration INT NOT NULL,
crop INT[],
status TEXT NOT NULL,
error TEXT DEFAULT NULL,
added_time timestamp NOT NULL
);
COMMIT;

View file

@ -28,6 +28,8 @@ DROP SCHEMA or_cache CASCADE;
ALTER TABLE IF EXISTS public.tenants
DROP COLUMN IF EXISTS scope_state;
DROP SCHEMA IF EXISTS spots CASCADE;
COMMIT;
\elif :is_next