Skip to content

Commit c2051ae

Browse files
committed
Add SQL style guide as Cursor rule
- Add comprehensive SQL style guide from postgres.ai as Cursor rule - Rule applies to *.sql and *.psql files - Includes formatting guidelines, best practices, and examples - Update .gitignore to exclude only environment.json, keep rules tracked
1 parent b21e613 commit c2051ae

File tree

2 files changed

+137
-0
lines changed

2 files changed

+137
-0
lines changed

.cursor/rules/sql-style.mdc

Lines changed: 136 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,136 @@
1+
---
2+
globs: *.sql,*.psql
3+
description: SQL style guide rules for PostgreSQL development
4+
---
5+
6+
# SQL style guide
7+
8+
Source: [postgres.ai SQL style guide](https://postgres.ai/rules/sql-style)
9+
10+
## Core philosophy
11+
12+
From PEP8:
13+
14+
* Consistency with this style guide is important
15+
* Consistency within a project is more important
16+
* Consistency within one module or function is the most important
17+
* However, know when to be inconsistent -- sometimes style guide recommendations just aren't applicable
18+
19+
## Core rules
20+
21+
* **Use lowercase SQL keywords** (not uppercase)
22+
* Use `snake_case` for all identifiers (no CamelCase)
23+
* Names must begin with a letter and may not end in underscore
24+
* Only use letters, numbers, and underscores in names
25+
* Be explicit: always use `AS` for aliases, specify JOIN types
26+
* Root keywords on their own line (except with single argument)
27+
* Multi-line arguments must be indented relative to root keyword
28+
* Use **ISO 8601 date format**: `yyyy-mm-ddThh:mm:ss.sssss`
29+
* Foreign key naming: `user_id` to reference `users` table (singular + \_id)
30+
* Use meaningful aliases that reflect the data (not just single letters)
31+
32+
## Formatting
33+
34+
### Keywords and alignment
35+
36+
```sql
37+
-- Root keywords left-aligned
38+
-- Arguments indented relative to root keyword
39+
select
40+
client_id,
41+
submission_date
42+
from main_summary
43+
where
44+
sample_id = '42'
45+
and submission_date > '20180101'
46+
limit 10;
47+
```
48+
49+
### Comments
50+
51+
```sql
52+
/* Block comments for multi-line descriptions */
53+
-- Line comments for single line notes
54+
select
55+
client_id, -- user identifier
56+
submission_date
57+
from main_summary;
58+
```
59+
60+
### Parentheses
61+
62+
```sql
63+
-- Opening paren ends the line
64+
-- Closing paren aligns with starting line
65+
-- Contents indented
66+
with sample as (
67+
select
68+
client_id,
69+
submission_date
70+
from main_summary
71+
where sample_id = '42'
72+
)
73+
```
74+
75+
### Boolean operators
76+
77+
```sql
78+
-- AND/OR at beginning of line
79+
where
80+
submission_date > '20180101'
81+
and sample_id = '42'
82+
```
83+
84+
## Table design rules
85+
86+
* Always add `id` column of type `identity generated always`
87+
* Always add table comments using `comment on table...`
88+
* Default to `public` schema
89+
* Include schema in queries for clarity
90+
* Use singular table names with `_id` suffix for foreign keys
91+
92+
## Best practices
93+
94+
* Use CTEs instead of nested queries
95+
* Explicit column names in GROUP BY (except for expressions - see below)
96+
* Functions treated as identifiers: `date_trunc()` not `DATE_TRUNC()`
97+
* One argument per line for multi-argument clauses
98+
* Use meaningful aliases that reflect the data being selected
99+
100+
### GROUP BY exception
101+
102+
```sql
103+
-- Acceptable: use numbers to avoid repeating complex expressions
104+
select
105+
date_trunc('minute', xact_start) as xact_start_minute,
106+
count(*)
107+
from pg_stat_activity
108+
group by 1
109+
order by 1;
110+
```
111+
112+
## Examples
113+
114+
### Good
115+
116+
```sql
117+
select
118+
t.client_id as client_id,
119+
date(t.created_at) as day
120+
from telemetry as t
121+
inner join users as u
122+
on t.user_id = u.id
123+
where
124+
t.submission_date > '2019-07-01'
125+
and t.sample_id = '10'
126+
group by t.client_id, day;
127+
```
128+
129+
### Bad
130+
131+
```sql
132+
SELECT t.client_id, DATE(t.created_at) day
133+
FROM telemetry t, users u
134+
WHERE t.user_id = u.id AND t.submission_date > '2019-07-01'
135+
GROUP BY 1, 2;
136+
```

.gitignore

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,2 +1,3 @@
11
.DS_Store
2+
.cursor/environment.json
23

0 commit comments

Comments
 (0)