-- Create blog_posts table create table public.blog_posts ( id uuid primary key default gen_random_uuid(), slug text unique not null, title text not null, content text not null, featured_image_id text, featured_image_url text, author_id uuid references auth.users(id) not null, status text not null default 'draft' check (status in ('draft', 'published')), published_at timestamptz, view_count integer default 0, created_at timestamptz default now(), updated_at timestamptz default now() ); -- Indexes for performance create index idx_blog_posts_slug on blog_posts(slug); create index idx_blog_posts_status on blog_posts(status); create index idx_blog_posts_published_at on blog_posts(published_at desc nulls last); create index idx_blog_posts_author on blog_posts(author_id); -- Enable RLS alter table blog_posts enable row level security; -- RLS Policies create policy "Public can read published posts" on blog_posts for select using (status = 'published'); create policy "Admins can do everything" on blog_posts for all using (is_moderator(auth.uid())); -- Auto-update updated_at timestamp create trigger update_blog_posts_updated_at before update on blog_posts for each row execute function update_updated_at_column(); -- Function to increment view count create or replace function increment_blog_view_count(post_slug text) returns void language plpgsql security definer as $$ begin update blog_posts set view_count = view_count + 1 where slug = post_slug; end; $$;