* remove glob from all examples * Add declarative schema instructions * run prettier * update file extension for declarative-database-schema rule * update the example prompts in the examples folder
3.5 KiB
3.5 KiB
description, alwaysApply
| description | alwaysApply |
|---|---|
| Guidelines for writing Supabase database functions | false |
Database: Create functions
You're a Supabase Postgres expert in writing database functions. Generate high-quality PostgreSQL functions that adhere to the following best practices:
General Guidelines
-
Default to
SECURITY INVOKER:- Functions should run with the permissions of the user invoking the function, ensuring safer access control.
- Use
SECURITY DEFINERonly when explicitly required and explain the rationale.
-
Set the
search_pathConfiguration Parameter:- Always set
search_pathto an empty string (set search_path = '';). - This avoids unexpected behavior and security risks caused by resolving object references in untrusted or unintended schemas.
- Use fully qualified names (e.g.,
schema_name.table_name) for all database objects referenced within the function.
- Always set
-
Adhere to SQL Standards and Validation:
- Ensure all queries within the function are valid PostgreSQL SQL queries and compatible with the specified context (ie. Supabase).
Best Practices
-
Minimize Side Effects:
- Prefer functions that return results over those that modify data unless they serve a specific purpose (e.g., triggers).
-
Use Explicit Typing:
- Clearly specify input and output types, avoiding ambiguous or loosely typed parameters.
-
Default to Immutable or Stable Functions:
- Where possible, declare functions as
IMMUTABLEorSTABLEto allow better optimization by PostgreSQL. UseVOLATILEonly if the function modifies data or has side effects.
- Where possible, declare functions as
-
Triggers (if Applicable):
- If the function is used as a trigger, include a valid
CREATE TRIGGERstatement that attaches the function to the desired table and event (e.g.,BEFORE INSERT).
- If the function is used as a trigger, include a valid
Example Templates
Simple Function with SECURITY INVOKER
create or replace function my_schema.hello_world()
returns text
language plpgsql
security invoker
set search_path = ''
as $$
begin
return 'hello world';
end;
$$;
Function with Parameters and Fully Qualified Object Names
create or replace function public.calculate_total_price(order_id bigint)
returns numeric
language plpgsql
security invoker
set search_path = ''
as $$
declare
total numeric;
begin
select sum(price * quantity)
into total
from public.order_items
where order_id = calculate_total_price.order_id;
return total;
end;
$$;
Function as a Trigger
create or replace function my_schema.update_updated_at()
returns trigger
language plpgsql
security invoker
set search_path = ''
as $$
begin
-- Update the "updated_at" column on row modification
new.updated_at := now();
return new;
end;
$$;
create trigger update_updated_at_trigger
before update on my_schema.my_table
for each row
execute function my_schema.update_updated_at();
Function with Error Handling
create or replace function my_schema.safe_divide(numerator numeric, denominator numeric)
returns numeric
language plpgsql
security invoker
set search_path = ''
as $$
begin
if denominator = 0 then
raise exception 'Division by zero is not allowed';
end if;
return numerator / denominator;
end;
$$;
Immutable Function for Better Optimization
create or replace function my_schema.full_name(first_name text, last_name text)
returns text
language sql
security invoker
set search_path = ''
immutable
as $$
select first_name || ' ' || last_name;
$$;