🌊 A dynamic query builder for MySQL, Postgres and SQLite
[](https://crates.io/crates/sea-query) [](https://docs.rs/sea-query) [](https://github.com/SeaQL/sea-query/actions/workflows/rust.yml)SeaQuery is a query builder to help you construct dynamic SQL queries in Rust. You can construct expressions, queries and schema as abstract syntax trees using an ergonomic API. We support MySQL, Postgres and SQLite behind a common interface that aligns their behaviour where appropriate.
We provide integration for SQLx, postgres and rusqlite. See examples for usage.
SeaQuery is the foundation of SeaORM, an async & dynamic ORM for Rust.
```toml
[dependencies] sea-query = "^0" ```
SeaQuery is very lightweight, all dependencies are optional.
Macro: derive
Async support: thread-safe
(use Arc
inplace of Rc
)
SQL dialect: backend-mysql
, backend-postgres
, backend-sqlite
Type support: with-chrono
, with-json
, with-rust_decimal
, with-bigdecimal
, with-uuid
,
postgres-array
Driver support: sqlx-mysql
, sqlx-postgres
, sqlx-sqlite
,
postgres
, postgres-*
, rusqlite
Postgres support: postgres
, postgres-chrono
, postgres-json
, postgres-rust_decimal
,
postgres-bigdecimal
, postgres-uuid
, postgres-array
, postgres-interval
Table of Content
Basics
Query Statement
Schema Statement
Why would you want to use a dynamic query builder?
One of the headaches when using raw SQL is parameter binding. With SeaQuery you can:
rust
assert_eq!(
Query::select()
.column(Glyph::Image)
.from(Glyph::Table)
.and_where(Expr::col(Glyph::Image).like("A"))
.and_where(Expr::col(Glyph::Id).is_in(vec![1, 2, 3]))
.build(PostgresQueryBuilder),
(
r#"SELECT "image" FROM "glyph" WHERE "image" LIKE $1 AND "id" IN ($2, $3, $4)"#
.to_owned(),
Values(vec![
Value::String(Some(Box::new("A".to_owned()))),
Value::Int(Some(1)),
Value::Int(Some(2)),
Value::Int(Some(3))
])
)
);
You can construct the query at runtime based on user inputs:
rust
Query::select()
.column(Char::Character)
.from(Char::Table)
.conditions(
// some runtime condition
true,
// if condition is true then add the following condition
|q| {
q.and_where(Expr::col(Char::Id).eq(1));
},
// otherwise leave it as is
|q| {},
);
Iden
is a trait for identifiers used in any query statement.
Commonly implemented by Enum where each Enum represents a table found in a database, and its variants include table name and column name.
[Iden::unquoted()
] must be implemented to provide a mapping between Enum variants and its
corresponding string value.
```rust use sea_query::*;
// For example Character table with column id, character, font_size... pub enum Character { Table, Id, FontId, FontSize, }
// Mapping between Enum variant and its corresponding string value impl Iden for Character { fn unquoted(&self, s: &mut dyn std::fmt::Write) { write!( s, "{}", match self { Self::Table => "character", Self::Id => "id", Self::FontId => "fontid", Self::FontSize => "fontsize", } ) .unwrap(); } } ```
If you're okay with running another procedural macro, you can activate
the derive
feature on the crate to save you some boilerplate.
For more usage information, look at
the derive examples.
```rust use sea_query::Iden;
// This will implement Iden exactly as shown above
enum Character { Table, } asserteq!(Character::Table.tostring(), "character");
// You can also derive a unit struct
struct Glyph; asserteq!(Glyph.tostring(), "glyph"); ```
Use [Expr
] to construct select, join, where and having expression in query.
rust
assert_eq!(
Query::select()
.column(Char::Character)
.from(Char::Table)
.and_where(
Expr::expr(Expr::col(Char::SizeW).add(1))
.mul(2)
.equals(Expr::expr(Expr::col(Char::SizeH).div(2)).sub(1))
)
.and_where(
Expr::col(Char::SizeW).in_subquery(
Query::select()
.expr(Expr::cust_with_values("ln(? ^ ?)", vec![2.4, 1.2]))
.take()
)
)
.and_where(
Expr::col(Char::Character)
.like("D")
.and(Expr::col(Char::Character).like("E"))
)
.to_string(PostgresQueryBuilder),
[
r#"SELECT "character" FROM "character""#,
r#"WHERE ("size_w" + 1) * 2 = ("size_h" / 2) - 1"#,
r#"AND "size_w" IN (SELECT ln(2.4 ^ 1.2))"#,
r#"AND (("character" LIKE 'D') AND ("character" LIKE 'E'))"#,
]
.join(" ")
);
If you have complex conditions to express, you can use the [Condition
] builder,
usable for [ConditionalStatement::cond_where
] and [SelectStatement::cond_having
].
rust
assert_eq!(
Query::select()
.column(Glyph::Id)
.from(Glyph::Table)
.cond_where(
Cond::any()
.add(
Cond::all()
.add(Expr::col(Glyph::Aspect).is_null())
.add(Expr::col(Glyph::Image).is_null())
)
.add(
Cond::all()
.add(Expr::col(Glyph::Aspect).is_in(vec![3, 4]))
.add(Expr::col(Glyph::Image).like("A%"))
)
)
.to_string(PostgresQueryBuilder),
[
r#"SELECT "id" FROM "glyph""#,
r#"WHERE"#,
r#"("aspect" IS NULL AND "image" IS NULL)"#,
r#"OR"#,
r#"("aspect" IN (3, 4) AND "image" LIKE 'A%')"#,
]
.join(" ")
);
There is also the [any!
] and [all!
] macro at your convenience:
rust
Query::select().cond_where(any![
Expr::col(Glyph::Aspect).is_in(vec![3, 4]),
all![
Expr::col(Glyph::Aspect).is_null(),
Expr::col(Glyph::Image).like("A%")
]
]);
Statements are divided into 2 categories: Query and Schema, and to be serialized into SQL
with [QueryStatementBuilder
] and [SchemaStatementBuilder
] respectively.
Schema statement has the following interface:
rust
fn build<T: SchemaBuilder>(&self, schema_builder: T) -> String;
Query statement has the following interfaces:
```rust
fn build
fn tostring
build
builds a SQL statement as string and parameters to be passed to the database driver
through the binary protocol. This is the preferred way as it has less overhead and is more secure.
to_string
builds a SQL statement as string with parameters injected. This is good for testing
and debugging.
```rust let query = Query::select() .column(Char::Character) .column((Font::Table, Font::Name)) .from(Char::Table) .leftjoin(Font::Table, Expr::tbl(Char::Table, Char::FontId).equals(Font::Table, Font::Id)) .andwhere(Expr::col(Char::SizeW).isin(vec![3, 4])) .andwhere(Expr::col(Char::Character).like("A%")) .to_owned();
asserteq!(
query.tostring(MysqlQueryBuilder),
r#"SELECT character
, font
.name
FROM character
LEFT JOIN font
ON character
.font_id
= font
.id
WHERE size_w
IN (3, 4) AND character
LIKE 'A%'"#
);
asserteq!(
query.tostring(PostgresQueryBuilder),
r#"SELECT "character", "font"."name" FROM "character" LEFT JOIN "font" ON "character"."fontid" = "font"."id" WHERE "sizew" IN (3, 4) AND "character" LIKE 'A%'"#
);
asserteq!(
query.tostring(SqliteQueryBuilder),
r#"SELECT "character", "font"."name" FROM "character" LEFT JOIN "font" ON "character"."fontid" = "font"."id" WHERE "sizew" IN (3, 4) AND "character" LIKE 'A%'"#
);
```
```rust let query = Query::insert() .intotable(Glyph::Table) .columns(vec![Glyph::Aspect, Glyph::Image]) .valuespanic(vec![5.15.into(), "12A".into()]) .valuespanic(vec![4.21.into(), "123".into()]) .toowned();
asserteq!(
query.tostring(MysqlQueryBuilder),
r#"INSERT INTO glyph
(aspect
, image
) VALUES (5.15, '12A'), (4.21, '123')"#
);
asserteq!(
query.tostring(PostgresQueryBuilder),
r#"INSERT INTO "glyph" ("aspect", "image") VALUES (5.15, '12A'), (4.21, '123')"#
);
asserteq!(
query.tostring(SqliteQueryBuilder),
r#"INSERT INTO "glyph" ("aspect", "image") VALUES (5.15, '12A'), (4.21, '123')"#
);
```
```rust let query = Query::update() .table(Glyph::Table) .values(vec![ (Glyph::Aspect, 1.23.into()), (Glyph::Image, "123".into()), ]) .andwhere(Expr::col(Glyph::Id).eq(1)) .toowned();
asserteq!(
query.tostring(MysqlQueryBuilder),
r#"UPDATE glyph
SET aspect
= 1.23, image
= '123' WHERE id
= 1"#
);
asserteq!(
query.tostring(PostgresQueryBuilder),
r#"UPDATE "glyph" SET "aspect" = 1.23, "image" = '123' WHERE "id" = 1"#
);
asserteq!(
query.tostring(SqliteQueryBuilder),
r#"UPDATE "glyph" SET "aspect" = 1.23, "image" = '123' WHERE "id" = 1"#
);
```
```rust let query = Query::delete() .fromtable(Glyph::Table) .condwhere( Cond::any() .add(Expr::col(Glyph::Id).lt(1)) .add(Expr::col(Glyph::Id).gt(10)), ) .to_owned();
asserteq!(
query.tostring(MysqlQueryBuilder),
r#"DELETE FROM glyph
WHERE id
< 1 OR id
> 10"#
);
asserteq!(
query.tostring(PostgresQueryBuilder),
r#"DELETE FROM "glyph" WHERE "id" < 1 OR "id" > 10"#
);
asserteq!(
query.tostring(SqliteQueryBuilder),
r#"DELETE FROM "glyph" WHERE "id" < 1 OR "id" > 10"#
);
```
```rust let table = Table::create() .table(Char::Table) .ifnotexists() .col(ColumnDef::new(Char::Id).integer().notnull().autoincrement().primarykey()) .col(ColumnDef::new(Char::FontSize).integer().notnull()) .col(ColumnDef::new(Char::Character).string().notnull()) .col(ColumnDef::new(Char::SizeW).integer().notnull()) .col(ColumnDef::new(Char::SizeH).integer().notnull()) .col(ColumnDef::new(Char::FontId).integer().default(Value::Int(None))) .foreignkey( ForeignKey::create() .name("FK2e303c3a712662f1fc2a4d0aad6") .from(Char::Table, Char::FontId) .to(Font::Table, Font::Id) .ondelete(ForeignKeyAction::Cascade) .onupdate(ForeignKeyAction::Cascade) ) .toowned();
asserteq!(
table.tostring(MysqlQueryBuilder),
vec![
r#"CREATE TABLE IF NOT EXISTS character
("#,
r#"id
int NOT NULL AUTOINCREMENT PRIMARY KEY,"#,
r#"font_size
int NOT NULL,"#,
r#"character
varchar(255) NOT NULL,"#,
r#"size_w
int NOT NULL,"#,
r#"size_h
int NOT NULL,"#,
r#"font_id
int DEFAULT NULL,"#,
r#"CONSTRAINT FK_2e303c3a712662f1fc2a4d0aad6
"#,
r#"FOREIGN KEY (font_id
) REFERENCES font
(id
)"#,
r#"ON DELETE CASCADE ON UPDATE CASCADE"#,
r#")"#,
].join(" ")
);
asserteq!(
table.tostring(PostgresQueryBuilder),
vec![
r#"CREATE TABLE IF NOT EXISTS "character" ("#,
r#""id" serial NOT NULL PRIMARY KEY,"#,
r#""fontsize" integer NOT NULL,"#,
r#""character" varchar NOT NULL,"#,
r#""sizew" integer NOT NULL,"#,
r#""sizeh" integer NOT NULL,"#,
r#""fontid" integer DEFAULT NULL,"#,
r#"CONSTRAINT "FK2e303c3a712662f1fc2a4d0aad6""#,
r#"FOREIGN KEY ("fontid") REFERENCES "font" ("id")"#,
r#"ON DELETE CASCADE ON UPDATE CASCADE"#,
r#")"#,
].join(" ")
);
asserteq!(
table.tostring(SqliteQueryBuilder),
vec![
r#"CREATE TABLE IF NOT EXISTS "character" ("#,
r#""id" integer NOT NULL PRIMARY KEY AUTOINCREMENT,"#,
r#""fontsize" integer NOT NULL,"#,
r#""character" text NOT NULL,"#,
r#""sizew" integer NOT NULL,"#,
r#""sizeh" integer NOT NULL,"#,
r#""fontid" integer DEFAULT NULL,"#,
r#"FOREIGN KEY ("fontid") REFERENCES "font" ("id") ON DELETE CASCADE ON UPDATE CASCADE"#,
r#")"#,
].join(" ")
);
```
```rust let table = Table::alter() .table(Font::Table) .addcolumn( ColumnDef::new(Alias::new("newcol")) .integer() .notnull() .default(100), ) .toowned();
asserteq!(
table.tostring(MysqlQueryBuilder),
r#"ALTER TABLE font
ADD COLUMN new_col
int NOT NULL DEFAULT 100"#
);
asserteq!(
table.tostring(PostgresQueryBuilder),
r#"ALTER TABLE "font" ADD COLUMN "newcol" integer NOT NULL DEFAULT 100"#
);
asserteq!(
table.tostring(SqliteQueryBuilder),
r#"ALTER TABLE "font" ADD COLUMN "newcol" integer NOT NULL DEFAULT 100"#,
);
```
```rust let table = Table::drop() .table(Glyph::Table) .table(Char::Table) .to_owned();
asserteq!(
table.tostring(MysqlQueryBuilder),
r#"DROP TABLE glyph
, character
"#
);
asserteq!(
table.tostring(PostgresQueryBuilder),
r#"DROP TABLE "glyph", "character""#
);
asserteq!(
table.tostring(SqliteQueryBuilder),
r#"DROP TABLE "glyph", "character""#
);
```
```rust let table = Table::rename() .table(Font::Table, Alias::new("fontnew")) .toowned();
asserteq!(
table.tostring(MysqlQueryBuilder),
r#"RENAME TABLE font
TO font_new
"#
);
asserteq!(
table.tostring(PostgresQueryBuilder),
r#"ALTER TABLE "font" RENAME TO "fontnew""#
);
asserteq!(
table.tostring(SqliteQueryBuilder),
r#"ALTER TABLE "font" RENAME TO "fontnew""#
);
```
```rust let table = Table::truncate().table(Font::Table).to_owned();
asserteq!(
table.tostring(MysqlQueryBuilder),
r#"TRUNCATE TABLE font
"#
);
asserteq!(
table.tostring(PostgresQueryBuilder),
r#"TRUNCATE TABLE "font""#
);
asserteq!(
table.tostring(SqliteQueryBuilder),
r#"TRUNCATE TABLE "font""#
);
```
```rust let foreignkey = ForeignKey::create() .name("FKcharacterfont") .from(Char::Table, Char::FontId) .to(Font::Table, Font::Id) .ondelete(ForeignKeyAction::Cascade) .onupdate(ForeignKeyAction::Cascade) .toowned();
asserteq!(
foreignkey.tostring(MysqlQueryBuilder),
vec![
r#"ALTER TABLE character
"#,
r#"ADD CONSTRAINT FK_character_font
"#,
r#"FOREIGN KEY (font_id
) REFERENCES font
(id
)"#,
r#"ON DELETE CASCADE ON UPDATE CASCADE"#,
]
.join(" ")
);
asserteq!(
foreignkey.tostring(PostgresQueryBuilder),
vec![
r#"ALTER TABLE "character" ADD CONSTRAINT "FKcharacterfont""#,
r#"FOREIGN KEY ("font_id") REFERENCES "font" ("id")"#,
r#"ON DELETE CASCADE ON UPDATE CASCADE"#,
]
.join(" ")
);
// Sqlite does not support modification of foreign key constraints to existing tables
```
```rust let foreignkey = ForeignKey::drop() .name("FKcharacterfont") .table(Char::Table) .toowned();
asserteq!(
foreignkey.tostring(MysqlQueryBuilder),
r#"ALTER TABLE character
DROP FOREIGN KEY FK_character_font
"#
);
asserteq!(
foreignkey.tostring(PostgresQueryBuilder),
r#"ALTER TABLE "character" DROP CONSTRAINT "FKcharacterfont""#
);
// Sqlite does not support modification of foreign key constraints to existing tables
```
```rust let index = Index::create() .name("idx-glyph-aspect") .table(Glyph::Table) .col(Glyph::Aspect) .to_owned();
asserteq!(
index.tostring(MysqlQueryBuilder),
r#"CREATE INDEX idx-glyph-aspect
ON glyph
(aspect
)"#
);
asserteq!(
index.tostring(PostgresQueryBuilder),
r#"CREATE INDEX "idx-glyph-aspect" ON "glyph" ("aspect")"#
);
asserteq!(
index.tostring(SqliteQueryBuilder),
r#"CREATE INDEX "idx-glyph-aspect" ON "glyph" ("aspect")"#
);
```
```rust let index = Index::drop() .name("idx-glyph-aspect") .table(Glyph::Table) .to_owned();
asserteq!(
index.tostring(MysqlQueryBuilder),
r#"DROP INDEX idx-glyph-aspect
ON glyph
"#
);
asserteq!(
index.tostring(PostgresQueryBuilder),
r#"DROP INDEX "idx-glyph-aspect""#
);
asserteq!(
index.tostring(SqliteQueryBuilder),
r#"DROP INDEX "idx-glyph-aspect" ON "glyph""#
);
```
Licensed under either of
at your option.
Unless you explicitly state otherwise, any contribution intentionally submitted for inclusion in the work by you, as defined in the Apache-2.0 license, shall be dual licensed as above, without any additional terms or conditions.