Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add with_cte to include WITH clauses in Statements #859

Open
wants to merge 1 commit into
base: master
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
16 changes: 16 additions & 0 deletions src/backend/query_builder.rs
Original file line number Diff line number Diff line change
Expand Up @@ -18,6 +18,10 @@ pub trait QueryBuilder:

/// Translate [`InsertStatement`] into SQL statement.
fn prepare_insert_statement(&self, insert: &InsertStatement, sql: &mut dyn SqlWriter) {
if let Some(with) = &insert.with {
self.prepare_with_clause(with, sql);
}

self.prepare_insert(insert.replace, sql);

if let Some(table) = &insert.table {
Expand Down Expand Up @@ -95,6 +99,10 @@ pub trait QueryBuilder:

/// Translate [`SelectStatement`] into SQL statement.
fn prepare_select_statement(&self, select: &SelectStatement, sql: &mut dyn SqlWriter) {
if let Some(with) = &select.with {
self.prepare_with_clause(with, sql);
}

write!(sql, "SELECT ").unwrap();

if let Some(distinct) = &select.distinct {
Expand Down Expand Up @@ -191,6 +199,10 @@ pub trait QueryBuilder:

/// Translate [`UpdateStatement`] into SQL statement.
fn prepare_update_statement(&self, update: &UpdateStatement, sql: &mut dyn SqlWriter) {
if let Some(with) = &update.with {
self.prepare_with_clause(with, sql);
}

write!(sql, "UPDATE ").unwrap();

if let Some(table) = &update.table {
Expand Down Expand Up @@ -245,6 +257,10 @@ pub trait QueryBuilder:

/// Translate [`DeleteStatement`] into SQL statement.
fn prepare_delete_statement(&self, delete: &DeleteStatement, sql: &mut dyn SqlWriter) {
if let Some(with) = &delete.with {
self.prepare_with_clause(with, sql);
}

write!(sql, "DELETE ").unwrap();

if let Some(table) = &delete.table {
Expand Down
43 changes: 43 additions & 0 deletions src/query/delete.rs
Original file line number Diff line number Diff line change
Expand Up @@ -44,6 +44,7 @@ pub struct DeleteStatement {
pub(crate) orders: Vec<OrderExpr>,
pub(crate) limit: Option<Value>,
pub(crate) returning: Option<ReturningClause>,
pub(crate) with: Option<WithClause>,
}

impl DeleteStatement {
Expand Down Expand Up @@ -226,6 +227,48 @@ impl DeleteStatement {
pub fn with(self, clause: WithClause) -> WithQuery {
clause.query(self)
}

/// Create a Common Table Expression by specifying a [CommonTableExpression] or [WithClause] to execute this query with.
///
/// # Examples
///
/// ```
/// use sea_query::{*, IntoCondition, IntoIden, tests_cfg::*};
///
/// let select = SelectStatement::new()
/// .columns([Glyph::Id])
/// .from(Glyph::Table)
/// .and_where(Expr::col(Glyph::Image).like("0%"))
/// .to_owned();
/// let cte = CommonTableExpression::new()
/// .query(select)
/// .column(Glyph::Id)
/// .table_name(Alias::new("cte"))
/// .to_owned();
/// let with_clause = WithClause::new().cte(cte).to_owned();
/// let query = DeleteStatement::new()
/// .with_cte(with_clause)
/// .from_table(Glyph::Table)
/// .and_where(Expr::col(Glyph::Id).in_subquery(SelectStatement::new().column(Glyph::Id).from(Alias::new("cte")).to_owned()))
/// .to_owned();
///
/// assert_eq!(
/// query.to_string(MysqlQueryBuilder),
/// r#"WITH `cte` (`id`) AS (SELECT `id` FROM `glyph` WHERE `image` LIKE '0%') DELETE FROM `glyph` WHERE `id` IN (SELECT `id` FROM `cte`)"#
/// );
/// assert_eq!(
/// query.to_string(PostgresQueryBuilder),
/// r#"WITH "cte" ("id") AS (SELECT "id" FROM "glyph" WHERE "image" LIKE '0%') DELETE FROM "glyph" WHERE "id" IN (SELECT "id" FROM "cte")"#
/// );
/// assert_eq!(
/// query.to_string(SqliteQueryBuilder),
/// r#"WITH "cte" ("id") AS (SELECT "id" FROM "glyph" WHERE "image" LIKE '0%') DELETE FROM "glyph" WHERE "id" IN (SELECT "id" FROM "cte")"#
/// );
/// ```
pub fn with_cte<C: Into<WithClause>>(&mut self, clause: C) -> &mut Self {
self.with = Some(clause.into());
self
}
}

#[inherent]
Expand Down
50 changes: 50 additions & 0 deletions src/query/insert.rs
Original file line number Diff line number Diff line change
Expand Up @@ -51,6 +51,7 @@ pub struct InsertStatement {
pub(crate) on_conflict: Option<OnConflict>,
pub(crate) returning: Option<ReturningClause>,
pub(crate) default_values: Option<u32>,
pub(crate) with: Option<WithClause>,
}

impl InsertStatement {
Expand Down Expand Up @@ -473,6 +474,55 @@ impl InsertStatement {
clause.query(self)
}

/// Create a Common Table Expression by specifying a [CommonTableExpression] or [WithClause] to execute this query with.
///
/// # Examples
///
/// ```
/// use sea_query::{*, IntoCondition, IntoIden, tests_cfg::*};
///
/// let select = SelectStatement::new()
/// .columns([Glyph::Id, Glyph::Image, Glyph::Aspect])
/// .from(Glyph::Table)
/// .to_owned();
/// let cte = CommonTableExpression::new()
/// .query(select)
/// .column(Glyph::Id)
/// .column(Glyph::Image)
/// .column(Glyph::Aspect)
/// .table_name(Alias::new("cte"))
/// .to_owned();
/// let with_clause = WithClause::new().cte(cte).to_owned();
/// let select = SelectStatement::new()
/// .columns([Glyph::Id, Glyph::Image, Glyph::Aspect])
/// .from(Alias::new("cte"))
/// .to_owned();
/// let mut query = Query::insert();
/// query
/// .with_cte(with_clause)
/// .into_table(Glyph::Table)
/// .columns([Glyph::Id, Glyph::Image, Glyph::Aspect])
/// .select_from(select)
/// .unwrap();
///
/// assert_eq!(
/// query.to_string(MysqlQueryBuilder),
/// r#"WITH `cte` (`id`, `image`, `aspect`) AS (SELECT `id`, `image`, `aspect` FROM `glyph`) INSERT INTO `glyph` (`id`, `image`, `aspect`) SELECT `id`, `image`, `aspect` FROM `cte`"#
/// );
/// assert_eq!(
/// query.to_string(PostgresQueryBuilder),
/// r#"WITH "cte" ("id", "image", "aspect") AS (SELECT "id", "image", "aspect" FROM "glyph") INSERT INTO "glyph" ("id", "image", "aspect") SELECT "id", "image", "aspect" FROM "cte""#
/// );
/// assert_eq!(
/// query.to_string(SqliteQueryBuilder),
/// r#"WITH "cte" ("id", "image", "aspect") AS (SELECT "id", "image", "aspect" FROM "glyph") INSERT INTO "glyph" ("id", "image", "aspect") SELECT "id", "image", "aspect" FROM "cte""#
/// );
/// ```
pub fn with_cte<C: Into<WithClause>>(&mut self, clause: C) -> &mut Self {
self.with = Some(clause.into());
self
}

/// Insert with default values if columns and values are not supplied.
///
/// # Examples
Expand Down
68 changes: 68 additions & 0 deletions src/query/select.rs
Original file line number Diff line number Diff line change
Expand Up @@ -54,6 +54,7 @@ pub struct SelectStatement {
pub(crate) offset: Option<Value>,
pub(crate) lock: Option<LockClause>,
pub(crate) window: Option<(DynIden, WindowStatement)>,
pub(crate) with: Option<WithClause>,
#[cfg(feature = "backend-mysql")]
pub(crate) index_hints: Vec<crate::extension::mysql::IndexHint>,
}
Expand Down Expand Up @@ -162,6 +163,7 @@ impl SelectStatement {
offset: self.offset.take(),
lock: self.lock.take(),
window: self.window.take(),
with: self.with.take(),
#[cfg(feature = "backend-mysql")]
index_hints: std::mem::take(&mut self.index_hints),
}
Expand Down Expand Up @@ -2346,6 +2348,72 @@ impl SelectStatement {
clause.query(self)
}

/// Create a Common Table Expression by specifying a [CommonTableExpression] or [WithClause] to execute this query with.
///
/// # Examples
///
/// ```
/// use sea_query::{*, IntoCondition, IntoIden, tests_cfg::*};
///
/// let base_query = SelectStatement::new()
/// .column(Alias::new("id"))
/// .expr(1i32)
/// .column(Alias::new("next"))
/// .column(Alias::new("value"))
/// .from(Alias::new("table"))
/// .to_owned();
///
/// let cte_referencing = SelectStatement::new()
/// .column(Alias::new("id"))
/// .expr(Expr::col(Alias::new("depth")).add(1i32))
/// .column(Alias::new("next"))
/// .column(Alias::new("value"))
/// .from(Alias::new("table"))
/// .join(
/// JoinType::InnerJoin,
/// Alias::new("cte_traversal"),
/// Expr::col((Alias::new("cte_traversal"), Alias::new("next"))).equals((Alias::new("table"), Alias::new("id")))
/// )
/// .to_owned();
///
/// let common_table_expression = CommonTableExpression::new()
/// .query(
/// base_query.clone().union(UnionType::All, cte_referencing).to_owned()
/// )
/// .columns([Alias::new("id"), Alias::new("depth"), Alias::new("next"), Alias::new("value")])
/// .table_name(Alias::new("cte_traversal"))
/// .to_owned();
///
/// let with_clause = WithClause::new()
/// .recursive(true)
/// .cte(common_table_expression)
/// .cycle(Cycle::new_from_expr_set_using(SimpleExpr::Column(ColumnRef::Column(Alias::new("id").into_iden())), Alias::new("looped"), Alias::new("traversal_path")))
/// .to_owned();
///
/// let query = SelectStatement::new()
/// .column(ColumnRef::Asterisk)
/// .from(Alias::new("cte_traversal"))
/// .with_cte(with_clause)
/// .to_owned();
///
/// assert_eq!(
/// query.to_string(MysqlQueryBuilder),
/// r#"WITH RECURSIVE `cte_traversal` (`id`, `depth`, `next`, `value`) AS (SELECT `id`, 1, `next`, `value` FROM `table` UNION ALL (SELECT `id`, `depth` + 1, `next`, `value` FROM `table` INNER JOIN `cte_traversal` ON `cte_traversal`.`next` = `table`.`id`)) SELECT * FROM `cte_traversal`"#
/// );
/// assert_eq!(
/// query.to_string(PostgresQueryBuilder),
/// r#"WITH RECURSIVE "cte_traversal" ("id", "depth", "next", "value") AS (SELECT "id", 1, "next", "value" FROM "table" UNION ALL (SELECT "id", "depth" + 1, "next", "value" FROM "table" INNER JOIN "cte_traversal" ON "cte_traversal"."next" = "table"."id")) CYCLE "id" SET "looped" USING "traversal_path" SELECT * FROM "cte_traversal""#
/// );
/// assert_eq!(
/// query.to_string(SqliteQueryBuilder),
/// r#"WITH RECURSIVE "cte_traversal" ("id", "depth", "next", "value") AS (SELECT "id", 1, "next", "value" FROM "table" UNION ALL SELECT "id", "depth" + 1, "next", "value" FROM "table" INNER JOIN "cte_traversal" ON "cte_traversal"."next" = "table"."id") SELECT * FROM "cte_traversal""#
/// );
/// ```
pub fn with_cte<C: Into<WithClause>>(&mut self, clause: C) -> &mut Self {
self.with = Some(clause.into());
self
}

/// WINDOW
///
/// # Examples:
Expand Down
44 changes: 44 additions & 0 deletions src/query/update.rs
Original file line number Diff line number Diff line change
Expand Up @@ -44,6 +44,7 @@ pub struct UpdateStatement {
pub(crate) orders: Vec<OrderExpr>,
pub(crate) limit: Option<Value>,
pub(crate) returning: Option<ReturningClause>,
pub(crate) with: Option<WithClause>,
}

impl UpdateStatement {
Expand Down Expand Up @@ -307,6 +308,49 @@ impl UpdateStatement {
clause.query(self)
}

/// Create a Common Table Expression by specifying a [CommonTableExpression] or [WithClause] to execute this query with.
///
/// # Examples
///
/// ```
/// use sea_query::{*, IntoCondition, IntoIden, tests_cfg::*};
///
/// let select = SelectStatement::new()
/// .columns([Glyph::Id])
/// .from(Glyph::Table)
/// .and_where(Expr::col(Glyph::Image).like("0%"))
/// .to_owned();
/// let cte = CommonTableExpression::new()
/// .query(select)
/// .column(Glyph::Id)
/// .table_name(Alias::new("cte"))
/// .to_owned();
/// let with_clause = WithClause::new().cte(cte).to_owned();
/// let query = UpdateStatement::new()
/// .table(Glyph::Table)
/// .and_where(Expr::col(Glyph::Id).in_subquery(SelectStatement::new().column(Glyph::Id).from(Alias::new("cte")).to_owned()))
/// .value(Glyph::Aspect, Expr::cust("60 * 24 * 24"))
/// .with_cte(with_clause)
/// .to_owned();
///
/// assert_eq!(
/// query.to_string(MysqlQueryBuilder),
/// r#"WITH `cte` (`id`) AS (SELECT `id` FROM `glyph` WHERE `image` LIKE '0%') UPDATE `glyph` SET `aspect` = 60 * 24 * 24 WHERE `id` IN (SELECT `id` FROM `cte`)"#
/// );
/// assert_eq!(
/// query.to_string(PostgresQueryBuilder),
/// r#"WITH "cte" ("id") AS (SELECT "id" FROM "glyph" WHERE "image" LIKE '0%') UPDATE "glyph" SET "aspect" = 60 * 24 * 24 WHERE "id" IN (SELECT "id" FROM "cte")"#
/// );
/// assert_eq!(
/// query.to_string(SqliteQueryBuilder),
/// r#"WITH "cte" ("id") AS (SELECT "id" FROM "glyph" WHERE "image" LIKE '0%') UPDATE "glyph" SET "aspect" = 60 * 24 * 24 WHERE "id" IN (SELECT "id" FROM "cte")"#
/// );
/// ```
pub fn with_cte<C: Into<WithClause>>(&mut self, clause: C) -> &mut Self {
self.with = Some(clause.into());
self
}

/// Get column values
pub fn get_values(&self) -> &[(DynIden, Box<SimpleExpr>)] {
&self.values
Expand Down
7 changes: 7 additions & 0 deletions src/query/with.rs
Original file line number Diff line number Diff line change
Expand Up @@ -485,6 +485,13 @@ impl WithClause {
WithQuery::new().with_clause(self).query(query).to_owned()
}
}

impl From<CommonTableExpression> for WithClause {
fn from(cte: CommonTableExpression) -> WithClause {
WithClause::new().cte(cte).to_owned()
}
}

/// A WITH query. A simple SQL query that has a WITH clause ([WithClause]).
///
/// The [WithClause] can contain one or multiple common table expressions ([CommonTableExpression]).
Expand Down
Loading