Skip to main content

reinhardt_query/backend/
postgres.rs

1//! PostgreSQL query builder backend
2//!
3//! This module implements the SQL generation backend for PostgreSQL.
4//!
5//! # SQL Identifier Quoting
6//!
7//! PostgreSQL uses **double quotes** (`"`) for SQL identifiers (table names, column names,
8//! index names, etc.). This is different from string literals, which use single quotes (`'`).
9//!
10//! ## Quoting Behavior
11//!
12//! - All identifiers are automatically wrapped in double quotes
13//! - Double quotes within identifiers are escaped by doubling (`"` becomes `""`)
14//! - Case sensitivity is preserved when identifiers are quoted
15//!
16//! ## Examples
17//!
18//! | Input Identifier | Quoted Output |
19//! |-----------------|---------------|
20//! | `users` | `"users"` |
21//! | `user_name` | `"user_name"` |
22//! | `column"with"quotes` | `"column""with""quotes"` |
23//!
24//! ## Testing Generated SQL
25//!
26//! When writing tests for generated SQL, ensure you account for identifier quoting:
27//!
28//! ```rust,ignore
29//! use reinhardt_query::backend::{PostgresQueryBuilder, QueryBuilder};
30//! use reinhardt_query::prelude::*;
31//!
32//! let builder = PostgresQueryBuilder::new();
33//! let stmt = Query::select().column("name").from("users");
34//! let (sql, _) = builder.build_select(&stmt);
35//!
36//! // Note the double quotes around identifiers
37//! assert_eq!(sql, r#"SELECT "name" FROM "users""#);
38//! ```
39//!
40//! For more details on SQL syntax, see the
41//! [PostgreSQL Documentation](https://www.postgresql.org/docs/current/sql-syntax-lexical.html#SQL-SYNTAX-IDENTIFIERS).
42
43use super::{QueryBuilder, SqlWriter};
44use crate::{
45	expr::{Condition, SimpleExpr},
46	query::{
47		AlterIndexStatement, AlterTableOperation, AlterTableStatement, CheckTableStatement,
48		CreateIndexStatement, CreateTableStatement, CreateTriggerStatement, CreateViewStatement,
49		DeleteStatement, DropIndexStatement, DropTableStatement, DropTriggerStatement,
50		DropViewStatement, InsertStatement, OptimizeTableStatement, ReindexStatement,
51		RepairTableStatement, SelectStatement, TruncateTableStatement, UpdateStatement,
52	},
53	types::{BinOper, ColumnRef, TableRef, TriggerBody},
54	value::Values,
55};
56
57/// PostgreSQL query builder
58///
59/// This struct implements SQL generation for PostgreSQL, using the following conventions:
60/// - Identifiers: Double quotes (`"table_name"`)
61/// - Placeholders: Numbered (`$1`, `$2`, ...)
62///
63/// # Examples
64///
65/// ```rust,ignore
66/// use reinhardt_query::backend::{PostgresQueryBuilder, QueryBuilder};
67/// use reinhardt_query::prelude::*;
68///
69/// let builder = PostgresQueryBuilder::new();
70/// let stmt = Query::select()
71///     .column("id")
72///     .from("users");
73///
74/// let (sql, values) = builder.build_select(&stmt);
75/// // sql: SELECT "id" FROM "users"
76/// ```
77#[derive(Debug, Clone, Default)]
78pub struct PostgresQueryBuilder;
79
80impl PostgresQueryBuilder {
81	/// Create a new PostgreSQL query builder
82	pub fn new() -> Self {
83		Self
84	}
85
86	/// Escape an identifier for PostgreSQL
87	///
88	/// PostgreSQL uses double quotes for identifiers.
89	///
90	/// # Arguments
91	///
92	/// * `ident` - The identifier to escape
93	///
94	/// # Returns
95	///
96	/// The escaped identifier (e.g., `"user"`)
97	fn escape_iden(&self, ident: &str) -> String {
98		// Escape double quotes within the identifier
99		let escaped = ident.replace('"', "\"\"");
100		format!("\"{}\"", escaped)
101	}
102
103	/// Format a placeholder for PostgreSQL
104	///
105	/// PostgreSQL uses numbered placeholders ($1, $2, ...).
106	///
107	/// # Arguments
108	///
109	/// * `index` - The parameter index (1-based)
110	///
111	/// # Returns
112	///
113	/// The placeholder string (e.g., `$1`)
114	fn placeholder(&self, index: usize) -> String {
115		format!("${}", index)
116	}
117
118	/// Write a table reference
119	fn write_table_ref(&self, writer: &mut SqlWriter, table_ref: &TableRef) {
120		match table_ref {
121			TableRef::Table(iden) => {
122				writer.push_identifier(&iden.to_string(), |s| self.escape_iden(s));
123			}
124			TableRef::SchemaTable(schema, table) => {
125				writer.push_identifier(&schema.to_string(), |s| self.escape_iden(s));
126				writer.push(".");
127				writer.push_identifier(&table.to_string(), |s| self.escape_iden(s));
128			}
129			TableRef::DatabaseSchemaTable(db, schema, table) => {
130				writer.push_identifier(&db.to_string(), |s| self.escape_iden(s));
131				writer.push(".");
132				writer.push_identifier(&schema.to_string(), |s| self.escape_iden(s));
133				writer.push(".");
134				writer.push_identifier(&table.to_string(), |s| self.escape_iden(s));
135			}
136			TableRef::TableAlias(table, alias) => {
137				writer.push_identifier(&table.to_string(), |s| self.escape_iden(s));
138				writer.push_keyword("AS");
139				writer.push_space();
140				writer.push_identifier(&alias.to_string(), |s| self.escape_iden(s));
141			}
142			TableRef::SchemaTableAlias(schema, table, alias) => {
143				writer.push_identifier(&schema.to_string(), |s| self.escape_iden(s));
144				writer.push(".");
145				writer.push_identifier(&table.to_string(), |s| self.escape_iden(s));
146				writer.push_keyword("AS");
147				writer.push_space();
148				writer.push_identifier(&alias.to_string(), |s| self.escape_iden(s));
149			}
150			TableRef::SubQuery(query, alias) => {
151				let (subquery_sql, subquery_values) = self.build_select(query);
152
153				// Adjust placeholders for PostgreSQL ($1, $2, ... -> $N, $N+1, ...)
154				let offset = writer.param_index() - 1;
155				let adjusted_sql = if offset > 0 {
156					let mut sql = subquery_sql;
157					for i in (1..=subquery_values.len()).rev() {
158						sql = sql.replace(&format!("${}", i), &format!("${}", i + offset));
159					}
160					sql
161				} else {
162					subquery_sql
163				};
164
165				writer.push("(");
166				writer.push(&adjusted_sql);
167				writer.push(")");
168				writer.push_keyword("AS");
169				writer.push_space();
170				writer.push_identifier(&alias.to_string(), |s| self.escape_iden(s));
171
172				// Merge the values from the subquery
173				writer.append_values(&subquery_values);
174			}
175		}
176	}
177
178	/// Write a column reference
179	fn write_column_ref(&self, writer: &mut SqlWriter, col_ref: &ColumnRef) {
180		match col_ref {
181			ColumnRef::Column(iden) => {
182				writer.push_identifier(&iden.to_string(), |s| self.escape_iden(s));
183			}
184			ColumnRef::TableColumn(table, col) => {
185				writer.push_identifier(&table.to_string(), |s| self.escape_iden(s));
186				writer.push(".");
187				writer.push_identifier(&col.to_string(), |s| self.escape_iden(s));
188			}
189			ColumnRef::SchemaTableColumn(schema, table, col) => {
190				writer.push_identifier(&schema.to_string(), |s| self.escape_iden(s));
191				writer.push(".");
192				writer.push_identifier(&table.to_string(), |s| self.escape_iden(s));
193				writer.push(".");
194				writer.push_identifier(&col.to_string(), |s| self.escape_iden(s));
195			}
196			ColumnRef::Asterisk => {
197				writer.push("*");
198			}
199			ColumnRef::TableAsterisk(table) => {
200				writer.push_identifier(&table.to_string(), |s| self.escape_iden(s));
201				writer.push(".*");
202			}
203		}
204	}
205
206	/// Write a simple expression
207	fn write_simple_expr(&self, writer: &mut SqlWriter, expr: &SimpleExpr) {
208		match expr {
209			SimpleExpr::Column(col_ref) => {
210				self.write_column_ref(writer, col_ref);
211			}
212			SimpleExpr::Value(value) => {
213				writer.push_value(value.clone(), |i| self.placeholder(i));
214			}
215			SimpleExpr::Binary(left, op, right) => match (op, right.as_ref()) {
216				(BinOper::Between | BinOper::NotBetween, SimpleExpr::Tuple(items))
217					if items.len() == 2 =>
218				{
219					self.write_simple_expr(writer, left);
220					writer.push_space();
221					writer.push(op.as_str());
222					writer.push_space();
223					self.write_simple_expr(writer, &items[0]);
224					writer.push(" AND ");
225					self.write_simple_expr(writer, &items[1]);
226				}
227				(BinOper::In | BinOper::NotIn, SimpleExpr::Tuple(items)) => {
228					self.write_simple_expr(writer, left);
229					writer.push_space();
230					writer.push(op.as_str());
231					writer.push(" (");
232					writer.push_list(items, ", ", |w, item| {
233						self.write_simple_expr(w, item);
234					});
235					writer.push(")");
236				}
237				_ => {
238					self.write_simple_expr(writer, left);
239					writer.push_space();
240					writer.push(op.as_str());
241					writer.push_space();
242					self.write_simple_expr(writer, right);
243				}
244			},
245			SimpleExpr::Unary(op, expr) => {
246				writer.push(op.as_str());
247				writer.push_space();
248				self.write_simple_expr(writer, expr);
249			}
250			SimpleExpr::FunctionCall(func_name, args) => {
251				writer.push(&func_name.to_string());
252				writer.push("(");
253				writer.push_list(args, ", ", |w, arg| {
254					self.write_simple_expr(w, arg);
255				});
256				writer.push(")");
257			}
258			SimpleExpr::Constant(val) => {
259				writer.push(val.as_str());
260			}
261			SimpleExpr::SubQuery(op, select_stmt) => {
262				use crate::expr::SubQueryOper;
263
264				// Write the operator keyword if present
265				if let Some(operator) = op {
266					match operator {
267						SubQueryOper::Exists => {
268							writer.push("EXISTS");
269							writer.push_space();
270						}
271						SubQueryOper::NotExists => {
272							writer.push("NOT EXISTS");
273							writer.push_space();
274						}
275						SubQueryOper::In | SubQueryOper::NotIn => {
276							// These are handled in Binary expressions
277						}
278						SubQueryOper::All => {
279							writer.push("ALL");
280							writer.push_space();
281						}
282						SubQueryOper::Any => {
283							writer.push("ANY");
284							writer.push_space();
285						}
286						SubQueryOper::Some => {
287							writer.push("SOME");
288							writer.push_space();
289						}
290					}
291				}
292
293				// Write the subquery wrapped in parentheses
294				writer.push("(");
295
296				// Recursively build the subquery
297				let (subquery_sql, subquery_values) = self.build_select(select_stmt);
298
299				// Adjust placeholders for PostgreSQL ($1, $2, ... -> $N, $N+1, ...)
300				let offset = writer.param_index() - 1;
301				let adjusted_sql = if offset > 0 {
302					let mut sql = subquery_sql;
303					for i in (1..=subquery_values.len()).rev() {
304						sql = sql.replace(&format!("${}", i), &format!("${}", i + offset));
305					}
306					sql
307				} else {
308					subquery_sql
309				};
310
311				writer.push(&adjusted_sql);
312				writer.push(")");
313
314				// Merge the values from the subquery
315				writer.append_values(&subquery_values);
316			}
317			SimpleExpr::Window { func, window } => {
318				// Write the function
319				self.write_simple_expr(writer, func);
320				writer.push_space();
321				writer.push_keyword("OVER");
322				writer.push_space();
323				writer.push("(");
324				self.write_window_statement(writer, window);
325				writer.push(")");
326			}
327			SimpleExpr::WindowNamed { func, name } => {
328				// Write the function
329				self.write_simple_expr(writer, func);
330				writer.push_space();
331				writer.push_keyword("OVER");
332				writer.push_space();
333				writer.push_identifier(&name.to_string(), |s| self.escape_iden(s));
334			}
335			SimpleExpr::Tuple(items) => {
336				writer.push("(");
337				writer.push_list(items, ", ", |w, item| {
338					self.write_simple_expr(w, item);
339				});
340				writer.push(")");
341			}
342			SimpleExpr::Case(case) => {
343				writer.push_keyword("CASE");
344				for (condition, result) in &case.when_clauses {
345					writer.push_space();
346					writer.push_keyword("WHEN");
347					writer.push_space();
348					self.write_simple_expr(writer, condition);
349					writer.push_space();
350					writer.push_keyword("THEN");
351					writer.push_space();
352					self.write_simple_expr(writer, result);
353				}
354				if let Some(else_result) = &case.else_clause {
355					writer.push_space();
356					writer.push_keyword("ELSE");
357					writer.push_space();
358					self.write_simple_expr(writer, else_result);
359				}
360				writer.push_space();
361				writer.push_keyword("END");
362			}
363			SimpleExpr::Custom(sql) => {
364				writer.push(sql);
365			}
366			SimpleExpr::CustomWithExpr(template, exprs) => {
367				// Replace `?` placeholders with the rendered expressions
368				let mut parts = template.split('?');
369				if let Some(first) = parts.next() {
370					writer.push(first);
371				}
372				let mut expr_iter = exprs.iter();
373				for part in parts {
374					if let Some(expr) = expr_iter.next() {
375						self.write_simple_expr(writer, expr);
376					}
377					writer.push(part);
378				}
379			}
380			SimpleExpr::Asterisk => {
381				writer.push("*");
382			}
383			SimpleExpr::TableColumn(table, col) => {
384				writer.push_identifier(&table.to_string(), |s| self.escape_iden(s));
385				writer.push(".");
386				writer.push_identifier(&col.to_string(), |s| self.escape_iden(s));
387			}
388			SimpleExpr::AsEnum(name, expr) => {
389				self.write_simple_expr(writer, expr);
390				writer.push("::");
391				writer.push_identifier(&name.to_string(), |s| self.escape_iden(s));
392			}
393			SimpleExpr::Cast(expr, type_name) => {
394				writer.push("CAST(");
395				self.write_simple_expr(writer, expr);
396				writer.push(" AS ");
397				writer.push_identifier(&type_name.to_string(), |s| self.escape_iden(s));
398				writer.push(")");
399			}
400		}
401	}
402
403	/// Write a simple expression with values inlined (no placeholders)
404	///
405	/// This is used for CHECK constraints in DDL statements, which cannot use
406	/// parameterized queries. Values are written directly as SQL literals.
407	fn write_simple_expr_unquoted(&self, writer: &mut SqlWriter, expr: &SimpleExpr) {
408		use crate::types::BinOper;
409		use crate::value::Value;
410
411		match expr {
412			SimpleExpr::Column(col_ref) => {
413				self.write_column_ref(writer, col_ref);
414			}
415			SimpleExpr::Value(value) => {
416				// Write values inline as SQL literals instead of using placeholders
417				match value {
418					Value::Int(Some(n)) => {
419						writer.push(&n.to_string());
420					}
421					Value::BigInt(Some(n)) => {
422						writer.push(&n.to_string());
423					}
424					Value::TinyInt(Some(n)) => {
425						writer.push(&n.to_string());
426					}
427					Value::SmallInt(Some(n)) => {
428						writer.push(&n.to_string());
429					}
430					Value::Unsigned(Some(n)) => {
431						writer.push(&n.to_string());
432					}
433					Value::SmallUnsigned(Some(n)) => {
434						writer.push(&n.to_string());
435					}
436					Value::TinyUnsigned(Some(n)) => {
437						writer.push(&n.to_string());
438					}
439					Value::BigUnsigned(Some(n)) => {
440						writer.push(&n.to_string());
441					}
442					Value::String(Some(s)) => {
443						let escaped = s.as_str().replace('\'', "''");
444						writer.push(&format!("'{}'", escaped));
445					}
446					Value::Bool(Some(b)) => {
447						writer.push(if *b { "TRUE" } else { "FALSE" });
448					}
449					Value::Float(Some(f)) => {
450						writer.push(&f.to_string());
451					}
452					Value::Double(Some(d)) => {
453						writer.push(&d.to_string());
454					}
455					// None values render as NULL
456					_ => {
457						writer.push("NULL");
458					}
459				}
460			}
461			SimpleExpr::Binary(left, op, right) => match (op, right.as_ref()) {
462				(BinOper::Between | BinOper::NotBetween, SimpleExpr::Tuple(items))
463					if items.len() == 2 =>
464				{
465					self.write_simple_expr_unquoted(writer, left);
466					writer.push_space();
467					writer.push(op.as_str());
468					writer.push_space();
469					self.write_simple_expr_unquoted(writer, &items[0]);
470					writer.push(" AND ");
471					self.write_simple_expr_unquoted(writer, &items[1]);
472				}
473				(BinOper::In | BinOper::NotIn, SimpleExpr::Tuple(items)) => {
474					self.write_simple_expr_unquoted(writer, left);
475					writer.push_space();
476					writer.push(op.as_str());
477					writer.push(" (");
478					writer.push_list(items, ", ", |w, item| {
479						self.write_simple_expr_unquoted(w, item);
480					});
481					writer.push(")");
482				}
483				_ => {
484					self.write_simple_expr_unquoted(writer, left);
485					writer.push_space();
486					writer.push(op.as_str());
487					writer.push_space();
488					self.write_simple_expr_unquoted(writer, right);
489				}
490			},
491			SimpleExpr::Unary(op, expr) => {
492				writer.push(op.as_str());
493				writer.push_space();
494				self.write_simple_expr_unquoted(writer, expr);
495			}
496			SimpleExpr::FunctionCall(func_name, args) => {
497				writer.push(&func_name.to_string());
498				writer.push("(");
499				writer.push_list(args, ", ", |w, arg| {
500					self.write_simple_expr_unquoted(w, arg);
501				});
502				writer.push(")");
503			}
504			SimpleExpr::Constant(val) => {
505				writer.push(val.as_str());
506			}
507			SimpleExpr::Tuple(items) => {
508				writer.push("(");
509				writer.push_list(items, ", ", |w, item| {
510					self.write_simple_expr_unquoted(w, item);
511				});
512				writer.push(")");
513			}
514			SimpleExpr::Case(case) => {
515				writer.push_keyword("CASE");
516				for (condition, result) in &case.when_clauses {
517					writer.push_space();
518					writer.push_keyword("WHEN");
519					writer.push_space();
520					self.write_simple_expr_unquoted(writer, condition);
521					writer.push_space();
522					writer.push_keyword("THEN");
523					writer.push_space();
524					self.write_simple_expr_unquoted(writer, result);
525				}
526				if let Some(else_result) = &case.else_clause {
527					writer.push_space();
528					writer.push_keyword("ELSE");
529					writer.push_space();
530					self.write_simple_expr_unquoted(writer, else_result);
531				}
532				writer.push_space();
533				writer.push_keyword("END");
534			}
535			// Subqueries are not supported in CHECK constraints
536			SimpleExpr::SubQuery(_, _) => {
537				writer.push("(TRUE)");
538			}
539			// Window expressions are not supported in CHECK constraints
540			SimpleExpr::Window { .. } | SimpleExpr::WindowNamed { .. } => {
541				writer.push("(TRUE)");
542			}
543			SimpleExpr::Custom(sql) => {
544				writer.push(sql);
545			}
546			SimpleExpr::CustomWithExpr(template, exprs) => {
547				let mut parts = template.split('?');
548				if let Some(first) = parts.next() {
549					writer.push(first);
550				}
551				let mut expr_iter = exprs.iter();
552				for part in parts {
553					if let Some(expr) = expr_iter.next() {
554						self.write_simple_expr_unquoted(writer, expr);
555					}
556					writer.push(part);
557				}
558			}
559			SimpleExpr::Asterisk => {
560				writer.push("*");
561			}
562			SimpleExpr::TableColumn(table, col) => {
563				writer.push_identifier(&table.to_string(), |s| self.escape_iden(s));
564				writer.push(".");
565				writer.push_identifier(&col.to_string(), |s| self.escape_iden(s));
566			}
567			SimpleExpr::AsEnum(name, expr) => {
568				self.write_simple_expr_unquoted(writer, expr);
569				writer.push("::");
570				writer.push_identifier(&name.to_string(), |s| self.escape_iden(s));
571			}
572			SimpleExpr::Cast(expr, type_name) => {
573				writer.push("CAST(");
574				self.write_simple_expr_unquoted(writer, expr);
575				writer.push(" AS ");
576				writer.push_identifier(&type_name.to_string(), |s| self.escape_iden(s));
577				writer.push(")");
578			}
579		}
580	}
581
582	/// Write a condition
583	fn write_condition(&self, writer: &mut SqlWriter, condition: &Condition) {
584		use crate::expr::ConditionType;
585
586		if condition.conditions.is_empty() {
587			return;
588		}
589
590		if condition.negate {
591			writer.push("NOT ");
592		}
593
594		if condition.conditions.len() == 1 {
595			self.write_condition_expr(writer, &condition.conditions[0]);
596			return;
597		}
598
599		writer.push("(");
600		let separator = match condition.condition_type {
601			ConditionType::All => " AND ",
602			ConditionType::Any => " OR ",
603		};
604		writer.push_list(&condition.conditions, separator, |w, cond_expr| {
605			self.write_condition_expr(w, cond_expr);
606		});
607		writer.push(")");
608	}
609
610	/// Write a condition expression
611	fn write_condition_expr(
612		&self,
613		writer: &mut SqlWriter,
614		cond_expr: &crate::expr::ConditionExpression,
615	) {
616		use crate::expr::ConditionExpression;
617
618		match cond_expr {
619			ConditionExpression::Condition(cond) => {
620				self.write_condition(writer, cond);
621			}
622			ConditionExpression::SimpleExpr(expr) => {
623				self.write_simple_expr(writer, expr);
624			}
625		}
626	}
627
628	/// Write a JOIN expression
629	fn write_join_expr(&self, writer: &mut SqlWriter, join: &crate::types::JoinExpr) {
630		use crate::types::JoinOn;
631
632		// JOIN type
633		writer.push_keyword(join.join.as_str());
634		writer.push_space();
635
636		// Table
637		self.write_table_ref(writer, &join.table);
638
639		// ON or USING clause
640		if let Some(on) = &join.on {
641			match on {
642				JoinOn::Columns(pair) => {
643					writer.push_keyword("ON");
644					writer.push_space();
645					self.write_column_spec(writer, &pair.left);
646					writer.push(" = ");
647					self.write_column_spec(writer, &pair.right);
648				}
649				JoinOn::Condition(cond) => {
650					writer.push_keyword("ON");
651					writer.push_space();
652					self.write_condition(writer, cond);
653				}
654				JoinOn::Using(cols) => {
655					writer.push_keyword("USING");
656					writer.push_space();
657					writer.push("(");
658					writer.push_list(cols, ", ", |w, col| {
659						w.push_identifier(&col.to_string(), |s| self.escape_iden(s));
660					});
661					writer.push(")");
662				}
663			}
664		}
665	}
666
667	/// Write a column specification (for JOIN ON conditions)
668	fn write_column_spec(&self, writer: &mut SqlWriter, spec: &crate::types::ColumnSpec) {
669		match spec {
670			crate::types::ColumnSpec::Column(iden) => {
671				writer.push_identifier(&iden.to_string(), |s| self.escape_iden(s));
672			}
673			crate::types::ColumnSpec::TableColumn(table, col) => {
674				writer.push_identifier(&table.to_string(), |s| self.escape_iden(s));
675				writer.push(".");
676				writer.push_identifier(&col.to_string(), |s| self.escape_iden(s));
677			}
678		}
679	}
680
681	/// Write a window statement (PARTITION BY, ORDER BY, frame clause)
682	fn write_window_statement(
683		&self,
684		writer: &mut SqlWriter,
685		window: &crate::types::WindowStatement,
686	) {
687		// PARTITION BY clause
688		if !window.partition_by.is_empty() {
689			writer.push_keyword("PARTITION BY");
690			writer.push_space();
691			writer.push_list(&window.partition_by, ", ", |w, expr| {
692				self.write_simple_expr(w, expr);
693			});
694			writer.push_space();
695		}
696
697		// ORDER BY clause
698		if !window.order_by.is_empty() {
699			writer.push_keyword("ORDER BY");
700			writer.push_space();
701			writer.push_list(&window.order_by, ", ", |w, order_expr| {
702				use crate::types::OrderExprKind;
703				match &order_expr.expr {
704					OrderExprKind::Column(iden) => {
705						w.push_identifier(&iden.to_string(), |s| self.escape_iden(s));
706					}
707					OrderExprKind::TableColumn(table, col) => {
708						w.push_identifier(&table.to_string(), |s| self.escape_iden(s));
709						w.push(".");
710						w.push_identifier(&col.to_string(), |s| self.escape_iden(s));
711					}
712					OrderExprKind::Expr(expr) => {
713						self.write_simple_expr(w, expr);
714					}
715				}
716				match order_expr.order {
717					crate::types::Order::Asc => {
718						w.push_keyword("ASC");
719					}
720					crate::types::Order::Desc => {
721						w.push_keyword("DESC");
722					}
723				}
724				if let Some(nulls) = order_expr.nulls {
725					w.push_space();
726					w.push(nulls.as_str());
727				}
728			});
729			writer.push_space();
730		}
731
732		// Frame clause
733		if let Some(frame) = &window.frame {
734			self.write_frame_clause(writer, frame);
735		}
736	}
737
738	/// Write a frame clause (ROWS/RANGE/GROUPS BETWEEN ... AND ...)
739	fn write_frame_clause(&self, writer: &mut SqlWriter, frame: &crate::types::FrameClause) {
740		use crate::types::FrameType;
741
742		// Frame type (ROWS, RANGE, GROUPS)
743		match frame.frame_type {
744			FrameType::Rows => writer.push_keyword("ROWS"),
745			FrameType::Range => writer.push_keyword("RANGE"),
746			FrameType::Groups => writer.push_keyword("GROUPS"),
747		}
748		writer.push_space();
749
750		// Frame specification
751		if let Some(end) = &frame.end {
752			writer.push_keyword("BETWEEN");
753			writer.push_space();
754			self.write_frame_boundary(writer, &frame.start);
755			writer.push_keyword("AND");
756			writer.push_space();
757			self.write_frame_boundary(writer, end);
758		} else {
759			self.write_frame_boundary(writer, &frame.start);
760		}
761	}
762
763	/// Write a frame boundary (UNBOUNDED PRECEDING, CURRENT ROW, etc.)
764	fn write_frame_boundary(&self, writer: &mut SqlWriter, frame: &crate::types::Frame) {
765		use crate::types::Frame;
766		match frame {
767			Frame::UnboundedPreceding => writer.push("UNBOUNDED PRECEDING"),
768			Frame::Preceding(n) => {
769				writer.push(&n.to_string());
770				writer.push(" PRECEDING");
771			}
772			Frame::CurrentRow => writer.push("CURRENT ROW"),
773			Frame::Following(n) => {
774				writer.push(&n.to_string());
775				writer.push(" FOLLOWING");
776			}
777			Frame::UnboundedFollowing => writer.push("UNBOUNDED FOLLOWING"),
778		}
779	}
780}
781
782impl QueryBuilder for PostgresQueryBuilder {
783	fn build_select(&self, stmt: &SelectStatement) -> (String, Values) {
784		let mut writer = SqlWriter::new();
785
786		// WITH clause (Common Table Expressions)
787		if !stmt.ctes.is_empty() {
788			// Check if any CTE is recursive
789			let has_recursive = stmt.ctes.iter().any(|cte| cte.recursive);
790
791			// Write WITH [RECURSIVE]
792			writer.push_keyword("WITH");
793			writer.push_space();
794			if has_recursive {
795				writer.push_keyword("RECURSIVE");
796				writer.push_space();
797			}
798
799			// Write each CTE
800			writer.push_list(&stmt.ctes, ", ", |w, cte| {
801				// CTE name
802				w.push_identifier(&cte.name.to_string(), |s| self.escape_iden(s));
803				w.push_space();
804				w.push_keyword("AS");
805				w.push_space();
806				w.push("(");
807
808				// Recursively build the CTE query
809				let (cte_sql, cte_values) = self.build_select(&cte.query);
810
811				// Adjust placeholders for PostgreSQL ($1, $2, ... -> $N, $N+1, ...)
812				let offset = w.param_index() - 1;
813				let adjusted_sql = if offset > 0 {
814					let mut sql = cte_sql;
815					for i in (1..=cte_values.len()).rev() {
816						sql = sql.replace(&format!("${}", i), &format!("${}", i + offset));
817					}
818					sql
819				} else {
820					cte_sql
821				};
822
823				w.push(&adjusted_sql);
824				w.push(")");
825
826				// Merge the values from the CTE query
827				w.append_values(&cte_values);
828			});
829
830			writer.push_space();
831		}
832
833		// SELECT clause
834		writer.push("SELECT");
835		writer.push_space();
836
837		// DISTINCT clause
838		if let Some(distinct) = &stmt.distinct {
839			use crate::query::SelectDistinct;
840			match distinct {
841				SelectDistinct::All => {
842					// SELECT ALL - explicit but not required in PostgreSQL
843				}
844				SelectDistinct::Distinct => {
845					writer.push_keyword("DISTINCT");
846					writer.push_space();
847				}
848				SelectDistinct::DistinctRow => {
849					panic!("PostgreSQL does not support DISTINCT ROW. Use DISTINCT instead.");
850				}
851				SelectDistinct::DistinctOn(cols) => {
852					writer.push_keyword("DISTINCT ON");
853					writer.push_space();
854					writer.push("(");
855					writer.push_list(cols, ", ", |w, col_ref| {
856						self.write_column_ref(w, col_ref);
857					});
858					writer.push(")");
859					writer.push_space();
860				}
861			}
862		}
863
864		if stmt.selects.is_empty() {
865			writer.push("*");
866		} else {
867			writer.push_list(&stmt.selects, ", ", |w, select_expr| {
868				self.write_simple_expr(w, &select_expr.expr);
869				if let Some(alias) = &select_expr.alias {
870					w.push_keyword("AS");
871					w.push_space();
872					w.push_identifier(&alias.to_string(), |s| self.escape_iden(s));
873				}
874			});
875		}
876
877		// FROM clause
878		if !stmt.from.is_empty() {
879			writer.push_keyword("FROM");
880			writer.push_space();
881			writer.push_list(&stmt.from, ", ", |w, table_ref| {
882				self.write_table_ref(w, table_ref);
883			});
884		}
885
886		// JOIN clauses
887		for join in &stmt.join {
888			writer.push_space();
889			self.write_join_expr(&mut writer, join);
890		}
891
892		// WHERE clause
893		if !stmt.r#where.is_empty() {
894			writer.push_keyword("WHERE");
895			writer.push_space();
896			// Write all conditions in the ConditionHolder with AND
897			writer.push_list(&stmt.r#where.conditions, " AND ", |w, cond_expr| {
898				self.write_condition_expr(w, cond_expr);
899			});
900		}
901
902		// GROUP BY clause
903		if !stmt.groups.is_empty() {
904			writer.push_keyword("GROUP BY");
905			writer.push_space();
906			writer.push_list(&stmt.groups, ", ", |w, expr| {
907				self.write_simple_expr(w, expr);
908			});
909		}
910
911		// HAVING clause
912		if !stmt.having.conditions.is_empty() {
913			writer.push_keyword("HAVING");
914			writer.push_space();
915			// Write all conditions in the ConditionHolder with AND
916			writer.push_list(&stmt.having.conditions, " AND ", |w, cond_expr| {
917				self.write_condition_expr(w, cond_expr);
918			});
919		}
920
921		// ORDER BY clause
922		if !stmt.orders.is_empty() {
923			writer.push_keyword("ORDER BY");
924			writer.push_space();
925			writer.push_list(&stmt.orders, ", ", |w, order_expr| {
926				use crate::types::OrderExprKind;
927				match &order_expr.expr {
928					OrderExprKind::Column(iden) => {
929						w.push_identifier(&iden.to_string(), |s| self.escape_iden(s));
930					}
931					OrderExprKind::TableColumn(table, col) => {
932						w.push_identifier(&table.to_string(), |s| self.escape_iden(s));
933						w.push(".");
934						w.push_identifier(&col.to_string(), |s| self.escape_iden(s));
935					}
936					OrderExprKind::Expr(expr) => {
937						self.write_simple_expr(w, expr);
938					}
939				}
940				match order_expr.order {
941					crate::types::Order::Asc => {
942						w.push_keyword("ASC");
943					}
944					crate::types::Order::Desc => {
945						w.push_keyword("DESC");
946					}
947				}
948				if let Some(nulls) = order_expr.nulls {
949					w.push_space();
950					w.push(nulls.as_str());
951				}
952			});
953		}
954
955		// WINDOW clause
956		if !stmt.windows.is_empty() {
957			writer.push_keyword("WINDOW");
958			writer.push_space();
959			writer.push_list(&stmt.windows, ", ", |w, (name, window)| {
960				w.push_identifier(&name.to_string(), |s| self.escape_iden(s));
961				w.push_space();
962				w.push_keyword("AS");
963				w.push_space();
964				w.push("(");
965				self.write_window_statement(w, window);
966				w.push(")");
967			});
968		}
969
970		// LIMIT clause
971		if let Some(limit) = &stmt.limit {
972			writer.push_keyword("LIMIT");
973			writer.push_space();
974			writer.push_value(limit.clone(), |i| self.placeholder(i));
975		}
976
977		// OFFSET clause
978		if let Some(offset) = &stmt.offset {
979			writer.push_keyword("OFFSET");
980			writer.push_space();
981			writer.push_value(offset.clone(), |i| self.placeholder(i));
982		}
983
984		// UNION/INTERSECT/EXCEPT clauses
985		for (union_type, union_stmt) in &stmt.unions {
986			writer.push_space();
987			use crate::query::UnionType;
988			match union_type {
989				UnionType::Distinct => {
990					writer.push_keyword("UNION");
991				}
992				UnionType::All => {
993					writer.push_keyword("UNION ALL");
994				}
995				UnionType::Intersect => {
996					writer.push_keyword("INTERSECT");
997				}
998				UnionType::Except => {
999					writer.push_keyword("EXCEPT");
1000				}
1001			}
1002			writer.push_space();
1003
1004			// Recursively build the union query
1005			let (mut union_sql, union_values) = self.build_select(union_stmt);
1006
1007			// Adjust placeholders for PostgreSQL ($1, $2, ... -> $N, $N+1, ...)
1008			let offset = writer.param_index() - 1;
1009			if offset > 0 {
1010				for i in (1..=union_values.len()).rev() {
1011					union_sql = union_sql.replace(&format!("${}", i), &format!("${}", i + offset));
1012				}
1013			}
1014
1015			// Append the union SQL (wrapped in parentheses if it has unions itself)
1016			if !union_stmt.unions.is_empty() {
1017				writer.push("(");
1018				writer.push(&union_sql);
1019				writer.push(")");
1020			} else {
1021				writer.push(&union_sql);
1022			}
1023
1024			// Merge the values from the union query
1025			writer.append_values(&union_values);
1026		}
1027
1028		writer.finish()
1029	}
1030
1031	fn build_insert(&self, stmt: &InsertStatement) -> (String, Values) {
1032		use crate::query::insert::InsertSource;
1033
1034		let mut writer = SqlWriter::new();
1035
1036		// INSERT INTO clause
1037		writer.push("INSERT INTO");
1038		writer.push_space();
1039
1040		if let Some(table) = &stmt.table {
1041			self.write_table_ref(&mut writer, table);
1042		} else {
1043			// No table specified - this should not happen in valid SQL
1044			writer.push("(NO_TABLE)");
1045		}
1046
1047		// Column list
1048		if !stmt.columns.is_empty() {
1049			writer.push_space();
1050			writer.push("(");
1051			writer.push_list(&stmt.columns, ", ", |w, col| {
1052				w.push_identifier(&col.to_string(), |s| self.escape_iden(s));
1053			});
1054			writer.push(")");
1055		}
1056
1057		// VALUES clause or SELECT subquery
1058		match &stmt.source {
1059			InsertSource::Values(values) if !values.is_empty() => {
1060				writer.push_keyword("VALUES");
1061				writer.push_space();
1062
1063				writer.push_list(values, ", ", |w, row| {
1064					w.push("(");
1065					w.push_list(row, ", ", |w2, value| {
1066						w2.push_value(value.clone(), |i| self.placeholder(i));
1067					});
1068					w.push(")");
1069				});
1070			}
1071			InsertSource::Subquery(select) => {
1072				writer.push_space();
1073				let (select_sql, select_values) = self.build_select(select);
1074				writer.push(&select_sql);
1075				writer.append_values(&select_values);
1076			}
1077			_ => {
1078				// Empty values - this is valid SQL in some contexts
1079			}
1080		}
1081
1082		// ON CONFLICT clause
1083		if let Some(on_conflict) = &stmt.on_conflict {
1084			use crate::query::{OnConflictAction, OnConflictTarget};
1085			writer.push_keyword("ON CONFLICT");
1086			writer.push_space();
1087
1088			// Target columns
1089			writer.push("(");
1090			match &on_conflict.target {
1091				OnConflictTarget::Column(col) => {
1092					writer.push_identifier(&col.to_string(), |s| self.escape_iden(s));
1093				}
1094				OnConflictTarget::Columns(cols) => {
1095					writer.push_list(cols, ", ", |w, col| {
1096						w.push_identifier(&col.to_string(), |s| self.escape_iden(s));
1097					});
1098				}
1099			}
1100			writer.push(")");
1101
1102			// Action
1103			match &on_conflict.action {
1104				OnConflictAction::DoNothing => {
1105					writer.push_keyword("DO NOTHING");
1106				}
1107				OnConflictAction::DoUpdate(cols) => {
1108					writer.push_keyword("DO UPDATE SET");
1109					writer.push_space();
1110					writer.push_list(cols, ", ", |w, col| {
1111						let col_str = col.to_string();
1112						w.push_identifier(&col_str, |s| self.escape_iden(s));
1113						w.push(" = EXCLUDED.");
1114						w.push_identifier(&col_str, |s| self.escape_iden(s));
1115					});
1116				}
1117			}
1118		}
1119
1120		// RETURNING clause (PostgreSQL specific)
1121		if let Some(returning) = &stmt.returning {
1122			writer.push_keyword("RETURNING");
1123			writer.push_space();
1124
1125			use crate::query::ReturningClause;
1126			match returning {
1127				ReturningClause::All => {
1128					writer.push("*");
1129				}
1130				ReturningClause::Columns(cols) => {
1131					writer.push_list(cols, ", ", |w, col| {
1132						self.write_column_ref(w, col);
1133					});
1134				}
1135			}
1136		}
1137
1138		writer.finish()
1139	}
1140
1141	fn build_update(&self, stmt: &UpdateStatement) -> (String, Values) {
1142		let mut writer = SqlWriter::new();
1143
1144		// UPDATE clause
1145		writer.push("UPDATE");
1146		writer.push_space();
1147
1148		if let Some(table) = &stmt.table {
1149			self.write_table_ref(&mut writer, table);
1150		} else {
1151			writer.push("(NO_TABLE)");
1152		}
1153
1154		// SET clause
1155		if !stmt.values.is_empty() {
1156			writer.push_keyword("SET");
1157			writer.push_space();
1158
1159			writer.push_list(&stmt.values, ", ", |w, (col, value)| {
1160				w.push_identifier(&col.to_string(), |s| self.escape_iden(s));
1161				w.push(" = ");
1162				self.write_simple_expr(w, value);
1163			});
1164		}
1165
1166		// WHERE clause
1167		if !stmt.r#where.is_empty() {
1168			writer.push_keyword("WHERE");
1169			writer.push_space();
1170			writer.push_list(&stmt.r#where.conditions, " AND ", |w, cond_expr| {
1171				self.write_condition_expr(w, cond_expr);
1172			});
1173		}
1174
1175		// RETURNING clause (PostgreSQL specific)
1176		if let Some(returning) = &stmt.returning {
1177			writer.push_keyword("RETURNING");
1178			writer.push_space();
1179
1180			use crate::query::ReturningClause;
1181			match returning {
1182				ReturningClause::All => {
1183					writer.push("*");
1184				}
1185				ReturningClause::Columns(cols) => {
1186					writer.push_list(cols, ", ", |w, col| {
1187						self.write_column_ref(w, col);
1188					});
1189				}
1190			}
1191		}
1192
1193		writer.finish()
1194	}
1195
1196	fn build_delete(&self, stmt: &DeleteStatement) -> (String, Values) {
1197		let mut writer = SqlWriter::new();
1198
1199		// DELETE FROM clause
1200		writer.push("DELETE FROM");
1201		writer.push_space();
1202
1203		if let Some(table) = &stmt.table {
1204			self.write_table_ref(&mut writer, table);
1205		} else {
1206			writer.push("(NO_TABLE)");
1207		}
1208
1209		// WHERE clause
1210		if !stmt.r#where.is_empty() {
1211			writer.push_keyword("WHERE");
1212			writer.push_space();
1213			writer.push_list(&stmt.r#where.conditions, " AND ", |w, cond_expr| {
1214				self.write_condition_expr(w, cond_expr);
1215			});
1216		}
1217
1218		// RETURNING clause (PostgreSQL specific)
1219		if let Some(returning) = &stmt.returning {
1220			writer.push_keyword("RETURNING");
1221			writer.push_space();
1222
1223			use crate::query::ReturningClause;
1224			match returning {
1225				ReturningClause::All => {
1226					writer.push("*");
1227				}
1228				ReturningClause::Columns(cols) => {
1229					writer.push_list(cols, ", ", |w, col| {
1230						self.write_column_ref(w, col);
1231					});
1232				}
1233			}
1234		}
1235
1236		writer.finish()
1237	}
1238
1239	fn build_create_table(&self, stmt: &CreateTableStatement) -> (String, Values) {
1240		let mut writer = SqlWriter::new();
1241
1242		writer.push("CREATE TABLE");
1243		writer.push_space();
1244
1245		if stmt.if_not_exists {
1246			writer.push_keyword("IF NOT EXISTS");
1247			writer.push_space();
1248		}
1249
1250		if let Some(table) = &stmt.table {
1251			self.write_table_ref(&mut writer, table);
1252		}
1253
1254		writer.push_space();
1255		writer.push("(");
1256
1257		// Columns
1258		let mut first = true;
1259		for column in &stmt.columns {
1260			if !first {
1261				writer.push(", ");
1262			}
1263			first = false;
1264
1265			// Column name
1266			writer.push_identifier(&column.name.to_string(), |s| self.escape_iden(s));
1267			writer.push_space();
1268
1269			// Column type
1270			if let Some(col_type) = &column.column_type {
1271				// For auto_increment columns, use SERIAL types instead of INTEGER/BIGINT
1272				if column.auto_increment {
1273					use crate::types::ColumnType;
1274					let serial_type = match col_type {
1275						ColumnType::SmallInteger => "SMALLSERIAL",
1276						ColumnType::Integer => "SERIAL",
1277						ColumnType::BigInteger => "BIGSERIAL",
1278						_ => &self.column_type_to_sql(col_type),
1279					};
1280					writer.push(serial_type);
1281				} else {
1282					writer.push(&self.column_type_to_sql(col_type));
1283				}
1284			}
1285
1286			// NOT NULL
1287			if column.not_null {
1288				writer.push_space();
1289				writer.push_keyword("NOT NULL");
1290			}
1291
1292			// UNIQUE
1293			if column.unique {
1294				writer.push_space();
1295				writer.push_keyword("UNIQUE");
1296			}
1297
1298			// PRIMARY KEY
1299			if column.primary_key {
1300				writer.push_space();
1301				writer.push_keyword("PRIMARY KEY");
1302			}
1303
1304			// DEFAULT
1305			if let Some(default_expr) = &column.default {
1306				writer.push_space();
1307				writer.push_keyword("DEFAULT");
1308				writer.push_space();
1309				self.write_simple_expr(&mut writer, default_expr);
1310			}
1311
1312			// CHECK
1313			if let Some(check_expr) = &column.check {
1314				writer.push_space();
1315				writer.push_keyword("CHECK");
1316				writer.push_space();
1317				writer.push("(");
1318				self.write_simple_expr_unquoted(&mut writer, check_expr);
1319				writer.push(")");
1320			}
1321		}
1322
1323		// Table constraints
1324		for constraint in &stmt.constraints {
1325			writer.push(", ");
1326			self.write_table_constraint(&mut writer, constraint);
1327		}
1328
1329		writer.push(")");
1330
1331		writer.finish()
1332	}
1333
1334	fn build_alter_table(&self, stmt: &AlterTableStatement) -> (String, Values) {
1335		let mut writer = SqlWriter::new();
1336
1337		// ALTER TABLE table_name
1338		writer.push("ALTER TABLE");
1339		writer.push_space();
1340		if let Some(table) = &stmt.table {
1341			self.write_table_ref(&mut writer, table);
1342		}
1343
1344		// Process operations
1345		let mut first = true;
1346		for operation in &stmt.operations {
1347			if !first {
1348				writer.push(",");
1349			}
1350			first = false;
1351			writer.push_space();
1352
1353			match operation {
1354				AlterTableOperation::AddColumn(column_def) => {
1355					writer.push("ADD COLUMN");
1356					writer.push_space();
1357					writer.push_identifier(&column_def.name.to_string(), |s| self.escape_iden(s));
1358					writer.push_space();
1359					if let Some(col_type) = &column_def.column_type {
1360						writer.push(&self.column_type_to_sql(col_type));
1361					}
1362					if column_def.not_null {
1363						writer.push(" NOT NULL");
1364					}
1365					if column_def.unique {
1366						writer.push(" UNIQUE");
1367					}
1368					if let Some(default) = &column_def.default {
1369						writer.push(" DEFAULT ");
1370						self.write_simple_expr(&mut writer, default);
1371					}
1372					if let Some(check) = &column_def.check {
1373						writer.push(" CHECK (");
1374						self.write_simple_expr_unquoted(&mut writer, check);
1375						writer.push(")");
1376					}
1377				}
1378				AlterTableOperation::DropColumn { name, if_exists } => {
1379					writer.push("DROP COLUMN");
1380					writer.push_space();
1381					if *if_exists {
1382						writer.push("IF EXISTS");
1383						writer.push_space();
1384					}
1385					writer.push_identifier(&name.to_string(), |s| self.escape_iden(s));
1386				}
1387				AlterTableOperation::RenameColumn { old, new } => {
1388					writer.push("RENAME COLUMN");
1389					writer.push_space();
1390					writer.push_identifier(&old.to_string(), |s| self.escape_iden(s));
1391					writer.push_space();
1392					writer.push("TO");
1393					writer.push_space();
1394					writer.push_identifier(&new.to_string(), |s| self.escape_iden(s));
1395				}
1396				AlterTableOperation::ModifyColumn(column_def) => {
1397					// PostgreSQL uses ALTER COLUMN instead of MODIFY COLUMN
1398					writer.push("ALTER COLUMN");
1399					writer.push_space();
1400					writer.push_identifier(&column_def.name.to_string(), |s| self.escape_iden(s));
1401					writer.push_space();
1402
1403					// TYPE change
1404					if let Some(col_type) = &column_def.column_type {
1405						writer.push("TYPE");
1406						writer.push_space();
1407						writer.push(&self.column_type_to_sql(col_type));
1408					}
1409
1410					// NOT NULL / NULL
1411					if column_def.not_null {
1412						writer.push(", ALTER COLUMN ");
1413						writer
1414							.push_identifier(&column_def.name.to_string(), |s| self.escape_iden(s));
1415						writer.push(" SET NOT NULL");
1416					}
1417
1418					// DEFAULT
1419					if let Some(default) = &column_def.default {
1420						writer.push(", ALTER COLUMN ");
1421						writer
1422							.push_identifier(&column_def.name.to_string(), |s| self.escape_iden(s));
1423						writer.push(" SET DEFAULT ");
1424						self.write_simple_expr(&mut writer, default);
1425					}
1426				}
1427				AlterTableOperation::AddConstraint(constraint) => {
1428					writer.push("ADD ");
1429					self.write_table_constraint(&mut writer, constraint);
1430				}
1431				AlterTableOperation::DropConstraint { name, if_exists } => {
1432					writer.push("DROP CONSTRAINT");
1433					writer.push_space();
1434					if *if_exists {
1435						writer.push("IF EXISTS");
1436						writer.push_space();
1437					}
1438					writer.push_identifier(&name.to_string(), |s| self.escape_iden(s));
1439				}
1440				AlterTableOperation::RenameTable(new_name) => {
1441					writer.push("RENAME TO");
1442					writer.push_space();
1443					writer.push_identifier(&new_name.to_string(), |s| self.escape_iden(s));
1444				}
1445			}
1446		}
1447
1448		writer.finish()
1449	}
1450
1451	fn build_drop_table(&self, stmt: &DropTableStatement) -> (String, Values) {
1452		let mut writer = SqlWriter::new();
1453
1454		// DROP TABLE
1455		writer.push("DROP TABLE");
1456		writer.push_space();
1457
1458		// IF EXISTS clause
1459		if stmt.if_exists {
1460			writer.push_keyword("IF EXISTS");
1461			writer.push_space();
1462		}
1463
1464		// Table names
1465		writer.push_list(&stmt.tables, ", ", |w, table_ref| {
1466			self.write_table_ref(w, table_ref);
1467		});
1468
1469		// CASCADE/RESTRICT clause
1470		if stmt.cascade {
1471			writer.push_space();
1472			writer.push_keyword("CASCADE");
1473		} else if stmt.restrict {
1474			writer.push_space();
1475			writer.push_keyword("RESTRICT");
1476		}
1477
1478		writer.finish()
1479	}
1480
1481	fn build_create_index(&self, stmt: &CreateIndexStatement) -> (String, Values) {
1482		let mut writer = SqlWriter::new();
1483
1484		// CREATE UNIQUE INDEX IF NOT EXISTS
1485		writer.push("CREATE");
1486		writer.push_space();
1487		if stmt.unique {
1488			writer.push_keyword("UNIQUE");
1489			writer.push_space();
1490		}
1491		writer.push_keyword("INDEX");
1492		writer.push_space();
1493		if stmt.if_not_exists {
1494			writer.push_keyword("IF NOT EXISTS");
1495			writer.push_space();
1496		}
1497
1498		// Index name
1499		if let Some(name) = &stmt.name {
1500			writer.push_identifier(&name.to_string(), |s| self.escape_iden(s));
1501			writer.push_space();
1502		}
1503
1504		// ON table
1505		writer.push_keyword("ON");
1506		writer.push_space();
1507		if let Some(table) = &stmt.table {
1508			self.write_table_ref(&mut writer, table);
1509		}
1510		writer.push_space();
1511
1512		// USING method
1513		if let Some(method) = &stmt.using {
1514			writer.push_keyword("USING");
1515			writer.push_space();
1516			writer.push(self.index_method_to_sql(method));
1517			writer.push_space();
1518		}
1519
1520		// (column1 ASC, column2 DESC, ...)
1521		writer.push("(");
1522		let mut first = true;
1523		for col in &stmt.columns {
1524			if !first {
1525				writer.push(", ");
1526			}
1527			first = false;
1528			writer.push_identifier(&col.name.to_string(), |s| self.escape_iden(s));
1529			if let Some(order) = &col.order {
1530				writer.push_space();
1531				match order {
1532					crate::types::Order::Asc => writer.push("ASC"),
1533					crate::types::Order::Desc => writer.push("DESC"),
1534				}
1535			}
1536		}
1537		writer.push(")");
1538
1539		// WHERE clause (partial index)
1540		if let Some(where_expr) = &stmt.r#where {
1541			writer.push_space();
1542			writer.push_keyword("WHERE");
1543			writer.push_space();
1544			self.write_simple_expr(&mut writer, where_expr);
1545		}
1546
1547		writer.finish()
1548	}
1549
1550	fn build_drop_index(&self, stmt: &DropIndexStatement) -> (String, Values) {
1551		let mut writer = SqlWriter::new();
1552
1553		// DROP INDEX
1554		writer.push("DROP INDEX");
1555		writer.push_space();
1556
1557		// IF EXISTS clause
1558		if stmt.if_exists {
1559			writer.push_keyword("IF EXISTS");
1560			writer.push_space();
1561		}
1562
1563		// Index name
1564		if let Some(name) = &stmt.name {
1565			writer.push_identifier(&name.to_string(), |s| self.escape_iden(s));
1566		}
1567
1568		// CASCADE/RESTRICT clause
1569		if stmt.cascade {
1570			writer.push_space();
1571			writer.push_keyword("CASCADE");
1572		} else if stmt.restrict {
1573			writer.push_space();
1574			writer.push_keyword("RESTRICT");
1575		}
1576
1577		writer.finish()
1578	}
1579
1580	fn build_create_view(&self, stmt: &CreateViewStatement) -> (String, Values) {
1581		let mut writer = SqlWriter::new();
1582
1583		writer.push("CREATE");
1584
1585		if stmt.or_replace {
1586			writer.push_keyword("OR REPLACE");
1587		}
1588
1589		if stmt.materialized {
1590			writer.push_keyword("MATERIALIZED");
1591		}
1592
1593		writer.push_keyword("VIEW");
1594
1595		if stmt.if_not_exists {
1596			writer.push_keyword("IF NOT EXISTS");
1597		}
1598
1599		if let Some(name) = &stmt.name {
1600			writer.push_space();
1601			writer.push_identifier(&name.to_string(), |s| self.escape_iden(s));
1602		}
1603
1604		if !stmt.columns.is_empty() {
1605			writer.push_space();
1606			writer.push("(");
1607			writer.push_list(stmt.columns.iter(), ", ", |w, col| {
1608				w.push_identifier(&col.to_string(), |s| self.escape_iden(s));
1609			});
1610			writer.push(")");
1611		}
1612
1613		writer.push_keyword("AS");
1614
1615		if let Some(select) = &stmt.select {
1616			let (select_sql, select_values) = self.build_select(select);
1617			writer.push_space();
1618			writer.push(&select_sql);
1619			writer.append_values(&select_values);
1620		}
1621
1622		writer.finish()
1623	}
1624
1625	fn build_drop_view(&self, stmt: &DropViewStatement) -> (String, Values) {
1626		let mut writer = SqlWriter::new();
1627
1628		writer.push("DROP");
1629
1630		if stmt.materialized {
1631			writer.push_keyword("MATERIALIZED");
1632		}
1633
1634		writer.push_keyword("VIEW");
1635
1636		if stmt.if_exists {
1637			writer.push_keyword("IF EXISTS");
1638		}
1639
1640		writer.push_space();
1641		writer.push_list(stmt.names.iter(), ", ", |w, name| {
1642			w.push_identifier(&name.to_string(), |s| self.escape_iden(s));
1643		});
1644
1645		if stmt.cascade {
1646			writer.push_keyword("CASCADE");
1647		} else if stmt.restrict {
1648			writer.push_keyword("RESTRICT");
1649		}
1650
1651		writer.finish()
1652	}
1653
1654	fn build_truncate_table(&self, stmt: &TruncateTableStatement) -> (String, Values) {
1655		let mut writer = SqlWriter::new();
1656
1657		// TRUNCATE TABLE
1658		writer.push("TRUNCATE TABLE");
1659		writer.push_space();
1660
1661		// Table names
1662		writer.push_list(&stmt.tables, ", ", |w, table_ref| {
1663			self.write_table_ref(w, table_ref);
1664		});
1665
1666		// RESTART IDENTITY clause (PostgreSQL-specific)
1667		if stmt.restart_identity {
1668			writer.push_space();
1669			writer.push_keyword("RESTART IDENTITY");
1670		}
1671
1672		// CASCADE/RESTRICT clause
1673		if stmt.cascade {
1674			writer.push_space();
1675			writer.push_keyword("CASCADE");
1676		} else if stmt.restrict {
1677			writer.push_space();
1678			writer.push_keyword("RESTRICT");
1679		}
1680
1681		writer.finish()
1682	}
1683
1684	fn build_create_trigger(&self, stmt: &CreateTriggerStatement) -> (String, Values) {
1685		use crate::types::{TriggerEvent, TriggerScope, TriggerTiming};
1686
1687		let mut writer = SqlWriter::new();
1688
1689		// CREATE TRIGGER
1690		writer.push("CREATE TRIGGER");
1691
1692		// Trigger name
1693		if let Some(name) = &stmt.name {
1694			writer.push_space();
1695			writer.push_identifier(&name.to_string(), |s| self.escape_iden(s));
1696		}
1697
1698		// Timing: BEFORE / AFTER / INSTEAD OF
1699		if let Some(timing) = stmt.timing {
1700			writer.push_space();
1701			match timing {
1702				TriggerTiming::Before => writer.push("BEFORE"),
1703				TriggerTiming::After => writer.push("AFTER"),
1704				TriggerTiming::InsteadOf => writer.push("INSTEAD OF"),
1705			}
1706		}
1707
1708		// Events: INSERT / UPDATE [OF columns] / DELETE
1709		if !stmt.events.is_empty() {
1710			writer.push_space();
1711			let mut first = true;
1712			for event in &stmt.events {
1713				if !first {
1714					writer.push(" OR ");
1715				}
1716				first = false;
1717
1718				match event {
1719					TriggerEvent::Insert => writer.push("INSERT"),
1720					TriggerEvent::Update { columns } => {
1721						writer.push("UPDATE");
1722						if let Some(cols) = columns {
1723							writer.push(" OF ");
1724							writer.push_list(cols.iter(), ", ", |w, col| {
1725								w.push_identifier(col, |s| self.escape_iden(s));
1726							});
1727						}
1728					}
1729					TriggerEvent::Delete => writer.push("DELETE"),
1730				}
1731			}
1732		}
1733
1734		// ON table
1735		writer.push_keyword("ON");
1736		if let Some(table) = &stmt.table {
1737			writer.push_space();
1738			self.write_table_ref(&mut writer, table);
1739		}
1740
1741		// FOR EACH ROW / FOR EACH STATEMENT
1742		if let Some(scope) = stmt.scope {
1743			writer.push_space();
1744			match scope {
1745				TriggerScope::Row => writer.push("FOR EACH ROW"),
1746				TriggerScope::Statement => writer.push("FOR EACH STATEMENT"),
1747			}
1748		}
1749
1750		// WHEN (condition)
1751		if let Some(when_cond) = &stmt.when_condition {
1752			writer.push_keyword("WHEN");
1753			writer.push(" (");
1754			self.write_simple_expr(&mut writer, when_cond);
1755			writer.push(")");
1756		}
1757
1758		// EXECUTE FUNCTION function_name() or EXECUTE PROCEDURE (older syntax)
1759		if let Some(body) = &stmt.body {
1760			writer.push_space();
1761			match body {
1762				TriggerBody::PostgresFunction(func_name) => {
1763					writer.push("EXECUTE FUNCTION ");
1764					writer.push_identifier(func_name.as_str(), |s| self.escape_iden(s));
1765					writer.push("()");
1766				}
1767				TriggerBody::Single(_) | TriggerBody::Multiple(_) => {
1768					panic!(
1769						"PostgreSQL triggers require EXECUTE FUNCTION, not inline SQL statements"
1770					);
1771				}
1772			}
1773		}
1774
1775		writer.finish()
1776	}
1777
1778	fn build_drop_trigger(&self, stmt: &DropTriggerStatement) -> (String, Values) {
1779		let mut writer = SqlWriter::new();
1780
1781		// DROP TRIGGER
1782		writer.push("DROP TRIGGER");
1783
1784		// IF EXISTS
1785		if stmt.if_exists {
1786			writer.push_keyword("IF EXISTS");
1787		}
1788
1789		// Trigger name
1790		if let Some(name) = &stmt.name {
1791			writer.push_space();
1792			writer.push_identifier(&name.to_string(), |s| self.escape_iden(s));
1793		}
1794
1795		// ON table (optional in PostgreSQL, but recommended)
1796		if let Some(table) = &stmt.table {
1797			writer.push_keyword("ON");
1798			writer.push_space();
1799			self.write_table_ref(&mut writer, table);
1800		}
1801
1802		// CASCADE / RESTRICT
1803		if stmt.cascade {
1804			writer.push_keyword("CASCADE");
1805		} else if stmt.restrict {
1806			writer.push_keyword("RESTRICT");
1807		}
1808
1809		writer.finish()
1810	}
1811
1812	fn build_alter_index(&self, stmt: &AlterIndexStatement) -> (String, Values) {
1813		use crate::types::Iden;
1814
1815		let mut writer = SqlWriter::new();
1816		writer.push_keyword("ALTER INDEX");
1817		writer.push_space();
1818
1819		if let Some(ref name) = stmt.name {
1820			writer.push_identifier(&Iden::to_string(name.as_ref()), |s| self.escape_iden(s));
1821		} else {
1822			panic!("ALTER INDEX requires an index name");
1823		}
1824
1825		// RENAME TO clause
1826		if let Some(ref new_name) = stmt.rename_to {
1827			writer.push_space();
1828			writer.push_keyword("RENAME TO");
1829			writer.push_space();
1830			writer.push_identifier(&Iden::to_string(new_name.as_ref()), |s| self.escape_iden(s));
1831		}
1832
1833		// SET TABLESPACE clause
1834		if let Some(ref tablespace) = stmt.set_tablespace {
1835			writer.push_space();
1836			writer.push_keyword("SET TABLESPACE");
1837			writer.push_space();
1838			writer.push_identifier(&Iden::to_string(tablespace.as_ref()), |s| {
1839				self.escape_iden(s)
1840			});
1841		}
1842
1843		writer.finish()
1844	}
1845
1846	fn build_reindex(&self, stmt: &ReindexStatement) -> (String, Values) {
1847		use crate::types::Iden;
1848
1849		let mut writer = SqlWriter::new();
1850		writer.push_keyword("REINDEX");
1851
1852		// Options (CONCURRENTLY, VERBOSE, TABLESPACE)
1853		let mut options = Vec::new();
1854		if stmt.concurrently {
1855			options.push("CONCURRENTLY".to_string());
1856		}
1857		if stmt.verbose {
1858			options.push("VERBOSE".to_string());
1859		}
1860		if let Some(ref tablespace) = stmt.tablespace {
1861			let escaped = self.escape_iden(&Iden::to_string(tablespace.as_ref()));
1862			options.push(format!("TABLESPACE {}", escaped));
1863		}
1864
1865		if !options.is_empty() {
1866			writer.push_space();
1867			writer.push("(");
1868			writer.push(&options.join(", "));
1869			writer.push(")");
1870		}
1871
1872		// Target (INDEX, TABLE, SCHEMA, DATABASE, SYSTEM)
1873		writer.push_space();
1874		if let Some(target) = stmt.target {
1875			use crate::query::ReindexTarget;
1876			match target {
1877				ReindexTarget::Index => writer.push_keyword("INDEX"),
1878				ReindexTarget::Table => writer.push_keyword("TABLE"),
1879				ReindexTarget::Schema => writer.push_keyword("SCHEMA"),
1880				ReindexTarget::Database => writer.push_keyword("DATABASE"),
1881				ReindexTarget::System => writer.push_keyword("SYSTEM"),
1882			}
1883		} else {
1884			panic!("REINDEX requires a target");
1885		}
1886
1887		// Name
1888		writer.push_space();
1889		if let Some(ref name) = stmt.name {
1890			writer.push_identifier(&Iden::to_string(name.as_ref()), |s| self.escape_iden(s));
1891		} else {
1892			panic!("REINDEX requires a name");
1893		}
1894
1895		writer.finish()
1896	}
1897
1898	fn build_optimize_table(&self, _stmt: &OptimizeTableStatement) -> (String, Values) {
1899		panic!(
1900			"OPTIMIZE TABLE is MySQL-specific. PostgreSQL users should use VACUUM ANALYZE instead."
1901		);
1902	}
1903
1904	fn build_repair_table(&self, _stmt: &RepairTableStatement) -> (String, Values) {
1905		panic!(
1906			"REPAIR TABLE is not supported in PostgreSQL. PostgreSQL automatically repairs corrupted data during normal operation."
1907		);
1908	}
1909
1910	fn build_check_table(&self, _stmt: &CheckTableStatement) -> (String, Values) {
1911		panic!(
1912			"CHECK TABLE is not supported in PostgreSQL. Use pg_catalog system views or pg_stat_* functions to monitor table health."
1913		);
1914	}
1915
1916	fn build_create_function(
1917		&self,
1918		stmt: &crate::query::CreateFunctionStatement,
1919	) -> (String, Values) {
1920		use crate::types::{
1921			Iden,
1922			function::{FunctionBehavior, FunctionLanguage, FunctionSecurity},
1923		};
1924
1925		let mut writer = SqlWriter::new();
1926
1927		// CREATE [OR REPLACE] FUNCTION
1928		writer.push_keyword("CREATE");
1929		if stmt.function_def.or_replace {
1930			writer.push_keyword("OR REPLACE");
1931		}
1932		writer.push_keyword("FUNCTION");
1933
1934		// Function name
1935		writer.push_space();
1936		writer.push_identifier(&Iden::to_string(stmt.function_def.name.as_ref()), |s| {
1937			self.escape_iden(s)
1938		});
1939
1940		// Parameters (param1 type1, param2 type2, ...)
1941		writer.push("(");
1942		let mut first = true;
1943		for param in &stmt.function_def.parameters {
1944			if !first {
1945				writer.push(", ");
1946			}
1947			first = false;
1948
1949			// Parameter mode (IN, OUT, INOUT, VARIADIC)
1950			if let Some(mode) = &param.mode {
1951				use crate::types::function::ParameterMode;
1952				match mode {
1953					ParameterMode::In => writer.push("IN "),
1954					ParameterMode::Out => writer.push("OUT "),
1955					ParameterMode::InOut => writer.push("INOUT "),
1956					ParameterMode::Variadic => writer.push("VARIADIC "),
1957				}
1958			}
1959
1960			// Parameter name (optional)
1961			if let Some(name) = &param.name {
1962				writer.push_identifier(&Iden::to_string(name.as_ref()), |s| self.escape_iden(s));
1963				writer.push(" ");
1964			}
1965
1966			// Parameter type
1967			if let Some(param_type) = &param.param_type {
1968				writer.push(param_type);
1969			}
1970
1971			// Default value (optional)
1972			if let Some(default) = &param.default_value {
1973				writer.push(" DEFAULT ");
1974				writer.push(default);
1975			}
1976		}
1977		writer.push(")");
1978
1979		// RETURNS type
1980		if let Some(returns) = &stmt.function_def.returns {
1981			writer.push_keyword("RETURNS");
1982			writer.push_space();
1983			writer.push(returns);
1984		}
1985
1986		// LANGUAGE
1987		if let Some(language) = &stmt.function_def.language {
1988			writer.push_keyword("LANGUAGE");
1989			writer.push_space();
1990			match language {
1991				FunctionLanguage::Sql => writer.push("SQL"),
1992				FunctionLanguage::PlPgSql => writer.push("PLPGSQL"),
1993				FunctionLanguage::C => writer.push("C"),
1994				FunctionLanguage::Custom(lang) => writer.push(lang),
1995			}
1996		}
1997
1998		// Behavior (IMMUTABLE/STABLE/VOLATILE)
1999		if let Some(behavior) = &stmt.function_def.behavior {
2000			writer.push_space();
2001			match behavior {
2002				FunctionBehavior::Immutable => writer.push_keyword("IMMUTABLE"),
2003				FunctionBehavior::Stable => writer.push_keyword("STABLE"),
2004				FunctionBehavior::Volatile => writer.push_keyword("VOLATILE"),
2005			}
2006		}
2007
2008		// Security (SECURITY DEFINER/INVOKER)
2009		if let Some(security) = &stmt.function_def.security {
2010			writer.push_space();
2011			match security {
2012				FunctionSecurity::Definer => writer.push_keyword("SECURITY DEFINER"),
2013				FunctionSecurity::Invoker => writer.push_keyword("SECURITY INVOKER"),
2014			}
2015		}
2016
2017		// AS 'body'
2018		if let Some(body) = &stmt.function_def.body {
2019			writer.push_keyword("AS");
2020			writer.push_space();
2021			let delimiter = generate_safe_dollar_quote_delimiter(body);
2022			writer.push(&delimiter);
2023			writer.push(body);
2024			writer.push(&delimiter);
2025		}
2026
2027		writer.finish()
2028	}
2029
2030	fn build_alter_function(
2031		&self,
2032		stmt: &crate::query::AlterFunctionStatement,
2033	) -> (String, Values) {
2034		use crate::query::function::alter_function::AlterFunctionOperation;
2035		use crate::types::{
2036			Iden,
2037			function::{FunctionBehavior, FunctionSecurity},
2038		};
2039
2040		let mut writer = SqlWriter::new();
2041
2042		// ALTER FUNCTION
2043		writer.push_keyword("ALTER FUNCTION");
2044
2045		// Function name
2046		if let Some(name) = &stmt.name {
2047			writer.push_space();
2048			writer.push_identifier(&Iden::to_string(name.as_ref()), |s| self.escape_iden(s));
2049		}
2050
2051		// Function signature (for overloaded functions)
2052		if !stmt.parameters.is_empty() {
2053			writer.push("(");
2054			let mut first = true;
2055			for param in &stmt.parameters {
2056				if !first {
2057					writer.push(", ");
2058				}
2059				first = false;
2060
2061				// Parameter name (optional in signature)
2062				if let Some(name) = &param.name {
2063					let name_str = Iden::to_string(name.as_ref());
2064					if !name_str.is_empty() {
2065						writer.push_identifier(&name_str, |s| self.escape_iden(s));
2066						writer.push(" ");
2067					}
2068				}
2069
2070				// Parameter type
2071				if let Some(param_type) = &param.param_type {
2072					writer.push(param_type);
2073				}
2074			}
2075			writer.push(")");
2076		}
2077
2078		// ALTER FUNCTION operation
2079		if let Some(operation) = &stmt.operation {
2080			writer.push_space();
2081			match operation {
2082				AlterFunctionOperation::RenameTo(new_name) => {
2083					writer.push_keyword("RENAME TO");
2084					writer.push_space();
2085					writer.push_identifier(&Iden::to_string(new_name.as_ref()), |s| {
2086						self.escape_iden(s)
2087					});
2088				}
2089				AlterFunctionOperation::OwnerTo(new_owner) => {
2090					writer.push_keyword("OWNER TO");
2091					writer.push_space();
2092					writer.push_identifier(&Iden::to_string(new_owner.as_ref()), |s| {
2093						self.escape_iden(s)
2094					});
2095				}
2096				AlterFunctionOperation::SetSchema(new_schema) => {
2097					writer.push_keyword("SET SCHEMA");
2098					writer.push_space();
2099					writer.push_identifier(&Iden::to_string(new_schema.as_ref()), |s| {
2100						self.escape_iden(s)
2101					});
2102				}
2103				AlterFunctionOperation::SetBehavior(behavior) => match behavior {
2104					FunctionBehavior::Immutable => writer.push_keyword("IMMUTABLE"),
2105					FunctionBehavior::Stable => writer.push_keyword("STABLE"),
2106					FunctionBehavior::Volatile => writer.push_keyword("VOLATILE"),
2107				},
2108				AlterFunctionOperation::SetSecurity(security) => match security {
2109					FunctionSecurity::Definer => writer.push_keyword("SECURITY DEFINER"),
2110					FunctionSecurity::Invoker => writer.push_keyword("SECURITY INVOKER"),
2111				},
2112			}
2113		}
2114
2115		writer.finish()
2116	}
2117
2118	fn build_drop_function(&self, stmt: &crate::query::DropFunctionStatement) -> (String, Values) {
2119		use crate::types::Iden;
2120
2121		let mut writer = SqlWriter::new();
2122
2123		// DROP FUNCTION
2124		writer.push_keyword("DROP FUNCTION");
2125
2126		// IF EXISTS
2127		if stmt.if_exists {
2128			writer.push_keyword("IF EXISTS");
2129		}
2130
2131		// Function name
2132		if let Some(name) = &stmt.name {
2133			writer.push_space();
2134			writer.push_identifier(&Iden::to_string(name.as_ref()), |s| self.escape_iden(s));
2135		}
2136
2137		// Function signature (for overloaded functions)
2138		if !stmt.parameters.is_empty() {
2139			writer.push("(");
2140			let mut first = true;
2141			for param in &stmt.parameters {
2142				if !first {
2143					writer.push(", ");
2144				}
2145				first = false;
2146
2147				// Parameter name (optional in signature)
2148				if let Some(name) = &param.name {
2149					let name_str = Iden::to_string(name.as_ref());
2150					if !name_str.is_empty() {
2151						writer.push_identifier(&name_str, |s| self.escape_iden(s));
2152						writer.push(" ");
2153					}
2154				}
2155
2156				// Parameter type
2157				if let Some(param_type) = &param.param_type {
2158					writer.push(param_type);
2159				}
2160			}
2161			writer.push(")");
2162		}
2163
2164		// CASCADE
2165		if stmt.cascade {
2166			writer.push_keyword("CASCADE");
2167		}
2168
2169		writer.finish()
2170	}
2171
2172	fn build_grant(&self, stmt: &crate::dcl::GrantStatement) -> (String, Values) {
2173		use crate::dcl::Grantee;
2174
2175		let mut writer = SqlWriter::new();
2176
2177		// GRANT keyword
2178		writer.push("GRANT");
2179		writer.push_space();
2180
2181		// Privileges
2182		writer.push_list(&stmt.privileges, ", ", |w, privilege| {
2183			w.push(privilege.as_sql());
2184		});
2185
2186		// ON clause
2187		writer.push_keyword("ON");
2188		writer.push_space();
2189		writer.push(stmt.object_type.as_sql());
2190		writer.push_space();
2191
2192		// Objects
2193		writer.push_list(&stmt.objects, ", ", |w, obj| {
2194			w.push_identifier(&obj.to_string(), |s| self.escape_iden(s));
2195		});
2196
2197		// TO clause
2198		writer.push_keyword("TO");
2199		writer.push_space();
2200
2201		// Grantees
2202		writer.push_list(&stmt.grantees, ", ", |w, grantee| {
2203			match grantee {
2204				Grantee::Role(name) => {
2205					w.push_identifier(name, |s| self.escape_iden(s));
2206				}
2207				Grantee::User(_, _) => {
2208					// MySQL-specific, not supported in PostgreSQL
2209					w.push_identifier("(UNSUPPORTED_USER)", |s| self.escape_iden(s));
2210				}
2211				Grantee::Public => {
2212					w.push("PUBLIC");
2213				}
2214				Grantee::CurrentRole => {
2215					w.push("CURRENT_ROLE");
2216				}
2217				Grantee::CurrentUser => {
2218					w.push("CURRENT_USER");
2219				}
2220				Grantee::SessionUser => {
2221					w.push("SESSION_USER");
2222				}
2223			}
2224		});
2225
2226		// WITH GRANT OPTION
2227		if stmt.with_grant_option {
2228			writer.push_keyword("WITH GRANT OPTION");
2229		}
2230
2231		// GRANTED BY clause
2232		if let Some(grantor) = &stmt.granted_by {
2233			writer.push_keyword("GRANTED BY");
2234			writer.push_space();
2235			match grantor {
2236				Grantee::Role(name) => {
2237					writer.push_identifier(name, |s| self.escape_iden(s));
2238				}
2239				Grantee::User(_, _) => {
2240					writer.push_identifier("(UNSUPPORTED_USER)", |s| self.escape_iden(s));
2241				}
2242				Grantee::Public => {
2243					writer.push("PUBLIC");
2244				}
2245				Grantee::CurrentRole => {
2246					writer.push("CURRENT_ROLE");
2247				}
2248				Grantee::CurrentUser => {
2249					writer.push("CURRENT_USER");
2250				}
2251				Grantee::SessionUser => {
2252					writer.push("SESSION_USER");
2253				}
2254			}
2255		}
2256
2257		writer.finish()
2258	}
2259
2260	fn build_revoke(&self, stmt: &crate::dcl::RevokeStatement) -> (String, Values) {
2261		use crate::dcl::Grantee;
2262
2263		let mut writer = SqlWriter::new();
2264
2265		// REVOKE keyword
2266		writer.push("REVOKE");
2267		writer.push_space();
2268
2269		// GRANT OPTION FOR (if specified)
2270		if stmt.grant_option_for {
2271			writer.push("GRANT OPTION FOR");
2272			writer.push_space();
2273		}
2274
2275		// Privileges
2276		writer.push_list(&stmt.privileges, ", ", |w, privilege| {
2277			w.push(privilege.as_sql());
2278		});
2279
2280		// ON clause
2281		writer.push_keyword("ON");
2282		writer.push_space();
2283		writer.push(stmt.object_type.as_sql());
2284		writer.push_space();
2285
2286		// Objects
2287		writer.push_list(&stmt.objects, ", ", |w, obj| {
2288			w.push_identifier(&obj.to_string(), |s| self.escape_iden(s));
2289		});
2290
2291		// FROM clause
2292		writer.push_keyword("FROM");
2293		writer.push_space();
2294
2295		// Grantees
2296		writer.push_list(&stmt.grantees, ", ", |w, grantee| {
2297			match grantee {
2298				Grantee::Role(name) => {
2299					w.push_identifier(name, |s| self.escape_iden(s));
2300				}
2301				Grantee::User(_, _) => {
2302					// MySQL-specific, not supported in PostgreSQL
2303					w.push_identifier("(UNSUPPORTED_USER)", |s| self.escape_iden(s));
2304				}
2305				Grantee::Public => {
2306					w.push("PUBLIC");
2307				}
2308				Grantee::CurrentRole => {
2309					w.push("CURRENT_ROLE");
2310				}
2311				Grantee::CurrentUser => {
2312					w.push("CURRENT_USER");
2313				}
2314				Grantee::SessionUser => {
2315					w.push("SESSION_USER");
2316				}
2317			}
2318		});
2319
2320		// CASCADE / RESTRICT
2321		if stmt.cascade {
2322			writer.push_keyword("CASCADE");
2323		}
2324
2325		writer.finish()
2326	}
2327
2328	fn build_grant_role(&self, stmt: &crate::dcl::GrantRoleStatement) -> (String, Values) {
2329		let mut writer = SqlWriter::new();
2330
2331		// GRANT keyword
2332		writer.push("GRANT");
2333		writer.push_space();
2334
2335		// Roles (comma-separated list)
2336		writer.push_list(&stmt.roles, ", ", |w, role| {
2337			w.push_identifier(role, |s| self.escape_iden(s));
2338		});
2339
2340		// TO clause
2341		writer.push_keyword("TO");
2342		writer.push_space();
2343
2344		// Grantees
2345		writer.push_list(&stmt.grantees, ", ", |w, grantee| {
2346			w.push(Self::format_role_specification(grantee));
2347		});
2348
2349		// WITH ADMIN OPTION
2350		if stmt.with_admin_option {
2351			writer.push_keyword("WITH ADMIN OPTION");
2352		}
2353
2354		// GRANTED BY
2355		if let Some(ref grantor) = stmt.granted_by {
2356			writer.push_keyword("GRANTED BY");
2357			writer.push_space();
2358			writer.push(Self::format_role_specification(grantor));
2359		}
2360
2361		writer.finish()
2362	}
2363
2364	fn build_revoke_role(&self, stmt: &crate::dcl::RevokeRoleStatement) -> (String, Values) {
2365		use crate::dcl::DropBehavior;
2366
2367		let mut writer = SqlWriter::new();
2368
2369		// REVOKE keyword
2370		writer.push("REVOKE");
2371		writer.push_space();
2372
2373		// ADMIN OPTION FOR
2374		if stmt.admin_option_for {
2375			writer.push("ADMIN OPTION FOR");
2376			writer.push_space();
2377		}
2378
2379		// Roles (comma-separated list)
2380		writer.push_list(&stmt.roles, ", ", |w, role| {
2381			w.push_identifier(role, |s| self.escape_iden(s));
2382		});
2383
2384		// FROM clause
2385		writer.push_keyword("FROM");
2386		writer.push_space();
2387
2388		// Grantees
2389		writer.push_list(&stmt.grantees, ", ", |w, grantee| {
2390			w.push(Self::format_role_specification(grantee));
2391		});
2392
2393		// GRANTED BY
2394		if let Some(ref grantor) = stmt.granted_by {
2395			writer.push_keyword("GRANTED BY");
2396			writer.push_space();
2397			writer.push(Self::format_role_specification(grantor));
2398		}
2399
2400		// CASCADE / RESTRICT
2401		if let Some(behavior) = stmt.drop_behavior {
2402			match behavior {
2403				DropBehavior::Cascade => writer.push_keyword("CASCADE"),
2404				DropBehavior::Restrict => writer.push_keyword("RESTRICT"),
2405			}
2406		}
2407
2408		writer.finish()
2409	}
2410
2411	fn build_create_role(&self, stmt: &crate::dcl::CreateRoleStatement) -> (String, Values) {
2412		use crate::dcl::RoleAttribute;
2413		use crate::value::Value;
2414
2415		let mut writer = SqlWriter::new();
2416
2417		// CREATE ROLE keyword
2418		writer.push("CREATE ROLE");
2419		writer.push_space();
2420
2421		// Role name
2422		writer.push_identifier(&stmt.role_name, |s| self.escape_iden(s));
2423
2424		// WITH keyword (optional but commonly used)
2425		if !stmt.attributes.is_empty() {
2426			writer.push_keyword("WITH");
2427		}
2428
2429		// Attributes
2430		for attr in &stmt.attributes {
2431			writer.push_space();
2432			match attr {
2433				RoleAttribute::SuperUser => writer.push("SUPERUSER"),
2434				RoleAttribute::NoSuperUser => writer.push("NOSUPERUSER"),
2435				RoleAttribute::CreateDb => writer.push("CREATEDB"),
2436				RoleAttribute::NoCreateDb => writer.push("NOCREATEDB"),
2437				RoleAttribute::CreateRole => writer.push("CREATEROLE"),
2438				RoleAttribute::NoCreateRole => writer.push("NOCREATEROLE"),
2439				RoleAttribute::Inherit => writer.push("INHERIT"),
2440				RoleAttribute::NoInherit => writer.push("NOINHERIT"),
2441				RoleAttribute::Login => writer.push("LOGIN"),
2442				RoleAttribute::NoLogin => writer.push("NOLOGIN"),
2443				RoleAttribute::Replication => writer.push("REPLICATION"),
2444				RoleAttribute::NoReplication => writer.push("NOREPLICATION"),
2445				RoleAttribute::BypassRls => writer.push("BYPASSRLS"),
2446				RoleAttribute::NoBypassRls => writer.push("NOBYPASSRLS"),
2447				RoleAttribute::ConnectionLimit(limit) => {
2448					writer.push("CONNECTION LIMIT");
2449					writer.push_space();
2450					writer.push(&limit.to_string());
2451				}
2452				RoleAttribute::Password(pwd) => {
2453					writer.push("PASSWORD");
2454					writer.push_space();
2455					writer.push_value(Value::String(Some(Box::new(pwd.clone()))), |i| {
2456						self.placeholder(i)
2457					});
2458				}
2459				RoleAttribute::EncryptedPassword(pwd) => {
2460					writer.push("ENCRYPTED PASSWORD");
2461					writer.push_space();
2462					writer.push_value(Value::String(Some(Box::new(pwd.clone()))), |i| {
2463						self.placeholder(i)
2464					});
2465				}
2466				RoleAttribute::UnencryptedPassword(pwd) => {
2467					writer.push("UNENCRYPTED PASSWORD");
2468					writer.push_space();
2469					writer.push_value(Value::String(Some(Box::new(pwd.clone()))), |i| {
2470						self.placeholder(i)
2471					});
2472				}
2473				RoleAttribute::ValidUntil(timestamp) => {
2474					writer.push("VALID UNTIL");
2475					writer.push_space();
2476					writer.push("'");
2477					writer.push(timestamp);
2478					writer.push("'");
2479				}
2480				RoleAttribute::InRole(roles) => {
2481					writer.push("IN ROLE");
2482					writer.push_space();
2483					writer.push_list(roles, ", ", |w, role| {
2484						w.push_identifier(role, |s| self.escape_iden(s));
2485					});
2486				}
2487				RoleAttribute::Role(roles) => {
2488					writer.push("ROLE");
2489					writer.push_space();
2490					writer.push_list(roles, ", ", |w, role| {
2491						w.push_identifier(role, |s| self.escape_iden(s));
2492					});
2493				}
2494				RoleAttribute::Admin(roles) => {
2495					writer.push("ADMIN");
2496					writer.push_space();
2497					writer.push_list(roles, ", ", |w, role| {
2498						w.push_identifier(role, |s| self.escape_iden(s));
2499					});
2500				}
2501			}
2502		}
2503
2504		writer.finish()
2505	}
2506
2507	fn build_drop_role(&self, stmt: &crate::dcl::DropRoleStatement) -> (String, Values) {
2508		let mut writer = SqlWriter::new();
2509
2510		// DROP ROLE keyword
2511		writer.push("DROP ROLE");
2512		writer.push_space();
2513
2514		// IF EXISTS clause
2515		if stmt.if_exists {
2516			writer.push("IF EXISTS");
2517			writer.push_space();
2518		}
2519
2520		// Role names (comma-separated)
2521		writer.push_list(&stmt.role_names, ", ", |w, role_name| {
2522			w.push_identifier(role_name, |s| self.escape_iden(s));
2523		});
2524
2525		writer.finish()
2526	}
2527
2528	fn build_alter_role(&self, stmt: &crate::dcl::AlterRoleStatement) -> (String, Values) {
2529		use crate::dcl::RoleAttribute;
2530		use crate::value::Value;
2531
2532		let mut writer = SqlWriter::new();
2533
2534		// Check for RENAME TO (special case in PostgreSQL)
2535		if let Some(ref new_name) = stmt.rename_to {
2536			writer.push("ALTER ROLE");
2537			writer.push_space();
2538			writer.push_identifier(&stmt.role_name, |s| self.escape_iden(s));
2539			writer.push_keyword("RENAME TO");
2540			writer.push_space();
2541			writer.push_identifier(new_name, |s| self.escape_iden(s));
2542			return writer.finish();
2543		}
2544
2545		// ALTER ROLE keyword
2546		writer.push("ALTER ROLE");
2547		writer.push_space();
2548
2549		// Role name
2550		writer.push_identifier(&stmt.role_name, |s| self.escape_iden(s));
2551
2552		// WITH keyword (optional but commonly used)
2553		if !stmt.attributes.is_empty() {
2554			writer.push_keyword("WITH");
2555		}
2556
2557		// Attributes (same as CREATE ROLE)
2558		for attr in &stmt.attributes {
2559			writer.push_space();
2560			match attr {
2561				RoleAttribute::SuperUser => writer.push("SUPERUSER"),
2562				RoleAttribute::NoSuperUser => writer.push("NOSUPERUSER"),
2563				RoleAttribute::CreateDb => writer.push("CREATEDB"),
2564				RoleAttribute::NoCreateDb => writer.push("NOCREATEDB"),
2565				RoleAttribute::CreateRole => writer.push("CREATEROLE"),
2566				RoleAttribute::NoCreateRole => writer.push("NOCREATEROLE"),
2567				RoleAttribute::Inherit => writer.push("INHERIT"),
2568				RoleAttribute::NoInherit => writer.push("NOINHERIT"),
2569				RoleAttribute::Login => writer.push("LOGIN"),
2570				RoleAttribute::NoLogin => writer.push("NOLOGIN"),
2571				RoleAttribute::Replication => writer.push("REPLICATION"),
2572				RoleAttribute::NoReplication => writer.push("NOREPLICATION"),
2573				RoleAttribute::BypassRls => writer.push("BYPASSRLS"),
2574				RoleAttribute::NoBypassRls => writer.push("NOBYPASSRLS"),
2575				RoleAttribute::ConnectionLimit(limit) => {
2576					writer.push("CONNECTION LIMIT");
2577					writer.push_space();
2578					writer.push(&limit.to_string());
2579				}
2580				RoleAttribute::Password(pwd) => {
2581					writer.push("PASSWORD");
2582					writer.push_space();
2583					writer.push_value(Value::String(Some(Box::new(pwd.clone()))), |i| {
2584						self.placeholder(i)
2585					});
2586				}
2587				RoleAttribute::EncryptedPassword(pwd) => {
2588					writer.push("ENCRYPTED PASSWORD");
2589					writer.push_space();
2590					writer.push_value(Value::String(Some(Box::new(pwd.clone()))), |i| {
2591						self.placeholder(i)
2592					});
2593				}
2594				RoleAttribute::UnencryptedPassword(pwd) => {
2595					writer.push("UNENCRYPTED PASSWORD");
2596					writer.push_space();
2597					writer.push_value(Value::String(Some(Box::new(pwd.clone()))), |i| {
2598						self.placeholder(i)
2599					});
2600				}
2601				RoleAttribute::ValidUntil(timestamp) => {
2602					writer.push("VALID UNTIL");
2603					writer.push_space();
2604					writer.push("'");
2605					writer.push(timestamp);
2606					writer.push("'");
2607				}
2608				RoleAttribute::InRole(roles) => {
2609					writer.push("IN ROLE");
2610					writer.push_space();
2611					writer.push_list(roles, ", ", |w, role| {
2612						w.push_identifier(role, |s| self.escape_iden(s));
2613					});
2614				}
2615				RoleAttribute::Role(roles) => {
2616					writer.push("ROLE");
2617					writer.push_space();
2618					writer.push_list(roles, ", ", |w, role| {
2619						w.push_identifier(role, |s| self.escape_iden(s));
2620					});
2621				}
2622				RoleAttribute::Admin(roles) => {
2623					writer.push("ADMIN");
2624					writer.push_space();
2625					writer.push_list(roles, ", ", |w, role| {
2626						w.push_identifier(role, |s| self.escape_iden(s));
2627					});
2628				}
2629			}
2630		}
2631
2632		writer.finish()
2633	}
2634
2635	fn build_create_user(&self, stmt: &crate::dcl::CreateUserStatement) -> (String, Values) {
2636		use crate::dcl::{CreateRoleStatement, RoleAttribute};
2637
2638		// PostgreSQL CREATE USER is CREATE ROLE WITH LOGIN
2639		let mut create_role = CreateRoleStatement::new()
2640			.role(&stmt.user_name)
2641			.attribute(RoleAttribute::Login);
2642
2643		// Add all attributes from CREATE USER
2644		for attr in &stmt.attributes {
2645			create_role = create_role.attribute(attr.clone());
2646		}
2647
2648		// Use build_create_role to generate the SQL
2649		self.build_create_role(&create_role)
2650	}
2651
2652	fn build_drop_user(&self, stmt: &crate::dcl::DropUserStatement) -> (String, Values) {
2653		use crate::dcl::DropRoleStatement;
2654
2655		// PostgreSQL DROP USER is DROP ROLE
2656		let mut drop_role = DropRoleStatement::new();
2657		drop_role.role_names = stmt.user_names.clone();
2658		drop_role.if_exists = stmt.if_exists;
2659
2660		// Use build_drop_role to generate the SQL
2661		self.build_drop_role(&drop_role)
2662	}
2663
2664	fn build_alter_user(&self, stmt: &crate::dcl::AlterUserStatement) -> (String, Values) {
2665		use crate::dcl::AlterRoleStatement;
2666
2667		// PostgreSQL ALTER USER is ALTER ROLE
2668		let mut alter_role = AlterRoleStatement::new().role(&stmt.user_name);
2669
2670		// Add all attributes from ALTER USER
2671		for attr in &stmt.attributes {
2672			alter_role = alter_role.attribute(attr.clone());
2673		}
2674
2675		// Use build_alter_role to generate the SQL
2676		self.build_alter_role(&alter_role)
2677	}
2678
2679	fn build_rename_user(&self, _stmt: &crate::dcl::RenameUserStatement) -> (String, Values) {
2680		panic!("RENAME USER is not supported by PostgreSQL. Use ALTER USER ... RENAME TO instead.");
2681	}
2682
2683	fn build_set_role(&self, stmt: &crate::dcl::SetRoleStatement) -> (String, Values) {
2684		use crate::dcl::RoleTarget;
2685
2686		let mut writer = SqlWriter::new();
2687
2688		writer.push("SET ROLE");
2689		writer.push_space();
2690
2691		match &stmt.target {
2692			Some(RoleTarget::Named(name)) => {
2693				writer.push_identifier(name, |s| self.escape_iden(s));
2694			}
2695			Some(RoleTarget::None) => {
2696				writer.push("NONE");
2697			}
2698			Some(RoleTarget::All) => {
2699				panic!("SET ROLE ALL is not supported by PostgreSQL (MySQL only)");
2700			}
2701			Some(RoleTarget::AllExcept(_)) => {
2702				panic!("SET ROLE ALL EXCEPT is not supported by PostgreSQL (MySQL only)");
2703			}
2704			Some(RoleTarget::Default) => {
2705				panic!("SET ROLE DEFAULT is not supported by PostgreSQL (MySQL only)");
2706			}
2707			None => {
2708				panic!("SET ROLE requires a role target");
2709			}
2710		}
2711
2712		writer.finish()
2713	}
2714
2715	fn build_reset_role(&self, _stmt: &crate::dcl::ResetRoleStatement) -> (String, Values) {
2716		let mut writer = SqlWriter::new();
2717		writer.push("RESET ROLE");
2718		writer.finish()
2719	}
2720
2721	fn build_set_default_role(
2722		&self,
2723		_stmt: &crate::dcl::SetDefaultRoleStatement,
2724	) -> (String, Values) {
2725		panic!("SET DEFAULT ROLE is not supported by PostgreSQL (MySQL only)");
2726	}
2727
2728	fn escape_identifier(&self, ident: &str) -> String {
2729		self.escape_iden(ident)
2730	}
2731
2732	fn format_placeholder(&self, index: usize) -> String {
2733		self.placeholder(index)
2734	}
2735
2736	fn build_create_schema(&self, stmt: &crate::query::CreateSchemaStatement) -> (String, Values) {
2737		use crate::types::Iden;
2738
2739		let mut writer = SqlWriter::new();
2740
2741		// CREATE SCHEMA
2742		writer.push_keyword("CREATE SCHEMA");
2743
2744		// IF NOT EXISTS
2745		if stmt.if_not_exists {
2746			writer.push_keyword("IF NOT EXISTS");
2747		}
2748
2749		// Schema name
2750		if let Some(name) = &stmt.schema_name {
2751			writer.push_space();
2752			writer.push_identifier(&Iden::to_string(name.as_ref()), |s| self.escape_iden(s));
2753		}
2754
2755		// AUTHORIZATION owner
2756		if let Some(owner) = &stmt.authorization {
2757			writer.push_keyword("AUTHORIZATION");
2758			writer.push_space();
2759			writer.push_identifier(&Iden::to_string(owner.as_ref()), |s| self.escape_iden(s));
2760		}
2761
2762		writer.finish()
2763	}
2764
2765	fn build_alter_schema(&self, stmt: &crate::query::AlterSchemaStatement) -> (String, Values) {
2766		use crate::query::AlterSchemaOperation;
2767		use crate::types::Iden;
2768
2769		let mut writer = SqlWriter::new();
2770
2771		// ALTER SCHEMA
2772		writer.push_keyword("ALTER SCHEMA");
2773
2774		// Schema name
2775		if let Some(name) = &stmt.schema_name {
2776			writer.push_space();
2777			writer.push_identifier(&Iden::to_string(name.as_ref()), |s| self.escape_iden(s));
2778		}
2779
2780		// Operation
2781		if let Some(operation) = &stmt.operation {
2782			writer.push_space();
2783			match operation {
2784				AlterSchemaOperation::RenameTo(new_name) => {
2785					writer.push_keyword("RENAME TO");
2786					writer.push_space();
2787					writer.push_identifier(&Iden::to_string(new_name.as_ref()), |s| {
2788						self.escape_iden(s)
2789					});
2790				}
2791				AlterSchemaOperation::OwnerTo(new_owner) => {
2792					writer.push_keyword("OWNER TO");
2793					writer.push_space();
2794					writer.push_identifier(&Iden::to_string(new_owner.as_ref()), |s| {
2795						self.escape_iden(s)
2796					});
2797				}
2798			}
2799		}
2800
2801		writer.finish()
2802	}
2803
2804	fn build_drop_schema(&self, stmt: &crate::query::DropSchemaStatement) -> (String, Values) {
2805		use crate::types::Iden;
2806
2807		let mut writer = SqlWriter::new();
2808
2809		// DROP SCHEMA
2810		writer.push_keyword("DROP SCHEMA");
2811
2812		// IF EXISTS
2813		if stmt.if_exists {
2814			writer.push_keyword("IF EXISTS");
2815		}
2816
2817		// Schema name
2818		if let Some(name) = &stmt.schema_name {
2819			writer.push_space();
2820			writer.push_identifier(&Iden::to_string(name.as_ref()), |s| self.escape_iden(s));
2821		}
2822
2823		// CASCADE or RESTRICT
2824		if stmt.cascade {
2825			writer.push_keyword("CASCADE");
2826		}
2827
2828		writer.finish()
2829	}
2830
2831	fn build_create_sequence(
2832		&self,
2833		stmt: &crate::query::CreateSequenceStatement,
2834	) -> (String, Values) {
2835		use crate::types::{Iden, sequence::OwnedBy};
2836
2837		let mut writer = SqlWriter::new();
2838		let seq_def = &stmt.sequence_def;
2839
2840		// CREATE SEQUENCE
2841		writer.push_keyword("CREATE SEQUENCE");
2842
2843		// IF NOT EXISTS
2844		if seq_def.if_not_exists {
2845			writer.push_keyword("IF NOT EXISTS");
2846		}
2847
2848		// Sequence name
2849		writer.push_space();
2850		writer.push_identifier(&Iden::to_string(seq_def.name.as_ref()), |s| {
2851			self.escape_iden(s)
2852		});
2853
2854		// INCREMENT BY
2855		if let Some(increment) = seq_def.increment {
2856			writer.push_keyword("INCREMENT BY");
2857			writer.push_space();
2858			writer.push(&increment.to_string());
2859		}
2860
2861		// MINVALUE or NO MINVALUE
2862		if let Some(min_value) = &seq_def.min_value {
2863			writer.push_space();
2864			match min_value {
2865				Some(val) => {
2866					writer.push_keyword("MINVALUE");
2867					writer.push_space();
2868					writer.push(&val.to_string());
2869				}
2870				None => {
2871					writer.push_keyword("NO MINVALUE");
2872				}
2873			}
2874		}
2875
2876		// MAXVALUE or NO MAXVALUE
2877		if let Some(max_value) = &seq_def.max_value {
2878			writer.push_space();
2879			match max_value {
2880				Some(val) => {
2881					writer.push_keyword("MAXVALUE");
2882					writer.push_space();
2883					writer.push(&val.to_string());
2884				}
2885				None => {
2886					writer.push_keyword("NO MAXVALUE");
2887				}
2888			}
2889		}
2890
2891		// START WITH
2892		if let Some(start) = seq_def.start {
2893			writer.push_keyword("START WITH");
2894			writer.push_space();
2895			writer.push(&start.to_string());
2896		}
2897
2898		// CACHE
2899		if let Some(cache) = seq_def.cache {
2900			writer.push_keyword("CACHE");
2901			writer.push_space();
2902			writer.push(&cache.to_string());
2903		}
2904
2905		// CYCLE or NO CYCLE
2906		if let Some(cycle) = seq_def.cycle {
2907			writer.push_space();
2908			if cycle {
2909				writer.push_keyword("CYCLE");
2910			} else {
2911				writer.push_keyword("NO CYCLE");
2912			}
2913		}
2914
2915		// OWNED BY
2916		if let Some(owned_by) = &seq_def.owned_by {
2917			writer.push_keyword("OWNED BY");
2918			writer.push_space();
2919			match owned_by {
2920				OwnedBy::Column { table, column } => {
2921					writer
2922						.push_identifier(&Iden::to_string(table.as_ref()), |s| self.escape_iden(s));
2923					writer.push(".");
2924					writer.push_identifier(&Iden::to_string(column.as_ref()), |s| {
2925						self.escape_iden(s)
2926					});
2927				}
2928				OwnedBy::None => {
2929					writer.push_keyword("NONE");
2930				}
2931			}
2932		}
2933
2934		writer.finish()
2935	}
2936
2937	fn build_alter_sequence(
2938		&self,
2939		stmt: &crate::query::AlterSequenceStatement,
2940	) -> (String, Values) {
2941		use crate::types::{
2942			Iden,
2943			sequence::{OwnedBy, SequenceOption},
2944		};
2945
2946		let mut writer = SqlWriter::new();
2947
2948		// ALTER SEQUENCE
2949		writer.push_keyword("ALTER SEQUENCE");
2950
2951		// Sequence name
2952		writer.push_space();
2953		writer.push_identifier(&Iden::to_string(stmt.name.as_ref()), |s| {
2954			self.escape_iden(s)
2955		});
2956
2957		// Options
2958		for option in &stmt.options {
2959			writer.push_space();
2960			match option {
2961				SequenceOption::Restart(value) => {
2962					writer.push_keyword("RESTART");
2963					if let Some(val) = value {
2964						writer.push_keyword("WITH");
2965						writer.push_space();
2966						writer.push(&val.to_string());
2967					}
2968				}
2969				SequenceOption::IncrementBy(value) => {
2970					writer.push_keyword("INCREMENT BY");
2971					writer.push_space();
2972					writer.push(&value.to_string());
2973				}
2974				SequenceOption::MinValue(value) => {
2975					writer.push_keyword("MINVALUE");
2976					writer.push_space();
2977					writer.push(&value.to_string());
2978				}
2979				SequenceOption::NoMinValue => {
2980					writer.push_keyword("NO MINVALUE");
2981				}
2982				SequenceOption::MaxValue(value) => {
2983					writer.push_keyword("MAXVALUE");
2984					writer.push_space();
2985					writer.push(&value.to_string());
2986				}
2987				SequenceOption::NoMaxValue => {
2988					writer.push_keyword("NO MAXVALUE");
2989				}
2990				SequenceOption::Cache(value) => {
2991					writer.push_keyword("CACHE");
2992					writer.push_space();
2993					writer.push(&value.to_string());
2994				}
2995				SequenceOption::Cycle => {
2996					writer.push_keyword("CYCLE");
2997				}
2998				SequenceOption::NoCycle => {
2999					writer.push_keyword("NO CYCLE");
3000				}
3001				SequenceOption::OwnedBy(owned_by) => {
3002					writer.push_keyword("OWNED BY");
3003					writer.push_space();
3004					match owned_by {
3005						OwnedBy::Column { table, column } => {
3006							writer.push_identifier(&Iden::to_string(table.as_ref()), |s| {
3007								self.escape_iden(s)
3008							});
3009							writer.push(".");
3010							writer.push_identifier(&Iden::to_string(column.as_ref()), |s| {
3011								self.escape_iden(s)
3012							});
3013						}
3014						OwnedBy::None => {
3015							writer.push_keyword("NONE");
3016						}
3017					}
3018				}
3019			}
3020		}
3021
3022		writer.finish()
3023	}
3024
3025	fn build_drop_sequence(&self, stmt: &crate::query::DropSequenceStatement) -> (String, Values) {
3026		use crate::types::Iden;
3027
3028		let mut writer = SqlWriter::new();
3029
3030		// DROP SEQUENCE
3031		writer.push_keyword("DROP SEQUENCE");
3032
3033		// IF EXISTS
3034		if stmt.if_exists {
3035			writer.push_keyword("IF EXISTS");
3036		}
3037
3038		// Sequence name
3039		writer.push_space();
3040		writer.push_identifier(&Iden::to_string(stmt.name.as_ref()), |s| {
3041			self.escape_iden(s)
3042		});
3043
3044		// CASCADE or RESTRICT
3045		if stmt.cascade {
3046			writer.push_keyword("CASCADE");
3047		} else if stmt.restrict {
3048			writer.push_keyword("RESTRICT");
3049		}
3050
3051		writer.finish()
3052	}
3053
3054	fn build_comment(&self, stmt: &crate::query::CommentStatement) -> (String, Values) {
3055		use crate::types::{CommentTarget, Iden};
3056
3057		let mut writer = SqlWriter::new();
3058
3059		// COMMENT ON
3060		writer.push_keyword("COMMENT ON");
3061
3062		// Target object type and name
3063		if let Some(target) = &stmt.target {
3064			writer.push_space();
3065			match target {
3066				CommentTarget::Table(table) => {
3067					writer.push_keyword("TABLE");
3068					writer.push_space();
3069					writer
3070						.push_identifier(&Iden::to_string(table.as_ref()), |s| self.escape_iden(s));
3071				}
3072				CommentTarget::Column(table, column) => {
3073					writer.push_keyword("COLUMN");
3074					writer.push_space();
3075					writer
3076						.push_identifier(&Iden::to_string(table.as_ref()), |s| self.escape_iden(s));
3077					writer.push(".");
3078					writer.push_identifier(&Iden::to_string(column.as_ref()), |s| {
3079						self.escape_iden(s)
3080					});
3081				}
3082				CommentTarget::Index(index) => {
3083					writer.push_keyword("INDEX");
3084					writer.push_space();
3085					writer
3086						.push_identifier(&Iden::to_string(index.as_ref()), |s| self.escape_iden(s));
3087				}
3088				CommentTarget::View(view) => {
3089					writer.push_keyword("VIEW");
3090					writer.push_space();
3091					writer
3092						.push_identifier(&Iden::to_string(view.as_ref()), |s| self.escape_iden(s));
3093				}
3094				CommentTarget::MaterializedView(view) => {
3095					writer.push_keyword("MATERIALIZED VIEW");
3096					writer.push_space();
3097					writer
3098						.push_identifier(&Iden::to_string(view.as_ref()), |s| self.escape_iden(s));
3099				}
3100				CommentTarget::Sequence(seq) => {
3101					writer.push_keyword("SEQUENCE");
3102					writer.push_space();
3103					writer.push_identifier(&Iden::to_string(seq.as_ref()), |s| self.escape_iden(s));
3104				}
3105				CommentTarget::Schema(schema) => {
3106					writer.push_keyword("SCHEMA");
3107					writer.push_space();
3108					writer.push_identifier(&Iden::to_string(schema.as_ref()), |s| {
3109						self.escape_iden(s)
3110					});
3111				}
3112				CommentTarget::Database(db) => {
3113					writer.push_keyword("DATABASE");
3114					writer.push_space();
3115					writer.push_identifier(&Iden::to_string(db.as_ref()), |s| self.escape_iden(s));
3116				}
3117				CommentTarget::Function(func) => {
3118					writer.push_keyword("FUNCTION");
3119					writer.push_space();
3120					writer
3121						.push_identifier(&Iden::to_string(func.as_ref()), |s| self.escape_iden(s));
3122				}
3123				CommentTarget::Trigger(trigger, table) => {
3124					writer.push_keyword("TRIGGER");
3125					writer.push_space();
3126					writer.push_identifier(&Iden::to_string(trigger.as_ref()), |s| {
3127						self.escape_iden(s)
3128					});
3129					writer.push_keyword("ON");
3130					writer.push_space();
3131					writer
3132						.push_identifier(&Iden::to_string(table.as_ref()), |s| self.escape_iden(s));
3133				}
3134				CommentTarget::Type(typ) => {
3135					writer.push_keyword("TYPE");
3136					writer.push_space();
3137					writer.push_identifier(&Iden::to_string(typ.as_ref()), |s| self.escape_iden(s));
3138				}
3139			}
3140		}
3141
3142		// IS 'comment' or IS NULL
3143		writer.push_keyword("IS");
3144		writer.push_space();
3145		if stmt.is_null {
3146			writer.push_keyword("NULL");
3147		} else if let Some(comment) = &stmt.comment {
3148			// Escape single quotes in comment text
3149			let escaped = comment.replace('\'', "''");
3150			writer.push(&format!("'{}'", escaped));
3151		}
3152
3153		writer.finish()
3154	}
3155
3156	fn build_create_database(
3157		&self,
3158		stmt: &crate::query::CreateDatabaseStatement,
3159	) -> (String, Values) {
3160		use crate::types::Iden;
3161
3162		let mut writer = SqlWriter::new();
3163
3164		// CREATE DATABASE
3165		writer.push_keyword("CREATE DATABASE");
3166
3167		// IF NOT EXISTS - PostgreSQL does not support IF NOT EXISTS for CREATE DATABASE
3168		// if stmt.if_not_exists {
3169		//     writer.push_keyword("IF NOT EXISTS");
3170		// }
3171
3172		// Database name
3173		if let Some(name) = &stmt.database_name {
3174			writer.push_space();
3175			writer.push_identifier(&Iden::to_string(name.as_ref()), |s| self.escape_iden(s));
3176		}
3177
3178		// OWNER
3179		if let Some(owner) = &stmt.owner {
3180			writer.push_keyword("OWNER");
3181			writer.push_space();
3182			writer.push_identifier(&Iden::to_string(owner.as_ref()), |s| self.escape_iden(s));
3183		}
3184
3185		// TEMPLATE
3186		if let Some(template) = &stmt.template {
3187			writer.push_keyword("TEMPLATE");
3188			writer.push_space();
3189			writer.push_identifier(&Iden::to_string(template.as_ref()), |s| self.escape_iden(s));
3190		}
3191
3192		// ENCODING
3193		if let Some(encoding) = &stmt.encoding {
3194			writer.push_keyword("ENCODING");
3195			writer.push_space();
3196			let escaped = encoding.replace('\'', "''");
3197			writer.push(&format!("'{}'", escaped));
3198		}
3199
3200		// LC_COLLATE
3201		if let Some(lc_collate) = &stmt.lc_collate {
3202			writer.push_keyword("LC_COLLATE");
3203			writer.push_space();
3204			let escaped = lc_collate.replace('\'', "''");
3205			writer.push(&format!("'{}'", escaped));
3206		}
3207
3208		// LC_CTYPE
3209		if let Some(lc_ctype) = &stmt.lc_ctype {
3210			writer.push_keyword("LC_CTYPE");
3211			writer.push_space();
3212			let escaped = lc_ctype.replace('\'', "''");
3213			writer.push(&format!("'{}'", escaped));
3214		}
3215
3216		writer.finish()
3217	}
3218
3219	fn build_alter_database(
3220		&self,
3221		stmt: &crate::query::AlterDatabaseStatement,
3222	) -> (String, Values) {
3223		use crate::types::{DatabaseOperation, Iden};
3224
3225		let mut writer = SqlWriter::new();
3226
3227		// ALTER DATABASE
3228		writer.push_keyword("ALTER DATABASE");
3229
3230		// Database name
3231		if let Some(name) = &stmt.database_name {
3232			writer.push_space();
3233			writer.push_identifier(&Iden::to_string(name.as_ref()), |s| self.escape_iden(s));
3234		}
3235
3236		// Operations
3237		for (i, operation) in stmt.operations.iter().enumerate() {
3238			if i == 0 {
3239				writer.push_space();
3240			} else {
3241				writer.push(", ");
3242			}
3243			match operation {
3244				DatabaseOperation::RenameDatabase(new_name) => {
3245					writer.push_keyword("RENAME TO");
3246					writer.push_space();
3247					writer.push_identifier(&Iden::to_string(new_name.as_ref()), |s| {
3248						self.escape_iden(s)
3249					});
3250				}
3251				DatabaseOperation::OwnerTo(new_owner) => {
3252					writer.push_keyword("OWNER TO");
3253					writer.push_space();
3254					writer.push_identifier(&Iden::to_string(new_owner.as_ref()), |s| {
3255						self.escape_iden(s)
3256					});
3257				}
3258				// CockroachDB-specific operations are not supported in PostgreSQL
3259				DatabaseOperation::AddRegion(region) => {
3260					// For CockroachDB compatibility: ADD REGION 'region-name'
3261					writer.push_keyword("ADD REGION");
3262					writer.push_space();
3263					let escaped = region.replace('\'', "''");
3264					writer.push(&format!("'{}'", escaped));
3265				}
3266				DatabaseOperation::DropRegion(region) => {
3267					// For CockroachDB compatibility: DROP REGION 'region-name'
3268					writer.push_keyword("DROP REGION");
3269					writer.push_space();
3270					let escaped = region.replace('\'', "''");
3271					writer.push(&format!("'{}'", escaped));
3272				}
3273				DatabaseOperation::SetPrimaryRegion(region) => {
3274					// For CockroachDB compatibility: PRIMARY REGION 'region-name'
3275					writer.push_keyword("PRIMARY REGION");
3276					writer.push_space();
3277					let escaped = region.replace('\'', "''");
3278					writer.push(&format!("'{}'", escaped));
3279				}
3280				DatabaseOperation::ConfigureZone(zone_config) => {
3281					// For CockroachDB compatibility: CONFIGURE ZONE USING ...
3282					writer.push_keyword("CONFIGURE ZONE USING");
3283					writer.push_space();
3284
3285					let mut parts = Vec::new();
3286
3287					if let Some(num_replicas) = zone_config.num_replicas {
3288						parts.push(format!("num_replicas = {}", num_replicas));
3289					}
3290
3291					if !zone_config.constraints.is_empty() {
3292						let constraints: Vec<String> = zone_config
3293							.constraints
3294							.iter()
3295							.map(ToString::to_string)
3296							.collect();
3297						parts.push(format!("constraints = '[{}]'", constraints.join(", ")));
3298					}
3299
3300					if !zone_config.lease_preferences.is_empty() {
3301						let prefs: Vec<String> = zone_config
3302							.lease_preferences
3303							.iter()
3304							.map(|p| format!("[{}]", p))
3305							.collect();
3306						parts.push(format!("lease_preferences = '[{}]'", prefs.join(", ")));
3307					}
3308
3309					writer.push(&parts.join(", "));
3310				}
3311			}
3312		}
3313
3314		writer.finish()
3315	}
3316
3317	fn build_drop_database(&self, stmt: &crate::query::DropDatabaseStatement) -> (String, Values) {
3318		use crate::types::Iden;
3319
3320		let mut writer = SqlWriter::new();
3321
3322		// DROP DATABASE
3323		writer.push_keyword("DROP DATABASE");
3324
3325		// IF EXISTS
3326		if stmt.if_exists {
3327			writer.push_keyword("IF EXISTS");
3328		}
3329
3330		// Database name
3331		if let Some(name) = &stmt.database_name {
3332			writer.push_space();
3333			writer.push_identifier(&Iden::to_string(name.as_ref()), |s| self.escape_iden(s));
3334		}
3335
3336		// WITH (FORCE) - PostgreSQL 13+
3337		if stmt.force {
3338			writer.push_space();
3339			writer.push_keyword("WITH");
3340			writer.push(" (");
3341			writer.push("FORCE");
3342			writer.push(")");
3343		}
3344
3345		writer.finish()
3346	}
3347
3348	fn build_analyze(&self, stmt: &crate::query::AnalyzeStatement) -> (String, Values) {
3349		use crate::types::Iden;
3350		let mut writer = SqlWriter::new();
3351
3352		writer.push_keyword("ANALYZE");
3353
3354		if stmt.verbose {
3355			writer.push_keyword("VERBOSE");
3356		}
3357
3358		// Tables and columns
3359		if !stmt.tables.is_empty() {
3360			writer.push_space();
3361			writer.push_list(&stmt.tables, ", ", |w, table| {
3362				w.push_identifier(&Iden::to_string(table.table.as_ref()), |s| {
3363					self.escape_iden(s)
3364				});
3365				if !table.columns.is_empty() {
3366					w.push(" (");
3367					w.push_list(&table.columns, ", ", |w2, col| {
3368						w2.push_identifier(&Iden::to_string(col.as_ref()), |s| self.escape_iden(s));
3369					});
3370					w.push(")");
3371				}
3372			});
3373		}
3374
3375		writer.finish()
3376	}
3377
3378	fn build_vacuum(&self, stmt: &crate::query::VacuumStatement) -> (String, Values) {
3379		use crate::types::Iden;
3380		let mut writer = SqlWriter::new();
3381
3382		writer.push_keyword("VACUUM");
3383
3384		// Options
3385		if stmt.full {
3386			writer.push_keyword("FULL");
3387		}
3388		if stmt.freeze {
3389			writer.push_keyword("FREEZE");
3390		}
3391		if stmt.verbose {
3392			writer.push_keyword("VERBOSE");
3393		}
3394		if stmt.analyze {
3395			writer.push_keyword("ANALYZE");
3396		}
3397
3398		// Tables
3399		if !stmt.tables.is_empty() {
3400			writer.push_space();
3401			writer.push_list(&stmt.tables, ", ", |w, table| {
3402				w.push_identifier(&Iden::to_string(table.as_ref()), |s| self.escape_iden(s));
3403			});
3404		}
3405
3406		writer.finish()
3407	}
3408
3409	fn build_create_materialized_view(
3410		&self,
3411		stmt: &crate::query::CreateMaterializedViewStatement,
3412	) -> (String, Values) {
3413		use crate::types::Iden;
3414		let mut writer = SqlWriter::new();
3415
3416		writer.push_keyword("CREATE MATERIALIZED VIEW");
3417
3418		// IF NOT EXISTS
3419		if stmt.def.if_not_exists {
3420			writer.push_keyword("IF NOT EXISTS");
3421		}
3422
3423		// View name
3424		writer.push_space();
3425		writer.push_identifier(&Iden::to_string(stmt.def.name.as_ref()), |s| {
3426			self.escape_iden(s)
3427		});
3428
3429		// Column names
3430		if !stmt.def.columns.is_empty() {
3431			writer.push_space();
3432			writer.push("(");
3433			writer.push_list(&stmt.def.columns, ", ", |w, col| {
3434				w.push_identifier(&Iden::to_string(col.as_ref()), |s| self.escape_iden(s));
3435			});
3436			writer.push(")");
3437		}
3438
3439		// TABLESPACE
3440		if let Some(ref tablespace) = stmt.def.tablespace {
3441			writer.push_keyword("TABLESPACE");
3442			writer.push_space();
3443			writer.push_identifier(&Iden::to_string(tablespace.as_ref()), |s| {
3444				self.escape_iden(s)
3445			});
3446		}
3447
3448		// AS SELECT
3449		if let Some(ref select) = stmt.select {
3450			writer.push_keyword("AS");
3451			writer.push_space();
3452			let (select_sql, select_values) = self.build_select(select);
3453			writer.push(&select_sql);
3454
3455			// WITH [NO] DATA
3456			if let Some(with_data) = stmt.def.with_data {
3457				writer.push_space();
3458				if with_data {
3459					writer.push_keyword("WITH DATA");
3460				} else {
3461					writer.push_keyword("WITH NO DATA");
3462				}
3463			}
3464
3465			let (sql, _) = writer.finish();
3466			return (sql, select_values);
3467		}
3468
3469		writer.finish()
3470	}
3471
3472	fn build_alter_materialized_view(
3473		&self,
3474		stmt: &crate::query::AlterMaterializedViewStatement,
3475	) -> (String, Values) {
3476		use crate::types::{Iden, MaterializedViewOperation};
3477		let mut writer = SqlWriter::new();
3478
3479		writer.push_keyword("ALTER MATERIALIZED VIEW");
3480
3481		// View name
3482		if let Some(ref name) = stmt.name {
3483			writer.push_space();
3484			writer.push_identifier(&Iden::to_string(name.as_ref()), |s| self.escape_iden(s));
3485		}
3486
3487		// Operations
3488		for operation in &stmt.operations {
3489			writer.push_space();
3490			match operation {
3491				MaterializedViewOperation::Rename(new_name) => {
3492					writer.push_keyword("RENAME TO");
3493					writer.push_space();
3494					writer.push_identifier(&Iden::to_string(new_name.as_ref()), |s| {
3495						self.escape_iden(s)
3496					});
3497				}
3498				MaterializedViewOperation::OwnerTo(new_owner) => {
3499					writer.push_keyword("OWNER TO");
3500					writer.push_space();
3501					writer.push_identifier(&Iden::to_string(new_owner.as_ref()), |s| {
3502						self.escape_iden(s)
3503					});
3504				}
3505				MaterializedViewOperation::SetSchema(schema_name) => {
3506					writer.push_keyword("SET SCHEMA");
3507					writer.push_space();
3508					writer.push_identifier(&Iden::to_string(schema_name.as_ref()), |s| {
3509						self.escape_iden(s)
3510					});
3511				}
3512			}
3513		}
3514
3515		writer.finish()
3516	}
3517
3518	fn build_drop_materialized_view(
3519		&self,
3520		stmt: &crate::query::DropMaterializedViewStatement,
3521	) -> (String, Values) {
3522		use crate::types::Iden;
3523		let mut writer = SqlWriter::new();
3524
3525		writer.push_keyword("DROP MATERIALIZED VIEW");
3526
3527		// IF EXISTS
3528		if stmt.if_exists {
3529			writer.push_keyword("IF EXISTS");
3530		}
3531
3532		// View names
3533		writer.push_space();
3534		writer.push_list(&stmt.names, ", ", |w, name| {
3535			w.push_identifier(&Iden::to_string(name.as_ref()), |s| self.escape_iden(s));
3536		});
3537
3538		// CASCADE or RESTRICT
3539		if stmt.cascade {
3540			writer.push_keyword("CASCADE");
3541		} else if stmt.restrict {
3542			writer.push_keyword("RESTRICT");
3543		}
3544
3545		writer.finish()
3546	}
3547
3548	fn build_refresh_materialized_view(
3549		&self,
3550		stmt: &crate::query::RefreshMaterializedViewStatement,
3551	) -> (String, Values) {
3552		use crate::types::Iden;
3553		let mut writer = SqlWriter::new();
3554
3555		writer.push_keyword("REFRESH MATERIALIZED VIEW");
3556
3557		// CONCURRENTLY
3558		if stmt.concurrently {
3559			writer.push_keyword("CONCURRENTLY");
3560		}
3561
3562		// View name
3563		if let Some(ref name) = stmt.name {
3564			writer.push_space();
3565			writer.push_identifier(&Iden::to_string(name.as_ref()), |s| self.escape_iden(s));
3566		}
3567
3568		// WITH [NO] DATA
3569		if let Some(with_data) = stmt.with_data {
3570			writer.push_space();
3571			if with_data {
3572				writer.push_keyword("WITH DATA");
3573			} else {
3574				writer.push_keyword("WITH NO DATA");
3575			}
3576		}
3577
3578		writer.finish()
3579	}
3580
3581	fn build_create_procedure(
3582		&self,
3583		stmt: &crate::query::CreateProcedureStatement,
3584	) -> (String, Values) {
3585		use crate::types::{
3586			Iden,
3587			function::{FunctionBehavior, FunctionLanguage, FunctionSecurity},
3588		};
3589
3590		let mut writer = SqlWriter::new();
3591
3592		// CREATE [OR REPLACE] PROCEDURE
3593		writer.push_keyword("CREATE");
3594		if stmt.procedure_def.or_replace {
3595			writer.push_keyword("OR REPLACE");
3596		}
3597		writer.push_keyword("PROCEDURE");
3598
3599		// Procedure name
3600		writer.push_space();
3601		writer.push_identifier(&Iden::to_string(stmt.procedure_def.name.as_ref()), |s| {
3602			self.escape_iden(s)
3603		});
3604
3605		// Parameters (param1 type1, param2 type2, ...)
3606		writer.push("(");
3607		let mut first = true;
3608		for param in &stmt.procedure_def.parameters {
3609			if !first {
3610				writer.push(", ");
3611			}
3612			first = false;
3613
3614			// Parameter mode (IN, OUT, INOUT, VARIADIC)
3615			if let Some(mode) = &param.mode {
3616				use crate::types::function::ParameterMode;
3617				match mode {
3618					ParameterMode::In => writer.push("IN "),
3619					ParameterMode::Out => writer.push("OUT "),
3620					ParameterMode::InOut => writer.push("INOUT "),
3621					ParameterMode::Variadic => writer.push("VARIADIC "),
3622				}
3623			}
3624
3625			// Parameter name (optional)
3626			if let Some(name) = &param.name {
3627				writer.push_identifier(&Iden::to_string(name.as_ref()), |s| self.escape_iden(s));
3628				writer.push(" ");
3629			}
3630
3631			// Parameter type
3632			if let Some(param_type) = &param.param_type {
3633				writer.push(param_type);
3634			}
3635
3636			// Default value (optional)
3637			if let Some(default) = &param.default_value {
3638				writer.push(" DEFAULT ");
3639				writer.push(default);
3640			}
3641		}
3642		writer.push(")");
3643
3644		// LANGUAGE
3645		if let Some(language) = &stmt.procedure_def.language {
3646			writer.push_keyword("LANGUAGE");
3647			writer.push_space();
3648			match language {
3649				FunctionLanguage::Sql => writer.push("SQL"),
3650				FunctionLanguage::PlPgSql => writer.push("PLPGSQL"),
3651				FunctionLanguage::C => writer.push("C"),
3652				FunctionLanguage::Custom(lang) => writer.push(lang),
3653			}
3654		}
3655
3656		// Behavior (IMMUTABLE/STABLE/VOLATILE)
3657		if let Some(behavior) = &stmt.procedure_def.behavior {
3658			writer.push_space();
3659			match behavior {
3660				FunctionBehavior::Immutable => writer.push_keyword("IMMUTABLE"),
3661				FunctionBehavior::Stable => writer.push_keyword("STABLE"),
3662				FunctionBehavior::Volatile => writer.push_keyword("VOLATILE"),
3663			}
3664		}
3665
3666		// Security (SECURITY DEFINER/INVOKER)
3667		if let Some(security) = &stmt.procedure_def.security {
3668			writer.push_space();
3669			match security {
3670				FunctionSecurity::Definer => writer.push_keyword("SECURITY DEFINER"),
3671				FunctionSecurity::Invoker => writer.push_keyword("SECURITY INVOKER"),
3672			}
3673		}
3674
3675		// AS 'body'
3676		if let Some(body) = &stmt.procedure_def.body {
3677			writer.push_keyword("AS");
3678			writer.push_space();
3679			let delimiter = generate_safe_dollar_quote_delimiter(body);
3680			writer.push(&delimiter);
3681			writer.push(body);
3682			writer.push(&delimiter);
3683		}
3684
3685		writer.finish()
3686	}
3687
3688	fn build_alter_procedure(
3689		&self,
3690		stmt: &crate::query::AlterProcedureStatement,
3691	) -> (String, Values) {
3692		use crate::types::{
3693			Iden,
3694			function::{FunctionBehavior, FunctionSecurity},
3695			procedure::ProcedureOperation,
3696		};
3697
3698		let mut writer = SqlWriter::new();
3699
3700		// ALTER PROCEDURE
3701		writer.push_keyword("ALTER PROCEDURE");
3702
3703		// Procedure name
3704		if let Some(name) = &stmt.name {
3705			writer.push_space();
3706			writer.push_identifier(&Iden::to_string(name.as_ref()), |s| self.escape_iden(s));
3707		}
3708
3709		// Procedure signature (for overloaded procedures)
3710		if !stmt.parameters.is_empty() {
3711			writer.push("(");
3712			let mut first = true;
3713			for param in &stmt.parameters {
3714				if !first {
3715					writer.push(", ");
3716				}
3717				first = false;
3718
3719				// Parameter name (optional in signature)
3720				if let Some(name) = &param.name {
3721					let name_str = Iden::to_string(name.as_ref());
3722					if !name_str.is_empty() {
3723						writer.push_identifier(&name_str, |s| self.escape_iden(s));
3724						writer.push(" ");
3725					}
3726				}
3727
3728				// Parameter type
3729				if let Some(param_type) = &param.param_type {
3730					writer.push(param_type);
3731				}
3732			}
3733			writer.push(")");
3734		}
3735
3736		// ALTER PROCEDURE operation
3737		if let Some(operation) = &stmt.operation {
3738			writer.push_space();
3739			match operation {
3740				ProcedureOperation::RenameTo(new_name) => {
3741					writer.push_keyword("RENAME TO");
3742					writer.push_space();
3743					writer.push_identifier(&Iden::to_string(new_name.as_ref()), |s| {
3744						self.escape_iden(s)
3745					});
3746				}
3747				ProcedureOperation::OwnerTo(new_owner) => {
3748					writer.push_keyword("OWNER TO");
3749					writer.push_space();
3750					writer.push_identifier(&Iden::to_string(new_owner.as_ref()), |s| {
3751						self.escape_iden(s)
3752					});
3753				}
3754				ProcedureOperation::SetSchema(new_schema) => {
3755					writer.push_keyword("SET SCHEMA");
3756					writer.push_space();
3757					writer.push_identifier(&Iden::to_string(new_schema.as_ref()), |s| {
3758						self.escape_iden(s)
3759					});
3760				}
3761				ProcedureOperation::SetBehavior(behavior) => match behavior {
3762					FunctionBehavior::Immutable => writer.push_keyword("IMMUTABLE"),
3763					FunctionBehavior::Stable => writer.push_keyword("STABLE"),
3764					FunctionBehavior::Volatile => writer.push_keyword("VOLATILE"),
3765				},
3766				ProcedureOperation::SetSecurity(security) => match security {
3767					FunctionSecurity::Definer => writer.push_keyword("SECURITY DEFINER"),
3768					FunctionSecurity::Invoker => writer.push_keyword("SECURITY INVOKER"),
3769				},
3770			}
3771		}
3772
3773		writer.finish()
3774	}
3775
3776	fn build_drop_procedure(
3777		&self,
3778		stmt: &crate::query::DropProcedureStatement,
3779	) -> (String, Values) {
3780		use crate::types::Iden;
3781
3782		let mut writer = SqlWriter::new();
3783
3784		// DROP PROCEDURE
3785		writer.push_keyword("DROP PROCEDURE");
3786
3787		// IF EXISTS
3788		if stmt.if_exists {
3789			writer.push_keyword("IF EXISTS");
3790		}
3791
3792		// Procedure name
3793		if let Some(name) = &stmt.name {
3794			writer.push_space();
3795			writer.push_identifier(&Iden::to_string(name.as_ref()), |s| self.escape_iden(s));
3796		}
3797
3798		// Procedure signature (for overloaded procedures)
3799		if !stmt.parameters.is_empty() {
3800			writer.push("(");
3801			let mut first = true;
3802			for param in &stmt.parameters {
3803				if !first {
3804					writer.push(", ");
3805				}
3806				first = false;
3807
3808				// Parameter name (optional in signature)
3809				if let Some(name) = &param.name {
3810					let name_str = Iden::to_string(name.as_ref());
3811					if !name_str.is_empty() {
3812						writer.push_identifier(&name_str, |s| self.escape_iden(s));
3813						writer.push(" ");
3814					}
3815				}
3816
3817				// Parameter type
3818				if let Some(param_type) = &param.param_type {
3819					writer.push(param_type);
3820				}
3821			}
3822			writer.push(")");
3823		}
3824
3825		// CASCADE
3826		if stmt.cascade {
3827			writer.push_keyword("CASCADE");
3828		}
3829
3830		writer.finish()
3831	}
3832	//
3833	fn build_create_type(&self, stmt: &crate::query::CreateTypeStatement) -> (String, Values) {
3834		let mut writer = SqlWriter::new();
3835
3836		writer.push_keyword("CREATE TYPE");
3837		writer.push_space();
3838
3839		// Type name
3840		if let Some(name) = &stmt.name {
3841			writer.push_identifier(&name.to_string(), |s| self.escape_iden(s));
3842		}
3843
3844		// Type definition
3845		if let Some(kind) = &stmt.kind {
3846			use crate::types::type_def::TypeKind;
3847			match kind {
3848				TypeKind::Enum { values } => {
3849					writer.push_space();
3850					writer.push_keyword("AS ENUM");
3851					writer.push_space();
3852					writer.push("(");
3853					writer.push_list(values, ", ", |w, value| {
3854						w.push("'");
3855						w.push(&value.replace('\'', "''"));
3856						w.push("'");
3857					});
3858					writer.push(")");
3859				}
3860				TypeKind::Composite { attributes } => {
3861					writer.push_space();
3862					writer.push_keyword("AS");
3863					writer.push_space();
3864					writer.push("(");
3865					writer.push_list(attributes, ", ", |w, (name, type_name)| {
3866						w.push_identifier(name, |s| self.escape_iden(s));
3867						w.push_space();
3868						w.push(type_name);
3869					});
3870					writer.push(")");
3871				}
3872				TypeKind::Domain {
3873					base_type,
3874					constraint,
3875					default,
3876					not_null,
3877				} => {
3878					writer.push_space();
3879					writer.push_keyword("AS");
3880					writer.push_space();
3881					writer.push(base_type);
3882
3883					// DEFAULT clause
3884					if let Some(default_val) = default {
3885						writer.push_space();
3886						writer.push_keyword("DEFAULT");
3887						writer.push_space();
3888						writer.push(default_val);
3889					}
3890
3891					// CONSTRAINT clause
3892					if let Some(check) = constraint {
3893						writer.push_space();
3894						writer.push(check);
3895					}
3896
3897					// NOT NULL clause
3898					if *not_null {
3899						writer.push_space();
3900						writer.push_keyword("NOT NULL");
3901					}
3902				}
3903				TypeKind::Range {
3904					subtype,
3905					subtype_diff,
3906					canonical,
3907				} => {
3908					writer.push_space();
3909					writer.push_keyword("AS RANGE");
3910					writer.push_space();
3911					writer.push("(");
3912					writer.push("SUBTYPE = ");
3913					writer.push(subtype);
3914
3915					// SUBTYPE_DIFF clause
3916					if let Some(diff_fn) = subtype_diff {
3917						writer.push(", SUBTYPE_DIFF = ");
3918						writer.push(diff_fn);
3919					}
3920
3921					// CANONICAL clause
3922					if let Some(canonical_fn) = canonical {
3923						writer.push(", CANONICAL = ");
3924						writer.push(canonical_fn);
3925					}
3926
3927					writer.push(")");
3928				}
3929			}
3930		}
3931
3932		writer.finish()
3933	}
3934
3935	fn build_alter_type(&self, stmt: &crate::query::AlterTypeStatement) -> (String, Values) {
3936		let mut writer = SqlWriter::new();
3937
3938		writer.push_keyword("ALTER TYPE");
3939		writer.push_space();
3940		writer.push_identifier(&stmt.name.to_string(), |s| self.escape_iden(s));
3941
3942		// Process operations
3943		for operation in &stmt.operations {
3944			writer.push_space();
3945			use crate::types::type_def::TypeOperation;
3946			match operation {
3947				TypeOperation::RenameTo(new_name) => {
3948					writer.push_keyword("RENAME TO");
3949					writer.push_space();
3950					writer.push_identifier(&new_name.to_string(), |s| self.escape_iden(s));
3951				}
3952				TypeOperation::OwnerTo(owner) => {
3953					writer.push_keyword("OWNER TO");
3954					writer.push_space();
3955					writer.push_identifier(&owner.to_string(), |s| self.escape_iden(s));
3956				}
3957				TypeOperation::SetSchema(schema) => {
3958					writer.push_keyword("SET SCHEMA");
3959					writer.push_space();
3960					writer.push_identifier(&schema.to_string(), |s| self.escape_iden(s));
3961				}
3962				TypeOperation::AddValue(value, position) => {
3963					writer.push_keyword("ADD VALUE");
3964					writer.push_space();
3965					writer.push("'");
3966					writer.push(&value.replace('\'', "''"));
3967					writer.push("'");
3968
3969					if let Some(pos) = position {
3970						writer.push_space();
3971						writer.push_keyword("BEFORE");
3972						writer.push_space();
3973						writer.push("'");
3974						writer.push(&pos.replace('\'', "''"));
3975						writer.push("'");
3976					}
3977				}
3978				TypeOperation::RenameValue(old_value, new_value) => {
3979					writer.push_keyword("RENAME VALUE");
3980					writer.push_space();
3981					writer.push("'");
3982					writer.push(&old_value.replace('\'', "''"));
3983					writer.push("'");
3984					writer.push_space();
3985					writer.push_keyword("TO");
3986					writer.push_space();
3987					writer.push("'");
3988					writer.push(&new_value.replace('\'', "''"));
3989					writer.push("'");
3990				}
3991				TypeOperation::AddConstraint(name, check) => {
3992					writer.push_keyword("ADD CONSTRAINT");
3993					writer.push_space();
3994					writer.push_identifier(name, |s| self.escape_iden(s));
3995					writer.push_space();
3996					writer.push(check);
3997				}
3998				TypeOperation::DropConstraint(name, if_exists) => {
3999					writer.push_keyword("DROP CONSTRAINT");
4000					if *if_exists {
4001						writer.push_space();
4002						writer.push_keyword("IF EXISTS");
4003					}
4004					writer.push_space();
4005					writer.push_identifier(name, |s| self.escape_iden(s));
4006				}
4007				TypeOperation::SetDefault(value) => {
4008					writer.push_keyword("SET DEFAULT");
4009					writer.push_space();
4010					writer.push(value);
4011				}
4012				TypeOperation::DropDefault => {
4013					writer.push_keyword("DROP DEFAULT");
4014				}
4015				TypeOperation::SetNotNull => {
4016					writer.push_keyword("SET NOT NULL");
4017				}
4018				TypeOperation::DropNotNull => {
4019					writer.push_keyword("DROP NOT NULL");
4020				}
4021			}
4022		}
4023
4024		writer.finish()
4025	}
4026
4027	fn build_drop_type(&self, stmt: &crate::query::DropTypeStatement) -> (String, Values) {
4028		let mut writer = SqlWriter::new();
4029
4030		writer.push_keyword("DROP TYPE");
4031		writer.push_space();
4032
4033		// IF EXISTS clause
4034		if stmt.if_exists {
4035			writer.push_keyword("IF EXISTS");
4036			writer.push_space();
4037		}
4038
4039		// Type name
4040		writer.push_identifier(&stmt.name.to_string(), |s| self.escape_iden(s));
4041
4042		// CASCADE/RESTRICT clause
4043		if stmt.cascade {
4044			writer.push_space();
4045			writer.push_keyword("CASCADE");
4046		} else if stmt.restrict {
4047			writer.push_space();
4048			writer.push_keyword("RESTRICT");
4049		}
4050
4051		writer.finish()
4052	}
4053}
4054
4055// Helper methods for DDL operations
4056impl PostgresQueryBuilder {
4057	/// Convert ColumnType to PostgreSQL SQL type string
4058	///
4059	/// Note: The `self` parameter is used in recursive calls for Array types (e.g., INTEGER[]).
4060	/// The clippy::only_used_in_recursion warning is allowed because this is the intended design
4061	/// for handling nested array types, and keeping `self` maintains consistency with other
4062	/// backend implementations.
4063	#[allow(clippy::only_used_in_recursion)]
4064	fn column_type_to_sql(&self, col_type: &crate::types::ColumnType) -> String {
4065		use crate::types::ColumnType;
4066		match col_type {
4067			ColumnType::Char(len) => format!("CHAR({})", len.unwrap_or(1)),
4068			ColumnType::String(len) => {
4069				if let Some(l) = len {
4070					format!("VARCHAR({})", l)
4071				} else {
4072					"VARCHAR".to_string()
4073				}
4074			}
4075			ColumnType::Text => "TEXT".to_string(),
4076			ColumnType::TinyInteger => "SMALLINT".to_string(),
4077			ColumnType::SmallInteger => "SMALLINT".to_string(),
4078			ColumnType::Integer => "INTEGER".to_string(),
4079			ColumnType::BigInteger => "BIGINT".to_string(),
4080			ColumnType::Float => "REAL".to_string(),
4081			ColumnType::Double => "DOUBLE PRECISION".to_string(),
4082			ColumnType::Decimal(precision) => {
4083				// PostgreSQL uses NUMERIC as the canonical name (DECIMAL is an alias)
4084				if let Some((p, s)) = precision {
4085					format!("NUMERIC({}, {})", p, s)
4086				} else {
4087					"NUMERIC".to_string()
4088				}
4089			}
4090			ColumnType::DateTime => "TIMESTAMP".to_string(),
4091			ColumnType::Timestamp => "TIMESTAMP".to_string(),
4092			ColumnType::TimestampWithTimeZone => "TIMESTAMP WITH TIME ZONE".to_string(),
4093			ColumnType::Time => "TIME".to_string(),
4094			ColumnType::Date => "DATE".to_string(),
4095			ColumnType::Binary(_len) => {
4096				// PostgreSQL BYTEA does not support length modifiers
4097				"BYTEA".to_string()
4098			}
4099			ColumnType::VarBinary(_len) => {
4100				// PostgreSQL BYTEA does not support length modifiers
4101				"BYTEA".to_string()
4102			}
4103			ColumnType::Blob => "BYTEA".to_string(),
4104			ColumnType::Boolean => "BOOLEAN".to_string(),
4105			ColumnType::Json => "JSON".to_string(),
4106			ColumnType::JsonBinary => "JSONB".to_string(),
4107			ColumnType::Uuid => "UUID".to_string(),
4108			ColumnType::Array(inner_type) => {
4109				format!("{}[]", self.column_type_to_sql(inner_type))
4110			}
4111			ColumnType::Custom(name) => name.clone(),
4112		}
4113	}
4114
4115	fn write_table_constraint(
4116		&self,
4117		writer: &mut SqlWriter,
4118		constraint: &crate::types::TableConstraint,
4119	) {
4120		use crate::types::TableConstraint;
4121		match constraint {
4122			TableConstraint::PrimaryKey { name, columns } => {
4123				if let Some(n) = name {
4124					writer.push_keyword("CONSTRAINT");
4125					writer.push_space();
4126					writer.push_identifier(&n.to_string(), |s| self.escape_iden(s));
4127					writer.push_space();
4128				}
4129				writer.push_keyword("PRIMARY KEY");
4130				writer.push_space();
4131				writer.push("(");
4132				writer.push_list(columns, ", ", |w, col| {
4133					w.push_identifier(&col.to_string(), |s| self.escape_iden(s));
4134				});
4135				writer.push(")");
4136			}
4137			TableConstraint::Unique { name, columns } => {
4138				if let Some(n) = name {
4139					writer.push_keyword("CONSTRAINT");
4140					writer.push_space();
4141					writer.push_identifier(&n.to_string(), |s| self.escape_iden(s));
4142					writer.push_space();
4143				}
4144				writer.push_keyword("UNIQUE");
4145				writer.push_space();
4146				writer.push("(");
4147				writer.push_list(columns, ", ", |w, col| {
4148					w.push_identifier(&col.to_string(), |s| self.escape_iden(s));
4149				});
4150				writer.push(")");
4151			}
4152			TableConstraint::ForeignKey {
4153				name,
4154				columns,
4155				ref_table,
4156				ref_columns,
4157				on_delete,
4158				on_update,
4159			} => {
4160				if let Some(n) = name {
4161					writer.push_keyword("CONSTRAINT");
4162					writer.push_space();
4163					writer.push_identifier(&n.to_string(), |s| self.escape_iden(s));
4164					writer.push_space();
4165				}
4166				writer.push_keyword("FOREIGN KEY");
4167				writer.push_space();
4168				writer.push("(");
4169				writer.push_list(columns, ", ", |w, col| {
4170					w.push_identifier(&col.to_string(), |s| self.escape_iden(s));
4171				});
4172				writer.push(")");
4173				writer.push_space();
4174				writer.push_keyword("REFERENCES");
4175				writer.push_space();
4176				self.write_table_ref(writer, ref_table);
4177				writer.push_space();
4178				writer.push("(");
4179				writer.push_list(ref_columns, ", ", |w, col| {
4180					w.push_identifier(&col.to_string(), |s| self.escape_iden(s));
4181				});
4182				writer.push(")");
4183				if let Some(action) = on_delete {
4184					writer.push_space();
4185					writer.push_keyword("ON DELETE");
4186					writer.push_space();
4187					writer.push_keyword(self.foreign_key_action_to_sql(action));
4188				}
4189				if let Some(action) = on_update {
4190					writer.push_space();
4191					writer.push_keyword("ON UPDATE");
4192					writer.push_space();
4193					writer.push_keyword(self.foreign_key_action_to_sql(action));
4194				}
4195			}
4196			TableConstraint::Check { name, expr } => {
4197				if let Some(n) = name {
4198					writer.push_keyword("CONSTRAINT");
4199					writer.push_space();
4200					writer.push_identifier(&n.to_string(), |s| self.escape_iden(s));
4201					writer.push_space();
4202				}
4203				writer.push_keyword("CHECK");
4204				writer.push_space();
4205				writer.push("(");
4206				self.write_simple_expr(writer, expr);
4207				writer.push(")");
4208			}
4209		}
4210	}
4211
4212	fn foreign_key_action_to_sql(&self, action: &crate::types::ForeignKeyAction) -> &'static str {
4213		use crate::types::ForeignKeyAction;
4214		match action {
4215			ForeignKeyAction::Restrict => "RESTRICT",
4216			ForeignKeyAction::Cascade => "CASCADE",
4217			ForeignKeyAction::SetNull => "SET NULL",
4218			ForeignKeyAction::SetDefault => "SET DEFAULT",
4219			ForeignKeyAction::NoAction => "NO ACTION",
4220		}
4221	}
4222
4223	fn index_method_to_sql(&self, method: &crate::query::IndexMethod) -> &'static str {
4224		use crate::query::IndexMethod;
4225		match method {
4226			IndexMethod::BTree => "BTREE",
4227			IndexMethod::Hash => "HASH",
4228			IndexMethod::Gist => "GIST",
4229			IndexMethod::Gin => "GIN",
4230			IndexMethod::Brin => "BRIN",
4231			IndexMethod::FullText => "GIN", // PostgreSQL uses GIN for full-text search
4232			IndexMethod::Spatial => "GIST", // PostgreSQL uses GIST for spatial indexes
4233		}
4234	}
4235}
4236
4237impl PostgresQueryBuilder {
4238	/// Format a role specification for PostgreSQL
4239	///
4240	/// # Arguments
4241	///
4242	/// * `spec` - The role specification to format
4243	///
4244	/// # Returns
4245	///
4246	/// The SQL representation of the role specification
4247	fn format_role_specification(spec: &crate::dcl::RoleSpecification) -> &str {
4248		use crate::dcl::RoleSpecification;
4249
4250		match spec {
4251			RoleSpecification::RoleName(name) => name,
4252			RoleSpecification::CurrentRole => "CURRENT_ROLE",
4253			RoleSpecification::CurrentUser => "CURRENT_USER",
4254			RoleSpecification::SessionUser => "SESSION_USER",
4255		}
4256	}
4257}
4258
4259#[cfg(test)]
4260mod tests {
4261	use super::*;
4262	use crate::{
4263		expr::{Expr, ExprTrait},
4264		query::Query,
4265		types::{Alias, IntoIden},
4266	};
4267	use rstest::rstest;
4268
4269	#[test]
4270	fn test_escape_identifier() {
4271		let builder = PostgresQueryBuilder::new();
4272		assert_eq!(builder.escape_identifier("user"), "\"user\"");
4273		assert_eq!(builder.escape_identifier("table_name"), "\"table_name\"");
4274	}
4275
4276	#[test]
4277	fn test_escape_identifier_with_quotes() {
4278		let builder = PostgresQueryBuilder::new();
4279		assert_eq!(builder.escape_identifier("user\"name"), "\"user\"\"name\"");
4280	}
4281
4282	#[test]
4283	fn test_format_placeholder() {
4284		let builder = PostgresQueryBuilder::new();
4285		assert_eq!(builder.format_placeholder(1), "$1");
4286		assert_eq!(builder.format_placeholder(2), "$2");
4287		assert_eq!(builder.format_placeholder(10), "$10");
4288	}
4289
4290	#[test]
4291	fn test_select_basic() {
4292		let builder = PostgresQueryBuilder::new();
4293		let mut stmt = Query::select();
4294		stmt.column("id").column("name").from("users");
4295
4296		let (sql, values) = builder.build_select(&stmt);
4297		assert_eq!(sql, "SELECT \"id\", \"name\" FROM \"users\"");
4298		assert_eq!(values.len(), 0);
4299	}
4300
4301	#[test]
4302	fn test_select_asterisk() {
4303		let builder = PostgresQueryBuilder::new();
4304		let mut stmt = Query::select();
4305		stmt.from("users");
4306
4307		let (sql, values) = builder.build_select(&stmt);
4308		assert_eq!(sql, "SELECT * FROM \"users\"");
4309		assert_eq!(values.len(), 0);
4310	}
4311
4312	#[test]
4313	fn test_select_with_where() {
4314		let builder = PostgresQueryBuilder::new();
4315		let mut stmt = Query::select();
4316		stmt.column("id")
4317			.from("users")
4318			.and_where(Expr::col("active").eq(true));
4319
4320		let (sql, _values) = builder.build_select(&stmt);
4321		// Note: The exact WHERE clause format depends on Expr implementation
4322		assert!(sql.contains("SELECT"));
4323		assert!(sql.contains("FROM"));
4324		assert!(sql.contains("WHERE"));
4325	}
4326
4327	#[test]
4328	fn test_select_with_limit_offset() {
4329		let builder = PostgresQueryBuilder::new();
4330		let mut stmt = Query::select();
4331		stmt.column("id").from("users").limit(10).offset(20);
4332
4333		let (sql, values) = builder.build_select(&stmt);
4334		assert!(sql.contains("SELECT"));
4335		assert!(sql.contains("FROM"));
4336		assert!(sql.contains("LIMIT"));
4337		assert!(sql.contains("OFFSET"));
4338		assert_eq!(values.len(), 2);
4339	}
4340
4341	#[test]
4342	fn test_insert_basic() {
4343		let builder = PostgresQueryBuilder::new();
4344		let mut stmt = Query::insert();
4345		stmt.into_table("users")
4346			.columns(["name", "email"])
4347			.values_panic(["Alice", "alice@example.com"]);
4348
4349		let (sql, values) = builder.build_insert(&stmt);
4350		assert_eq!(
4351			sql,
4352			"INSERT INTO \"users\" (\"name\", \"email\") VALUES ($1, $2)"
4353		);
4354		assert_eq!(values.len(), 2);
4355	}
4356
4357	#[test]
4358	fn test_insert_multiple_rows() {
4359		let builder = PostgresQueryBuilder::new();
4360		let mut stmt = Query::insert();
4361		stmt.into_table("users")
4362			.columns(["name", "email"])
4363			.values_panic(["Alice", "alice@example.com"])
4364			.values_panic(["Bob", "bob@example.com"]);
4365
4366		let (sql, values) = builder.build_insert(&stmt);
4367		assert_eq!(
4368			sql,
4369			"INSERT INTO \"users\" (\"name\", \"email\") VALUES ($1, $2), ($3, $4)"
4370		);
4371		assert_eq!(values.len(), 4);
4372	}
4373
4374	#[test]
4375	fn test_insert_with_returning() {
4376		let builder = PostgresQueryBuilder::new();
4377		let mut stmt = Query::insert();
4378		stmt.into_table("users")
4379			.columns(["name"])
4380			.values_panic(["Alice"])
4381			.returning(["id", "created_at"]);
4382
4383		let (sql, values) = builder.build_insert(&stmt);
4384		assert!(sql.contains("INSERT INTO"));
4385		assert!(sql.contains("VALUES"));
4386		assert!(sql.contains("RETURNING"));
4387		assert!(sql.contains("\"id\""));
4388		assert!(sql.contains("\"created_at\""));
4389		assert_eq!(values.len(), 1);
4390	}
4391
4392	#[test]
4393	fn test_insert_with_returning_all() {
4394		let builder = PostgresQueryBuilder::new();
4395		let mut stmt = Query::insert();
4396		stmt.into_table("users")
4397			.columns(["name"])
4398			.values_panic(["Alice"])
4399			.returning_all();
4400
4401		let (sql, values) = builder.build_insert(&stmt);
4402		assert!(sql.contains("RETURNING *"));
4403		assert_eq!(values.len(), 1);
4404	}
4405
4406	#[test]
4407	fn test_insert_from_subquery() {
4408		let builder = PostgresQueryBuilder::new();
4409
4410		// Create a SELECT subquery
4411		let select = Query::select()
4412			.column("name")
4413			.column("email")
4414			.from("temp_users")
4415			.to_owned();
4416
4417		// Create an INSERT with subquery
4418		let mut stmt = Query::insert();
4419		stmt.into_table("users")
4420			.columns(["name", "email"])
4421			.from_subquery(select);
4422
4423		let (sql, values) = builder.build_insert(&stmt);
4424		assert!(sql.contains("INSERT INTO \"users\""));
4425		assert!(sql.contains("\"name\", \"email\""));
4426		assert!(sql.contains("SELECT \"name\", \"email\" FROM \"temp_users\""));
4427		assert!(!sql.contains("VALUES"));
4428		assert_eq!(values.len(), 0);
4429	}
4430
4431	#[test]
4432	fn test_insert_from_subquery_with_where() {
4433		let builder = PostgresQueryBuilder::new();
4434
4435		// Create a SELECT subquery with WHERE clause
4436		let select = Query::select()
4437			.column("name")
4438			.column("email")
4439			.from("temp_users")
4440			.and_where(Expr::col("active").eq(true))
4441			.to_owned();
4442
4443		// Create an INSERT with subquery
4444		let mut stmt = Query::insert();
4445		stmt.into_table("users")
4446			.columns(["name", "email"])
4447			.from_subquery(select);
4448
4449		let (sql, values) = builder.build_insert(&stmt);
4450		assert!(sql.contains("INSERT INTO \"users\""));
4451		assert!(sql.contains("SELECT"));
4452		assert!(sql.contains("FROM \"temp_users\""));
4453		assert!(sql.contains("WHERE"));
4454		assert_eq!(values.len(), 1); // true value from WHERE clause
4455	}
4456
4457	#[test]
4458	fn test_update_basic() {
4459		let builder = PostgresQueryBuilder::new();
4460		let mut stmt = Query::update();
4461		stmt.table("users")
4462			.value("name", "Alice")
4463			.value("email", "alice@example.com");
4464
4465		let (sql, values) = builder.build_update(&stmt);
4466		assert_eq!(sql, "UPDATE \"users\" SET \"name\" = $1, \"email\" = $2");
4467		assert_eq!(values.len(), 2);
4468	}
4469
4470	#[test]
4471	fn test_update_with_where() {
4472		let builder = PostgresQueryBuilder::new();
4473		let mut stmt = Query::update();
4474		stmt.table("users")
4475			.value("active", false)
4476			.and_where(Expr::col("id").eq(1));
4477
4478		let (sql, values) = builder.build_update(&stmt);
4479		assert!(sql.contains("UPDATE"));
4480		assert!(sql.contains("SET"));
4481		assert!(sql.contains("WHERE"));
4482		assert_eq!(values.len(), 2); // false + 1
4483	}
4484
4485	#[test]
4486	fn test_update_with_returning() {
4487		let builder = PostgresQueryBuilder::new();
4488		let mut stmt = Query::update();
4489		stmt.table("users")
4490			.value("active", false)
4491			.and_where(Expr::col("id").eq(1))
4492			.returning(["id", "updated_at"]);
4493
4494		let (sql, values) = builder.build_update(&stmt);
4495		assert!(sql.contains("UPDATE"));
4496		assert!(sql.contains("RETURNING"));
4497		assert!(sql.contains("\"id\""));
4498		assert!(sql.contains("\"updated_at\""));
4499		assert_eq!(values.len(), 2);
4500	}
4501
4502	#[test]
4503	fn test_delete_basic() {
4504		let builder = PostgresQueryBuilder::new();
4505		let mut stmt = Query::delete();
4506		stmt.from_table("users")
4507			.and_where(Expr::col("active").eq(false));
4508
4509		let (sql, values) = builder.build_delete(&stmt);
4510		assert!(sql.contains("DELETE FROM"));
4511		assert!(sql.contains("\"users\""));
4512		assert!(sql.contains("WHERE"));
4513		assert_eq!(values.len(), 1); // false
4514	}
4515
4516	#[test]
4517	fn test_delete_no_where() {
4518		let builder = PostgresQueryBuilder::new();
4519		let mut stmt = Query::delete();
4520		stmt.from_table("users");
4521
4522		let (sql, values) = builder.build_delete(&stmt);
4523		assert_eq!(sql, "DELETE FROM \"users\"");
4524		assert_eq!(values.len(), 0);
4525	}
4526
4527	#[test]
4528	fn test_delete_with_returning() {
4529		let builder = PostgresQueryBuilder::new();
4530		let mut stmt = Query::delete();
4531		stmt.from_table("users")
4532			.and_where(Expr::col("id").eq(1))
4533			.returning(["id", "name"]);
4534
4535		let (sql, values) = builder.build_delete(&stmt);
4536		assert!(sql.contains("DELETE FROM"));
4537		assert!(sql.contains("RETURNING"));
4538		assert!(sql.contains("\"id\""));
4539		assert!(sql.contains("\"name\""));
4540		assert_eq!(values.len(), 1);
4541	}
4542
4543	#[test]
4544	fn test_delete_with_returning_all() {
4545		let builder = PostgresQueryBuilder::new();
4546		let mut stmt = Query::delete();
4547		stmt.from_table("users")
4548			.and_where(Expr::col("id").eq(1))
4549			.returning_all();
4550
4551		let (sql, values) = builder.build_delete(&stmt);
4552		assert!(sql.contains("RETURNING *"));
4553		assert_eq!(values.len(), 1);
4554	}
4555
4556	// JOIN tests
4557
4558	#[test]
4559	fn test_inner_join_simple() {
4560		let builder = PostgresQueryBuilder::new();
4561		let mut stmt = Query::select();
4562		stmt.column("users.name")
4563			.column("orders.amount")
4564			.from("users")
4565			.inner_join(
4566				"orders",
4567				Expr::col(("users", "id")).eq(Expr::col(("orders", "user_id"))),
4568			);
4569
4570		let (sql, _values) = builder.build_select(&stmt);
4571		assert!(sql.contains("FROM \"users\""));
4572		assert!(sql.contains("INNER JOIN \"orders\""));
4573		assert!(sql.contains("ON \"users\".\"id\" = \"orders\".\"user_id\""));
4574	}
4575
4576	#[test]
4577	fn test_left_join() {
4578		let builder = PostgresQueryBuilder::new();
4579		let mut stmt = Query::select();
4580		stmt.column("users.name")
4581			.column("profiles.bio")
4582			.from("users")
4583			.left_join(
4584				"profiles",
4585				Expr::col(("users", "id")).eq(Expr::col(("profiles", "user_id"))),
4586			);
4587
4588		let (sql, _values) = builder.build_select(&stmt);
4589		assert!(sql.contains("LEFT JOIN \"profiles\""));
4590		assert!(sql.contains("ON \"users\".\"id\" = \"profiles\".\"user_id\""));
4591	}
4592
4593	#[test]
4594	fn test_right_join() {
4595		let builder = PostgresQueryBuilder::new();
4596		let mut stmt = Query::select();
4597		stmt.column("users.name")
4598			.column("orders.amount")
4599			.from("users")
4600			.right_join(
4601				"orders",
4602				Expr::col(("users", "id")).eq(Expr::col(("orders", "user_id"))),
4603			);
4604
4605		let (sql, _values) = builder.build_select(&stmt);
4606		assert!(sql.contains("RIGHT JOIN \"orders\""));
4607		assert!(sql.contains("ON \"users\".\"id\" = \"orders\".\"user_id\""));
4608	}
4609
4610	#[test]
4611	fn test_full_outer_join() {
4612		let builder = PostgresQueryBuilder::new();
4613		let mut stmt = Query::select();
4614		stmt.column("users.name")
4615			.column("orders.amount")
4616			.from("users")
4617			.full_outer_join(
4618				"orders",
4619				Expr::col(("users", "id")).eq(Expr::col(("orders", "user_id"))),
4620			);
4621
4622		let (sql, _values) = builder.build_select(&stmt);
4623		assert!(sql.contains("FULL OUTER JOIN \"orders\""));
4624		assert!(sql.contains("ON \"users\".\"id\" = \"orders\".\"user_id\""));
4625	}
4626
4627	#[test]
4628	fn test_cross_join() {
4629		let builder = PostgresQueryBuilder::new();
4630		let mut stmt = Query::select();
4631		stmt.column("users.name")
4632			.column("roles.title")
4633			.from("users")
4634			.cross_join("roles");
4635
4636		let (sql, _values) = builder.build_select(&stmt);
4637		assert!(sql.contains("CROSS JOIN \"roles\""));
4638		assert!(!sql.contains("ON"));
4639	}
4640
4641	#[test]
4642	fn test_multiple_joins() {
4643		let builder = PostgresQueryBuilder::new();
4644		let mut stmt = Query::select();
4645		stmt.column("users.name")
4646			.column("orders.amount")
4647			.column("products.title")
4648			.from("users")
4649			.inner_join(
4650				"orders",
4651				Expr::col(("users", "id")).eq(Expr::col(("orders", "user_id"))),
4652			)
4653			.inner_join(
4654				"products",
4655				Expr::col(("orders", "product_id")).eq(Expr::col(("products", "id"))),
4656			);
4657
4658		let (sql, _values) = builder.build_select(&stmt);
4659		assert!(sql.contains("INNER JOIN \"orders\""));
4660		assert!(sql.contains("INNER JOIN \"products\""));
4661		assert!(sql.contains("\"users\".\"id\" = \"orders\".\"user_id\""));
4662		assert!(sql.contains("\"orders\".\"product_id\" = \"products\".\"id\""));
4663	}
4664
4665	#[test]
4666	fn test_join_with_complex_condition() {
4667		let builder = PostgresQueryBuilder::new();
4668		let mut stmt = Query::select();
4669		stmt.column("users.name")
4670			.column("orders.amount")
4671			.from("users")
4672			.inner_join(
4673				"orders",
4674				Expr::col(("users", "id"))
4675					.eq(Expr::col(("orders", "user_id")))
4676					.and(Expr::col(("orders", "status")).eq("active")),
4677			);
4678
4679		let (sql, values) = builder.build_select(&stmt);
4680		assert!(sql.contains("INNER JOIN \"orders\""));
4681		assert!(sql.contains("ON"));
4682		assert!(sql.contains("\"users\".\"id\" = \"orders\".\"user_id\""));
4683		assert!(sql.contains("AND"));
4684		assert!(sql.contains("\"orders\".\"status\" = $"));
4685		assert_eq!(values.len(), 1);
4686	}
4687
4688	// GROUP BY / HAVING tests
4689
4690	#[test]
4691	fn test_group_by_single_column() {
4692		let builder = PostgresQueryBuilder::new();
4693		let mut stmt = Query::select();
4694		stmt.column("category")
4695			.from("products")
4696			.group_by("category");
4697
4698		let (sql, _values) = builder.build_select(&stmt);
4699		assert!(sql.contains("GROUP BY \"category\""));
4700	}
4701
4702	#[test]
4703	fn test_group_by_multiple_columns() {
4704		let builder = PostgresQueryBuilder::new();
4705		let mut stmt = Query::select();
4706		stmt.column("category")
4707			.column("brand")
4708			.from("products")
4709			.group_by("category")
4710			.group_by("brand");
4711
4712		let (sql, _values) = builder.build_select(&stmt);
4713		assert!(sql.contains("GROUP BY \"category\", \"brand\""));
4714	}
4715
4716	#[test]
4717	fn test_group_by_with_count() {
4718		use crate::expr::SimpleExpr;
4719		use crate::types::{ColumnRef, IntoIden};
4720
4721		let builder = PostgresQueryBuilder::new();
4722		let mut stmt = Query::select();
4723		stmt.column("category")
4724			.expr(SimpleExpr::FunctionCall(
4725				"COUNT".into_iden(),
4726				vec![SimpleExpr::Column(ColumnRef::Asterisk)],
4727			))
4728			.from("products")
4729			.group_by("category");
4730
4731		let (sql, _values) = builder.build_select(&stmt);
4732		assert!(sql.contains("COUNT(*)"));
4733		assert!(sql.contains("GROUP BY \"category\""));
4734	}
4735
4736	#[test]
4737	fn test_having_simple() {
4738		use crate::expr::SimpleExpr;
4739		use crate::types::{BinOper, ColumnRef, IntoIden};
4740
4741		let builder = PostgresQueryBuilder::new();
4742		let mut stmt = Query::select();
4743		let count_expr = SimpleExpr::FunctionCall(
4744			"COUNT".into_iden(),
4745			vec![SimpleExpr::Column(ColumnRef::Asterisk)],
4746		);
4747
4748		stmt.column("category")
4749			.expr(count_expr.clone())
4750			.from("products")
4751			.group_by("category")
4752			.and_having(SimpleExpr::Binary(
4753				Box::new(count_expr),
4754				BinOper::GreaterThan,
4755				Box::new(SimpleExpr::Value(5.into())),
4756			));
4757
4758		let (sql, values) = builder.build_select(&stmt);
4759		assert!(sql.contains("GROUP BY \"category\""));
4760		assert!(sql.contains("HAVING"));
4761		assert!(sql.contains("COUNT(*)"));
4762		assert!(sql.contains(">"));
4763		assert_eq!(values.len(), 1);
4764	}
4765
4766	#[test]
4767	fn test_group_by_having_with_sum() {
4768		use crate::expr::SimpleExpr;
4769		use crate::types::{BinOper, ColumnRef, IntoIden};
4770
4771		let builder = PostgresQueryBuilder::new();
4772		let mut stmt = Query::select();
4773		let sum_expr = SimpleExpr::FunctionCall(
4774			"SUM".into_iden(),
4775			vec![SimpleExpr::Column(ColumnRef::column("amount"))],
4776		);
4777
4778		stmt.column("user_id")
4779			.expr(sum_expr.clone())
4780			.from("orders")
4781			.group_by("user_id")
4782			.and_having(SimpleExpr::Binary(
4783				Box::new(sum_expr),
4784				BinOper::GreaterThan,
4785				Box::new(SimpleExpr::Value(1000.into())),
4786			));
4787
4788		let (sql, values) = builder.build_select(&stmt);
4789		assert!(sql.contains("SUM(\"amount\")"));
4790		assert!(sql.contains("GROUP BY \"user_id\""));
4791		assert!(sql.contains("HAVING"));
4792		assert_eq!(values.len(), 1);
4793	}
4794
4795	#[test]
4796	fn test_select_distinct() {
4797		let builder = PostgresQueryBuilder::new();
4798		let mut stmt = Query::select();
4799		stmt.column("category").from("products").distinct();
4800
4801		let (sql, _values) = builder.build_select(&stmt);
4802		assert!(sql.starts_with("SELECT DISTINCT"));
4803		assert!(sql.contains("\"category\""));
4804		assert!(sql.contains("FROM \"products\""));
4805	}
4806
4807	#[test]
4808	fn test_select_distinct_on() {
4809		let builder = PostgresQueryBuilder::new();
4810		let mut stmt = Query::select();
4811		stmt.column("id")
4812			.column("name")
4813			.from("users")
4814			.distinct_on(vec!["category"])
4815			.order_by("category", crate::types::Order::Asc);
4816
4817		let (sql, _values) = builder.build_select(&stmt);
4818		assert!(sql.contains("SELECT DISTINCT ON (\"category\")"));
4819		assert!(sql.contains("\"id\""));
4820		assert!(sql.contains("\"name\""));
4821		assert!(sql.contains("ORDER BY \"category\" ASC"));
4822	}
4823
4824	#[test]
4825	#[should_panic(expected = "PostgreSQL does not support DISTINCT ROW")]
4826	fn test_select_distinct_row_panics() {
4827		use crate::query::SelectDistinct;
4828
4829		let builder = PostgresQueryBuilder::new();
4830		let mut stmt = Query::select();
4831		stmt.column("name").from("products");
4832		stmt.distinct = Some(SelectDistinct::DistinctRow);
4833
4834		let _ = builder.build_select(&stmt);
4835	}
4836
4837	#[test]
4838	fn test_select_union() {
4839		let builder = PostgresQueryBuilder::new();
4840		let mut stmt1 = Query::select();
4841		stmt1.column("id").from("users");
4842
4843		let mut stmt2 = Query::select();
4844		stmt2.column("id").from("customers");
4845
4846		stmt1.union(stmt2);
4847
4848		let (sql, _values) = builder.build_select(&stmt1);
4849		assert!(sql.contains("SELECT \"id\" FROM \"users\""));
4850		assert!(sql.contains("UNION SELECT \"id\" FROM \"customers\""));
4851	}
4852
4853	#[test]
4854	fn test_select_union_all() {
4855		let builder = PostgresQueryBuilder::new();
4856		let mut stmt1 = Query::select();
4857		stmt1.column("name").from("products");
4858
4859		let mut stmt2 = Query::select();
4860		stmt2.column("name").from("archived_products");
4861
4862		stmt1.union_all(stmt2);
4863
4864		let (sql, _values) = builder.build_select(&stmt1);
4865		assert!(sql.contains("SELECT \"name\" FROM \"products\""));
4866		assert!(sql.contains("UNION ALL SELECT \"name\" FROM \"archived_products\""));
4867	}
4868
4869	#[test]
4870	fn test_select_intersect() {
4871		let builder = PostgresQueryBuilder::new();
4872		let mut stmt1 = Query::select();
4873		stmt1.column("email").from("subscribers");
4874
4875		let mut stmt2 = Query::select();
4876		stmt2.column("email").from("customers");
4877
4878		stmt1.intersect(stmt2);
4879
4880		let (sql, _values) = builder.build_select(&stmt1);
4881		assert!(sql.contains("SELECT \"email\" FROM \"subscribers\""));
4882		assert!(sql.contains("INTERSECT SELECT \"email\" FROM \"customers\""));
4883	}
4884
4885	#[test]
4886	fn test_select_except() {
4887		let builder = PostgresQueryBuilder::new();
4888		let mut stmt1 = Query::select();
4889		stmt1.column("id").from("all_users");
4890
4891		let mut stmt2 = Query::select();
4892		stmt2.column("id").from("banned_users");
4893
4894		stmt1.except(stmt2);
4895
4896		let (sql, _values) = builder.build_select(&stmt1);
4897		assert!(sql.contains("SELECT \"id\" FROM \"all_users\""));
4898		assert!(sql.contains("EXCEPT SELECT \"id\" FROM \"banned_users\""));
4899	}
4900
4901	#[test]
4902	fn test_select_multiple_unions() {
4903		let builder = PostgresQueryBuilder::new();
4904		let mut stmt1 = Query::select();
4905		stmt1.column("id").from("table1");
4906
4907		let mut stmt2 = Query::select();
4908		stmt2.column("id").from("table2");
4909
4910		let mut stmt3 = Query::select();
4911		stmt3.column("id").from("table3");
4912
4913		stmt1.union(stmt2);
4914		stmt1.union_all(stmt3);
4915
4916		let (sql, _values) = builder.build_select(&stmt1);
4917		assert!(sql.contains("SELECT \"id\" FROM \"table1\""));
4918		assert!(sql.contains("UNION SELECT \"id\" FROM \"table2\""));
4919		assert!(sql.contains("UNION ALL SELECT \"id\" FROM \"table3\""));
4920	}
4921
4922	#[test]
4923	fn test_select_exists_subquery() {
4924		use crate::expr::Expr;
4925
4926		let builder = PostgresQueryBuilder::new();
4927		let mut stmt = Query::select();
4928
4929		// Main query
4930		stmt.column("name").from("users");
4931
4932		// Subquery
4933		let mut subquery = Query::select();
4934		subquery
4935			.column("id")
4936			.from("orders")
4937			.and_where(Expr::col(("orders", "user_id")).eq(Expr::col(("users", "id"))));
4938
4939		// Add EXISTS condition
4940		stmt.and_where(Expr::exists(subquery));
4941
4942		let (sql, _values) = builder.build_select(&stmt);
4943		assert!(sql.contains("SELECT \"name\" FROM \"users\""));
4944		assert!(sql.contains("WHERE"));
4945		assert!(sql.contains("EXISTS"));
4946		assert!(sql.contains("SELECT \"id\" FROM \"orders\""));
4947	}
4948
4949	#[test]
4950	fn test_select_in_subquery() {
4951		use crate::expr::Expr;
4952
4953		let builder = PostgresQueryBuilder::new();
4954		let mut stmt = Query::select();
4955
4956		// Main query
4957		stmt.column("name").from("users");
4958
4959		// Subquery
4960		let mut subquery = Query::select();
4961		subquery.column("user_id").from("premium_users");
4962
4963		// Add IN condition
4964		stmt.and_where(Expr::col("id").in_subquery(subquery));
4965
4966		let (sql, _values) = builder.build_select(&stmt);
4967		assert!(sql.contains("SELECT \"name\" FROM \"users\""));
4968		assert!(sql.contains("WHERE"));
4969		assert!(sql.contains("\"id\""));
4970		assert!(sql.contains("IN"));
4971		assert!(sql.contains("SELECT \"user_id\" FROM \"premium_users\""));
4972	}
4973
4974	#[test]
4975	fn test_select_not_exists_subquery() {
4976		use crate::expr::Expr;
4977
4978		let builder = PostgresQueryBuilder::new();
4979		let mut stmt = Query::select();
4980
4981		// Main query
4982		stmt.column("email").from("users");
4983
4984		// Subquery
4985		let mut subquery = Query::select();
4986		subquery
4987			.column("id")
4988			.from("banned_users")
4989			.and_where(Expr::col(("banned_users", "user_id")).eq(Expr::col(("users", "id"))));
4990
4991		// Add NOT EXISTS condition
4992		stmt.and_where(Expr::not_exists(subquery));
4993
4994		let (sql, _values) = builder.build_select(&stmt);
4995		assert!(sql.contains("SELECT \"email\" FROM \"users\""));
4996		assert!(sql.contains("WHERE"));
4997		assert!(sql.contains("NOT EXISTS"));
4998		assert!(sql.contains("SELECT \"id\" FROM \"banned_users\""));
4999	}
5000
5001	// --- Phase 5: Subquery Edge Case Tests ---
5002
5003	#[test]
5004	fn test_not_in_subquery() {
5005		let builder = PostgresQueryBuilder::new();
5006
5007		let mut subquery = Query::select();
5008		subquery
5009			.column("user_id")
5010			.from("blocked_users")
5011			.and_where(Expr::col("reason").eq("spam"));
5012
5013		let mut stmt = Query::select();
5014		stmt.column("name")
5015			.from("users")
5016			.and_where(Expr::col("id").not_in_subquery(subquery));
5017
5018		let (sql, values) = builder.build_select(&stmt);
5019		assert!(sql.contains("NOT IN"));
5020		assert!(sql.contains("SELECT \"user_id\" FROM \"blocked_users\""));
5021		assert!(sql.contains("\"reason\" = $"));
5022		assert_eq!(values.len(), 1);
5023	}
5024
5025	#[test]
5026	fn test_subquery_in_select_list() {
5027		let builder = PostgresQueryBuilder::new();
5028
5029		let mut subquery = Query::select();
5030		subquery
5031			.expr(Expr::col("count"))
5032			.from("order_counts")
5033			.and_where(Expr::col(("order_counts", "user_id")).eq(Expr::col(("users", "id"))));
5034
5035		let mut stmt = Query::select();
5036		stmt.column("name")
5037			.expr(Expr::subquery(subquery))
5038			.from("users");
5039
5040		let (sql, _values) = builder.build_select(&stmt);
5041		assert!(sql.contains("\"name\""));
5042		assert!(sql.contains("(SELECT \"count\" FROM \"order_counts\""));
5043		assert!(sql.contains("\"order_counts\".\"user_id\" = \"users\".\"id\""));
5044	}
5045
5046	#[test]
5047	fn test_multiple_exists_conditions() {
5048		let builder = PostgresQueryBuilder::new();
5049
5050		let mut sub1 = Query::select();
5051		sub1.column("id")
5052			.from("orders")
5053			.and_where(Expr::col(("orders", "user_id")).eq(Expr::col(("users", "id"))));
5054
5055		let mut sub2 = Query::select();
5056		sub2.column("id")
5057			.from("reviews")
5058			.and_where(Expr::col(("reviews", "user_id")).eq(Expr::col(("users", "id"))));
5059
5060		let mut stmt = Query::select();
5061		stmt.column("name")
5062			.from("users")
5063			.and_where(Expr::exists(sub1))
5064			.and_where(Expr::exists(sub2));
5065
5066		let (sql, _values) = builder.build_select(&stmt);
5067		assert!(sql.contains("EXISTS (SELECT \"id\" FROM \"orders\""));
5068		assert!(sql.contains("EXISTS (SELECT \"id\" FROM \"reviews\""));
5069	}
5070
5071	#[test]
5072	fn test_nested_subquery() {
5073		let builder = PostgresQueryBuilder::new();
5074
5075		let mut inner_subquery = Query::select();
5076		inner_subquery
5077			.column("department_id")
5078			.from("top_departments")
5079			.and_where(Expr::col("revenue").gt(1000000));
5080
5081		let mut outer_subquery = Query::select();
5082		outer_subquery
5083			.column("id")
5084			.from("employees")
5085			.and_where(Expr::col("department_id").in_subquery(inner_subquery));
5086
5087		let mut stmt = Query::select();
5088		stmt.column("name")
5089			.from("users")
5090			.and_where(Expr::col("employee_id").in_subquery(outer_subquery));
5091
5092		let (sql, values) = builder.build_select(&stmt);
5093		assert!(sql.contains("IN (SELECT \"id\" FROM \"employees\""));
5094		assert!(sql.contains("IN (SELECT \"department_id\" FROM \"top_departments\""));
5095		assert!(sql.contains("\"revenue\" > $"));
5096		assert_eq!(values.len(), 1);
5097	}
5098
5099	#[test]
5100	fn test_subquery_with_complex_where() {
5101		let builder = PostgresQueryBuilder::new();
5102
5103		let mut subquery = Query::select();
5104		subquery
5105			.column("product_id")
5106			.from("inventory")
5107			.and_where(Expr::col("quantity").gt(0))
5108			.and_where(Expr::col("warehouse").eq("main"))
5109			.and_where(Expr::col("status").eq("available"));
5110
5111		let mut stmt = Query::select();
5112		stmt.column("name")
5113			.column("price")
5114			.from("products")
5115			.and_where(Expr::col("id").in_subquery(subquery))
5116			.and_where(Expr::col("active").eq(true));
5117
5118		let (sql, values) = builder.build_select(&stmt);
5119		assert!(sql.contains("IN (SELECT \"product_id\" FROM \"inventory\""));
5120		assert!(sql.contains("\"quantity\" > $"));
5121		assert!(sql.contains("\"warehouse\" = $"));
5122		assert!(sql.contains("\"status\" = $"));
5123		assert!(sql.contains("\"active\" = $"));
5124		assert_eq!(values.len(), 4); // 0, "main", "available", true
5125	}
5126
5127	#[test]
5128	fn test_from_subquery_preserves_parameter_values() {
5129		let builder = PostgresQueryBuilder::new();
5130
5131		// Arrange
5132		let mut subquery = Query::select();
5133		subquery
5134			.column("id")
5135			.column("name")
5136			.from("users")
5137			.and_where(Expr::col("active").eq(true))
5138			.and_where(Expr::col("role").eq("admin"));
5139
5140		let mut stmt = Query::select();
5141		stmt.column("name")
5142			.from_subquery(subquery, Alias::new("active_admins"))
5143			.and_where(Expr::col("name").like("A%"));
5144
5145		// Act
5146		let (sql, values) = builder.build_select(&stmt);
5147
5148		// Assert
5149		assert!(sql.contains("(SELECT"));
5150		assert!(sql.contains(") AS \"active_admins\""));
5151		// Subquery params (true, "admin") + outer param ("A%") = 3 values
5152		assert_eq!(values.len(), 3);
5153	}
5154
5155	#[test]
5156	fn test_from_subquery_postgres_placeholder_renumbering() {
5157		let builder = PostgresQueryBuilder::new();
5158
5159		// Arrange: outer query has params before the FROM subquery
5160		let mut subquery = Query::select();
5161		subquery
5162			.column("id")
5163			.from("users")
5164			.and_where(Expr::col("role").eq("admin"));
5165
5166		let mut stmt = Query::select();
5167		stmt.column("name")
5168			.from_subquery(subquery, Alias::new("sub"))
5169			.and_where(Expr::col("status").eq("active"));
5170
5171		// Act
5172		let (sql, values) = builder.build_select(&stmt);
5173
5174		// Assert: subquery param should be $1, outer param should be $2
5175		assert!(sql.contains("$1"));
5176		assert!(sql.contains("$2"));
5177		assert_eq!(values.len(), 2);
5178	}
5179
5180	// --- Phase 5: NULL Handling Tests ---
5181
5182	#[test]
5183	fn test_where_is_null() {
5184		let builder = PostgresQueryBuilder::new();
5185		let mut stmt = Query::select();
5186		stmt.column("name")
5187			.from("users")
5188			.and_where(Expr::col("deleted_at").is_null());
5189
5190		let (sql, values) = builder.build_select(&stmt);
5191		assert!(sql.contains("\"deleted_at\" IS"));
5192		assert!(sql.to_uppercase().contains("NULL"));
5193		assert_eq!(values.len(), 0);
5194	}
5195
5196	#[test]
5197	fn test_where_is_not_null() {
5198		let builder = PostgresQueryBuilder::new();
5199		let mut stmt = Query::select();
5200		stmt.column("name")
5201			.from("users")
5202			.and_where(Expr::col("email").is_not_null());
5203
5204		let (sql, values) = builder.build_select(&stmt);
5205		assert!(sql.contains("\"email\" IS NOT"));
5206		assert!(sql.to_uppercase().contains("NULL"));
5207		assert_eq!(values.len(), 0);
5208	}
5209
5210	#[test]
5211	fn test_is_null_combined_with_other_conditions() {
5212		let builder = PostgresQueryBuilder::new();
5213		let mut stmt = Query::select();
5214		stmt.column("name")
5215			.from("users")
5216			.and_where(Expr::col("active").eq(true))
5217			.and_where(Expr::col("deleted_at").is_null())
5218			.and_where(Expr::col("email").is_not_null());
5219
5220		let (sql, values) = builder.build_select(&stmt);
5221		assert!(sql.contains("\"active\" = $"));
5222		assert!(sql.contains("\"deleted_at\" IS"));
5223		assert!(sql.contains("\"email\" IS NOT"));
5224		assert_eq!(values.len(), 1);
5225	}
5226
5227	#[test]
5228	fn test_is_null_with_join() {
5229		let builder = PostgresQueryBuilder::new();
5230		let mut stmt = Query::select();
5231		stmt.column(("users", "name"))
5232			.from("users")
5233			.left_join(
5234				"profiles",
5235				Expr::col(("users", "id")).eq(Expr::col(("profiles", "user_id"))),
5236			)
5237			.and_where(Expr::col(("profiles", "id")).is_null());
5238
5239		let (sql, values) = builder.build_select(&stmt);
5240		assert!(sql.contains("LEFT JOIN \"profiles\""));
5241		assert!(sql.contains("\"profiles\".\"id\" IS"));
5242		assert_eq!(values.len(), 0);
5243	}
5244
5245	// --- Phase 5: Complex WHERE Clause Tests ---
5246	#[test]
5247	fn test_where_or_condition() {
5248		use crate::expr::Condition;
5249
5250		let builder = PostgresQueryBuilder::new();
5251		let mut stmt = Query::select();
5252		stmt.column("name").from("users").cond_where(
5253			Condition::any()
5254				.add(Expr::col("status").eq("active"))
5255				.add(Expr::col("status").eq("pending")),
5256		);
5257
5258		let (sql, values) = builder.build_select(&stmt);
5259		assert!(sql.contains("\"status\" = $"));
5260		assert!(sql.contains(" OR "));
5261		assert_eq!(values.len(), 2);
5262	}
5263
5264	#[test]
5265	fn test_where_between() {
5266		let builder = PostgresQueryBuilder::new();
5267		let mut stmt = Query::select();
5268		stmt.column("name")
5269			.from("products")
5270			.and_where(Expr::col("price").between(100, 500));
5271
5272		let (sql, values) = builder.build_select(&stmt);
5273		assert!(sql.contains("\"price\" BETWEEN $"));
5274		assert!(sql.contains("AND $"));
5275		assert_eq!(values.len(), 2);
5276	}
5277
5278	#[test]
5279	fn test_where_not_between() {
5280		let builder = PostgresQueryBuilder::new();
5281		let mut stmt = Query::select();
5282		stmt.column("name")
5283			.from("products")
5284			.and_where(Expr::col("price").not_between(0, 10));
5285
5286		let (sql, values) = builder.build_select(&stmt);
5287		assert!(sql.contains("\"price\" NOT BETWEEN $"));
5288		assert!(sql.contains("AND $"));
5289		assert_eq!(values.len(), 2);
5290	}
5291
5292	#[test]
5293	fn test_where_like() {
5294		let builder = PostgresQueryBuilder::new();
5295		let mut stmt = Query::select();
5296		stmt.column("name")
5297			.from("users")
5298			.and_where(Expr::col("email").like("%@gmail.com"));
5299
5300		let (sql, values) = builder.build_select(&stmt);
5301		assert!(sql.contains("\"email\" LIKE $"));
5302		assert_eq!(values.len(), 1);
5303	}
5304
5305	#[test]
5306	fn test_where_in_values() {
5307		let builder = PostgresQueryBuilder::new();
5308		let mut stmt = Query::select();
5309		stmt.column("name")
5310			.from("users")
5311			.and_where(Expr::col("role").is_in(vec!["admin", "moderator", "editor"]));
5312
5313		let (sql, values) = builder.build_select(&stmt);
5314		assert!(sql.contains("\"role\" IN"));
5315		assert_eq!(values.len(), 3);
5316	}
5317
5318	#[test]
5319	fn test_insert_with_null_value() {
5320		use crate::value::Value;
5321
5322		let builder = PostgresQueryBuilder::new();
5323		let mut stmt = Query::insert();
5324		stmt.into_table("users")
5325			.columns(vec!["name", "email", "phone"])
5326			.values(vec![
5327				Value::String(Some(Box::new("John".to_string()))),
5328				Value::String(Some(Box::new("john@example.com".to_string()))),
5329				Value::String(None),
5330			])
5331			.unwrap();
5332
5333		let (sql, values) = builder.build_insert(&stmt);
5334		assert!(sql.contains("INSERT INTO \"users\""));
5335		assert!(sql.contains("\"name\""));
5336		assert!(sql.contains("\"email\""));
5337		assert!(sql.contains("\"phone\""));
5338		// NULL values are inlined directly, not parameterized
5339		assert!(sql.contains("NULL"));
5340		assert_eq!(values.len(), 2);
5341	}
5342
5343	#[test]
5344	fn test_select_with_single_cte() {
5345		let builder = PostgresQueryBuilder::new();
5346
5347		// Create CTE query
5348		let mut cte_query = Query::select();
5349		cte_query
5350			.column("id")
5351			.column("name")
5352			.from("employees")
5353			.and_where(Expr::col("department").eq("Engineering"));
5354
5355		// Main query using the CTE
5356		let mut stmt = Query::select();
5357		stmt.with_cte("eng_employees", cte_query)
5358			.column("name")
5359			.from("eng_employees");
5360
5361		let (sql, _values) = builder.build_select(&stmt);
5362		assert!(sql.contains("WITH"));
5363		assert!(sql.contains("\"eng_employees\""));
5364		assert!(sql.contains("AS"));
5365		assert!(sql.contains("SELECT \"id\", \"name\" FROM \"employees\""));
5366		assert!(sql.contains("SELECT \"name\" FROM \"eng_employees\""));
5367	}
5368
5369	#[test]
5370	fn test_select_with_multiple_ctes() {
5371		let builder = PostgresQueryBuilder::new();
5372
5373		// First CTE
5374		let mut cte1 = Query::select();
5375		cte1.column("id")
5376			.column("name")
5377			.from("employees")
5378			.and_where(Expr::col("department").eq("Engineering"));
5379
5380		// Second CTE
5381		let mut cte2 = Query::select();
5382		cte2.column("id")
5383			.column("name")
5384			.from("employees")
5385			.and_where(Expr::col("department").eq("Sales"));
5386
5387		// Main query using both CTEs
5388		let mut stmt = Query::select();
5389		stmt.with_cte("eng_emp", cte1)
5390			.with_cte("sales_emp", cte2)
5391			.column("name")
5392			.from("eng_emp");
5393
5394		let (sql, _values) = builder.build_select(&stmt);
5395		assert!(sql.contains("WITH"));
5396		assert!(sql.contains("\"eng_emp\""));
5397		assert!(sql.contains("\"sales_emp\""));
5398		assert!(sql.contains("AS"));
5399		// Both CTEs should be present, and there should be a comma between them
5400		assert!(sql.contains("\"eng_emp\" AS"));
5401		assert!(sql.contains("\"sales_emp\" AS"));
5402	}
5403
5404	#[test]
5405	fn test_select_with_recursive_cte() {
5406		let builder = PostgresQueryBuilder::new();
5407
5408		// Recursive CTE for organizational hierarchy
5409		let mut cte_query = Query::select();
5410		cte_query
5411			.column("id")
5412			.column("name")
5413			.column("manager_id")
5414			.from("employees");
5415
5416		// Main query using recursive CTE
5417		let mut stmt = Query::select();
5418		stmt.with_recursive_cte("employee_hierarchy", cte_query)
5419			.column("name")
5420			.from("employee_hierarchy");
5421
5422		let (sql, _values) = builder.build_select(&stmt);
5423		assert!(sql.contains("WITH RECURSIVE"));
5424		assert!(sql.contains("\"employee_hierarchy\""));
5425		assert!(sql.contains("AS"));
5426		assert!(sql.contains("SELECT \"id\", \"name\", \"manager_id\" FROM \"employees\""));
5427		assert!(sql.contains("SELECT \"name\" FROM \"employee_hierarchy\""));
5428	}
5429
5430	// Window function tests
5431
5432	#[test]
5433	fn test_window_row_number_with_partition_and_order() {
5434		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5435
5436		let builder = PostgresQueryBuilder::new();
5437		let mut stmt = Query::select();
5438
5439		let window = WindowStatement {
5440			partition_by: vec![Expr::col("department").into_simple_expr()],
5441			order_by: vec![OrderExpr {
5442				expr: OrderExprKind::Column("salary".into_iden()),
5443				order: Order::Desc,
5444				nulls: None,
5445			}],
5446			frame: None,
5447		};
5448
5449		stmt.expr(Expr::row_number().over(window))
5450			.column("name")
5451			.from("employees");
5452
5453		let (sql, _values) = builder.build_select(&stmt);
5454		assert_eq!(
5455			sql,
5456			r#"SELECT ROW_NUMBER() OVER ( PARTITION BY "department" ORDER BY "salary" DESC ), "name" FROM "employees""#
5457		);
5458	}
5459
5460	#[test]
5461	fn test_window_row_number_order_only() {
5462		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5463
5464		let builder = PostgresQueryBuilder::new();
5465		let mut stmt = Query::select();
5466
5467		let window = WindowStatement {
5468			partition_by: vec![],
5469			order_by: vec![OrderExpr {
5470				expr: OrderExprKind::Column("id".into_iden()),
5471				order: Order::Asc,
5472				nulls: None,
5473			}],
5474			frame: None,
5475		};
5476
5477		stmt.expr(Expr::row_number().over(window)).from("users");
5478
5479		let (sql, _values) = builder.build_select(&stmt);
5480		assert_eq!(
5481			sql,
5482			r#"SELECT ROW_NUMBER() OVER ( ORDER BY "id" ASC ) FROM "users""#
5483		);
5484	}
5485
5486	#[test]
5487	fn test_window_rank_basic() {
5488		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5489
5490		let builder = PostgresQueryBuilder::new();
5491		let mut stmt = Query::select();
5492
5493		let window = WindowStatement {
5494			partition_by: vec![],
5495			order_by: vec![OrderExpr {
5496				expr: OrderExprKind::Column("score".into_iden()),
5497				order: Order::Desc,
5498				nulls: None,
5499			}],
5500			frame: None,
5501		};
5502
5503		stmt.expr(Expr::rank().over(window))
5504			.column("name")
5505			.from("students");
5506
5507		let (sql, _values) = builder.build_select(&stmt);
5508		assert_eq!(
5509			sql,
5510			r#"SELECT RANK() OVER ( ORDER BY "score" DESC ), "name" FROM "students""#
5511		);
5512	}
5513
5514	#[test]
5515	fn test_window_rank_with_partition() {
5516		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5517
5518		let builder = PostgresQueryBuilder::new();
5519		let mut stmt = Query::select();
5520
5521		let window = WindowStatement {
5522			partition_by: vec![Expr::col("class").into_simple_expr()],
5523			order_by: vec![OrderExpr {
5524				expr: OrderExprKind::Column("score".into_iden()),
5525				order: Order::Desc,
5526				nulls: None,
5527			}],
5528			frame: None,
5529		};
5530
5531		stmt.expr(Expr::rank().over(window))
5532			.column("name")
5533			.from("students");
5534
5535		let (sql, _values) = builder.build_select(&stmt);
5536		assert_eq!(
5537			sql,
5538			r#"SELECT RANK() OVER ( PARTITION BY "class" ORDER BY "score" DESC ), "name" FROM "students""#
5539		);
5540	}
5541
5542	#[test]
5543	fn test_window_dense_rank_basic() {
5544		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5545
5546		let builder = PostgresQueryBuilder::new();
5547		let mut stmt = Query::select();
5548
5549		let window = WindowStatement {
5550			partition_by: vec![],
5551			order_by: vec![OrderExpr {
5552				expr: OrderExprKind::Column("points".into_iden()),
5553				order: Order::Desc,
5554				nulls: None,
5555			}],
5556			frame: None,
5557		};
5558
5559		stmt.expr(Expr::dense_rank().over(window))
5560			.column("player")
5561			.from("scores");
5562
5563		let (sql, _values) = builder.build_select(&stmt);
5564		assert_eq!(
5565			sql,
5566			r#"SELECT DENSE_RANK() OVER ( ORDER BY "points" DESC ), "player" FROM "scores""#
5567		);
5568	}
5569
5570	#[test]
5571	fn test_window_dense_rank_with_partition() {
5572		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5573
5574		let builder = PostgresQueryBuilder::new();
5575		let mut stmt = Query::select();
5576
5577		let window = WindowStatement {
5578			partition_by: vec![Expr::col("league").into_simple_expr()],
5579			order_by: vec![OrderExpr {
5580				expr: OrderExprKind::Column("points".into_iden()),
5581				order: Order::Desc,
5582				nulls: None,
5583			}],
5584			frame: None,
5585		};
5586
5587		stmt.expr(Expr::dense_rank().over(window))
5588			.column("player")
5589			.from("scores");
5590
5591		let (sql, _values) = builder.build_select(&stmt);
5592		assert_eq!(
5593			sql,
5594			r#"SELECT DENSE_RANK() OVER ( PARTITION BY "league" ORDER BY "points" DESC ), "player" FROM "scores""#
5595		);
5596	}
5597
5598	#[test]
5599	fn test_window_ntile_four_buckets() {
5600		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5601
5602		let builder = PostgresQueryBuilder::new();
5603		let mut stmt = Query::select();
5604
5605		let window = WindowStatement {
5606			partition_by: vec![],
5607			order_by: vec![OrderExpr {
5608				expr: OrderExprKind::Column("salary".into_iden()),
5609				order: Order::Asc,
5610				nulls: None,
5611			}],
5612			frame: None,
5613		};
5614
5615		stmt.expr(Expr::ntile(4).over(window))
5616			.column("name")
5617			.from("employees");
5618
5619		let (sql, _values) = builder.build_select(&stmt);
5620		assert_eq!(
5621			sql,
5622			r#"SELECT NTILE($1) OVER ( ORDER BY "salary" ASC ), "name" FROM "employees""#
5623		);
5624	}
5625
5626	#[test]
5627	fn test_window_ntile_custom_buckets() {
5628		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5629
5630		let builder = PostgresQueryBuilder::new();
5631		let mut stmt = Query::select();
5632
5633		let window = WindowStatement {
5634			partition_by: vec![Expr::col("department").into_simple_expr()],
5635			order_by: vec![OrderExpr {
5636				expr: OrderExprKind::Column("salary".into_iden()),
5637				order: Order::Desc,
5638				nulls: None,
5639			}],
5640			frame: None,
5641		};
5642
5643		stmt.expr(Expr::ntile(3).over(window))
5644			.column("name")
5645			.from("employees");
5646
5647		let (sql, _values) = builder.build_select(&stmt);
5648		assert_eq!(
5649			sql,
5650			r#"SELECT NTILE($1) OVER ( PARTITION BY "department" ORDER BY "salary" DESC ), "name" FROM "employees""#
5651		);
5652	}
5653
5654	#[test]
5655	fn test_window_lead_basic() {
5656		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5657
5658		let builder = PostgresQueryBuilder::new();
5659		let mut stmt = Query::select();
5660
5661		let window = WindowStatement {
5662			partition_by: vec![],
5663			order_by: vec![OrderExpr {
5664				expr: OrderExprKind::Column("date".into_iden()),
5665				order: Order::Asc,
5666				nulls: None,
5667			}],
5668			frame: None,
5669		};
5670
5671		stmt.expr(Expr::lead(Expr::col("price").into_simple_expr(), None, None).over(window))
5672			.column("date")
5673			.from("stocks");
5674
5675		let (sql, values) = builder.build_select(&stmt);
5676		assert_eq!(
5677			sql,
5678			r#"SELECT LEAD("price") OVER ( ORDER BY "date" ASC ), "date" FROM "stocks""#
5679		);
5680		assert_eq!(values.len(), 0);
5681	}
5682
5683	#[test]
5684	fn test_window_lead_with_offset_and_default() {
5685		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5686
5687		let builder = PostgresQueryBuilder::new();
5688		let mut stmt = Query::select();
5689
5690		let window = WindowStatement {
5691			partition_by: vec![Expr::col("ticker").into_simple_expr()],
5692			order_by: vec![OrderExpr {
5693				expr: OrderExprKind::Column("date".into_iden()),
5694				order: Order::Asc,
5695				nulls: None,
5696			}],
5697			frame: None,
5698		};
5699
5700		stmt.expr(
5701			Expr::lead(
5702				Expr::col("price").into_simple_expr(),
5703				Some(2),
5704				Some(0.0.into()),
5705			)
5706			.over(window),
5707		)
5708		.column("date")
5709		.from("stocks");
5710
5711		let (sql, values) = builder.build_select(&stmt);
5712		assert!(sql.contains("LEAD"));
5713		assert!(sql.contains("OVER"));
5714		assert!(sql.contains(r#"PARTITION BY "ticker""#));
5715		assert!(sql.contains(r#"ORDER BY "date" ASC"#));
5716		assert_eq!(values.len(), 2);
5717	}
5718
5719	#[test]
5720	fn test_window_lag_basic() {
5721		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5722
5723		let builder = PostgresQueryBuilder::new();
5724		let mut stmt = Query::select();
5725
5726		let window = WindowStatement {
5727			partition_by: vec![],
5728			order_by: vec![OrderExpr {
5729				expr: OrderExprKind::Column("month".into_iden()),
5730				order: Order::Asc,
5731				nulls: None,
5732			}],
5733			frame: None,
5734		};
5735
5736		stmt.expr(Expr::lag(Expr::col("revenue").into_simple_expr(), None, None).over(window))
5737			.column("month")
5738			.from("sales");
5739
5740		let (sql, values) = builder.build_select(&stmt);
5741		assert_eq!(
5742			sql,
5743			r#"SELECT LAG("revenue") OVER ( ORDER BY "month" ASC ), "month" FROM "sales""#
5744		);
5745		assert_eq!(values.len(), 0);
5746	}
5747
5748	#[test]
5749	fn test_window_lag_with_offset_and_default() {
5750		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5751
5752		let builder = PostgresQueryBuilder::new();
5753		let mut stmt = Query::select();
5754
5755		let window = WindowStatement {
5756			partition_by: vec![Expr::col("product").into_simple_expr()],
5757			order_by: vec![OrderExpr {
5758				expr: OrderExprKind::Column("month".into_iden()),
5759				order: Order::Asc,
5760				nulls: None,
5761			}],
5762			frame: None,
5763		};
5764
5765		stmt.expr(
5766			Expr::lag(
5767				Expr::col("revenue").into_simple_expr(),
5768				Some(3),
5769				Some(0.0.into()),
5770			)
5771			.over(window),
5772		)
5773		.column("month")
5774		.from("sales");
5775
5776		let (sql, values) = builder.build_select(&stmt);
5777		assert!(sql.contains("LAG"));
5778		assert!(sql.contains("OVER"));
5779		assert!(sql.contains(r#"PARTITION BY "product""#));
5780		assert!(sql.contains(r#"ORDER BY "month" ASC"#));
5781		assert_eq!(values.len(), 2);
5782	}
5783
5784	#[test]
5785	fn test_window_first_value() {
5786		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5787
5788		let builder = PostgresQueryBuilder::new();
5789		let mut stmt = Query::select();
5790
5791		let window = WindowStatement {
5792			partition_by: vec![Expr::col("category").into_simple_expr()],
5793			order_by: vec![OrderExpr {
5794				expr: OrderExprKind::Column("price".into_iden()),
5795				order: Order::Asc,
5796				nulls: None,
5797			}],
5798			frame: None,
5799		};
5800
5801		stmt.expr(Expr::first_value(Expr::col("name").into_simple_expr()).over(window))
5802			.column("name")
5803			.from("products");
5804
5805		let (sql, _values) = builder.build_select(&stmt);
5806		assert_eq!(
5807			sql,
5808			r#"SELECT FIRST_VALUE("name") OVER ( PARTITION BY "category" ORDER BY "price" ASC ), "name" FROM "products""#
5809		);
5810	}
5811
5812	#[test]
5813	fn test_window_last_value() {
5814		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5815
5816		let builder = PostgresQueryBuilder::new();
5817		let mut stmt = Query::select();
5818
5819		let window = WindowStatement {
5820			partition_by: vec![Expr::col("category").into_simple_expr()],
5821			order_by: vec![OrderExpr {
5822				expr: OrderExprKind::Column("price".into_iden()),
5823				order: Order::Desc,
5824				nulls: None,
5825			}],
5826			frame: None,
5827		};
5828
5829		stmt.expr(Expr::last_value(Expr::col("name").into_simple_expr()).over(window))
5830			.column("name")
5831			.from("products");
5832
5833		let (sql, _values) = builder.build_select(&stmt);
5834		assert_eq!(
5835			sql,
5836			r#"SELECT LAST_VALUE("name") OVER ( PARTITION BY "category" ORDER BY "price" DESC ), "name" FROM "products""#
5837		);
5838	}
5839
5840	#[test]
5841	fn test_window_nth_value() {
5842		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5843
5844		let builder = PostgresQueryBuilder::new();
5845		let mut stmt = Query::select();
5846
5847		let window = WindowStatement {
5848			partition_by: vec![Expr::col("department").into_simple_expr()],
5849			order_by: vec![OrderExpr {
5850				expr: OrderExprKind::Column("salary".into_iden()),
5851				order: Order::Desc,
5852				nulls: None,
5853			}],
5854			frame: None,
5855		};
5856
5857		stmt.expr(Expr::nth_value(Expr::col("name").into_simple_expr(), 2).over(window))
5858			.column("name")
5859			.from("employees");
5860
5861		let (sql, values) = builder.build_select(&stmt);
5862		assert!(sql.contains("NTH_VALUE"));
5863		assert!(sql.contains(r#"PARTITION BY "department""#));
5864		assert!(sql.contains(r#"ORDER BY "salary" DESC"#));
5865		assert_eq!(values.len(), 1); // The "2" parameter
5866	}
5867
5868	#[test]
5869	fn test_window_row_number_multiple_partition_columns() {
5870		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5871
5872		let builder = PostgresQueryBuilder::new();
5873		let mut stmt = Query::select();
5874
5875		let window = WindowStatement {
5876			partition_by: vec![
5877				Expr::col("country").into_simple_expr(),
5878				Expr::col("city").into_simple_expr(),
5879			],
5880			order_by: vec![OrderExpr {
5881				expr: OrderExprKind::Column("population".into_iden()),
5882				order: Order::Desc,
5883				nulls: None,
5884			}],
5885			frame: None,
5886		};
5887
5888		stmt.expr(Expr::row_number().over(window))
5889			.column("name")
5890			.from("cities");
5891
5892		let (sql, _values) = builder.build_select(&stmt);
5893		assert_eq!(
5894			sql,
5895			r#"SELECT ROW_NUMBER() OVER ( PARTITION BY "country", "city" ORDER BY "population" DESC ), "name" FROM "cities""#
5896		);
5897	}
5898
5899	#[test]
5900	fn test_window_ntile_with_partition() {
5901		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5902
5903		let builder = PostgresQueryBuilder::new();
5904		let mut stmt = Query::select();
5905
5906		let window = WindowStatement {
5907			partition_by: vec![Expr::col("region").into_simple_expr()],
5908			order_by: vec![OrderExpr {
5909				expr: OrderExprKind::Column("revenue".into_iden()),
5910				order: Order::Desc,
5911				nulls: None,
5912			}],
5913			frame: None,
5914		};
5915
5916		stmt.expr(Expr::ntile(5).over(window))
5917			.column("store_name")
5918			.from("stores");
5919
5920		let (sql, _values) = builder.build_select(&stmt);
5921		assert_eq!(
5922			sql,
5923			r#"SELECT NTILE($1) OVER ( PARTITION BY "region" ORDER BY "revenue" DESC ), "store_name" FROM "stores""#
5924		);
5925	}
5926
5927	#[test]
5928	fn test_window_lead_with_offset_no_default() {
5929		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5930
5931		let builder = PostgresQueryBuilder::new();
5932		let mut stmt = Query::select();
5933
5934		let window = WindowStatement {
5935			partition_by: vec![],
5936			order_by: vec![OrderExpr {
5937				expr: OrderExprKind::Column("quarter".into_iden()),
5938				order: Order::Asc,
5939				nulls: None,
5940			}],
5941			frame: None,
5942		};
5943
5944		stmt.expr(Expr::lead(Expr::col("sales").into_simple_expr(), Some(2), None).over(window))
5945			.column("quarter")
5946			.from("quarterly_sales");
5947
5948		let (sql, _values) = builder.build_select(&stmt);
5949		assert_eq!(
5950			sql,
5951			r#"SELECT LEAD("sales", $1) OVER ( ORDER BY "quarter" ASC ), "quarter" FROM "quarterly_sales""#
5952		);
5953	}
5954
5955	#[test]
5956	fn test_window_lag_with_different_offset() {
5957		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5958
5959		let builder = PostgresQueryBuilder::new();
5960		let mut stmt = Query::select();
5961
5962		let window = WindowStatement {
5963			partition_by: vec![Expr::col("sensor_id").into_simple_expr()],
5964			order_by: vec![OrderExpr {
5965				expr: OrderExprKind::Column("timestamp".into_iden()),
5966				order: Order::Asc,
5967				nulls: None,
5968			}],
5969			frame: None,
5970		};
5971
5972		stmt.expr(Expr::lag(Expr::col("reading").into_simple_expr(), Some(5), None).over(window))
5973			.column("timestamp")
5974			.from("sensor_data");
5975
5976		let (sql, values) = builder.build_select(&stmt);
5977		assert_eq!(
5978			sql,
5979			r#"SELECT LAG("reading", $1) OVER ( PARTITION BY "sensor_id" ORDER BY "timestamp" ASC ), "timestamp" FROM "sensor_data""#
5980		);
5981		assert_eq!(values.len(), 1);
5982	}
5983
5984	#[test]
5985	fn test_window_multiple_functions_in_query() {
5986		use crate::types::{Order, OrderExpr, OrderExprKind, WindowStatement};
5987
5988		let builder = PostgresQueryBuilder::new();
5989		let mut stmt = Query::select();
5990
5991		let window1 = WindowStatement {
5992			partition_by: vec![Expr::col("department").into_simple_expr()],
5993			order_by: vec![OrderExpr {
5994				expr: OrderExprKind::Column("salary".into_iden()),
5995				order: Order::Desc,
5996				nulls: None,
5997			}],
5998			frame: None,
5999		};
6000
6001		let window2 = WindowStatement {
6002			partition_by: vec![],
6003			order_by: vec![OrderExpr {
6004				expr: OrderExprKind::Column("hire_date".into_iden()),
6005				order: Order::Asc,
6006				nulls: None,
6007			}],
6008			frame: None,
6009		};
6010
6011		stmt.expr(Expr::row_number().over(window1))
6012			.expr(Expr::rank().over(window2))
6013			.column("name")
6014			.from("employees");
6015
6016		let (sql, _values) = builder.build_select(&stmt);
6017		assert!(
6018			sql.contains(
6019				r#"ROW_NUMBER() OVER ( PARTITION BY "department" ORDER BY "salary" DESC )"#
6020			)
6021		);
6022		assert!(sql.contains(r#"RANK() OVER ( ORDER BY "hire_date" ASC )"#));
6023		assert!(sql.contains(r#""name""#));
6024		assert!(sql.contains(r#"FROM "employees""#));
6025	}
6026
6027	// JOIN enhancement tests
6028
6029	#[test]
6030	fn test_join_three_tables() {
6031		let builder = PostgresQueryBuilder::new();
6032		let mut stmt = Query::select();
6033		stmt.column(("users", "name"))
6034			.column(("orders", "order_date"))
6035			.column(("products", "product_name"))
6036			.from("users")
6037			.inner_join(
6038				"orders",
6039				Expr::col(("users", "id")).eq(Expr::col(("orders", "user_id"))),
6040			)
6041			.inner_join(
6042				"products",
6043				Expr::col(("orders", "product_id")).eq(Expr::col(("products", "id"))),
6044			);
6045
6046		let (sql, _values) = builder.build_select(&stmt);
6047		assert_eq!(
6048			sql,
6049			r#"SELECT "users"."name", "orders"."order_date", "products"."product_name" FROM "users" INNER JOIN "orders" ON "users"."id" = "orders"."user_id" INNER JOIN "products" ON "orders"."product_id" = "products"."id""#
6050		);
6051	}
6052
6053	#[test]
6054	fn test_self_join() {
6055		use crate::types::TableRef;
6056
6057		let builder = PostgresQueryBuilder::new();
6058		let mut stmt = Query::select();
6059		stmt.column(("e1", "name"))
6060			.column(("e2", "name"))
6061			.from(TableRef::table_alias("employees", "e1"))
6062			.inner_join(
6063				TableRef::table_alias("employees", "e2"),
6064				Expr::col(("e1", "manager_id")).eq(Expr::col(("e2", "id"))),
6065			);
6066
6067		let (sql, _values) = builder.build_select(&stmt);
6068		assert!(sql.contains(r#"FROM "employees" AS "e1""#));
6069		assert!(sql.contains(r#"INNER JOIN "employees" AS "e2""#));
6070		assert!(sql.contains(r#"ON "e1"."manager_id" = "e2"."id""#));
6071	}
6072
6073	#[test]
6074	fn test_join_complex_conditions() {
6075		let builder = PostgresQueryBuilder::new();
6076		let mut stmt = Query::select();
6077		stmt.from("orders").left_join(
6078			"customers",
6079			Expr::col(("orders", "customer_id"))
6080				.eq(Expr::col(("customers", "id")))
6081				.and(Expr::col(("customers", "active")).eq(true))
6082				.and(
6083					Expr::col(("orders", "created_at"))
6084						.gt(Expr::col(("customers", "registered_at"))),
6085				),
6086		);
6087
6088		let (sql, values) = builder.build_select(&stmt);
6089		assert!(sql.contains("LEFT JOIN \"customers\""));
6090		assert!(sql.contains("\"orders\".\"customer_id\" = \"customers\".\"id\""));
6091		assert!(sql.contains("AND \"customers\".\"active\" = $"));
6092		assert!(sql.contains("AND \"orders\".\"created_at\" > \"customers\".\"registered_at\""));
6093		assert_eq!(values.len(), 1); // true value
6094	}
6095
6096	#[test]
6097	fn test_join_with_subquery_in_condition() {
6098		let builder = PostgresQueryBuilder::new();
6099
6100		let mut subquery = Query::select();
6101		subquery.expr(Expr::col("max_id")).from("user_stats");
6102
6103		let mut stmt = Query::select();
6104		stmt.from("users").inner_join(
6105			"profiles",
6106			Expr::col(("users", "id"))
6107				.eq(Expr::col(("profiles", "user_id")))
6108				.and(Expr::col(("users", "id")).in_subquery(subquery)),
6109		);
6110
6111		let (sql, _values) = builder.build_select(&stmt);
6112		assert!(sql.contains("INNER JOIN \"profiles\""));
6113		assert!(sql.contains("\"users\".\"id\" = \"profiles\".\"user_id\""));
6114		assert!(sql.contains("IN"));
6115		assert!(sql.contains("SELECT \"max_id\" FROM \"user_stats\""));
6116	}
6117
6118	#[test]
6119	fn test_multiple_left_joins() {
6120		let builder = PostgresQueryBuilder::new();
6121		let mut stmt = Query::select();
6122		stmt.column(("users", "name"))
6123			.column(("profiles", "bio"))
6124			.column(("addresses", "city"))
6125			.column(("phone_numbers", "number"))
6126			.from("users")
6127			.left_join(
6128				"profiles",
6129				Expr::col(("users", "id")).eq(Expr::col(("profiles", "user_id"))),
6130			)
6131			.left_join(
6132				"addresses",
6133				Expr::col(("users", "id")).eq(Expr::col(("addresses", "user_id"))),
6134			)
6135			.left_join(
6136				"phone_numbers",
6137				Expr::col(("users", "id")).eq(Expr::col(("phone_numbers", "user_id"))),
6138			);
6139
6140		let (sql, _values) = builder.build_select(&stmt);
6141		assert!(sql.contains("LEFT JOIN \"profiles\""));
6142		assert!(sql.contains("LEFT JOIN \"addresses\""));
6143		assert!(sql.contains("LEFT JOIN \"phone_numbers\""));
6144	}
6145
6146	#[test]
6147	fn test_mixed_join_types() {
6148		let builder = PostgresQueryBuilder::new();
6149		let mut stmt = Query::select();
6150		stmt.column(("users", "name"))
6151			.from("users")
6152			.inner_join(
6153				"orders",
6154				Expr::col(("users", "id")).eq(Expr::col(("orders", "user_id"))),
6155			)
6156			.left_join(
6157				"reviews",
6158				Expr::col(("orders", "id")).eq(Expr::col(("reviews", "order_id"))),
6159			)
6160			.right_join(
6161				"refunds",
6162				Expr::col(("orders", "id")).eq(Expr::col(("refunds", "order_id"))),
6163			);
6164
6165		let (sql, _values) = builder.build_select(&stmt);
6166		assert!(sql.contains("INNER JOIN \"orders\""));
6167		assert!(sql.contains("LEFT JOIN \"reviews\""));
6168		assert!(sql.contains("RIGHT JOIN \"refunds\""));
6169	}
6170
6171	#[test]
6172	fn test_join_with_group_by() {
6173		use crate::expr::SimpleExpr;
6174		use crate::types::{BinOper, ColumnRef, IntoIden};
6175
6176		let builder = PostgresQueryBuilder::new();
6177		let mut stmt = Query::select();
6178		let count_expr = SimpleExpr::FunctionCall(
6179			"COUNT".into_iden(),
6180			vec![SimpleExpr::Column(ColumnRef::Asterisk)],
6181		);
6182
6183		stmt.column(("users", "name"))
6184			.expr(count_expr.clone())
6185			.from("users")
6186			.inner_join(
6187				"orders",
6188				Expr::col(("users", "id")).eq(Expr::col(("orders", "user_id"))),
6189			)
6190			.group_by(("users", "name"))
6191			.and_having(SimpleExpr::Binary(
6192				Box::new(count_expr),
6193				BinOper::GreaterThan,
6194				Box::new(SimpleExpr::Value(5.into())),
6195			));
6196
6197		let (sql, values) = builder.build_select(&stmt);
6198		assert!(sql.contains("INNER JOIN \"orders\""));
6199		assert!(sql.contains("GROUP BY \"users\".\"name\""));
6200		assert!(sql.contains("HAVING"));
6201		assert!(sql.contains("COUNT(*) > $"));
6202		assert_eq!(values.len(), 1);
6203	}
6204
6205	#[test]
6206	fn test_join_with_window_function() {
6207		use crate::types::{IntoIden, Order, OrderExpr, OrderExprKind, WindowStatement};
6208
6209		let builder = PostgresQueryBuilder::new();
6210		let mut stmt = Query::select();
6211
6212		let window = WindowStatement {
6213			partition_by: vec![Expr::col(("departments", "name")).into_simple_expr()],
6214			order_by: vec![OrderExpr {
6215				expr: OrderExprKind::TableColumn("employees".into_iden(), "salary".into_iden()),
6216				order: Order::Desc,
6217				nulls: None,
6218			}],
6219			frame: None,
6220		};
6221
6222		stmt.column(("employees", "name"))
6223			.expr(Expr::row_number().over(window))
6224			.from("employees")
6225			.inner_join(
6226				"departments",
6227				Expr::col(("employees", "department_id")).eq(Expr::col(("departments", "id"))),
6228			);
6229
6230		let (sql, _values) = builder.build_select(&stmt);
6231		assert!(sql.contains("INNER JOIN \"departments\""));
6232		assert!(sql.contains("ROW_NUMBER() OVER"));
6233		assert!(sql.contains(r#"PARTITION BY "departments"."name""#));
6234	}
6235
6236	#[test]
6237	fn test_four_table_join() {
6238		let builder = PostgresQueryBuilder::new();
6239		let mut stmt = Query::select();
6240		stmt.column(("users", "name"))
6241			.column(("orders", "order_date"))
6242			.column(("products", "product_name"))
6243			.column(("categories", "category_name"))
6244			.from("users")
6245			.inner_join(
6246				"orders",
6247				Expr::col(("users", "id")).eq(Expr::col(("orders", "user_id"))),
6248			)
6249			.inner_join(
6250				"products",
6251				Expr::col(("orders", "product_id")).eq(Expr::col(("products", "id"))),
6252			)
6253			.inner_join(
6254				"categories",
6255				Expr::col(("products", "category_id")).eq(Expr::col(("categories", "id"))),
6256			);
6257
6258		let (sql, _values) = builder.build_select(&stmt);
6259		assert!(sql.contains("FROM \"users\""));
6260		assert!(sql.contains("INNER JOIN \"orders\""));
6261		assert!(sql.contains("INNER JOIN \"products\""));
6262		assert!(sql.contains("INNER JOIN \"categories\""));
6263	}
6264
6265	#[test]
6266	fn test_join_with_cte() {
6267		use crate::types::TableRef;
6268
6269		let builder = PostgresQueryBuilder::new();
6270
6271		let mut cte = Query::select();
6272		cte.column("user_id")
6273			.expr(Expr::col("total"))
6274			.from("order_totals")
6275			.and_where(Expr::col("total").gt(1000));
6276
6277		let mut stmt = Query::select();
6278		stmt.with_cte("high_value_customers", cte)
6279			.column(("users", "name"))
6280			.column(("hvc", "total"))
6281			.from("users")
6282			.inner_join(
6283				TableRef::table_alias("high_value_customers", "hvc"),
6284				Expr::col(("users", "id")).eq(Expr::col(("hvc", "user_id"))),
6285			);
6286
6287		let (sql, values) = builder.build_select(&stmt);
6288		assert!(sql.contains("WITH \"high_value_customers\" AS"));
6289		assert!(sql.contains("INNER JOIN \"high_value_customers\" AS \"hvc\""));
6290		assert_eq!(values.len(), 1); // 1000
6291	}
6292
6293	#[test]
6294	fn test_cte_with_where_and_params() {
6295		let builder = PostgresQueryBuilder::new();
6296
6297		let mut cte_query = Query::select();
6298		cte_query
6299			.column("id")
6300			.column("total")
6301			.from("orders")
6302			.and_where(Expr::col("status").eq("completed"))
6303			.and_where(Expr::col("amount").gt(1000));
6304
6305		let mut stmt = Query::select();
6306		stmt.with_cte("large_orders", cte_query)
6307			.column("id")
6308			.column("total")
6309			.from("large_orders");
6310
6311		let (sql, values) = builder.build_select(&stmt);
6312		assert!(sql.contains("WITH"));
6313		assert!(sql.contains(r#""large_orders" AS"#));
6314		assert!(sql.contains(r#""status" = $"#));
6315		assert!(sql.contains(r#""amount" > $"#));
6316		assert_eq!(values.len(), 2);
6317	}
6318
6319	#[test]
6320	fn test_cte_used_in_join() {
6321		use crate::types::TableRef;
6322
6323		let builder = PostgresQueryBuilder::new();
6324
6325		let mut cte_query = Query::select();
6326		cte_query
6327			.column("user_id")
6328			.column("order_count")
6329			.from("orders")
6330			.group_by("user_id");
6331
6332		let mut stmt = Query::select();
6333		stmt.with_cte("user_orders", cte_query)
6334			.column(("users", "name"))
6335			.column(("uo", "order_count"))
6336			.from("users")
6337			.inner_join(
6338				TableRef::table_alias("user_orders", "uo"),
6339				Expr::col(("users", "id")).eq(Expr::col(("uo", "user_id"))),
6340			);
6341
6342		let (sql, values) = builder.build_select(&stmt);
6343		assert!(sql.contains("WITH"));
6344		assert!(sql.contains(r#""user_orders" AS"#));
6345		assert!(sql.contains(r#"INNER JOIN "user_orders" AS "uo""#));
6346		assert!(sql.contains(r#""users"."id" = "uo"."user_id""#));
6347		assert_eq!(values.len(), 0);
6348	}
6349
6350	#[test]
6351	fn test_cte_with_aggregation() {
6352		use crate::expr::SimpleExpr;
6353		use crate::types::{ColumnRef, IntoIden};
6354
6355		let builder = PostgresQueryBuilder::new();
6356
6357		let mut cte_query = Query::select();
6358		cte_query
6359			.column("category")
6360			.expr(SimpleExpr::FunctionCall(
6361				"COUNT".into_iden(),
6362				vec![SimpleExpr::Column(ColumnRef::Asterisk)],
6363			))
6364			.expr(SimpleExpr::FunctionCall(
6365				"SUM".into_iden(),
6366				vec![SimpleExpr::Column(ColumnRef::column("price"))],
6367			))
6368			.from("products")
6369			.group_by("category");
6370
6371		let mut stmt = Query::select();
6372		stmt.with_cte("category_stats", cte_query)
6373			.column("category")
6374			.from("category_stats");
6375
6376		let (sql, values) = builder.build_select(&stmt);
6377		assert!(sql.contains("WITH"));
6378		assert!(sql.contains(r#""category_stats" AS"#));
6379		assert!(sql.contains("COUNT(*)"));
6380		assert!(sql.contains(r#"SUM("price")"#));
6381		assert!(sql.contains(r#"GROUP BY "category""#));
6382		assert_eq!(values.len(), 0);
6383	}
6384
6385	#[test]
6386	fn test_cte_with_subquery() {
6387		let builder = PostgresQueryBuilder::new();
6388
6389		let mut sub = Query::select();
6390		sub.column("user_id").from("vip_users");
6391
6392		let mut cte_query = Query::select();
6393		cte_query
6394			.column("id")
6395			.column("total")
6396			.from("orders")
6397			.and_where(Expr::col("user_id").in_subquery(sub))
6398			.and_where(Expr::col("status").eq("shipped"));
6399
6400		let mut stmt = Query::select();
6401		stmt.with_cte("vip_orders", cte_query)
6402			.column("id")
6403			.column("total")
6404			.from("vip_orders");
6405
6406		let (sql, values) = builder.build_select(&stmt);
6407		assert!(sql.contains("WITH"));
6408		assert!(sql.contains(r#""vip_orders" AS"#));
6409		assert!(sql.contains("IN"));
6410		assert!(sql.contains(r#"SELECT "user_id" FROM "vip_users""#));
6411		assert!(sql.contains(r#""status" = $"#));
6412		assert_eq!(values.len(), 1);
6413	}
6414
6415	#[test]
6416	fn test_multiple_recursive_and_regular_ctes() {
6417		let builder = PostgresQueryBuilder::new();
6418
6419		// Regular CTE
6420		let mut regular_cte = Query::select();
6421		regular_cte
6422			.column("id")
6423			.column("name")
6424			.from("departments")
6425			.and_where(Expr::col("active").eq(true));
6426
6427		// Recursive CTE
6428		let mut recursive_cte = Query::select();
6429		recursive_cte
6430			.column("id")
6431			.column("name")
6432			.column("parent_id")
6433			.from("categories");
6434
6435		// Main query
6436		let mut stmt = Query::select();
6437		stmt.with_cte("active_depts", regular_cte)
6438			.with_recursive_cte("category_tree", recursive_cte)
6439			.column("name")
6440			.from("category_tree");
6441
6442		let (sql, values) = builder.build_select(&stmt);
6443		assert!(sql.contains("WITH RECURSIVE"));
6444		assert!(sql.contains(r#""active_depts" AS"#));
6445		assert!(sql.contains(r#""category_tree" AS"#));
6446		assert!(sql.contains(r#""active" = $"#));
6447		assert!(sql.contains(r#"FROM "category_tree""#));
6448		assert_eq!(values.len(), 1);
6449	}
6450
6451	// CASE expression tests
6452
6453	#[test]
6454	fn test_case_simple_when_else() {
6455		let builder = PostgresQueryBuilder::new();
6456
6457		let case_expr = Expr::case()
6458			.when(Expr::col("status").eq("active"), "Active")
6459			.else_result("Inactive");
6460
6461		let mut stmt = Query::select();
6462		stmt.expr_as(case_expr, "status_label").from("users");
6463
6464		let (sql, values) = builder.build_select(&stmt);
6465		assert!(sql.contains("CASE"));
6466		assert!(sql.contains("WHEN"));
6467		assert!(sql.contains(r#""status" = $"#));
6468		assert!(sql.contains("THEN"));
6469		assert!(sql.contains("ELSE"));
6470		assert!(sql.contains("END"));
6471		assert!(sql.contains(r#"AS "status_label""#));
6472		assert_eq!(values.len(), 3);
6473	}
6474
6475	#[test]
6476	fn test_case_multiple_when_clauses() {
6477		let builder = PostgresQueryBuilder::new();
6478
6479		let case_expr = Expr::case()
6480			.when(Expr::col("score").gte(90), "A")
6481			.when(Expr::col("score").gte(80), "B")
6482			.when(Expr::col("score").gte(70), "C")
6483			.else_result("F");
6484
6485		let mut stmt = Query::select();
6486		stmt.expr_as(case_expr, "grade").from("students");
6487
6488		let (sql, values) = builder.build_select(&stmt);
6489		assert!(sql.contains("CASE"));
6490		// Verify multiple WHEN clauses
6491		let when_count = sql.matches("WHEN").count();
6492		assert_eq!(when_count, 3);
6493		let then_count = sql.matches("THEN").count();
6494		assert_eq!(then_count, 3);
6495		assert!(sql.contains("ELSE"));
6496		assert!(sql.contains("END"));
6497		// 3 score comparisons + 3 THEN values + 1 ELSE value = 7
6498		assert_eq!(values.len(), 7);
6499	}
6500
6501	#[test]
6502	fn test_case_without_else() {
6503		let builder = PostgresQueryBuilder::new();
6504
6505		let case_expr = Expr::case()
6506			.when(Expr::col("type").eq("admin"), "Administrator")
6507			.when(Expr::col("type").eq("user"), "Regular User")
6508			.build();
6509
6510		let mut stmt = Query::select();
6511		stmt.expr_as(case_expr, "type_label").from("accounts");
6512
6513		let (sql, values) = builder.build_select(&stmt);
6514		assert!(sql.contains("CASE"));
6515		assert!(sql.contains("WHEN"));
6516		assert!(sql.contains("THEN"));
6517		assert!(!sql.contains("ELSE"));
6518		assert!(sql.contains("END"));
6519		assert_eq!(values.len(), 4);
6520	}
6521
6522	#[test]
6523	fn test_case_in_where_clause() {
6524		let builder = PostgresQueryBuilder::new();
6525
6526		let case_expr = Expr::case()
6527			.when(Expr::col("role").eq("admin"), 1)
6528			.else_result(0);
6529
6530		let mut stmt = Query::select();
6531		stmt.column("name").from("users").and_where(case_expr.eq(1));
6532
6533		let (sql, values) = builder.build_select(&stmt);
6534		assert!(sql.contains("WHERE"));
6535		assert!(sql.contains("CASE"));
6536		assert!(sql.contains("WHEN"));
6537		assert!(sql.contains("END"));
6538		assert!(values.len() >= 3);
6539	}
6540
6541	#[test]
6542	fn test_case_in_order_by() {
6543		let builder = PostgresQueryBuilder::new();
6544
6545		let case_expr = Expr::case()
6546			.when(Expr::col("priority").eq("high"), 1)
6547			.when(Expr::col("priority").eq("medium"), 2)
6548			.else_result(3);
6549
6550		let mut stmt = Query::select();
6551		stmt.column("name")
6552			.column("priority")
6553			.from("tasks")
6554			.order_by_expr(case_expr, crate::types::Order::Asc);
6555
6556		let (sql, values) = builder.build_select(&stmt);
6557		assert!(sql.contains("ORDER BY"));
6558		assert!(sql.contains("CASE"));
6559		assert!(sql.contains("WHEN"));
6560		assert!(sql.contains("END"));
6561		assert!(sql.contains("ASC"));
6562		assert_eq!(values.len(), 5);
6563	}
6564
6565	// ORDER BY / LIMIT edge case tests
6566
6567	#[test]
6568	fn test_order_by_multiple_columns_mixed() {
6569		let builder = PostgresQueryBuilder::new();
6570
6571		let mut stmt = Query::select();
6572		stmt.column("name")
6573			.column("age")
6574			.column("score")
6575			.from("students")
6576			.order_by("name", crate::types::Order::Asc)
6577			.order_by("age", crate::types::Order::Desc)
6578			.order_by("score", crate::types::Order::Asc);
6579
6580		let (sql, _values) = builder.build_select(&stmt);
6581		assert!(sql.contains("ORDER BY"));
6582		assert!(sql.contains(r#""name" ASC"#));
6583		assert!(sql.contains(r#""age" DESC"#));
6584		assert!(sql.contains(r#""score" ASC"#));
6585	}
6586
6587	#[test]
6588	fn test_order_by_nulls_first() {
6589		use crate::types::{IntoColumnRef, NullOrdering, OrderExpr, OrderExprKind};
6590
6591		let builder = PostgresQueryBuilder::new();
6592
6593		let mut stmt = Query::select();
6594		stmt.column("name").column("created_at").from("events");
6595		stmt.orders.push(OrderExpr {
6596			expr: OrderExprKind::Expr(Box::new(SimpleExpr::Column("created_at".into_column_ref()))),
6597			order: crate::types::Order::Desc,
6598			nulls: Some(NullOrdering::First),
6599		});
6600
6601		let (sql, _values) = builder.build_select(&stmt);
6602		assert!(sql.contains("ORDER BY"));
6603		assert!(sql.contains("DESC"));
6604		assert!(sql.contains("NULLS FIRST"));
6605	}
6606
6607	#[test]
6608	fn test_order_by_nulls_last() {
6609		use crate::types::{IntoColumnRef, NullOrdering, OrderExpr, OrderExprKind};
6610
6611		let builder = PostgresQueryBuilder::new();
6612
6613		let mut stmt = Query::select();
6614		stmt.column("name").column("updated_at").from("posts");
6615		stmt.orders.push(OrderExpr {
6616			expr: OrderExprKind::Expr(Box::new(SimpleExpr::Column("updated_at".into_column_ref()))),
6617			order: crate::types::Order::Asc,
6618			nulls: Some(NullOrdering::Last),
6619		});
6620
6621		let (sql, _values) = builder.build_select(&stmt);
6622		assert!(sql.contains("ORDER BY"));
6623		assert!(sql.contains("ASC"));
6624		assert!(sql.contains("NULLS LAST"));
6625	}
6626
6627	#[test]
6628	fn test_limit_without_offset() {
6629		let builder = PostgresQueryBuilder::new();
6630
6631		let mut stmt = Query::select();
6632		stmt.column("id").from("items").limit(5);
6633
6634		let (sql, values) = builder.build_select(&stmt);
6635		assert!(sql.contains("LIMIT"));
6636		assert!(!sql.contains("OFFSET"));
6637		assert_eq!(values.len(), 1);
6638	}
6639
6640	// Arithmetic / string operation tests
6641
6642	#[test]
6643	fn test_arithmetic_add_sub() {
6644		let builder = PostgresQueryBuilder::new();
6645		let mut stmt = Query::select();
6646		stmt.column("name").from("products");
6647		stmt.and_where(Expr::col("price").add(10i32).gt(100i32));
6648
6649		let (sql, values) = builder.build_select(&stmt);
6650		assert!(sql.contains(r#""price" + $1"#));
6651		assert!(sql.contains("> $2"));
6652		assert_eq!(values.len(), 2);
6653	}
6654
6655	#[test]
6656	fn test_arithmetic_mul_div_mod() {
6657		let builder = PostgresQueryBuilder::new();
6658		let mut stmt = Query::select();
6659		stmt.column("name").from("items");
6660		stmt.and_where(
6661			Expr::col("quantity")
6662				.mul(Expr::col("unit_price"))
6663				.gt(1000i32),
6664		);
6665
6666		let (sql, values) = builder.build_select(&stmt);
6667		assert!(sql.contains(r#""quantity" * "unit_price""#));
6668		assert!(sql.contains("> $1"));
6669		assert_eq!(values.len(), 1);
6670	}
6671
6672	#[test]
6673	fn test_like_ilike_pattern() {
6674		let builder = PostgresQueryBuilder::new();
6675		let mut stmt = Query::select();
6676		stmt.column("name").from("users");
6677		stmt.and_where(Expr::col("email").like("%@example.com"));
6678
6679		let (sql, values) = builder.build_select(&stmt);
6680		assert!(sql.contains(r#""email" LIKE $1"#));
6681		assert_eq!(values.len(), 1);
6682	}
6683
6684	#[test]
6685	fn test_pg_concat_operator() {
6686		use crate::types::{BinOper, IntoColumnRef, PgBinOper};
6687		let builder = PostgresQueryBuilder::new();
6688		let mut stmt = Query::select();
6689		stmt.expr(SimpleExpr::Binary(
6690			Box::new(SimpleExpr::Column("first_name".into_column_ref())),
6691			BinOper::PgOperator(PgBinOper::Concatenate),
6692			Box::new(SimpleExpr::Column("last_name".into_column_ref())),
6693		));
6694		stmt.from("users");
6695
6696		let (sql, _values) = builder.build_select(&stmt);
6697		assert!(sql.contains(r#""first_name" || "last_name""#));
6698	}
6699
6700	// DDL Tests
6701
6702	#[test]
6703	fn test_drop_table_basic() {
6704		let builder = PostgresQueryBuilder::new();
6705		let mut stmt = Query::drop_table();
6706		stmt.table("users");
6707
6708		let (sql, values) = builder.build_drop_table(&stmt);
6709		assert_eq!(sql, "DROP TABLE \"users\"");
6710		assert_eq!(values.len(), 0);
6711	}
6712
6713	#[test]
6714	fn test_drop_table_if_exists() {
6715		let builder = PostgresQueryBuilder::new();
6716		let mut stmt = Query::drop_table();
6717		stmt.table("users").if_exists();
6718
6719		let (sql, values) = builder.build_drop_table(&stmt);
6720		assert_eq!(sql, "DROP TABLE IF EXISTS \"users\"");
6721		assert_eq!(values.len(), 0);
6722	}
6723
6724	#[test]
6725	fn test_drop_table_cascade() {
6726		let builder = PostgresQueryBuilder::new();
6727		let mut stmt = Query::drop_table();
6728		stmt.table("users").cascade();
6729
6730		let (sql, values) = builder.build_drop_table(&stmt);
6731		assert_eq!(sql, "DROP TABLE \"users\" CASCADE");
6732		assert_eq!(values.len(), 0);
6733	}
6734
6735	#[test]
6736	fn test_drop_table_restrict() {
6737		let builder = PostgresQueryBuilder::new();
6738		let mut stmt = Query::drop_table();
6739		stmt.table("users").restrict();
6740
6741		let (sql, values) = builder.build_drop_table(&stmt);
6742		assert_eq!(sql, "DROP TABLE \"users\" RESTRICT");
6743		assert_eq!(values.len(), 0);
6744	}
6745
6746	#[test]
6747	fn test_drop_table_multiple() {
6748		let builder = PostgresQueryBuilder::new();
6749		let mut stmt = Query::drop_table();
6750		stmt.table("users").table("posts");
6751
6752		let (sql, values) = builder.build_drop_table(&stmt);
6753		assert_eq!(sql, "DROP TABLE \"users\", \"posts\"");
6754		assert_eq!(values.len(), 0);
6755	}
6756
6757	#[test]
6758	fn test_drop_index_basic() {
6759		let builder = PostgresQueryBuilder::new();
6760		let mut stmt = Query::drop_index();
6761		stmt.name("idx_email");
6762
6763		let (sql, values) = builder.build_drop_index(&stmt);
6764		assert_eq!(sql, "DROP INDEX \"idx_email\"");
6765		assert_eq!(values.len(), 0);
6766	}
6767
6768	#[test]
6769	fn test_drop_index_if_exists() {
6770		let builder = PostgresQueryBuilder::new();
6771		let mut stmt = Query::drop_index();
6772		stmt.name("idx_email").if_exists();
6773
6774		let (sql, values) = builder.build_drop_index(&stmt);
6775		assert_eq!(sql, "DROP INDEX IF EXISTS \"idx_email\"");
6776		assert_eq!(values.len(), 0);
6777	}
6778
6779	#[test]
6780	fn test_drop_index_cascade() {
6781		let builder = PostgresQueryBuilder::new();
6782		let mut stmt = Query::drop_index();
6783		stmt.name("idx_email").cascade();
6784
6785		let (sql, values) = builder.build_drop_index(&stmt);
6786		assert_eq!(sql, "DROP INDEX \"idx_email\" CASCADE");
6787		assert_eq!(values.len(), 0);
6788	}
6789
6790	#[test]
6791	fn test_drop_index_restrict() {
6792		let builder = PostgresQueryBuilder::new();
6793		let mut stmt = Query::drop_index();
6794		stmt.name("idx_email").restrict();
6795
6796		let (sql, values) = builder.build_drop_index(&stmt);
6797		assert_eq!(sql, "DROP INDEX \"idx_email\" RESTRICT");
6798		assert_eq!(values.len(), 0);
6799	}
6800
6801	// CREATE TABLE tests
6802
6803	#[test]
6804	fn test_create_table_basic() {
6805		use crate::types::{ColumnDef, ColumnType};
6806
6807		let builder = PostgresQueryBuilder::new();
6808		let mut stmt = Query::create_table();
6809		stmt.table("users");
6810		stmt.columns.push(ColumnDef {
6811			name: "id".into_iden(),
6812			column_type: Some(ColumnType::Integer),
6813			not_null: false,
6814			unique: false,
6815			primary_key: false,
6816			auto_increment: false,
6817			default: None,
6818			check: None,
6819			comment: None,
6820		});
6821		stmt.columns.push(ColumnDef {
6822			name: "name".into_iden(),
6823			column_type: Some(ColumnType::String(Some(255))),
6824			not_null: false,
6825			unique: false,
6826			primary_key: false,
6827			auto_increment: false,
6828			default: None,
6829			check: None,
6830			comment: None,
6831		});
6832
6833		let (sql, values) = builder.build_create_table(&stmt);
6834		assert!(sql.contains("CREATE TABLE \"users\""));
6835		assert!(sql.contains("\"id\" INTEGER"));
6836		assert!(sql.contains("\"name\" VARCHAR(255)"));
6837		assert_eq!(values.len(), 0);
6838	}
6839
6840	#[test]
6841	fn test_create_table_if_not_exists() {
6842		use crate::types::{ColumnDef, ColumnType};
6843
6844		let builder = PostgresQueryBuilder::new();
6845		let mut stmt = Query::create_table();
6846		stmt.table("users").if_not_exists();
6847		stmt.columns.push(ColumnDef {
6848			name: "id".into_iden(),
6849			column_type: Some(ColumnType::Integer),
6850			not_null: false,
6851			unique: false,
6852			primary_key: false,
6853			auto_increment: false,
6854			default: None,
6855			check: None,
6856			comment: None,
6857		});
6858
6859		let (sql, values) = builder.build_create_table(&stmt);
6860		assert!(sql.contains("CREATE TABLE IF NOT EXISTS \"users\""));
6861		assert!(sql.contains("\"id\" INTEGER"));
6862		assert_eq!(values.len(), 0);
6863	}
6864
6865	#[test]
6866	fn test_create_table_with_primary_key() {
6867		use crate::types::{ColumnDef, ColumnType};
6868
6869		let builder = PostgresQueryBuilder::new();
6870		let mut stmt = Query::create_table();
6871		stmt.table("users");
6872		stmt.columns.push(ColumnDef {
6873			name: "id".into_iden(),
6874			column_type: Some(ColumnType::Integer),
6875			not_null: false,
6876			unique: false,
6877			primary_key: true,
6878			auto_increment: false,
6879			default: None,
6880			check: None,
6881			comment: None,
6882		});
6883
6884		let (sql, values) = builder.build_create_table(&stmt);
6885		assert!(sql.contains("CREATE TABLE \"users\""));
6886		assert!(sql.contains("\"id\" INTEGER PRIMARY KEY"));
6887		assert_eq!(values.len(), 0);
6888	}
6889
6890	#[test]
6891	fn test_create_table_with_not_null() {
6892		use crate::types::{ColumnDef, ColumnType};
6893
6894		let builder = PostgresQueryBuilder::new();
6895		let mut stmt = Query::create_table();
6896		stmt.table("users");
6897		stmt.columns.push(ColumnDef {
6898			name: "email".into_iden(),
6899			column_type: Some(ColumnType::String(Some(255))),
6900			not_null: true,
6901			unique: false,
6902			primary_key: false,
6903			auto_increment: false,
6904			default: None,
6905			check: None,
6906			comment: None,
6907		});
6908
6909		let (sql, values) = builder.build_create_table(&stmt);
6910		assert!(sql.contains("\"email\" VARCHAR(255) NOT NULL"));
6911		assert_eq!(values.len(), 0);
6912	}
6913
6914	#[test]
6915	fn test_create_table_with_unique() {
6916		use crate::types::{ColumnDef, ColumnType};
6917
6918		let builder = PostgresQueryBuilder::new();
6919		let mut stmt = Query::create_table();
6920		stmt.table("users");
6921		stmt.columns.push(ColumnDef {
6922			name: "username".into_iden(),
6923			column_type: Some(ColumnType::String(Some(50))),
6924			not_null: false,
6925			unique: true,
6926			primary_key: false,
6927			auto_increment: false,
6928			default: None,
6929			check: None,
6930			comment: None,
6931		});
6932
6933		let (sql, values) = builder.build_create_table(&stmt);
6934		assert!(sql.contains("\"username\" VARCHAR(50) UNIQUE"));
6935		assert_eq!(values.len(), 0);
6936	}
6937
6938	#[test]
6939	fn test_create_table_with_default() {
6940		use crate::types::{ColumnDef, ColumnType};
6941
6942		let builder = PostgresQueryBuilder::new();
6943		let mut stmt = Query::create_table();
6944		stmt.table("users");
6945		stmt.columns.push(ColumnDef {
6946			name: "active".into_iden(),
6947			column_type: Some(ColumnType::Boolean),
6948			not_null: false,
6949			unique: false,
6950			primary_key: false,
6951			auto_increment: false,
6952			default: Some(Expr::value(true).into_simple_expr()),
6953			check: None,
6954			comment: None,
6955		});
6956
6957		let (sql, values) = builder.build_create_table(&stmt);
6958		assert!(sql.contains("\"active\" BOOLEAN DEFAULT"));
6959		assert_eq!(values.len(), 1);
6960	}
6961
6962	#[test]
6963	fn test_create_table_with_check() {
6964		use crate::types::{ColumnDef, ColumnType};
6965
6966		let builder = PostgresQueryBuilder::new();
6967		let mut stmt = Query::create_table();
6968		stmt.table("users");
6969		stmt.columns.push(ColumnDef {
6970			name: "age".into_iden(),
6971			column_type: Some(ColumnType::Integer),
6972			not_null: false,
6973			unique: false,
6974			primary_key: false,
6975			auto_increment: false,
6976			default: None,
6977			check: Some(Expr::col("age").gte(0).into_simple_expr()),
6978			comment: None,
6979		});
6980
6981		let (sql, values) = builder.build_create_table(&stmt);
6982		// CHECK constraints use inlined values (not parameters) in PostgreSQL
6983		assert!(sql.contains("\"age\" INTEGER CHECK"));
6984		assert!(sql.contains(">= 0"));
6985		assert_eq!(values.len(), 0);
6986	}
6987
6988	#[test]
6989	fn test_create_table_with_table_constraint() {
6990		use crate::types::{ColumnDef, ColumnType, TableConstraint};
6991
6992		let builder = PostgresQueryBuilder::new();
6993		let mut stmt = Query::create_table();
6994		stmt.table("users");
6995		stmt.columns.push(ColumnDef {
6996			name: "id".into_iden(),
6997			column_type: Some(ColumnType::Integer),
6998			not_null: false,
6999			unique: false,
7000			primary_key: false,
7001			auto_increment: false,
7002			default: None,
7003			check: None,
7004			comment: None,
7005		});
7006		stmt.columns.push(ColumnDef {
7007			name: "email".into_iden(),
7008			column_type: Some(ColumnType::String(Some(255))),
7009			not_null: false,
7010			unique: false,
7011			primary_key: false,
7012			auto_increment: false,
7013			default: None,
7014			check: None,
7015			comment: None,
7016		});
7017		stmt.constraints.push(TableConstraint::PrimaryKey {
7018			name: Some("pk_users".into_iden()),
7019			columns: vec!["id".into_iden()],
7020		});
7021
7022		let (sql, values) = builder.build_create_table(&stmt);
7023		assert!(sql.contains("CONSTRAINT \"pk_users\" PRIMARY KEY (\"id\")"));
7024		assert_eq!(values.len(), 0);
7025	}
7026
7027	#[test]
7028	fn test_create_table_with_foreign_key() {
7029		use crate::types::{
7030			ColumnDef, ColumnType, ForeignKeyAction, IntoTableRef, TableConstraint,
7031		};
7032
7033		let builder = PostgresQueryBuilder::new();
7034		let mut stmt = Query::create_table();
7035		stmt.table("posts");
7036		stmt.columns.push(ColumnDef {
7037			name: "id".into_iden(),
7038			column_type: Some(ColumnType::Integer),
7039			not_null: false,
7040			unique: false,
7041			primary_key: true,
7042			auto_increment: false,
7043			default: None,
7044			check: None,
7045			comment: None,
7046		});
7047		stmt.columns.push(ColumnDef {
7048			name: "user_id".into_iden(),
7049			column_type: Some(ColumnType::Integer),
7050			not_null: false,
7051			unique: false,
7052			primary_key: false,
7053			auto_increment: false,
7054			default: None,
7055			check: None,
7056			comment: None,
7057		});
7058		stmt.constraints.push(TableConstraint::ForeignKey {
7059			name: Some("fk_user".into_iden()),
7060			columns: vec!["user_id".into_iden()],
7061			ref_table: Box::new("users".into_table_ref()),
7062			ref_columns: vec!["id".into_iden()],
7063			on_delete: Some(ForeignKeyAction::Cascade),
7064			on_update: Some(ForeignKeyAction::Restrict),
7065		});
7066
7067		let (sql, values) = builder.build_create_table(&stmt);
7068		assert!(sql.contains("CONSTRAINT \"fk_user\" FOREIGN KEY (\"user_id\")"));
7069		assert!(sql.contains("REFERENCES \"users\" (\"id\")"));
7070		assert!(sql.contains("ON DELETE CASCADE"));
7071		assert!(sql.contains("ON UPDATE RESTRICT"));
7072		assert_eq!(values.len(), 0);
7073	}
7074
7075	#[test]
7076	fn test_create_index_basic() {
7077		use crate::query::IndexColumn;
7078
7079		let builder = PostgresQueryBuilder::new();
7080		let mut stmt = Query::create_index();
7081		stmt.name("idx_users_email");
7082		stmt.table("users");
7083		stmt.columns.push(IndexColumn {
7084			name: "email".into_iden(),
7085			order: None,
7086		});
7087
7088		let (sql, values) = builder.build_create_index(&stmt);
7089		assert_eq!(
7090			sql,
7091			r#"CREATE INDEX "idx_users_email" ON "users" ("email")"#
7092		);
7093		assert_eq!(values.len(), 0);
7094	}
7095
7096	#[test]
7097	fn test_create_index_unique() {
7098		use crate::query::IndexColumn;
7099
7100		let builder = PostgresQueryBuilder::new();
7101		let mut stmt = Query::create_index();
7102		stmt.name("idx_users_username");
7103		stmt.table("users");
7104		stmt.unique = true;
7105		stmt.columns.push(IndexColumn {
7106			name: "username".into_iden(),
7107			order: None,
7108		});
7109
7110		let (sql, values) = builder.build_create_index(&stmt);
7111		assert_eq!(
7112			sql,
7113			r#"CREATE UNIQUE INDEX "idx_users_username" ON "users" ("username")"#
7114		);
7115		assert_eq!(values.len(), 0);
7116	}
7117
7118	#[test]
7119	fn test_create_index_if_not_exists() {
7120		use crate::query::IndexColumn;
7121
7122		let builder = PostgresQueryBuilder::new();
7123		let mut stmt = Query::create_index();
7124		stmt.name("idx_users_email");
7125		stmt.table("users");
7126		stmt.if_not_exists = true;
7127		stmt.columns.push(IndexColumn {
7128			name: "email".into_iden(),
7129			order: None,
7130		});
7131
7132		let (sql, values) = builder.build_create_index(&stmt);
7133		assert_eq!(
7134			sql,
7135			r#"CREATE INDEX IF NOT EXISTS "idx_users_email" ON "users" ("email")"#
7136		);
7137		assert_eq!(values.len(), 0);
7138	}
7139
7140	#[test]
7141	fn test_create_index_with_order() {
7142		use crate::query::IndexColumn;
7143		use crate::types::Order;
7144
7145		let builder = PostgresQueryBuilder::new();
7146		let mut stmt = Query::create_index();
7147		stmt.name("idx_users_created");
7148		stmt.table("users");
7149		stmt.columns.push(IndexColumn {
7150			name: "created_at".into_iden(),
7151			order: Some(Order::Desc),
7152		});
7153
7154		let (sql, values) = builder.build_create_index(&stmt);
7155		assert_eq!(
7156			sql,
7157			r#"CREATE INDEX "idx_users_created" ON "users" ("created_at" DESC)"#
7158		);
7159		assert_eq!(values.len(), 0);
7160	}
7161
7162	#[test]
7163	fn test_create_index_multiple_columns() {
7164		use crate::query::IndexColumn;
7165		use crate::types::Order;
7166
7167		let builder = PostgresQueryBuilder::new();
7168		let mut stmt = Query::create_index();
7169		stmt.name("idx_users_name");
7170		stmt.table("users");
7171		stmt.columns.push(IndexColumn {
7172			name: "last_name".into_iden(),
7173			order: Some(Order::Asc),
7174		});
7175		stmt.columns.push(IndexColumn {
7176			name: "first_name".into_iden(),
7177			order: Some(Order::Asc),
7178		});
7179
7180		let (sql, values) = builder.build_create_index(&stmt);
7181		assert_eq!(
7182			sql,
7183			r#"CREATE INDEX "idx_users_name" ON "users" ("last_name" ASC, "first_name" ASC)"#
7184		);
7185		assert_eq!(values.len(), 0);
7186	}
7187
7188	#[test]
7189	fn test_create_index_with_using_btree() {
7190		use crate::query::{IndexColumn, IndexMethod};
7191
7192		let builder = PostgresQueryBuilder::new();
7193		let mut stmt = Query::create_index();
7194		stmt.name("idx_users_id");
7195		stmt.table("users");
7196		stmt.using = Some(IndexMethod::BTree);
7197		stmt.columns.push(IndexColumn {
7198			name: "id".into_iden(),
7199			order: None,
7200		});
7201
7202		let (sql, values) = builder.build_create_index(&stmt);
7203		assert_eq!(
7204			sql,
7205			r#"CREATE INDEX "idx_users_id" ON "users" USING BTREE ("id")"#
7206		);
7207		assert_eq!(values.len(), 0);
7208	}
7209
7210	#[test]
7211	fn test_create_index_with_using_gin() {
7212		use crate::query::{IndexColumn, IndexMethod};
7213
7214		let builder = PostgresQueryBuilder::new();
7215		let mut stmt = Query::create_index();
7216		stmt.name("idx_posts_tags");
7217		stmt.table("posts");
7218		stmt.using = Some(IndexMethod::Gin);
7219		stmt.columns.push(IndexColumn {
7220			name: "tags".into_iden(),
7221			order: None,
7222		});
7223
7224		let (sql, values) = builder.build_create_index(&stmt);
7225		assert_eq!(
7226			sql,
7227			r#"CREATE INDEX "idx_posts_tags" ON "posts" USING GIN ("tags")"#
7228		);
7229		assert_eq!(values.len(), 0);
7230	}
7231
7232	#[test]
7233	fn test_create_index_partial_with_where() {
7234		use crate::query::IndexColumn;
7235
7236		let builder = PostgresQueryBuilder::new();
7237		let mut stmt = Query::create_index();
7238		stmt.name("idx_users_active_email");
7239		stmt.table("users");
7240		stmt.columns.push(IndexColumn {
7241			name: "email".into_iden(),
7242			order: None,
7243		});
7244		stmt.r#where = Some(Expr::col("active").eq(true).into_simple_expr());
7245
7246		let (sql, values) = builder.build_create_index(&stmt);
7247		assert_eq!(
7248			sql,
7249			r#"CREATE INDEX "idx_users_active_email" ON "users" ("email") WHERE "active" = $1"#
7250		);
7251		assert_eq!(values.len(), 1);
7252	}
7253
7254	#[test]
7255	fn test_alter_table_add_column() {
7256		use crate::query::AlterTableOperation;
7257		use crate::types::{ColumnDef, ColumnType};
7258
7259		let builder = PostgresQueryBuilder::new();
7260		let mut stmt = Query::alter_table();
7261		stmt.table("users");
7262		stmt.operations
7263			.push(AlterTableOperation::AddColumn(ColumnDef {
7264				name: "age".into_iden(),
7265				column_type: Some(ColumnType::Integer),
7266				not_null: false,
7267				unique: false,
7268				primary_key: false,
7269				auto_increment: false,
7270				default: None,
7271				check: None,
7272				comment: None,
7273			}));
7274
7275		let (sql, values) = builder.build_alter_table(&stmt);
7276		assert_eq!(sql, r#"ALTER TABLE "users" ADD COLUMN "age" INTEGER"#);
7277		assert_eq!(values.len(), 0);
7278	}
7279
7280	#[test]
7281	fn test_alter_table_drop_column() {
7282		use crate::query::AlterTableOperation;
7283
7284		let builder = PostgresQueryBuilder::new();
7285		let mut stmt = Query::alter_table();
7286		stmt.table("users");
7287		stmt.operations.push(AlterTableOperation::DropColumn {
7288			name: "age".into_iden(),
7289			if_exists: false,
7290		});
7291
7292		let (sql, values) = builder.build_alter_table(&stmt);
7293		assert_eq!(sql, r#"ALTER TABLE "users" DROP COLUMN "age""#);
7294		assert_eq!(values.len(), 0);
7295	}
7296
7297	#[test]
7298	fn test_alter_table_drop_column_if_exists() {
7299		use crate::query::AlterTableOperation;
7300
7301		let builder = PostgresQueryBuilder::new();
7302		let mut stmt = Query::alter_table();
7303		stmt.table("users");
7304		stmt.operations.push(AlterTableOperation::DropColumn {
7305			name: "age".into_iden(),
7306			if_exists: true,
7307		});
7308
7309		let (sql, values) = builder.build_alter_table(&stmt);
7310		assert_eq!(sql, r#"ALTER TABLE "users" DROP COLUMN IF EXISTS "age""#);
7311		assert_eq!(values.len(), 0);
7312	}
7313
7314	#[test]
7315	fn test_alter_table_rename_column() {
7316		use crate::query::AlterTableOperation;
7317
7318		let builder = PostgresQueryBuilder::new();
7319		let mut stmt = Query::alter_table();
7320		stmt.table("users");
7321		stmt.operations.push(AlterTableOperation::RenameColumn {
7322			old: "email".into_iden(),
7323			new: "email_address".into_iden(),
7324		});
7325
7326		let (sql, values) = builder.build_alter_table(&stmt);
7327		assert_eq!(
7328			sql,
7329			r#"ALTER TABLE "users" RENAME COLUMN "email" TO "email_address""#
7330		);
7331		assert_eq!(values.len(), 0);
7332	}
7333
7334	#[test]
7335	fn test_alter_table_modify_column_type() {
7336		use crate::query::AlterTableOperation;
7337		use crate::types::{ColumnDef, ColumnType};
7338
7339		let builder = PostgresQueryBuilder::new();
7340		let mut stmt = Query::alter_table();
7341		stmt.table("users");
7342		stmt.operations
7343			.push(AlterTableOperation::ModifyColumn(ColumnDef {
7344				name: "age".into_iden(),
7345				column_type: Some(ColumnType::BigInteger),
7346				not_null: false,
7347				unique: false,
7348				primary_key: false,
7349				auto_increment: false,
7350				default: None,
7351				check: None,
7352				comment: None,
7353			}));
7354
7355		let (sql, values) = builder.build_alter_table(&stmt);
7356		assert_eq!(sql, r#"ALTER TABLE "users" ALTER COLUMN "age" TYPE BIGINT"#);
7357		assert_eq!(values.len(), 0);
7358	}
7359
7360	#[test]
7361	fn test_alter_table_add_constraint() {
7362		use crate::query::AlterTableOperation;
7363		use crate::types::TableConstraint;
7364
7365		let builder = PostgresQueryBuilder::new();
7366		let mut stmt = Query::alter_table();
7367		stmt.table("users");
7368		stmt.operations.push(AlterTableOperation::AddConstraint(
7369			TableConstraint::Unique {
7370				name: Some("unique_email".into_iden()),
7371				columns: vec!["email".into_iden()],
7372			},
7373		));
7374
7375		let (sql, values) = builder.build_alter_table(&stmt);
7376		assert_eq!(
7377			sql,
7378			r#"ALTER TABLE "users" ADD CONSTRAINT "unique_email" UNIQUE ("email")"#
7379		);
7380		assert_eq!(values.len(), 0);
7381	}
7382
7383	#[test]
7384	fn test_alter_table_drop_constraint() {
7385		use crate::query::AlterTableOperation;
7386
7387		let builder = PostgresQueryBuilder::new();
7388		let mut stmt = Query::alter_table();
7389		stmt.table("users");
7390		stmt.operations.push(AlterTableOperation::DropConstraint {
7391			name: "unique_email".into_iden(),
7392			if_exists: false,
7393		});
7394
7395		let (sql, values) = builder.build_alter_table(&stmt);
7396		assert_eq!(sql, r#"ALTER TABLE "users" DROP CONSTRAINT "unique_email""#);
7397		assert_eq!(values.len(), 0);
7398	}
7399
7400	#[test]
7401	fn test_alter_table_rename_table() {
7402		use crate::query::AlterTableOperation;
7403
7404		let builder = PostgresQueryBuilder::new();
7405		let mut stmt = Query::alter_table();
7406		stmt.table("users");
7407		stmt.operations
7408			.push(AlterTableOperation::RenameTable("accounts".into_iden()));
7409
7410		let (sql, values) = builder.build_alter_table(&stmt);
7411		assert_eq!(sql, r#"ALTER TABLE "users" RENAME TO "accounts""#);
7412		assert_eq!(values.len(), 0);
7413	}
7414
7415	// TRUNCATE TABLE tests
7416
7417	#[test]
7418	fn test_truncate_table_basic() {
7419		let builder = PostgresQueryBuilder::new();
7420		let mut stmt = Query::truncate_table();
7421		stmt.table("users");
7422
7423		let (sql, values) = builder.build_truncate_table(&stmt);
7424		assert_eq!(sql, r#"TRUNCATE TABLE "users""#);
7425		assert_eq!(values.len(), 0);
7426	}
7427
7428	#[test]
7429	fn test_truncate_table_multiple() {
7430		let builder = PostgresQueryBuilder::new();
7431		let mut stmt = Query::truncate_table();
7432		stmt.table("users").table("posts").table("comments");
7433
7434		let (sql, values) = builder.build_truncate_table(&stmt);
7435		assert_eq!(sql, r#"TRUNCATE TABLE "users", "posts", "comments""#);
7436		assert_eq!(values.len(), 0);
7437	}
7438
7439	#[test]
7440	fn test_truncate_table_restart_identity() {
7441		let builder = PostgresQueryBuilder::new();
7442		let mut stmt = Query::truncate_table();
7443		stmt.table("users").restart_identity();
7444
7445		let (sql, values) = builder.build_truncate_table(&stmt);
7446		assert_eq!(sql, r#"TRUNCATE TABLE "users" RESTART IDENTITY"#);
7447		assert_eq!(values.len(), 0);
7448	}
7449
7450	#[test]
7451	fn test_truncate_table_cascade() {
7452		let builder = PostgresQueryBuilder::new();
7453		let mut stmt = Query::truncate_table();
7454		stmt.table("users").cascade();
7455
7456		let (sql, values) = builder.build_truncate_table(&stmt);
7457		assert_eq!(sql, r#"TRUNCATE TABLE "users" CASCADE"#);
7458		assert_eq!(values.len(), 0);
7459	}
7460
7461	#[test]
7462	fn test_truncate_table_restrict() {
7463		let builder = PostgresQueryBuilder::new();
7464		let mut stmt = Query::truncate_table();
7465		stmt.table("users").restrict();
7466
7467		let (sql, values) = builder.build_truncate_table(&stmt);
7468		assert_eq!(sql, r#"TRUNCATE TABLE "users" RESTRICT"#);
7469		assert_eq!(values.len(), 0);
7470	}
7471
7472	#[test]
7473	fn test_truncate_table_restart_identity_cascade() {
7474		let builder = PostgresQueryBuilder::new();
7475		let mut stmt = Query::truncate_table();
7476		stmt.table("users").restart_identity().cascade();
7477
7478		let (sql, values) = builder.build_truncate_table(&stmt);
7479		assert_eq!(sql, r#"TRUNCATE TABLE "users" RESTART IDENTITY CASCADE"#);
7480		assert_eq!(values.len(), 0);
7481	}
7482
7483	#[test]
7484	fn test_create_trigger_basic() {
7485		use crate::types::{TriggerEvent, TriggerScope, TriggerTiming};
7486
7487		let builder = PostgresQueryBuilder::new();
7488		let mut stmt = Query::create_trigger();
7489		stmt.name("audit_log")
7490			.timing(TriggerTiming::After)
7491			.event(TriggerEvent::Insert)
7492			.on_table("users")
7493			.for_each(TriggerScope::Row)
7494			.execute_function("log_user_insert");
7495
7496		let (sql, values) = builder.build_create_trigger(&stmt);
7497		assert_eq!(
7498			sql,
7499			r#"CREATE TRIGGER "audit_log" AFTER INSERT ON "users" FOR EACH ROW EXECUTE FUNCTION "log_user_insert"()"#
7500		);
7501		assert_eq!(values.len(), 0);
7502	}
7503
7504	#[test]
7505	fn test_create_trigger_before_update() {
7506		use crate::types::{TriggerEvent, TriggerScope, TriggerTiming};
7507
7508		let builder = PostgresQueryBuilder::new();
7509		let mut stmt = Query::create_trigger();
7510		stmt.name("update_timestamp")
7511			.timing(TriggerTiming::Before)
7512			.event(TriggerEvent::Update { columns: None })
7513			.on_table("users")
7514			.for_each(TriggerScope::Row)
7515			.execute_function("update_modified_at");
7516
7517		let (sql, values) = builder.build_create_trigger(&stmt);
7518		assert_eq!(
7519			sql,
7520			r#"CREATE TRIGGER "update_timestamp" BEFORE UPDATE ON "users" FOR EACH ROW EXECUTE FUNCTION "update_modified_at"()"#
7521		);
7522		assert_eq!(values.len(), 0);
7523	}
7524
7525	#[test]
7526	fn test_create_trigger_delete_for_statement() {
7527		use crate::types::{TriggerEvent, TriggerScope, TriggerTiming};
7528
7529		let builder = PostgresQueryBuilder::new();
7530		let mut stmt = Query::create_trigger();
7531		stmt.name("audit_delete")
7532			.timing(TriggerTiming::After)
7533			.event(TriggerEvent::Delete)
7534			.on_table("users")
7535			.for_each(TriggerScope::Statement)
7536			.execute_function("log_bulk_delete");
7537
7538		let (sql, values) = builder.build_create_trigger(&stmt);
7539		assert_eq!(
7540			sql,
7541			r#"CREATE TRIGGER "audit_delete" AFTER DELETE ON "users" FOR EACH STATEMENT EXECUTE FUNCTION "log_bulk_delete"()"#
7542		);
7543		assert_eq!(values.len(), 0);
7544	}
7545
7546	#[test]
7547	fn test_drop_trigger_basic() {
7548		let builder = PostgresQueryBuilder::new();
7549		let mut stmt = Query::drop_trigger();
7550		stmt.name("audit_log").on_table("users");
7551
7552		let (sql, values) = builder.build_drop_trigger(&stmt);
7553		assert_eq!(sql, r#"DROP TRIGGER "audit_log" ON "users""#);
7554		assert_eq!(values.len(), 0);
7555	}
7556
7557	#[test]
7558	fn test_drop_trigger_if_exists() {
7559		let builder = PostgresQueryBuilder::new();
7560		let mut stmt = Query::drop_trigger();
7561		stmt.name("audit_log").on_table("users").if_exists();
7562
7563		let (sql, values) = builder.build_drop_trigger(&stmt);
7564		assert_eq!(sql, r#"DROP TRIGGER IF EXISTS "audit_log" ON "users""#);
7565		assert_eq!(values.len(), 0);
7566	}
7567
7568	#[test]
7569	fn test_drop_trigger_cascade() {
7570		let builder = PostgresQueryBuilder::new();
7571		let mut stmt = Query::drop_trigger();
7572		stmt.name("audit_log").on_table("users").cascade();
7573
7574		let (sql, values) = builder.build_drop_trigger(&stmt);
7575		assert_eq!(sql, r#"DROP TRIGGER "audit_log" ON "users" CASCADE"#);
7576		assert_eq!(values.len(), 0);
7577	}
7578
7579	// CREATE FUNCTION tests
7580	#[test]
7581	fn test_create_function_basic() {
7582		use crate::types::function::FunctionLanguage;
7583
7584		let builder = PostgresQueryBuilder::new();
7585		let mut stmt = Query::create_function();
7586		stmt.name("my_func")
7587			.returns("integer")
7588			.language(FunctionLanguage::Sql)
7589			.body("SELECT 1");
7590
7591		let (sql, values) = builder.build_create_function(&stmt);
7592		assert_eq!(
7593			sql,
7594			r#"CREATE FUNCTION "my_func"() RETURNS integer LANGUAGE SQL AS $$SELECT 1$$"#
7595		);
7596		assert_eq!(values.len(), 0);
7597	}
7598
7599	#[test]
7600	fn test_create_function_or_replace() {
7601		use crate::types::function::FunctionLanguage;
7602
7603		let builder = PostgresQueryBuilder::new();
7604		let mut stmt = Query::create_function();
7605		stmt.name("my_func")
7606			.or_replace()
7607			.returns("integer")
7608			.language(FunctionLanguage::Sql)
7609			.body("SELECT 1");
7610
7611		let (sql, values) = builder.build_create_function(&stmt);
7612		assert_eq!(
7613			sql,
7614			r#"CREATE OR REPLACE FUNCTION "my_func"() RETURNS integer LANGUAGE SQL AS $$SELECT 1$$"#
7615		);
7616		assert_eq!(values.len(), 0);
7617	}
7618
7619	#[test]
7620	fn test_create_function_with_parameters() {
7621		use crate::types::function::FunctionLanguage;
7622
7623		let builder = PostgresQueryBuilder::new();
7624		let mut stmt = Query::create_function();
7625		stmt.name("add_numbers")
7626			.add_parameter("a", "integer")
7627			.add_parameter("b", "integer")
7628			.returns("integer")
7629			.language(FunctionLanguage::Sql)
7630			.body("SELECT $1 + $2");
7631
7632		let (sql, values) = builder.build_create_function(&stmt);
7633		assert_eq!(
7634			sql,
7635			r#"CREATE FUNCTION "add_numbers"("a" integer, "b" integer) RETURNS integer LANGUAGE SQL AS $$SELECT $1 + $2$$"#
7636		);
7637		assert_eq!(values.len(), 0);
7638	}
7639
7640	#[test]
7641	fn test_create_function_with_behavior() {
7642		use crate::types::function::{FunctionBehavior, FunctionLanguage};
7643
7644		let builder = PostgresQueryBuilder::new();
7645		let mut stmt = Query::create_function();
7646		stmt.name("my_func")
7647			.returns("integer")
7648			.language(FunctionLanguage::Sql)
7649			.behavior(FunctionBehavior::Immutable)
7650			.body("SELECT 1");
7651
7652		let (sql, values) = builder.build_create_function(&stmt);
7653		assert_eq!(
7654			sql,
7655			r#"CREATE FUNCTION "my_func"() RETURNS integer LANGUAGE SQL IMMUTABLE AS $$SELECT 1$$"#
7656		);
7657		assert_eq!(values.len(), 0);
7658	}
7659
7660	#[test]
7661	fn test_create_function_with_security() {
7662		use crate::types::function::{FunctionLanguage, FunctionSecurity};
7663
7664		let builder = PostgresQueryBuilder::new();
7665		let mut stmt = Query::create_function();
7666		stmt.name("my_func")
7667			.returns("integer")
7668			.language(FunctionLanguage::Sql)
7669			.security(FunctionSecurity::Definer)
7670			.body("SELECT 1");
7671
7672		let (sql, values) = builder.build_create_function(&stmt);
7673		assert_eq!(
7674			sql,
7675			r#"CREATE FUNCTION "my_func"() RETURNS integer LANGUAGE SQL SECURITY DEFINER AS $$SELECT 1$$"#
7676		);
7677		assert_eq!(values.len(), 0);
7678	}
7679
7680	#[test]
7681	fn test_create_function_plpgsql() {
7682		use crate::types::function::FunctionLanguage;
7683
7684		let builder = PostgresQueryBuilder::new();
7685		let mut stmt = Query::create_function();
7686		stmt.name("increment")
7687			.add_parameter("val", "integer")
7688			.returns("integer")
7689			.language(FunctionLanguage::PlPgSql)
7690			.body("BEGIN RETURN val + 1; END;");
7691
7692		let (sql, values) = builder.build_create_function(&stmt);
7693		assert_eq!(
7694			sql,
7695			r#"CREATE FUNCTION "increment"("val" integer) RETURNS integer LANGUAGE PLPGSQL AS $$BEGIN RETURN val + 1; END;$$"#
7696		);
7697		assert_eq!(values.len(), 0);
7698	}
7699
7700	#[test]
7701	fn test_create_function_all_options() {
7702		use crate::types::function::{FunctionBehavior, FunctionLanguage, FunctionSecurity};
7703
7704		let builder = PostgresQueryBuilder::new();
7705		let mut stmt = Query::create_function();
7706		stmt.name("complex_func")
7707			.or_replace()
7708			.add_parameter("a", "integer")
7709			.add_parameter("b", "text")
7710			.returns("integer")
7711			.language(FunctionLanguage::PlPgSql)
7712			.behavior(FunctionBehavior::Stable)
7713			.security(FunctionSecurity::Definer)
7714			.body("BEGIN RETURN a + LENGTH(b); END;");
7715
7716		let (sql, values) = builder.build_create_function(&stmt);
7717		assert_eq!(
7718			sql,
7719			r#"CREATE OR REPLACE FUNCTION "complex_func"("a" integer, "b" text) RETURNS integer LANGUAGE PLPGSQL STABLE SECURITY DEFINER AS $$BEGIN RETURN a + LENGTH(b); END;$$"#
7720		);
7721		assert_eq!(values.len(), 0);
7722	}
7723
7724	// ALTER FUNCTION tests
7725	#[test]
7726	fn test_alter_function_rename_to() {
7727		let builder = PostgresQueryBuilder::new();
7728		let mut stmt = Query::alter_function();
7729		stmt.name("my_func").rename_to("new_func");
7730
7731		let (sql, values) = builder.build_alter_function(&stmt);
7732		assert_eq!(sql, r#"ALTER FUNCTION "my_func" RENAME TO "new_func""#);
7733		assert_eq!(values.len(), 0);
7734	}
7735
7736	#[test]
7737	fn test_alter_function_owner_to() {
7738		let builder = PostgresQueryBuilder::new();
7739		let mut stmt = Query::alter_function();
7740		stmt.name("my_func").owner_to("new_owner");
7741
7742		let (sql, values) = builder.build_alter_function(&stmt);
7743		assert_eq!(sql, r#"ALTER FUNCTION "my_func" OWNER TO "new_owner""#);
7744		assert_eq!(values.len(), 0);
7745	}
7746
7747	#[test]
7748	fn test_alter_function_set_schema() {
7749		let builder = PostgresQueryBuilder::new();
7750		let mut stmt = Query::alter_function();
7751		stmt.name("my_func").set_schema("new_schema");
7752
7753		let (sql, values) = builder.build_alter_function(&stmt);
7754		assert_eq!(sql, r#"ALTER FUNCTION "my_func" SET SCHEMA "new_schema""#);
7755		assert_eq!(values.len(), 0);
7756	}
7757
7758	#[test]
7759	fn test_alter_function_set_behavior_immutable() {
7760		use crate::types::function::FunctionBehavior;
7761
7762		let builder = PostgresQueryBuilder::new();
7763		let mut stmt = Query::alter_function();
7764		stmt.name("my_func")
7765			.set_behavior(FunctionBehavior::Immutable);
7766
7767		let (sql, values) = builder.build_alter_function(&stmt);
7768		assert_eq!(sql, r#"ALTER FUNCTION "my_func" IMMUTABLE"#);
7769		assert_eq!(values.len(), 0);
7770	}
7771
7772	#[test]
7773	fn test_alter_function_set_security_definer() {
7774		use crate::types::function::FunctionSecurity;
7775
7776		let builder = PostgresQueryBuilder::new();
7777		let mut stmt = Query::alter_function();
7778		stmt.name("my_func").set_security(FunctionSecurity::Definer);
7779
7780		let (sql, values) = builder.build_alter_function(&stmt);
7781		assert_eq!(sql, r#"ALTER FUNCTION "my_func" SECURITY DEFINER"#);
7782		assert_eq!(values.len(), 0);
7783	}
7784
7785	#[test]
7786	fn test_alter_function_with_parameters() {
7787		let builder = PostgresQueryBuilder::new();
7788		let mut stmt = Query::alter_function();
7789		stmt.name("my_func")
7790			.add_parameter("a", "integer")
7791			.add_parameter("b", "text")
7792			.rename_to("new_func");
7793
7794		let (sql, values) = builder.build_alter_function(&stmt);
7795		assert_eq!(
7796			sql,
7797			r#"ALTER FUNCTION "my_func"("a" integer, "b" text) RENAME TO "new_func""#
7798		);
7799		assert_eq!(values.len(), 0);
7800	}
7801
7802	// DROP FUNCTION tests
7803	#[test]
7804	fn test_drop_function_basic() {
7805		let builder = PostgresQueryBuilder::new();
7806		let mut stmt = Query::drop_function();
7807		stmt.name("my_func");
7808
7809		let (sql, values) = builder.build_drop_function(&stmt);
7810		assert_eq!(sql, r#"DROP FUNCTION "my_func""#);
7811		assert_eq!(values.len(), 0);
7812	}
7813
7814	#[test]
7815	fn test_drop_function_if_exists() {
7816		let builder = PostgresQueryBuilder::new();
7817		let mut stmt = Query::drop_function();
7818		stmt.name("my_func").if_exists();
7819
7820		let (sql, values) = builder.build_drop_function(&stmt);
7821		assert_eq!(sql, r#"DROP FUNCTION IF EXISTS "my_func""#);
7822		assert_eq!(values.len(), 0);
7823	}
7824
7825	#[test]
7826	fn test_drop_function_cascade() {
7827		let builder = PostgresQueryBuilder::new();
7828		let mut stmt = Query::drop_function();
7829		stmt.name("my_func").cascade();
7830
7831		let (sql, values) = builder.build_drop_function(&stmt);
7832		assert_eq!(sql, r#"DROP FUNCTION "my_func" CASCADE"#);
7833		assert_eq!(values.len(), 0);
7834	}
7835
7836	#[test]
7837	fn test_drop_function_with_parameters() {
7838		let builder = PostgresQueryBuilder::new();
7839		let mut stmt = Query::drop_function();
7840		stmt.name("my_func")
7841			.add_parameter("", "integer")
7842			.add_parameter("", "text");
7843
7844		let (sql, values) = builder.build_drop_function(&stmt);
7845		assert_eq!(sql, r#"DROP FUNCTION "my_func"(integer, text)"#);
7846		assert_eq!(values.len(), 0);
7847	}
7848
7849	#[test]
7850	fn test_drop_function_all_options() {
7851		let builder = PostgresQueryBuilder::new();
7852		let mut stmt = Query::drop_function();
7853		stmt.name("my_func")
7854			.if_exists()
7855			.add_parameter("", "integer")
7856			.cascade();
7857
7858		let (sql, values) = builder.build_drop_function(&stmt);
7859		assert_eq!(sql, r#"DROP FUNCTION IF EXISTS "my_func"(integer) CASCADE"#);
7860		assert_eq!(values.len(), 0);
7861	}
7862
7863	// Procedure tests
7864	#[test]
7865	fn test_create_procedure_basic() {
7866		use crate::types::function::FunctionLanguage;
7867
7868		let builder = PostgresQueryBuilder::new();
7869		let mut stmt = Query::create_procedure();
7870		stmt.name("my_proc")
7871			.language(FunctionLanguage::Sql)
7872			.body("SELECT 1");
7873
7874		let (sql, values) = builder.build_create_procedure(&stmt);
7875		assert_eq!(
7876			sql,
7877			r#"CREATE PROCEDURE "my_proc"() LANGUAGE SQL AS $$SELECT 1$$"#
7878		);
7879		assert_eq!(values.len(), 0);
7880	}
7881
7882	#[test]
7883	fn test_create_procedure_or_replace() {
7884		use crate::types::function::FunctionLanguage;
7885
7886		let builder = PostgresQueryBuilder::new();
7887		let mut stmt = Query::create_procedure();
7888		stmt.name("my_proc")
7889			.or_replace()
7890			.language(FunctionLanguage::PlPgSql)
7891			.body("BEGIN SELECT 1; END;");
7892
7893		let (sql, values) = builder.build_create_procedure(&stmt);
7894		assert_eq!(
7895			sql,
7896			r#"CREATE OR REPLACE PROCEDURE "my_proc"() LANGUAGE PLPGSQL AS $$BEGIN SELECT 1; END;$$"#
7897		);
7898		assert_eq!(values.len(), 0);
7899	}
7900
7901	#[test]
7902	fn test_create_procedure_with_parameters() {
7903		use crate::types::function::FunctionLanguage;
7904
7905		let builder = PostgresQueryBuilder::new();
7906		let mut stmt = Query::create_procedure();
7907		stmt.name("my_proc")
7908			.add_parameter("a", "integer")
7909			.add_parameter("b", "text")
7910			.language(FunctionLanguage::PlPgSql)
7911			.body("BEGIN INSERT INTO log VALUES (a, b); END;");
7912
7913		let (sql, values) = builder.build_create_procedure(&stmt);
7914		assert_eq!(
7915			sql,
7916			r#"CREATE PROCEDURE "my_proc"("a" integer, "b" text) LANGUAGE PLPGSQL AS $$BEGIN INSERT INTO log VALUES (a, b); END;$$"#
7917		);
7918		assert_eq!(values.len(), 0);
7919	}
7920
7921	#[test]
7922	fn test_create_procedure_with_behavior() {
7923		use crate::types::function::{FunctionBehavior, FunctionLanguage};
7924
7925		let builder = PostgresQueryBuilder::new();
7926		let mut stmt = Query::create_procedure();
7927		stmt.name("my_proc")
7928			.language(FunctionLanguage::Sql)
7929			.behavior(FunctionBehavior::Immutable)
7930			.body("SELECT 1");
7931
7932		let (sql, values) = builder.build_create_procedure(&stmt);
7933		assert_eq!(
7934			sql,
7935			r#"CREATE PROCEDURE "my_proc"() LANGUAGE SQL IMMUTABLE AS $$SELECT 1$$"#
7936		);
7937		assert_eq!(values.len(), 0);
7938	}
7939
7940	#[test]
7941	fn test_create_procedure_with_security() {
7942		use crate::types::function::{FunctionLanguage, FunctionSecurity};
7943
7944		let builder = PostgresQueryBuilder::new();
7945		let mut stmt = Query::create_procedure();
7946		stmt.name("my_proc")
7947			.language(FunctionLanguage::Sql)
7948			.security(FunctionSecurity::Definer)
7949			.body("SELECT 1");
7950
7951		let (sql, values) = builder.build_create_procedure(&stmt);
7952		assert_eq!(
7953			sql,
7954			r#"CREATE PROCEDURE "my_proc"() LANGUAGE SQL SECURITY DEFINER AS $$SELECT 1$$"#
7955		);
7956		assert_eq!(values.len(), 0);
7957	}
7958
7959	#[test]
7960	fn test_create_procedure_all_options() {
7961		use crate::types::function::{FunctionBehavior, FunctionLanguage, FunctionSecurity};
7962
7963		let builder = PostgresQueryBuilder::new();
7964		let mut stmt = Query::create_procedure();
7965		stmt.name("my_proc")
7966			.or_replace()
7967			.add_parameter("a", "integer")
7968			.add_parameter("b", "text")
7969			.language(FunctionLanguage::PlPgSql)
7970			.behavior(FunctionBehavior::Immutable)
7971			.security(FunctionSecurity::Definer)
7972			.body("BEGIN INSERT INTO log VALUES (a, b); END;");
7973
7974		let (sql, values) = builder.build_create_procedure(&stmt);
7975		assert_eq!(
7976			sql,
7977			r#"CREATE OR REPLACE PROCEDURE "my_proc"("a" integer, "b" text) LANGUAGE PLPGSQL IMMUTABLE SECURITY DEFINER AS $$BEGIN INSERT INTO log VALUES (a, b); END;$$"#
7978		);
7979		assert_eq!(values.len(), 0);
7980	}
7981
7982	#[test]
7983	fn test_alter_procedure_rename_to() {
7984		let builder = PostgresQueryBuilder::new();
7985		let mut stmt = Query::alter_procedure();
7986		stmt.name("my_proc").rename_to("new_proc");
7987
7988		let (sql, values) = builder.build_alter_procedure(&stmt);
7989		assert_eq!(sql, r#"ALTER PROCEDURE "my_proc" RENAME TO "new_proc""#);
7990		assert_eq!(values.len(), 0);
7991	}
7992
7993	#[test]
7994	fn test_alter_procedure_owner_to() {
7995		let builder = PostgresQueryBuilder::new();
7996		let mut stmt = Query::alter_procedure();
7997		stmt.name("my_proc").owner_to("new_owner");
7998
7999		let (sql, values) = builder.build_alter_procedure(&stmt);
8000		assert_eq!(sql, r#"ALTER PROCEDURE "my_proc" OWNER TO "new_owner""#);
8001		assert_eq!(values.len(), 0);
8002	}
8003
8004	#[test]
8005	fn test_alter_procedure_set_schema() {
8006		let builder = PostgresQueryBuilder::new();
8007		let mut stmt = Query::alter_procedure();
8008		stmt.name("my_proc").set_schema("new_schema");
8009
8010		let (sql, values) = builder.build_alter_procedure(&stmt);
8011		assert_eq!(sql, r#"ALTER PROCEDURE "my_proc" SET SCHEMA "new_schema""#);
8012		assert_eq!(values.len(), 0);
8013	}
8014
8015	#[test]
8016	fn test_alter_procedure_with_signature() {
8017		let builder = PostgresQueryBuilder::new();
8018		let mut stmt = Query::alter_procedure();
8019		stmt.name("my_proc")
8020			.add_parameter("a", "integer")
8021			.rename_to("new_proc");
8022
8023		let (sql, values) = builder.build_alter_procedure(&stmt);
8024		assert_eq!(
8025			sql,
8026			r#"ALTER PROCEDURE "my_proc"("a" integer) RENAME TO "new_proc""#
8027		);
8028		assert_eq!(values.len(), 0);
8029	}
8030
8031	#[test]
8032	fn test_drop_procedure_basic() {
8033		let builder = PostgresQueryBuilder::new();
8034		let mut stmt = Query::drop_procedure();
8035		stmt.name("my_proc");
8036
8037		let (sql, values) = builder.build_drop_procedure(&stmt);
8038		assert_eq!(sql, r#"DROP PROCEDURE "my_proc""#);
8039		assert_eq!(values.len(), 0);
8040	}
8041
8042	#[test]
8043	fn test_drop_procedure_if_exists() {
8044		let builder = PostgresQueryBuilder::new();
8045		let mut stmt = Query::drop_procedure();
8046		stmt.name("my_proc").if_exists();
8047
8048		let (sql, values) = builder.build_drop_procedure(&stmt);
8049		assert_eq!(sql, r#"DROP PROCEDURE IF EXISTS "my_proc""#);
8050		assert_eq!(values.len(), 0);
8051	}
8052
8053	#[test]
8054	fn test_drop_procedure_cascade() {
8055		let builder = PostgresQueryBuilder::new();
8056		let mut stmt = Query::drop_procedure();
8057		stmt.name("my_proc").cascade();
8058
8059		let (sql, values) = builder.build_drop_procedure(&stmt);
8060		assert_eq!(sql, r#"DROP PROCEDURE "my_proc" CASCADE"#);
8061		assert_eq!(values.len(), 0);
8062	}
8063
8064	#[test]
8065	fn test_drop_procedure_with_signature() {
8066		let builder = PostgresQueryBuilder::new();
8067		let mut stmt = Query::drop_procedure();
8068		stmt.name("my_proc").add_parameter("", "integer");
8069
8070		let (sql, values) = builder.build_drop_procedure(&stmt);
8071		assert_eq!(sql, r#"DROP PROCEDURE "my_proc"(integer)"#);
8072		assert_eq!(values.len(), 0);
8073	}
8074
8075	#[test]
8076	fn test_drop_procedure_all_options() {
8077		let builder = PostgresQueryBuilder::new();
8078		let mut stmt = Query::drop_procedure();
8079		stmt.name("my_proc")
8080			.if_exists()
8081			.add_parameter("", "integer")
8082			.cascade();
8083
8084		let (sql, values) = builder.build_drop_procedure(&stmt);
8085		assert_eq!(
8086			sql,
8087			r#"DROP PROCEDURE IF EXISTS "my_proc"(integer) CASCADE"#
8088		);
8089		assert_eq!(values.len(), 0);
8090	}
8091
8092	// CREATE TYPE tests
8093	#[test]
8094	fn test_create_type_enum() {
8095		let builder = PostgresQueryBuilder::new();
8096		let mut stmt = Query::create_type();
8097		stmt.name("mood")
8098			.as_enum(vec!["happy".to_string(), "sad".to_string()]);
8099
8100		let (sql, values) = builder.build_create_type(&stmt);
8101		assert_eq!(sql, r#"CREATE TYPE "mood" AS ENUM ('happy', 'sad')"#);
8102		assert_eq!(values.len(), 0);
8103	}
8104
8105	#[test]
8106	fn test_create_type_enum_with_single_quote() {
8107		let builder = PostgresQueryBuilder::new();
8108		let mut stmt = Query::create_type();
8109		stmt.name("test").as_enum(vec!["it's".to_string()]);
8110
8111		let (sql, values) = builder.build_create_type(&stmt);
8112		assert_eq!(sql, r#"CREATE TYPE "test" AS ENUM ('it''s')"#);
8113		assert_eq!(values.len(), 0);
8114	}
8115
8116	#[test]
8117	fn test_create_type_composite() {
8118		let builder = PostgresQueryBuilder::new();
8119		let mut stmt = Query::create_type();
8120		stmt.name("address").as_composite(vec![
8121			("street".to_string(), "text".to_string()),
8122			("city".to_string(), "text".to_string()),
8123		]);
8124
8125		let (sql, values) = builder.build_create_type(&stmt);
8126		assert_eq!(
8127			sql,
8128			r#"CREATE TYPE "address" AS ("street" text, "city" text)"#
8129		);
8130		assert_eq!(values.len(), 0);
8131	}
8132
8133	#[test]
8134	fn test_create_type_domain_minimal() {
8135		let builder = PostgresQueryBuilder::new();
8136		let mut stmt = Query::create_type();
8137		stmt.name("positive_int").as_domain("integer".to_string());
8138
8139		let (sql, values) = builder.build_create_type(&stmt);
8140		assert_eq!(sql, r#"CREATE TYPE "positive_int" AS integer"#);
8141		assert_eq!(values.len(), 0);
8142	}
8143
8144	#[test]
8145	fn test_create_type_domain_with_constraint() {
8146		let builder = PostgresQueryBuilder::new();
8147		let mut stmt = Query::create_type();
8148		stmt.name("positive_int")
8149			.as_domain("integer".to_string())
8150			.constraint(
8151				"check_positive".to_string(),
8152				"CHECK (VALUE > 0)".to_string(),
8153			);
8154
8155		let (sql, values) = builder.build_create_type(&stmt);
8156		assert_eq!(
8157			sql,
8158			r#"CREATE TYPE "positive_int" AS integer CHECK (VALUE > 0)"#
8159		);
8160		assert_eq!(values.len(), 0);
8161	}
8162
8163	#[test]
8164	fn test_create_type_domain_with_default() {
8165		let builder = PostgresQueryBuilder::new();
8166		let mut stmt = Query::create_type();
8167		stmt.name("my_domain")
8168			.as_domain("integer".to_string())
8169			.default_value("0".to_string());
8170
8171		let (sql, values) = builder.build_create_type(&stmt);
8172		assert_eq!(sql, r#"CREATE TYPE "my_domain" AS integer DEFAULT 0"#);
8173		assert_eq!(values.len(), 0);
8174	}
8175
8176	#[test]
8177	fn test_create_type_domain_not_null() {
8178		let builder = PostgresQueryBuilder::new();
8179		let mut stmt = Query::create_type();
8180		stmt.name("my_domain")
8181			.as_domain("integer".to_string())
8182			.not_null();
8183
8184		let (sql, values) = builder.build_create_type(&stmt);
8185		assert_eq!(sql, r#"CREATE TYPE "my_domain" AS integer NOT NULL"#);
8186		assert_eq!(values.len(), 0);
8187	}
8188
8189	#[test]
8190	fn test_create_type_domain_full() {
8191		let builder = PostgresQueryBuilder::new();
8192		let mut stmt = Query::create_type();
8193		stmt.name("positive_int")
8194			.as_domain("integer".to_string())
8195			.default_value("1".to_string())
8196			.constraint(
8197				"check_positive".to_string(),
8198				"CHECK (VALUE > 0)".to_string(),
8199			)
8200			.not_null();
8201
8202		let (sql, values) = builder.build_create_type(&stmt);
8203		assert_eq!(
8204			sql,
8205			r#"CREATE TYPE "positive_int" AS integer DEFAULT 1 CHECK (VALUE > 0) NOT NULL"#
8206		);
8207		assert_eq!(values.len(), 0);
8208	}
8209
8210	#[test]
8211	fn test_create_type_range_minimal() {
8212		let builder = PostgresQueryBuilder::new();
8213		let mut stmt = Query::create_type();
8214		stmt.name("int_range").as_range("integer".to_string());
8215
8216		let (sql, values) = builder.build_create_type(&stmt);
8217		assert_eq!(
8218			sql,
8219			r#"CREATE TYPE "int_range" AS RANGE (SUBTYPE = integer)"#
8220		);
8221		assert_eq!(values.len(), 0);
8222	}
8223
8224	#[test]
8225	fn test_create_type_range_with_subtype_diff() {
8226		let builder = PostgresQueryBuilder::new();
8227		let mut stmt = Query::create_type();
8228		stmt.name("int_range")
8229			.as_range("integer".to_string())
8230			.subtype_diff("int4range_subdiff".to_string());
8231
8232		let (sql, values) = builder.build_create_type(&stmt);
8233		assert_eq!(
8234			sql,
8235			r#"CREATE TYPE "int_range" AS RANGE (SUBTYPE = integer, SUBTYPE_DIFF = int4range_subdiff)"#
8236		);
8237		assert_eq!(values.len(), 0);
8238	}
8239
8240	#[test]
8241	fn test_create_type_range_full() {
8242		let builder = PostgresQueryBuilder::new();
8243		let mut stmt = Query::create_type();
8244		stmt.name("int_range")
8245			.as_range("integer".to_string())
8246			.subtype_diff("int4range_subdiff".to_string())
8247			.canonical("int4range_canonical".to_string());
8248
8249		let (sql, values) = builder.build_create_type(&stmt);
8250		assert_eq!(
8251			sql,
8252			r#"CREATE TYPE "int_range" AS RANGE (SUBTYPE = integer, SUBTYPE_DIFF = int4range_subdiff, CANONICAL = int4range_canonical)"#
8253		);
8254		assert_eq!(values.len(), 0);
8255	}
8256
8257	// ALTER TYPE tests
8258	#[test]
8259	fn test_alter_type_rename_to() {
8260		let builder = PostgresQueryBuilder::new();
8261		let mut stmt = Query::alter_type();
8262		stmt.name("old_name").rename_to("new_name");
8263
8264		let (sql, values) = builder.build_alter_type(&stmt);
8265		assert_eq!(sql, r#"ALTER TYPE "old_name" RENAME TO "new_name""#);
8266		assert_eq!(values.len(), 0);
8267	}
8268
8269	#[test]
8270	fn test_alter_type_owner_to() {
8271		let builder = PostgresQueryBuilder::new();
8272		let mut stmt = Query::alter_type();
8273		stmt.name("my_type").owner_to("new_owner");
8274
8275		let (sql, values) = builder.build_alter_type(&stmt);
8276		assert_eq!(sql, r#"ALTER TYPE "my_type" OWNER TO "new_owner""#);
8277		assert_eq!(values.len(), 0);
8278	}
8279
8280	#[test]
8281	fn test_alter_type_set_schema() {
8282		let builder = PostgresQueryBuilder::new();
8283		let mut stmt = Query::alter_type();
8284		stmt.name("my_type").set_schema("new_schema");
8285
8286		let (sql, values) = builder.build_alter_type(&stmt);
8287		assert_eq!(sql, r#"ALTER TYPE "my_type" SET SCHEMA "new_schema""#);
8288		assert_eq!(values.len(), 0);
8289	}
8290
8291	#[test]
8292	fn test_alter_type_add_value() {
8293		let builder = PostgresQueryBuilder::new();
8294		let mut stmt = Query::alter_type();
8295		stmt.name("mood").add_value("excited", None);
8296
8297		let (sql, values) = builder.build_alter_type(&stmt);
8298		assert_eq!(sql, r#"ALTER TYPE "mood" ADD VALUE 'excited'"#);
8299		assert_eq!(values.len(), 0);
8300	}
8301
8302	#[test]
8303	fn test_alter_type_add_value_before() {
8304		let builder = PostgresQueryBuilder::new();
8305		let mut stmt = Query::alter_type();
8306		stmt.name("mood").add_value("excited", Some("happy"));
8307
8308		let (sql, values) = builder.build_alter_type(&stmt);
8309		assert_eq!(
8310			sql,
8311			r#"ALTER TYPE "mood" ADD VALUE 'excited' BEFORE 'happy'"#
8312		);
8313		assert_eq!(values.len(), 0);
8314	}
8315
8316	#[test]
8317	fn test_alter_type_rename_value() {
8318		let builder = PostgresQueryBuilder::new();
8319		let mut stmt = Query::alter_type();
8320		stmt.name("mood").rename_value("happy", "joyful");
8321
8322		let (sql, values) = builder.build_alter_type(&stmt);
8323		assert_eq!(sql, r#"ALTER TYPE "mood" RENAME VALUE 'happy' TO 'joyful'"#);
8324		assert_eq!(values.len(), 0);
8325	}
8326
8327	#[test]
8328	fn test_alter_type_add_constraint() {
8329		let builder = PostgresQueryBuilder::new();
8330		let mut stmt = Query::alter_type();
8331		stmt.name("my_domain")
8332			.add_constraint("positive_check", "CHECK (VALUE > 0)");
8333
8334		let (sql, values) = builder.build_alter_type(&stmt);
8335		assert_eq!(
8336			sql,
8337			r#"ALTER TYPE "my_domain" ADD CONSTRAINT "positive_check" CHECK (VALUE > 0)"#
8338		);
8339		assert_eq!(values.len(), 0);
8340	}
8341
8342	#[test]
8343	fn test_alter_type_drop_constraint() {
8344		let builder = PostgresQueryBuilder::new();
8345		let mut stmt = Query::alter_type();
8346		stmt.name("my_domain")
8347			.drop_constraint("my_constraint", false);
8348
8349		let (sql, values) = builder.build_alter_type(&stmt);
8350		assert_eq!(
8351			sql,
8352			r#"ALTER TYPE "my_domain" DROP CONSTRAINT "my_constraint""#
8353		);
8354		assert_eq!(values.len(), 0);
8355	}
8356
8357	#[test]
8358	fn test_alter_type_drop_constraint_if_exists() {
8359		let builder = PostgresQueryBuilder::new();
8360		let mut stmt = Query::alter_type();
8361		stmt.name("my_domain")
8362			.drop_constraint("my_constraint", true);
8363
8364		let (sql, values) = builder.build_alter_type(&stmt);
8365		assert_eq!(
8366			sql,
8367			r#"ALTER TYPE "my_domain" DROP CONSTRAINT IF EXISTS "my_constraint""#
8368		);
8369		assert_eq!(values.len(), 0);
8370	}
8371
8372	#[test]
8373	fn test_alter_type_set_default() {
8374		let builder = PostgresQueryBuilder::new();
8375		let mut stmt = Query::alter_type();
8376		stmt.name("my_domain").set_default("0");
8377
8378		let (sql, values) = builder.build_alter_type(&stmt);
8379		assert_eq!(sql, r#"ALTER TYPE "my_domain" SET DEFAULT 0"#);
8380		assert_eq!(values.len(), 0);
8381	}
8382
8383	#[test]
8384	fn test_alter_type_drop_default() {
8385		let builder = PostgresQueryBuilder::new();
8386		let mut stmt = Query::alter_type();
8387		stmt.name("my_domain").drop_default();
8388
8389		let (sql, values) = builder.build_alter_type(&stmt);
8390		assert_eq!(sql, r#"ALTER TYPE "my_domain" DROP DEFAULT"#);
8391		assert_eq!(values.len(), 0);
8392	}
8393
8394	#[test]
8395	fn test_alter_type_set_not_null() {
8396		let builder = PostgresQueryBuilder::new();
8397		let mut stmt = Query::alter_type();
8398		stmt.name("my_domain").set_not_null();
8399
8400		let (sql, values) = builder.build_alter_type(&stmt);
8401		assert_eq!(sql, r#"ALTER TYPE "my_domain" SET NOT NULL"#);
8402		assert_eq!(values.len(), 0);
8403	}
8404
8405	#[test]
8406	fn test_alter_type_drop_not_null() {
8407		let builder = PostgresQueryBuilder::new();
8408		let mut stmt = Query::alter_type();
8409		stmt.name("my_domain").drop_not_null();
8410
8411		let (sql, values) = builder.build_alter_type(&stmt);
8412		assert_eq!(sql, r#"ALTER TYPE "my_domain" DROP NOT NULL"#);
8413		assert_eq!(values.len(), 0);
8414	}
8415
8416	// DROP TYPE tests
8417	#[test]
8418	fn test_drop_type_basic() {
8419		let builder = PostgresQueryBuilder::new();
8420		let mut stmt = Query::drop_type();
8421		stmt.name("my_type");
8422
8423		let (sql, values) = builder.build_drop_type(&stmt);
8424		assert_eq!(sql, r#"DROP TYPE "my_type""#);
8425		assert_eq!(values.len(), 0);
8426	}
8427
8428	#[test]
8429	fn test_drop_type_if_exists() {
8430		let builder = PostgresQueryBuilder::new();
8431		let mut stmt = Query::drop_type();
8432		stmt.name("my_type").if_exists();
8433
8434		let (sql, values) = builder.build_drop_type(&stmt);
8435		assert_eq!(sql, r#"DROP TYPE IF EXISTS "my_type""#);
8436		assert_eq!(values.len(), 0);
8437	}
8438
8439	#[test]
8440	fn test_drop_type_cascade() {
8441		let builder = PostgresQueryBuilder::new();
8442		let mut stmt = Query::drop_type();
8443		stmt.name("my_type").cascade();
8444
8445		let (sql, values) = builder.build_drop_type(&stmt);
8446		assert_eq!(sql, r#"DROP TYPE "my_type" CASCADE"#);
8447		assert_eq!(values.len(), 0);
8448	}
8449
8450	#[test]
8451	fn test_drop_type_restrict() {
8452		let builder = PostgresQueryBuilder::new();
8453		let mut stmt = Query::drop_type();
8454		stmt.name("my_type").restrict();
8455
8456		let (sql, values) = builder.build_drop_type(&stmt);
8457		assert_eq!(sql, r#"DROP TYPE "my_type" RESTRICT"#);
8458		assert_eq!(values.len(), 0);
8459	}
8460
8461	#[test]
8462	fn test_drop_type_all_options() {
8463		let builder = PostgresQueryBuilder::new();
8464		let mut stmt = Query::drop_type();
8465		stmt.name("my_type").if_exists().cascade();
8466
8467		let (sql, values) = builder.build_drop_type(&stmt);
8468		assert_eq!(sql, r#"DROP TYPE IF EXISTS "my_type" CASCADE"#);
8469		assert_eq!(values.len(), 0);
8470	}
8471
8472	// MySQL-specific maintenance command panic tests
8473	#[test]
8474	#[should_panic(expected = "PostgreSQL users should use VACUUM ANALYZE")]
8475	fn test_optimize_table_panics() {
8476		let builder = PostgresQueryBuilder::new();
8477		let mut stmt = Query::optimize_table();
8478		stmt.table("users");
8479
8480		let _ = builder.build_optimize_table(&stmt);
8481	}
8482
8483	#[test]
8484	#[should_panic(expected = "not supported in PostgreSQL")]
8485	fn test_repair_table_panics() {
8486		let builder = PostgresQueryBuilder::new();
8487		let mut stmt = Query::repair_table();
8488		stmt.table("users");
8489
8490		let _ = builder.build_repair_table(&stmt);
8491	}
8492
8493	#[test]
8494	#[should_panic(expected = "not supported in PostgreSQL")]
8495	fn test_check_table_panics() {
8496		let builder = PostgresQueryBuilder::new();
8497		let mut stmt = Query::check_table();
8498		stmt.table("users");
8499
8500		let _ = builder.build_check_table(&stmt);
8501	}
8502
8503	// DCL (Data Control Language) Tests
8504
8505	#[test]
8506	fn test_grant_single_privilege_on_table() {
8507		use crate::dcl::{GrantStatement, Privilege};
8508
8509		let builder = PostgresQueryBuilder::new();
8510		let stmt = GrantStatement::new()
8511			.privilege(Privilege::Select)
8512			.on_table("users")
8513			.to("app_user");
8514
8515		let (sql, values) = builder.build_grant(&stmt);
8516		assert_eq!(sql, r#"GRANT SELECT ON TABLE "users" TO "app_user""#);
8517		assert!(values.is_empty());
8518	}
8519
8520	#[test]
8521	fn test_grant_multiple_privileges() {
8522		use crate::dcl::{GrantStatement, Privilege};
8523
8524		let builder = PostgresQueryBuilder::new();
8525		let stmt = GrantStatement::new()
8526			.privileges(vec![
8527				Privilege::Select,
8528				Privilege::Insert,
8529				Privilege::Update,
8530			])
8531			.on_table("users")
8532			.to("app_user");
8533
8534		let (sql, values) = builder.build_grant(&stmt);
8535		assert_eq!(
8536			sql,
8537			r#"GRANT SELECT, INSERT, UPDATE ON TABLE "users" TO "app_user""#
8538		);
8539		assert!(values.is_empty());
8540	}
8541
8542	#[test]
8543	fn test_grant_multiple_objects() {
8544		use crate::dcl::{GrantStatement, ObjectType, Privilege};
8545
8546		let builder = PostgresQueryBuilder::new();
8547		let stmt = GrantStatement::new()
8548			.privilege(Privilege::Select)
8549			.object_type(ObjectType::Table)
8550			.object("users")
8551			.object("posts")
8552			.to("app_user");
8553
8554		let (sql, values) = builder.build_grant(&stmt);
8555		assert_eq!(
8556			sql,
8557			r#"GRANT SELECT ON TABLE "users", "posts" TO "app_user""#
8558		);
8559		assert!(values.is_empty());
8560	}
8561
8562	#[test]
8563	fn test_grant_multiple_grantees() {
8564		use crate::dcl::{GrantStatement, Grantee, Privilege};
8565
8566		let builder = PostgresQueryBuilder::new();
8567		let stmt = GrantStatement::new()
8568			.privilege(Privilege::Select)
8569			.on_table("users")
8570			.grantee(Grantee::role("app_user"))
8571			.grantee(Grantee::role("readonly_user"));
8572
8573		let (sql, values) = builder.build_grant(&stmt);
8574		assert_eq!(
8575			sql,
8576			r#"GRANT SELECT ON TABLE "users" TO "app_user", "readonly_user""#
8577		);
8578		assert!(values.is_empty());
8579	}
8580
8581	#[test]
8582	fn test_grant_with_grant_option() {
8583		use crate::dcl::{GrantStatement, Privilege};
8584
8585		let builder = PostgresQueryBuilder::new();
8586		let stmt = GrantStatement::new()
8587			.privilege(Privilege::Select)
8588			.on_table("users")
8589			.to("app_user")
8590			.with_grant_option(true);
8591
8592		let (sql, values) = builder.build_grant(&stmt);
8593		assert_eq!(
8594			sql,
8595			r#"GRANT SELECT ON TABLE "users" TO "app_user" WITH GRANT OPTION"#
8596		);
8597		assert!(values.is_empty());
8598	}
8599
8600	#[test]
8601	fn test_grant_with_granted_by() {
8602		use crate::dcl::{GrantStatement, Grantee, Privilege};
8603
8604		let builder = PostgresQueryBuilder::new();
8605		let stmt = GrantStatement::new()
8606			.privilege(Privilege::Select)
8607			.on_table("users")
8608			.to("app_user")
8609			.granted_by(Grantee::role("admin"));
8610
8611		let (sql, values) = builder.build_grant(&stmt);
8612		assert_eq!(
8613			sql,
8614			r#"GRANT SELECT ON TABLE "users" TO "app_user" GRANTED BY "admin""#
8615		);
8616		assert!(values.is_empty());
8617	}
8618
8619	#[test]
8620	fn test_grant_on_database() {
8621		use crate::dcl::{GrantStatement, Privilege};
8622
8623		let builder = PostgresQueryBuilder::new();
8624		let stmt = GrantStatement::new()
8625			.privilege(Privilege::Create)
8626			.on_database("mydb")
8627			.to("app_user");
8628
8629		let (sql, values) = builder.build_grant(&stmt);
8630		assert_eq!(sql, r#"GRANT CREATE ON DATABASE "mydb" TO "app_user""#);
8631		assert!(values.is_empty());
8632	}
8633
8634	#[test]
8635	fn test_grant_on_schema() {
8636		use crate::dcl::{GrantStatement, Privilege};
8637
8638		let builder = PostgresQueryBuilder::new();
8639		let stmt = GrantStatement::new()
8640			.privilege(Privilege::Usage)
8641			.on_schema("public")
8642			.to("app_user");
8643
8644		let (sql, values) = builder.build_grant(&stmt);
8645		assert_eq!(sql, r#"GRANT USAGE ON SCHEMA "public" TO "app_user""#);
8646		assert!(values.is_empty());
8647	}
8648
8649	#[test]
8650	fn test_grant_on_sequence() {
8651		use crate::dcl::{GrantStatement, Privilege};
8652
8653		let builder = PostgresQueryBuilder::new();
8654		let stmt = GrantStatement::new()
8655			.privilege(Privilege::Usage)
8656			.on_sequence("user_id_seq")
8657			.to("app_user");
8658
8659		let (sql, values) = builder.build_grant(&stmt);
8660		assert_eq!(
8661			sql,
8662			r#"GRANT USAGE ON SEQUENCE "user_id_seq" TO "app_user""#
8663		);
8664		assert!(values.is_empty());
8665	}
8666
8667	#[test]
8668	fn test_grant_all_privileges() {
8669		use crate::dcl::{GrantStatement, Privilege};
8670
8671		let builder = PostgresQueryBuilder::new();
8672		let stmt = GrantStatement::new()
8673			.privilege(Privilege::All)
8674			.on_table("users")
8675			.to("admin");
8676
8677		let (sql, values) = builder.build_grant(&stmt);
8678		assert_eq!(sql, r#"GRANT ALL PRIVILEGES ON TABLE "users" TO "admin""#);
8679		assert!(values.is_empty());
8680	}
8681
8682	#[test]
8683	fn test_grant_to_public() {
8684		use crate::dcl::{GrantStatement, Grantee, Privilege};
8685
8686		let builder = PostgresQueryBuilder::new();
8687		let stmt = GrantStatement::new()
8688			.privilege(Privilege::Select)
8689			.on_table("public_data")
8690			.grantee(Grantee::Public);
8691
8692		let (sql, values) = builder.build_grant(&stmt);
8693		assert_eq!(sql, r#"GRANT SELECT ON TABLE "public_data" TO PUBLIC"#);
8694		assert!(values.is_empty());
8695	}
8696
8697	#[test]
8698	fn test_grant_to_current_user() {
8699		use crate::dcl::{GrantStatement, Grantee, Privilege};
8700
8701		let builder = PostgresQueryBuilder::new();
8702		let stmt = GrantStatement::new()
8703			.privilege(Privilege::Select)
8704			.on_table("users")
8705			.grantee(Grantee::CurrentUser);
8706
8707		let (sql, values) = builder.build_grant(&stmt);
8708		assert_eq!(sql, r#"GRANT SELECT ON TABLE "users" TO CURRENT_USER"#);
8709		assert!(values.is_empty());
8710	}
8711
8712	#[test]
8713	fn test_grant_complex() {
8714		use crate::dcl::{GrantStatement, Grantee, Privilege};
8715
8716		let builder = PostgresQueryBuilder::new();
8717		let stmt = GrantStatement::new()
8718			.privileges(vec![
8719				Privilege::Select,
8720				Privilege::Insert,
8721				Privilege::Update,
8722			])
8723			.on_table("users")
8724			.on_table("posts")
8725			.grantee(Grantee::role("app_user"))
8726			.grantee(Grantee::role("readonly_user"))
8727			.with_grant_option(true)
8728			.granted_by(Grantee::role("admin"));
8729
8730		let (sql, values) = builder.build_grant(&stmt);
8731		assert!(sql.starts_with("GRANT SELECT, INSERT, UPDATE ON TABLE"));
8732		assert!(sql.contains(r#""users", "posts""#));
8733		assert!(sql.contains(r#"TO "app_user", "readonly_user""#));
8734		assert!(sql.contains("WITH GRANT OPTION"));
8735		assert!(sql.contains(r#"GRANTED BY "admin""#));
8736		assert!(values.is_empty());
8737	}
8738
8739	// REVOKE tests
8740
8741	#[test]
8742	fn test_revoke_single_privilege() {
8743		use crate::dcl::{Privilege, RevokeStatement};
8744
8745		let builder = PostgresQueryBuilder::new();
8746		let stmt = RevokeStatement::new()
8747			.privilege(Privilege::Insert)
8748			.from_table("users")
8749			.from("app_user");
8750
8751		let (sql, values) = builder.build_revoke(&stmt);
8752		assert_eq!(sql, r#"REVOKE INSERT ON TABLE "users" FROM "app_user""#);
8753		assert!(values.is_empty());
8754	}
8755
8756	#[test]
8757	fn test_revoke_multiple_privileges() {
8758		use crate::dcl::{Privilege, RevokeStatement};
8759
8760		let builder = PostgresQueryBuilder::new();
8761		let stmt = RevokeStatement::new()
8762			.privileges(vec![
8763				Privilege::Select,
8764				Privilege::Insert,
8765				Privilege::Update,
8766			])
8767			.from_table("users")
8768			.from("app_user");
8769
8770		let (sql, values) = builder.build_revoke(&stmt);
8771		assert_eq!(
8772			sql,
8773			r#"REVOKE SELECT, INSERT, UPDATE ON TABLE "users" FROM "app_user""#
8774		);
8775		assert!(values.is_empty());
8776	}
8777
8778	#[test]
8779	fn test_revoke_with_cascade() {
8780		use crate::dcl::{Privilege, RevokeStatement};
8781
8782		let builder = PostgresQueryBuilder::new();
8783		let stmt = RevokeStatement::new()
8784			.privilege(Privilege::All)
8785			.from_table("users")
8786			.from("app_user")
8787			.cascade(true);
8788
8789		let (sql, values) = builder.build_revoke(&stmt);
8790		assert_eq!(
8791			sql,
8792			r#"REVOKE ALL PRIVILEGES ON TABLE "users" FROM "app_user" CASCADE"#
8793		);
8794		assert!(values.is_empty());
8795	}
8796
8797	#[test]
8798	fn test_revoke_grant_option_for() {
8799		use crate::dcl::{Privilege, RevokeStatement};
8800
8801		let builder = PostgresQueryBuilder::new();
8802		let stmt = RevokeStatement::new()
8803			.privilege(Privilege::Select)
8804			.from_table("users")
8805			.from("app_user")
8806			.grant_option_for(true);
8807
8808		let (sql, values) = builder.build_revoke(&stmt);
8809		assert_eq!(
8810			sql,
8811			r#"REVOKE GRANT OPTION FOR SELECT ON TABLE "users" FROM "app_user""#
8812		);
8813		assert!(values.is_empty());
8814	}
8815
8816	#[test]
8817	fn test_revoke_from_database() {
8818		use crate::dcl::{Privilege, RevokeStatement};
8819
8820		let builder = PostgresQueryBuilder::new();
8821		let stmt = RevokeStatement::new()
8822			.privilege(Privilege::Create)
8823			.from_database("mydb")
8824			.from("app_user");
8825
8826		let (sql, values) = builder.build_revoke(&stmt);
8827		assert_eq!(sql, r#"REVOKE CREATE ON DATABASE "mydb" FROM "app_user""#);
8828		assert!(values.is_empty());
8829	}
8830
8831	#[test]
8832	fn test_revoke_from_schema() {
8833		use crate::dcl::{Privilege, RevokeStatement};
8834
8835		let builder = PostgresQueryBuilder::new();
8836		let stmt = RevokeStatement::new()
8837			.privilege(Privilege::Usage)
8838			.from_schema("public")
8839			.from("app_user");
8840
8841		let (sql, values) = builder.build_revoke(&stmt);
8842		assert_eq!(sql, r#"REVOKE USAGE ON SCHEMA "public" FROM "app_user""#);
8843		assert!(values.is_empty());
8844	}
8845
8846	#[test]
8847	fn test_revoke_from_sequence() {
8848		use crate::dcl::{Privilege, RevokeStatement};
8849
8850		let builder = PostgresQueryBuilder::new();
8851		let stmt = RevokeStatement::new()
8852			.privilege(Privilege::Usage)
8853			.from_sequence("user_id_seq")
8854			.from("app_user");
8855
8856		let (sql, values) = builder.build_revoke(&stmt);
8857		assert_eq!(
8858			sql,
8859			r#"REVOKE USAGE ON SEQUENCE "user_id_seq" FROM "app_user""#
8860		);
8861		assert!(values.is_empty());
8862	}
8863
8864	#[test]
8865	fn test_revoke_from_public() {
8866		use crate::dcl::{Grantee, Privilege, RevokeStatement};
8867
8868		let builder = PostgresQueryBuilder::new();
8869		let stmt = RevokeStatement::new()
8870			.privilege(Privilege::Select)
8871			.from_table("public_data")
8872			.grantee(Grantee::Public);
8873
8874		let (sql, values) = builder.build_revoke(&stmt);
8875		assert_eq!(sql, r#"REVOKE SELECT ON TABLE "public_data" FROM PUBLIC"#);
8876		assert!(values.is_empty());
8877	}
8878
8879	#[test]
8880	fn test_revoke_from_current_user() {
8881		use crate::dcl::{Grantee, Privilege, RevokeStatement};
8882
8883		let builder = PostgresQueryBuilder::new();
8884		let stmt = RevokeStatement::new()
8885			.privilege(Privilege::Select)
8886			.from_table("users")
8887			.grantee(Grantee::CurrentUser);
8888
8889		let (sql, values) = builder.build_revoke(&stmt);
8890		assert_eq!(sql, r#"REVOKE SELECT ON TABLE "users" FROM CURRENT_USER"#);
8891		assert!(values.is_empty());
8892	}
8893
8894	#[test]
8895	fn test_revoke_complex() {
8896		use crate::dcl::{Grantee, Privilege, RevokeStatement};
8897
8898		let builder = PostgresQueryBuilder::new();
8899		let stmt = RevokeStatement::new()
8900			.privileges(vec![Privilege::Select, Privilege::Insert])
8901			.from_table("users")
8902			.from_table("posts")
8903			.grantee(Grantee::role("app_user"))
8904			.grantee(Grantee::role("readonly_user"))
8905			.cascade(true);
8906
8907		let (sql, values) = builder.build_revoke(&stmt);
8908		assert!(sql.starts_with("REVOKE SELECT, INSERT ON TABLE"));
8909		assert!(sql.contains(r#""users", "posts""#));
8910		assert!(sql.contains(r#"FROM "app_user", "readonly_user""#));
8911		assert!(sql.contains("CASCADE"));
8912		assert!(values.is_empty());
8913	}
8914
8915	#[test]
8916	fn test_create_role_simple() {
8917		use crate::dcl::CreateRoleStatement;
8918
8919		let builder = PostgresQueryBuilder::new();
8920		let stmt = CreateRoleStatement::new().role("developer");
8921
8922		let (sql, values) = builder.build_create_role(&stmt);
8923		assert_eq!(sql, r#"CREATE ROLE "developer""#);
8924		assert!(values.is_empty());
8925	}
8926
8927	#[test]
8928	fn test_create_role_with_login() {
8929		use crate::dcl::{CreateRoleStatement, RoleAttribute};
8930		use crate::value::Value;
8931
8932		let builder = PostgresQueryBuilder::new();
8933		let stmt = CreateRoleStatement::new()
8934			.role("app_user")
8935			.attribute(RoleAttribute::Login)
8936			.attribute(RoleAttribute::Password("secret".to_string()));
8937
8938		let (sql, values) = builder.build_create_role(&stmt);
8939		assert_eq!(sql, r#"CREATE ROLE "app_user" WITH LOGIN PASSWORD $1"#);
8940		assert_eq!(values.len(), 1);
8941		assert_eq!(
8942			values[0],
8943			Value::String(Some(Box::new("secret".to_string())))
8944		);
8945	}
8946
8947	#[test]
8948	fn test_create_role_with_multiple_attributes() {
8949		use crate::dcl::{CreateRoleStatement, RoleAttribute};
8950
8951		let builder = PostgresQueryBuilder::new();
8952		let stmt = CreateRoleStatement::new()
8953			.role("superuser")
8954			.attribute(RoleAttribute::SuperUser)
8955			.attribute(RoleAttribute::CreateDb)
8956			.attribute(RoleAttribute::CreateRole)
8957			.attribute(RoleAttribute::ConnectionLimit(10));
8958
8959		let (sql, values) = builder.build_create_role(&stmt);
8960		assert_eq!(
8961			sql,
8962			r#"CREATE ROLE "superuser" WITH SUPERUSER CREATEDB CREATEROLE CONNECTION LIMIT 10"#
8963		);
8964		assert!(values.is_empty());
8965	}
8966
8967	#[test]
8968	fn test_drop_role_simple() {
8969		use crate::dcl::DropRoleStatement;
8970
8971		let builder = PostgresQueryBuilder::new();
8972		let stmt = DropRoleStatement::new().role("old_role");
8973
8974		let (sql, values) = builder.build_drop_role(&stmt);
8975		assert_eq!(sql, r#"DROP ROLE "old_role""#);
8976		assert!(values.is_empty());
8977	}
8978
8979	#[test]
8980	fn test_drop_role_if_exists() {
8981		use crate::dcl::DropRoleStatement;
8982
8983		let builder = PostgresQueryBuilder::new();
8984		let stmt = DropRoleStatement::new().role("old_role").if_exists(true);
8985
8986		let (sql, values) = builder.build_drop_role(&stmt);
8987		assert_eq!(sql, r#"DROP ROLE IF EXISTS "old_role""#);
8988		assert!(values.is_empty());
8989	}
8990
8991	#[test]
8992	fn test_drop_role_multiple() {
8993		use crate::dcl::DropRoleStatement;
8994
8995		let builder = PostgresQueryBuilder::new();
8996		let stmt = DropRoleStatement::new()
8997			.role("role1")
8998			.role("role2")
8999			.role("role3");
9000
9001		let (sql, values) = builder.build_drop_role(&stmt);
9002		assert_eq!(sql, r#"DROP ROLE "role1", "role2", "role3""#);
9003		assert!(values.is_empty());
9004	}
9005
9006	#[test]
9007	fn test_alter_role_with_attributes() {
9008		use crate::dcl::{AlterRoleStatement, RoleAttribute};
9009
9010		let builder = PostgresQueryBuilder::new();
9011		let stmt = AlterRoleStatement::new()
9012			.role("developer")
9013			.attribute(RoleAttribute::NoLogin)
9014			.attribute(RoleAttribute::ConnectionLimit(5));
9015
9016		let (sql, values) = builder.build_alter_role(&stmt);
9017		assert_eq!(
9018			sql,
9019			r#"ALTER ROLE "developer" WITH NOLOGIN CONNECTION LIMIT 5"#
9020		);
9021		assert!(values.is_empty());
9022	}
9023
9024	#[test]
9025	fn test_alter_role_rename_to() {
9026		use crate::dcl::AlterRoleStatement;
9027
9028		let builder = PostgresQueryBuilder::new();
9029		let stmt = AlterRoleStatement::new()
9030			.role("old_name")
9031			.rename_to("new_name");
9032
9033		let (sql, values) = builder.build_alter_role(&stmt);
9034		assert_eq!(sql, r#"ALTER ROLE "old_name" RENAME TO "new_name""#);
9035		assert!(values.is_empty());
9036	}
9037
9038	// CREATE USER tests
9039	#[test]
9040	fn test_create_user_basic() {
9041		use crate::dcl::CreateUserStatement;
9042
9043		let builder = PostgresQueryBuilder::new();
9044		let stmt = CreateUserStatement::new().user("app_user");
9045
9046		let (sql, values) = builder.build_create_user(&stmt);
9047		assert_eq!(sql, r#"CREATE ROLE "app_user" WITH LOGIN"#);
9048		assert!(values.is_empty());
9049	}
9050
9051	#[test]
9052	fn test_create_user_with_password() {
9053		use crate::dcl::{CreateUserStatement, RoleAttribute};
9054		use crate::value::Value;
9055
9056		let builder = PostgresQueryBuilder::new();
9057		let stmt = CreateUserStatement::new()
9058			.user("app_user")
9059			.attribute(RoleAttribute::Password("secret".to_string()));
9060
9061		let (sql, values) = builder.build_create_user(&stmt);
9062		assert_eq!(sql, r#"CREATE ROLE "app_user" WITH LOGIN PASSWORD $1"#);
9063		assert_eq!(values.len(), 1);
9064		assert_eq!(
9065			values[0],
9066			Value::String(Some(Box::new("secret".to_string())))
9067		);
9068	}
9069
9070	// DROP USER tests
9071	#[test]
9072	fn test_drop_user_basic() {
9073		use crate::dcl::DropUserStatement;
9074
9075		let builder = PostgresQueryBuilder::new();
9076		let stmt = DropUserStatement::new().user("app_user");
9077
9078		let (sql, values) = builder.build_drop_user(&stmt);
9079		assert_eq!(sql, r#"DROP ROLE "app_user""#);
9080		assert!(values.is_empty());
9081	}
9082
9083	#[test]
9084	fn test_drop_user_if_exists() {
9085		use crate::dcl::DropUserStatement;
9086
9087		let builder = PostgresQueryBuilder::new();
9088		let stmt = DropUserStatement::new().user("app_user").if_exists(true);
9089
9090		let (sql, values) = builder.build_drop_user(&stmt);
9091		assert_eq!(sql, r#"DROP ROLE IF EXISTS "app_user""#);
9092		assert!(values.is_empty());
9093	}
9094
9095	// ALTER USER tests
9096	#[test]
9097	fn test_alter_user_basic() {
9098		use crate::dcl::{AlterUserStatement, RoleAttribute};
9099		use crate::value::Value;
9100
9101		let builder = PostgresQueryBuilder::new();
9102		let stmt = AlterUserStatement::new()
9103			.user("app_user")
9104			.attribute(RoleAttribute::Password("new_secret".to_string()));
9105
9106		let (sql, values) = builder.build_alter_user(&stmt);
9107		assert_eq!(sql, r#"ALTER ROLE "app_user" WITH PASSWORD $1"#);
9108		assert_eq!(values.len(), 1);
9109		assert_eq!(
9110			values[0],
9111			Value::String(Some(Box::new("new_secret".to_string())))
9112		);
9113	}
9114
9115	// RENAME USER panic test
9116	#[test]
9117	#[should_panic(expected = "RENAME USER is not supported by PostgreSQL")]
9118	fn test_rename_user_panics() {
9119		use crate::dcl::RenameUserStatement;
9120
9121		let builder = PostgresQueryBuilder::new();
9122		let stmt = RenameUserStatement::new().rename("old", "new");
9123
9124		builder.build_rename_user(&stmt);
9125	}
9126
9127	// SET ROLE tests
9128	#[test]
9129	fn test_set_role_named() {
9130		use crate::dcl::{RoleTarget, SetRoleStatement};
9131
9132		let builder = PostgresQueryBuilder::new();
9133		let stmt = SetRoleStatement::new().role(RoleTarget::Named("admin".to_string()));
9134
9135		let (sql, values) = builder.build_set_role(&stmt);
9136		assert_eq!(sql, r#"SET ROLE "admin""#);
9137		assert!(values.is_empty());
9138	}
9139
9140	#[test]
9141	fn test_set_role_none() {
9142		use crate::dcl::{RoleTarget, SetRoleStatement};
9143
9144		let builder = PostgresQueryBuilder::new();
9145		let stmt = SetRoleStatement::new().role(RoleTarget::None);
9146
9147		let (sql, values) = builder.build_set_role(&stmt);
9148		assert_eq!(sql, "SET ROLE NONE");
9149		assert!(values.is_empty());
9150	}
9151
9152	#[test]
9153	#[should_panic(expected = "SET ROLE ALL is not supported by PostgreSQL")]
9154	fn test_set_role_all_panics() {
9155		use crate::dcl::{RoleTarget, SetRoleStatement};
9156
9157		let builder = PostgresQueryBuilder::new();
9158		let stmt = SetRoleStatement::new().role(RoleTarget::All);
9159
9160		builder.build_set_role(&stmt);
9161	}
9162
9163	// RESET ROLE test
9164	#[test]
9165	fn test_reset_role() {
9166		use crate::dcl::ResetRoleStatement;
9167
9168		let builder = PostgresQueryBuilder::new();
9169		let stmt = ResetRoleStatement::new();
9170
9171		let (sql, values) = builder.build_reset_role(&stmt);
9172		assert_eq!(sql, "RESET ROLE");
9173		assert!(values.is_empty());
9174	}
9175
9176	// SET DEFAULT ROLE panic test
9177	#[test]
9178	#[should_panic(expected = "SET DEFAULT ROLE is not supported by PostgreSQL")]
9179	fn test_set_default_role_panics() {
9180		use crate::dcl::{DefaultRoleSpec, SetDefaultRoleStatement};
9181
9182		let builder = PostgresQueryBuilder::new();
9183		let stmt = SetDefaultRoleStatement::new()
9184			.roles(DefaultRoleSpec::All)
9185			.user("app_user");
9186
9187		builder.build_set_default_role(&stmt);
9188	}
9189
9190	// ==================== SQL identifier escaping tests ====================
9191
9192	#[rstest]
9193	fn test_as_enum_escapes_type_name_with_special_characters() {
9194		// Arrange
9195		let builder = PostgresQueryBuilder::new();
9196		let mut stmt = Query::select();
9197		stmt.expr(Expr::val("active").as_enum(Alias::new("user\"status")))
9198			.from("users");
9199
9200		// Act
9201		let (sql, _) = builder.build_select(&stmt);
9202
9203		// Assert: enum type name must be quoted and inner quotes doubled
9204		assert!(sql.contains("::\"user\"\"status\""));
9205	}
9206
9207	#[rstest]
9208	fn test_cast_escapes_type_name_with_special_characters() {
9209		// Arrange
9210		let builder = PostgresQueryBuilder::new();
9211		let mut stmt = Query::select();
9212		stmt.expr(Expr::col("age").cast_as(Alias::new("my\"type")))
9213			.from("users");
9214
9215		// Act
9216		let (sql, _) = builder.build_select(&stmt);
9217
9218		// Assert: cast type name must be quoted and inner quotes doubled
9219		assert!(sql.contains("CAST(\"age\" AS \"my\"\"type\")"));
9220	}
9221
9222	#[rstest]
9223	fn test_trigger_function_name_is_escaped() {
9224		// Arrange
9225		let builder = PostgresQueryBuilder::new();
9226		let mut stmt = Query::create_trigger();
9227		stmt.name("test_trigger")
9228			.timing(crate::types::TriggerTiming::After)
9229			.event(crate::types::TriggerEvent::Insert)
9230			.on_table("users")
9231			.for_each(crate::types::TriggerScope::Row)
9232			.execute_function("my\"func");
9233
9234		// Act
9235		let (sql, _) = builder.build_create_trigger(&stmt);
9236
9237		// Assert: function name must be quoted and inner quotes doubled
9238		assert!(sql.contains("EXECUTE FUNCTION \"my\"\"func\"()"));
9239	}
9240
9241	#[rstest]
9242	fn test_as_enum_normal_type_name_is_quoted() {
9243		// Arrange
9244		let builder = PostgresQueryBuilder::new();
9245		let mut stmt = Query::select();
9246		stmt.expr(Expr::val("active").as_enum(Alias::new("status")))
9247			.from("users");
9248
9249		// Act
9250		let (sql, _) = builder.build_select(&stmt);
9251
9252		// Assert: even normal identifiers should be quoted
9253		assert!(sql.contains("::\"status\""));
9254	}
9255
9256	#[rstest]
9257	fn test_cast_normal_type_name_is_quoted() {
9258		// Arrange
9259		let builder = PostgresQueryBuilder::new();
9260		let mut stmt = Query::select();
9261		stmt.expr(Expr::col("age").cast_as(Alias::new("INTEGER")))
9262			.from("users");
9263
9264		// Act
9265		let (sql, _) = builder.build_select(&stmt);
9266
9267		// Assert: cast type name should be quoted
9268		assert!(sql.contains("CAST(\"age\" AS \"INTEGER\")"));
9269	}
9270
9271	// ==================== Dollar-quote delimiter safety tests ====================
9272
9273	#[rstest]
9274	fn test_safe_delimiter_default_when_body_has_no_dollar_quotes() {
9275		// Arrange
9276		let body = "BEGIN RETURN 1; END;";
9277
9278		// Act
9279		let delimiter = generate_safe_dollar_quote_delimiter(body);
9280
9281		// Assert
9282		assert_eq!(delimiter, "$$");
9283	}
9284
9285	#[rstest]
9286	fn test_safe_delimiter_avoids_collision_with_dollar_dollar() {
9287		// Arrange
9288		let body = "BEGIN $$ nested $$ END;";
9289
9290		// Act
9291		let delimiter = generate_safe_dollar_quote_delimiter(body);
9292
9293		// Assert
9294		assert_ne!(
9295			delimiter, "$$",
9296			"Delimiter must not be $$ when body contains $$"
9297		);
9298		assert_eq!(delimiter, "$body_0$");
9299	}
9300
9301	#[rstest]
9302	fn test_safe_delimiter_injection_attempt_with_dollar_quotes() {
9303		// Arrange: attacker tries to break out of dollar-quoting
9304		let body = "$$ ; DROP TABLE users; --";
9305
9306		// Act
9307		let delimiter = generate_safe_dollar_quote_delimiter(body);
9308
9309		// Assert
9310		assert_ne!(delimiter, "$$");
9311		let delimiters = collect_dollar_quote_delimiters(body);
9312		assert!(
9313			!delimiters.contains(&delimiter),
9314			"Generated delimiter must not conflict with any delimiter in body"
9315		);
9316	}
9317
9318	#[rstest]
9319	fn test_safe_delimiter_skips_collision_with_body_0() {
9320		// Arrange: body contains both $$ and $body_0$
9321		let body = "BEGIN $$ test $body_0$ END;";
9322
9323		// Act
9324		let delimiter = generate_safe_dollar_quote_delimiter(body);
9325
9326		// Assert
9327		assert_eq!(delimiter, "$body_1$");
9328	}
9329
9330	#[rstest]
9331	fn test_safe_delimiter_multiple_collisions() {
9332		// Arrange: body contains $$, $body_0$, $body_1$
9333		let body = "$$ $body_0$ $body_1$";
9334
9335		// Act
9336		let delimiter = generate_safe_dollar_quote_delimiter(body);
9337
9338		// Assert
9339		assert_eq!(delimiter, "$body_2$");
9340	}
9341
9342	#[rstest]
9343	fn test_safe_delimiter_ignores_dollar_amount_not_delimiter() {
9344		// Arrange: $100 is not a dollar-quote delimiter (digit after $)
9345		let body = "SELECT $100 + $200";
9346
9347		// Act
9348		let delimiter = generate_safe_dollar_quote_delimiter(body);
9349
9350		// Assert: $$ is safe because $100 is not a delimiter
9351		assert_eq!(delimiter, "$$");
9352	}
9353
9354	#[rstest]
9355	fn test_safe_delimiter_empty_body() {
9356		// Arrange
9357		let body = "";
9358
9359		// Act
9360		let delimiter = generate_safe_dollar_quote_delimiter(body);
9361
9362		// Assert
9363		assert_eq!(delimiter, "$$");
9364	}
9365
9366	#[rstest]
9367	fn test_safe_delimiter_whitespace_only_body() {
9368		// Arrange
9369		let body = "   \t\n  ";
9370
9371		// Act
9372		let delimiter = generate_safe_dollar_quote_delimiter(body);
9373
9374		// Assert
9375		assert_eq!(delimiter, "$$");
9376	}
9377
9378	#[rstest]
9379	fn test_safe_delimiter_nested_dollar_quotes() {
9380		// Arrange: body contains nested dollar-quoted strings
9381		let body = "$inner$ SELECT 1 $inner$ $$ nested $$";
9382
9383		// Act
9384		let delimiter = generate_safe_dollar_quote_delimiter(body);
9385
9386		// Assert: must avoid both $$ and $inner$
9387		assert_ne!(delimiter, "$$");
9388		assert_ne!(delimiter, "$inner$");
9389		assert_eq!(delimiter, "$body_0$");
9390	}
9391
9392	#[rstest]
9393	fn test_safe_delimiter_tag_style_delimiters() {
9394		// Arrange: body contains $tag$ style delimiters
9395		let body = "$func$ BEGIN RETURN 1; END; $func$";
9396
9397		// Act
9398		let delimiter = generate_safe_dollar_quote_delimiter(body);
9399
9400		// Assert: $$ is safe because body only contains $func$
9401		assert_eq!(delimiter, "$$");
9402	}
9403
9404	// ==================== Dollar-quote delimiter collection tests ====================
9405
9406	#[rstest]
9407	fn test_collect_delimiters_empty_body() {
9408		// Arrange
9409		let body = "";
9410
9411		// Act
9412		let delimiters = collect_dollar_quote_delimiters(body);
9413
9414		// Assert
9415		assert!(delimiters.is_empty());
9416	}
9417
9418	#[rstest]
9419	fn test_collect_delimiters_no_dollar_signs() {
9420		// Arrange
9421		let body = "SELECT 1 + 2";
9422
9423		// Act
9424		let delimiters = collect_dollar_quote_delimiters(body);
9425
9426		// Assert
9427		assert!(delimiters.is_empty());
9428	}
9429
9430	#[rstest]
9431	fn test_collect_delimiters_dollar_amounts_are_not_delimiters() {
9432		// Arrange: $1, $2 are PostgreSQL parameter placeholders, not delimiters
9433		let body = "SELECT $1 + $2";
9434
9435		// Act
9436		let delimiters = collect_dollar_quote_delimiters(body);
9437
9438		// Assert
9439		assert!(delimiters.is_empty());
9440	}
9441
9442	#[rstest]
9443	fn test_collect_delimiters_finds_empty_tag() {
9444		// Arrange
9445		let body = "$$ body content $$";
9446
9447		// Act
9448		let delimiters = collect_dollar_quote_delimiters(body);
9449
9450		// Assert
9451		assert_eq!(delimiters.len(), 1);
9452		assert!(delimiters.contains("$$"));
9453	}
9454
9455	#[rstest]
9456	fn test_collect_delimiters_finds_named_tag() {
9457		// Arrange
9458		let body = "$func$ body $func$";
9459
9460		// Act
9461		let delimiters = collect_dollar_quote_delimiters(body);
9462
9463		// Assert
9464		assert_eq!(delimiters.len(), 1);
9465		assert!(delimiters.contains("$func$"));
9466	}
9467
9468	#[rstest]
9469	fn test_collect_delimiters_finds_multiple_tags() {
9470		// Arrange
9471		let body = "$$ outer $inner$ nested $inner$ outer $$";
9472
9473		// Act
9474		let delimiters = collect_dollar_quote_delimiters(body);
9475
9476		// Assert
9477		assert_eq!(delimiters.len(), 2);
9478		assert!(delimiters.contains("$$"));
9479		assert!(delimiters.contains("$inner$"));
9480	}
9481
9482	#[rstest]
9483	fn test_collect_delimiters_underscore_in_tag() {
9484		// Arrange
9485		let body = "$my_tag$ content $my_tag$";
9486
9487		// Act
9488		let delimiters = collect_dollar_quote_delimiters(body);
9489
9490		// Assert
9491		assert!(delimiters.contains("$my_tag$"));
9492	}
9493
9494	#[rstest]
9495	fn test_collect_delimiters_rejects_digit_start_tag() {
9496		// Arrange: $1tag$ is not valid because tag starts with digit
9497		let body = "$1tag$ content";
9498
9499		// Act
9500		let delimiters = collect_dollar_quote_delimiters(body);
9501
9502		// Assert: $1tag$ is not a valid delimiter
9503		assert!(!delimiters.contains("$1tag$"));
9504	}
9505}
9506
9507/// Collect all dollar-quote delimiters present in the body text.
9508///
9509/// A dollar-quote delimiter in PostgreSQL has the form `$tag$` where `tag` is
9510/// either empty or consists of `[a-zA-Z0-9_]` characters not starting with a
9511/// digit. This function scans the body and returns the set of all such
9512/// delimiters (including the surrounding `$` signs).
9513///
9514/// Using exact delimiter boundary detection instead of substring matching
9515/// prevents false positives (e.g. `$100` is not a delimiter) and false
9516/// negatives (e.g. partial overlap with candidate delimiter tags).
9517fn collect_dollar_quote_delimiters(body: &str) -> std::collections::HashSet<String> {
9518	let mut delimiters = std::collections::HashSet::new();
9519	let bytes = body.as_bytes();
9520	let len = bytes.len();
9521	let mut i = 0;
9522
9523	while i < len {
9524		if bytes[i] == b'$' {
9525			// Found a '$', try to parse a dollar-quote delimiter
9526			let start = i;
9527			i += 1;
9528
9529			// Empty tag: `$$`
9530			if i < len && bytes[i] == b'$' {
9531				delimiters.insert("$$".to_string());
9532				i += 1;
9533				continue;
9534			}
9535
9536			// Non-empty tag: tag must match [a-zA-Z_][a-zA-Z0-9_]*
9537			if i < len && (bytes[i].is_ascii_alphabetic() || bytes[i] == b'_') {
9538				let tag_start = i;
9539				i += 1;
9540				while i < len && (bytes[i].is_ascii_alphanumeric() || bytes[i] == b'_') {
9541					i += 1;
9542				}
9543				// Check for closing '$'
9544				if i < len && bytes[i] == b'$' {
9545					let delimiter = &body[start..=i];
9546					delimiters.insert(delimiter.to_string());
9547					i += 1;
9548					continue;
9549				}
9550				// Not a valid delimiter, continue from after the initial '$'
9551				i = tag_start;
9552				continue;
9553			}
9554
9555			// '$' followed by a digit or other non-tag character -- not a delimiter
9556			continue;
9557		}
9558		i += 1;
9559	}
9560
9561	delimiters
9562}
9563
9564/// Generate a safe dollar-quote delimiter that does not appear in the body.
9565///
9566/// PostgreSQL dollar-quoting uses `$$` as the default delimiter. If the function
9567/// body contains `$$`, an attacker could break out of the dollar-quoted string.
9568/// This function scans for all dollar-quote delimiter patterns in the body and
9569/// generates a unique delimiter that does not conflict with any of them.
9570fn generate_safe_dollar_quote_delimiter(body: &str) -> String {
9571	let existing = collect_dollar_quote_delimiters(body);
9572
9573	if !existing.contains("$$") {
9574		return "$$".to_string();
9575	}
9576
9577	// Try numbered delimiters: $body_0$, $body_1$, ...
9578	for i in 0u64.. {
9579		let candidate = format!("$body_{}$", i);
9580		if !existing.contains(&candidate) {
9581			return candidate;
9582		}
9583	}
9584
9585	// Unreachable in practice, but satisfy the compiler
9586	"$$".to_string()
9587}
9588
9589impl crate::query::QueryBuilderTrait for PostgresQueryBuilder {
9590	fn placeholder(&self) -> (&str, bool) {
9591		("$", true)
9592	}
9593
9594	fn quote_char(&self) -> char {
9595		'"'
9596	}
9597}