1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384
//! Feature map for SQL dialects.
//!
//! The general principle with is to strive to target only the generic (i.e. default) dialect.
//!
//! This means that we prioritize common dialects and old dialect versions, because such
//! implementations would also be supported by newer versions.
//!
//! Dialect-specifics should be added only if:
//! - the generic dialect is not supported (i.e. LIMIT is not supported in MS SQL),
//! - dialect-specific impl is more performant than generic impl.
//!
//! As a consequence, generated SQL may be verbose, since it will avoid newer or less adopted SQL
//! constructs. The upside is much less complex translator.
use core::fmt::Debug;
use serde::{Deserialize, Serialize};
use std::any::{Any, TypeId};
use strum::VariantNames;
/// SQL dialect.
///
/// This only changes the output for a relatively small subset of features.
///
/// If something does not work in a specific dialect, please raise in a
/// GitHub issue.
// Make sure to update Python bindings, JS bindings & docs in the book.
#[derive(
Debug,
PartialEq,
Eq,
Clone,
Copy,
Serialize,
Default,
Deserialize,
strum::Display,
strum::EnumIter,
strum::EnumMessage,
strum::EnumString,
strum::EnumVariantNames,
)]
#[strum(serialize_all = "lowercase")]
pub enum Dialect {
Ansi,
BigQuery,
ClickHouse,
DuckDb,
#[default]
Generic,
GlareDb,
MsSql,
MySql,
Postgres,
SQLite,
Snowflake,
}
// Is this the best approach for the Enum / Struct — basically that we have one
// Enum that gets its respective Struct, and then the Struct can also get its
// respective Enum?
impl Dialect {
pub(super) fn handler(&self) -> Box<dyn DialectHandler> {
match self {
Dialect::MsSql => Box::new(MsSqlDialect),
Dialect::MySql => Box::new(MySqlDialect),
Dialect::BigQuery => Box::new(BigQueryDialect),
Dialect::SQLite => Box::new(SQLiteDialect),
Dialect::ClickHouse => Box::new(ClickHouseDialect),
Dialect::Snowflake => Box::new(SnowflakeDialect),
Dialect::DuckDb => Box::new(DuckDbDialect),
Dialect::Postgres => Box::new(PostgresDialect),
Dialect::GlareDb => Box::new(GlareDbDialect),
Dialect::Ansi | Dialect::Generic => Box::new(GenericDialect),
}
}
pub fn support_level(&self) -> SupportLevel {
match self {
Dialect::DuckDb
| Dialect::SQLite
| Dialect::Postgres
| Dialect::MySql
| Dialect::Generic
| Dialect::ClickHouse => SupportLevel::Supported,
Dialect::MsSql
| Dialect::GlareDb
| Dialect::Ansi
| Dialect::BigQuery
| Dialect::Snowflake => SupportLevel::Unsupported,
}
}
#[deprecated(note = "Use `Dialect::VARIANTS` instead")]
pub fn names() -> &'static [&'static str] {
Dialect::VARIANTS
}
}
pub enum SupportLevel {
Supported,
Unsupported,
Nascent,
}
#[derive(Debug)]
pub struct GenericDialect;
#[derive(Debug)]
pub struct SQLiteDialect;
#[derive(Debug)]
pub struct MySqlDialect;
#[derive(Debug)]
pub struct MsSqlDialect;
#[derive(Debug)]
pub struct BigQueryDialect;
#[derive(Debug)]
pub struct ClickHouseDialect;
#[derive(Debug)]
pub struct SnowflakeDialect;
#[derive(Debug)]
pub struct DuckDbDialect;
#[derive(Debug)]
pub struct PostgresDialect;
#[derive(Debug)]
pub struct GlareDbDialect;
pub(super) enum ColumnExclude {
Exclude,
Except,
}
pub(super) trait DialectHandler: Any + Debug {
fn use_top(&self) -> bool {
false
}
fn ident_quote(&self) -> char {
'"'
}
fn column_exclude(&self) -> Option<ColumnExclude> {
None
}
/// Support for DISTINCT in set ops (UNION DISTINCT, INTERSECT DISTINCT)
/// When not supported we fallback to implicit DISTINCT.
fn set_ops_distinct(&self) -> bool {
true
}
/// Support or EXCEPT ALL.
/// When not supported, fallback to anti join.
fn except_all(&self) -> bool {
true
}
fn intersect_all(&self) -> bool {
self.except_all()
}
/// Support for CONCAT function.
/// When not supported we fallback to use `||` as concat operator.
fn has_concat_function(&self) -> bool {
true
}
/// Whether or not intervals such as `INTERVAL 1 HOUR` require quotes like
/// `INTERVAL '1' HOUR`
fn requires_quotes_intervals(&self) -> bool {
false
}
/// Support for GROUP BY *
fn stars_in_group(&self) -> bool {
true
}
fn supports_distinct_on(&self) -> bool {
false
}
}
impl dyn DialectHandler {
#[inline]
pub fn is<T: DialectHandler + 'static>(&self) -> bool {
TypeId::of::<T>() == self.type_id()
}
}
impl DialectHandler for GenericDialect {}
impl DialectHandler for PostgresDialect {
fn requires_quotes_intervals(&self) -> bool {
true
}
fn supports_distinct_on(&self) -> bool {
// https://www.postgresql.org/docs/current/sql-select.html
true
}
}
impl DialectHandler for GlareDbDialect {
fn requires_quotes_intervals(&self) -> bool {
true
}
}
impl DialectHandler for SQLiteDialect {
fn set_ops_distinct(&self) -> bool {
false
}
fn except_all(&self) -> bool {
false
}
fn has_concat_function(&self) -> bool {
false
}
fn stars_in_group(&self) -> bool {
false
}
}
impl DialectHandler for MsSqlDialect {
fn use_top(&self) -> bool {
true
}
// https://learn.microsoft.com/en-us/sql/t-sql/language-elements/set-operators-except-and-intersect-transact-sql?view=sql-server-ver16
fn except_all(&self) -> bool {
false
}
fn set_ops_distinct(&self) -> bool {
false
}
}
impl DialectHandler for MySqlDialect {
fn ident_quote(&self) -> char {
'`'
}
fn set_ops_distinct(&self) -> bool {
// https://dev.mysql.com/doc/refman/8.0/en/set-operations.html
true
}
}
impl DialectHandler for ClickHouseDialect {
fn ident_quote(&self) -> char {
'`'
}
fn supports_distinct_on(&self) -> bool {
// https://clickhouse.com/docs/en/sql-reference/statements/select/distinct
true
}
}
impl DialectHandler for BigQueryDialect {
fn ident_quote(&self) -> char {
'`'
}
fn column_exclude(&self) -> Option<ColumnExclude> {
// https://cloud.google.com/bigquery/docs/reference/standard-sql/query-syntax#select_except
Some(ColumnExclude::Except)
}
fn set_ops_distinct(&self) -> bool {
// https://cloud.google.com/bigquery/docs/reference/standard-sql/query-syntax#set_operators
true
}
}
impl DialectHandler for SnowflakeDialect {
fn column_exclude(&self) -> Option<ColumnExclude> {
// https://docs.snowflake.com/en/sql-reference/sql/select.html
Some(ColumnExclude::Exclude)
}
fn set_ops_distinct(&self) -> bool {
// https://docs.snowflake.com/en/sql-reference/operators-query.html
false
}
}
impl DialectHandler for DuckDbDialect {
fn column_exclude(&self) -> Option<ColumnExclude> {
// https://duckdb.org/2022/05/04/friendlier-sql.html#select--exclude
Some(ColumnExclude::Exclude)
}
fn except_all(&self) -> bool {
// https://duckdb.org/docs/sql/query_syntax/setops.html
false
}
fn supports_distinct_on(&self) -> bool {
// https://duckdb.org/docs/sql/query_syntax/select.html#distinct-on-clause
true
}
}
#[cfg(test)]
mod tests {
use super::Dialect;
use insta::assert_debug_snapshot;
use std::str::FromStr;
#[test]
fn test_dialect_from_str() {
assert_debug_snapshot!(Dialect::from_str("postgres"), @r###"
Ok(
Postgres,
)
"###);
assert_debug_snapshot!(Dialect::from_str("foo"), @r###"
Err(
VariantNotFound,
)
"###);
}
}
/*
## Set operations support matrix
Set-ops have quite different support in major SQL dialects. This is an attempt to document it.
| SQL construct | SQLite | BQ | Postgres | MySQL 8+ | DuckDB
|-------------------------------|---------|--------|----------|----------|--------
| UNION (implicit DISTINCT) | x | | x | x | x
| UNION DISTINCT | | x | x | x | x
| UNION ALL | x | x | x | x | x
| EXCEPT (implicit DISTINCT) | x | | x | x | x
| EXCEPT DISTINCT | | x | x | x | x
| EXCEPT ALL | | | x | x |
### UNION DISTINCT
For UNION, these are equivalent:
- a UNION DISTINCT b,
- DISTINCT (a UNION ALL b)
- DISTINCT (a UNION ALL (DISTINCT b))
- DISTINCT ((DISTINCT a) UNION ALL b)
- DISTINCT ((DISTINCT a) UNION ALL (DISTINCT b))
### EXCEPT DISTINCT
For EXCEPT it makes a difference when DISTINCT is applied. Below is a test query to validate
the behavior. When applied before EXCEPT, the output should be [3] and when applied after EXCEPT,
the output should be [2, 3].
```
SELECT * FROM (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 2 UNION ALL SELECT 3) t
EXCEPT
SELECT * FROM (SELECT 1 UNION ALL SELECT 2) t;
```
All dialects seem to be applying *before*, but none seem to document that.
### INTERSECT DISTINCT
For INTERSECT, it does not matter when DISTINCT is applied. BigQuery documentation does mention
it is applied *after*, which makes me think there is a difference I'm not seeing.
My reasoning is that:
- Distinct is equivalent to applying `group * (take 1)`.
- In effect, this is a restriction that "each group can have at most one value".
- If we apply DISTINCT to any input of INTERSECT ALL, this restriction on the input is retained
through the operation. That's because no group will not contain more values than it started with,
and no group that was present in both inputs, will be missing from the output.
- Thus, applying distinct after INTERSECT ALL is equivalent to applying it to any of the inputs.
*/