Skip to content

Commit

Permalink
feat(friends): Start implementing database layer
Browse files Browse the repository at this point in the history
  • Loading branch information
Likqez committed Nov 30, 2024
1 parent f0ac62d commit 05ef067
Show file tree
Hide file tree
Showing 6 changed files with 141 additions and 0 deletions.
122 changes: 122 additions & 0 deletions DB/friendships.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,122 @@
CREATE TYPE friendship_status AS ENUM ('pending', 'accepted', 'declined', 'blocked');

CREATE TABLE friendships
(
friendship_id BIGSERIAL PRIMARY KEY,
user1_id UUID NOT NULL,
user2_id UUID NOT NULL,
status friendship_status NOT NULL,
action_user_id UUID NOT NULL, -- The user who performed the last action
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),

-- Ensure user1_id is always less than user2_id to prevent duplicate friendships
CONSTRAINT ensure_user_order CHECK (user1_id < user2_id),
CONSTRAINT unique_friendship UNIQUE (user1_id, user2_id),

-- Foreign keys
CONSTRAINT fk_user1 FOREIGN KEY (user1_id) REFERENCES users (id),
CONSTRAINT fk_user2 FOREIGN KEY (user2_id) REFERENCES users (id),
CONSTRAINT fk_action_user FOREIGN KEY (action_user_id) REFERENCES users (id)
);

CREATE INDEX idx_friendship_user1 ON friendships (user1_id, status);
CREATE INDEX idx_friendship_user2 ON friendships (user2_id, status);

-- Functions

-- automatically update updated_at timestamp
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS
$$
BEGIN
NEW.updated_at = now();
RETURN NEW;
END;
$$;

CREATE TRIGGER update_friendships_timestamp
BEFORE UPDATE
ON friendships
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();

-- Send a friend request
CREATE OR REPLACE FUNCTION send_friend_request(sender_id UUID, receiver_id UUID) RETURNS void AS
$$
DECLARE
smaller_id UUID;
larger_id UUID;
BEGIN
-- Determine order of IDs using UUID comparison
IF sender_id < receiver_id THEN
smaller_id := sender_id;
larger_id := receiver_id;
ELSE
smaller_id := receiver_id;
larger_id := sender_id;
END IF;

-- Insert friendship record
INSERT INTO friendships (user1_id, user2_id, status, action_user_id)
VALUES (smaller_id, larger_id, 'pending', sender_id)
ON CONFLICT (user1_id, user2_id) DO UPDATE
SET status = CASE
WHEN friendships.status = 'declined' THEN 'pending'::friendship_status
ELSE friendships.status
END,
action_user_id = sender_id;
END;
$$ LANGUAGE plpgsql;

-- retrieve incoming friend requests
CREATE OR REPLACE FUNCTION get_incoming_friend_requests(user_id UUID)
RETURNS TABLE
(
friendship_id BIGINT,
sender_id UUID,
receiver_id UUID,
status friendship_status,
created_at TIMESTAMP WITH TIME ZONE,
updated_at TIMESTAMP WITH TIME ZONE
)
AS
$$
BEGIN
RETURN QUERY
SELECT f.friendship_id,
CASE
WHEN f.user1_id = user_id THEN f.user2_id
ELSE f.user1_id
END AS sender_id,
user_id AS receiver_id,
f.status,
f.created_at,
f.updated_at
FROM friendships f
WHERE (f.user1_id = user_id OR f.user2_id = user_id)
AND f.status = 'pending'
AND f.action_user_id != user_id;
END;
$$ LANGUAGE plpgsql;

CREATE OR REPLACE FUNCTION accept_friend_request_by_id(friendship_id_param BIGINT)
RETURNS void AS
$$
BEGIN
UPDATE friendships
SET status = 'accepted'
WHERE friendship_id = friendship_id_param
AND status = 'pending';

IF NOT FOUND THEN
RAISE EXCEPTION 'No pending friend request found with this ID';
END IF;
END;
$$ LANGUAGE plpgsql;


-- examples
SELECT *
FROM get_incoming_friend_requests('d2e6a9a3-a0be-45ce-ae39-676c6a88c53a');
SELECT accept_friend_request_by_id(4::bigint);
15 changes: 15 additions & 0 deletions DB/users.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,15 @@
CREATE TABLE users
(
id uuid not null references auth.users on delete cascade,
avatar_url text,
username text not null,
spotify_id text not null,
spotify_visibility boolean not null default false,
primary key (id)
);

ALTER TABLE users
ADD CONSTRAINT unique_username UNIQUE (username),
ADD CONSTRAINT valid_username check (username <> '' AND length(trim(username)) >= 4 AND username ~ '^[a-zA-Z0-9_]+$');

CREATE INDEX idx_username ON users(username);
1 change: 1 addition & 0 deletions server/api/v1/user/friends/index.delete.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
// remove friend
1 change: 1 addition & 0 deletions server/api/v1/user/friends/index.get.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
// Not relative to userid because you should always only be able to see your own friends
1 change: 1 addition & 0 deletions server/api/v1/user/friends/index.post.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
// send friend invite
1 change: 1 addition & 0 deletions server/api/v1/user/friends/index.put.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
// accept or decline friend request

0 comments on commit 05ef067

Please sign in to comment.