mirror of
https://github.com/mito-systems/ranger-app.git
synced 2026-01-09 09:54:07 +00:00
161 lines
4.6 KiB
PL/PgSQL
161 lines
4.6 KiB
PL/PgSQL
-- Schema for Supabase to set up user points tracking
|
|
-- This file is just for reference and should be executed in the Supabase SQL Editor
|
|
|
|
-- Create user_points table to track total points for each user
|
|
CREATE TABLE IF NOT EXISTS user_points (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
user_id UUID NOT NULL UNIQUE,
|
|
email TEXT NOT NULL,
|
|
total_points INTEGER NOT NULL DEFAULT 0,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT now(),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT now()
|
|
);
|
|
|
|
-- Create point_transactions table to track individual point awards
|
|
CREATE TABLE IF NOT EXISTS point_transactions (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
user_id UUID NOT NULL REFERENCES user_points(user_id),
|
|
points INTEGER NOT NULL,
|
|
transaction_type TEXT NOT NULL,
|
|
image_hash TEXT,
|
|
image_url TEXT,
|
|
description TEXT,
|
|
animal_type TEXT,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT now()
|
|
);
|
|
|
|
-- Create indexes for faster queries
|
|
CREATE INDEX IF NOT EXISTS idx_point_transactions_user_id ON point_transactions(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_point_transactions_image_hash ON point_transactions(image_hash);
|
|
|
|
-- Create a function to increment user points (matching TypeScript parameter names and order)
|
|
CREATE OR REPLACE FUNCTION increment_user_points(
|
|
user_id_param TEXT,
|
|
points_param INTEGER
|
|
)
|
|
RETURNS void AS $$
|
|
BEGIN
|
|
UPDATE user_points
|
|
SET
|
|
total_points = total_points + points_param,
|
|
updated_at = now()
|
|
WHERE user_id = user_id_param::UUID;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Create a function to get current points for a user (matching TypeScript parameter names and order)
|
|
CREATE OR REPLACE FUNCTION get_current_points(
|
|
user_id_param TEXT
|
|
)
|
|
RETURNS INTEGER AS $$
|
|
DECLARE
|
|
current_points INTEGER;
|
|
BEGIN
|
|
SELECT total_points INTO current_points
|
|
FROM user_points
|
|
WHERE user_id = user_id_param::UUID;
|
|
|
|
RETURN COALESCE(current_points, 0);
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Create a function to create a user (matching TypeScript parameter names and order)
|
|
CREATE OR REPLACE FUNCTION create_user_points(
|
|
user_id_param TEXT,
|
|
email_param TEXT,
|
|
initial_points INTEGER DEFAULT 0
|
|
)
|
|
RETURNS json AS $$
|
|
DECLARE
|
|
new_user_record user_points;
|
|
BEGIN
|
|
INSERT INTO user_points (user_id, email, total_points, created_at, updated_at)
|
|
VALUES (user_id_param::UUID, email_param, initial_points, now(), now())
|
|
RETURNING * INTO new_user_record;
|
|
|
|
RETURN row_to_json(new_user_record);
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
-- Create a function to create a point transaction (matching TypeScript parameter names and order)
|
|
CREATE OR REPLACE FUNCTION create_point_transaction(
|
|
user_id_param TEXT,
|
|
points_param INTEGER,
|
|
transaction_type_param TEXT,
|
|
image_hash_param TEXT DEFAULT NULL,
|
|
image_url_param TEXT DEFAULT NULL,
|
|
description_param TEXT DEFAULT NULL,
|
|
animal_type_param TEXT DEFAULT NULL
|
|
)
|
|
RETURNS json AS $$
|
|
DECLARE
|
|
new_transaction point_transactions;
|
|
BEGIN
|
|
INSERT INTO point_transactions (
|
|
user_id,
|
|
points,
|
|
transaction_type,
|
|
image_hash,
|
|
image_url,
|
|
description,
|
|
animal_type,
|
|
created_at
|
|
)
|
|
VALUES (
|
|
user_id_param::UUID,
|
|
points_param,
|
|
transaction_type_param,
|
|
image_hash_param,
|
|
image_url_param,
|
|
description_param,
|
|
animal_type_param,
|
|
now()
|
|
)
|
|
RETURNING * INTO new_transaction;
|
|
|
|
RETURN row_to_json(new_transaction);
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
-- Create a function to get user transactions (matching TypeScript parameter names and order)
|
|
CREATE OR REPLACE FUNCTION get_user_transactions(
|
|
user_id_param TEXT
|
|
)
|
|
RETURNS SETOF point_transactions AS $$
|
|
BEGIN
|
|
RETURN QUERY
|
|
SELECT *
|
|
FROM point_transactions
|
|
WHERE user_id = user_id_param::UUID
|
|
ORDER BY created_at DESC;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
-- Add Row Level Security (RLS) policies
|
|
-- Enable RLS
|
|
ALTER TABLE user_points ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE point_transactions ENABLE ROW LEVEL SECURITY;
|
|
|
|
-- Skip policy creation if they already exist (will generate warnings but not fail)
|
|
-- Comment out policy sections if you've already created them
|
|
|
|
-- Create policies section - uncomment if you need to recreate policies
|
|
/*
|
|
-- user_points policies
|
|
CREATE POLICY "Users can view their own points"
|
|
ON user_points FOR SELECT
|
|
USING (auth.uid() = user_id);
|
|
|
|
CREATE POLICY "Service role can manage all points"
|
|
ON user_points FOR ALL
|
|
USING (auth.role() = 'service_role');
|
|
|
|
-- point_transactions policies
|
|
CREATE POLICY "Users can view their own transactions"
|
|
ON point_transactions FOR SELECT
|
|
USING (auth.uid() = user_id);
|
|
|
|
CREATE POLICY "Service role can manage all transactions"
|
|
ON point_transactions FOR ALL
|
|
USING (auth.role() = 'service_role');
|
|
*/ |