14 KiB
Query Patterns Reference Guide
Complete reference for querying with Drizzle ORM.
Table of Contents
- Basic CRUD Operations
- Advanced Filtering
- Joins and Relations
- Aggregations
- Subqueries
- Transactions
- Batch Operations
- Raw SQL
- Performance Optimization
- Type Safety
- Common Patterns
- Related Resources
Basic CRUD Operations
Create (Insert)
Single record:
import { db } from './db';
import { users } from './db/schema';
const newUser = await db.insert(users)
.values({
email: 'user@example.com',
name: 'John Doe',
})
.returning();
console.log(newUser[0]); // { id: 1, email: '...', name: '...' }
Multiple records:
const newUsers = await db.insert(users)
.values([
{ email: 'user1@example.com', name: 'User 1' },
{ email: 'user2@example.com', name: 'User 2' },
{ email: 'user3@example.com', name: 'User 3' },
])
.returning();
With onConflictDoNothing:
await db.insert(users)
.values({ email: 'user@example.com', name: 'John' })
.onConflictDoNothing();
With onConflictDoUpdate (upsert):
await db.insert(users)
.values({ email: 'user@example.com', name: 'John' })
.onConflictDoUpdate({
target: users.email,
set: { name: 'John Updated' },
});
Read (Select)
All records:
const allUsers = await db.select().from(users);
Specific columns:
const userEmails = await db.select({
id: users.id,
email: users.email,
}).from(users);
With WHERE clause:
import { eq, gt, lt, like, and, or } from 'drizzle-orm';
const user = await db.select()
.from(users)
.where(eq(users.email, 'user@example.com'));
const activeUsers = await db.select()
.from(users)
.where(eq(users.isActive, true));
Multiple conditions:
const filteredUsers = await db.select()
.from(users)
.where(
and(
eq(users.isActive, true),
gt(users.createdAt, new Date('2024-01-01'))
)
);
With LIMIT and OFFSET:
const paginatedUsers = await db.select()
.from(users)
.limit(10)
.offset(20); // Page 3
With ORDER BY:
const sortedUsers = await db.select()
.from(users)
.orderBy(users.createdAt); // ASC by default
import { desc } from 'drizzle-orm';
const recentUsers = await db.select()
.from(users)
.orderBy(desc(users.createdAt));
Update
Single record:
await db.update(users)
.set({ name: 'Jane Doe' })
.where(eq(users.id, 1));
Multiple records:
await db.update(users)
.set({ isActive: false })
.where(eq(users.deletedAt, null));
With returning:
const updated = await db.update(users)
.set({ name: 'Updated Name' })
.where(eq(users.id, 1))
.returning();
Partial updates:
const updates: Partial<typeof users.$inferSelect> = {
name: 'New Name',
};
await db.update(users)
.set(updates)
.where(eq(users.id, 1));
Delete
Single record:
await db.delete(users)
.where(eq(users.id, 1));
Multiple records:
await db.delete(users)
.where(eq(users.isActive, false));
With returning:
const deleted = await db.delete(users)
.where(eq(users.id, 1))
.returning();
Soft delete (recommended):
await db.update(users)
.set({ deletedAt: new Date() })
.where(eq(users.id, 1));
Advanced Filtering
Comparison Operators
import { eq, ne, gt, gte, lt, lte } from 'drizzle-orm';
const adults = await db.select()
.from(users)
.where(gte(users.age, 18));
const recentPosts = await db.select()
.from(posts)
.where(gt(posts.createdAt, new Date('2024-01-01')));
const excludeAdmin = await db.select()
.from(users)
.where(ne(users.role, 'admin'));
Pattern Matching
import { like, ilike } from 'drizzle-orm';
const gmailUsers = await db.select()
.from(users)
.where(like(users.email, '%@gmail.com'));
const searchByName = await db.select()
.from(users)
.where(ilike(users.name, '%john%')); // Case-insensitive
NULL Checks
import { isNull, isNotNull } from 'drizzle-orm';
const usersWithPhone = await db.select()
.from(users)
.where(isNotNull(users.phoneNumber));
const unverifiedUsers = await db.select()
.from(users)
.where(isNull(users.emailVerifiedAt));
IN Operator
import { inArray } from 'drizzle-orm';
const specificUsers = await db.select()
.from(users)
.where(inArray(users.id, [1, 2, 3, 4, 5]));
BETWEEN
import { between } from 'drizzle-orm';
const postsThisMonth = await db.select()
.from(posts)
.where(
between(
posts.createdAt,
new Date('2024-01-01'),
new Date('2024-01-31')
)
);
Complex Conditions
import { and, or, not } from 'drizzle-orm';
const complexQuery = await db.select()
.from(users)
.where(
or(
and(
eq(users.isActive, true),
gte(users.age, 18)
),
eq(users.role, 'admin')
)
);
Joins and Relations
Manual Joins
Inner join:
const postsWithAuthors = await db.select({
postId: posts.id,
postTitle: posts.title,
authorName: users.name,
authorEmail: users.email,
})
.from(posts)
.innerJoin(users, eq(posts.authorId, users.id));
Left join:
const allPostsWithOptionalAuthors = await db.select()
.from(posts)
.leftJoin(users, eq(posts.authorId, users.id));
Relational Queries (Recommended)
Define relations first:
import { relations } from 'drizzle-orm';
export const usersRelations = relations(users, ({ many }) => ({
posts: many(posts),
}));
export const postsRelations = relations(posts, ({ one }) => ({
author: one(users, {
fields: [posts.authorId],
references: [users.id],
}),
}));
Query with relations:
const usersWithPosts = await db.query.users.findMany({
with: {
posts: true,
},
});
console.log(usersWithPosts[0].posts); // Array of posts
Nested relations:
const postsWithAuthorsAndComments = await db.query.posts.findMany({
with: {
author: true,
comments: {
with: {
author: true,
},
},
},
});
Filtered relations:
const usersWithRecentPosts = await db.query.users.findMany({
with: {
posts: {
where: gt(posts.createdAt, new Date('2024-01-01')),
orderBy: desc(posts.createdAt),
limit: 5,
},
},
});
Partial selection:
const usersWithPostTitles = await db.query.users.findMany({
columns: {
id: true,
name: true,
},
with: {
posts: {
columns: {
id: true,
title: true,
},
},
},
});
Aggregations
Count
import { count } from 'drizzle-orm';
const userCount = await db.select({
count: count(),
}).from(users);
console.log(userCount[0].count); // Total users
Count with grouping:
const postsByAuthor = await db.select({
authorId: posts.authorId,
postCount: count(),
})
.from(posts)
.groupBy(posts.authorId);
Sum, Avg, Min, Max
import { sum, avg, min, max } from 'drizzle-orm';
const stats = await db.select({
totalViews: sum(posts.views),
avgViews: avg(posts.views),
minViews: min(posts.views),
maxViews: max(posts.views),
}).from(posts);
Having
const activeAuthors = await db.select({
authorId: posts.authorId,
postCount: count(),
})
.from(posts)
.groupBy(posts.authorId)
.having(gt(count(), 5)); // Authors with > 5 posts
Subqueries
In WHERE clause
const activeUserIds = db.select({ id: users.id })
.from(users)
.where(eq(users.isActive, true));
const postsFromActiveUsers = await db.select()
.from(posts)
.where(inArray(posts.authorId, activeUserIds));
As derived table
const recentPosts = db.select()
.from(posts)
.where(gt(posts.createdAt, new Date('2024-01-01')))
.as('recentPosts');
const authorsOfRecentPosts = await db.select()
.from(users)
.innerJoin(recentPosts, eq(users.id, recentPosts.authorId));
Transactions
Only available with WebSocket adapter!
await db.transaction(async (tx) => {
const user = await tx.insert(users)
.values({ email: 'user@example.com', name: 'John' })
.returning();
await tx.insert(posts)
.values({
authorId: user[0].id,
title: 'First post',
content: 'Hello world',
});
});
With error handling:
try {
await db.transaction(async (tx) => {
await tx.insert(users).values({ email: 'user@example.com' });
await tx.insert(posts).values({ title: 'Post' });
throw new Error('Rollback!'); // Transaction rolls back
});
} catch (err) {
console.error('Transaction failed:', err);
}
Nested transactions:
await db.transaction(async (tx) => {
await tx.insert(users).values({ email: 'user1@example.com' });
await tx.transaction(async (tx2) => {
await tx2.insert(posts).values({ title: 'Post 1' });
});
});
Batch Operations
HTTP adapter alternative to transactions:
await db.batch([
db.insert(users).values({ email: 'user1@example.com' }),
db.insert(users).values({ email: 'user2@example.com' }),
db.insert(posts).values({ title: 'Post 1' }),
]);
Note: Not atomic! Use transactions if you need rollback capability.
Raw SQL
Execute raw query
import { sql } from 'drizzle-orm';
const result = await db.execute(sql`
SELECT * FROM users
WHERE email LIKE ${'%@gmail.com'}
`);
SQL in WHERE clause
const users = await db.select()
.from(users)
.where(sql`${users.email} LIKE '%@gmail.com'`);
SQL expressions
const posts = await db.select({
id: posts.id,
title: posts.title,
excerpt: sql<string>`LEFT(${posts.content}, 100)`,
}).from(posts);
Custom functions
const searchResults = await db.select()
.from(posts)
.where(
sql`to_tsvector('english', ${posts.content}) @@ to_tsquery('english', ${'search query'})`
);
Performance Optimization
Select only needed columns
❌ Bad:
const users = await db.select().from(users); // All columns
✅ Good:
const users = await db.select({
id: users.id,
email: users.email,
}).from(users);
Use indexes
Ensure indexed columns in WHERE:
// Assuming index on users.email
const user = await db.select()
.from(users)
.where(eq(users.email, 'user@example.com')); // Fast
Avoid N+1 queries
❌ Bad:
const posts = await db.select().from(posts);
for (const post of posts) {
const author = await db.select()
.from(users)
.where(eq(users.id, post.authorId)); // N queries!
}
✅ Good:
const posts = await db.query.posts.findMany({
with: {
author: true, // Single query with join
},
});
Use pagination
async function getPaginatedUsers(page: number, pageSize: number = 10) {
return db.select()
.from(users)
.limit(pageSize)
.offset((page - 1) * pageSize);
}
Batch inserts
❌ Bad:
for (const user of users) {
await db.insert(users).values(user); // N queries
}
✅ Good:
await db.insert(users).values(users); // Single query
Type Safety
Infer types from schema
type User = typeof users.$inferSelect;
type NewUser = typeof users.$inferInsert;
const user: User = {
id: 1,
email: 'user@example.com',
name: 'John',
createdAt: new Date(),
};
const newUser: NewUser = {
email: 'user@example.com',
name: 'John',
};
Type-safe WHERE conditions
function getUsersByStatus(status: User['status']) {
return db.select()
.from(users)
.where(eq(users.status, status));
}
Type-safe updates
function updateUser(id: number, data: Partial<NewUser>) {
return db.update(users)
.set(data)
.where(eq(users.id, id))
.returning();
}
Common Patterns
Soft deletes
Schema:
export const posts = pgTable('posts', {
id: serial('id').primaryKey(),
title: text('title').notNull(),
deletedAt: timestamp('deleted_at'),
});
Queries:
const activePosts = await db.select()
.from(posts)
.where(isNull(posts.deletedAt));
const deletedPosts = await db.select()
.from(posts)
.where(isNotNull(posts.deletedAt));
Timestamps
Auto-update:
async function updatePost(id: number, data: Partial<NewPost>) {
return db.update(posts)
.set({
...data,
updatedAt: new Date(),
})
.where(eq(posts.id, id))
.returning();
}
Search
Simple search:
const searchUsers = await db.select()
.from(users)
.where(
or(
ilike(users.name, `%${query}%`),
ilike(users.email, `%${query}%`)
)
);
Full-text search:
const searchPosts = await db.select()
.from(posts)
.where(
sql`to_tsvector('english', ${posts.title} || ' ' || ${posts.content}) @@ plainto_tsquery('english', ${query})`
);
Unique constraints
Handle duplicates:
try {
await db.insert(users).values({ email: 'user@example.com' });
} catch (err) {
if (err.code === '23505') { // Unique violation
console.error('Email already exists');
}
}
Or use upsert:
await db.insert(users)
.values({ email: 'user@example.com', name: 'John' })
.onConflictDoUpdate({
target: users.email,
set: { name: 'John Updated' },
});
Related Resources
guides/schema-only.md- Schema design patternsreferences/adapters.md- Transaction availability by adapterguides/troubleshooting.md- Query error solutionstemplates/schema-example.ts- Complete schema with relations