Initial commit
This commit is contained in:
174
templates/d1-setup-migration.sh
Executable file
174
templates/d1-setup-migration.sh
Executable file
@@ -0,0 +1,174 @@
|
||||
#!/bin/bash
|
||||
#
|
||||
# Cloudflare D1 Setup and Migration Workflow
|
||||
#
|
||||
# This script demonstrates the complete D1 workflow:
|
||||
# 1. Create a D1 database
|
||||
# 2. Configure bindings
|
||||
# 3. Create and apply migrations
|
||||
# 4. Query the database
|
||||
#
|
||||
# Usage:
|
||||
# chmod +x d1-setup-migration.sh
|
||||
# ./d1-setup-migration.sh my-app-database
|
||||
#
|
||||
|
||||
set -e # Exit on error
|
||||
|
||||
DATABASE_NAME="${1:-my-database}"
|
||||
|
||||
echo "========================================="
|
||||
echo "Cloudflare D1 Setup and Migration"
|
||||
echo "========================================="
|
||||
echo ""
|
||||
|
||||
# Step 1: Create D1 Database
|
||||
echo "📦 Step 1: Creating D1 database '$DATABASE_NAME'..."
|
||||
echo ""
|
||||
|
||||
npx wrangler d1 create "$DATABASE_NAME"
|
||||
|
||||
echo ""
|
||||
echo "✅ Database created!"
|
||||
echo ""
|
||||
echo "📝 IMPORTANT: Copy the output above and add to your wrangler.jsonc:"
|
||||
echo ""
|
||||
echo ' {
|
||||
"d1_databases": [
|
||||
{
|
||||
"binding": "DB",
|
||||
"database_name": "'"$DATABASE_NAME"'",
|
||||
"database_id": "<UUID_FROM_OUTPUT_ABOVE>",
|
||||
"preview_database_id": "local-dev-db"
|
||||
}
|
||||
]
|
||||
}'
|
||||
echo ""
|
||||
read -p "Press ENTER when you've added the binding to wrangler.jsonc..."
|
||||
|
||||
# Step 2: Create Migrations Directory
|
||||
echo ""
|
||||
echo "📁 Step 2: Setting up migrations directory..."
|
||||
mkdir -p migrations
|
||||
|
||||
# Step 3: Create Initial Migration
|
||||
echo ""
|
||||
echo "🔨 Step 3: Creating initial migration..."
|
||||
echo ""
|
||||
|
||||
npx wrangler d1 migrations create "$DATABASE_NAME" create_initial_schema
|
||||
|
||||
# Find the created migration file (most recent .sql file in migrations/)
|
||||
MIGRATION_FILE=$(ls -t migrations/*.sql | head -n1)
|
||||
|
||||
echo ""
|
||||
echo "✅ Migration file created: $MIGRATION_FILE"
|
||||
echo ""
|
||||
echo "📝 Add your schema to this file. Example:"
|
||||
echo ""
|
||||
echo " DROP TABLE IF EXISTS users;
|
||||
CREATE TABLE IF NOT EXISTS users (
|
||||
user_id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
email TEXT NOT NULL UNIQUE,
|
||||
username TEXT NOT NULL,
|
||||
created_at INTEGER NOT NULL,
|
||||
updated_at INTEGER
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_users_email ON users(email);
|
||||
|
||||
PRAGMA optimize;"
|
||||
echo ""
|
||||
read -p "Press ENTER when you've edited the migration file..."
|
||||
|
||||
# Step 4: Apply Migration Locally
|
||||
echo ""
|
||||
echo "🔧 Step 4: Applying migration to LOCAL database..."
|
||||
echo ""
|
||||
|
||||
npx wrangler d1 migrations apply "$DATABASE_NAME" --local
|
||||
|
||||
echo ""
|
||||
echo "✅ Local migration applied!"
|
||||
|
||||
# Step 5: Verify Local Database
|
||||
echo ""
|
||||
echo "🔍 Step 5: Verifying local database..."
|
||||
echo ""
|
||||
|
||||
npx wrangler d1 execute "$DATABASE_NAME" --local --command "SELECT name FROM sqlite_master WHERE type='table'"
|
||||
|
||||
# Step 6: Seed Local Database (Optional)
|
||||
echo ""
|
||||
echo "🌱 Step 6: Would you like to seed the local database with test data?"
|
||||
read -p "Seed database? (y/n): " -n 1 -r
|
||||
echo ""
|
||||
|
||||
if [[ $REPLY =~ ^[Yy]$ ]]; then
|
||||
echo "Creating seed data..."
|
||||
|
||||
cat > seed.sql << 'EOF'
|
||||
-- Seed data for testing
|
||||
INSERT INTO users (email, username, created_at) VALUES
|
||||
('alice@example.com', 'alice', unixepoch()),
|
||||
('bob@example.com', 'bob', unixepoch()),
|
||||
('charlie@example.com', 'charlie', unixepoch());
|
||||
EOF
|
||||
|
||||
npx wrangler d1 execute "$DATABASE_NAME" --local --file=seed.sql
|
||||
|
||||
echo ""
|
||||
echo "✅ Seed data inserted!"
|
||||
echo ""
|
||||
echo "🔍 Verifying data..."
|
||||
npx wrangler d1 execute "$DATABASE_NAME" --local --command "SELECT * FROM users"
|
||||
fi
|
||||
|
||||
# Step 7: Apply to Production (Optional)
|
||||
echo ""
|
||||
echo "🚀 Step 7: Ready to apply migration to PRODUCTION?"
|
||||
echo ""
|
||||
echo "⚠️ WARNING: This will modify your production database!"
|
||||
read -p "Apply to production? (y/n): " -n 1 -r
|
||||
echo ""
|
||||
|
||||
if [[ $REPLY =~ ^[Yy]$ ]]; then
|
||||
echo "Applying migration to production..."
|
||||
npx wrangler d1 migrations apply "$DATABASE_NAME" --remote
|
||||
|
||||
echo ""
|
||||
echo "✅ Production migration applied!"
|
||||
else
|
||||
echo "Skipping production migration."
|
||||
echo ""
|
||||
echo "To apply later, run:"
|
||||
echo " npx wrangler d1 migrations apply $DATABASE_NAME --remote"
|
||||
fi
|
||||
|
||||
# Summary
|
||||
echo ""
|
||||
echo "========================================="
|
||||
echo "✅ D1 Setup Complete!"
|
||||
echo "========================================="
|
||||
echo ""
|
||||
echo "Database: $DATABASE_NAME"
|
||||
echo "Local database: ✅"
|
||||
echo "Migrations: ✅"
|
||||
echo ""
|
||||
echo "📚 Next steps:"
|
||||
echo ""
|
||||
echo "1. Start dev server:"
|
||||
echo " npm run dev"
|
||||
echo ""
|
||||
echo "2. Query from your Worker:"
|
||||
echo ' const user = await env.DB.prepare("SELECT * FROM users WHERE email = ?")
|
||||
.bind("alice@example.com")
|
||||
.first();'
|
||||
echo ""
|
||||
echo "3. Create more migrations as needed:"
|
||||
echo " npx wrangler d1 migrations create $DATABASE_NAME <migration_name>"
|
||||
echo ""
|
||||
echo "4. View all tables:"
|
||||
echo " npx wrangler d1 execute $DATABASE_NAME --local --command \"SELECT name FROM sqlite_master WHERE type='table'\""
|
||||
echo ""
|
||||
echo "========================================="
|
||||
591
templates/d1-worker-queries.ts
Normal file
591
templates/d1-worker-queries.ts
Normal file
@@ -0,0 +1,591 @@
|
||||
/**
|
||||
* Cloudflare D1 Worker Query Examples
|
||||
*
|
||||
* This file demonstrates type-safe D1 queries in a Cloudflare Worker with Hono.
|
||||
*
|
||||
* Topics covered:
|
||||
* - Type definitions for D1 bindings
|
||||
* - CRUD operations (Create, Read, Update, Delete)
|
||||
* - Batch queries for performance
|
||||
* - Error handling and validation
|
||||
* - Pagination patterns
|
||||
* - JOIN queries
|
||||
* - Transaction-like behavior
|
||||
*
|
||||
* Usage:
|
||||
* 1. Copy relevant patterns to your Worker
|
||||
* 2. Update table/column names to match your schema
|
||||
* 3. Add proper input validation
|
||||
*/
|
||||
|
||||
import { Hono } from 'hono';
|
||||
|
||||
// ============================================
|
||||
// Type Definitions
|
||||
// ============================================
|
||||
|
||||
interface Env {
|
||||
DB: D1Database;
|
||||
// ... other bindings
|
||||
}
|
||||
|
||||
type Bindings = {
|
||||
DB: D1Database;
|
||||
};
|
||||
|
||||
interface User {
|
||||
user_id: number;
|
||||
email: string;
|
||||
username: string;
|
||||
full_name: string | null;
|
||||
created_at: number;
|
||||
updated_at: number | null;
|
||||
}
|
||||
|
||||
interface Post {
|
||||
post_id: number;
|
||||
user_id: number;
|
||||
title: string;
|
||||
content: string;
|
||||
slug: string;
|
||||
published: number;
|
||||
created_at: number;
|
||||
published_at: number | null;
|
||||
}
|
||||
|
||||
interface PostWithAuthor extends Post {
|
||||
author_name: string;
|
||||
author_email: string;
|
||||
}
|
||||
|
||||
// ============================================
|
||||
// App Setup
|
||||
// ============================================
|
||||
|
||||
const app = new Hono<{ Bindings: Bindings }>();
|
||||
|
||||
// ============================================
|
||||
// CREATE Operations
|
||||
// ============================================
|
||||
|
||||
// Create a new user
|
||||
app.post('/api/users', async (c) => {
|
||||
try {
|
||||
const { email, username, full_name } = await c.req.json();
|
||||
|
||||
// Validate input
|
||||
if (!email || !username) {
|
||||
return c.json({ error: 'Email and username are required' }, 400);
|
||||
}
|
||||
|
||||
// Check if email already exists
|
||||
const existing = await c.env.DB.prepare(
|
||||
'SELECT user_id FROM users WHERE email = ? LIMIT 1'
|
||||
)
|
||||
.bind(email)
|
||||
.first();
|
||||
|
||||
if (existing) {
|
||||
return c.json({ error: 'Email already registered' }, 409);
|
||||
}
|
||||
|
||||
// Insert new user
|
||||
const result = await c.env.DB.prepare(
|
||||
'INSERT INTO users (email, username, full_name, created_at) VALUES (?, ?, ?, ?)'
|
||||
)
|
||||
.bind(email, username, full_name || null, Date.now())
|
||||
.run();
|
||||
|
||||
const userId = result.meta.last_row_id;
|
||||
|
||||
// Fetch the created user
|
||||
const user = await c.env.DB.prepare('SELECT * FROM users WHERE user_id = ?')
|
||||
.bind(userId)
|
||||
.first<User>();
|
||||
|
||||
return c.json({ user }, 201);
|
||||
} catch (error: any) {
|
||||
console.error('Error creating user:', error.message);
|
||||
return c.json({ error: 'Failed to create user' }, 500);
|
||||
}
|
||||
});
|
||||
|
||||
// Bulk insert with batch()
|
||||
app.post('/api/users/bulk', async (c) => {
|
||||
try {
|
||||
const { users } = await c.req.json();
|
||||
|
||||
if (!Array.isArray(users) || users.length === 0) {
|
||||
return c.json({ error: 'Invalid users array' }, 400);
|
||||
}
|
||||
|
||||
// Create batch of insert statements
|
||||
const inserts = users.map(user =>
|
||||
c.env.DB.prepare(
|
||||
'INSERT INTO users (email, username, full_name, created_at) VALUES (?, ?, ?, ?)'
|
||||
).bind(user.email, user.username, user.full_name || null, Date.now())
|
||||
);
|
||||
|
||||
// Execute all inserts in one batch
|
||||
const results = await c.env.DB.batch(inserts);
|
||||
|
||||
const insertedCount = results.filter(r => r.success).length;
|
||||
|
||||
return c.json({
|
||||
message: `Inserted ${insertedCount} users`,
|
||||
count: insertedCount
|
||||
}, 201);
|
||||
} catch (error: any) {
|
||||
console.error('Error bulk inserting users:', error.message);
|
||||
return c.json({ error: 'Failed to insert users' }, 500);
|
||||
}
|
||||
});
|
||||
|
||||
// ============================================
|
||||
// READ Operations
|
||||
// ============================================
|
||||
|
||||
// Get single user by ID
|
||||
app.get('/api/users/:id', async (c) => {
|
||||
try {
|
||||
const userId = parseInt(c.req.param('id'));
|
||||
|
||||
const user = await c.env.DB.prepare('SELECT * FROM users WHERE user_id = ?')
|
||||
.bind(userId)
|
||||
.first<User>();
|
||||
|
||||
if (!user) {
|
||||
return c.json({ error: 'User not found' }, 404);
|
||||
}
|
||||
|
||||
return c.json({ user });
|
||||
} catch (error: any) {
|
||||
console.error('Error fetching user:', error.message);
|
||||
return c.json({ error: 'Failed to fetch user' }, 500);
|
||||
}
|
||||
});
|
||||
|
||||
// Get user by email
|
||||
app.get('/api/users/email/:email', async (c) => {
|
||||
try {
|
||||
const email = c.req.param('email');
|
||||
|
||||
const user = await c.env.DB.prepare('SELECT * FROM users WHERE email = ?')
|
||||
.bind(email)
|
||||
.first<User>();
|
||||
|
||||
if (!user) {
|
||||
return c.json({ error: 'User not found' }, 404);
|
||||
}
|
||||
|
||||
return c.json({ user });
|
||||
} catch (error: any) {
|
||||
console.error('Error fetching user:', error.message);
|
||||
return c.json({ error: 'Failed to fetch user' }, 500);
|
||||
}
|
||||
});
|
||||
|
||||
// List users with pagination
|
||||
app.get('/api/users', async (c) => {
|
||||
try {
|
||||
const page = parseInt(c.req.query('page') || '1');
|
||||
const limit = Math.min(parseInt(c.req.query('limit') || '20'), 100); // Max 100
|
||||
const offset = (page - 1) * limit;
|
||||
|
||||
// Use batch to get count and users in one round trip
|
||||
const [countResult, usersResult] = await c.env.DB.batch([
|
||||
c.env.DB.prepare('SELECT COUNT(*) as total FROM users WHERE deleted_at IS NULL'),
|
||||
c.env.DB.prepare(
|
||||
'SELECT * FROM users WHERE deleted_at IS NULL ORDER BY created_at DESC LIMIT ? OFFSET ?'
|
||||
).bind(limit, offset)
|
||||
]);
|
||||
|
||||
const total = (countResult.results[0] as any).total as number;
|
||||
const users = usersResult.results as User[];
|
||||
|
||||
return c.json({
|
||||
users,
|
||||
pagination: {
|
||||
page,
|
||||
limit,
|
||||
total,
|
||||
pages: Math.ceil(total / limit)
|
||||
}
|
||||
});
|
||||
} catch (error: any) {
|
||||
console.error('Error listing users:', error.message);
|
||||
return c.json({ error: 'Failed to list users' }, 500);
|
||||
}
|
||||
});
|
||||
|
||||
// ============================================
|
||||
// UPDATE Operations
|
||||
// ============================================
|
||||
|
||||
// Update user
|
||||
app.put('/api/users/:id', async (c) => {
|
||||
try {
|
||||
const userId = parseInt(c.req.param('id'));
|
||||
const { username, full_name, bio } = await c.req.json();
|
||||
|
||||
// Build dynamic update query
|
||||
const updates: string[] = [];
|
||||
const values: any[] = [];
|
||||
|
||||
if (username !== undefined) {
|
||||
updates.push('username = ?');
|
||||
values.push(username);
|
||||
}
|
||||
if (full_name !== undefined) {
|
||||
updates.push('full_name = ?');
|
||||
values.push(full_name);
|
||||
}
|
||||
if (bio !== undefined) {
|
||||
updates.push('bio = ?');
|
||||
values.push(bio);
|
||||
}
|
||||
|
||||
if (updates.length === 0) {
|
||||
return c.json({ error: 'No fields to update' }, 400);
|
||||
}
|
||||
|
||||
// Add updated_at
|
||||
updates.push('updated_at = ?');
|
||||
values.push(Date.now());
|
||||
|
||||
// Add user_id for WHERE clause
|
||||
values.push(userId);
|
||||
|
||||
const sql = `UPDATE users SET ${updates.join(', ')} WHERE user_id = ?`;
|
||||
|
||||
const result = await c.env.DB.prepare(sql).bind(...values).run();
|
||||
|
||||
if (result.meta.rows_written === 0) {
|
||||
return c.json({ error: 'User not found' }, 404);
|
||||
}
|
||||
|
||||
// Fetch updated user
|
||||
const user = await c.env.DB.prepare('SELECT * FROM users WHERE user_id = ?')
|
||||
.bind(userId)
|
||||
.first<User>();
|
||||
|
||||
return c.json({ user });
|
||||
} catch (error: any) {
|
||||
console.error('Error updating user:', error.message);
|
||||
return c.json({ error: 'Failed to update user' }, 500);
|
||||
}
|
||||
});
|
||||
|
||||
// Increment post view count (simple update)
|
||||
app.post('/api/posts/:id/view', async (c) => {
|
||||
try {
|
||||
const postId = parseInt(c.req.param('id'));
|
||||
|
||||
const result = await c.env.DB.prepare(
|
||||
'UPDATE posts SET view_count = view_count + 1 WHERE post_id = ?'
|
||||
)
|
||||
.bind(postId)
|
||||
.run();
|
||||
|
||||
if (result.meta.rows_written === 0) {
|
||||
return c.json({ error: 'Post not found' }, 404);
|
||||
}
|
||||
|
||||
return c.json({ success: true });
|
||||
} catch (error: any) {
|
||||
console.error('Error incrementing view count:', error.message);
|
||||
return c.json({ error: 'Failed to update view count' }, 500);
|
||||
}
|
||||
});
|
||||
|
||||
// ============================================
|
||||
// DELETE Operations
|
||||
// ============================================
|
||||
|
||||
// Soft delete user
|
||||
app.delete('/api/users/:id', async (c) => {
|
||||
try {
|
||||
const userId = parseInt(c.req.param('id'));
|
||||
|
||||
const result = await c.env.DB.prepare(
|
||||
'UPDATE users SET deleted_at = ? WHERE user_id = ? AND deleted_at IS NULL'
|
||||
)
|
||||
.bind(Date.now(), userId)
|
||||
.run();
|
||||
|
||||
if (result.meta.rows_written === 0) {
|
||||
return c.json({ error: 'User not found or already deleted' }, 404);
|
||||
}
|
||||
|
||||
return c.json({ success: true });
|
||||
} catch (error: any) {
|
||||
console.error('Error deleting user:', error.message);
|
||||
return c.json({ error: 'Failed to delete user' }, 500);
|
||||
}
|
||||
});
|
||||
|
||||
// Hard delete post
|
||||
app.delete('/api/posts/:id/permanent', async (c) => {
|
||||
try {
|
||||
const postId = parseInt(c.req.param('id'));
|
||||
|
||||
const result = await c.env.DB.prepare('DELETE FROM posts WHERE post_id = ?')
|
||||
.bind(postId)
|
||||
.run();
|
||||
|
||||
if (result.meta.rows_written === 0) {
|
||||
return c.json({ error: 'Post not found' }, 404);
|
||||
}
|
||||
|
||||
return c.json({ success: true });
|
||||
} catch (error: any) {
|
||||
console.error('Error deleting post:', error.message);
|
||||
return c.json({ error: 'Failed to delete post' }, 500);
|
||||
}
|
||||
});
|
||||
|
||||
// ============================================
|
||||
// JOIN Queries
|
||||
// ============================================
|
||||
|
||||
// Get posts with author information
|
||||
app.get('/api/posts', async (c) => {
|
||||
try {
|
||||
const limit = Math.min(parseInt(c.req.query('limit') || '20'), 100);
|
||||
|
||||
const { results } = await c.env.DB.prepare(`
|
||||
SELECT
|
||||
posts.*,
|
||||
users.username as author_name,
|
||||
users.email as author_email
|
||||
FROM posts
|
||||
INNER JOIN users ON posts.user_id = users.user_id
|
||||
WHERE posts.published = 1
|
||||
AND users.deleted_at IS NULL
|
||||
ORDER BY posts.published_at DESC
|
||||
LIMIT ?
|
||||
`)
|
||||
.bind(limit)
|
||||
.all<PostWithAuthor>();
|
||||
|
||||
return c.json({ posts: results });
|
||||
} catch (error: any) {
|
||||
console.error('Error fetching posts:', error.message);
|
||||
return c.json({ error: 'Failed to fetch posts' }, 500);
|
||||
}
|
||||
});
|
||||
|
||||
// Get post with author and tags
|
||||
app.get('/api/posts/:slug', async (c) => {
|
||||
try {
|
||||
const slug = c.req.param('slug');
|
||||
|
||||
// Use batch to get post+author and tags in one round trip
|
||||
const [postResult, tagsResult] = await c.env.DB.batch([
|
||||
// Get post with author
|
||||
c.env.DB.prepare(`
|
||||
SELECT
|
||||
posts.*,
|
||||
users.username as author_name,
|
||||
users.email as author_email
|
||||
FROM posts
|
||||
INNER JOIN users ON posts.user_id = users.user_id
|
||||
WHERE posts.slug = ?
|
||||
LIMIT 1
|
||||
`).bind(slug),
|
||||
|
||||
// Get post's tags
|
||||
c.env.DB.prepare(`
|
||||
SELECT tags.*
|
||||
FROM tags
|
||||
INNER JOIN post_tags ON tags.tag_id = post_tags.tag_id
|
||||
INNER JOIN posts ON post_tags.post_id = posts.post_id
|
||||
WHERE posts.slug = ?
|
||||
`).bind(slug)
|
||||
]);
|
||||
|
||||
const post = postResult.results[0] as PostWithAuthor | undefined;
|
||||
|
||||
if (!post) {
|
||||
return c.json({ error: 'Post not found' }, 404);
|
||||
}
|
||||
|
||||
const tags = tagsResult.results;
|
||||
|
||||
return c.json({ post, tags });
|
||||
} catch (error: any) {
|
||||
console.error('Error fetching post:', error.message);
|
||||
return c.json({ error: 'Failed to fetch post' }, 500);
|
||||
}
|
||||
});
|
||||
|
||||
// ============================================
|
||||
// Transaction-like Behavior with Batch
|
||||
// ============================================
|
||||
|
||||
// Publish post (update post + record event)
|
||||
app.post('/api/posts/:id/publish', async (c) => {
|
||||
try {
|
||||
const postId = parseInt(c.req.param('id'));
|
||||
const now = Date.now();
|
||||
|
||||
// Execute multiple related updates in one batch
|
||||
const results = await c.env.DB.batch([
|
||||
// Update post status
|
||||
c.env.DB.prepare(
|
||||
'UPDATE posts SET published = 1, published_at = ?, updated_at = ? WHERE post_id = ?'
|
||||
).bind(now, now, postId),
|
||||
|
||||
// Record publish event (example analytics table)
|
||||
c.env.DB.prepare(
|
||||
'INSERT INTO post_events (post_id, event_type, created_at) VALUES (?, ?, ?)'
|
||||
).bind(postId, 'published', now)
|
||||
]);
|
||||
|
||||
// Check if post update succeeded
|
||||
if (results[0].meta.rows_written === 0) {
|
||||
return c.json({ error: 'Post not found' }, 404);
|
||||
}
|
||||
|
||||
return c.json({ success: true });
|
||||
} catch (error: any) {
|
||||
console.error('Error publishing post:', error.message);
|
||||
return c.json({ error: 'Failed to publish post' }, 500);
|
||||
}
|
||||
});
|
||||
|
||||
// ============================================
|
||||
// Advanced Patterns
|
||||
// ============================================
|
||||
|
||||
// Search posts by keyword (simple full-text search)
|
||||
app.get('/api/posts/search', async (c) => {
|
||||
try {
|
||||
const query = c.req.query('q') || '';
|
||||
const limit = Math.min(parseInt(c.req.query('limit') || '20'), 100);
|
||||
|
||||
if (query.length < 2) {
|
||||
return c.json({ error: 'Query must be at least 2 characters' }, 400);
|
||||
}
|
||||
|
||||
const searchTerm = `%${query}%`;
|
||||
|
||||
const { results } = await c.env.DB.prepare(`
|
||||
SELECT
|
||||
posts.*,
|
||||
users.username as author_name
|
||||
FROM posts
|
||||
INNER JOIN users ON posts.user_id = users.user_id
|
||||
WHERE posts.published = 1
|
||||
AND (posts.title LIKE ? OR posts.content LIKE ?)
|
||||
ORDER BY posts.published_at DESC
|
||||
LIMIT ?
|
||||
`)
|
||||
.bind(searchTerm, searchTerm, limit)
|
||||
.all<PostWithAuthor>();
|
||||
|
||||
return c.json({ posts: results, query });
|
||||
} catch (error: any) {
|
||||
console.error('Error searching posts:', error.message);
|
||||
return c.json({ error: 'Failed to search posts' }, 500);
|
||||
}
|
||||
});
|
||||
|
||||
// Get user stats (multiple aggregations in batch)
|
||||
app.get('/api/users/:id/stats', async (c) => {
|
||||
try {
|
||||
const userId = parseInt(c.req.param('id'));
|
||||
|
||||
const [userResult, statsResults] = await c.env.DB.batch([
|
||||
// Get user
|
||||
c.env.DB.prepare('SELECT * FROM users WHERE user_id = ?').bind(userId),
|
||||
|
||||
// Get all stats in one query with UNION
|
||||
c.env.DB.prepare(`
|
||||
SELECT 'posts' as metric, COUNT(*) as count FROM posts WHERE user_id = ?
|
||||
UNION ALL
|
||||
SELECT 'comments', COUNT(*) FROM comments WHERE user_id = ?
|
||||
UNION ALL
|
||||
SELECT 'published_posts', COUNT(*) FROM posts WHERE user_id = ? AND published = 1
|
||||
`).bind(userId, userId, userId)
|
||||
]);
|
||||
|
||||
const user = userResult.results[0] as User | undefined;
|
||||
|
||||
if (!user) {
|
||||
return c.json({ error: 'User not found' }, 404);
|
||||
}
|
||||
|
||||
// Parse stats results
|
||||
const stats: Record<string, number> = {};
|
||||
for (const row of statsResults.results as any[]) {
|
||||
stats[row.metric] = row.count;
|
||||
}
|
||||
|
||||
return c.json({ user, stats });
|
||||
} catch (error: any) {
|
||||
console.error('Error fetching user stats:', error.message);
|
||||
return c.json({ error: 'Failed to fetch user stats' }, 500);
|
||||
}
|
||||
});
|
||||
|
||||
// ============================================
|
||||
// Error Handling Example with Retry
|
||||
// ============================================
|
||||
|
||||
async function queryWithRetry<T>(
|
||||
queryFn: () => Promise<T>,
|
||||
maxRetries = 3
|
||||
): Promise<T> {
|
||||
for (let attempt = 0; attempt < maxRetries; attempt++) {
|
||||
try {
|
||||
return await queryFn();
|
||||
} catch (error: any) {
|
||||
const message = error.message;
|
||||
|
||||
// Check if error is retryable
|
||||
const isRetryable =
|
||||
message.includes('Network connection lost') ||
|
||||
message.includes('storage caused object to be reset') ||
|
||||
message.includes('reset because its code was updated');
|
||||
|
||||
if (!isRetryable || attempt === maxRetries - 1) {
|
||||
throw error;
|
||||
}
|
||||
|
||||
// Exponential backoff
|
||||
const delay = Math.min(1000 * Math.pow(2, attempt), 5000);
|
||||
await new Promise(resolve => setTimeout(resolve, delay));
|
||||
}
|
||||
}
|
||||
|
||||
throw new Error('Retry logic failed');
|
||||
}
|
||||
|
||||
// Example usage with retry
|
||||
app.get('/api/users/:id/with-retry', async (c) => {
|
||||
try {
|
||||
const userId = parseInt(c.req.param('id'));
|
||||
|
||||
const user = await queryWithRetry(() =>
|
||||
c.env.DB.prepare('SELECT * FROM users WHERE user_id = ?')
|
||||
.bind(userId)
|
||||
.first<User>()
|
||||
);
|
||||
|
||||
if (!user) {
|
||||
return c.json({ error: 'User not found' }, 404);
|
||||
}
|
||||
|
||||
return c.json({ user });
|
||||
} catch (error: any) {
|
||||
console.error('Error fetching user (with retry):', error.message);
|
||||
return c.json({ error: 'Failed to fetch user' }, 500);
|
||||
}
|
||||
});
|
||||
|
||||
// ============================================
|
||||
// Export App
|
||||
// ============================================
|
||||
|
||||
export default app;
|
||||
248
templates/schema-example.sql
Normal file
248
templates/schema-example.sql
Normal file
@@ -0,0 +1,248 @@
|
||||
-- Cloudflare D1 Schema Example
|
||||
-- Production-ready database schema with best practices
|
||||
--
|
||||
-- This file demonstrates:
|
||||
-- - Proper table creation with constraints
|
||||
-- - Primary and foreign keys
|
||||
-- - Indexes for performance
|
||||
-- - Sample data for testing
|
||||
--
|
||||
-- Apply with:
|
||||
-- npx wrangler d1 execute my-database --local --file=schema-example.sql
|
||||
|
||||
-- ============================================
|
||||
-- Users Table
|
||||
-- ============================================
|
||||
|
||||
DROP TABLE IF EXISTS users;
|
||||
CREATE TABLE IF NOT EXISTS users (
|
||||
user_id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
email TEXT NOT NULL UNIQUE,
|
||||
username TEXT NOT NULL,
|
||||
full_name TEXT,
|
||||
bio TEXT,
|
||||
avatar_url TEXT,
|
||||
created_at INTEGER NOT NULL DEFAULT (unixepoch()),
|
||||
updated_at INTEGER,
|
||||
deleted_at INTEGER -- Soft delete pattern
|
||||
);
|
||||
|
||||
-- Index for email lookups (login, registration checks)
|
||||
CREATE INDEX IF NOT EXISTS idx_users_email ON users(email);
|
||||
|
||||
-- Index for filtering out deleted users
|
||||
CREATE INDEX IF NOT EXISTS idx_users_active ON users(user_id) WHERE deleted_at IS NULL;
|
||||
|
||||
-- ============================================
|
||||
-- Posts Table
|
||||
-- ============================================
|
||||
|
||||
DROP TABLE IF EXISTS posts;
|
||||
CREATE TABLE IF NOT EXISTS posts (
|
||||
post_id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
user_id INTEGER NOT NULL,
|
||||
title TEXT NOT NULL,
|
||||
content TEXT NOT NULL,
|
||||
slug TEXT NOT NULL UNIQUE,
|
||||
published INTEGER NOT NULL DEFAULT 0, -- 0 = draft, 1 = published
|
||||
view_count INTEGER NOT NULL DEFAULT 0,
|
||||
created_at INTEGER NOT NULL DEFAULT (unixepoch()),
|
||||
updated_at INTEGER,
|
||||
published_at INTEGER,
|
||||
|
||||
-- Foreign key constraint
|
||||
FOREIGN KEY (user_id) REFERENCES users(user_id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
-- Index for user's posts
|
||||
CREATE INDEX IF NOT EXISTS idx_posts_user_id ON posts(user_id);
|
||||
|
||||
-- Index for published posts (most common query)
|
||||
CREATE INDEX IF NOT EXISTS idx_posts_published_created ON posts(published, created_at DESC)
|
||||
WHERE published = 1;
|
||||
|
||||
-- Index for slug lookups (e.g., /blog/my-post-slug)
|
||||
CREATE INDEX IF NOT EXISTS idx_posts_slug ON posts(slug);
|
||||
|
||||
-- ============================================
|
||||
-- Comments Table
|
||||
-- ============================================
|
||||
|
||||
DROP TABLE IF EXISTS comments;
|
||||
CREATE TABLE IF NOT EXISTS comments (
|
||||
comment_id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
post_id INTEGER NOT NULL,
|
||||
user_id INTEGER NOT NULL,
|
||||
parent_comment_id INTEGER, -- For threaded comments (NULL = top-level)
|
||||
content TEXT NOT NULL,
|
||||
created_at INTEGER NOT NULL DEFAULT (unixepoch()),
|
||||
updated_at INTEGER,
|
||||
deleted_at INTEGER,
|
||||
|
||||
-- Foreign keys
|
||||
FOREIGN KEY (post_id) REFERENCES posts(post_id) ON DELETE CASCADE,
|
||||
FOREIGN KEY (user_id) REFERENCES users(user_id) ON DELETE CASCADE,
|
||||
FOREIGN KEY (parent_comment_id) REFERENCES comments(comment_id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
-- Index for post's comments
|
||||
CREATE INDEX IF NOT EXISTS idx_comments_post_id ON comments(post_id);
|
||||
|
||||
-- Index for user's comments
|
||||
CREATE INDEX IF NOT EXISTS idx_comments_user_id ON comments(user_id);
|
||||
|
||||
-- Index for threaded replies
|
||||
CREATE INDEX IF NOT EXISTS idx_comments_parent ON comments(parent_comment_id)
|
||||
WHERE parent_comment_id IS NOT NULL;
|
||||
|
||||
-- ============================================
|
||||
-- Tags Table (Many-to-Many Example)
|
||||
-- ============================================
|
||||
|
||||
DROP TABLE IF EXISTS tags;
|
||||
CREATE TABLE IF NOT EXISTS tags (
|
||||
tag_id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
name TEXT NOT NULL UNIQUE,
|
||||
slug TEXT NOT NULL UNIQUE,
|
||||
created_at INTEGER NOT NULL DEFAULT (unixepoch())
|
||||
);
|
||||
|
||||
-- Index for tag lookups
|
||||
CREATE INDEX IF NOT EXISTS idx_tags_slug ON tags(slug);
|
||||
|
||||
-- ============================================
|
||||
-- Post Tags Junction Table
|
||||
-- ============================================
|
||||
|
||||
DROP TABLE IF EXISTS post_tags;
|
||||
CREATE TABLE IF NOT EXISTS post_tags (
|
||||
post_id INTEGER NOT NULL,
|
||||
tag_id INTEGER NOT NULL,
|
||||
created_at INTEGER NOT NULL DEFAULT (unixepoch()),
|
||||
|
||||
-- Composite primary key
|
||||
PRIMARY KEY (post_id, tag_id),
|
||||
|
||||
-- Foreign keys
|
||||
FOREIGN KEY (post_id) REFERENCES posts(post_id) ON DELETE CASCADE,
|
||||
FOREIGN KEY (tag_id) REFERENCES tags(tag_id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
-- Index for finding posts by tag
|
||||
CREATE INDEX IF NOT EXISTS idx_post_tags_tag_id ON post_tags(tag_id);
|
||||
|
||||
-- ============================================
|
||||
-- Sessions Table (Example: Auth Sessions)
|
||||
-- ============================================
|
||||
|
||||
DROP TABLE IF EXISTS sessions;
|
||||
CREATE TABLE IF NOT EXISTS sessions (
|
||||
session_id TEXT PRIMARY KEY, -- UUID or random token
|
||||
user_id INTEGER NOT NULL,
|
||||
ip_address TEXT,
|
||||
user_agent TEXT,
|
||||
created_at INTEGER NOT NULL DEFAULT (unixepoch()),
|
||||
expires_at INTEGER NOT NULL,
|
||||
last_activity_at INTEGER NOT NULL DEFAULT (unixepoch()),
|
||||
|
||||
FOREIGN KEY (user_id) REFERENCES users(user_id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
-- Index for session cleanup (delete expired sessions)
|
||||
CREATE INDEX IF NOT EXISTS idx_sessions_expires ON sessions(expires_at);
|
||||
|
||||
-- Index for user's sessions
|
||||
CREATE INDEX IF NOT EXISTS idx_sessions_user_id ON sessions(user_id);
|
||||
|
||||
-- ============================================
|
||||
-- Analytics Table (High-Write Pattern)
|
||||
-- ============================================
|
||||
|
||||
DROP TABLE IF EXISTS page_views;
|
||||
CREATE TABLE IF NOT EXISTS page_views (
|
||||
view_id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
post_id INTEGER,
|
||||
user_id INTEGER, -- NULL for anonymous views
|
||||
ip_address TEXT,
|
||||
referrer TEXT,
|
||||
user_agent TEXT,
|
||||
viewed_at INTEGER NOT NULL DEFAULT (unixepoch())
|
||||
);
|
||||
|
||||
-- Partial index: only index recent views (last 30 days)
|
||||
CREATE INDEX IF NOT EXISTS idx_page_views_recent ON page_views(post_id, viewed_at)
|
||||
WHERE viewed_at > unixepoch() - 2592000; -- 30 days in seconds
|
||||
|
||||
-- ============================================
|
||||
-- Optimize Database
|
||||
-- ============================================
|
||||
|
||||
-- Run PRAGMA optimize to collect statistics for query planner
|
||||
PRAGMA optimize;
|
||||
|
||||
-- ============================================
|
||||
-- Sample Seed Data (Optional - for testing)
|
||||
-- ============================================
|
||||
|
||||
-- Insert test users
|
||||
INSERT INTO users (email, username, full_name, bio) VALUES
|
||||
('alice@example.com', 'alice', 'Alice Johnson', 'Software engineer and blogger'),
|
||||
('bob@example.com', 'bob', 'Bob Smith', 'Tech enthusiast'),
|
||||
('charlie@example.com', 'charlie', 'Charlie Brown', 'Writer and photographer');
|
||||
|
||||
-- Insert test tags
|
||||
INSERT INTO tags (name, slug) VALUES
|
||||
('JavaScript', 'javascript'),
|
||||
('TypeScript', 'typescript'),
|
||||
('Cloudflare', 'cloudflare'),
|
||||
('Web Development', 'web-development'),
|
||||
('Tutorial', 'tutorial');
|
||||
|
||||
-- Insert test posts
|
||||
INSERT INTO posts (user_id, title, content, slug, published, published_at) VALUES
|
||||
(1, 'Getting Started with D1', 'Learn how to use Cloudflare D1 database...', 'getting-started-with-d1', 1, unixepoch()),
|
||||
(1, 'Building APIs with Hono', 'Hono is a lightweight web framework...', 'building-apis-with-hono', 1, unixepoch() - 86400),
|
||||
(2, 'My First Draft', 'This is a draft post...', 'my-first-draft', 0, NULL);
|
||||
|
||||
-- Link posts to tags
|
||||
INSERT INTO post_tags (post_id, tag_id) VALUES
|
||||
(1, 3), -- Getting Started with D1 -> Cloudflare
|
||||
(1, 5), -- Getting Started with D1 -> Tutorial
|
||||
(2, 1), -- Building APIs with Hono -> JavaScript
|
||||
(2, 3), -- Building APIs with Hono -> Cloudflare
|
||||
(2, 5); -- Building APIs with Hono -> Tutorial
|
||||
|
||||
-- Insert test comments
|
||||
INSERT INTO comments (post_id, user_id, content) VALUES
|
||||
(1, 2, 'Great tutorial! Really helpful.'),
|
||||
(1, 3, 'Thanks for sharing this!'),
|
||||
(2, 3, 'Looking forward to more content on Hono.');
|
||||
|
||||
-- Insert threaded reply
|
||||
INSERT INTO comments (post_id, user_id, parent_comment_id, content) VALUES
|
||||
(1, 1, 1, 'Glad you found it useful!');
|
||||
|
||||
-- ============================================
|
||||
-- Verification Queries
|
||||
-- ============================================
|
||||
|
||||
-- Count records in each table
|
||||
SELECT 'users' as table_name, COUNT(*) as count FROM users
|
||||
UNION ALL
|
||||
SELECT 'posts', COUNT(*) FROM posts
|
||||
UNION ALL
|
||||
SELECT 'comments', COUNT(*) FROM comments
|
||||
UNION ALL
|
||||
SELECT 'tags', COUNT(*) FROM tags
|
||||
UNION ALL
|
||||
SELECT 'post_tags', COUNT(*) FROM post_tags;
|
||||
|
||||
-- List all tables and indexes
|
||||
SELECT
|
||||
type,
|
||||
name,
|
||||
tbl_name as table_name
|
||||
FROM sqlite_master
|
||||
WHERE type IN ('table', 'index')
|
||||
AND name NOT LIKE 'sqlite_%'
|
||||
ORDER BY type, tbl_name, name;
|
||||
Reference in New Issue
Block a user