supabase-postgres-best-practices
references/schema-foreign-key-indexes.md
.md 60 lines
Content
---
title: Index Foreign Key Columns
impact: HIGH
impactDescription: 10-100x faster JOINs and CASCADE operations
tags: foreign-key, indexes, joins, schema
---
## Index Foreign Key Columns
Postgres does not automatically index foreign key columns. Missing indexes cause slow JOINs and CASCADE operations.
**Incorrect (unindexed foreign key):**
```sql
create table orders (
id bigint generated always as identity primary key,
customer_id bigint references customers(id) on delete cascade,
total numeric(10,2)
);
-- No index on customer_id!
-- JOINs and ON DELETE CASCADE both require full table scan
select * from orders where customer_id = 123; -- Seq Scan
delete from customers where id = 123; -- Locks table, scans all orders
```
**Correct (indexed foreign key):**
```sql
create table orders (
id bigint generated always as identity primary key,
customer_id bigint references customers(id) on delete cascade,
total numeric(10,2)
);
-- Always index the FK column
create index orders_customer_id_idx on orders (customer_id);
-- Now JOINs and cascades are fast
select * from orders where customer_id = 123; -- Index Scan
delete from customers where id = 123; -- Uses index, fast cascade
```
Find missing FK indexes:
```sql
select
conrelid::regclass as table_name,
a.attname as fk_column
from pg_constraint c
join pg_attribute a on a.attrelid = c.conrelid and a.attnum = any(c.conkey)
where c.contype = 'f'
and not exists (
select 1 from pg_index i
where i.indrelid = c.conrelid and a.attnum = any(i.indkey)
);
```
Reference: [Foreign Keys](https://www.postgresql.org/docs/current/ddl-constraints.html#DDL-CONSTRAINTS-FK)