buster/api/documentation/database_migrations.mdc

358 lines
9.3 KiB
Plaintext

---
description: Helpful when making migrations with diesel.rs
globs:
alwaysApply: false
---
# Database Migrations Guide
This document provides a comprehensive guide on how to create and manage database migrations in our project.
## Overview
Database migrations are a way to evolve your database schema over time. Each migration represents a specific change to the database schema, such as creating a table, adding a column, or modifying an enum type. Migrations are version-controlled and can be applied or reverted as needed.
In our project, we use [Diesel](mdc:https:/diesel.rs) for handling database migrations. Diesel is an ORM and query builder for Rust that helps us manage our database schema changes in a safe and consistent way.
## Migration Workflow
### 1. Creating a New Migration
To create a new migration, use the Diesel CLI:
```bash
diesel migration generate name_of_migration
```
This command creates a new directory in the `migrations` folder with a timestamp prefix (e.g., `2025-03-06-232923_name_of_migration`). Inside this directory, two files are created:
- `up.sql`: Contains SQL statements to apply the migration
- `down.sql`: Contains SQL statements to revert the migration
### 2. Writing Migration SQL
#### Up Migration
The `up.sql` file should contain all the SQL statements needed to apply your changes to the database. For example:
```sql
-- Create a new table
CREATE TABLE users (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name VARCHAR NOT NULL,
email VARCHAR NOT NULL UNIQUE,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
);
-- Add a column to an existing table
ALTER TABLE organizations
ADD COLUMN description TEXT;
-- Create an enum type
CREATE TYPE user_role_enum AS ENUM ('admin', 'member', 'guest');
```
#### Down Migration
The `down.sql` file should contain SQL statements that revert the changes made in `up.sql`. It should be written in the reverse order of the operations in `up.sql`:
```sql
-- Remove the enum type
DROP TYPE user_role_enum;
-- Remove the column
ALTER TABLE organizations
DROP COLUMN description;
-- Drop the table
DROP TABLE users;
```
### 3. Running Migrations
To apply all pending migrations:
```bash
diesel migration run
```
This command:
1. Executes the SQL in the `up.sql` files of all pending migrations
2. Updates the `__diesel_schema_migrations` table to track which migrations have been applied
3. Regenerates the `schema.rs` file to reflect the current database schema
### 4. Reverting Migrations
To revert the most recent migration:
```bash
diesel migration revert
```
This executes the SQL in the `down.sql` file of the most recently applied migration.
### 5. Checking Migration Status
To see which migrations have been applied and which are pending:
```bash
diesel migration list
```
## Working with Enums
We prefer using enums when possible for fields with a fixed set of values. Here's how to work with enums in our project:
### 1. Creating an Enum in SQL Migration
```sql
-- In up.sql
CREATE TYPE asset_type_enum AS ENUM ('dashboard', 'dataset', 'metric');
-- In down.sql
DROP TYPE asset_type_enum;
```
### 2. Adding Values to an Existing Enum
```sql
-- In up.sql
ALTER TYPE asset_type_enum ADD VALUE IF NOT EXISTS 'chat';
-- In down.sql
DELETE FROM pg_enum
WHERE enumlabel = 'chat'
AND enumtypid = (SELECT oid FROM pg_type WHERE typname = 'asset_type_enum');
```
### 3. Implementing the Enum in Rust
After running the migration, you need to update the `enums.rs` file to reflect the changes:
```rust
#[derive(
Serialize,
Deserialize,
Debug,
Clone,
Copy,
PartialEq,
Eq,
diesel::AsExpression,
diesel::FromSqlRow,
)]
#[diesel(sql_type = sql_types::AssetTypeEnum)]
#[serde(rename_all = "camelCase")]
pub enum AssetType {
Dashboard,
Dataset,
Metric,
Chat,
}
impl ToSql<sql_types::AssetTypeEnum, Pg> for AssetType {
fn to_sql<'b>(&'b self, out: &mut Output<'b, '_, Pg>) -> serialize::Result {
match *self {
AssetType::Dashboard => out.write_all(b"dashboard")?,
AssetType::Dataset => out.write_all(b"dataset")?,
AssetType::Metric => out.write_all(b"metric")?,
AssetType::Chat => out.write_all(b"chat")?,
}
Ok(IsNull::No)
}
}
impl FromSql<sql_types::AssetTypeEnum, Pg> for AssetType {
fn from_sql(bytes: PgValue<'_>) -> deserialize::Result<Self> {
match bytes.as_bytes() {
b"dashboard" => Ok(AssetType::Dashboard),
b"dataset" => Ok(AssetType::Dataset),
b"metric" => Ok(AssetType::Metric),
b"chat" => Ok(AssetType::Chat),
_ => Err("Unrecognized enum variant".into()),
}
}
}
```
## Working with JSON Types
When working with JSON data in the database, we map it to Rust structs. Here's how:
### 1. Adding a JSON Column in Migration
```sql
-- In up.sql
ALTER TABLE metric_files
ADD COLUMN version_history JSONB NOT NULL DEFAULT '{}'::jsonb;
-- In down.sql
ALTER TABLE metric_files
DROP COLUMN version_history;
```
### 2. Creating a Type for the JSON Data
Create a new file in the `libs/database/src/types` directory or update an existing one:
```rust
// In libs/database/src/types/version_history.rs
use std::io::Write;
use diesel::{
deserialize::FromSql,
pg::Pg,
serialize::{IsNull, Output, ToSql},
sql_types::Jsonb,
AsExpression, FromSqlRow,
};
use serde::{Deserialize, Serialize};
#[derive(Debug, Serialize, Deserialize, FromSqlRow, AsExpression, Clone)]
#[diesel(sql_type = Jsonb)]
pub struct VersionHistory {
pub version: String,
pub updated_at: String,
pub content: serde_json::Value,
}
impl FromSql<Jsonb, Pg> for VersionHistory {
fn from_sql(bytes: diesel::pg::PgValue) -> diesel::deserialize::Result<Self> {
let value = serde_json::from_value(Jsonb::from_sql(bytes)?)?;
Ok(value)
}
}
impl ToSql<Jsonb, Pg> for VersionHistory {
fn to_sql<'b>(&'b self, out: &mut Output<'b, '_, Pg>) -> diesel::serialize::Result {
let json = serde_json::to_value(self)?;
ToSql::<Jsonb, Pg>::to_sql(&json, out)
}
}
```
### 3. Updating the `mod.rs` File
Make sure to export your new type in the `libs/database/src/types/mod.rs` file:
```rust
pub mod version_history;
pub use version_history::*;
```
### 4. Using the Type in Models
Update the corresponding model in `models.rs` to use your new type:
```rust
#[derive(Queryable, Insertable, Identifiable, Debug, Clone, Serialize)]
#[diesel(table_name = metric_files)]
pub struct MetricFile {
pub id: Uuid,
pub name: String,
pub content: String,
pub organization_id: Uuid,
pub created_by: Uuid,
pub created_at: DateTime<Utc>,
pub updated_at: DateTime<Utc>,
pub deleted_at: Option<DateTime<Utc>>,
pub version_history: VersionHistory,
}
```
## Best Practices
1. **Keep migrations small and focused**: Each migration should do one logical change to the schema.
2. **Test migrations before applying to production**: Always test migrations in a development or staging environment first.
3. **Always provide a down migration**: Make sure your `down.sql` properly reverts all changes made in `up.sql`.
4. **Use transactions**: Wrap complex migrations in transactions to ensure atomicity.
5. **Be careful with data migrations**: If you need to migrate data (not just schema), consider using separate migrations or Rust code.
6. **Document your migrations**: Add comments to your SQL files explaining what the migration does and why.
7. **Version control your migrations**: Always commit your migrations to version control.
## Common Migration Patterns
### Adding a New Table
```sql
-- up.sql
CREATE TABLE new_table (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name VARCHAR NOT NULL,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
);
-- down.sql
DROP TABLE new_table;
```
### Adding a Column
```sql
-- up.sql
ALTER TABLE existing_table
ADD COLUMN new_column VARCHAR;
-- down.sql
ALTER TABLE existing_table
DROP COLUMN new_column;
```
### Creating a Join Table
```sql
-- up.sql
CREATE TABLE table_a_to_table_b (
table_a_id UUID NOT NULL REFERENCES table_a(id),
table_b_id UUID NOT NULL REFERENCES table_b(id),
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
PRIMARY KEY (table_a_id, table_b_id)
);
-- down.sql
DROP TABLE table_a_to_table_b;
```
### Working with Constraints
```sql
-- up.sql
ALTER TABLE users
ADD CONSTRAINT unique_email UNIQUE (email);
-- down.sql
ALTER TABLE users
DROP CONSTRAINT unique_email;
```
## Troubleshooting
### Migration Failed to Apply
If a migration fails to apply, Diesel will stop and not apply any further migrations. You'll need to fix the issue and try again.
### Schema Drift
If your `schema.rs` doesn't match the actual database schema, you can regenerate it:
```bash
diesel print-schema > libs/database/src/schema.rs
```
### Fixing a Bad Migration
If you've applied a migration that has errors:
1. Fix the issues in your `up.sql` file
2. Run `diesel migration revert` to undo the migration
3. Run `diesel migration run` to apply the fixed migration
## Conclusion
Following these guidelines will help maintain a clean and consistent database schema evolution process. Remember that migrations are part of your codebase and should be treated with the same care as any other code.