Skip to content

Commit 61e1f7d

Browse files
committed
feat: add supabase migration files | docs for setup
1 parent 9187a0e commit 61e1f7d

File tree

2 files changed

+253
-0
lines changed

2 files changed

+253
-0
lines changed

supabase/README.md

Lines changed: 65 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,65 @@
1+
# Supabase Setup
2+
3+
## Running Migrations
4+
5+
### Option 1: Supabase Dashboard (Easiest for now)
6+
7+
1. Go to your Supabase project dashboard
8+
2. Navigate to **SQL Editor**
9+
3. Copy and paste the contents of `migrations/20241112000000_initial_schema.sql`
10+
4. Click **Run** to execute the migration
11+
12+
### Option 2: Supabase CLI (For later)
13+
14+
If you want to use the CLI for local development:
15+
16+
```bash
17+
# Install Supabase CLI
18+
brew install supabase/tap/supabase
19+
20+
# Initialize Supabase in your project (if not already done)
21+
supabase init
22+
23+
# Link to your remote project
24+
supabase link --project-ref your-project-ref
25+
26+
# Push migrations to remote
27+
supabase db push
28+
```
29+
30+
## Database Schema
31+
32+
### Tables
33+
34+
- **profiles** - Extends `auth.users` with app-specific data
35+
- **sleep_sessions** - Core sleep tracking data
36+
- **user_settings** - User preferences (target hours, timezone)
37+
38+
### Key Features
39+
40+
- ✅ Row Level Security (RLS) enabled on all tables
41+
- ✅ Users can only access their own data
42+
- ✅ Automatic `updated_at` timestamp updates
43+
- ✅ Auto-creation of profile and settings on user signup
44+
- ✅ Proper indexes for query performance
45+
- ✅ Validation constraints (end_time >= start_time, etc.)
46+
47+
## Testing the Schema
48+
49+
After running the migration, test in the Supabase dashboard:
50+
51+
1. **Create a test user** (Authentication > Users > Add user)
52+
2. **Verify auto-creation**: Check that profile and settings were created automatically
53+
3. **Test RLS**: Try inserting/querying data as that user
54+
4. **Test constraints**: Try inserting invalid data (end_time < start_time) - should fail
55+
56+
## Environment Variables
57+
58+
You'll need these for your iOS and web apps:
59+
60+
```bash
61+
SUPABASE_URL=https://your-project-ref.supabase.co
62+
SUPABASE_ANON_KEY=your-anon-key
63+
```
64+
65+
Find these in: Project Settings > API
Lines changed: 188 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,188 @@
1+
-- Initial schema for Sleep Tracker
2+
-- Creates profiles, sleep_sessions, and user_settings tables with RLS policies
3+
4+
-- Enable UUID extension
5+
create extension if not exists "uuid-ossp";
6+
7+
-- ============================================================================
8+
-- PROFILES TABLE
9+
-- ============================================================================
10+
-- Extends auth.users with app-specific profile data
11+
create table public.profiles (
12+
id uuid primary key references auth.users(id) on delete cascade,
13+
created_at timestamptz not null default now(),
14+
updated_at timestamptz not null default now()
15+
);
16+
17+
-- Enable RLS
18+
alter table public.profiles enable row level security;
19+
20+
-- RLS Policies for profiles
21+
create policy "Users can view their own profile"
22+
on public.profiles
23+
for select
24+
using (auth.uid() = id);
25+
26+
create policy "Users can update their own profile"
27+
on public.profiles
28+
for update
29+
using (auth.uid() = id);
30+
31+
create policy "Users can insert their own profile"
32+
on public.profiles
33+
for insert
34+
with check (auth.uid() = id);
35+
36+
-- ============================================================================
37+
-- SLEEP SESSIONS TABLE
38+
-- ============================================================================
39+
create table public.sleep_sessions (
40+
id uuid primary key default gen_random_uuid(),
41+
user_id uuid not null references auth.users(id) on delete cascade,
42+
start_time timestamptz not null,
43+
end_time timestamptz not null,
44+
source text not null default 'manual',
45+
updated_at timestamptz not null,
46+
47+
-- Constraints
48+
constraint valid_end_time check (end_time >= start_time),
49+
constraint valid_source check (source in ('manual', 'widget', 'shortcut'))
50+
);
51+
52+
-- Enable RLS
53+
alter table public.sleep_sessions enable row level security;
54+
55+
-- RLS Policies for sleep_sessions
56+
create policy "Users can view their own sleep sessions"
57+
on public.sleep_sessions
58+
for select
59+
using (auth.uid() = user_id);
60+
61+
create policy "Users can insert their own sleep sessions"
62+
on public.sleep_sessions
63+
for insert
64+
with check (auth.uid() = user_id);
65+
66+
create policy "Users can update their own sleep sessions"
67+
on public.sleep_sessions
68+
for update
69+
using (auth.uid() = user_id);
70+
71+
create policy "Users can delete their own sleep sessions"
72+
on public.sleep_sessions
73+
for delete
74+
using (auth.uid() = user_id);
75+
76+
-- Indexes for performance
77+
create index sleep_sessions_user_id_idx on public.sleep_sessions(user_id);
78+
create index sleep_sessions_start_time_idx on public.sleep_sessions(start_time desc);
79+
create index sleep_sessions_user_start_idx on public.sleep_sessions(user_id, start_time desc);
80+
81+
-- ============================================================================
82+
-- USER SETTINGS TABLE
83+
-- ============================================================================
84+
create table public.user_settings (
85+
user_id uuid primary key references auth.users(id) on delete cascade,
86+
target_hours decimal(3,1) not null default 8.0,
87+
timezone text not null default 'UTC',
88+
created_at timestamptz not null default now(),
89+
updated_at timestamptz not null default now(),
90+
91+
-- Constraints
92+
constraint valid_target_hours check (target_hours > 0 and target_hours <= 24)
93+
);
94+
95+
-- Enable RLS
96+
alter table public.user_settings enable row level security;
97+
98+
-- RLS Policies for user_settings
99+
create policy "Users can view their own settings"
100+
on public.user_settings
101+
for select
102+
using (auth.uid() = user_id);
103+
104+
create policy "Users can insert their own settings"
105+
on public.user_settings
106+
for insert
107+
with check (auth.uid() = user_id);
108+
109+
create policy "Users can update their own settings"
110+
on public.user_settings
111+
for update
112+
using (auth.uid() = user_id);
113+
114+
-- ============================================================================
115+
-- FUNCTIONS & TRIGGERS
116+
-- ============================================================================
117+
118+
-- Function to automatically update updated_at timestamp
119+
create or replace function public.handle_updated_at()
120+
returns trigger as $$
121+
begin
122+
new.updated_at = now();
123+
return new;
124+
end;
125+
$$ language plpgsql;
126+
127+
-- Triggers for updated_at (profiles and user_settings)
128+
create trigger set_updated_at
129+
before update on public.profiles
130+
for each row
131+
execute function public.handle_updated_at();
132+
133+
create trigger set_updated_at
134+
before update on public.user_settings
135+
for each row
136+
execute function public.handle_updated_at();
137+
138+
-- Special function for sleep_sessions: set updated_at to end_time on insert, now() on update
139+
create or replace function public.handle_sleep_session_updated_at()
140+
returns trigger as $$
141+
begin
142+
if TG_OP = 'INSERT' then
143+
new.updated_at = new.end_time;
144+
elsif TG_OP = 'UPDATE' then
145+
new.updated_at = now();
146+
end if;
147+
return new;
148+
end;
149+
$$ language plpgsql;
150+
151+
-- Trigger for sleep_sessions updated_at
152+
create trigger set_sleep_session_updated_at
153+
before insert or update on public.sleep_sessions
154+
for each row
155+
execute function public.handle_sleep_session_updated_at();
156+
157+
-- Function to create profile and settings on user signup
158+
create or replace function public.handle_new_user()
159+
returns trigger as $$
160+
begin
161+
insert into public.profiles (id)
162+
values (new.id);
163+
164+
insert into public.user_settings (user_id)
165+
values (new.id);
166+
167+
return new;
168+
end;
169+
$$ language plpgsql security definer;
170+
171+
-- Trigger to auto-create profile and settings when user signs up
172+
create trigger on_auth_user_created
173+
after insert on auth.users
174+
for each row
175+
execute function public.handle_new_user();
176+
177+
-- ============================================================================
178+
-- COMMENTS (for documentation)
179+
-- ============================================================================
180+
181+
comment on table public.profiles is 'User profiles extending auth.users';
182+
comment on table public.sleep_sessions is 'Sleep tracking sessions with start and end times';
183+
comment on table public.user_settings is 'User preferences and settings';
184+
185+
comment on column public.sleep_sessions.source is 'How the session was created: manual, widget, or shortcut';
186+
comment on column public.user_settings.target_hours is 'Target sleep hours per night (for future sleep debt calculation)';
187+
comment on column public.user_settings.timezone is 'User timezone for display purposes';
188+

0 commit comments

Comments
 (0)