sqlglot.generator
1from __future__ import annotations 2 3import logging 4import typing as t 5 6from sqlglot import exp 7from sqlglot.errors import ErrorLevel, UnsupportedError, concat_messages 8from sqlglot.helper import apply_index_offset, csv, seq_get, should_identify 9from sqlglot.time import format_time 10from sqlglot.tokens import TokenType 11 12logger = logging.getLogger("sqlglot") 13 14 15class Generator: 16 """ 17 Generator interprets the given syntax tree and produces a SQL string as an output. 18 19 Args: 20 time_mapping (dict): the dictionary of custom time mappings in which the key 21 represents a python time format and the output the target time format 22 time_trie (trie): a trie of the time_mapping keys 23 pretty (bool): if set to True the returned string will be formatted. Default: False. 24 quote_start (str): specifies which starting character to use to delimit quotes. Default: '. 25 quote_end (str): specifies which ending character to use to delimit quotes. Default: '. 26 identifier_start (str): specifies which starting character to use to delimit identifiers. Default: ". 27 identifier_end (str): specifies which ending character to use to delimit identifiers. Default: ". 28 bit_start (str): specifies which starting character to use to delimit bit literals. Default: None. 29 bit_end (str): specifies which ending character to use to delimit bit literals. Default: None. 30 hex_start (str): specifies which starting character to use to delimit hex literals. Default: None. 31 hex_end (str): specifies which ending character to use to delimit hex literals. Default: None. 32 byte_start (str): specifies which starting character to use to delimit byte literals. Default: None. 33 byte_end (str): specifies which ending character to use to delimit byte literals. Default: None. 34 raw_start (str): specifies which starting character to use to delimit raw literals. Default: None. 35 raw_end (str): specifies which ending character to use to delimit raw literals. Default: None. 36 identify (bool | str): 'always': always quote, 'safe': quote identifiers if they don't contain an upcase, True defaults to always. 37 normalize (bool): if set to True all identifiers will lower cased 38 string_escape (str): specifies a string escape character. Default: '. 39 identifier_escape (str): specifies an identifier escape character. Default: ". 40 pad (int): determines padding in a formatted string. Default: 2. 41 indent (int): determines the size of indentation in a formatted string. Default: 4. 42 unnest_column_only (bool): if true unnest table aliases are considered only as column aliases 43 normalize_functions (str): normalize function names, "upper", "lower", or None 44 Default: "upper" 45 alias_post_tablesample (bool): if the table alias comes after tablesample 46 Default: False 47 unsupported_level (ErrorLevel): determines the generator's behavior when it encounters 48 unsupported expressions. Default ErrorLevel.WARN. 49 null_ordering (str): Indicates the default null ordering method to use if not explicitly set. 50 Options are "nulls_are_small", "nulls_are_large", "nulls_are_last". 51 Default: "nulls_are_small" 52 max_unsupported (int): Maximum number of unsupported messages to include in a raised UnsupportedError. 53 This is only relevant if unsupported_level is ErrorLevel.RAISE. 54 Default: 3 55 leading_comma (bool): if the the comma is leading or trailing in select statements 56 Default: False 57 max_text_width: The max number of characters in a segment before creating new lines in pretty mode. 58 The default is on the smaller end because the length only represents a segment and not the true 59 line length. 60 Default: 80 61 comments: Whether or not to preserve comments in the output SQL code. 62 Default: True 63 """ 64 65 TRANSFORMS = { 66 exp.DateAdd: lambda self, e: self.func( 67 "DATE_ADD", e.this, e.expression, exp.Literal.string(e.text("unit")) 68 ), 69 exp.TsOrDsAdd: lambda self, e: self.func( 70 "TS_OR_DS_ADD", e.this, e.expression, exp.Literal.string(e.text("unit")) 71 ), 72 exp.VarMap: lambda self, e: self.func("MAP", e.args["keys"], e.args["values"]), 73 exp.CharacterSetProperty: lambda self, e: f"{'DEFAULT ' if e.args.get('default') else ''}CHARACTER SET={self.sql(e, 'this')}", 74 exp.ExecuteAsProperty: lambda self, e: self.naked_property(e), 75 exp.ExternalProperty: lambda self, e: "EXTERNAL", 76 exp.LanguageProperty: lambda self, e: self.naked_property(e), 77 exp.LocationProperty: lambda self, e: self.naked_property(e), 78 exp.LogProperty: lambda self, e: f"{'NO ' if e.args.get('no') else ''}LOG", 79 exp.MaterializedProperty: lambda self, e: "MATERIALIZED", 80 exp.NoPrimaryIndexProperty: lambda self, e: "NO PRIMARY INDEX", 81 exp.OnCommitProperty: lambda self, e: f"ON COMMIT {'DELETE' if e.args.get('delete') else 'PRESERVE'} ROWS", 82 exp.ReturnsProperty: lambda self, e: self.naked_property(e), 83 exp.SetProperty: lambda self, e: f"{'MULTI' if e.args.get('multi') else ''}SET", 84 exp.SettingsProperty: lambda self, e: f"SETTINGS{self.seg('')}{(self.expressions(e))}", 85 exp.SqlSecurityProperty: lambda self, e: f"SQL SECURITY {'DEFINER' if e.args.get('definer') else 'INVOKER'}", 86 exp.TemporaryProperty: lambda self, e: f"TEMPORARY", 87 exp.TransientProperty: lambda self, e: "TRANSIENT", 88 exp.StabilityProperty: lambda self, e: e.name, 89 exp.VolatileProperty: lambda self, e: "VOLATILE", 90 exp.WithJournalTableProperty: lambda self, e: f"WITH JOURNAL TABLE={self.sql(e, 'this')}", 91 exp.CaseSpecificColumnConstraint: lambda self, e: f"{'NOT ' if e.args.get('not_') else ''}CASESPECIFIC", 92 exp.CharacterSetColumnConstraint: lambda self, e: f"CHARACTER SET {self.sql(e, 'this')}", 93 exp.DateFormatColumnConstraint: lambda self, e: f"FORMAT {self.sql(e, 'this')}", 94 exp.OnUpdateColumnConstraint: lambda self, e: f"ON UPDATE {self.sql(e, 'this')}", 95 exp.UppercaseColumnConstraint: lambda self, e: f"UPPERCASE", 96 exp.TitleColumnConstraint: lambda self, e: f"TITLE {self.sql(e, 'this')}", 97 exp.PathColumnConstraint: lambda self, e: f"PATH {self.sql(e, 'this')}", 98 exp.CheckColumnConstraint: lambda self, e: f"CHECK ({self.sql(e, 'this')})", 99 exp.CommentColumnConstraint: lambda self, e: f"COMMENT {self.sql(e, 'this')}", 100 exp.CollateColumnConstraint: lambda self, e: f"COLLATE {self.sql(e, 'this')}", 101 exp.EncodeColumnConstraint: lambda self, e: f"ENCODE {self.sql(e, 'this')}", 102 exp.DefaultColumnConstraint: lambda self, e: f"DEFAULT {self.sql(e, 'this')}", 103 exp.InlineLengthColumnConstraint: lambda self, e: f"INLINE LENGTH {self.sql(e, 'this')}", 104 } 105 106 # Whether or not null ordering is supported in order by 107 NULL_ORDERING_SUPPORTED = True 108 109 # Whether or not locking reads (i.e. SELECT ... FOR UPDATE/SHARE) are supported 110 LOCKING_READS_SUPPORTED = False 111 112 # Always do union distinct or union all 113 EXPLICIT_UNION = False 114 115 # Wrap derived values in parens, usually standard but spark doesn't support it 116 WRAP_DERIVED_VALUES = True 117 118 # Whether or not create function uses an AS before the RETURN 119 CREATE_FUNCTION_RETURN_AS = True 120 121 # Whether or not MERGE ... WHEN MATCHED BY SOURCE is allowed 122 MATCHED_BY_SOURCE = True 123 124 # Whether or not the INTERVAL expression works only with values like '1 day' 125 SINGLE_STRING_INTERVAL = False 126 127 # Whether or not the plural form of date parts like day (i.e. "days") is supported in INTERVALs 128 INTERVAL_ALLOWS_PLURAL_FORM = True 129 130 # Whether or not the TABLESAMPLE clause supports a method name, like BERNOULLI 131 TABLESAMPLE_WITH_METHOD = True 132 133 # Whether or not to treat the number in TABLESAMPLE (50) as a percentage 134 TABLESAMPLE_SIZE_IS_PERCENT = False 135 136 # Whether or not limit and fetch are supported (possible values: "ALL", "LIMIT", "FETCH") 137 LIMIT_FETCH = "ALL" 138 139 # Whether a table is allowed to be renamed with a db 140 RENAME_TABLE_WITH_DB = True 141 142 # The separator for grouping sets and rollups 143 GROUPINGS_SEP = "," 144 145 # The string used for creating index on a table 146 INDEX_ON = "ON" 147 148 TYPE_MAPPING = { 149 exp.DataType.Type.NCHAR: "CHAR", 150 exp.DataType.Type.NVARCHAR: "VARCHAR", 151 exp.DataType.Type.MEDIUMTEXT: "TEXT", 152 exp.DataType.Type.LONGTEXT: "TEXT", 153 exp.DataType.Type.MEDIUMBLOB: "BLOB", 154 exp.DataType.Type.LONGBLOB: "BLOB", 155 exp.DataType.Type.INET: "INET", 156 } 157 158 STAR_MAPPING = { 159 "except": "EXCEPT", 160 "replace": "REPLACE", 161 } 162 163 TIME_PART_SINGULARS = { 164 "microseconds": "microsecond", 165 "seconds": "second", 166 "minutes": "minute", 167 "hours": "hour", 168 "days": "day", 169 "weeks": "week", 170 "months": "month", 171 "quarters": "quarter", 172 "years": "year", 173 } 174 175 TOKEN_MAPPING: t.Dict[TokenType, str] = {} 176 177 STRUCT_DELIMITER = ("<", ">") 178 179 PARAMETER_TOKEN = "@" 180 181 PROPERTIES_LOCATION = { 182 exp.AlgorithmProperty: exp.Properties.Location.POST_CREATE, 183 exp.AutoIncrementProperty: exp.Properties.Location.POST_SCHEMA, 184 exp.BlockCompressionProperty: exp.Properties.Location.POST_NAME, 185 exp.CharacterSetProperty: exp.Properties.Location.POST_SCHEMA, 186 exp.ChecksumProperty: exp.Properties.Location.POST_NAME, 187 exp.CollateProperty: exp.Properties.Location.POST_SCHEMA, 188 exp.Cluster: exp.Properties.Location.POST_SCHEMA, 189 exp.DataBlocksizeProperty: exp.Properties.Location.POST_NAME, 190 exp.DefinerProperty: exp.Properties.Location.POST_CREATE, 191 exp.DistKeyProperty: exp.Properties.Location.POST_SCHEMA, 192 exp.DistStyleProperty: exp.Properties.Location.POST_SCHEMA, 193 exp.EngineProperty: exp.Properties.Location.POST_SCHEMA, 194 exp.ExecuteAsProperty: exp.Properties.Location.POST_SCHEMA, 195 exp.ExternalProperty: exp.Properties.Location.POST_CREATE, 196 exp.FallbackProperty: exp.Properties.Location.POST_NAME, 197 exp.FileFormatProperty: exp.Properties.Location.POST_WITH, 198 exp.FreespaceProperty: exp.Properties.Location.POST_NAME, 199 exp.IsolatedLoadingProperty: exp.Properties.Location.POST_NAME, 200 exp.JournalProperty: exp.Properties.Location.POST_NAME, 201 exp.LanguageProperty: exp.Properties.Location.POST_SCHEMA, 202 exp.LikeProperty: exp.Properties.Location.POST_SCHEMA, 203 exp.LocationProperty: exp.Properties.Location.POST_SCHEMA, 204 exp.LockingProperty: exp.Properties.Location.POST_ALIAS, 205 exp.LogProperty: exp.Properties.Location.POST_NAME, 206 exp.MaterializedProperty: exp.Properties.Location.POST_CREATE, 207 exp.MergeBlockRatioProperty: exp.Properties.Location.POST_NAME, 208 exp.NoPrimaryIndexProperty: exp.Properties.Location.POST_EXPRESSION, 209 exp.OnCommitProperty: exp.Properties.Location.POST_EXPRESSION, 210 exp.Order: exp.Properties.Location.POST_SCHEMA, 211 exp.PartitionedByProperty: exp.Properties.Location.POST_WITH, 212 exp.PrimaryKey: exp.Properties.Location.POST_SCHEMA, 213 exp.Property: exp.Properties.Location.POST_WITH, 214 exp.ReturnsProperty: exp.Properties.Location.POST_SCHEMA, 215 exp.RowFormatProperty: exp.Properties.Location.POST_SCHEMA, 216 exp.RowFormatDelimitedProperty: exp.Properties.Location.POST_SCHEMA, 217 exp.RowFormatSerdeProperty: exp.Properties.Location.POST_SCHEMA, 218 exp.SchemaCommentProperty: exp.Properties.Location.POST_SCHEMA, 219 exp.SerdeProperties: exp.Properties.Location.POST_SCHEMA, 220 exp.Set: exp.Properties.Location.POST_SCHEMA, 221 exp.SettingsProperty: exp.Properties.Location.POST_SCHEMA, 222 exp.SetProperty: exp.Properties.Location.POST_CREATE, 223 exp.SortKeyProperty: exp.Properties.Location.POST_SCHEMA, 224 exp.SqlSecurityProperty: exp.Properties.Location.POST_CREATE, 225 exp.StabilityProperty: exp.Properties.Location.POST_SCHEMA, 226 exp.TemporaryProperty: exp.Properties.Location.POST_CREATE, 227 exp.TransientProperty: exp.Properties.Location.POST_CREATE, 228 exp.MergeTreeTTL: exp.Properties.Location.POST_SCHEMA, 229 exp.VolatileProperty: exp.Properties.Location.POST_CREATE, 230 exp.WithDataProperty: exp.Properties.Location.POST_EXPRESSION, 231 exp.WithJournalTableProperty: exp.Properties.Location.POST_NAME, 232 } 233 234 JOIN_HINTS = True 235 TABLE_HINTS = True 236 237 RESERVED_KEYWORDS: t.Set[str] = set() 238 WITH_SEPARATED_COMMENTS = (exp.Select, exp.From, exp.Where, exp.With) 239 UNWRAPPED_INTERVAL_VALUES = (exp.Column, exp.Literal, exp.Neg, exp.Paren) 240 241 SENTINEL_LINE_BREAK = "__SQLGLOT__LB__" 242 243 __slots__ = ( 244 "time_mapping", 245 "time_trie", 246 "pretty", 247 "quote_start", 248 "quote_end", 249 "identifier_start", 250 "identifier_end", 251 "bit_start", 252 "bit_end", 253 "hex_start", 254 "hex_end", 255 "byte_start", 256 "byte_end", 257 "raw_start", 258 "raw_end", 259 "identify", 260 "normalize", 261 "string_escape", 262 "identifier_escape", 263 "pad", 264 "index_offset", 265 "unnest_column_only", 266 "alias_post_tablesample", 267 "normalize_functions", 268 "unsupported_level", 269 "unsupported_messages", 270 "null_ordering", 271 "max_unsupported", 272 "_indent", 273 "_escaped_quote_end", 274 "_escaped_identifier_end", 275 "_leading_comma", 276 "_max_text_width", 277 "_comments", 278 "_cache", 279 ) 280 281 def __init__( 282 self, 283 time_mapping=None, 284 time_trie=None, 285 pretty=None, 286 quote_start=None, 287 quote_end=None, 288 identifier_start=None, 289 identifier_end=None, 290 bit_start=None, 291 bit_end=None, 292 hex_start=None, 293 hex_end=None, 294 byte_start=None, 295 byte_end=None, 296 raw_start=None, 297 raw_end=None, 298 identify=False, 299 normalize=False, 300 string_escape=None, 301 identifier_escape=None, 302 pad=2, 303 indent=2, 304 index_offset=0, 305 unnest_column_only=False, 306 alias_post_tablesample=False, 307 normalize_functions="upper", 308 unsupported_level=ErrorLevel.WARN, 309 null_ordering=None, 310 max_unsupported=3, 311 leading_comma=False, 312 max_text_width=80, 313 comments=True, 314 ): 315 import sqlglot 316 317 self.time_mapping = time_mapping or {} 318 self.time_trie = time_trie 319 self.pretty = pretty if pretty is not None else sqlglot.pretty 320 self.quote_start = quote_start or "'" 321 self.quote_end = quote_end or "'" 322 self.identifier_start = identifier_start or '"' 323 self.identifier_end = identifier_end or '"' 324 self.bit_start = bit_start 325 self.bit_end = bit_end 326 self.hex_start = hex_start 327 self.hex_end = hex_end 328 self.byte_start = byte_start 329 self.byte_end = byte_end 330 self.raw_start = raw_start 331 self.raw_end = raw_end 332 self.identify = identify 333 self.normalize = normalize 334 self.string_escape = string_escape or "'" 335 self.identifier_escape = identifier_escape or '"' 336 self.pad = pad 337 self.index_offset = index_offset 338 self.unnest_column_only = unnest_column_only 339 self.alias_post_tablesample = alias_post_tablesample 340 self.normalize_functions = normalize_functions 341 self.unsupported_level = unsupported_level 342 self.unsupported_messages = [] 343 self.max_unsupported = max_unsupported 344 self.null_ordering = null_ordering 345 self._indent = indent 346 self._escaped_quote_end = self.string_escape + self.quote_end 347 self._escaped_identifier_end = self.identifier_escape + self.identifier_end 348 self._leading_comma = leading_comma 349 self._max_text_width = max_text_width 350 self._comments = comments 351 self._cache = None 352 353 def generate( 354 self, 355 expression: t.Optional[exp.Expression], 356 cache: t.Optional[t.Dict[int, str]] = None, 357 ) -> str: 358 """ 359 Generates a SQL string by interpreting the given syntax tree. 360 361 Args 362 expression: the syntax tree. 363 cache: an optional sql string cache. this leverages the hash of an expression which is slow, so only use this if you set _hash on each node. 364 365 Returns 366 the SQL string. 367 """ 368 if cache is not None: 369 self._cache = cache 370 self.unsupported_messages = [] 371 sql = self.sql(expression).strip() 372 self._cache = None 373 374 if self.unsupported_level == ErrorLevel.IGNORE: 375 return sql 376 377 if self.unsupported_level == ErrorLevel.WARN: 378 for msg in self.unsupported_messages: 379 logger.warning(msg) 380 elif self.unsupported_level == ErrorLevel.RAISE and self.unsupported_messages: 381 raise UnsupportedError(concat_messages(self.unsupported_messages, self.max_unsupported)) 382 383 if self.pretty: 384 sql = sql.replace(self.SENTINEL_LINE_BREAK, "\n") 385 return sql 386 387 def unsupported(self, message: str) -> None: 388 if self.unsupported_level == ErrorLevel.IMMEDIATE: 389 raise UnsupportedError(message) 390 self.unsupported_messages.append(message) 391 392 def sep(self, sep: str = " ") -> str: 393 return f"{sep.strip()}\n" if self.pretty else sep 394 395 def seg(self, sql: str, sep: str = " ") -> str: 396 return f"{self.sep(sep)}{sql}" 397 398 def pad_comment(self, comment: str) -> str: 399 comment = " " + comment if comment[0].strip() else comment 400 comment = comment + " " if comment[-1].strip() else comment 401 return comment 402 403 def maybe_comment( 404 self, 405 sql: str, 406 expression: t.Optional[exp.Expression] = None, 407 comments: t.Optional[t.List[str]] = None, 408 ) -> str: 409 comments = ((expression and expression.comments) if comments is None else comments) if self._comments else None # type: ignore 410 411 if not comments or isinstance(expression, exp.Binary): 412 return sql 413 414 sep = "\n" if self.pretty else " " 415 comments_sql = sep.join( 416 f"/*{self.pad_comment(comment)}*/" for comment in comments if comment 417 ) 418 419 if not comments_sql: 420 return sql 421 422 if isinstance(expression, self.WITH_SEPARATED_COMMENTS): 423 return ( 424 f"{self.sep()}{comments_sql}{sql}" 425 if sql[0].isspace() 426 else f"{comments_sql}{self.sep()}{sql}" 427 ) 428 429 return f"{sql} {comments_sql}" 430 431 def wrap(self, expression: exp.Expression | str) -> str: 432 this_sql = self.indent( 433 self.sql(expression) 434 if isinstance(expression, (exp.Select, exp.Union)) 435 else self.sql(expression, "this"), 436 level=1, 437 pad=0, 438 ) 439 return f"({self.sep('')}{this_sql}{self.seg(')', sep='')}" 440 441 def no_identify(self, func: t.Callable[..., str], *args, **kwargs) -> str: 442 original = self.identify 443 self.identify = False 444 result = func(*args, **kwargs) 445 self.identify = original 446 return result 447 448 def normalize_func(self, name: str) -> str: 449 if self.normalize_functions == "upper": 450 return name.upper() 451 if self.normalize_functions == "lower": 452 return name.lower() 453 return name 454 455 def indent( 456 self, 457 sql: str, 458 level: int = 0, 459 pad: t.Optional[int] = None, 460 skip_first: bool = False, 461 skip_last: bool = False, 462 ) -> str: 463 if not self.pretty: 464 return sql 465 466 pad = self.pad if pad is None else pad 467 lines = sql.split("\n") 468 469 return "\n".join( 470 line 471 if (skip_first and i == 0) or (skip_last and i == len(lines) - 1) 472 else f"{' ' * (level * self._indent + pad)}{line}" 473 for i, line in enumerate(lines) 474 ) 475 476 def sql( 477 self, 478 expression: t.Optional[str | exp.Expression], 479 key: t.Optional[str] = None, 480 comment: bool = True, 481 ) -> str: 482 if not expression: 483 return "" 484 485 if isinstance(expression, str): 486 return expression 487 488 if key: 489 return self.sql(expression.args.get(key)) 490 491 if self._cache is not None: 492 expression_id = hash(expression) 493 494 if expression_id in self._cache: 495 return self._cache[expression_id] 496 497 transform = self.TRANSFORMS.get(expression.__class__) 498 499 if callable(transform): 500 sql = transform(self, expression) 501 elif transform: 502 sql = transform 503 elif isinstance(expression, exp.Expression): 504 exp_handler_name = f"{expression.key}_sql" 505 506 if hasattr(self, exp_handler_name): 507 sql = getattr(self, exp_handler_name)(expression) 508 elif isinstance(expression, exp.Func): 509 sql = self.function_fallback_sql(expression) 510 elif isinstance(expression, exp.Property): 511 sql = self.property_sql(expression) 512 else: 513 raise ValueError(f"Unsupported expression type {expression.__class__.__name__}") 514 else: 515 raise ValueError(f"Expected an Expression. Received {type(expression)}: {expression}") 516 517 sql = self.maybe_comment(sql, expression) if self._comments and comment else sql 518 519 if self._cache is not None: 520 self._cache[expression_id] = sql 521 return sql 522 523 def uncache_sql(self, expression: exp.Uncache) -> str: 524 table = self.sql(expression, "this") 525 exists_sql = " IF EXISTS" if expression.args.get("exists") else "" 526 return f"UNCACHE TABLE{exists_sql} {table}" 527 528 def cache_sql(self, expression: exp.Cache) -> str: 529 lazy = " LAZY" if expression.args.get("lazy") else "" 530 table = self.sql(expression, "this") 531 options = expression.args.get("options") 532 options = f" OPTIONS({self.sql(options[0])} = {self.sql(options[1])})" if options else "" 533 sql = self.sql(expression, "expression") 534 sql = f" AS{self.sep()}{sql}" if sql else "" 535 sql = f"CACHE{lazy} TABLE {table}{options}{sql}" 536 return self.prepend_ctes(expression, sql) 537 538 def characterset_sql(self, expression: exp.CharacterSet) -> str: 539 if isinstance(expression.parent, exp.Cast): 540 return f"CHAR CHARACTER SET {self.sql(expression, 'this')}" 541 default = "DEFAULT " if expression.args.get("default") else "" 542 return f"{default}CHARACTER SET={self.sql(expression, 'this')}" 543 544 def column_sql(self, expression: exp.Column) -> str: 545 return ".".join( 546 self.sql(part) 547 for part in ( 548 expression.args.get("catalog"), 549 expression.args.get("db"), 550 expression.args.get("table"), 551 expression.args.get("this"), 552 ) 553 if part 554 ) 555 556 def columnposition_sql(self, expression: exp.ColumnPosition) -> str: 557 this = self.sql(expression, "this") 558 this = f" {this}" if this else "" 559 position = self.sql(expression, "position") 560 return f"{position}{this}" 561 562 def columndef_sql(self, expression: exp.ColumnDef, sep: str = " ") -> str: 563 column = self.sql(expression, "this") 564 kind = self.sql(expression, "kind") 565 constraints = self.expressions(expression, key="constraints", sep=" ", flat=True) 566 exists = "IF NOT EXISTS " if expression.args.get("exists") else "" 567 kind = f"{sep}{kind}" if kind else "" 568 constraints = f" {constraints}" if constraints else "" 569 position = self.sql(expression, "position") 570 position = f" {position}" if position else "" 571 572 return f"{exists}{column}{kind}{constraints}{position}" 573 574 def columnconstraint_sql(self, expression: exp.ColumnConstraint) -> str: 575 this = self.sql(expression, "this") 576 kind_sql = self.sql(expression, "kind").strip() 577 return f"CONSTRAINT {this} {kind_sql}" if this else kind_sql 578 579 def autoincrementcolumnconstraint_sql(self, _) -> str: 580 return self.token_sql(TokenType.AUTO_INCREMENT) 581 582 def compresscolumnconstraint_sql(self, expression: exp.CompressColumnConstraint) -> str: 583 if isinstance(expression.this, list): 584 this = self.wrap(self.expressions(expression, key="this", flat=True)) 585 else: 586 this = self.sql(expression, "this") 587 588 return f"COMPRESS {this}" 589 590 def generatedasidentitycolumnconstraint_sql( 591 self, expression: exp.GeneratedAsIdentityColumnConstraint 592 ) -> str: 593 this = "" 594 if expression.this is not None: 595 on_null = "ON NULL " if expression.args.get("on_null") else "" 596 this = " ALWAYS " if expression.this else f" BY DEFAULT {on_null}" 597 598 start = expression.args.get("start") 599 start = f"START WITH {start}" if start else "" 600 increment = expression.args.get("increment") 601 increment = f" INCREMENT BY {increment}" if increment else "" 602 minvalue = expression.args.get("minvalue") 603 minvalue = f" MINVALUE {minvalue}" if minvalue else "" 604 maxvalue = expression.args.get("maxvalue") 605 maxvalue = f" MAXVALUE {maxvalue}" if maxvalue else "" 606 cycle = expression.args.get("cycle") 607 cycle_sql = "" 608 609 if cycle is not None: 610 cycle_sql = f"{' NO' if not cycle else ''} CYCLE" 611 cycle_sql = cycle_sql.strip() if not start and not increment else cycle_sql 612 613 sequence_opts = "" 614 if start or increment or cycle_sql: 615 sequence_opts = f"{start}{increment}{minvalue}{maxvalue}{cycle_sql}" 616 sequence_opts = f" ({sequence_opts.strip()})" 617 618 expr = self.sql(expression, "expression") 619 expr = f"({expr})" if expr else "IDENTITY" 620 621 return f"GENERATED{this}AS {expr}{sequence_opts}" 622 623 def notnullcolumnconstraint_sql(self, expression: exp.NotNullColumnConstraint) -> str: 624 return f"{'' if expression.args.get('allow_null') else 'NOT '}NULL" 625 626 def primarykeycolumnconstraint_sql(self, expression: exp.PrimaryKeyColumnConstraint) -> str: 627 desc = expression.args.get("desc") 628 if desc is not None: 629 return f"PRIMARY KEY{' DESC' if desc else ' ASC'}" 630 return f"PRIMARY KEY" 631 632 def uniquecolumnconstraint_sql(self, expression: exp.UniqueColumnConstraint) -> str: 633 this = self.sql(expression, "this") 634 this = f" {this}" if this else "" 635 return f"UNIQUE{this}" 636 637 def create_sql(self, expression: exp.Create) -> str: 638 kind = self.sql(expression, "kind").upper() 639 properties = expression.args.get("properties") 640 properties_exp = expression.copy() 641 properties_locs = self.locate_properties(properties) if properties else {} 642 if properties_locs.get(exp.Properties.Location.POST_SCHEMA) or properties_locs.get( 643 exp.Properties.Location.POST_WITH 644 ): 645 properties_exp.set( 646 "properties", 647 exp.Properties( 648 expressions=[ 649 *properties_locs[exp.Properties.Location.POST_SCHEMA], 650 *properties_locs[exp.Properties.Location.POST_WITH], 651 ] 652 ), 653 ) 654 if kind == "TABLE" and properties_locs.get(exp.Properties.Location.POST_NAME): 655 this_name = self.sql(expression.this, "this") 656 this_properties = self.properties( 657 exp.Properties(expressions=properties_locs[exp.Properties.Location.POST_NAME]), 658 wrapped=False, 659 ) 660 this_schema = f"({self.expressions(expression.this)})" 661 this = f"{this_name}, {this_properties} {this_schema}" 662 properties_sql = "" 663 else: 664 this = self.sql(expression, "this") 665 properties_sql = self.sql(properties_exp, "properties") 666 begin = " BEGIN" if expression.args.get("begin") else "" 667 expression_sql = self.sql(expression, "expression") 668 if expression_sql: 669 expression_sql = f"{begin}{self.sep()}{expression_sql}" 670 671 if self.CREATE_FUNCTION_RETURN_AS or not isinstance(expression.expression, exp.Return): 672 if properties_locs.get(exp.Properties.Location.POST_ALIAS): 673 postalias_props_sql = self.properties( 674 exp.Properties( 675 expressions=properties_locs[exp.Properties.Location.POST_ALIAS] 676 ), 677 wrapped=False, 678 ) 679 expression_sql = f" AS {postalias_props_sql}{expression_sql}" 680 else: 681 expression_sql = f" AS{expression_sql}" 682 683 postindex_props_sql = "" 684 if properties_locs.get(exp.Properties.Location.POST_INDEX): 685 postindex_props_sql = self.properties( 686 exp.Properties(expressions=properties_locs[exp.Properties.Location.POST_INDEX]), 687 wrapped=False, 688 prefix=" ", 689 ) 690 691 indexes = self.expressions(expression, key="indexes", indent=False, sep=" ") 692 indexes = f" {indexes}" if indexes else "" 693 index_sql = indexes + postindex_props_sql 694 695 replace = " OR REPLACE" if expression.args.get("replace") else "" 696 unique = " UNIQUE" if expression.args.get("unique") else "" 697 698 postcreate_props_sql = "" 699 if properties_locs.get(exp.Properties.Location.POST_CREATE): 700 postcreate_props_sql = self.properties( 701 exp.Properties(expressions=properties_locs[exp.Properties.Location.POST_CREATE]), 702 sep=" ", 703 prefix=" ", 704 wrapped=False, 705 ) 706 707 modifiers = "".join((replace, unique, postcreate_props_sql)) 708 709 postexpression_props_sql = "" 710 if properties_locs.get(exp.Properties.Location.POST_EXPRESSION): 711 postexpression_props_sql = self.properties( 712 exp.Properties( 713 expressions=properties_locs[exp.Properties.Location.POST_EXPRESSION] 714 ), 715 sep=" ", 716 prefix=" ", 717 wrapped=False, 718 ) 719 720 exists_sql = " IF NOT EXISTS" if expression.args.get("exists") else "" 721 no_schema_binding = ( 722 " WITH NO SCHEMA BINDING" if expression.args.get("no_schema_binding") else "" 723 ) 724 725 clone = self.sql(expression, "clone") 726 clone = f" {clone}" if clone else "" 727 728 expression_sql = f"CREATE{modifiers} {kind}{exists_sql} {this}{properties_sql}{expression_sql}{postexpression_props_sql}{index_sql}{no_schema_binding}{clone}" 729 return self.prepend_ctes(expression, expression_sql) 730 731 def clone_sql(self, expression: exp.Clone) -> str: 732 this = self.sql(expression, "this") 733 when = self.sql(expression, "when") 734 735 if when: 736 kind = self.sql(expression, "kind") 737 expr = self.sql(expression, "expression") 738 return f"CLONE {this} {when} ({kind} => {expr})" 739 740 return f"CLONE {this}" 741 742 def describe_sql(self, expression: exp.Describe) -> str: 743 return f"DESCRIBE {self.sql(expression, 'this')}" 744 745 def prepend_ctes(self, expression: exp.Expression, sql: str) -> str: 746 with_ = self.sql(expression, "with") 747 if with_: 748 sql = f"{with_}{self.sep()}{sql}" 749 return sql 750 751 def with_sql(self, expression: exp.With) -> str: 752 sql = self.expressions(expression, flat=True) 753 recursive = "RECURSIVE " if expression.args.get("recursive") else "" 754 755 return f"WITH {recursive}{sql}" 756 757 def cte_sql(self, expression: exp.CTE) -> str: 758 alias = self.sql(expression, "alias") 759 return f"{alias} AS {self.wrap(expression)}" 760 761 def tablealias_sql(self, expression: exp.TableAlias) -> str: 762 alias = self.sql(expression, "this") 763 columns = self.expressions(expression, key="columns", flat=True) 764 columns = f"({columns})" if columns else "" 765 return f"{alias}{columns}" 766 767 def bitstring_sql(self, expression: exp.BitString) -> str: 768 this = self.sql(expression, "this") 769 if self.bit_start: 770 return f"{self.bit_start}{this}{self.bit_end}" 771 return f"{int(this, 2)}" 772 773 def hexstring_sql(self, expression: exp.HexString) -> str: 774 this = self.sql(expression, "this") 775 if self.hex_start: 776 return f"{self.hex_start}{this}{self.hex_end}" 777 return f"{int(this, 16)}" 778 779 def bytestring_sql(self, expression: exp.ByteString) -> str: 780 this = self.sql(expression, "this") 781 if self.byte_start: 782 return f"{self.byte_start}{this}{self.byte_end}" 783 return this 784 785 def rawstring_sql(self, expression: exp.RawString) -> str: 786 if self.raw_start: 787 return f"{self.raw_start}{expression.name}{self.raw_end}" 788 return self.sql(exp.Literal.string(expression.name.replace("\\", "\\\\"))) 789 790 def datatypesize_sql(self, expression: exp.DataTypeSize) -> str: 791 this = self.sql(expression, "this") 792 specifier = self.sql(expression, "expression") 793 specifier = f" {specifier}" if specifier else "" 794 return f"{this}{specifier}" 795 796 def datatype_sql(self, expression: exp.DataType) -> str: 797 type_value = expression.this 798 type_sql = self.TYPE_MAPPING.get(type_value, type_value.value) 799 nested = "" 800 interior = self.expressions(expression, flat=True) 801 values = "" 802 if interior: 803 if expression.args.get("nested"): 804 nested = f"{self.STRUCT_DELIMITER[0]}{interior}{self.STRUCT_DELIMITER[1]}" 805 if expression.args.get("values") is not None: 806 delimiters = ("[", "]") if type_value == exp.DataType.Type.ARRAY else ("(", ")") 807 values = self.expressions(expression, key="values", flat=True) 808 values = f"{delimiters[0]}{values}{delimiters[1]}" 809 else: 810 nested = f"({interior})" 811 812 return f"{type_sql}{nested}{values}" 813 814 def directory_sql(self, expression: exp.Directory) -> str: 815 local = "LOCAL " if expression.args.get("local") else "" 816 row_format = self.sql(expression, "row_format") 817 row_format = f" {row_format}" if row_format else "" 818 return f"{local}DIRECTORY {self.sql(expression, 'this')}{row_format}" 819 820 def delete_sql(self, expression: exp.Delete) -> str: 821 this = self.sql(expression, "this") 822 this = f" FROM {this}" if this else "" 823 using_sql = ( 824 f" USING {self.expressions(expression, key='using', sep=', USING ')}" 825 if expression.args.get("using") 826 else "" 827 ) 828 where_sql = self.sql(expression, "where") 829 returning = self.sql(expression, "returning") 830 sql = f"DELETE{this}{using_sql}{where_sql}{returning}" 831 return self.prepend_ctes(expression, sql) 832 833 def drop_sql(self, expression: exp.Drop) -> str: 834 this = self.sql(expression, "this") 835 kind = expression.args["kind"] 836 exists_sql = " IF EXISTS " if expression.args.get("exists") else " " 837 temporary = " TEMPORARY" if expression.args.get("temporary") else "" 838 materialized = " MATERIALIZED" if expression.args.get("materialized") else "" 839 cascade = " CASCADE" if expression.args.get("cascade") else "" 840 constraints = " CONSTRAINTS" if expression.args.get("constraints") else "" 841 purge = " PURGE" if expression.args.get("purge") else "" 842 return ( 843 f"DROP{temporary}{materialized} {kind}{exists_sql}{this}{cascade}{constraints}{purge}" 844 ) 845 846 def except_sql(self, expression: exp.Except) -> str: 847 return self.prepend_ctes( 848 expression, 849 self.set_operation(expression, self.except_op(expression)), 850 ) 851 852 def except_op(self, expression: exp.Except) -> str: 853 return f"EXCEPT{'' if expression.args.get('distinct') else ' ALL'}" 854 855 def fetch_sql(self, expression: exp.Fetch) -> str: 856 direction = expression.args.get("direction") 857 direction = f" {direction.upper()}" if direction else "" 858 count = expression.args.get("count") 859 count = f" {count}" if count else "" 860 if expression.args.get("percent"): 861 count = f"{count} PERCENT" 862 with_ties_or_only = "WITH TIES" if expression.args.get("with_ties") else "ONLY" 863 return f"{self.seg('FETCH')}{direction}{count} ROWS {with_ties_or_only}" 864 865 def filter_sql(self, expression: exp.Filter) -> str: 866 this = self.sql(expression, "this") 867 where = self.sql(expression, "expression")[1:] # where has a leading space 868 return f"{this} FILTER({where})" 869 870 def hint_sql(self, expression: exp.Hint) -> str: 871 if self.sql(expression, "this"): 872 self.unsupported("Hints are not supported") 873 return "" 874 875 def index_sql(self, expression: exp.Index) -> str: 876 unique = "UNIQUE " if expression.args.get("unique") else "" 877 primary = "PRIMARY " if expression.args.get("primary") else "" 878 amp = "AMP " if expression.args.get("amp") else "" 879 name = f"{expression.name} " if expression.name else "" 880 table = self.sql(expression, "table") 881 table = f"{self.INDEX_ON} {table} " if table else "" 882 index = "INDEX " if not table else "" 883 columns = self.expressions(expression, key="columns", flat=True) 884 partition_by = self.expressions(expression, key="partition_by", flat=True) 885 partition_by = f" PARTITION BY {partition_by}" if partition_by else "" 886 return f"{unique}{primary}{amp}{index}{name}{table}({columns}){partition_by}" 887 888 def identifier_sql(self, expression: exp.Identifier) -> str: 889 text = expression.name 890 lower = text.lower() 891 text = lower if self.normalize and not expression.quoted else text 892 text = text.replace(self.identifier_end, self._escaped_identifier_end) 893 if ( 894 expression.quoted 895 or should_identify(text, self.identify) 896 or lower in self.RESERVED_KEYWORDS 897 ): 898 text = f"{self.identifier_start}{text}{self.identifier_end}" 899 return text 900 901 def inputoutputformat_sql(self, expression: exp.InputOutputFormat) -> str: 902 input_format = self.sql(expression, "input_format") 903 input_format = f"INPUTFORMAT {input_format}" if input_format else "" 904 output_format = self.sql(expression, "output_format") 905 output_format = f"OUTPUTFORMAT {output_format}" if output_format else "" 906 return self.sep().join((input_format, output_format)) 907 908 def national_sql(self, expression: exp.National, prefix: str = "N") -> str: 909 string = self.sql(exp.Literal.string(expression.name)) 910 return f"{prefix}{string}" 911 912 def partition_sql(self, expression: exp.Partition) -> str: 913 return f"PARTITION({self.expressions(expression)})" 914 915 def properties_sql(self, expression: exp.Properties) -> str: 916 root_properties = [] 917 with_properties = [] 918 919 for p in expression.expressions: 920 p_loc = self.PROPERTIES_LOCATION[p.__class__] 921 if p_loc == exp.Properties.Location.POST_WITH: 922 with_properties.append(p) 923 elif p_loc == exp.Properties.Location.POST_SCHEMA: 924 root_properties.append(p) 925 926 return self.root_properties( 927 exp.Properties(expressions=root_properties) 928 ) + self.with_properties(exp.Properties(expressions=with_properties)) 929 930 def root_properties(self, properties: exp.Properties) -> str: 931 if properties.expressions: 932 return self.sep() + self.expressions(properties, indent=False, sep=" ") 933 return "" 934 935 def properties( 936 self, 937 properties: exp.Properties, 938 prefix: str = "", 939 sep: str = ", ", 940 suffix: str = "", 941 wrapped: bool = True, 942 ) -> str: 943 if properties.expressions: 944 expressions = self.expressions(properties, sep=sep, indent=False) 945 expressions = self.wrap(expressions) if wrapped else expressions 946 return f"{prefix}{' ' if prefix and prefix != ' ' else ''}{expressions}{suffix}" 947 return "" 948 949 def with_properties(self, properties: exp.Properties) -> str: 950 return self.properties(properties, prefix=self.seg("WITH")) 951 952 def locate_properties( 953 self, properties: exp.Properties 954 ) -> t.Dict[exp.Properties.Location, list[exp.Property]]: 955 properties_locs: t.Dict[exp.Properties.Location, list[exp.Property]] = { 956 key: [] for key in exp.Properties.Location 957 } 958 959 for p in properties.expressions: 960 p_loc = self.PROPERTIES_LOCATION[p.__class__] 961 if p_loc == exp.Properties.Location.POST_NAME: 962 properties_locs[exp.Properties.Location.POST_NAME].append(p) 963 elif p_loc == exp.Properties.Location.POST_INDEX: 964 properties_locs[exp.Properties.Location.POST_INDEX].append(p) 965 elif p_loc == exp.Properties.Location.POST_SCHEMA: 966 properties_locs[exp.Properties.Location.POST_SCHEMA].append(p) 967 elif p_loc == exp.Properties.Location.POST_WITH: 968 properties_locs[exp.Properties.Location.POST_WITH].append(p) 969 elif p_loc == exp.Properties.Location.POST_CREATE: 970 properties_locs[exp.Properties.Location.POST_CREATE].append(p) 971 elif p_loc == exp.Properties.Location.POST_ALIAS: 972 properties_locs[exp.Properties.Location.POST_ALIAS].append(p) 973 elif p_loc == exp.Properties.Location.POST_EXPRESSION: 974 properties_locs[exp.Properties.Location.POST_EXPRESSION].append(p) 975 elif p_loc == exp.Properties.Location.UNSUPPORTED: 976 self.unsupported(f"Unsupported property {p.key}") 977 978 return properties_locs 979 980 def property_sql(self, expression: exp.Property) -> str: 981 property_cls = expression.__class__ 982 if property_cls == exp.Property: 983 return f"{expression.name}={self.sql(expression, 'value')}" 984 985 property_name = exp.Properties.PROPERTY_TO_NAME.get(property_cls) 986 if not property_name: 987 self.unsupported(f"Unsupported property {expression.key}") 988 989 return f"{property_name}={self.sql(expression, 'this')}" 990 991 def likeproperty_sql(self, expression: exp.LikeProperty) -> str: 992 options = " ".join(f"{e.name} {self.sql(e, 'value')}" for e in expression.expressions) 993 options = f" {options}" if options else "" 994 return f"LIKE {self.sql(expression, 'this')}{options}" 995 996 def fallbackproperty_sql(self, expression: exp.FallbackProperty) -> str: 997 no = "NO " if expression.args.get("no") else "" 998 protection = " PROTECTION" if expression.args.get("protection") else "" 999 return f"{no}FALLBACK{protection}" 1000 1001 def journalproperty_sql(self, expression: exp.JournalProperty) -> str: 1002 no = "NO " if expression.args.get("no") else "" 1003 local = expression.args.get("local") 1004 local = f"{local} " if local else "" 1005 dual = "DUAL " if expression.args.get("dual") else "" 1006 before = "BEFORE " if expression.args.get("before") else "" 1007 after = "AFTER " if expression.args.get("after") else "" 1008 return f"{no}{local}{dual}{before}{after}JOURNAL" 1009 1010 def freespaceproperty_sql(self, expression: exp.FreespaceProperty) -> str: 1011 freespace = self.sql(expression, "this") 1012 percent = " PERCENT" if expression.args.get("percent") else "" 1013 return f"FREESPACE={freespace}{percent}" 1014 1015 def checksumproperty_sql(self, expression: exp.ChecksumProperty) -> str: 1016 if expression.args.get("default"): 1017 property = "DEFAULT" 1018 elif expression.args.get("on"): 1019 property = "ON" 1020 else: 1021 property = "OFF" 1022 return f"CHECKSUM={property}" 1023 1024 def mergeblockratioproperty_sql(self, expression: exp.MergeBlockRatioProperty) -> str: 1025 if expression.args.get("no"): 1026 return "NO MERGEBLOCKRATIO" 1027 if expression.args.get("default"): 1028 return "DEFAULT MERGEBLOCKRATIO" 1029 1030 percent = " PERCENT" if expression.args.get("percent") else "" 1031 return f"MERGEBLOCKRATIO={self.sql(expression, 'this')}{percent}" 1032 1033 def datablocksizeproperty_sql(self, expression: exp.DataBlocksizeProperty) -> str: 1034 default = expression.args.get("default") 1035 minimum = expression.args.get("minimum") 1036 maximum = expression.args.get("maximum") 1037 if default or minimum or maximum: 1038 if default: 1039 prop = "DEFAULT" 1040 elif minimum: 1041 prop = "MINIMUM" 1042 else: 1043 prop = "MAXIMUM" 1044 return f"{prop} DATABLOCKSIZE" 1045 units = expression.args.get("units") 1046 units = f" {units}" if units else "" 1047 return f"DATABLOCKSIZE={self.sql(expression, 'size')}{units}" 1048 1049 def blockcompressionproperty_sql(self, expression: exp.BlockCompressionProperty) -> str: 1050 autotemp = expression.args.get("autotemp") 1051 always = expression.args.get("always") 1052 default = expression.args.get("default") 1053 manual = expression.args.get("manual") 1054 never = expression.args.get("never") 1055 1056 if autotemp is not None: 1057 prop = f"AUTOTEMP({self.expressions(autotemp)})" 1058 elif always: 1059 prop = "ALWAYS" 1060 elif default: 1061 prop = "DEFAULT" 1062 elif manual: 1063 prop = "MANUAL" 1064 elif never: 1065 prop = "NEVER" 1066 return f"BLOCKCOMPRESSION={prop}" 1067 1068 def isolatedloadingproperty_sql(self, expression: exp.IsolatedLoadingProperty) -> str: 1069 no = expression.args.get("no") 1070 no = " NO" if no else "" 1071 concurrent = expression.args.get("concurrent") 1072 concurrent = " CONCURRENT" if concurrent else "" 1073 1074 for_ = "" 1075 if expression.args.get("for_all"): 1076 for_ = " FOR ALL" 1077 elif expression.args.get("for_insert"): 1078 for_ = " FOR INSERT" 1079 elif expression.args.get("for_none"): 1080 for_ = " FOR NONE" 1081 return f"WITH{no}{concurrent} ISOLATED LOADING{for_}" 1082 1083 def lockingproperty_sql(self, expression: exp.LockingProperty) -> str: 1084 kind = expression.args.get("kind") 1085 this: str = f" {this}" if expression.this else "" 1086 for_or_in = expression.args.get("for_or_in") 1087 lock_type = expression.args.get("lock_type") 1088 override = " OVERRIDE" if expression.args.get("override") else "" 1089 return f"LOCKING {kind}{this} {for_or_in} {lock_type}{override}" 1090 1091 def withdataproperty_sql(self, expression: exp.WithDataProperty) -> str: 1092 data_sql = f"WITH {'NO ' if expression.args.get('no') else ''}DATA" 1093 statistics = expression.args.get("statistics") 1094 statistics_sql = "" 1095 if statistics is not None: 1096 statistics_sql = f" AND {'NO ' if not statistics else ''}STATISTICS" 1097 return f"{data_sql}{statistics_sql}" 1098 1099 def insert_sql(self, expression: exp.Insert) -> str: 1100 overwrite = expression.args.get("overwrite") 1101 1102 if isinstance(expression.this, exp.Directory): 1103 this = "OVERWRITE " if overwrite else "INTO " 1104 else: 1105 this = "OVERWRITE TABLE " if overwrite else "INTO " 1106 1107 alternative = expression.args.get("alternative") 1108 alternative = f" OR {alternative} " if alternative else " " 1109 this = f"{this}{self.sql(expression, 'this')}" 1110 1111 exists = " IF EXISTS " if expression.args.get("exists") else " " 1112 partition_sql = ( 1113 self.sql(expression, "partition") if expression.args.get("partition") else "" 1114 ) 1115 expression_sql = self.sql(expression, "expression") 1116 conflict = self.sql(expression, "conflict") 1117 returning = self.sql(expression, "returning") 1118 sep = self.sep() if partition_sql else "" 1119 sql = f"INSERT{alternative}{this}{exists}{partition_sql}{sep}{expression_sql}{conflict}{returning}" 1120 return self.prepend_ctes(expression, sql) 1121 1122 def intersect_sql(self, expression: exp.Intersect) -> str: 1123 return self.prepend_ctes( 1124 expression, 1125 self.set_operation(expression, self.intersect_op(expression)), 1126 ) 1127 1128 def intersect_op(self, expression: exp.Intersect) -> str: 1129 return f"INTERSECT{'' if expression.args.get('distinct') else ' ALL'}" 1130 1131 def introducer_sql(self, expression: exp.Introducer) -> str: 1132 return f"{self.sql(expression, 'this')} {self.sql(expression, 'expression')}" 1133 1134 def pseudotype_sql(self, expression: exp.PseudoType) -> str: 1135 return expression.name.upper() 1136 1137 def onconflict_sql(self, expression: exp.OnConflict) -> str: 1138 conflict = "ON DUPLICATE KEY" if expression.args.get("duplicate") else "ON CONFLICT" 1139 constraint = self.sql(expression, "constraint") 1140 if constraint: 1141 constraint = f"ON CONSTRAINT {constraint}" 1142 key = self.expressions(expression, key="key", flat=True) 1143 do = "" if expression.args.get("duplicate") else " DO " 1144 nothing = "NOTHING" if expression.args.get("nothing") else "" 1145 expressions = self.expressions(expression, flat=True) 1146 if expressions: 1147 expressions = f"UPDATE SET {expressions}" 1148 return f"{self.seg(conflict)} {constraint}{key}{do}{nothing}{expressions}" 1149 1150 def returning_sql(self, expression: exp.Returning) -> str: 1151 return f"{self.seg('RETURNING')} {self.expressions(expression, flat=True)}" 1152 1153 def rowformatdelimitedproperty_sql(self, expression: exp.RowFormatDelimitedProperty) -> str: 1154 fields = expression.args.get("fields") 1155 fields = f" FIELDS TERMINATED BY {fields}" if fields else "" 1156 escaped = expression.args.get("escaped") 1157 escaped = f" ESCAPED BY {escaped}" if escaped else "" 1158 items = expression.args.get("collection_items") 1159 items = f" COLLECTION ITEMS TERMINATED BY {items}" if items else "" 1160 keys = expression.args.get("map_keys") 1161 keys = f" MAP KEYS TERMINATED BY {keys}" if keys else "" 1162 lines = expression.args.get("lines") 1163 lines = f" LINES TERMINATED BY {lines}" if lines else "" 1164 null = expression.args.get("null") 1165 null = f" NULL DEFINED AS {null}" if null else "" 1166 return f"ROW FORMAT DELIMITED{fields}{escaped}{items}{keys}{lines}{null}" 1167 1168 def table_sql(self, expression: exp.Table, sep: str = " AS ") -> str: 1169 table = ".".join( 1170 part 1171 for part in [ 1172 self.sql(expression, "catalog"), 1173 self.sql(expression, "db"), 1174 self.sql(expression, "this"), 1175 ] 1176 if part 1177 ) 1178 1179 alias = self.sql(expression, "alias") 1180 alias = f"{sep}{alias}" if alias else "" 1181 hints = self.expressions(expression, key="hints", flat=True) 1182 hints = f" WITH ({hints})" if hints and self.TABLE_HINTS else "" 1183 pivots = self.expressions(expression, key="pivots", sep=" ", flat=True) 1184 pivots = f" {pivots}" if pivots else "" 1185 joins = self.expressions(expression, key="joins", sep="") 1186 laterals = self.expressions(expression, key="laterals", sep="") 1187 system_time = expression.args.get("system_time") 1188 system_time = f" {self.sql(expression, 'system_time')}" if system_time else "" 1189 1190 return f"{table}{system_time}{alias}{hints}{pivots}{joins}{laterals}" 1191 1192 def tablesample_sql( 1193 self, expression: exp.TableSample, seed_prefix: str = "SEED", sep=" AS " 1194 ) -> str: 1195 if self.alias_post_tablesample and expression.this.alias: 1196 table = expression.this.copy() 1197 table.set("alias", None) 1198 this = self.sql(table) 1199 alias = f"{sep}{self.sql(expression.this, 'alias')}" 1200 else: 1201 this = self.sql(expression, "this") 1202 alias = "" 1203 method = self.sql(expression, "method") 1204 method = f"{method.upper()} " if method and self.TABLESAMPLE_WITH_METHOD else "" 1205 numerator = self.sql(expression, "bucket_numerator") 1206 denominator = self.sql(expression, "bucket_denominator") 1207 field = self.sql(expression, "bucket_field") 1208 field = f" ON {field}" if field else "" 1209 bucket = f"BUCKET {numerator} OUT OF {denominator}{field}" if numerator else "" 1210 percent = self.sql(expression, "percent") 1211 percent = f"{percent} PERCENT" if percent else "" 1212 rows = self.sql(expression, "rows") 1213 rows = f"{rows} ROWS" if rows else "" 1214 size = self.sql(expression, "size") 1215 if size and self.TABLESAMPLE_SIZE_IS_PERCENT: 1216 size = f"{size} PERCENT" 1217 seed = self.sql(expression, "seed") 1218 seed = f" {seed_prefix} ({seed})" if seed else "" 1219 kind = expression.args.get("kind", "TABLESAMPLE") 1220 return f"{this} {kind} {method}({bucket}{percent}{rows}{size}){seed}{alias}" 1221 1222 def pivot_sql(self, expression: exp.Pivot) -> str: 1223 expressions = self.expressions(expression, flat=True) 1224 1225 if expression.this: 1226 this = self.sql(expression, "this") 1227 on = f"{self.seg('ON')} {expressions}" 1228 using = self.expressions(expression, key="using", flat=True) 1229 using = f"{self.seg('USING')} {using}" if using else "" 1230 group = self.sql(expression, "group") 1231 return f"PIVOT {this}{on}{using}{group}" 1232 1233 alias = self.sql(expression, "alias") 1234 alias = f" AS {alias}" if alias else "" 1235 unpivot = expression.args.get("unpivot") 1236 direction = "UNPIVOT" if unpivot else "PIVOT" 1237 field = self.sql(expression, "field") 1238 return f"{direction}({expressions} FOR {field}){alias}" 1239 1240 def tuple_sql(self, expression: exp.Tuple) -> str: 1241 return f"({self.expressions(expression, flat=True)})" 1242 1243 def update_sql(self, expression: exp.Update) -> str: 1244 this = self.sql(expression, "this") 1245 set_sql = self.expressions(expression, flat=True) 1246 from_sql = self.sql(expression, "from") 1247 where_sql = self.sql(expression, "where") 1248 returning = self.sql(expression, "returning") 1249 sql = f"UPDATE {this} SET {set_sql}{from_sql}{where_sql}{returning}" 1250 return self.prepend_ctes(expression, sql) 1251 1252 def values_sql(self, expression: exp.Values) -> str: 1253 args = self.expressions(expression) 1254 alias = self.sql(expression, "alias") 1255 values = f"VALUES{self.seg('')}{args}" 1256 values = ( 1257 f"({values})" 1258 if self.WRAP_DERIVED_VALUES and (alias or isinstance(expression.parent, exp.From)) 1259 else values 1260 ) 1261 return f"{values} AS {alias}" if alias else values 1262 1263 def var_sql(self, expression: exp.Var) -> str: 1264 return self.sql(expression, "this") 1265 1266 def into_sql(self, expression: exp.Into) -> str: 1267 temporary = " TEMPORARY" if expression.args.get("temporary") else "" 1268 unlogged = " UNLOGGED" if expression.args.get("unlogged") else "" 1269 return f"{self.seg('INTO')}{temporary or unlogged} {self.sql(expression, 'this')}" 1270 1271 def from_sql(self, expression: exp.From) -> str: 1272 return f"{self.seg('FROM')} {self.sql(expression, 'this')}" 1273 1274 def group_sql(self, expression: exp.Group) -> str: 1275 group_by = self.op_expressions("GROUP BY", expression) 1276 grouping_sets = self.expressions(expression, key="grouping_sets", indent=False) 1277 grouping_sets = ( 1278 f"{self.seg('GROUPING SETS')} {self.wrap(grouping_sets)}" if grouping_sets else "" 1279 ) 1280 1281 cube = expression.args.get("cube", []) 1282 if seq_get(cube, 0) is True: 1283 return f"{group_by}{self.seg('WITH CUBE')}" 1284 else: 1285 cube_sql = self.expressions(expression, key="cube", indent=False) 1286 cube_sql = f"{self.seg('CUBE')} {self.wrap(cube_sql)}" if cube_sql else "" 1287 1288 rollup = expression.args.get("rollup", []) 1289 if seq_get(rollup, 0) is True: 1290 return f"{group_by}{self.seg('WITH ROLLUP')}" 1291 else: 1292 rollup_sql = self.expressions(expression, key="rollup", indent=False) 1293 rollup_sql = f"{self.seg('ROLLUP')} {self.wrap(rollup_sql)}" if rollup_sql else "" 1294 1295 groupings = csv( 1296 grouping_sets, 1297 cube_sql, 1298 rollup_sql, 1299 self.seg("WITH TOTALS") if expression.args.get("totals") else "", 1300 sep=self.GROUPINGS_SEP, 1301 ) 1302 1303 if expression.args.get("expressions") and groupings: 1304 group_by = f"{group_by}{self.GROUPINGS_SEP}" 1305 1306 return f"{group_by}{groupings}" 1307 1308 def having_sql(self, expression: exp.Having) -> str: 1309 this = self.indent(self.sql(expression, "this")) 1310 return f"{self.seg('HAVING')}{self.sep()}{this}" 1311 1312 def join_sql(self, expression: exp.Join) -> str: 1313 op_sql = " ".join( 1314 op 1315 for op in ( 1316 "NATURAL" if expression.args.get("natural") else None, 1317 "GLOBAL" if expression.args.get("global") else None, 1318 expression.side, 1319 expression.kind, 1320 expression.hint if self.JOIN_HINTS else None, 1321 ) 1322 if op 1323 ) 1324 on_sql = self.sql(expression, "on") 1325 using = expression.args.get("using") 1326 1327 if not on_sql and using: 1328 on_sql = csv(*(self.sql(column) for column in using)) 1329 1330 this_sql = self.sql(expression, "this") 1331 1332 if on_sql: 1333 on_sql = self.indent(on_sql, skip_first=True) 1334 space = self.seg(" " * self.pad) if self.pretty else " " 1335 if using: 1336 on_sql = f"{space}USING ({on_sql})" 1337 else: 1338 on_sql = f"{space}ON {on_sql}" 1339 elif not op_sql: 1340 return f", {this_sql}" 1341 1342 op_sql = f"{op_sql} JOIN" if op_sql else "JOIN" 1343 return f"{self.seg(op_sql)} {this_sql}{on_sql}" 1344 1345 def lambda_sql(self, expression: exp.Lambda, arrow_sep: str = "->") -> str: 1346 args = self.expressions(expression, flat=True) 1347 args = f"({args})" if len(args.split(",")) > 1 else args 1348 return f"{args} {arrow_sep} {self.sql(expression, 'this')}" 1349 1350 def lateral_sql(self, expression: exp.Lateral) -> str: 1351 this = self.sql(expression, "this") 1352 1353 if isinstance(expression.this, exp.Subquery): 1354 return f"LATERAL {this}" 1355 1356 if expression.args.get("view"): 1357 alias = expression.args["alias"] 1358 columns = self.expressions(alias, key="columns", flat=True) 1359 table = f" {alias.name}" if alias.name else "" 1360 columns = f" AS {columns}" if columns else "" 1361 op_sql = self.seg(f"LATERAL VIEW{' OUTER' if expression.args.get('outer') else ''}") 1362 return f"{op_sql}{self.sep()}{this}{table}{columns}" 1363 1364 alias = self.sql(expression, "alias") 1365 alias = f" AS {alias}" if alias else "" 1366 return f"LATERAL {this}{alias}" 1367 1368 def limit_sql(self, expression: exp.Limit) -> str: 1369 this = self.sql(expression, "this") 1370 return f"{this}{self.seg('LIMIT')} {self.sql(expression, 'expression')}" 1371 1372 def offset_sql(self, expression: exp.Offset) -> str: 1373 this = self.sql(expression, "this") 1374 return f"{this}{self.seg('OFFSET')} {self.sql(expression, 'expression')}" 1375 1376 def setitem_sql(self, expression: exp.SetItem) -> str: 1377 kind = self.sql(expression, "kind") 1378 kind = f"{kind} " if kind else "" 1379 this = self.sql(expression, "this") 1380 expressions = self.expressions(expression) 1381 collate = self.sql(expression, "collate") 1382 collate = f" COLLATE {collate}" if collate else "" 1383 global_ = "GLOBAL " if expression.args.get("global") else "" 1384 return f"{global_}{kind}{this}{expressions}{collate}" 1385 1386 def set_sql(self, expression: exp.Set) -> str: 1387 expressions = ( 1388 f" {self.expressions(expression, flat=True)}" if expression.expressions else "" 1389 ) 1390 return f"SET{expressions}" 1391 1392 def pragma_sql(self, expression: exp.Pragma) -> str: 1393 return f"PRAGMA {self.sql(expression, 'this')}" 1394 1395 def lock_sql(self, expression: exp.Lock) -> str: 1396 if not self.LOCKING_READS_SUPPORTED: 1397 self.unsupported("Locking reads using 'FOR UPDATE/SHARE' are not supported") 1398 return "" 1399 1400 lock_type = "FOR UPDATE" if expression.args["update"] else "FOR SHARE" 1401 expressions = self.expressions(expression, flat=True) 1402 expressions = f" OF {expressions}" if expressions else "" 1403 wait = expression.args.get("wait") 1404 1405 if wait is not None: 1406 if isinstance(wait, exp.Literal): 1407 wait = f" WAIT {self.sql(wait)}" 1408 else: 1409 wait = " NOWAIT" if wait else " SKIP LOCKED" 1410 1411 return f"{lock_type}{expressions}{wait or ''}" 1412 1413 def literal_sql(self, expression: exp.Literal) -> str: 1414 text = expression.this or "" 1415 if expression.is_string: 1416 text = text.replace(self.quote_end, self._escaped_quote_end) 1417 if self.pretty: 1418 text = text.replace("\n", self.SENTINEL_LINE_BREAK) 1419 text = f"{self.quote_start}{text}{self.quote_end}" 1420 return text 1421 1422 def loaddata_sql(self, expression: exp.LoadData) -> str: 1423 local = " LOCAL" if expression.args.get("local") else "" 1424 inpath = f" INPATH {self.sql(expression, 'inpath')}" 1425 overwrite = " OVERWRITE" if expression.args.get("overwrite") else "" 1426 this = f" INTO TABLE {self.sql(expression, 'this')}" 1427 partition = self.sql(expression, "partition") 1428 partition = f" {partition}" if partition else "" 1429 input_format = self.sql(expression, "input_format") 1430 input_format = f" INPUTFORMAT {input_format}" if input_format else "" 1431 serde = self.sql(expression, "serde") 1432 serde = f" SERDE {serde}" if serde else "" 1433 return f"LOAD DATA{local}{inpath}{overwrite}{this}{partition}{input_format}{serde}" 1434 1435 def null_sql(self, *_) -> str: 1436 return "NULL" 1437 1438 def boolean_sql(self, expression: exp.Boolean) -> str: 1439 return "TRUE" if expression.this else "FALSE" 1440 1441 def order_sql(self, expression: exp.Order, flat: bool = False) -> str: 1442 this = self.sql(expression, "this") 1443 this = f"{this} " if this else this 1444 return self.op_expressions(f"{this}ORDER BY", expression, flat=this or flat) # type: ignore 1445 1446 def cluster_sql(self, expression: exp.Cluster) -> str: 1447 return self.op_expressions("CLUSTER BY", expression) 1448 1449 def distribute_sql(self, expression: exp.Distribute) -> str: 1450 return self.op_expressions("DISTRIBUTE BY", expression) 1451 1452 def sort_sql(self, expression: exp.Sort) -> str: 1453 return self.op_expressions("SORT BY", expression) 1454 1455 def ordered_sql(self, expression: exp.Ordered) -> str: 1456 desc = expression.args.get("desc") 1457 asc = not desc 1458 1459 nulls_first = expression.args.get("nulls_first") 1460 nulls_last = not nulls_first 1461 nulls_are_large = self.null_ordering == "nulls_are_large" 1462 nulls_are_small = self.null_ordering == "nulls_are_small" 1463 nulls_are_last = self.null_ordering == "nulls_are_last" 1464 1465 sort_order = " DESC" if desc else "" 1466 nulls_sort_change = "" 1467 if nulls_first and ( 1468 (asc and nulls_are_large) or (desc and nulls_are_small) or nulls_are_last 1469 ): 1470 nulls_sort_change = " NULLS FIRST" 1471 elif ( 1472 nulls_last 1473 and ((asc and nulls_are_small) or (desc and nulls_are_large)) 1474 and not nulls_are_last 1475 ): 1476 nulls_sort_change = " NULLS LAST" 1477 1478 if nulls_sort_change and not self.NULL_ORDERING_SUPPORTED: 1479 self.unsupported( 1480 "Sorting in an ORDER BY on NULLS FIRST/NULLS LAST is not supported by this dialect" 1481 ) 1482 nulls_sort_change = "" 1483 1484 return f"{self.sql(expression, 'this')}{sort_order}{nulls_sort_change}" 1485 1486 def matchrecognize_sql(self, expression: exp.MatchRecognize) -> str: 1487 partition = self.partition_by_sql(expression) 1488 order = self.sql(expression, "order") 1489 measures = self.expressions(expression, key="measures") 1490 measures = self.seg(f"MEASURES{self.seg(measures)}") if measures else "" 1491 rows = self.sql(expression, "rows") 1492 rows = self.seg(rows) if rows else "" 1493 after = self.sql(expression, "after") 1494 after = self.seg(after) if after else "" 1495 pattern = self.sql(expression, "pattern") 1496 pattern = self.seg(f"PATTERN ({pattern})") if pattern else "" 1497 definition_sqls = [ 1498 f"{self.sql(definition, 'alias')} AS {self.sql(definition, 'this')}" 1499 for definition in expression.args.get("define", []) 1500 ] 1501 definitions = self.expressions(sqls=definition_sqls) 1502 define = self.seg(f"DEFINE{self.seg(definitions)}") if definitions else "" 1503 body = "".join( 1504 ( 1505 partition, 1506 order, 1507 measures, 1508 rows, 1509 after, 1510 pattern, 1511 define, 1512 ) 1513 ) 1514 alias = self.sql(expression, "alias") 1515 alias = f" {alias}" if alias else "" 1516 return f"{self.seg('MATCH_RECOGNIZE')} {self.wrap(body)}{alias}" 1517 1518 def query_modifiers(self, expression: exp.Expression, *sqls: str) -> str: 1519 limit = expression.args.get("limit") 1520 1521 if self.LIMIT_FETCH == "LIMIT" and isinstance(limit, exp.Fetch): 1522 limit = exp.Limit(expression=limit.args.get("count")) 1523 elif self.LIMIT_FETCH == "FETCH" and isinstance(limit, exp.Limit): 1524 limit = exp.Fetch(direction="FIRST", count=limit.expression) 1525 1526 fetch = isinstance(limit, exp.Fetch) 1527 1528 return csv( 1529 *sqls, 1530 *[self.sql(join) for join in expression.args.get("joins") or []], 1531 self.sql(expression, "match"), 1532 *[self.sql(lateral) for lateral in expression.args.get("laterals") or []], 1533 self.sql(expression, "where"), 1534 self.sql(expression, "group"), 1535 self.sql(expression, "having"), 1536 *self.after_having_modifiers(expression), 1537 self.sql(expression, "order"), 1538 self.sql(expression, "offset") if fetch else self.sql(limit), 1539 self.sql(limit) if fetch else self.sql(expression, "offset"), 1540 *self.after_limit_modifiers(expression), 1541 sep="", 1542 ) 1543 1544 def after_having_modifiers(self, expression: exp.Expression) -> t.List[str]: 1545 return [ 1546 self.sql(expression, "qualify"), 1547 self.seg("WINDOW ") + self.expressions(expression, key="windows", flat=True) 1548 if expression.args.get("windows") 1549 else "", 1550 ] 1551 1552 def after_limit_modifiers(self, expression: exp.Expression) -> t.List[str]: 1553 locks = self.expressions(expression, key="locks", sep=" ") 1554 locks = f" {locks}" if locks else "" 1555 return [locks, self.sql(expression, "sample")] 1556 1557 def select_sql(self, expression: exp.Select) -> str: 1558 hint = self.sql(expression, "hint") 1559 distinct = self.sql(expression, "distinct") 1560 distinct = f" {distinct}" if distinct else "" 1561 kind = expression.args.get("kind") 1562 kind = f" AS {kind}" if kind else "" 1563 expressions = self.expressions(expression) 1564 expressions = f"{self.sep()}{expressions}" if expressions else expressions 1565 sql = self.query_modifiers( 1566 expression, 1567 f"SELECT{hint}{distinct}{kind}{expressions}", 1568 self.sql(expression, "into", comment=False), 1569 self.sql(expression, "from", comment=False), 1570 ) 1571 return self.prepend_ctes(expression, sql) 1572 1573 def schema_sql(self, expression: exp.Schema) -> str: 1574 this = self.sql(expression, "this") 1575 this = f"{this} " if this else "" 1576 sql = f"({self.sep('')}{self.expressions(expression)}{self.seg(')', sep='')}" 1577 return f"{this}{sql}" 1578 1579 def star_sql(self, expression: exp.Star) -> str: 1580 except_ = self.expressions(expression, key="except", flat=True) 1581 except_ = f"{self.seg(self.STAR_MAPPING['except'])} ({except_})" if except_ else "" 1582 replace = self.expressions(expression, key="replace", flat=True) 1583 replace = f"{self.seg(self.STAR_MAPPING['replace'])} ({replace})" if replace else "" 1584 return f"*{except_}{replace}" 1585 1586 def parameter_sql(self, expression: exp.Parameter) -> str: 1587 this = self.sql(expression, "this") 1588 this = f"{{{this}}}" if expression.args.get("wrapped") else f"{this}" 1589 return f"{self.PARAMETER_TOKEN}{this}" 1590 1591 def sessionparameter_sql(self, expression: exp.SessionParameter) -> str: 1592 this = self.sql(expression, "this") 1593 kind = expression.text("kind") 1594 if kind: 1595 kind = f"{kind}." 1596 return f"@@{kind}{this}" 1597 1598 def placeholder_sql(self, expression: exp.Placeholder) -> str: 1599 return f":{expression.name}" if expression.name else "?" 1600 1601 def subquery_sql(self, expression: exp.Subquery, sep: str = " AS ") -> str: 1602 alias = self.sql(expression, "alias") 1603 alias = f"{sep}{alias}" if alias else "" 1604 1605 pivots = self.expressions(expression, key="pivots", sep=" ", flat=True) 1606 pivots = f" {pivots}" if pivots else "" 1607 1608 sql = self.query_modifiers(expression, self.wrap(expression), alias, pivots) 1609 return self.prepend_ctes(expression, sql) 1610 1611 def qualify_sql(self, expression: exp.Qualify) -> str: 1612 this = self.indent(self.sql(expression, "this")) 1613 return f"{self.seg('QUALIFY')}{self.sep()}{this}" 1614 1615 def union_sql(self, expression: exp.Union) -> str: 1616 return self.prepend_ctes( 1617 expression, 1618 self.set_operation(expression, self.union_op(expression)), 1619 ) 1620 1621 def union_op(self, expression: exp.Union) -> str: 1622 kind = " DISTINCT" if self.EXPLICIT_UNION else "" 1623 kind = kind if expression.args.get("distinct") else " ALL" 1624 return f"UNION{kind}" 1625 1626 def unnest_sql(self, expression: exp.Unnest) -> str: 1627 args = self.expressions(expression, flat=True) 1628 alias = expression.args.get("alias") 1629 if alias and self.unnest_column_only: 1630 columns = alias.columns 1631 alias = self.sql(columns[0]) if columns else "" 1632 else: 1633 alias = self.sql(expression, "alias") 1634 alias = f" AS {alias}" if alias else alias 1635 ordinality = " WITH ORDINALITY" if expression.args.get("ordinality") else "" 1636 offset = expression.args.get("offset") 1637 offset = f" WITH OFFSET AS {self.sql(offset)}" if offset else "" 1638 return f"UNNEST({args}){ordinality}{alias}{offset}" 1639 1640 def where_sql(self, expression: exp.Where) -> str: 1641 this = self.indent(self.sql(expression, "this")) 1642 return f"{self.seg('WHERE')}{self.sep()}{this}" 1643 1644 def window_sql(self, expression: exp.Window) -> str: 1645 this = self.sql(expression, "this") 1646 1647 partition = self.partition_by_sql(expression) 1648 1649 order = expression.args.get("order") 1650 order_sql = self.order_sql(order, flat=True) if order else "" 1651 1652 partition_sql = partition + " " if partition and order else partition 1653 1654 spec = expression.args.get("spec") 1655 spec_sql = " " + self.windowspec_sql(spec) if spec else "" 1656 1657 alias = self.sql(expression, "alias") 1658 over = self.sql(expression, "over") or "OVER" 1659 this = f"{this} {'AS' if expression.arg_key == 'windows' else over}" 1660 1661 first = expression.args.get("first") 1662 if first is not None: 1663 first = " FIRST " if first else " LAST " 1664 first = first or "" 1665 1666 if not partition and not order and not spec and alias: 1667 return f"{this} {alias}" 1668 1669 window_args = alias + first + partition_sql + order_sql + spec_sql 1670 1671 return f"{this} ({window_args.strip()})" 1672 1673 def partition_by_sql(self, expression: exp.Window | exp.MatchRecognize) -> str: 1674 partition = self.expressions(expression, key="partition_by", flat=True) 1675 return f"PARTITION BY {partition}" if partition else "" 1676 1677 def windowspec_sql(self, expression: exp.WindowSpec) -> str: 1678 kind = self.sql(expression, "kind") 1679 start = csv(self.sql(expression, "start"), self.sql(expression, "start_side"), sep=" ") 1680 end = ( 1681 csv(self.sql(expression, "end"), self.sql(expression, "end_side"), sep=" ") 1682 or "CURRENT ROW" 1683 ) 1684 return f"{kind} BETWEEN {start} AND {end}" 1685 1686 def withingroup_sql(self, expression: exp.WithinGroup) -> str: 1687 this = self.sql(expression, "this") 1688 expression_sql = self.sql(expression, "expression")[1:] # order has a leading space 1689 return f"{this} WITHIN GROUP ({expression_sql})" 1690 1691 def between_sql(self, expression: exp.Between) -> str: 1692 this = self.sql(expression, "this") 1693 low = self.sql(expression, "low") 1694 high = self.sql(expression, "high") 1695 return f"{this} BETWEEN {low} AND {high}" 1696 1697 def bracket_sql(self, expression: exp.Bracket) -> str: 1698 expressions = apply_index_offset(expression.this, expression.expressions, self.index_offset) 1699 expressions_sql = ", ".join(self.sql(e) for e in expressions) 1700 1701 return f"{self.sql(expression, 'this')}[{expressions_sql}]" 1702 1703 def all_sql(self, expression: exp.All) -> str: 1704 return f"ALL {self.wrap(expression)}" 1705 1706 def any_sql(self, expression: exp.Any) -> str: 1707 this = self.sql(expression, "this") 1708 if isinstance(expression.this, exp.Subqueryable): 1709 this = self.wrap(this) 1710 return f"ANY {this}" 1711 1712 def exists_sql(self, expression: exp.Exists) -> str: 1713 return f"EXISTS{self.wrap(expression)}" 1714 1715 def case_sql(self, expression: exp.Case) -> str: 1716 this = self.sql(expression, "this") 1717 statements = [f"CASE {this}" if this else "CASE"] 1718 1719 for e in expression.args["ifs"]: 1720 statements.append(f"WHEN {self.sql(e, 'this')}") 1721 statements.append(f"THEN {self.sql(e, 'true')}") 1722 1723 default = self.sql(expression, "default") 1724 1725 if default: 1726 statements.append(f"ELSE {default}") 1727 1728 statements.append("END") 1729 1730 if self.pretty and self.text_width(statements) > self._max_text_width: 1731 return self.indent("\n".join(statements), skip_first=True, skip_last=True) 1732 1733 return " ".join(statements) 1734 1735 def constraint_sql(self, expression: exp.Constraint) -> str: 1736 this = self.sql(expression, "this") 1737 expressions = self.expressions(expression, flat=True) 1738 return f"CONSTRAINT {this} {expressions}" 1739 1740 def nextvaluefor_sql(self, expression: exp.NextValueFor) -> str: 1741 order = expression.args.get("order") 1742 order = f" OVER ({self.order_sql(order, flat=True)})" if order else "" 1743 return f"NEXT VALUE FOR {self.sql(expression, 'this')}{order}" 1744 1745 def extract_sql(self, expression: exp.Extract) -> str: 1746 this = self.sql(expression, "this") 1747 expression_sql = self.sql(expression, "expression") 1748 return f"EXTRACT({this} FROM {expression_sql})" 1749 1750 def trim_sql(self, expression: exp.Trim) -> str: 1751 trim_type = self.sql(expression, "position") 1752 1753 if trim_type == "LEADING": 1754 return self.func("LTRIM", expression.this) 1755 elif trim_type == "TRAILING": 1756 return self.func("RTRIM", expression.this) 1757 else: 1758 return self.func("TRIM", expression.this, expression.expression) 1759 1760 def concat_sql(self, expression: exp.Concat) -> str: 1761 if len(expression.expressions) == 1: 1762 return self.sql(expression.expressions[0]) 1763 return self.function_fallback_sql(expression) 1764 1765 def check_sql(self, expression: exp.Check) -> str: 1766 this = self.sql(expression, key="this") 1767 return f"CHECK ({this})" 1768 1769 def foreignkey_sql(self, expression: exp.ForeignKey) -> str: 1770 expressions = self.expressions(expression, flat=True) 1771 reference = self.sql(expression, "reference") 1772 reference = f" {reference}" if reference else "" 1773 delete = self.sql(expression, "delete") 1774 delete = f" ON DELETE {delete}" if delete else "" 1775 update = self.sql(expression, "update") 1776 update = f" ON UPDATE {update}" if update else "" 1777 return f"FOREIGN KEY ({expressions}){reference}{delete}{update}" 1778 1779 def primarykey_sql(self, expression: exp.ForeignKey) -> str: 1780 expressions = self.expressions(expression, flat=True) 1781 options = self.expressions(expression, key="options", flat=True, sep=" ") 1782 options = f" {options}" if options else "" 1783 return f"PRIMARY KEY ({expressions}){options}" 1784 1785 def if_sql(self, expression: exp.If) -> str: 1786 return self.case_sql( 1787 exp.Case(ifs=[expression.copy()], default=expression.args.get("false")) 1788 ) 1789 1790 def matchagainst_sql(self, expression: exp.MatchAgainst) -> str: 1791 modifier = expression.args.get("modifier") 1792 modifier = f" {modifier}" if modifier else "" 1793 return f"{self.func('MATCH', *expression.expressions)} AGAINST({self.sql(expression, 'this')}{modifier})" 1794 1795 def jsonkeyvalue_sql(self, expression: exp.JSONKeyValue) -> str: 1796 return f"{self.sql(expression, 'this')}: {self.sql(expression, 'expression')}" 1797 1798 def jsonobject_sql(self, expression: exp.JSONObject) -> str: 1799 expressions = self.expressions(expression) 1800 null_handling = expression.args.get("null_handling") 1801 null_handling = f" {null_handling}" if null_handling else "" 1802 unique_keys = expression.args.get("unique_keys") 1803 if unique_keys is not None: 1804 unique_keys = f" {'WITH' if unique_keys else 'WITHOUT'} UNIQUE KEYS" 1805 else: 1806 unique_keys = "" 1807 return_type = self.sql(expression, "return_type") 1808 return_type = f" RETURNING {return_type}" if return_type else "" 1809 format_json = " FORMAT JSON" if expression.args.get("format_json") else "" 1810 encoding = self.sql(expression, "encoding") 1811 encoding = f" ENCODING {encoding}" if encoding else "" 1812 return f"JSON_OBJECT({expressions}{null_handling}{unique_keys}{return_type}{format_json}{encoding})" 1813 1814 def openjsoncolumndef_sql(self, expression: exp.OpenJSONColumnDef) -> str: 1815 this = self.sql(expression, "this") 1816 kind = self.sql(expression, "kind") 1817 path = self.sql(expression, "path") 1818 path = f" {path}" if path else "" 1819 as_json = " AS JSON" if expression.args.get("as_json") else "" 1820 return f"{this} {kind}{path}{as_json}" 1821 1822 def openjson_sql(self, expression: exp.OpenJSON) -> str: 1823 this = self.sql(expression, "this") 1824 path = self.sql(expression, "path") 1825 path = f", {path}" if path else "" 1826 expressions = self.expressions(expression) 1827 with_ = ( 1828 f" WITH ({self.seg(self.indent(expressions), sep='')}{self.seg(')', sep='')}" 1829 if expressions 1830 else "" 1831 ) 1832 return f"OPENJSON({this}{path}){with_}" 1833 1834 def in_sql(self, expression: exp.In) -> str: 1835 query = expression.args.get("query") 1836 unnest = expression.args.get("unnest") 1837 field = expression.args.get("field") 1838 is_global = " GLOBAL" if expression.args.get("is_global") else "" 1839 1840 if query: 1841 in_sql = self.wrap(query) 1842 elif unnest: 1843 in_sql = self.in_unnest_op(unnest) 1844 elif field: 1845 in_sql = self.sql(field) 1846 else: 1847 in_sql = f"({self.expressions(expression, flat=True)})" 1848 1849 return f"{self.sql(expression, 'this')}{is_global} IN {in_sql}" 1850 1851 def in_unnest_op(self, unnest: exp.Unnest) -> str: 1852 return f"(SELECT {self.sql(unnest)})" 1853 1854 def interval_sql(self, expression: exp.Interval) -> str: 1855 unit = self.sql(expression, "unit") 1856 if not self.INTERVAL_ALLOWS_PLURAL_FORM: 1857 unit = self.TIME_PART_SINGULARS.get(unit.lower(), unit) 1858 unit = f" {unit}" if unit else "" 1859 1860 if self.SINGLE_STRING_INTERVAL: 1861 this = expression.this.name if expression.this else "" 1862 return f"INTERVAL '{this}{unit}'" if this else f"INTERVAL{unit}" 1863 1864 this = self.sql(expression, "this") 1865 if this: 1866 unwrapped = isinstance(expression.this, self.UNWRAPPED_INTERVAL_VALUES) 1867 this = f" {this}" if unwrapped else f" ({this})" 1868 1869 return f"INTERVAL{this}{unit}" 1870 1871 def return_sql(self, expression: exp.Return) -> str: 1872 return f"RETURN {self.sql(expression, 'this')}" 1873 1874 def reference_sql(self, expression: exp.Reference) -> str: 1875 this = self.sql(expression, "this") 1876 expressions = self.expressions(expression, flat=True) 1877 expressions = f"({expressions})" if expressions else "" 1878 options = self.expressions(expression, key="options", flat=True, sep=" ") 1879 options = f" {options}" if options else "" 1880 return f"REFERENCES {this}{expressions}{options}" 1881 1882 def anonymous_sql(self, expression: exp.Anonymous) -> str: 1883 return self.func(expression.name, *expression.expressions) 1884 1885 def paren_sql(self, expression: exp.Paren) -> str: 1886 if isinstance(expression.unnest(), exp.Select): 1887 sql = self.wrap(expression) 1888 else: 1889 sql = self.seg(self.indent(self.sql(expression, "this")), sep="") 1890 sql = f"({sql}{self.seg(')', sep='')}" 1891 1892 return self.prepend_ctes(expression, sql) 1893 1894 def neg_sql(self, expression: exp.Neg) -> str: 1895 # This makes sure we don't convert "- - 5" to "--5", which is a comment 1896 this_sql = self.sql(expression, "this") 1897 sep = " " if this_sql[0] == "-" else "" 1898 return f"-{sep}{this_sql}" 1899 1900 def not_sql(self, expression: exp.Not) -> str: 1901 return f"NOT {self.sql(expression, 'this')}" 1902 1903 def alias_sql(self, expression: exp.Alias) -> str: 1904 alias = self.sql(expression, "alias") 1905 alias = f" AS {alias}" if alias else "" 1906 return f"{self.sql(expression, 'this')}{alias}" 1907 1908 def aliases_sql(self, expression: exp.Aliases) -> str: 1909 return f"{self.sql(expression, 'this')} AS ({self.expressions(expression, flat=True)})" 1910 1911 def attimezone_sql(self, expression: exp.AtTimeZone) -> str: 1912 this = self.sql(expression, "this") 1913 zone = self.sql(expression, "zone") 1914 return f"{this} AT TIME ZONE {zone}" 1915 1916 def add_sql(self, expression: exp.Add) -> str: 1917 return self.binary(expression, "+") 1918 1919 def and_sql(self, expression: exp.And) -> str: 1920 return self.connector_sql(expression, "AND") 1921 1922 def connector_sql(self, expression: exp.Connector, op: str) -> str: 1923 if not self.pretty: 1924 return self.binary(expression, op) 1925 1926 sqls = tuple( 1927 self.maybe_comment(self.sql(e), e, e.parent.comments or []) if i != 1 else self.sql(e) 1928 for i, e in enumerate(expression.flatten(unnest=False)) 1929 ) 1930 1931 sep = "\n" if self.text_width(sqls) > self._max_text_width else " " 1932 return f"{sep}{op} ".join(sqls) 1933 1934 def bitwiseand_sql(self, expression: exp.BitwiseAnd) -> str: 1935 return self.binary(expression, "&") 1936 1937 def bitwiseleftshift_sql(self, expression: exp.BitwiseLeftShift) -> str: 1938 return self.binary(expression, "<<") 1939 1940 def bitwisenot_sql(self, expression: exp.BitwiseNot) -> str: 1941 return f"~{self.sql(expression, 'this')}" 1942 1943 def bitwiseor_sql(self, expression: exp.BitwiseOr) -> str: 1944 return self.binary(expression, "|") 1945 1946 def bitwiserightshift_sql(self, expression: exp.BitwiseRightShift) -> str: 1947 return self.binary(expression, ">>") 1948 1949 def bitwisexor_sql(self, expression: exp.BitwiseXor) -> str: 1950 return self.binary(expression, "^") 1951 1952 def cast_sql(self, expression: exp.Cast) -> str: 1953 return f"CAST({self.sql(expression, 'this')} AS {self.sql(expression, 'to')})" 1954 1955 def currentdate_sql(self, expression: exp.CurrentDate) -> str: 1956 zone = self.sql(expression, "this") 1957 return f"CURRENT_DATE({zone})" if zone else "CURRENT_DATE" 1958 1959 def collate_sql(self, expression: exp.Collate) -> str: 1960 return self.binary(expression, "COLLATE") 1961 1962 def command_sql(self, expression: exp.Command) -> str: 1963 return f"{self.sql(expression, 'this').upper()} {expression.text('expression').strip()}" 1964 1965 def comment_sql(self, expression: exp.Comment) -> str: 1966 this = self.sql(expression, "this") 1967 kind = expression.args["kind"] 1968 exists_sql = " IF EXISTS " if expression.args.get("exists") else " " 1969 expression_sql = self.sql(expression, "expression") 1970 return f"COMMENT{exists_sql}ON {kind} {this} IS {expression_sql}" 1971 1972 def mergetreettlaction_sql(self, expression: exp.MergeTreeTTLAction) -> str: 1973 this = self.sql(expression, "this") 1974 delete = " DELETE" if expression.args.get("delete") else "" 1975 recompress = self.sql(expression, "recompress") 1976 recompress = f" RECOMPRESS {recompress}" if recompress else "" 1977 to_disk = self.sql(expression, "to_disk") 1978 to_disk = f" TO DISK {to_disk}" if to_disk else "" 1979 to_volume = self.sql(expression, "to_volume") 1980 to_volume = f" TO VOLUME {to_volume}" if to_volume else "" 1981 return f"{this}{delete}{recompress}{to_disk}{to_volume}" 1982 1983 def mergetreettl_sql(self, expression: exp.MergeTreeTTL) -> str: 1984 where = self.sql(expression, "where") 1985 group = self.sql(expression, "group") 1986 aggregates = self.expressions(expression, key="aggregates") 1987 aggregates = self.seg("SET") + self.seg(aggregates) if aggregates else "" 1988 1989 if not (where or group or aggregates) and len(expression.expressions) == 1: 1990 return f"TTL {self.expressions(expression, flat=True)}" 1991 1992 return f"TTL{self.seg(self.expressions(expression))}{where}{group}{aggregates}" 1993 1994 def transaction_sql(self, expression: exp.Transaction) -> str: 1995 return "BEGIN" 1996 1997 def commit_sql(self, expression: exp.Commit) -> str: 1998 chain = expression.args.get("chain") 1999 if chain is not None: 2000 chain = " AND CHAIN" if chain else " AND NO CHAIN" 2001 2002 return f"COMMIT{chain or ''}" 2003 2004 def rollback_sql(self, expression: exp.Rollback) -> str: 2005 savepoint = expression.args.get("savepoint") 2006 savepoint = f" TO {savepoint}" if savepoint else "" 2007 return f"ROLLBACK{savepoint}" 2008 2009 def altercolumn_sql(self, expression: exp.AlterColumn) -> str: 2010 this = self.sql(expression, "this") 2011 2012 dtype = self.sql(expression, "dtype") 2013 if dtype: 2014 collate = self.sql(expression, "collate") 2015 collate = f" COLLATE {collate}" if collate else "" 2016 using = self.sql(expression, "using") 2017 using = f" USING {using}" if using else "" 2018 return f"ALTER COLUMN {this} TYPE {dtype}{collate}{using}" 2019 2020 default = self.sql(expression, "default") 2021 if default: 2022 return f"ALTER COLUMN {this} SET DEFAULT {default}" 2023 2024 if not expression.args.get("drop"): 2025 self.unsupported("Unsupported ALTER COLUMN syntax") 2026 2027 return f"ALTER COLUMN {this} DROP DEFAULT" 2028 2029 def renametable_sql(self, expression: exp.RenameTable) -> str: 2030 if not self.RENAME_TABLE_WITH_DB: 2031 # Remove db from tables 2032 expression = expression.transform( 2033 lambda n: exp.table_(n.this) if isinstance(n, exp.Table) else n 2034 ) 2035 this = self.sql(expression, "this") 2036 return f"RENAME TO {this}" 2037 2038 def altertable_sql(self, expression: exp.AlterTable) -> str: 2039 actions = expression.args["actions"] 2040 2041 if isinstance(actions[0], exp.ColumnDef): 2042 actions = self.expressions(expression, key="actions", prefix="ADD COLUMN ") 2043 elif isinstance(actions[0], exp.Schema): 2044 actions = self.expressions(expression, key="actions", prefix="ADD COLUMNS ") 2045 elif isinstance(actions[0], exp.Delete): 2046 actions = self.expressions(expression, key="actions", flat=True) 2047 else: 2048 actions = self.expressions(expression, key="actions") 2049 2050 exists = " IF EXISTS" if expression.args.get("exists") else "" 2051 return f"ALTER TABLE{exists} {self.sql(expression, 'this')} {actions}" 2052 2053 def droppartition_sql(self, expression: exp.DropPartition) -> str: 2054 expressions = self.expressions(expression) 2055 exists = " IF EXISTS " if expression.args.get("exists") else " " 2056 return f"DROP{exists}{expressions}" 2057 2058 def addconstraint_sql(self, expression: exp.AddConstraint) -> str: 2059 this = self.sql(expression, "this") 2060 expression_ = self.sql(expression, "expression") 2061 add_constraint = f"ADD CONSTRAINT {this}" if this else "ADD" 2062 2063 enforced = expression.args.get("enforced") 2064 if enforced is not None: 2065 return f"{add_constraint} CHECK ({expression_}){' ENFORCED' if enforced else ''}" 2066 2067 return f"{add_constraint} {expression_}" 2068 2069 def distinct_sql(self, expression: exp.Distinct) -> str: 2070 this = self.expressions(expression, flat=True) 2071 this = f" {this}" if this else "" 2072 2073 on = self.sql(expression, "on") 2074 on = f" ON {on}" if on else "" 2075 return f"DISTINCT{this}{on}" 2076 2077 def ignorenulls_sql(self, expression: exp.IgnoreNulls) -> str: 2078 return f"{self.sql(expression, 'this')} IGNORE NULLS" 2079 2080 def respectnulls_sql(self, expression: exp.RespectNulls) -> str: 2081 return f"{self.sql(expression, 'this')} RESPECT NULLS" 2082 2083 def intdiv_sql(self, expression: exp.IntDiv) -> str: 2084 return self.sql( 2085 exp.Cast( 2086 this=exp.Div(this=expression.this, expression=expression.expression), 2087 to=exp.DataType(this=exp.DataType.Type.INT), 2088 ) 2089 ) 2090 2091 def dpipe_sql(self, expression: exp.DPipe) -> str: 2092 return self.binary(expression, "||") 2093 2094 def div_sql(self, expression: exp.Div) -> str: 2095 return self.binary(expression, "/") 2096 2097 def overlaps_sql(self, expression: exp.Overlaps) -> str: 2098 return self.binary(expression, "OVERLAPS") 2099 2100 def distance_sql(self, expression: exp.Distance) -> str: 2101 return self.binary(expression, "<->") 2102 2103 def dot_sql(self, expression: exp.Dot) -> str: 2104 return f"{self.sql(expression, 'this')}.{self.sql(expression, 'expression')}" 2105 2106 def eq_sql(self, expression: exp.EQ) -> str: 2107 return self.binary(expression, "=") 2108 2109 def escape_sql(self, expression: exp.Escape) -> str: 2110 return self.binary(expression, "ESCAPE") 2111 2112 def glob_sql(self, expression: exp.Glob) -> str: 2113 return self.binary(expression, "GLOB") 2114 2115 def gt_sql(self, expression: exp.GT) -> str: 2116 return self.binary(expression, ">") 2117 2118 def gte_sql(self, expression: exp.GTE) -> str: 2119 return self.binary(expression, ">=") 2120 2121 def ilike_sql(self, expression: exp.ILike) -> str: 2122 return self.binary(expression, "ILIKE") 2123 2124 def ilikeany_sql(self, expression: exp.ILikeAny) -> str: 2125 return self.binary(expression, "ILIKE ANY") 2126 2127 def is_sql(self, expression: exp.Is) -> str: 2128 return self.binary(expression, "IS") 2129 2130 def like_sql(self, expression: exp.Like) -> str: 2131 return self.binary(expression, "LIKE") 2132 2133 def likeany_sql(self, expression: exp.LikeAny) -> str: 2134 return self.binary(expression, "LIKE ANY") 2135 2136 def similarto_sql(self, expression: exp.SimilarTo) -> str: 2137 return self.binary(expression, "SIMILAR TO") 2138 2139 def lt_sql(self, expression: exp.LT) -> str: 2140 return self.binary(expression, "<") 2141 2142 def lte_sql(self, expression: exp.LTE) -> str: 2143 return self.binary(expression, "<=") 2144 2145 def mod_sql(self, expression: exp.Mod) -> str: 2146 return self.binary(expression, "%") 2147 2148 def mul_sql(self, expression: exp.Mul) -> str: 2149 return self.binary(expression, "*") 2150 2151 def neq_sql(self, expression: exp.NEQ) -> str: 2152 return self.binary(expression, "<>") 2153 2154 def nullsafeeq_sql(self, expression: exp.NullSafeEQ) -> str: 2155 return self.binary(expression, "IS NOT DISTINCT FROM") 2156 2157 def nullsafeneq_sql(self, expression: exp.NullSafeNEQ) -> str: 2158 return self.binary(expression, "IS DISTINCT FROM") 2159 2160 def or_sql(self, expression: exp.Or) -> str: 2161 return self.connector_sql(expression, "OR") 2162 2163 def slice_sql(self, expression: exp.Slice) -> str: 2164 return self.binary(expression, ":") 2165 2166 def sub_sql(self, expression: exp.Sub) -> str: 2167 return self.binary(expression, "-") 2168 2169 def trycast_sql(self, expression: exp.TryCast) -> str: 2170 return f"TRY_CAST({self.sql(expression, 'this')} AS {self.sql(expression, 'to')})" 2171 2172 def use_sql(self, expression: exp.Use) -> str: 2173 kind = self.sql(expression, "kind") 2174 kind = f" {kind}" if kind else "" 2175 this = self.sql(expression, "this") 2176 this = f" {this}" if this else "" 2177 return f"USE{kind}{this}" 2178 2179 def binary(self, expression: exp.Binary, op: str) -> str: 2180 op = self.maybe_comment(op, comments=expression.comments) 2181 return f"{self.sql(expression, 'this')} {op} {self.sql(expression, 'expression')}" 2182 2183 def function_fallback_sql(self, expression: exp.Func) -> str: 2184 args = [] 2185 for arg_value in expression.args.values(): 2186 if isinstance(arg_value, list): 2187 for value in arg_value: 2188 args.append(value) 2189 else: 2190 args.append(arg_value) 2191 2192 return self.func(expression.sql_name(), *args) 2193 2194 def func(self, name: str, *args: t.Optional[exp.Expression | str]) -> str: 2195 return f"{self.normalize_func(name)}({self.format_args(*args)})" 2196 2197 def format_args(self, *args: t.Optional[str | exp.Expression]) -> str: 2198 arg_sqls = tuple(self.sql(arg) for arg in args if arg is not None) 2199 if self.pretty and self.text_width(arg_sqls) > self._max_text_width: 2200 return self.indent("\n" + f",\n".join(arg_sqls) + "\n", skip_first=True, skip_last=True) 2201 return ", ".join(arg_sqls) 2202 2203 def text_width(self, args: t.Iterable) -> int: 2204 return sum(len(arg) for arg in args) 2205 2206 def format_time(self, expression: exp.Expression) -> t.Optional[str]: 2207 return format_time(self.sql(expression, "format"), self.time_mapping, self.time_trie) 2208 2209 def expressions( 2210 self, 2211 expression: t.Optional[exp.Expression] = None, 2212 key: t.Optional[str] = None, 2213 sqls: t.Optional[t.List[str]] = None, 2214 flat: bool = False, 2215 indent: bool = True, 2216 sep: str = ", ", 2217 prefix: str = "", 2218 ) -> str: 2219 expressions = expression.args.get(key or "expressions") if expression else sqls 2220 2221 if not expressions: 2222 return "" 2223 2224 if flat: 2225 return sep.join(self.sql(e) for e in expressions) 2226 2227 num_sqls = len(expressions) 2228 2229 # These are calculated once in case we have the leading_comma / pretty option set, correspondingly 2230 pad = " " * self.pad 2231 stripped_sep = sep.strip() 2232 2233 result_sqls = [] 2234 for i, e in enumerate(expressions): 2235 sql = self.sql(e, comment=False) 2236 comments = self.maybe_comment("", e) if isinstance(e, exp.Expression) else "" 2237 2238 if self.pretty: 2239 if self._leading_comma: 2240 result_sqls.append(f"{sep if i > 0 else pad}{prefix}{sql}{comments}") 2241 else: 2242 result_sqls.append( 2243 f"{prefix}{sql}{stripped_sep if i + 1 < num_sqls else ''}{comments}" 2244 ) 2245 else: 2246 result_sqls.append(f"{prefix}{sql}{comments}{sep if i + 1 < num_sqls else ''}") 2247 2248 result_sql = "\n".join(result_sqls) if self.pretty else "".join(result_sqls) 2249 return self.indent(result_sql, skip_first=False) if indent else result_sql 2250 2251 def op_expressions(self, op: str, expression: exp.Expression, flat: bool = False) -> str: 2252 flat = flat or isinstance(expression.parent, exp.Properties) 2253 expressions_sql = self.expressions(expression, flat=flat) 2254 if flat: 2255 return f"{op} {expressions_sql}" 2256 return f"{self.seg(op)}{self.sep() if expressions_sql else ''}{expressions_sql}" 2257 2258 def naked_property(self, expression: exp.Property) -> str: 2259 property_name = exp.Properties.PROPERTY_TO_NAME.get(expression.__class__) 2260 if not property_name: 2261 self.unsupported(f"Unsupported property {expression.__class__.__name__}") 2262 return f"{property_name} {self.sql(expression, 'this')}" 2263 2264 def set_operation(self, expression: exp.Expression, op: str) -> str: 2265 this = self.sql(expression, "this") 2266 op = self.seg(op) 2267 return self.query_modifiers( 2268 expression, f"{this}{op}{self.sep()}{self.sql(expression, 'expression')}" 2269 ) 2270 2271 def tag_sql(self, expression: exp.Tag) -> str: 2272 return f"{expression.args.get('prefix')}{self.sql(expression.this)}{expression.args.get('postfix')}" 2273 2274 def token_sql(self, token_type: TokenType) -> str: 2275 return self.TOKEN_MAPPING.get(token_type, token_type.name) 2276 2277 def userdefinedfunction_sql(self, expression: exp.UserDefinedFunction) -> str: 2278 this = self.sql(expression, "this") 2279 expressions = self.no_identify(self.expressions, expression) 2280 expressions = ( 2281 self.wrap(expressions) if expression.args.get("wrapped") else f" {expressions}" 2282 ) 2283 return f"{this}{expressions}" 2284 2285 def joinhint_sql(self, expression: exp.JoinHint) -> str: 2286 this = self.sql(expression, "this") 2287 expressions = self.expressions(expression, flat=True) 2288 return f"{this}({expressions})" 2289 2290 def kwarg_sql(self, expression: exp.Kwarg) -> str: 2291 return self.binary(expression, "=>") 2292 2293 def when_sql(self, expression: exp.When) -> str: 2294 matched = "MATCHED" if expression.args["matched"] else "NOT MATCHED" 2295 source = " BY SOURCE" if self.MATCHED_BY_SOURCE and expression.args.get("source") else "" 2296 condition = self.sql(expression, "condition") 2297 condition = f" AND {condition}" if condition else "" 2298 2299 then_expression = expression.args.get("then") 2300 if isinstance(then_expression, exp.Insert): 2301 then = f"INSERT {self.sql(then_expression, 'this')}" 2302 if "expression" in then_expression.args: 2303 then += f" VALUES {self.sql(then_expression, 'expression')}" 2304 elif isinstance(then_expression, exp.Update): 2305 if isinstance(then_expression.args.get("expressions"), exp.Star): 2306 then = f"UPDATE {self.sql(then_expression, 'expressions')}" 2307 else: 2308 then = f"UPDATE SET {self.expressions(then_expression, flat=True)}" 2309 else: 2310 then = self.sql(then_expression) 2311 return f"WHEN {matched}{source}{condition} THEN {then}" 2312 2313 def merge_sql(self, expression: exp.Merge) -> str: 2314 this = self.sql(expression, "this") 2315 using = f"USING {self.sql(expression, 'using')}" 2316 on = f"ON {self.sql(expression, 'on')}" 2317 return f"MERGE INTO {this} {using} {on} {self.expressions(expression, sep=' ')}" 2318 2319 def tochar_sql(self, expression: exp.ToChar) -> str: 2320 if expression.args.get("format"): 2321 self.unsupported("Format argument unsupported for TO_CHAR/TO_VARCHAR function") 2322 2323 return self.sql(exp.cast(expression.this, "text")) 2324 2325 2326def cached_generator( 2327 cache: t.Optional[t.Dict[int, str]] = None 2328) -> t.Callable[[exp.Expression], str]: 2329 """Returns a cached generator.""" 2330 cache = {} if cache is None else cache 2331 generator = Generator(normalize=True, identify="safe") 2332 return lambda e: generator.generate(e, cache)
class
Generator:
16class Generator: 17 """ 18 Generator interprets the given syntax tree and produces a SQL string as an output. 19 20 Args: 21 time_mapping (dict): the dictionary of custom time mappings in which the key 22 represents a python time format and the output the target time format 23 time_trie (trie): a trie of the time_mapping keys 24 pretty (bool): if set to True the returned string will be formatted. Default: False. 25 quote_start (str): specifies which starting character to use to delimit quotes. Default: '. 26 quote_end (str): specifies which ending character to use to delimit quotes. Default: '. 27 identifier_start (str): specifies which starting character to use to delimit identifiers. Default: ". 28 identifier_end (str): specifies which ending character to use to delimit identifiers. Default: ". 29 bit_start (str): specifies which starting character to use to delimit bit literals. Default: None. 30 bit_end (str): specifies which ending character to use to delimit bit literals. Default: None. 31 hex_start (str): specifies which starting character to use to delimit hex literals. Default: None. 32 hex_end (str): specifies which ending character to use to delimit hex literals. Default: None. 33 byte_start (str): specifies which starting character to use to delimit byte literals. Default: None. 34 byte_end (str): specifies which ending character to use to delimit byte literals. Default: None. 35 raw_start (str): specifies which starting character to use to delimit raw literals. Default: None. 36 raw_end (str): specifies which ending character to use to delimit raw literals. Default: None. 37 identify (bool | str): 'always': always quote, 'safe': quote identifiers if they don't contain an upcase, True defaults to always. 38 normalize (bool): if set to True all identifiers will lower cased 39 string_escape (str): specifies a string escape character. Default: '. 40 identifier_escape (str): specifies an identifier escape character. Default: ". 41 pad (int): determines padding in a formatted string. Default: 2. 42 indent (int): determines the size of indentation in a formatted string. Default: 4. 43 unnest_column_only (bool): if true unnest table aliases are considered only as column aliases 44 normalize_functions (str): normalize function names, "upper", "lower", or None 45 Default: "upper" 46 alias_post_tablesample (bool): if the table alias comes after tablesample 47 Default: False 48 unsupported_level (ErrorLevel): determines the generator's behavior when it encounters 49 unsupported expressions. Default ErrorLevel.WARN. 50 null_ordering (str): Indicates the default null ordering method to use if not explicitly set. 51 Options are "nulls_are_small", "nulls_are_large", "nulls_are_last". 52 Default: "nulls_are_small" 53 max_unsupported (int): Maximum number of unsupported messages to include in a raised UnsupportedError. 54 This is only relevant if unsupported_level is ErrorLevel.RAISE. 55 Default: 3 56 leading_comma (bool): if the the comma is leading or trailing in select statements 57 Default: False 58 max_text_width: The max number of characters in a segment before creating new lines in pretty mode. 59 The default is on the smaller end because the length only represents a segment and not the true 60 line length. 61 Default: 80 62 comments: Whether or not to preserve comments in the output SQL code. 63 Default: True 64 """ 65 66 TRANSFORMS = { 67 exp.DateAdd: lambda self, e: self.func( 68 "DATE_ADD", e.this, e.expression, exp.Literal.string(e.text("unit")) 69 ), 70 exp.TsOrDsAdd: lambda self, e: self.func( 71 "TS_OR_DS_ADD", e.this, e.expression, exp.Literal.string(e.text("unit")) 72 ), 73 exp.VarMap: lambda self, e: self.func("MAP", e.args["keys"], e.args["values"]), 74 exp.CharacterSetProperty: lambda self, e: f"{'DEFAULT ' if e.args.get('default') else ''}CHARACTER SET={self.sql(e, 'this')}", 75 exp.ExecuteAsProperty: lambda self, e: self.naked_property(e), 76 exp.ExternalProperty: lambda self, e: "EXTERNAL", 77 exp.LanguageProperty: lambda self, e: self.naked_property(e), 78 exp.LocationProperty: lambda self, e: self.naked_property(e), 79 exp.LogProperty: lambda self, e: f"{'NO ' if e.args.get('no') else ''}LOG", 80 exp.MaterializedProperty: lambda self, e: "MATERIALIZED", 81 exp.NoPrimaryIndexProperty: lambda self, e: "NO PRIMARY INDEX", 82 exp.OnCommitProperty: lambda self, e: f"ON COMMIT {'DELETE' if e.args.get('delete') else 'PRESERVE'} ROWS", 83 exp.ReturnsProperty: lambda self, e: self.naked_property(e), 84 exp.SetProperty: lambda self, e: f"{'MULTI' if e.args.get('multi') else ''}SET", 85 exp.SettingsProperty: lambda self, e: f"SETTINGS{self.seg('')}{(self.expressions(e))}", 86 exp.SqlSecurityProperty: lambda self, e: f"SQL SECURITY {'DEFINER' if e.args.get('definer') else 'INVOKER'}", 87 exp.TemporaryProperty: lambda self, e: f"TEMPORARY", 88 exp.TransientProperty: lambda self, e: "TRANSIENT", 89 exp.StabilityProperty: lambda self, e: e.name, 90 exp.VolatileProperty: lambda self, e: "VOLATILE", 91 exp.WithJournalTableProperty: lambda self, e: f"WITH JOURNAL TABLE={self.sql(e, 'this')}", 92 exp.CaseSpecificColumnConstraint: lambda self, e: f"{'NOT ' if e.args.get('not_') else ''}CASESPECIFIC", 93 exp.CharacterSetColumnConstraint: lambda self, e: f"CHARACTER SET {self.sql(e, 'this')}", 94 exp.DateFormatColumnConstraint: lambda self, e: f"FORMAT {self.sql(e, 'this')}", 95 exp.OnUpdateColumnConstraint: lambda self, e: f"ON UPDATE {self.sql(e, 'this')}", 96 exp.UppercaseColumnConstraint: lambda self, e: f"UPPERCASE", 97 exp.TitleColumnConstraint: lambda self, e: f"TITLE {self.sql(e, 'this')}", 98 exp.PathColumnConstraint: lambda self, e: f"PATH {self.sql(e, 'this')}", 99 exp.CheckColumnConstraint: lambda self, e: f"CHECK ({self.sql(e, 'this')})", 100 exp.CommentColumnConstraint: lambda self, e: f"COMMENT {self.sql(e, 'this')}", 101 exp.CollateColumnConstraint: lambda self, e: f"COLLATE {self.sql(e, 'this')}", 102 exp.EncodeColumnConstraint: lambda self, e: f"ENCODE {self.sql(e, 'this')}", 103 exp.DefaultColumnConstraint: lambda self, e: f"DEFAULT {self.sql(e, 'this')}", 104 exp.InlineLengthColumnConstraint: lambda self, e: f"INLINE LENGTH {self.sql(e, 'this')}", 105 } 106 107 # Whether or not null ordering is supported in order by 108 NULL_ORDERING_SUPPORTED = True 109 110 # Whether or not locking reads (i.e. SELECT ... FOR UPDATE/SHARE) are supported 111 LOCKING_READS_SUPPORTED = False 112 113 # Always do union distinct or union all 114 EXPLICIT_UNION = False 115 116 # Wrap derived values in parens, usually standard but spark doesn't support it 117 WRAP_DERIVED_VALUES = True 118 119 # Whether or not create function uses an AS before the RETURN 120 CREATE_FUNCTION_RETURN_AS = True 121 122 # Whether or not MERGE ... WHEN MATCHED BY SOURCE is allowed 123 MATCHED_BY_SOURCE = True 124 125 # Whether or not the INTERVAL expression works only with values like '1 day' 126 SINGLE_STRING_INTERVAL = False 127 128 # Whether or not the plural form of date parts like day (i.e. "days") is supported in INTERVALs 129 INTERVAL_ALLOWS_PLURAL_FORM = True 130 131 # Whether or not the TABLESAMPLE clause supports a method name, like BERNOULLI 132 TABLESAMPLE_WITH_METHOD = True 133 134 # Whether or not to treat the number in TABLESAMPLE (50) as a percentage 135 TABLESAMPLE_SIZE_IS_PERCENT = False 136 137 # Whether or not limit and fetch are supported (possible values: "ALL", "LIMIT", "FETCH") 138 LIMIT_FETCH = "ALL" 139 140 # Whether a table is allowed to be renamed with a db 141 RENAME_TABLE_WITH_DB = True 142 143 # The separator for grouping sets and rollups 144 GROUPINGS_SEP = "," 145 146 # The string used for creating index on a table 147 INDEX_ON = "ON" 148 149 TYPE_MAPPING = { 150 exp.DataType.Type.NCHAR: "CHAR", 151 exp.DataType.Type.NVARCHAR: "VARCHAR", 152 exp.DataType.Type.MEDIUMTEXT: "TEXT", 153 exp.DataType.Type.LONGTEXT: "TEXT", 154 exp.DataType.Type.MEDIUMBLOB: "BLOB", 155 exp.DataType.Type.LONGBLOB: "BLOB", 156 exp.DataType.Type.INET: "INET", 157 } 158 159 STAR_MAPPING = { 160 "except": "EXCEPT", 161 "replace": "REPLACE", 162 } 163 164 TIME_PART_SINGULARS = { 165 "microseconds": "microsecond", 166 "seconds": "second", 167 "minutes": "minute", 168 "hours": "hour", 169 "days": "day", 170 "weeks": "week", 171 "months": "month", 172 "quarters": "quarter", 173 "years": "year", 174 } 175 176 TOKEN_MAPPING: t.Dict[TokenType, str] = {} 177 178 STRUCT_DELIMITER = ("<", ">") 179 180 PARAMETER_TOKEN = "@" 181 182 PROPERTIES_LOCATION = { 183 exp.AlgorithmProperty: exp.Properties.Location.POST_CREATE, 184 exp.AutoIncrementProperty: exp.Properties.Location.POST_SCHEMA, 185 exp.BlockCompressionProperty: exp.Properties.Location.POST_NAME, 186 exp.CharacterSetProperty: exp.Properties.Location.POST_SCHEMA, 187 exp.ChecksumProperty: exp.Properties.Location.POST_NAME, 188 exp.CollateProperty: exp.Properties.Location.POST_SCHEMA, 189 exp.Cluster: exp.Properties.Location.POST_SCHEMA, 190 exp.DataBlocksizeProperty: exp.Properties.Location.POST_NAME, 191 exp.DefinerProperty: exp.Properties.Location.POST_CREATE, 192 exp.DistKeyProperty: exp.Properties.Location.POST_SCHEMA, 193 exp.DistStyleProperty: exp.Properties.Location.POST_SCHEMA, 194 exp.EngineProperty: exp.Properties.Location.POST_SCHEMA, 195 exp.ExecuteAsProperty: exp.Properties.Location.POST_SCHEMA, 196 exp.ExternalProperty: exp.Properties.Location.POST_CREATE, 197 exp.FallbackProperty: exp.Properties.Location.POST_NAME, 198 exp.FileFormatProperty: exp.Properties.Location.POST_WITH, 199 exp.FreespaceProperty: exp.Properties.Location.POST_NAME, 200 exp.IsolatedLoadingProperty: exp.Properties.Location.POST_NAME, 201 exp.JournalProperty: exp.Properties.Location.POST_NAME, 202 exp.LanguageProperty: exp.Properties.Location.POST_SCHEMA, 203 exp.LikeProperty: exp.Properties.Location.POST_SCHEMA, 204 exp.LocationProperty: exp.Properties.Location.POST_SCHEMA, 205 exp.LockingProperty: exp.Properties.Location.POST_ALIAS, 206 exp.LogProperty: exp.Properties.Location.POST_NAME, 207 exp.MaterializedProperty: exp.Properties.Location.POST_CREATE, 208 exp.MergeBlockRatioProperty: exp.Properties.Location.POST_NAME, 209 exp.NoPrimaryIndexProperty: exp.Properties.Location.POST_EXPRESSION, 210 exp.OnCommitProperty: exp.Properties.Location.POST_EXPRESSION, 211 exp.Order: exp.Properties.Location.POST_SCHEMA, 212 exp.PartitionedByProperty: exp.Properties.Location.POST_WITH, 213 exp.PrimaryKey: exp.Properties.Location.POST_SCHEMA, 214 exp.Property: exp.Properties.Location.POST_WITH, 215 exp.ReturnsProperty: exp.Properties.Location.POST_SCHEMA, 216 exp.RowFormatProperty: exp.Properties.Location.POST_SCHEMA, 217 exp.RowFormatDelimitedProperty: exp.Properties.Location.POST_SCHEMA, 218 exp.RowFormatSerdeProperty: exp.Properties.Location.POST_SCHEMA, 219 exp.SchemaCommentProperty: exp.Properties.Location.POST_SCHEMA, 220 exp.SerdeProperties: exp.Properties.Location.POST_SCHEMA, 221 exp.Set: exp.Properties.Location.POST_SCHEMA, 222 exp.SettingsProperty: exp.Properties.Location.POST_SCHEMA, 223 exp.SetProperty: exp.Properties.Location.POST_CREATE, 224 exp.SortKeyProperty: exp.Properties.Location.POST_SCHEMA, 225 exp.SqlSecurityProperty: exp.Properties.Location.POST_CREATE, 226 exp.StabilityProperty: exp.Properties.Location.POST_SCHEMA, 227 exp.TemporaryProperty: exp.Properties.Location.POST_CREATE, 228 exp.TransientProperty: exp.Properties.Location.POST_CREATE, 229 exp.MergeTreeTTL: exp.Properties.Location.POST_SCHEMA, 230 exp.VolatileProperty: exp.Properties.Location.POST_CREATE, 231 exp.WithDataProperty: exp.Properties.Location.POST_EXPRESSION, 232 exp.WithJournalTableProperty: exp.Properties.Location.POST_NAME, 233 } 234 235 JOIN_HINTS = True 236 TABLE_HINTS = True 237 238 RESERVED_KEYWORDS: t.Set[str] = set() 239 WITH_SEPARATED_COMMENTS = (exp.Select, exp.From, exp.Where, exp.With) 240 UNWRAPPED_INTERVAL_VALUES = (exp.Column, exp.Literal, exp.Neg, exp.Paren) 241 242 SENTINEL_LINE_BREAK = "__SQLGLOT__LB__" 243 244 __slots__ = ( 245 "time_mapping", 246 "time_trie", 247 "pretty", 248 "quote_start", 249 "quote_end", 250 "identifier_start", 251 "identifier_end", 252 "bit_start", 253 "bit_end", 254 "hex_start", 255 "hex_end", 256 "byte_start", 257 "byte_end", 258 "raw_start", 259 "raw_end", 260 "identify", 261 "normalize", 262 "string_escape", 263 "identifier_escape", 264 "pad", 265 "index_offset", 266 "unnest_column_only", 267 "alias_post_tablesample", 268 "normalize_functions", 269 "unsupported_level", 270 "unsupported_messages", 271 "null_ordering", 272 "max_unsupported", 273 "_indent", 274 "_escaped_quote_end", 275 "_escaped_identifier_end", 276 "_leading_comma", 277 "_max_text_width", 278 "_comments", 279 "_cache", 280 ) 281 282 def __init__( 283 self, 284 time_mapping=None, 285 time_trie=None, 286 pretty=None, 287 quote_start=None, 288 quote_end=None, 289 identifier_start=None, 290 identifier_end=None, 291 bit_start=None, 292 bit_end=None, 293 hex_start=None, 294 hex_end=None, 295 byte_start=None, 296 byte_end=None, 297 raw_start=None, 298 raw_end=None, 299 identify=False, 300 normalize=False, 301 string_escape=None, 302 identifier_escape=None, 303 pad=2, 304 indent=2, 305 index_offset=0, 306 unnest_column_only=False, 307 alias_post_tablesample=False, 308 normalize_functions="upper", 309 unsupported_level=ErrorLevel.WARN, 310 null_ordering=None, 311 max_unsupported=3, 312 leading_comma=False, 313 max_text_width=80, 314 comments=True, 315 ): 316 import sqlglot 317 318 self.time_mapping = time_mapping or {} 319 self.time_trie = time_trie 320 self.pretty = pretty if pretty is not None else sqlglot.pretty 321 self.quote_start = quote_start or "'" 322 self.quote_end = quote_end or "'" 323 self.identifier_start = identifier_start or '"' 324 self.identifier_end = identifier_end or '"' 325 self.bit_start = bit_start 326 self.bit_end = bit_end 327 self.hex_start = hex_start 328 self.hex_end = hex_end 329 self.byte_start = byte_start 330 self.byte_end = byte_end 331 self.raw_start = raw_start 332 self.raw_end = raw_end 333 self.identify = identify 334 self.normalize = normalize 335 self.string_escape = string_escape or "'" 336 self.identifier_escape = identifier_escape or '"' 337 self.pad = pad 338 self.index_offset = index_offset 339 self.unnest_column_only = unnest_column_only 340 self.alias_post_tablesample = alias_post_tablesample 341 self.normalize_functions = normalize_functions 342 self.unsupported_level = unsupported_level 343 self.unsupported_messages = [] 344 self.max_unsupported = max_unsupported 345 self.null_ordering = null_ordering 346 self._indent = indent 347 self._escaped_quote_end = self.string_escape + self.quote_end 348 self._escaped_identifier_end = self.identifier_escape + self.identifier_end 349 self._leading_comma = leading_comma 350 self._max_text_width = max_text_width 351 self._comments = comments 352 self._cache = None 353 354 def generate( 355 self, 356 expression: t.Optional[exp.Expression], 357 cache: t.Optional[t.Dict[int, str]] = None, 358 ) -> str: 359 """ 360 Generates a SQL string by interpreting the given syntax tree. 361 362 Args 363 expression: the syntax tree. 364 cache: an optional sql string cache. this leverages the hash of an expression which is slow, so only use this if you set _hash on each node. 365 366 Returns 367 the SQL string. 368 """ 369 if cache is not None: 370 self._cache = cache 371 self.unsupported_messages = [] 372 sql = self.sql(expression).strip() 373 self._cache = None 374 375 if self.unsupported_level == ErrorLevel.IGNORE: 376 return sql 377 378 if self.unsupported_level == ErrorLevel.WARN: 379 for msg in self.unsupported_messages: 380 logger.warning(msg) 381 elif self.unsupported_level == ErrorLevel.RAISE and self.unsupported_messages: 382 raise UnsupportedError(concat_messages(self.unsupported_messages, self.max_unsupported)) 383 384 if self.pretty: 385 sql = sql.replace(self.SENTINEL_LINE_BREAK, "\n") 386 return sql 387 388 def unsupported(self, message: str) -> None: 389 if self.unsupported_level == ErrorLevel.IMMEDIATE: 390 raise UnsupportedError(message) 391 self.unsupported_messages.append(message) 392 393 def sep(self, sep: str = " ") -> str: 394 return f"{sep.strip()}\n" if self.pretty else sep 395 396 def seg(self, sql: str, sep: str = " ") -> str: 397 return f"{self.sep(sep)}{sql}" 398 399 def pad_comment(self, comment: str) -> str: 400 comment = " " + comment if comment[0].strip() else comment 401 comment = comment + " " if comment[-1].strip() else comment 402 return comment 403 404 def maybe_comment( 405 self, 406 sql: str, 407 expression: t.Optional[exp.Expression] = None, 408 comments: t.Optional[t.List[str]] = None, 409 ) -> str: 410 comments = ((expression and expression.comments) if comments is None else comments) if self._comments else None # type: ignore 411 412 if not comments or isinstance(expression, exp.Binary): 413 return sql 414 415 sep = "\n" if self.pretty else " " 416 comments_sql = sep.join( 417 f"/*{self.pad_comment(comment)}*/" for comment in comments if comment 418 ) 419 420 if not comments_sql: 421 return sql 422 423 if isinstance(expression, self.WITH_SEPARATED_COMMENTS): 424 return ( 425 f"{self.sep()}{comments_sql}{sql}" 426 if sql[0].isspace() 427 else f"{comments_sql}{self.sep()}{sql}" 428 ) 429 430 return f"{sql} {comments_sql}" 431 432 def wrap(self, expression: exp.Expression | str) -> str: 433 this_sql = self.indent( 434 self.sql(expression) 435 if isinstance(expression, (exp.Select, exp.Union)) 436 else self.sql(expression, "this"), 437 level=1, 438 pad=0, 439 ) 440 return f"({self.sep('')}{this_sql}{self.seg(')', sep='')}" 441 442 def no_identify(self, func: t.Callable[..., str], *args, **kwargs) -> str: 443 original = self.identify 444 self.identify = False 445 result = func(*args, **kwargs) 446 self.identify = original 447 return result 448 449 def normalize_func(self, name: str) -> str: 450 if self.normalize_functions == "upper": 451 return name.upper() 452 if self.normalize_functions == "lower": 453 return name.lower() 454 return name 455 456 def indent( 457 self, 458 sql: str, 459 level: int = 0, 460 pad: t.Optional[int] = None, 461 skip_first: bool = False, 462 skip_last: bool = False, 463 ) -> str: 464 if not self.pretty: 465 return sql 466 467 pad = self.pad if pad is None else pad 468 lines = sql.split("\n") 469 470 return "\n".join( 471 line 472 if (skip_first and i == 0) or (skip_last and i == len(lines) - 1) 473 else f"{' ' * (level * self._indent + pad)}{line}" 474 for i, line in enumerate(lines) 475 ) 476 477 def sql( 478 self, 479 expression: t.Optional[str | exp.Expression], 480 key: t.Optional[str] = None, 481 comment: bool = True, 482 ) -> str: 483 if not expression: 484 return "" 485 486 if isinstance(expression, str): 487 return expression 488 489 if key: 490 return self.sql(expression.args.get(key)) 491 492 if self._cache is not None: 493 expression_id = hash(expression) 494 495 if expression_id in self._cache: 496 return self._cache[expression_id] 497 498 transform = self.TRANSFORMS.get(expression.__class__) 499 500 if callable(transform): 501 sql = transform(self, expression) 502 elif transform: 503 sql = transform 504 elif isinstance(expression, exp.Expression): 505 exp_handler_name = f"{expression.key}_sql" 506 507 if hasattr(self, exp_handler_name): 508 sql = getattr(self, exp_handler_name)(expression) 509 elif isinstance(expression, exp.Func): 510 sql = self.function_fallback_sql(expression) 511 elif isinstance(expression, exp.Property): 512 sql = self.property_sql(expression) 513 else: 514 raise ValueError(f"Unsupported expression type {expression.__class__.__name__}") 515 else: 516 raise ValueError(f"Expected an Expression. Received {type(expression)}: {expression}") 517 518 sql = self.maybe_comment(sql, expression) if self._comments and comment else sql 519 520 if self._cache is not None: 521 self._cache[expression_id] = sql 522 return sql 523 524 def uncache_sql(self, expression: exp.Uncache) -> str: 525 table = self.sql(expression, "this") 526 exists_sql = " IF EXISTS" if expression.args.get("exists") else "" 527 return f"UNCACHE TABLE{exists_sql} {table}" 528 529 def cache_sql(self, expression: exp.Cache) -> str: 530 lazy = " LAZY" if expression.args.get("lazy") else "" 531 table = self.sql(expression, "this") 532 options = expression.args.get("options") 533 options = f" OPTIONS({self.sql(options[0])} = {self.sql(options[1])})" if options else "" 534 sql = self.sql(expression, "expression") 535 sql = f" AS{self.sep()}{sql}" if sql else "" 536 sql = f"CACHE{lazy} TABLE {table}{options}{sql}" 537 return self.prepend_ctes(expression, sql) 538 539 def characterset_sql(self, expression: exp.CharacterSet) -> str: 540 if isinstance(expression.parent, exp.Cast): 541 return f"CHAR CHARACTER SET {self.sql(expression, 'this')}" 542 default = "DEFAULT " if expression.args.get("default") else "" 543 return f"{default}CHARACTER SET={self.sql(expression, 'this')}" 544 545 def column_sql(self, expression: exp.Column) -> str: 546 return ".".join( 547 self.sql(part) 548 for part in ( 549 expression.args.get("catalog"), 550 expression.args.get("db"), 551 expression.args.get("table"), 552 expression.args.get("this"), 553 ) 554 if part 555 ) 556 557 def columnposition_sql(self, expression: exp.ColumnPosition) -> str: 558 this = self.sql(expression, "this") 559 this = f" {this}" if this else "" 560 position = self.sql(expression, "position") 561 return f"{position}{this}" 562 563 def columndef_sql(self, expression: exp.ColumnDef, sep: str = " ") -> str: 564 column = self.sql(expression, "this") 565 kind = self.sql(expression, "kind") 566 constraints = self.expressions(expression, key="constraints", sep=" ", flat=True) 567 exists = "IF NOT EXISTS " if expression.args.get("exists") else "" 568 kind = f"{sep}{kind}" if kind else "" 569 constraints = f" {constraints}" if constraints else "" 570 position = self.sql(expression, "position") 571 position = f" {position}" if position else "" 572 573 return f"{exists}{column}{kind}{constraints}{position}" 574 575 def columnconstraint_sql(self, expression: exp.ColumnConstraint) -> str: 576 this = self.sql(expression, "this") 577 kind_sql = self.sql(expression, "kind").strip() 578 return f"CONSTRAINT {this} {kind_sql}" if this else kind_sql 579 580 def autoincrementcolumnconstraint_sql(self, _) -> str: 581 return self.token_sql(TokenType.AUTO_INCREMENT) 582 583 def compresscolumnconstraint_sql(self, expression: exp.CompressColumnConstraint) -> str: 584 if isinstance(expression.this, list): 585 this = self.wrap(self.expressions(expression, key="this", flat=True)) 586 else: 587 this = self.sql(expression, "this") 588 589 return f"COMPRESS {this}" 590 591 def generatedasidentitycolumnconstraint_sql( 592 self, expression: exp.GeneratedAsIdentityColumnConstraint 593 ) -> str: 594 this = "" 595 if expression.this is not None: 596 on_null = "ON NULL " if expression.args.get("on_null") else "" 597 this = " ALWAYS " if expression.this else f" BY DEFAULT {on_null}" 598 599 start = expression.args.get("start") 600 start = f"START WITH {start}" if start else "" 601 increment = expression.args.get("increment") 602 increment = f" INCREMENT BY {increment}" if increment else "" 603 minvalue = expression.args.get("minvalue") 604 minvalue = f" MINVALUE {minvalue}" if minvalue else "" 605 maxvalue = expression.args.get("maxvalue") 606 maxvalue = f" MAXVALUE {maxvalue}" if maxvalue else "" 607 cycle = expression.args.get("cycle") 608 cycle_sql = "" 609 610 if cycle is not None: 611 cycle_sql = f"{' NO' if not cycle else ''} CYCLE" 612 cycle_sql = cycle_sql.strip() if not start and not increment else cycle_sql 613 614 sequence_opts = "" 615 if start or increment or cycle_sql: 616 sequence_opts = f"{start}{increment}{minvalue}{maxvalue}{cycle_sql}" 617 sequence_opts = f" ({sequence_opts.strip()})" 618 619 expr = self.sql(expression, "expression") 620 expr = f"({expr})" if expr else "IDENTITY" 621 622 return f"GENERATED{this}AS {expr}{sequence_opts}" 623 624 def notnullcolumnconstraint_sql(self, expression: exp.NotNullColumnConstraint) -> str: 625 return f"{'' if expression.args.get('allow_null') else 'NOT '}NULL" 626 627 def primarykeycolumnconstraint_sql(self, expression: exp.PrimaryKeyColumnConstraint) -> str: 628 desc = expression.args.get("desc") 629 if desc is not None: 630 return f"PRIMARY KEY{' DESC' if desc else ' ASC'}" 631 return f"PRIMARY KEY" 632 633 def uniquecolumnconstraint_sql(self, expression: exp.UniqueColumnConstraint) -> str: 634 this = self.sql(expression, "this") 635 this = f" {this}" if this else "" 636 return f"UNIQUE{this}" 637 638 def create_sql(self, expression: exp.Create) -> str: 639 kind = self.sql(expression, "kind").upper() 640 properties = expression.args.get("properties") 641 properties_exp = expression.copy() 642 properties_locs = self.locate_properties(properties) if properties else {} 643 if properties_locs.get(exp.Properties.Location.POST_SCHEMA) or properties_locs.get( 644 exp.Properties.Location.POST_WITH 645 ): 646 properties_exp.set( 647 "properties", 648 exp.Properties( 649 expressions=[ 650 *properties_locs[exp.Properties.Location.POST_SCHEMA], 651 *properties_locs[exp.Properties.Location.POST_WITH], 652 ] 653 ), 654 ) 655 if kind == "TABLE" and properties_locs.get(exp.Properties.Location.POST_NAME): 656 this_name = self.sql(expression.this, "this") 657 this_properties = self.properties( 658 exp.Properties(expressions=properties_locs[exp.Properties.Location.POST_NAME]), 659 wrapped=False, 660 ) 661 this_schema = f"({self.expressions(expression.this)})" 662 this = f"{this_name}, {this_properties} {this_schema}" 663 properties_sql = "" 664 else: 665 this = self.sql(expression, "this") 666 properties_sql = self.sql(properties_exp, "properties") 667 begin = " BEGIN" if expression.args.get("begin") else "" 668 expression_sql = self.sql(expression, "expression") 669 if expression_sql: 670 expression_sql = f"{begin}{self.sep()}{expression_sql}" 671 672 if self.CREATE_FUNCTION_RETURN_AS or not isinstance(expression.expression, exp.Return): 673 if properties_locs.get(exp.Properties.Location.POST_ALIAS): 674 postalias_props_sql = self.properties( 675 exp.Properties( 676 expressions=properties_locs[exp.Properties.Location.POST_ALIAS] 677 ), 678 wrapped=False, 679 ) 680 expression_sql = f" AS {postalias_props_sql}{expression_sql}" 681 else: 682 expression_sql = f" AS{expression_sql}" 683 684 postindex_props_sql = "" 685 if properties_locs.get(exp.Properties.Location.POST_INDEX): 686 postindex_props_sql = self.properties( 687 exp.Properties(expressions=properties_locs[exp.Properties.Location.POST_INDEX]), 688 wrapped=False, 689 prefix=" ", 690 ) 691 692 indexes = self.expressions(expression, key="indexes", indent=False, sep=" ") 693 indexes = f" {indexes}" if indexes else "" 694 index_sql = indexes + postindex_props_sql 695 696 replace = " OR REPLACE" if expression.args.get("replace") else "" 697 unique = " UNIQUE" if expression.args.get("unique") else "" 698 699 postcreate_props_sql = "" 700 if properties_locs.get(exp.Properties.Location.POST_CREATE): 701 postcreate_props_sql = self.properties( 702 exp.Properties(expressions=properties_locs[exp.Properties.Location.POST_CREATE]), 703 sep=" ", 704 prefix=" ", 705 wrapped=False, 706 ) 707 708 modifiers = "".join((replace, unique, postcreate_props_sql)) 709 710 postexpression_props_sql = "" 711 if properties_locs.get(exp.Properties.Location.POST_EXPRESSION): 712 postexpression_props_sql = self.properties( 713 exp.Properties( 714 expressions=properties_locs[exp.Properties.Location.POST_EXPRESSION] 715 ), 716 sep=" ", 717 prefix=" ", 718 wrapped=False, 719 ) 720 721 exists_sql = " IF NOT EXISTS" if expression.args.get("exists") else "" 722 no_schema_binding = ( 723 " WITH NO SCHEMA BINDING" if expression.args.get("no_schema_binding") else "" 724 ) 725 726 clone = self.sql(expression, "clone") 727 clone = f" {clone}" if clone else "" 728 729 expression_sql = f"CREATE{modifiers} {kind}{exists_sql} {this}{properties_sql}{expression_sql}{postexpression_props_sql}{index_sql}{no_schema_binding}{clone}" 730 return self.prepend_ctes(expression, expression_sql) 731 732 def clone_sql(self, expression: exp.Clone) -> str: 733 this = self.sql(expression, "this") 734 when = self.sql(expression, "when") 735 736 if when: 737 kind = self.sql(expression, "kind") 738 expr = self.sql(expression, "expression") 739 return f"CLONE {this} {when} ({kind} => {expr})" 740 741 return f"CLONE {this}" 742 743 def describe_sql(self, expression: exp.Describe) -> str: 744 return f"DESCRIBE {self.sql(expression, 'this')}" 745 746 def prepend_ctes(self, expression: exp.Expression, sql: str) -> str: 747 with_ = self.sql(expression, "with") 748 if with_: 749 sql = f"{with_}{self.sep()}{sql}" 750 return sql 751 752 def with_sql(self, expression: exp.With) -> str: 753 sql = self.expressions(expression, flat=True) 754 recursive = "RECURSIVE " if expression.args.get("recursive") else "" 755 756 return f"WITH {recursive}{sql}" 757 758 def cte_sql(self, expression: exp.CTE) -> str: 759 alias = self.sql(expression, "alias") 760 return f"{alias} AS {self.wrap(expression)}" 761 762 def tablealias_sql(self, expression: exp.TableAlias) -> str: 763 alias = self.sql(expression, "this") 764 columns = self.expressions(expression, key="columns", flat=True) 765 columns = f"({columns})" if columns else "" 766 return f"{alias}{columns}" 767 768 def bitstring_sql(self, expression: exp.BitString) -> str: 769 this = self.sql(expression, "this") 770 if self.bit_start: 771 return f"{self.bit_start}{this}{self.bit_end}" 772 return f"{int(this, 2)}" 773 774 def hexstring_sql(self, expression: exp.HexString) -> str: 775 this = self.sql(expression, "this") 776 if self.hex_start: 777 return f"{self.hex_start}{this}{self.hex_end}" 778 return f"{int(this, 16)}" 779 780 def bytestring_sql(self, expression: exp.ByteString) -> str: 781 this = self.sql(expression, "this") 782 if self.byte_start: 783 return f"{self.byte_start}{this}{self.byte_end}" 784 return this 785 786 def rawstring_sql(self, expression: exp.RawString) -> str: 787 if self.raw_start: 788 return f"{self.raw_start}{expression.name}{self.raw_end}" 789 return self.sql(exp.Literal.string(expression.name.replace("\\", "\\\\"))) 790 791 def datatypesize_sql(self, expression: exp.DataTypeSize) -> str: 792 this = self.sql(expression, "this") 793 specifier = self.sql(expression, "expression") 794 specifier = f" {specifier}" if specifier else "" 795 return f"{this}{specifier}" 796 797 def datatype_sql(self, expression: exp.DataType) -> str: 798 type_value = expression.this 799 type_sql = self.TYPE_MAPPING.get(type_value, type_value.value) 800 nested = "" 801 interior = self.expressions(expression, flat=True) 802 values = "" 803 if interior: 804 if expression.args.get("nested"): 805 nested = f"{self.STRUCT_DELIMITER[0]}{interior}{self.STRUCT_DELIMITER[1]}" 806 if expression.args.get("values") is not None: 807 delimiters = ("[", "]") if type_value == exp.DataType.Type.ARRAY else ("(", ")") 808 values = self.expressions(expression, key="values", flat=True) 809 values = f"{delimiters[0]}{values}{delimiters[1]}" 810 else: 811 nested = f"({interior})" 812 813 return f"{type_sql}{nested}{values}" 814 815 def directory_sql(self, expression: exp.Directory) -> str: 816 local = "LOCAL " if expression.args.get("local") else "" 817 row_format = self.sql(expression, "row_format") 818 row_format = f" {row_format}" if row_format else "" 819 return f"{local}DIRECTORY {self.sql(expression, 'this')}{row_format}" 820 821 def delete_sql(self, expression: exp.Delete) -> str: 822 this = self.sql(expression, "this") 823 this = f" FROM {this}" if this else "" 824 using_sql = ( 825 f" USING {self.expressions(expression, key='using', sep=', USING ')}" 826 if expression.args.get("using") 827 else "" 828 ) 829 where_sql = self.sql(expression, "where") 830 returning = self.sql(expression, "returning") 831 sql = f"DELETE{this}{using_sql}{where_sql}{returning}" 832 return self.prepend_ctes(expression, sql) 833 834 def drop_sql(self, expression: exp.Drop) -> str: 835 this = self.sql(expression, "this") 836 kind = expression.args["kind"] 837 exists_sql = " IF EXISTS " if expression.args.get("exists") else " " 838 temporary = " TEMPORARY" if expression.args.get("temporary") else "" 839 materialized = " MATERIALIZED" if expression.args.get("materialized") else "" 840 cascade = " CASCADE" if expression.args.get("cascade") else "" 841 constraints = " CONSTRAINTS" if expression.args.get("constraints") else "" 842 purge = " PURGE" if expression.args.get("purge") else "" 843 return ( 844 f"DROP{temporary}{materialized} {kind}{exists_sql}{this}{cascade}{constraints}{purge}" 845 ) 846 847 def except_sql(self, expression: exp.Except) -> str: 848 return self.prepend_ctes( 849 expression, 850 self.set_operation(expression, self.except_op(expression)), 851 ) 852 853 def except_op(self, expression: exp.Except) -> str: 854 return f"EXCEPT{'' if expression.args.get('distinct') else ' ALL'}" 855 856 def fetch_sql(self, expression: exp.Fetch) -> str: 857 direction = expression.args.get("direction") 858 direction = f" {direction.upper()}" if direction else "" 859 count = expression.args.get("count") 860 count = f" {count}" if count else "" 861 if expression.args.get("percent"): 862 count = f"{count} PERCENT" 863 with_ties_or_only = "WITH TIES" if expression.args.get("with_ties") else "ONLY" 864 return f"{self.seg('FETCH')}{direction}{count} ROWS {with_ties_or_only}" 865 866 def filter_sql(self, expression: exp.Filter) -> str: 867 this = self.sql(expression, "this") 868 where = self.sql(expression, "expression")[1:] # where has a leading space 869 return f"{this} FILTER({where})" 870 871 def hint_sql(self, expression: exp.Hint) -> str: 872 if self.sql(expression, "this"): 873 self.unsupported("Hints are not supported") 874 return "" 875 876 def index_sql(self, expression: exp.Index) -> str: 877 unique = "UNIQUE " if expression.args.get("unique") else "" 878 primary = "PRIMARY " if expression.args.get("primary") else "" 879 amp = "AMP " if expression.args.get("amp") else "" 880 name = f"{expression.name} " if expression.name else "" 881 table = self.sql(expression, "table") 882 table = f"{self.INDEX_ON} {table} " if table else "" 883 index = "INDEX " if not table else "" 884 columns = self.expressions(expression, key="columns", flat=True) 885 partition_by = self.expressions(expression, key="partition_by", flat=True) 886 partition_by = f" PARTITION BY {partition_by}" if partition_by else "" 887 return f"{unique}{primary}{amp}{index}{name}{table}({columns}){partition_by}" 888 889 def identifier_sql(self, expression: exp.Identifier) -> str: 890 text = expression.name 891 lower = text.lower() 892 text = lower if self.normalize and not expression.quoted else text 893 text = text.replace(self.identifier_end, self._escaped_identifier_end) 894 if ( 895 expression.quoted 896 or should_identify(text, self.identify) 897 or lower in self.RESERVED_KEYWORDS 898 ): 899 text = f"{self.identifier_start}{text}{self.identifier_end}" 900 return text 901 902 def inputoutputformat_sql(self, expression: exp.InputOutputFormat) -> str: 903 input_format = self.sql(expression, "input_format") 904 input_format = f"INPUTFORMAT {input_format}" if input_format else "" 905 output_format = self.sql(expression, "output_format") 906 output_format = f"OUTPUTFORMAT {output_format}" if output_format else "" 907 return self.sep().join((input_format, output_format)) 908 909 def national_sql(self, expression: exp.National, prefix: str = "N") -> str: 910 string = self.sql(exp.Literal.string(expression.name)) 911 return f"{prefix}{string}" 912 913 def partition_sql(self, expression: exp.Partition) -> str: 914 return f"PARTITION({self.expressions(expression)})" 915 916 def properties_sql(self, expression: exp.Properties) -> str: 917 root_properties = [] 918 with_properties = [] 919 920 for p in expression.expressions: 921 p_loc = self.PROPERTIES_LOCATION[p.__class__] 922 if p_loc == exp.Properties.Location.POST_WITH: 923 with_properties.append(p) 924 elif p_loc == exp.Properties.Location.POST_SCHEMA: 925 root_properties.append(p) 926 927 return self.root_properties( 928 exp.Properties(expressions=root_properties) 929 ) + self.with_properties(exp.Properties(expressions=with_properties)) 930 931 def root_properties(self, properties: exp.Properties) -> str: 932 if properties.expressions: 933 return self.sep() + self.expressions(properties, indent=False, sep=" ") 934 return "" 935 936 def properties( 937 self, 938 properties: exp.Properties, 939 prefix: str = "", 940 sep: str = ", ", 941 suffix: str = "", 942 wrapped: bool = True, 943 ) -> str: 944 if properties.expressions: 945 expressions = self.expressions(properties, sep=sep, indent=False) 946 expressions = self.wrap(expressions) if wrapped else expressions 947 return f"{prefix}{' ' if prefix and prefix != ' ' else ''}{expressions}{suffix}" 948 return "" 949 950 def with_properties(self, properties: exp.Properties) -> str: 951 return self.properties(properties, prefix=self.seg("WITH")) 952 953 def locate_properties( 954 self, properties: exp.Properties 955 ) -> t.Dict[exp.Properties.Location, list[exp.Property]]: 956 properties_locs: t.Dict[exp.Properties.Location, list[exp.Property]] = { 957 key: [] for key in exp.Properties.Location 958 } 959 960 for p in properties.expressions: 961 p_loc = self.PROPERTIES_LOCATION[p.__class__] 962 if p_loc == exp.Properties.Location.POST_NAME: 963 properties_locs[exp.Properties.Location.POST_NAME].append(p) 964 elif p_loc == exp.Properties.Location.POST_INDEX: 965 properties_locs[exp.Properties.Location.POST_INDEX].append(p) 966 elif p_loc == exp.Properties.Location.POST_SCHEMA: 967 properties_locs[exp.Properties.Location.POST_SCHEMA].append(p) 968 elif p_loc == exp.Properties.Location.POST_WITH: 969 properties_locs[exp.Properties.Location.POST_WITH].append(p) 970 elif p_loc == exp.Properties.Location.POST_CREATE: 971 properties_locs[exp.Properties.Location.POST_CREATE].append(p) 972 elif p_loc == exp.Properties.Location.POST_ALIAS: 973 properties_locs[exp.Properties.Location.POST_ALIAS].append(p) 974 elif p_loc == exp.Properties.Location.POST_EXPRESSION: 975 properties_locs[exp.Properties.Location.POST_EXPRESSION].append(p) 976 elif p_loc == exp.Properties.Location.UNSUPPORTED: 977 self.unsupported(f"Unsupported property {p.key}") 978 979 return properties_locs 980 981 def property_sql(self, expression: exp.Property) -> str: 982 property_cls = expression.__class__ 983 if property_cls == exp.Property: 984 return f"{expression.name}={self.sql(expression, 'value')}" 985 986 property_name = exp.Properties.PROPERTY_TO_NAME.get(property_cls) 987 if not property_name: 988 self.unsupported(f"Unsupported property {expression.key}") 989 990 return f"{property_name}={self.sql(expression, 'this')}" 991 992 def likeproperty_sql(self, expression: exp.LikeProperty) -> str: 993 options = " ".join(f"{e.name} {self.sql(e, 'value')}" for e in expression.expressions) 994 options = f" {options}" if options else "" 995 return f"LIKE {self.sql(expression, 'this')}{options}" 996 997 def fallbackproperty_sql(self, expression: exp.FallbackProperty) -> str: 998 no = "NO " if expression.args.get("no") else "" 999 protection = " PROTECTION" if expression.args.get("protection") else "" 1000 return f"{no}FALLBACK{protection}" 1001 1002 def journalproperty_sql(self, expression: exp.JournalProperty) -> str: 1003 no = "NO " if expression.args.get("no") else "" 1004 local = expression.args.get("local") 1005 local = f"{local} " if local else "" 1006 dual = "DUAL " if expression.args.get("dual") else "" 1007 before = "BEFORE " if expression.args.get("before") else "" 1008 after = "AFTER " if expression.args.get("after") else "" 1009 return f"{no}{local}{dual}{before}{after}JOURNAL" 1010 1011 def freespaceproperty_sql(self, expression: exp.FreespaceProperty) -> str: 1012 freespace = self.sql(expression, "this") 1013 percent = " PERCENT" if expression.args.get("percent") else "" 1014 return f"FREESPACE={freespace}{percent}" 1015 1016 def checksumproperty_sql(self, expression: exp.ChecksumProperty) -> str: 1017 if expression.args.get("default"): 1018 property = "DEFAULT" 1019 elif expression.args.get("on"): 1020 property = "ON" 1021 else: 1022 property = "OFF" 1023 return f"CHECKSUM={property}" 1024 1025 def mergeblockratioproperty_sql(self, expression: exp.MergeBlockRatioProperty) -> str: 1026 if expression.args.get("no"): 1027 return "NO MERGEBLOCKRATIO" 1028 if expression.args.get("default"): 1029 return "DEFAULT MERGEBLOCKRATIO" 1030 1031 percent = " PERCENT" if expression.args.get("percent") else "" 1032 return f"MERGEBLOCKRATIO={self.sql(expression, 'this')}{percent}" 1033 1034 def datablocksizeproperty_sql(self, expression: exp.DataBlocksizeProperty) -> str: 1035 default = expression.args.get("default") 1036 minimum = expression.args.get("minimum") 1037 maximum = expression.args.get("maximum") 1038 if default or minimum or maximum: 1039 if default: 1040 prop = "DEFAULT" 1041 elif minimum: 1042 prop = "MINIMUM" 1043 else: 1044 prop = "MAXIMUM" 1045 return f"{prop} DATABLOCKSIZE" 1046 units = expression.args.get("units") 1047 units = f" {units}" if units else "" 1048 return f"DATABLOCKSIZE={self.sql(expression, 'size')}{units}" 1049 1050 def blockcompressionproperty_sql(self, expression: exp.BlockCompressionProperty) -> str: 1051 autotemp = expression.args.get("autotemp") 1052 always = expression.args.get("always") 1053 default = expression.args.get("default") 1054 manual = expression.args.get("manual") 1055 never = expression.args.get("never") 1056 1057 if autotemp is not None: 1058 prop = f"AUTOTEMP({self.expressions(autotemp)})" 1059 elif always: 1060 prop = "ALWAYS" 1061 elif default: 1062 prop = "DEFAULT" 1063 elif manual: 1064 prop = "MANUAL" 1065 elif never: 1066 prop = "NEVER" 1067 return f"BLOCKCOMPRESSION={prop}" 1068 1069 def isolatedloadingproperty_sql(self, expression: exp.IsolatedLoadingProperty) -> str: 1070 no = expression.args.get("no") 1071 no = " NO" if no else "" 1072 concurrent = expression.args.get("concurrent") 1073 concurrent = " CONCURRENT" if concurrent else "" 1074 1075 for_ = "" 1076 if expression.args.get("for_all"): 1077 for_ = " FOR ALL" 1078 elif expression.args.get("for_insert"): 1079 for_ = " FOR INSERT" 1080 elif expression.args.get("for_none"): 1081 for_ = " FOR NONE" 1082 return f"WITH{no}{concurrent} ISOLATED LOADING{for_}" 1083 1084 def lockingproperty_sql(self, expression: exp.LockingProperty) -> str: 1085 kind = expression.args.get("kind") 1086 this: str = f" {this}" if expression.this else "" 1087 for_or_in = expression.args.get("for_or_in") 1088 lock_type = expression.args.get("lock_type") 1089 override = " OVERRIDE" if expression.args.get("override") else "" 1090 return f"LOCKING {kind}{this} {for_or_in} {lock_type}{override}" 1091 1092 def withdataproperty_sql(self, expression: exp.WithDataProperty) -> str: 1093 data_sql = f"WITH {'NO ' if expression.args.get('no') else ''}DATA" 1094 statistics = expression.args.get("statistics") 1095 statistics_sql = "" 1096 if statistics is not None: 1097 statistics_sql = f" AND {'NO ' if not statistics else ''}STATISTICS" 1098 return f"{data_sql}{statistics_sql}" 1099 1100 def insert_sql(self, expression: exp.Insert) -> str: 1101 overwrite = expression.args.get("overwrite") 1102 1103 if isinstance(expression.this, exp.Directory): 1104 this = "OVERWRITE " if overwrite else "INTO " 1105 else: 1106 this = "OVERWRITE TABLE " if overwrite else "INTO " 1107 1108 alternative = expression.args.get("alternative") 1109 alternative = f" OR {alternative} " if alternative else " " 1110 this = f"{this}{self.sql(expression, 'this')}" 1111 1112 exists = " IF EXISTS " if expression.args.get("exists") else " " 1113 partition_sql = ( 1114 self.sql(expression, "partition") if expression.args.get("partition") else "" 1115 ) 1116 expression_sql = self.sql(expression, "expression") 1117 conflict = self.sql(expression, "conflict") 1118 returning = self.sql(expression, "returning") 1119 sep = self.sep() if partition_sql else "" 1120 sql = f"INSERT{alternative}{this}{exists}{partition_sql}{sep}{expression_sql}{conflict}{returning}" 1121 return self.prepend_ctes(expression, sql) 1122 1123 def intersect_sql(self, expression: exp.Intersect) -> str: 1124 return self.prepend_ctes( 1125 expression, 1126 self.set_operation(expression, self.intersect_op(expression)), 1127 ) 1128 1129 def intersect_op(self, expression: exp.Intersect) -> str: 1130 return f"INTERSECT{'' if expression.args.get('distinct') else ' ALL'}" 1131 1132 def introducer_sql(self, expression: exp.Introducer) -> str: 1133 return f"{self.sql(expression, 'this')} {self.sql(expression, 'expression')}" 1134 1135 def pseudotype_sql(self, expression: exp.PseudoType) -> str: 1136 return expression.name.upper() 1137 1138 def onconflict_sql(self, expression: exp.OnConflict) -> str: 1139 conflict = "ON DUPLICATE KEY" if expression.args.get("duplicate") else "ON CONFLICT" 1140 constraint = self.sql(expression, "constraint") 1141 if constraint: 1142 constraint = f"ON CONSTRAINT {constraint}" 1143 key = self.expressions(expression, key="key", flat=True) 1144 do = "" if expression.args.get("duplicate") else " DO " 1145 nothing = "NOTHING" if expression.args.get("nothing") else "" 1146 expressions = self.expressions(expression, flat=True) 1147 if expressions: 1148 expressions = f"UPDATE SET {expressions}" 1149 return f"{self.seg(conflict)} {constraint}{key}{do}{nothing}{expressions}" 1150 1151 def returning_sql(self, expression: exp.Returning) -> str: 1152 return f"{self.seg('RETURNING')} {self.expressions(expression, flat=True)}" 1153 1154 def rowformatdelimitedproperty_sql(self, expression: exp.RowFormatDelimitedProperty) -> str: 1155 fields = expression.args.get("fields") 1156 fields = f" FIELDS TERMINATED BY {fields}" if fields else "" 1157 escaped = expression.args.get("escaped") 1158 escaped = f" ESCAPED BY {escaped}" if escaped else "" 1159 items = expression.args.get("collection_items") 1160 items = f" COLLECTION ITEMS TERMINATED BY {items}" if items else "" 1161 keys = expression.args.get("map_keys") 1162 keys = f" MAP KEYS TERMINATED BY {keys}" if keys else "" 1163 lines = expression.args.get("lines") 1164 lines = f" LINES TERMINATED BY {lines}" if lines else "" 1165 null = expression.args.get("null") 1166 null = f" NULL DEFINED AS {null}" if null else "" 1167 return f"ROW FORMAT DELIMITED{fields}{escaped}{items}{keys}{lines}{null}" 1168 1169 def table_sql(self, expression: exp.Table, sep: str = " AS ") -> str: 1170 table = ".".join( 1171 part 1172 for part in [ 1173 self.sql(expression, "catalog"), 1174 self.sql(expression, "db"), 1175 self.sql(expression, "this"), 1176 ] 1177 if part 1178 ) 1179 1180 alias = self.sql(expression, "alias") 1181 alias = f"{sep}{alias}" if alias else "" 1182 hints = self.expressions(expression, key="hints", flat=True) 1183 hints = f" WITH ({hints})" if hints and self.TABLE_HINTS else "" 1184 pivots = self.expressions(expression, key="pivots", sep=" ", flat=True) 1185 pivots = f" {pivots}" if pivots else "" 1186 joins = self.expressions(expression, key="joins", sep="") 1187 laterals = self.expressions(expression, key="laterals", sep="") 1188 system_time = expression.args.get("system_time") 1189 system_time = f" {self.sql(expression, 'system_time')}" if system_time else "" 1190 1191 return f"{table}{system_time}{alias}{hints}{pivots}{joins}{laterals}" 1192 1193 def tablesample_sql( 1194 self, expression: exp.TableSample, seed_prefix: str = "SEED", sep=" AS " 1195 ) -> str: 1196 if self.alias_post_tablesample and expression.this.alias: 1197 table = expression.this.copy() 1198 table.set("alias", None) 1199 this = self.sql(table) 1200 alias = f"{sep}{self.sql(expression.this, 'alias')}" 1201 else: 1202 this = self.sql(expression, "this") 1203 alias = "" 1204 method = self.sql(expression, "method") 1205 method = f"{method.upper()} " if method and self.TABLESAMPLE_WITH_METHOD else "" 1206 numerator = self.sql(expression, "bucket_numerator") 1207 denominator = self.sql(expression, "bucket_denominator") 1208 field = self.sql(expression, "bucket_field") 1209 field = f" ON {field}" if field else "" 1210 bucket = f"BUCKET {numerator} OUT OF {denominator}{field}" if numerator else "" 1211 percent = self.sql(expression, "percent") 1212 percent = f"{percent} PERCENT" if percent else "" 1213 rows = self.sql(expression, "rows") 1214 rows = f"{rows} ROWS" if rows else "" 1215 size = self.sql(expression, "size") 1216 if size and self.TABLESAMPLE_SIZE_IS_PERCENT: 1217 size = f"{size} PERCENT" 1218 seed = self.sql(expression, "seed") 1219 seed = f" {seed_prefix} ({seed})" if seed else "" 1220 kind = expression.args.get("kind", "TABLESAMPLE") 1221 return f"{this} {kind} {method}({bucket}{percent}{rows}{size}){seed}{alias}" 1222 1223 def pivot_sql(self, expression: exp.Pivot) -> str: 1224 expressions = self.expressions(expression, flat=True) 1225 1226 if expression.this: 1227 this = self.sql(expression, "this") 1228 on = f"{self.seg('ON')} {expressions}" 1229 using = self.expressions(expression, key="using", flat=True) 1230 using = f"{self.seg('USING')} {using}" if using else "" 1231 group = self.sql(expression, "group") 1232 return f"PIVOT {this}{on}{using}{group}" 1233 1234 alias = self.sql(expression, "alias") 1235 alias = f" AS {alias}" if alias else "" 1236 unpivot = expression.args.get("unpivot") 1237 direction = "UNPIVOT" if unpivot else "PIVOT" 1238 field = self.sql(expression, "field") 1239 return f"{direction}({expressions} FOR {field}){alias}" 1240 1241 def tuple_sql(self, expression: exp.Tuple) -> str: 1242 return f"({self.expressions(expression, flat=True)})" 1243 1244 def update_sql(self, expression: exp.Update) -> str: 1245 this = self.sql(expression, "this") 1246 set_sql = self.expressions(expression, flat=True) 1247 from_sql = self.sql(expression, "from") 1248 where_sql = self.sql(expression, "where") 1249 returning = self.sql(expression, "returning") 1250 sql = f"UPDATE {this} SET {set_sql}{from_sql}{where_sql}{returning}" 1251 return self.prepend_ctes(expression, sql) 1252 1253 def values_sql(self, expression: exp.Values) -> str: 1254 args = self.expressions(expression) 1255 alias = self.sql(expression, "alias") 1256 values = f"VALUES{self.seg('')}{args}" 1257 values = ( 1258 f"({values})" 1259 if self.WRAP_DERIVED_VALUES and (alias or isinstance(expression.parent, exp.From)) 1260 else values 1261 ) 1262 return f"{values} AS {alias}" if alias else values 1263 1264 def var_sql(self, expression: exp.Var) -> str: 1265 return self.sql(expression, "this") 1266 1267 def into_sql(self, expression: exp.Into) -> str: 1268 temporary = " TEMPORARY" if expression.args.get("temporary") else "" 1269 unlogged = " UNLOGGED" if expression.args.get("unlogged") else "" 1270 return f"{self.seg('INTO')}{temporary or unlogged} {self.sql(expression, 'this')}" 1271 1272 def from_sql(self, expression: exp.From) -> str: 1273 return f"{self.seg('FROM')} {self.sql(expression, 'this')}" 1274 1275 def group_sql(self, expression: exp.Group) -> str: 1276 group_by = self.op_expressions("GROUP BY", expression) 1277 grouping_sets = self.expressions(expression, key="grouping_sets", indent=False) 1278 grouping_sets = ( 1279 f"{self.seg('GROUPING SETS')} {self.wrap(grouping_sets)}" if grouping_sets else "" 1280 ) 1281 1282 cube = expression.args.get("cube", []) 1283 if seq_get(cube, 0) is True: 1284 return f"{group_by}{self.seg('WITH CUBE')}" 1285 else: 1286 cube_sql = self.expressions(expression, key="cube", indent=False) 1287 cube_sql = f"{self.seg('CUBE')} {self.wrap(cube_sql)}" if cube_sql else "" 1288 1289 rollup = expression.args.get("rollup", []) 1290 if seq_get(rollup, 0) is True: 1291 return f"{group_by}{self.seg('WITH ROLLUP')}" 1292 else: 1293 rollup_sql = self.expressions(expression, key="rollup", indent=False) 1294 rollup_sql = f"{self.seg('ROLLUP')} {self.wrap(rollup_sql)}" if rollup_sql else "" 1295 1296 groupings = csv( 1297 grouping_sets, 1298 cube_sql, 1299 rollup_sql, 1300 self.seg("WITH TOTALS") if expression.args.get("totals") else "", 1301 sep=self.GROUPINGS_SEP, 1302 ) 1303 1304 if expression.args.get("expressions") and groupings: 1305 group_by = f"{group_by}{self.GROUPINGS_SEP}" 1306 1307 return f"{group_by}{groupings}" 1308 1309 def having_sql(self, expression: exp.Having) -> str: 1310 this = self.indent(self.sql(expression, "this")) 1311 return f"{self.seg('HAVING')}{self.sep()}{this}" 1312 1313 def join_sql(self, expression: exp.Join) -> str: 1314 op_sql = " ".join( 1315 op 1316 for op in ( 1317 "NATURAL" if expression.args.get("natural") else None, 1318 "GLOBAL" if expression.args.get("global") else None, 1319 expression.side, 1320 expression.kind, 1321 expression.hint if self.JOIN_HINTS else None, 1322 ) 1323 if op 1324 ) 1325 on_sql = self.sql(expression, "on") 1326 using = expression.args.get("using") 1327 1328 if not on_sql and using: 1329 on_sql = csv(*(self.sql(column) for column in using)) 1330 1331 this_sql = self.sql(expression, "this") 1332 1333 if on_sql: 1334 on_sql = self.indent(on_sql, skip_first=True) 1335 space = self.seg(" " * self.pad) if self.pretty else " " 1336 if using: 1337 on_sql = f"{space}USING ({on_sql})" 1338 else: 1339 on_sql = f"{space}ON {on_sql}" 1340 elif not op_sql: 1341 return f", {this_sql}" 1342 1343 op_sql = f"{op_sql} JOIN" if op_sql else "JOIN" 1344 return f"{self.seg(op_sql)} {this_sql}{on_sql}" 1345 1346 def lambda_sql(self, expression: exp.Lambda, arrow_sep: str = "->") -> str: 1347 args = self.expressions(expression, flat=True) 1348 args = f"({args})" if len(args.split(",")) > 1 else args 1349 return f"{args} {arrow_sep} {self.sql(expression, 'this')}" 1350 1351 def lateral_sql(self, expression: exp.Lateral) -> str: 1352 this = self.sql(expression, "this") 1353 1354 if isinstance(expression.this, exp.Subquery): 1355 return f"LATERAL {this}" 1356 1357 if expression.args.get("view"): 1358 alias = expression.args["alias"] 1359 columns = self.expressions(alias, key="columns", flat=True) 1360 table = f" {alias.name}" if alias.name else "" 1361 columns = f" AS {columns}" if columns else "" 1362 op_sql = self.seg(f"LATERAL VIEW{' OUTER' if expression.args.get('outer') else ''}") 1363 return f"{op_sql}{self.sep()}{this}{table}{columns}" 1364 1365 alias = self.sql(expression, "alias") 1366 alias = f" AS {alias}" if alias else "" 1367 return f"LATERAL {this}{alias}" 1368 1369 def limit_sql(self, expression: exp.Limit) -> str: 1370 this = self.sql(expression, "this") 1371 return f"{this}{self.seg('LIMIT')} {self.sql(expression, 'expression')}" 1372 1373 def offset_sql(self, expression: exp.Offset) -> str: 1374 this = self.sql(expression, "this") 1375 return f"{this}{self.seg('OFFSET')} {self.sql(expression, 'expression')}" 1376 1377 def setitem_sql(self, expression: exp.SetItem) -> str: 1378 kind = self.sql(expression, "kind") 1379 kind = f"{kind} " if kind else "" 1380 this = self.sql(expression, "this") 1381 expressions = self.expressions(expression) 1382 collate = self.sql(expression, "collate") 1383 collate = f" COLLATE {collate}" if collate else "" 1384 global_ = "GLOBAL " if expression.args.get("global") else "" 1385 return f"{global_}{kind}{this}{expressions}{collate}" 1386 1387 def set_sql(self, expression: exp.Set) -> str: 1388 expressions = ( 1389 f" {self.expressions(expression, flat=True)}" if expression.expressions else "" 1390 ) 1391 return f"SET{expressions}" 1392 1393 def pragma_sql(self, expression: exp.Pragma) -> str: 1394 return f"PRAGMA {self.sql(expression, 'this')}" 1395 1396 def lock_sql(self, expression: exp.Lock) -> str: 1397 if not self.LOCKING_READS_SUPPORTED: 1398 self.unsupported("Locking reads using 'FOR UPDATE/SHARE' are not supported") 1399 return "" 1400 1401 lock_type = "FOR UPDATE" if expression.args["update"] else "FOR SHARE" 1402 expressions = self.expressions(expression, flat=True) 1403 expressions = f" OF {expressions}" if expressions else "" 1404 wait = expression.args.get("wait") 1405 1406 if wait is not None: 1407 if isinstance(wait, exp.Literal): 1408 wait = f" WAIT {self.sql(wait)}" 1409 else: 1410 wait = " NOWAIT" if wait else " SKIP LOCKED" 1411 1412 return f"{lock_type}{expressions}{wait or ''}" 1413 1414 def literal_sql(self, expression: exp.Literal) -> str: 1415 text = expression.this or "" 1416 if expression.is_string: 1417 text = text.replace(self.quote_end, self._escaped_quote_end) 1418 if self.pretty: 1419 text = text.replace("\n", self.SENTINEL_LINE_BREAK) 1420 text = f"{self.quote_start}{text}{self.quote_end}" 1421 return text 1422 1423 def loaddata_sql(self, expression: exp.LoadData) -> str: 1424 local = " LOCAL" if expression.args.get("local") else "" 1425 inpath = f" INPATH {self.sql(expression, 'inpath')}" 1426 overwrite = " OVERWRITE" if expression.args.get("overwrite") else "" 1427 this = f" INTO TABLE {self.sql(expression, 'this')}" 1428 partition = self.sql(expression, "partition") 1429 partition = f" {partition}" if partition else "" 1430 input_format = self.sql(expression, "input_format") 1431 input_format = f" INPUTFORMAT {input_format}" if input_format else "" 1432 serde = self.sql(expression, "serde") 1433 serde = f" SERDE {serde}" if serde else "" 1434 return f"LOAD DATA{local}{inpath}{overwrite}{this}{partition}{input_format}{serde}" 1435 1436 def null_sql(self, *_) -> str: 1437 return "NULL" 1438 1439 def boolean_sql(self, expression: exp.Boolean) -> str: 1440 return "TRUE" if expression.this else "FALSE" 1441 1442 def order_sql(self, expression: exp.Order, flat: bool = False) -> str: 1443 this = self.sql(expression, "this") 1444 this = f"{this} " if this else this 1445 return self.op_expressions(f"{this}ORDER BY", expression, flat=this or flat) # type: ignore 1446 1447 def cluster_sql(self, expression: exp.Cluster) -> str: 1448 return self.op_expressions("CLUSTER BY", expression) 1449 1450 def distribute_sql(self, expression: exp.Distribute) -> str: 1451 return self.op_expressions("DISTRIBUTE BY", expression) 1452 1453 def sort_sql(self, expression: exp.Sort) -> str: 1454 return self.op_expressions("SORT BY", expression) 1455 1456 def ordered_sql(self, expression: exp.Ordered) -> str: 1457 desc = expression.args.get("desc") 1458 asc = not desc 1459 1460 nulls_first = expression.args.get("nulls_first") 1461 nulls_last = not nulls_first 1462 nulls_are_large = self.null_ordering == "nulls_are_large" 1463 nulls_are_small = self.null_ordering == "nulls_are_small" 1464 nulls_are_last = self.null_ordering == "nulls_are_last" 1465 1466 sort_order = " DESC" if desc else "" 1467 nulls_sort_change = "" 1468 if nulls_first and ( 1469 (asc and nulls_are_large) or (desc and nulls_are_small) or nulls_are_last 1470 ): 1471 nulls_sort_change = " NULLS FIRST" 1472 elif ( 1473 nulls_last 1474 and ((asc and nulls_are_small) or (desc and nulls_are_large)) 1475 and not nulls_are_last 1476 ): 1477 nulls_sort_change = " NULLS LAST" 1478 1479 if nulls_sort_change and not self.NULL_ORDERING_SUPPORTED: 1480 self.unsupported( 1481 "Sorting in an ORDER BY on NULLS FIRST/NULLS LAST is not supported by this dialect" 1482 ) 1483 nulls_sort_change = "" 1484 1485 return f"{self.sql(expression, 'this')}{sort_order}{nulls_sort_change}" 1486 1487 def matchrecognize_sql(self, expression: exp.MatchRecognize) -> str: 1488 partition = self.partition_by_sql(expression) 1489 order = self.sql(expression, "order") 1490 measures = self.expressions(expression, key="measures") 1491 measures = self.seg(f"MEASURES{self.seg(measures)}") if measures else "" 1492 rows = self.sql(expression, "rows") 1493 rows = self.seg(rows) if rows else "" 1494 after = self.sql(expression, "after") 1495 after = self.seg(after) if after else "" 1496 pattern = self.sql(expression, "pattern") 1497 pattern = self.seg(f"PATTERN ({pattern})") if pattern else "" 1498 definition_sqls = [ 1499 f"{self.sql(definition, 'alias')} AS {self.sql(definition, 'this')}" 1500 for definition in expression.args.get("define", []) 1501 ] 1502 definitions = self.expressions(sqls=definition_sqls) 1503 define = self.seg(f"DEFINE{self.seg(definitions)}") if definitions else "" 1504 body = "".join( 1505 ( 1506 partition, 1507 order, 1508 measures, 1509 rows, 1510 after, 1511 pattern, 1512 define, 1513 ) 1514 ) 1515 alias = self.sql(expression, "alias") 1516 alias = f" {alias}" if alias else "" 1517 return f"{self.seg('MATCH_RECOGNIZE')} {self.wrap(body)}{alias}" 1518 1519 def query_modifiers(self, expression: exp.Expression, *sqls: str) -> str: 1520 limit = expression.args.get("limit") 1521 1522 if self.LIMIT_FETCH == "LIMIT" and isinstance(limit, exp.Fetch): 1523 limit = exp.Limit(expression=limit.args.get("count")) 1524 elif self.LIMIT_FETCH == "FETCH" and isinstance(limit, exp.Limit): 1525 limit = exp.Fetch(direction="FIRST", count=limit.expression) 1526 1527 fetch = isinstance(limit, exp.Fetch) 1528 1529 return csv( 1530 *sqls, 1531 *[self.sql(join) for join in expression.args.get("joins") or []], 1532 self.sql(expression, "match"), 1533 *[self.sql(lateral) for lateral in expression.args.get("laterals") or []], 1534 self.sql(expression, "where"), 1535 self.sql(expression, "group"), 1536 self.sql(expression, "having"), 1537 *self.after_having_modifiers(expression), 1538 self.sql(expression, "order"), 1539 self.sql(expression, "offset") if fetch else self.sql(limit), 1540 self.sql(limit) if fetch else self.sql(expression, "offset"), 1541 *self.after_limit_modifiers(expression), 1542 sep="", 1543 ) 1544 1545 def after_having_modifiers(self, expression: exp.Expression) -> t.List[str]: 1546 return [ 1547 self.sql(expression, "qualify"), 1548 self.seg("WINDOW ") + self.expressions(expression, key="windows", flat=True) 1549 if expression.args.get("windows") 1550 else "", 1551 ] 1552 1553 def after_limit_modifiers(self, expression: exp.Expression) -> t.List[str]: 1554 locks = self.expressions(expression, key="locks", sep=" ") 1555 locks = f" {locks}" if locks else "" 1556 return [locks, self.sql(expression, "sample")] 1557 1558 def select_sql(self, expression: exp.Select) -> str: 1559 hint = self.sql(expression, "hint") 1560 distinct = self.sql(expression, "distinct") 1561 distinct = f" {distinct}" if distinct else "" 1562 kind = expression.args.get("kind") 1563 kind = f" AS {kind}" if kind else "" 1564 expressions = self.expressions(expression) 1565 expressions = f"{self.sep()}{expressions}" if expressions else expressions 1566 sql = self.query_modifiers( 1567 expression, 1568 f"SELECT{hint}{distinct}{kind}{expressions}", 1569 self.sql(expression, "into", comment=False), 1570 self.sql(expression, "from", comment=False), 1571 ) 1572 return self.prepend_ctes(expression, sql) 1573 1574 def schema_sql(self, expression: exp.Schema) -> str: 1575 this = self.sql(expression, "this") 1576 this = f"{this} " if this else "" 1577 sql = f"({self.sep('')}{self.expressions(expression)}{self.seg(')', sep='')}" 1578 return f"{this}{sql}" 1579 1580 def star_sql(self, expression: exp.Star) -> str: 1581 except_ = self.expressions(expression, key="except", flat=True) 1582 except_ = f"{self.seg(self.STAR_MAPPING['except'])} ({except_})" if except_ else "" 1583 replace = self.expressions(expression, key="replace", flat=True) 1584 replace = f"{self.seg(self.STAR_MAPPING['replace'])} ({replace})" if replace else "" 1585 return f"*{except_}{replace}" 1586 1587 def parameter_sql(self, expression: exp.Parameter) -> str: 1588 this = self.sql(expression, "this") 1589 this = f"{{{this}}}" if expression.args.get("wrapped") else f"{this}" 1590 return f"{self.PARAMETER_TOKEN}{this}" 1591 1592 def sessionparameter_sql(self, expression: exp.SessionParameter) -> str: 1593 this = self.sql(expression, "this") 1594 kind = expression.text("kind") 1595 if kind: 1596 kind = f"{kind}." 1597 return f"@@{kind}{this}" 1598 1599 def placeholder_sql(self, expression: exp.Placeholder) -> str: 1600 return f":{expression.name}" if expression.name else "?" 1601 1602 def subquery_sql(self, expression: exp.Subquery, sep: str = " AS ") -> str: 1603 alias = self.sql(expression, "alias") 1604 alias = f"{sep}{alias}" if alias else "" 1605 1606 pivots = self.expressions(expression, key="pivots", sep=" ", flat=True) 1607 pivots = f" {pivots}" if pivots else "" 1608 1609 sql = self.query_modifiers(expression, self.wrap(expression), alias, pivots) 1610 return self.prepend_ctes(expression, sql) 1611 1612 def qualify_sql(self, expression: exp.Qualify) -> str: 1613 this = self.indent(self.sql(expression, "this")) 1614 return f"{self.seg('QUALIFY')}{self.sep()}{this}" 1615 1616 def union_sql(self, expression: exp.Union) -> str: 1617 return self.prepend_ctes( 1618 expression, 1619 self.set_operation(expression, self.union_op(expression)), 1620 ) 1621 1622 def union_op(self, expression: exp.Union) -> str: 1623 kind = " DISTINCT" if self.EXPLICIT_UNION else "" 1624 kind = kind if expression.args.get("distinct") else " ALL" 1625 return f"UNION{kind}" 1626 1627 def unnest_sql(self, expression: exp.Unnest) -> str: 1628 args = self.expressions(expression, flat=True) 1629 alias = expression.args.get("alias") 1630 if alias and self.unnest_column_only: 1631 columns = alias.columns 1632 alias = self.sql(columns[0]) if columns else "" 1633 else: 1634 alias = self.sql(expression, "alias") 1635 alias = f" AS {alias}" if alias else alias 1636 ordinality = " WITH ORDINALITY" if expression.args.get("ordinality") else "" 1637 offset = expression.args.get("offset") 1638 offset = f" WITH OFFSET AS {self.sql(offset)}" if offset else "" 1639 return f"UNNEST({args}){ordinality}{alias}{offset}" 1640 1641 def where_sql(self, expression: exp.Where) -> str: 1642 this = self.indent(self.sql(expression, "this")) 1643 return f"{self.seg('WHERE')}{self.sep()}{this}" 1644 1645 def window_sql(self, expression: exp.Window) -> str: 1646 this = self.sql(expression, "this") 1647 1648 partition = self.partition_by_sql(expression) 1649 1650 order = expression.args.get("order") 1651 order_sql = self.order_sql(order, flat=True) if order else "" 1652 1653 partition_sql = partition + " " if partition and order else partition 1654 1655 spec = expression.args.get("spec") 1656 spec_sql = " " + self.windowspec_sql(spec) if spec else "" 1657 1658 alias = self.sql(expression, "alias") 1659 over = self.sql(expression, "over") or "OVER" 1660 this = f"{this} {'AS' if expression.arg_key == 'windows' else over}" 1661 1662 first = expression.args.get("first") 1663 if first is not None: 1664 first = " FIRST " if first else " LAST " 1665 first = first or "" 1666 1667 if not partition and not order and not spec and alias: 1668 return f"{this} {alias}" 1669 1670 window_args = alias + first + partition_sql + order_sql + spec_sql 1671 1672 return f"{this} ({window_args.strip()})" 1673 1674 def partition_by_sql(self, expression: exp.Window | exp.MatchRecognize) -> str: 1675 partition = self.expressions(expression, key="partition_by", flat=True) 1676 return f"PARTITION BY {partition}" if partition else "" 1677 1678 def windowspec_sql(self, expression: exp.WindowSpec) -> str: 1679 kind = self.sql(expression, "kind") 1680 start = csv(self.sql(expression, "start"), self.sql(expression, "start_side"), sep=" ") 1681 end = ( 1682 csv(self.sql(expression, "end"), self.sql(expression, "end_side"), sep=" ") 1683 or "CURRENT ROW" 1684 ) 1685 return f"{kind} BETWEEN {start} AND {end}" 1686 1687 def withingroup_sql(self, expression: exp.WithinGroup) -> str: 1688 this = self.sql(expression, "this") 1689 expression_sql = self.sql(expression, "expression")[1:] # order has a leading space 1690 return f"{this} WITHIN GROUP ({expression_sql})" 1691 1692 def between_sql(self, expression: exp.Between) -> str: 1693 this = self.sql(expression, "this") 1694 low = self.sql(expression, "low") 1695 high = self.sql(expression, "high") 1696 return f"{this} BETWEEN {low} AND {high}" 1697 1698 def bracket_sql(self, expression: exp.Bracket) -> str: 1699 expressions = apply_index_offset(expression.this, expression.expressions, self.index_offset) 1700 expressions_sql = ", ".join(self.sql(e) for e in expressions) 1701 1702 return f"{self.sql(expression, 'this')}[{expressions_sql}]" 1703 1704 def all_sql(self, expression: exp.All) -> str: 1705 return f"ALL {self.wrap(expression)}" 1706 1707 def any_sql(self, expression: exp.Any) -> str: 1708 this = self.sql(expression, "this") 1709 if isinstance(expression.this, exp.Subqueryable): 1710 this = self.wrap(this) 1711 return f"ANY {this}" 1712 1713 def exists_sql(self, expression: exp.Exists) -> str: 1714 return f"EXISTS{self.wrap(expression)}" 1715 1716 def case_sql(self, expression: exp.Case) -> str: 1717 this = self.sql(expression, "this") 1718 statements = [f"CASE {this}" if this else "CASE"] 1719 1720 for e in expression.args["ifs"]: 1721 statements.append(f"WHEN {self.sql(e, 'this')}") 1722 statements.append(f"THEN {self.sql(e, 'true')}") 1723 1724 default = self.sql(expression, "default") 1725 1726 if default: 1727 statements.append(f"ELSE {default}") 1728 1729 statements.append("END") 1730 1731 if self.pretty and self.text_width(statements) > self._max_text_width: 1732 return self.indent("\n".join(statements), skip_first=True, skip_last=True) 1733 1734 return " ".join(statements) 1735 1736 def constraint_sql(self, expression: exp.Constraint) -> str: 1737 this = self.sql(expression, "this") 1738 expressions = self.expressions(expression, flat=True) 1739 return f"CONSTRAINT {this} {expressions}" 1740 1741 def nextvaluefor_sql(self, expression: exp.NextValueFor) -> str: 1742 order = expression.args.get("order") 1743 order = f" OVER ({self.order_sql(order, flat=True)})" if order else "" 1744 return f"NEXT VALUE FOR {self.sql(expression, 'this')}{order}" 1745 1746 def extract_sql(self, expression: exp.Extract) -> str: 1747 this = self.sql(expression, "this") 1748 expression_sql = self.sql(expression, "expression") 1749 return f"EXTRACT({this} FROM {expression_sql})" 1750 1751 def trim_sql(self, expression: exp.Trim) -> str: 1752 trim_type = self.sql(expression, "position") 1753 1754 if trim_type == "LEADING": 1755 return self.func("LTRIM", expression.this) 1756 elif trim_type == "TRAILING": 1757 return self.func("RTRIM", expression.this) 1758 else: 1759 return self.func("TRIM", expression.this, expression.expression) 1760 1761 def concat_sql(self, expression: exp.Concat) -> str: 1762 if len(expression.expressions) == 1: 1763 return self.sql(expression.expressions[0]) 1764 return self.function_fallback_sql(expression) 1765 1766 def check_sql(self, expression: exp.Check) -> str: 1767 this = self.sql(expression, key="this") 1768 return f"CHECK ({this})" 1769 1770 def foreignkey_sql(self, expression: exp.ForeignKey) -> str: 1771 expressions = self.expressions(expression, flat=True) 1772 reference = self.sql(expression, "reference") 1773 reference = f" {reference}" if reference else "" 1774 delete = self.sql(expression, "delete") 1775 delete = f" ON DELETE {delete}" if delete else "" 1776 update = self.sql(expression, "update") 1777 update = f" ON UPDATE {update}" if update else "" 1778 return f"FOREIGN KEY ({expressions}){reference}{delete}{update}" 1779 1780 def primarykey_sql(self, expression: exp.ForeignKey) -> str: 1781 expressions = self.expressions(expression, flat=True) 1782 options = self.expressions(expression, key="options", flat=True, sep=" ") 1783 options = f" {options}" if options else "" 1784 return f"PRIMARY KEY ({expressions}){options}" 1785 1786 def if_sql(self, expression: exp.If) -> str: 1787 return self.case_sql( 1788 exp.Case(ifs=[expression.copy()], default=expression.args.get("false")) 1789 ) 1790 1791 def matchagainst_sql(self, expression: exp.MatchAgainst) -> str: 1792 modifier = expression.args.get("modifier") 1793 modifier = f" {modifier}" if modifier else "" 1794 return f"{self.func('MATCH', *expression.expressions)} AGAINST({self.sql(expression, 'this')}{modifier})" 1795 1796 def jsonkeyvalue_sql(self, expression: exp.JSONKeyValue) -> str: 1797 return f"{self.sql(expression, 'this')}: {self.sql(expression, 'expression')}" 1798 1799 def jsonobject_sql(self, expression: exp.JSONObject) -> str: 1800 expressions = self.expressions(expression) 1801 null_handling = expression.args.get("null_handling") 1802 null_handling = f" {null_handling}" if null_handling else "" 1803 unique_keys = expression.args.get("unique_keys") 1804 if unique_keys is not None: 1805 unique_keys = f" {'WITH' if unique_keys else 'WITHOUT'} UNIQUE KEYS" 1806 else: 1807 unique_keys = "" 1808 return_type = self.sql(expression, "return_type") 1809 return_type = f" RETURNING {return_type}" if return_type else "" 1810 format_json = " FORMAT JSON" if expression.args.get("format_json") else "" 1811 encoding = self.sql(expression, "encoding") 1812 encoding = f" ENCODING {encoding}" if encoding else "" 1813 return f"JSON_OBJECT({expressions}{null_handling}{unique_keys}{return_type}{format_json}{encoding})" 1814 1815 def openjsoncolumndef_sql(self, expression: exp.OpenJSONColumnDef) -> str: 1816 this = self.sql(expression, "this") 1817 kind = self.sql(expression, "kind") 1818 path = self.sql(expression, "path") 1819 path = f" {path}" if path else "" 1820 as_json = " AS JSON" if expression.args.get("as_json") else "" 1821 return f"{this} {kind}{path}{as_json}" 1822 1823 def openjson_sql(self, expression: exp.OpenJSON) -> str: 1824 this = self.sql(expression, "this") 1825 path = self.sql(expression, "path") 1826 path = f", {path}" if path else "" 1827 expressions = self.expressions(expression) 1828 with_ = ( 1829 f" WITH ({self.seg(self.indent(expressions), sep='')}{self.seg(')', sep='')}" 1830 if expressions 1831 else "" 1832 ) 1833 return f"OPENJSON({this}{path}){with_}" 1834 1835 def in_sql(self, expression: exp.In) -> str: 1836 query = expression.args.get("query") 1837 unnest = expression.args.get("unnest") 1838 field = expression.args.get("field") 1839 is_global = " GLOBAL" if expression.args.get("is_global") else "" 1840 1841 if query: 1842 in_sql = self.wrap(query) 1843 elif unnest: 1844 in_sql = self.in_unnest_op(unnest) 1845 elif field: 1846 in_sql = self.sql(field) 1847 else: 1848 in_sql = f"({self.expressions(expression, flat=True)})" 1849 1850 return f"{self.sql(expression, 'this')}{is_global} IN {in_sql}" 1851 1852 def in_unnest_op(self, unnest: exp.Unnest) -> str: 1853 return f"(SELECT {self.sql(unnest)})" 1854 1855 def interval_sql(self, expression: exp.Interval) -> str: 1856 unit = self.sql(expression, "unit") 1857 if not self.INTERVAL_ALLOWS_PLURAL_FORM: 1858 unit = self.TIME_PART_SINGULARS.get(unit.lower(), unit) 1859 unit = f" {unit}" if unit else "" 1860 1861 if self.SINGLE_STRING_INTERVAL: 1862 this = expression.this.name if expression.this else "" 1863 return f"INTERVAL '{this}{unit}'" if this else f"INTERVAL{unit}" 1864 1865 this = self.sql(expression, "this") 1866 if this: 1867 unwrapped = isinstance(expression.this, self.UNWRAPPED_INTERVAL_VALUES) 1868 this = f" {this}" if unwrapped else f" ({this})" 1869 1870 return f"INTERVAL{this}{unit}" 1871 1872 def return_sql(self, expression: exp.Return) -> str: 1873 return f"RETURN {self.sql(expression, 'this')}" 1874 1875 def reference_sql(self, expression: exp.Reference) -> str: 1876 this = self.sql(expression, "this") 1877 expressions = self.expressions(expression, flat=True) 1878 expressions = f"({expressions})" if expressions else "" 1879 options = self.expressions(expression, key="options", flat=True, sep=" ") 1880 options = f" {options}" if options else "" 1881 return f"REFERENCES {this}{expressions}{options}" 1882 1883 def anonymous_sql(self, expression: exp.Anonymous) -> str: 1884 return self.func(expression.name, *expression.expressions) 1885 1886 def paren_sql(self, expression: exp.Paren) -> str: 1887 if isinstance(expression.unnest(), exp.Select): 1888 sql = self.wrap(expression) 1889 else: 1890 sql = self.seg(self.indent(self.sql(expression, "this")), sep="") 1891 sql = f"({sql}{self.seg(')', sep='')}" 1892 1893 return self.prepend_ctes(expression, sql) 1894 1895 def neg_sql(self, expression: exp.Neg) -> str: 1896 # This makes sure we don't convert "- - 5" to "--5", which is a comment 1897 this_sql = self.sql(expression, "this") 1898 sep = " " if this_sql[0] == "-" else "" 1899 return f"-{sep}{this_sql}" 1900 1901 def not_sql(self, expression: exp.Not) -> str: 1902 return f"NOT {self.sql(expression, 'this')}" 1903 1904 def alias_sql(self, expression: exp.Alias) -> str: 1905 alias = self.sql(expression, "alias") 1906 alias = f" AS {alias}" if alias else "" 1907 return f"{self.sql(expression, 'this')}{alias}" 1908 1909 def aliases_sql(self, expression: exp.Aliases) -> str: 1910 return f"{self.sql(expression, 'this')} AS ({self.expressions(expression, flat=True)})" 1911 1912 def attimezone_sql(self, expression: exp.AtTimeZone) -> str: 1913 this = self.sql(expression, "this") 1914 zone = self.sql(expression, "zone") 1915 return f"{this} AT TIME ZONE {zone}" 1916 1917 def add_sql(self, expression: exp.Add) -> str: 1918 return self.binary(expression, "+") 1919 1920 def and_sql(self, expression: exp.And) -> str: 1921 return self.connector_sql(expression, "AND") 1922 1923 def connector_sql(self, expression: exp.Connector, op: str) -> str: 1924 if not self.pretty: 1925 return self.binary(expression, op) 1926 1927 sqls = tuple( 1928 self.maybe_comment(self.sql(e), e, e.parent.comments or []) if i != 1 else self.sql(e) 1929 for i, e in enumerate(expression.flatten(unnest=False)) 1930 ) 1931 1932 sep = "\n" if self.text_width(sqls) > self._max_text_width else " " 1933 return f"{sep}{op} ".join(sqls) 1934 1935 def bitwiseand_sql(self, expression: exp.BitwiseAnd) -> str: 1936 return self.binary(expression, "&") 1937 1938 def bitwiseleftshift_sql(self, expression: exp.BitwiseLeftShift) -> str: 1939 return self.binary(expression, "<<") 1940 1941 def bitwisenot_sql(self, expression: exp.BitwiseNot) -> str: 1942 return f"~{self.sql(expression, 'this')}" 1943 1944 def bitwiseor_sql(self, expression: exp.BitwiseOr) -> str: 1945 return self.binary(expression, "|") 1946 1947 def bitwiserightshift_sql(self, expression: exp.BitwiseRightShift) -> str: 1948 return self.binary(expression, ">>") 1949 1950 def bitwisexor_sql(self, expression: exp.BitwiseXor) -> str: 1951 return self.binary(expression, "^") 1952 1953 def cast_sql(self, expression: exp.Cast) -> str: 1954 return f"CAST({self.sql(expression, 'this')} AS {self.sql(expression, 'to')})" 1955 1956 def currentdate_sql(self, expression: exp.CurrentDate) -> str: 1957 zone = self.sql(expression, "this") 1958 return f"CURRENT_DATE({zone})" if zone else "CURRENT_DATE" 1959 1960 def collate_sql(self, expression: exp.Collate) -> str: 1961 return self.binary(expression, "COLLATE") 1962 1963 def command_sql(self, expression: exp.Command) -> str: 1964 return f"{self.sql(expression, 'this').upper()} {expression.text('expression').strip()}" 1965 1966 def comment_sql(self, expression: exp.Comment) -> str: 1967 this = self.sql(expression, "this") 1968 kind = expression.args["kind"] 1969 exists_sql = " IF EXISTS " if expression.args.get("exists") else " " 1970 expression_sql = self.sql(expression, "expression") 1971 return f"COMMENT{exists_sql}ON {kind} {this} IS {expression_sql}" 1972 1973 def mergetreettlaction_sql(self, expression: exp.MergeTreeTTLAction) -> str: 1974 this = self.sql(expression, "this") 1975 delete = " DELETE" if expression.args.get("delete") else "" 1976 recompress = self.sql(expression, "recompress") 1977 recompress = f" RECOMPRESS {recompress}" if recompress else "" 1978 to_disk = self.sql(expression, "to_disk") 1979 to_disk = f" TO DISK {to_disk}" if to_disk else "" 1980 to_volume = self.sql(expression, "to_volume") 1981 to_volume = f" TO VOLUME {to_volume}" if to_volume else "" 1982 return f"{this}{delete}{recompress}{to_disk}{to_volume}" 1983 1984 def mergetreettl_sql(self, expression: exp.MergeTreeTTL) -> str: 1985 where = self.sql(expression, "where") 1986 group = self.sql(expression, "group") 1987 aggregates = self.expressions(expression, key="aggregates") 1988 aggregates = self.seg("SET") + self.seg(aggregates) if aggregates else "" 1989 1990 if not (where or group or aggregates) and len(expression.expressions) == 1: 1991 return f"TTL {self.expressions(expression, flat=True)}" 1992 1993 return f"TTL{self.seg(self.expressions(expression))}{where}{group}{aggregates}" 1994 1995 def transaction_sql(self, expression: exp.Transaction) -> str: 1996 return "BEGIN" 1997 1998 def commit_sql(self, expression: exp.Commit) -> str: 1999 chain = expression.args.get("chain") 2000 if chain is not None: 2001 chain = " AND CHAIN" if chain else " AND NO CHAIN" 2002 2003 return f"COMMIT{chain or ''}" 2004 2005 def rollback_sql(self, expression: exp.Rollback) -> str: 2006 savepoint = expression.args.get("savepoint") 2007 savepoint = f" TO {savepoint}" if savepoint else "" 2008 return f"ROLLBACK{savepoint}" 2009 2010 def altercolumn_sql(self, expression: exp.AlterColumn) -> str: 2011 this = self.sql(expression, "this") 2012 2013 dtype = self.sql(expression, "dtype") 2014 if dtype: 2015 collate = self.sql(expression, "collate") 2016 collate = f" COLLATE {collate}" if collate else "" 2017 using = self.sql(expression, "using") 2018 using = f" USING {using}" if using else "" 2019 return f"ALTER COLUMN {this} TYPE {dtype}{collate}{using}" 2020 2021 default = self.sql(expression, "default") 2022 if default: 2023 return f"ALTER COLUMN {this} SET DEFAULT {default}" 2024 2025 if not expression.args.get("drop"): 2026 self.unsupported("Unsupported ALTER COLUMN syntax") 2027 2028 return f"ALTER COLUMN {this} DROP DEFAULT" 2029 2030 def renametable_sql(self, expression: exp.RenameTable) -> str: 2031 if not self.RENAME_TABLE_WITH_DB: 2032 # Remove db from tables 2033 expression = expression.transform( 2034 lambda n: exp.table_(n.this) if isinstance(n, exp.Table) else n 2035 ) 2036 this = self.sql(expression, "this") 2037 return f"RENAME TO {this}" 2038 2039 def altertable_sql(self, expression: exp.AlterTable) -> str: 2040 actions = expression.args["actions"] 2041 2042 if isinstance(actions[0], exp.ColumnDef): 2043 actions = self.expressions(expression, key="actions", prefix="ADD COLUMN ") 2044 elif isinstance(actions[0], exp.Schema): 2045 actions = self.expressions(expression, key="actions", prefix="ADD COLUMNS ") 2046 elif isinstance(actions[0], exp.Delete): 2047 actions = self.expressions(expression, key="actions", flat=True) 2048 else: 2049 actions = self.expressions(expression, key="actions") 2050 2051 exists = " IF EXISTS" if expression.args.get("exists") else "" 2052 return f"ALTER TABLE{exists} {self.sql(expression, 'this')} {actions}" 2053 2054 def droppartition_sql(self, expression: exp.DropPartition) -> str: 2055 expressions = self.expressions(expression) 2056 exists = " IF EXISTS " if expression.args.get("exists") else " " 2057 return f"DROP{exists}{expressions}" 2058 2059 def addconstraint_sql(self, expression: exp.AddConstraint) -> str: 2060 this = self.sql(expression, "this") 2061 expression_ = self.sql(expression, "expression") 2062 add_constraint = f"ADD CONSTRAINT {this}" if this else "ADD" 2063 2064 enforced = expression.args.get("enforced") 2065 if enforced is not None: 2066 return f"{add_constraint} CHECK ({expression_}){' ENFORCED' if enforced else ''}" 2067 2068 return f"{add_constraint} {expression_}" 2069 2070 def distinct_sql(self, expression: exp.Distinct) -> str: 2071 this = self.expressions(expression, flat=True) 2072 this = f" {this}" if this else "" 2073 2074 on = self.sql(expression, "on") 2075 on = f" ON {on}" if on else "" 2076 return f"DISTINCT{this}{on}" 2077 2078 def ignorenulls_sql(self, expression: exp.IgnoreNulls) -> str: 2079 return f"{self.sql(expression, 'this')} IGNORE NULLS" 2080 2081 def respectnulls_sql(self, expression: exp.RespectNulls) -> str: 2082 return f"{self.sql(expression, 'this')} RESPECT NULLS" 2083 2084 def intdiv_sql(self, expression: exp.IntDiv) -> str: 2085 return self.sql( 2086 exp.Cast( 2087 this=exp.Div(this=expression.this, expression=expression.expression), 2088 to=exp.DataType(this=exp.DataType.Type.INT), 2089 ) 2090 ) 2091 2092 def dpipe_sql(self, expression: exp.DPipe) -> str: 2093 return self.binary(expression, "||") 2094 2095 def div_sql(self, expression: exp.Div) -> str: 2096 return self.binary(expression, "/") 2097 2098 def overlaps_sql(self, expression: exp.Overlaps) -> str: 2099 return self.binary(expression, "OVERLAPS") 2100 2101 def distance_sql(self, expression: exp.Distance) -> str: 2102 return self.binary(expression, "<->") 2103 2104 def dot_sql(self, expression: exp.Dot) -> str: 2105 return f"{self.sql(expression, 'this')}.{self.sql(expression, 'expression')}" 2106 2107 def eq_sql(self, expression: exp.EQ) -> str: 2108 return self.binary(expression, "=") 2109 2110 def escape_sql(self, expression: exp.Escape) -> str: 2111 return self.binary(expression, "ESCAPE") 2112 2113 def glob_sql(self, expression: exp.Glob) -> str: 2114 return self.binary(expression, "GLOB") 2115 2116 def gt_sql(self, expression: exp.GT) -> str: 2117 return self.binary(expression, ">") 2118 2119 def gte_sql(self, expression: exp.GTE) -> str: 2120 return self.binary(expression, ">=") 2121 2122 def ilike_sql(self, expression: exp.ILike) -> str: 2123 return self.binary(expression, "ILIKE") 2124 2125 def ilikeany_sql(self, expression: exp.ILikeAny) -> str: 2126 return self.binary(expression, "ILIKE ANY") 2127 2128 def is_sql(self, expression: exp.Is) -> str: 2129 return self.binary(expression, "IS") 2130 2131 def like_sql(self, expression: exp.Like) -> str: 2132 return self.binary(expression, "LIKE") 2133 2134 def likeany_sql(self, expression: exp.LikeAny) -> str: 2135 return self.binary(expression, "LIKE ANY") 2136 2137 def similarto_sql(self, expression: exp.SimilarTo) -> str: 2138 return self.binary(expression, "SIMILAR TO") 2139 2140 def lt_sql(self, expression: exp.LT) -> str: 2141 return self.binary(expression, "<") 2142 2143 def lte_sql(self, expression: exp.LTE) -> str: 2144 return self.binary(expression, "<=") 2145 2146 def mod_sql(self, expression: exp.Mod) -> str: 2147 return self.binary(expression, "%") 2148 2149 def mul_sql(self, expression: exp.Mul) -> str: 2150 return self.binary(expression, "*") 2151 2152 def neq_sql(self, expression: exp.NEQ) -> str: 2153 return self.binary(expression, "<>") 2154 2155 def nullsafeeq_sql(self, expression: exp.NullSafeEQ) -> str: 2156 return self.binary(expression, "IS NOT DISTINCT FROM") 2157 2158 def nullsafeneq_sql(self, expression: exp.NullSafeNEQ) -> str: 2159 return self.binary(expression, "IS DISTINCT FROM") 2160 2161 def or_sql(self, expression: exp.Or) -> str: 2162 return self.connector_sql(expression, "OR") 2163 2164 def slice_sql(self, expression: exp.Slice) -> str: 2165 return self.binary(expression, ":") 2166 2167 def sub_sql(self, expression: exp.Sub) -> str: 2168 return self.binary(expression, "-") 2169 2170 def trycast_sql(self, expression: exp.TryCast) -> str: 2171 return f"TRY_CAST({self.sql(expression, 'this')} AS {self.sql(expression, 'to')})" 2172 2173 def use_sql(self, expression: exp.Use) -> str: 2174 kind = self.sql(expression, "kind") 2175 kind = f" {kind}" if kind else "" 2176 this = self.sql(expression, "this") 2177 this = f" {this}" if this else "" 2178 return f"USE{kind}{this}" 2179 2180 def binary(self, expression: exp.Binary, op: str) -> str: 2181 op = self.maybe_comment(op, comments=expression.comments) 2182 return f"{self.sql(expression, 'this')} {op} {self.sql(expression, 'expression')}" 2183 2184 def function_fallback_sql(self, expression: exp.Func) -> str: 2185 args = [] 2186 for arg_value in expression.args.values(): 2187 if isinstance(arg_value, list): 2188 for value in arg_value: 2189 args.append(value) 2190 else: 2191 args.append(arg_value) 2192 2193 return self.func(expression.sql_name(), *args) 2194 2195 def func(self, name: str, *args: t.Optional[exp.Expression | str]) -> str: 2196 return f"{self.normalize_func(name)}({self.format_args(*args)})" 2197 2198 def format_args(self, *args: t.Optional[str | exp.Expression]) -> str: 2199 arg_sqls = tuple(self.sql(arg) for arg in args if arg is not None) 2200 if self.pretty and self.text_width(arg_sqls) > self._max_text_width: 2201 return self.indent("\n" + f",\n".join(arg_sqls) + "\n", skip_first=True, skip_last=True) 2202 return ", ".join(arg_sqls) 2203 2204 def text_width(self, args: t.Iterable) -> int: 2205 return sum(len(arg) for arg in args) 2206 2207 def format_time(self, expression: exp.Expression) -> t.Optional[str]: 2208 return format_time(self.sql(expression, "format"), self.time_mapping, self.time_trie) 2209 2210 def expressions( 2211 self, 2212 expression: t.Optional[exp.Expression] = None, 2213 key: t.Optional[str] = None, 2214 sqls: t.Optional[t.List[str]] = None, 2215 flat: bool = False, 2216 indent: bool = True, 2217 sep: str = ", ", 2218 prefix: str = "", 2219 ) -> str: 2220 expressions = expression.args.get(key or "expressions") if expression else sqls 2221 2222 if not expressions: 2223 return "" 2224 2225 if flat: 2226 return sep.join(self.sql(e) for e in expressions) 2227 2228 num_sqls = len(expressions) 2229 2230 # These are calculated once in case we have the leading_comma / pretty option set, correspondingly 2231 pad = " " * self.pad 2232 stripped_sep = sep.strip() 2233 2234 result_sqls = [] 2235 for i, e in enumerate(expressions): 2236 sql = self.sql(e, comment=False) 2237 comments = self.maybe_comment("", e) if isinstance(e, exp.Expression) else "" 2238 2239 if self.pretty: 2240 if self._leading_comma: 2241 result_sqls.append(f"{sep if i > 0 else pad}{prefix}{sql}{comments}") 2242 else: 2243 result_sqls.append( 2244 f"{prefix}{sql}{stripped_sep if i + 1 < num_sqls else ''}{comments}" 2245 ) 2246 else: 2247 result_sqls.append(f"{prefix}{sql}{comments}{sep if i + 1 < num_sqls else ''}") 2248 2249 result_sql = "\n".join(result_sqls) if self.pretty else "".join(result_sqls) 2250 return self.indent(result_sql, skip_first=False) if indent else result_sql 2251 2252 def op_expressions(self, op: str, expression: exp.Expression, flat: bool = False) -> str: 2253 flat = flat or isinstance(expression.parent, exp.Properties) 2254 expressions_sql = self.expressions(expression, flat=flat) 2255 if flat: 2256 return f"{op} {expressions_sql}" 2257 return f"{self.seg(op)}{self.sep() if expressions_sql else ''}{expressions_sql}" 2258 2259 def naked_property(self, expression: exp.Property) -> str: 2260 property_name = exp.Properties.PROPERTY_TO_NAME.get(expression.__class__) 2261 if not property_name: 2262 self.unsupported(f"Unsupported property {expression.__class__.__name__}") 2263 return f"{property_name} {self.sql(expression, 'this')}" 2264 2265 def set_operation(self, expression: exp.Expression, op: str) -> str: 2266 this = self.sql(expression, "this") 2267 op = self.seg(op) 2268 return self.query_modifiers( 2269 expression, f"{this}{op}{self.sep()}{self.sql(expression, 'expression')}" 2270 ) 2271 2272 def tag_sql(self, expression: exp.Tag) -> str: 2273 return f"{expression.args.get('prefix')}{self.sql(expression.this)}{expression.args.get('postfix')}" 2274 2275 def token_sql(self, token_type: TokenType) -> str: 2276 return self.TOKEN_MAPPING.get(token_type, token_type.name) 2277 2278 def userdefinedfunction_sql(self, expression: exp.UserDefinedFunction) -> str: 2279 this = self.sql(expression, "this") 2280 expressions = self.no_identify(self.expressions, expression) 2281 expressions = ( 2282 self.wrap(expressions) if expression.args.get("wrapped") else f" {expressions}" 2283 ) 2284 return f"{this}{expressions}" 2285 2286 def joinhint_sql(self, expression: exp.JoinHint) -> str: 2287 this = self.sql(expression, "this") 2288 expressions = self.expressions(expression, flat=True) 2289 return f"{this}({expressions})" 2290 2291 def kwarg_sql(self, expression: exp.Kwarg) -> str: 2292 return self.binary(expression, "=>") 2293 2294 def when_sql(self, expression: exp.When) -> str: 2295 matched = "MATCHED" if expression.args["matched"] else "NOT MATCHED" 2296 source = " BY SOURCE" if self.MATCHED_BY_SOURCE and expression.args.get("source") else "" 2297 condition = self.sql(expression, "condition") 2298 condition = f" AND {condition}" if condition else "" 2299 2300 then_expression = expression.args.get("then") 2301 if isinstance(then_expression, exp.Insert): 2302 then = f"INSERT {self.sql(then_expression, 'this')}" 2303 if "expression" in then_expression.args: 2304 then += f" VALUES {self.sql(then_expression, 'expression')}" 2305 elif isinstance(then_expression, exp.Update): 2306 if isinstance(then_expression.args.get("expressions"), exp.Star): 2307 then = f"UPDATE {self.sql(then_expression, 'expressions')}" 2308 else: 2309 then = f"UPDATE SET {self.expressions(then_expression, flat=True)}" 2310 else: 2311 then = self.sql(then_expression) 2312 return f"WHEN {matched}{source}{condition} THEN {then}" 2313 2314 def merge_sql(self, expression: exp.Merge) -> str: 2315 this = self.sql(expression, "this") 2316 using = f"USING {self.sql(expression, 'using')}" 2317 on = f"ON {self.sql(expression, 'on')}" 2318 return f"MERGE INTO {this} {using} {on} {self.expressions(expression, sep=' ')}" 2319 2320 def tochar_sql(self, expression: exp.ToChar) -> str: 2321 if expression.args.get("format"): 2322 self.unsupported("Format argument unsupported for TO_CHAR/TO_VARCHAR function") 2323 2324 return self.sql(exp.cast(expression.this, "text"))
Generator interprets the given syntax tree and produces a SQL string as an output.
Arguments:
- time_mapping (dict): the dictionary of custom time mappings in which the key represents a python time format and the output the target time format
- time_trie (trie): a trie of the time_mapping keys
- pretty (bool): if set to True the returned string will be formatted. Default: False.
- quote_start (str): specifies which starting character to use to delimit quotes. Default: '.
- quote_end (str): specifies which ending character to use to delimit quotes. Default: '.
- identifier_start (str): specifies which starting character to use to delimit identifiers. Default: ".
- identifier_end (str): specifies which ending character to use to delimit identifiers. Default: ".
- bit_start (str): specifies which starting character to use to delimit bit literals. Default: None.
- bit_end (str): specifies which ending character to use to delimit bit literals. Default: None.
- hex_start (str): specifies which starting character to use to delimit hex literals. Default: None.
- hex_end (str): specifies which ending character to use to delimit hex literals. Default: None.
- byte_start (str): specifies which starting character to use to delimit byte literals. Default: None.
- byte_end (str): specifies which ending character to use to delimit byte literals. Default: None.
- raw_start (str): specifies which starting character to use to delimit raw literals. Default: None.
- raw_end (str): specifies which ending character to use to delimit raw literals. Default: None.
- identify (bool | str): 'always': always quote, 'safe': quote identifiers if they don't contain an upcase, True defaults to always.
- normalize (bool): if set to True all identifiers will lower cased
- string_escape (str): specifies a string escape character. Default: '.
- identifier_escape (str): specifies an identifier escape character. Default: ".
- pad (int): determines padding in a formatted string. Default: 2.
- indent (int): determines the size of indentation in a formatted string. Default: 4.
- unnest_column_only (bool): if true unnest table aliases are considered only as column aliases
- normalize_functions (str): normalize function names, "upper", "lower", or None Default: "upper"
- alias_post_tablesample (bool): if the table alias comes after tablesample Default: False
- unsupported_level (ErrorLevel): determines the generator's behavior when it encounters unsupported expressions. Default ErrorLevel.WARN.
- null_ordering (str): Indicates the default null ordering method to use if not explicitly set. Options are "nulls_are_small", "nulls_are_large", "nulls_are_last". Default: "nulls_are_small"
- max_unsupported (int): Maximum number of unsupported messages to include in a raised UnsupportedError. This is only relevant if unsupported_level is ErrorLevel.RAISE. Default: 3
- leading_comma (bool): if the the comma is leading or trailing in select statements Default: False
- max_text_width: The max number of characters in a segment before creating new lines in pretty mode. The default is on the smaller end because the length only represents a segment and not the true line length. Default: 80
- comments: Whether or not to preserve comments in the output SQL code. Default: True
Generator( time_mapping=None, time_trie=None, pretty=None, quote_start=None, quote_end=None, identifier_start=None, identifier_end=None, bit_start=None, bit_end=None, hex_start=None, hex_end=None, byte_start=None, byte_end=None, raw_start=None, raw_end=None, identify=False, normalize=False, string_escape=None, identifier_escape=None, pad=2, indent=2, index_offset=0, unnest_column_only=False, alias_post_tablesample=False, normalize_functions='upper', unsupported_level=<ErrorLevel.WARN: 'WARN'>, null_ordering=None, max_unsupported=3, leading_comma=False, max_text_width=80, comments=True)
282 def __init__( 283 self, 284 time_mapping=None, 285 time_trie=None, 286 pretty=None, 287 quote_start=None, 288 quote_end=None, 289 identifier_start=None, 290 identifier_end=None, 291 bit_start=None, 292 bit_end=None, 293 hex_start=None, 294 hex_end=None, 295 byte_start=None, 296 byte_end=None, 297 raw_start=None, 298 raw_end=None, 299 identify=False, 300 normalize=False, 301 string_escape=None, 302 identifier_escape=None, 303 pad=2, 304 indent=2, 305 index_offset=0, 306 unnest_column_only=False, 307 alias_post_tablesample=False, 308 normalize_functions="upper", 309 unsupported_level=ErrorLevel.WARN, 310 null_ordering=None, 311 max_unsupported=3, 312 leading_comma=False, 313 max_text_width=80, 314 comments=True, 315 ): 316 import sqlglot 317 318 self.time_mapping = time_mapping or {} 319 self.time_trie = time_trie 320 self.pretty = pretty if pretty is not None else sqlglot.pretty 321 self.quote_start = quote_start or "'" 322 self.quote_end = quote_end or "'" 323 self.identifier_start = identifier_start or '"' 324 self.identifier_end = identifier_end or '"' 325 self.bit_start = bit_start 326 self.bit_end = bit_end 327 self.hex_start = hex_start 328 self.hex_end = hex_end 329 self.byte_start = byte_start 330 self.byte_end = byte_end 331 self.raw_start = raw_start 332 self.raw_end = raw_end 333 self.identify = identify 334 self.normalize = normalize 335 self.string_escape = string_escape or "'" 336 self.identifier_escape = identifier_escape or '"' 337 self.pad = pad 338 self.index_offset = index_offset 339 self.unnest_column_only = unnest_column_only 340 self.alias_post_tablesample = alias_post_tablesample 341 self.normalize_functions = normalize_functions 342 self.unsupported_level = unsupported_level 343 self.unsupported_messages = [] 344 self.max_unsupported = max_unsupported 345 self.null_ordering = null_ordering 346 self._indent = indent 347 self._escaped_quote_end = self.string_escape + self.quote_end 348 self._escaped_identifier_end = self.identifier_escape + self.identifier_end 349 self._leading_comma = leading_comma 350 self._max_text_width = max_text_width 351 self._comments = comments 352 self._cache = None
def
generate( self, expression: Optional[sqlglot.expressions.Expression], cache: Optional[Dict[int, str]] = None) -> str:
354 def generate( 355 self, 356 expression: t.Optional[exp.Expression], 357 cache: t.Optional[t.Dict[int, str]] = None, 358 ) -> str: 359 """ 360 Generates a SQL string by interpreting the given syntax tree. 361 362 Args 363 expression: the syntax tree. 364 cache: an optional sql string cache. this leverages the hash of an expression which is slow, so only use this if you set _hash on each node. 365 366 Returns 367 the SQL string. 368 """ 369 if cache is not None: 370 self._cache = cache 371 self.unsupported_messages = [] 372 sql = self.sql(expression).strip() 373 self._cache = None 374 375 if self.unsupported_level == ErrorLevel.IGNORE: 376 return sql 377 378 if self.unsupported_level == ErrorLevel.WARN: 379 for msg in self.unsupported_messages: 380 logger.warning(msg) 381 elif self.unsupported_level == ErrorLevel.RAISE and self.unsupported_messages: 382 raise UnsupportedError(concat_messages(self.unsupported_messages, self.max_unsupported)) 383 384 if self.pretty: 385 sql = sql.replace(self.SENTINEL_LINE_BREAK, "\n") 386 return sql
Generates a SQL string by interpreting the given syntax tree.
Args expression: the syntax tree. cache: an optional sql string cache. this leverages the hash of an expression which is slow, so only use this if you set _hash on each node.
Returns the SQL string.
def
maybe_comment( self, sql: str, expression: Optional[sqlglot.expressions.Expression] = None, comments: Optional[List[str]] = None) -> str:
404 def maybe_comment( 405 self, 406 sql: str, 407 expression: t.Optional[exp.Expression] = None, 408 comments: t.Optional[t.List[str]] = None, 409 ) -> str: 410 comments = ((expression and expression.comments) if comments is None else comments) if self._comments else None # type: ignore 411 412 if not comments or isinstance(expression, exp.Binary): 413 return sql 414 415 sep = "\n" if self.pretty else " " 416 comments_sql = sep.join( 417 f"/*{self.pad_comment(comment)}*/" for comment in comments if comment 418 ) 419 420 if not comments_sql: 421 return sql 422 423 if isinstance(expression, self.WITH_SEPARATED_COMMENTS): 424 return ( 425 f"{self.sep()}{comments_sql}{sql}" 426 if sql[0].isspace() 427 else f"{comments_sql}{self.sep()}{sql}" 428 ) 429 430 return f"{sql} {comments_sql}"
432 def wrap(self, expression: exp.Expression | str) -> str: 433 this_sql = self.indent( 434 self.sql(expression) 435 if isinstance(expression, (exp.Select, exp.Union)) 436 else self.sql(expression, "this"), 437 level=1, 438 pad=0, 439 ) 440 return f"({self.sep('')}{this_sql}{self.seg(')', sep='')}"
def
indent( self, sql: str, level: int = 0, pad: Optional[int] = None, skip_first: bool = False, skip_last: bool = False) -> str:
456 def indent( 457 self, 458 sql: str, 459 level: int = 0, 460 pad: t.Optional[int] = None, 461 skip_first: bool = False, 462 skip_last: bool = False, 463 ) -> str: 464 if not self.pretty: 465 return sql 466 467 pad = self.pad if pad is None else pad 468 lines = sql.split("\n") 469 470 return "\n".join( 471 line 472 if (skip_first and i == 0) or (skip_last and i == len(lines) - 1) 473 else f"{' ' * (level * self._indent + pad)}{line}" 474 for i, line in enumerate(lines) 475 )
def
sql( self, expression: Union[str, sqlglot.expressions.Expression, NoneType], key: Optional[str] = None, comment: bool = True) -> str:
477 def sql( 478 self, 479 expression: t.Optional[str | exp.Expression], 480 key: t.Optional[str] = None, 481 comment: bool = True, 482 ) -> str: 483 if not expression: 484 return "" 485 486 if isinstance(expression, str): 487 return expression 488 489 if key: 490 return self.sql(expression.args.get(key)) 491 492 if self._cache is not None: 493 expression_id = hash(expression) 494 495 if expression_id in self._cache: 496 return self._cache[expression_id] 497 498 transform = self.TRANSFORMS.get(expression.__class__) 499 500 if callable(transform): 501 sql = transform(self, expression) 502 elif transform: 503 sql = transform 504 elif isinstance(expression, exp.Expression): 505 exp_handler_name = f"{expression.key}_sql" 506 507 if hasattr(self, exp_handler_name): 508 sql = getattr(self, exp_handler_name)(expression) 509 elif isinstance(expression, exp.Func): 510 sql = self.function_fallback_sql(expression) 511 elif isinstance(expression, exp.Property): 512 sql = self.property_sql(expression) 513 else: 514 raise ValueError(f"Unsupported expression type {expression.__class__.__name__}") 515 else: 516 raise ValueError(f"Expected an Expression. Received {type(expression)}: {expression}") 517 518 sql = self.maybe_comment(sql, expression) if self._comments and comment else sql 519 520 if self._cache is not None: 521 self._cache[expression_id] = sql 522 return sql
529 def cache_sql(self, expression: exp.Cache) -> str: 530 lazy = " LAZY" if expression.args.get("lazy") else "" 531 table = self.sql(expression, "this") 532 options = expression.args.get("options") 533 options = f" OPTIONS({self.sql(options[0])} = {self.sql(options[1])})" if options else "" 534 sql = self.sql(expression, "expression") 535 sql = f" AS{self.sep()}{sql}" if sql else "" 536 sql = f"CACHE{lazy} TABLE {table}{options}{sql}" 537 return self.prepend_ctes(expression, sql)
539 def characterset_sql(self, expression: exp.CharacterSet) -> str: 540 if isinstance(expression.parent, exp.Cast): 541 return f"CHAR CHARACTER SET {self.sql(expression, 'this')}" 542 default = "DEFAULT " if expression.args.get("default") else "" 543 return f"{default}CHARACTER SET={self.sql(expression, 'this')}"
563 def columndef_sql(self, expression: exp.ColumnDef, sep: str = " ") -> str: 564 column = self.sql(expression, "this") 565 kind = self.sql(expression, "kind") 566 constraints = self.expressions(expression, key="constraints", sep=" ", flat=True) 567 exists = "IF NOT EXISTS " if expression.args.get("exists") else "" 568 kind = f"{sep}{kind}" if kind else "" 569 constraints = f" {constraints}" if constraints else "" 570 position = self.sql(expression, "position") 571 position = f" {position}" if position else "" 572 573 return f"{exists}{column}{kind}{constraints}{position}"
def
compresscolumnconstraint_sql(self, expression: sqlglot.expressions.CompressColumnConstraint) -> str:
def
generatedasidentitycolumnconstraint_sql( self, expression: sqlglot.expressions.GeneratedAsIdentityColumnConstraint) -> str:
591 def generatedasidentitycolumnconstraint_sql( 592 self, expression: exp.GeneratedAsIdentityColumnConstraint 593 ) -> str: 594 this = "" 595 if expression.this is not None: 596 on_null = "ON NULL " if expression.args.get("on_null") else "" 597 this = " ALWAYS " if expression.this else f" BY DEFAULT {on_null}" 598 599 start = expression.args.get("start") 600 start = f"START WITH {start}" if start else "" 601 increment = expression.args.get("increment") 602 increment = f" INCREMENT BY {increment}" if increment else "" 603 minvalue = expression.args.get("minvalue") 604 minvalue = f" MINVALUE {minvalue}" if minvalue else "" 605 maxvalue = expression.args.get("maxvalue") 606 maxvalue = f" MAXVALUE {maxvalue}" if maxvalue else "" 607 cycle = expression.args.get("cycle") 608 cycle_sql = "" 609 610 if cycle is not None: 611 cycle_sql = f"{' NO' if not cycle else ''} CYCLE" 612 cycle_sql = cycle_sql.strip() if not start and not increment else cycle_sql 613 614 sequence_opts = "" 615 if start or increment or cycle_sql: 616 sequence_opts = f"{start}{increment}{minvalue}{maxvalue}{cycle_sql}" 617 sequence_opts = f" ({sequence_opts.strip()})" 618 619 expr = self.sql(expression, "expression") 620 expr = f"({expr})" if expr else "IDENTITY" 621 622 return f"GENERATED{this}AS {expr}{sequence_opts}"
def
notnullcolumnconstraint_sql(self, expression: sqlglot.expressions.NotNullColumnConstraint) -> str:
def
primarykeycolumnconstraint_sql(self, expression: sqlglot.expressions.PrimaryKeyColumnConstraint) -> str:
def
uniquecolumnconstraint_sql(self, expression: sqlglot.expressions.UniqueColumnConstraint) -> str:
638 def create_sql(self, expression: exp.Create) -> str: 639 kind = self.sql(expression, "kind").upper() 640 properties = expression.args.get("properties") 641 properties_exp = expression.copy() 642 properties_locs = self.locate_properties(properties) if properties else {} 643 if properties_locs.get(exp.Properties.Location.POST_SCHEMA) or properties_locs.get( 644 exp.Properties.Location.POST_WITH 645 ): 646 properties_exp.set( 647 "properties", 648 exp.Properties( 649 expressions=[ 650 *properties_locs[exp.Properties.Location.POST_SCHEMA], 651 *properties_locs[exp.Properties.Location.POST_WITH], 652 ] 653 ), 654 ) 655 if kind == "TABLE" and properties_locs.get(exp.Properties.Location.POST_NAME): 656 this_name = self.sql(expression.this, "this") 657 this_properties = self.properties( 658 exp.Properties(expressions=properties_locs[exp.Properties.Location.POST_NAME]), 659 wrapped=False, 660 ) 661 this_schema = f"({self.expressions(expression.this)})" 662 this = f"{this_name}, {this_properties} {this_schema}" 663 properties_sql = "" 664 else: 665 this = self.sql(expression, "this") 666 properties_sql = self.sql(properties_exp, "properties") 667 begin = " BEGIN" if expression.args.get("begin") else "" 668 expression_sql = self.sql(expression, "expression") 669 if expression_sql: 670 expression_sql = f"{begin}{self.sep()}{expression_sql}" 671 672 if self.CREATE_FUNCTION_RETURN_AS or not isinstance(expression.expression, exp.Return): 673 if properties_locs.get(exp.Properties.Location.POST_ALIAS): 674 postalias_props_sql = self.properties( 675 exp.Properties( 676 expressions=properties_locs[exp.Properties.Location.POST_ALIAS] 677 ), 678 wrapped=False, 679 ) 680 expression_sql = f" AS {postalias_props_sql}{expression_sql}" 681 else: 682 expression_sql = f" AS{expression_sql}" 683 684 postindex_props_sql = "" 685 if properties_locs.get(exp.Properties.Location.POST_INDEX): 686 postindex_props_sql = self.properties( 687 exp.Properties(expressions=properties_locs[exp.Properties.Location.POST_INDEX]), 688 wrapped=False, 689 prefix=" ", 690 ) 691 692 indexes = self.expressions(expression, key="indexes", indent=False, sep=" ") 693 indexes = f" {indexes}" if indexes else "" 694 index_sql = indexes + postindex_props_sql 695 696 replace = " OR REPLACE" if expression.args.get("replace") else "" 697 unique = " UNIQUE" if expression.args.get("unique") else "" 698 699 postcreate_props_sql = "" 700 if properties_locs.get(exp.Properties.Location.POST_CREATE): 701 postcreate_props_sql = self.properties( 702 exp.Properties(expressions=properties_locs[exp.Properties.Location.POST_CREATE]), 703 sep=" ", 704 prefix=" ", 705 wrapped=False, 706 ) 707 708 modifiers = "".join((replace, unique, postcreate_props_sql)) 709 710 postexpression_props_sql = "" 711 if properties_locs.get(exp.Properties.Location.POST_EXPRESSION): 712 postexpression_props_sql = self.properties( 713 exp.Properties( 714 expressions=properties_locs[exp.Properties.Location.POST_EXPRESSION] 715 ), 716 sep=" ", 717 prefix=" ", 718 wrapped=False, 719 ) 720 721 exists_sql = " IF NOT EXISTS" if expression.args.get("exists") else "" 722 no_schema_binding = ( 723 " WITH NO SCHEMA BINDING" if expression.args.get("no_schema_binding") else "" 724 ) 725 726 clone = self.sql(expression, "clone") 727 clone = f" {clone}" if clone else "" 728 729 expression_sql = f"CREATE{modifiers} {kind}{exists_sql} {this}{properties_sql}{expression_sql}{postexpression_props_sql}{index_sql}{no_schema_binding}{clone}" 730 return self.prepend_ctes(expression, expression_sql)
732 def clone_sql(self, expression: exp.Clone) -> str: 733 this = self.sql(expression, "this") 734 when = self.sql(expression, "when") 735 736 if when: 737 kind = self.sql(expression, "kind") 738 expr = self.sql(expression, "expression") 739 return f"CLONE {this} {when} ({kind} => {expr})" 740 741 return f"CLONE {this}"
797 def datatype_sql(self, expression: exp.DataType) -> str: 798 type_value = expression.this 799 type_sql = self.TYPE_MAPPING.get(type_value, type_value.value) 800 nested = "" 801 interior = self.expressions(expression, flat=True) 802 values = "" 803 if interior: 804 if expression.args.get("nested"): 805 nested = f"{self.STRUCT_DELIMITER[0]}{interior}{self.STRUCT_DELIMITER[1]}" 806 if expression.args.get("values") is not None: 807 delimiters = ("[", "]") if type_value == exp.DataType.Type.ARRAY else ("(", ")") 808 values = self.expressions(expression, key="values", flat=True) 809 values = f"{delimiters[0]}{values}{delimiters[1]}" 810 else: 811 nested = f"({interior})" 812 813 return f"{type_sql}{nested}{values}"
815 def directory_sql(self, expression: exp.Directory) -> str: 816 local = "LOCAL " if expression.args.get("local") else "" 817 row_format = self.sql(expression, "row_format") 818 row_format = f" {row_format}" if row_format else "" 819 return f"{local}DIRECTORY {self.sql(expression, 'this')}{row_format}"
821 def delete_sql(self, expression: exp.Delete) -> str: 822 this = self.sql(expression, "this") 823 this = f" FROM {this}" if this else "" 824 using_sql = ( 825 f" USING {self.expressions(expression, key='using', sep=', USING ')}" 826 if expression.args.get("using") 827 else "" 828 ) 829 where_sql = self.sql(expression, "where") 830 returning = self.sql(expression, "returning") 831 sql = f"DELETE{this}{using_sql}{where_sql}{returning}" 832 return self.prepend_ctes(expression, sql)
834 def drop_sql(self, expression: exp.Drop) -> str: 835 this = self.sql(expression, "this") 836 kind = expression.args["kind"] 837 exists_sql = " IF EXISTS " if expression.args.get("exists") else " " 838 temporary = " TEMPORARY" if expression.args.get("temporary") else "" 839 materialized = " MATERIALIZED" if expression.args.get("materialized") else "" 840 cascade = " CASCADE" if expression.args.get("cascade") else "" 841 constraints = " CONSTRAINTS" if expression.args.get("constraints") else "" 842 purge = " PURGE" if expression.args.get("purge") else "" 843 return ( 844 f"DROP{temporary}{materialized} {kind}{exists_sql}{this}{cascade}{constraints}{purge}" 845 )
856 def fetch_sql(self, expression: exp.Fetch) -> str: 857 direction = expression.args.get("direction") 858 direction = f" {direction.upper()}" if direction else "" 859 count = expression.args.get("count") 860 count = f" {count}" if count else "" 861 if expression.args.get("percent"): 862 count = f"{count} PERCENT" 863 with_ties_or_only = "WITH TIES" if expression.args.get("with_ties") else "ONLY" 864 return f"{self.seg('FETCH')}{direction}{count} ROWS {with_ties_or_only}"
876 def index_sql(self, expression: exp.Index) -> str: 877 unique = "UNIQUE " if expression.args.get("unique") else "" 878 primary = "PRIMARY " if expression.args.get("primary") else "" 879 amp = "AMP " if expression.args.get("amp") else "" 880 name = f"{expression.name} " if expression.name else "" 881 table = self.sql(expression, "table") 882 table = f"{self.INDEX_ON} {table} " if table else "" 883 index = "INDEX " if not table else "" 884 columns = self.expressions(expression, key="columns", flat=True) 885 partition_by = self.expressions(expression, key="partition_by", flat=True) 886 partition_by = f" PARTITION BY {partition_by}" if partition_by else "" 887 return f"{unique}{primary}{amp}{index}{name}{table}({columns}){partition_by}"
889 def identifier_sql(self, expression: exp.Identifier) -> str: 890 text = expression.name 891 lower = text.lower() 892 text = lower if self.normalize and not expression.quoted else text 893 text = text.replace(self.identifier_end, self._escaped_identifier_end) 894 if ( 895 expression.quoted 896 or should_identify(text, self.identify) 897 or lower in self.RESERVED_KEYWORDS 898 ): 899 text = f"{self.identifier_start}{text}{self.identifier_end}" 900 return text
902 def inputoutputformat_sql(self, expression: exp.InputOutputFormat) -> str: 903 input_format = self.sql(expression, "input_format") 904 input_format = f"INPUTFORMAT {input_format}" if input_format else "" 905 output_format = self.sql(expression, "output_format") 906 output_format = f"OUTPUTFORMAT {output_format}" if output_format else "" 907 return self.sep().join((input_format, output_format))
916 def properties_sql(self, expression: exp.Properties) -> str: 917 root_properties = [] 918 with_properties = [] 919 920 for p in expression.expressions: 921 p_loc = self.PROPERTIES_LOCATION[p.__class__] 922 if p_loc == exp.Properties.Location.POST_WITH: 923 with_properties.append(p) 924 elif p_loc == exp.Properties.Location.POST_SCHEMA: 925 root_properties.append(p) 926 927 return self.root_properties( 928 exp.Properties(expressions=root_properties) 929 ) + self.with_properties(exp.Properties(expressions=with_properties))
def
properties( self, properties: sqlglot.expressions.Properties, prefix: str = '', sep: str = ', ', suffix: str = '', wrapped: bool = True) -> str:
936 def properties( 937 self, 938 properties: exp.Properties, 939 prefix: str = "", 940 sep: str = ", ", 941 suffix: str = "", 942 wrapped: bool = True, 943 ) -> str: 944 if properties.expressions: 945 expressions = self.expressions(properties, sep=sep, indent=False) 946 expressions = self.wrap(expressions) if wrapped else expressions 947 return f"{prefix}{' ' if prefix and prefix != ' ' else ''}{expressions}{suffix}" 948 return ""
def
locate_properties( self, properties: sqlglot.expressions.Properties) -> Dict[sqlglot.expressions.Properties.Location, list[sqlglot.expressions.Property]]:
953 def locate_properties( 954 self, properties: exp.Properties 955 ) -> t.Dict[exp.Properties.Location, list[exp.Property]]: 956 properties_locs: t.Dict[exp.Properties.Location, list[exp.Property]] = { 957 key: [] for key in exp.Properties.Location 958 } 959 960 for p in properties.expressions: 961 p_loc = self.PROPERTIES_LOCATION[p.__class__] 962 if p_loc == exp.Properties.Location.POST_NAME: 963 properties_locs[exp.Properties.Location.POST_NAME].append(p) 964 elif p_loc == exp.Properties.Location.POST_INDEX: 965 properties_locs[exp.Properties.Location.POST_INDEX].append(p) 966 elif p_loc == exp.Properties.Location.POST_SCHEMA: 967 properties_locs[exp.Properties.Location.POST_SCHEMA].append(p) 968 elif p_loc == exp.Properties.Location.POST_WITH: 969 properties_locs[exp.Properties.Location.POST_WITH].append(p) 970 elif p_loc == exp.Properties.Location.POST_CREATE: 971 properties_locs[exp.Properties.Location.POST_CREATE].append(p) 972 elif p_loc == exp.Properties.Location.POST_ALIAS: 973 properties_locs[exp.Properties.Location.POST_ALIAS].append(p) 974 elif p_loc == exp.Properties.Location.POST_EXPRESSION: 975 properties_locs[exp.Properties.Location.POST_EXPRESSION].append(p) 976 elif p_loc == exp.Properties.Location.UNSUPPORTED: 977 self.unsupported(f"Unsupported property {p.key}") 978 979 return properties_locs
981 def property_sql(self, expression: exp.Property) -> str: 982 property_cls = expression.__class__ 983 if property_cls == exp.Property: 984 return f"{expression.name}={self.sql(expression, 'value')}" 985 986 property_name = exp.Properties.PROPERTY_TO_NAME.get(property_cls) 987 if not property_name: 988 self.unsupported(f"Unsupported property {expression.key}") 989 990 return f"{property_name}={self.sql(expression, 'this')}"
1002 def journalproperty_sql(self, expression: exp.JournalProperty) -> str: 1003 no = "NO " if expression.args.get("no") else "" 1004 local = expression.args.get("local") 1005 local = f"{local} " if local else "" 1006 dual = "DUAL " if expression.args.get("dual") else "" 1007 before = "BEFORE " if expression.args.get("before") else "" 1008 after = "AFTER " if expression.args.get("after") else "" 1009 return f"{no}{local}{dual}{before}{after}JOURNAL"
def
mergeblockratioproperty_sql(self, expression: sqlglot.expressions.MergeBlockRatioProperty) -> str:
1025 def mergeblockratioproperty_sql(self, expression: exp.MergeBlockRatioProperty) -> str: 1026 if expression.args.get("no"): 1027 return "NO MERGEBLOCKRATIO" 1028 if expression.args.get("default"): 1029 return "DEFAULT MERGEBLOCKRATIO" 1030 1031 percent = " PERCENT" if expression.args.get("percent") else "" 1032 return f"MERGEBLOCKRATIO={self.sql(expression, 'this')}{percent}"
1034 def datablocksizeproperty_sql(self, expression: exp.DataBlocksizeProperty) -> str: 1035 default = expression.args.get("default") 1036 minimum = expression.args.get("minimum") 1037 maximum = expression.args.get("maximum") 1038 if default or minimum or maximum: 1039 if default: 1040 prop = "DEFAULT" 1041 elif minimum: 1042 prop = "MINIMUM" 1043 else: 1044 prop = "MAXIMUM" 1045 return f"{prop} DATABLOCKSIZE" 1046 units = expression.args.get("units") 1047 units = f" {units}" if units else "" 1048 return f"DATABLOCKSIZE={self.sql(expression, 'size')}{units}"
def
blockcompressionproperty_sql(self, expression: sqlglot.expressions.BlockCompressionProperty) -> str:
1050 def blockcompressionproperty_sql(self, expression: exp.BlockCompressionProperty) -> str: 1051 autotemp = expression.args.get("autotemp") 1052 always = expression.args.get("always") 1053 default = expression.args.get("default") 1054 manual = expression.args.get("manual") 1055 never = expression.args.get("never") 1056 1057 if autotemp is not None: 1058 prop = f"AUTOTEMP({self.expressions(autotemp)})" 1059 elif always: 1060 prop = "ALWAYS" 1061 elif default: 1062 prop = "DEFAULT" 1063 elif manual: 1064 prop = "MANUAL" 1065 elif never: 1066 prop = "NEVER" 1067 return f"BLOCKCOMPRESSION={prop}"
def
isolatedloadingproperty_sql(self, expression: sqlglot.expressions.IsolatedLoadingProperty) -> str:
1069 def isolatedloadingproperty_sql(self, expression: exp.IsolatedLoadingProperty) -> str: 1070 no = expression.args.get("no") 1071 no = " NO" if no else "" 1072 concurrent = expression.args.get("concurrent") 1073 concurrent = " CONCURRENT" if concurrent else "" 1074 1075 for_ = "" 1076 if expression.args.get("for_all"): 1077 for_ = " FOR ALL" 1078 elif expression.args.get("for_insert"): 1079 for_ = " FOR INSERT" 1080 elif expression.args.get("for_none"): 1081 for_ = " FOR NONE" 1082 return f"WITH{no}{concurrent} ISOLATED LOADING{for_}"
1084 def lockingproperty_sql(self, expression: exp.LockingProperty) -> str: 1085 kind = expression.args.get("kind") 1086 this: str = f" {this}" if expression.this else "" 1087 for_or_in = expression.args.get("for_or_in") 1088 lock_type = expression.args.get("lock_type") 1089 override = " OVERRIDE" if expression.args.get("override") else "" 1090 return f"LOCKING {kind}{this} {for_or_in} {lock_type}{override}"
1092 def withdataproperty_sql(self, expression: exp.WithDataProperty) -> str: 1093 data_sql = f"WITH {'NO ' if expression.args.get('no') else ''}DATA" 1094 statistics = expression.args.get("statistics") 1095 statistics_sql = "" 1096 if statistics is not None: 1097 statistics_sql = f" AND {'NO ' if not statistics else ''}STATISTICS" 1098 return f"{data_sql}{statistics_sql}"
1100 def insert_sql(self, expression: exp.Insert) -> str: 1101 overwrite = expression.args.get("overwrite") 1102 1103 if isinstance(expression.this, exp.Directory): 1104 this = "OVERWRITE " if overwrite else "INTO " 1105 else: 1106 this = "OVERWRITE TABLE " if overwrite else "INTO " 1107 1108 alternative = expression.args.get("alternative") 1109 alternative = f" OR {alternative} " if alternative else " " 1110 this = f"{this}{self.sql(expression, 'this')}" 1111 1112 exists = " IF EXISTS " if expression.args.get("exists") else " " 1113 partition_sql = ( 1114 self.sql(expression, "partition") if expression.args.get("partition") else "" 1115 ) 1116 expression_sql = self.sql(expression, "expression") 1117 conflict = self.sql(expression, "conflict") 1118 returning = self.sql(expression, "returning") 1119 sep = self.sep() if partition_sql else "" 1120 sql = f"INSERT{alternative}{this}{exists}{partition_sql}{sep}{expression_sql}{conflict}{returning}" 1121 return self.prepend_ctes(expression, sql)
1138 def onconflict_sql(self, expression: exp.OnConflict) -> str: 1139 conflict = "ON DUPLICATE KEY" if expression.args.get("duplicate") else "ON CONFLICT" 1140 constraint = self.sql(expression, "constraint") 1141 if constraint: 1142 constraint = f"ON CONSTRAINT {constraint}" 1143 key = self.expressions(expression, key="key", flat=True) 1144 do = "" if expression.args.get("duplicate") else " DO " 1145 nothing = "NOTHING" if expression.args.get("nothing") else "" 1146 expressions = self.expressions(expression, flat=True) 1147 if expressions: 1148 expressions = f"UPDATE SET {expressions}" 1149 return f"{self.seg(conflict)} {constraint}{key}{do}{nothing}{expressions}"
def
rowformatdelimitedproperty_sql(self, expression: sqlglot.expressions.RowFormatDelimitedProperty) -> str:
1154 def rowformatdelimitedproperty_sql(self, expression: exp.RowFormatDelimitedProperty) -> str: 1155 fields = expression.args.get("fields") 1156 fields = f" FIELDS TERMINATED BY {fields}" if fields else "" 1157 escaped = expression.args.get("escaped") 1158 escaped = f" ESCAPED BY {escaped}" if escaped else "" 1159 items = expression.args.get("collection_items") 1160 items = f" COLLECTION ITEMS TERMINATED BY {items}" if items else "" 1161 keys = expression.args.get("map_keys") 1162 keys = f" MAP KEYS TERMINATED BY {keys}" if keys else "" 1163 lines = expression.args.get("lines") 1164 lines = f" LINES TERMINATED BY {lines}" if lines else "" 1165 null = expression.args.get("null") 1166 null = f" NULL DEFINED AS {null}" if null else "" 1167 return f"ROW FORMAT DELIMITED{fields}{escaped}{items}{keys}{lines}{null}"
1169 def table_sql(self, expression: exp.Table, sep: str = " AS ") -> str: 1170 table = ".".join( 1171 part 1172 for part in [ 1173 self.sql(expression, "catalog"), 1174 self.sql(expression, "db"), 1175 self.sql(expression, "this"), 1176 ] 1177 if part 1178 ) 1179 1180 alias = self.sql(expression, "alias") 1181 alias = f"{sep}{alias}" if alias else "" 1182 hints = self.expressions(expression, key="hints", flat=True) 1183 hints = f" WITH ({hints})" if hints and self.TABLE_HINTS else "" 1184 pivots = self.expressions(expression, key="pivots", sep=" ", flat=True) 1185 pivots = f" {pivots}" if pivots else "" 1186 joins = self.expressions(expression, key="joins", sep="") 1187 laterals = self.expressions(expression, key="laterals", sep="") 1188 system_time = expression.args.get("system_time") 1189 system_time = f" {self.sql(expression, 'system_time')}" if system_time else "" 1190 1191 return f"{table}{system_time}{alias}{hints}{pivots}{joins}{laterals}"
def
tablesample_sql( self, expression: sqlglot.expressions.TableSample, seed_prefix: str = 'SEED', sep=' AS ') -> str:
1193 def tablesample_sql( 1194 self, expression: exp.TableSample, seed_prefix: str = "SEED", sep=" AS " 1195 ) -> str: 1196 if self.alias_post_tablesample and expression.this.alias: 1197 table = expression.this.copy() 1198 table.set("alias", None) 1199 this = self.sql(table) 1200 alias = f"{sep}{self.sql(expression.this, 'alias')}" 1201 else: 1202 this = self.sql(expression, "this") 1203 alias = "" 1204 method = self.sql(expression, "method") 1205 method = f"{method.upper()} " if method and self.TABLESAMPLE_WITH_METHOD else "" 1206 numerator = self.sql(expression, "bucket_numerator") 1207 denominator = self.sql(expression, "bucket_denominator") 1208 field = self.sql(expression, "bucket_field") 1209 field = f" ON {field}" if field else "" 1210 bucket = f"BUCKET {numerator} OUT OF {denominator}{field}" if numerator else "" 1211 percent = self.sql(expression, "percent") 1212 percent = f"{percent} PERCENT" if percent else "" 1213 rows = self.sql(expression, "rows") 1214 rows = f"{rows} ROWS" if rows else "" 1215 size = self.sql(expression, "size") 1216 if size and self.TABLESAMPLE_SIZE_IS_PERCENT: 1217 size = f"{size} PERCENT" 1218 seed = self.sql(expression, "seed") 1219 seed = f" {seed_prefix} ({seed})" if seed else "" 1220 kind = expression.args.get("kind", "TABLESAMPLE") 1221 return f"{this} {kind} {method}({bucket}{percent}{rows}{size}){seed}{alias}"
1223 def pivot_sql(self, expression: exp.Pivot) -> str: 1224 expressions = self.expressions(expression, flat=True) 1225 1226 if expression.this: 1227 this = self.sql(expression, "this") 1228 on = f"{self.seg('ON')} {expressions}" 1229 using = self.expressions(expression, key="using", flat=True) 1230 using = f"{self.seg('USING')} {using}" if using else "" 1231 group = self.sql(expression, "group") 1232 return f"PIVOT {this}{on}{using}{group}" 1233 1234 alias = self.sql(expression, "alias") 1235 alias = f" AS {alias}" if alias else "" 1236 unpivot = expression.args.get("unpivot") 1237 direction = "UNPIVOT" if unpivot else "PIVOT" 1238 field = self.sql(expression, "field") 1239 return f"{direction}({expressions} FOR {field}){alias}"
1244 def update_sql(self, expression: exp.Update) -> str: 1245 this = self.sql(expression, "this") 1246 set_sql = self.expressions(expression, flat=True) 1247 from_sql = self.sql(expression, "from") 1248 where_sql = self.sql(expression, "where") 1249 returning = self.sql(expression, "returning") 1250 sql = f"UPDATE {this} SET {set_sql}{from_sql}{where_sql}{returning}" 1251 return self.prepend_ctes(expression, sql)
1253 def values_sql(self, expression: exp.Values) -> str: 1254 args = self.expressions(expression) 1255 alias = self.sql(expression, "alias") 1256 values = f"VALUES{self.seg('')}{args}" 1257 values = ( 1258 f"({values})" 1259 if self.WRAP_DERIVED_VALUES and (alias or isinstance(expression.parent, exp.From)) 1260 else values 1261 ) 1262 return f"{values} AS {alias}" if alias else values
1275 def group_sql(self, expression: exp.Group) -> str: 1276 group_by = self.op_expressions("GROUP BY", expression) 1277 grouping_sets = self.expressions(expression, key="grouping_sets", indent=False) 1278 grouping_sets = ( 1279 f"{self.seg('GROUPING SETS')} {self.wrap(grouping_sets)}" if grouping_sets else "" 1280 ) 1281 1282 cube = expression.args.get("cube", []) 1283 if seq_get(cube, 0) is True: 1284 return f"{group_by}{self.seg('WITH CUBE')}" 1285 else: 1286 cube_sql = self.expressions(expression, key="cube", indent=False) 1287 cube_sql = f"{self.seg('CUBE')} {self.wrap(cube_sql)}" if cube_sql else "" 1288 1289 rollup = expression.args.get("rollup", []) 1290 if seq_get(rollup, 0) is True: 1291 return f"{group_by}{self.seg('WITH ROLLUP')}" 1292 else: 1293 rollup_sql = self.expressions(expression, key="rollup", indent=False) 1294 rollup_sql = f"{self.seg('ROLLUP')} {self.wrap(rollup_sql)}" if rollup_sql else "" 1295 1296 groupings = csv( 1297 grouping_sets, 1298 cube_sql, 1299 rollup_sql, 1300 self.seg("WITH TOTALS") if expression.args.get("totals") else "", 1301 sep=self.GROUPINGS_SEP, 1302 ) 1303 1304 if expression.args.get("expressions") and groupings: 1305 group_by = f"{group_by}{self.GROUPINGS_SEP}" 1306 1307 return f"{group_by}{groupings}"
1313 def join_sql(self, expression: exp.Join) -> str: 1314 op_sql = " ".join( 1315 op 1316 for op in ( 1317 "NATURAL" if expression.args.get("natural") else None, 1318 "GLOBAL" if expression.args.get("global") else None, 1319 expression.side, 1320 expression.kind, 1321 expression.hint if self.JOIN_HINTS else None, 1322 ) 1323 if op 1324 ) 1325 on_sql = self.sql(expression, "on") 1326 using = expression.args.get("using") 1327 1328 if not on_sql and using: 1329 on_sql = csv(*(self.sql(column) for column in using)) 1330 1331 this_sql = self.sql(expression, "this") 1332 1333 if on_sql: 1334 on_sql = self.indent(on_sql, skip_first=True) 1335 space = self.seg(" " * self.pad) if self.pretty else " " 1336 if using: 1337 on_sql = f"{space}USING ({on_sql})" 1338 else: 1339 on_sql = f"{space}ON {on_sql}" 1340 elif not op_sql: 1341 return f", {this_sql}" 1342 1343 op_sql = f"{op_sql} JOIN" if op_sql else "JOIN" 1344 return f"{self.seg(op_sql)} {this_sql}{on_sql}"
1351 def lateral_sql(self, expression: exp.Lateral) -> str: 1352 this = self.sql(expression, "this") 1353 1354 if isinstance(expression.this, exp.Subquery): 1355 return f"LATERAL {this}" 1356 1357 if expression.args.get("view"): 1358 alias = expression.args["alias"] 1359 columns = self.expressions(alias, key="columns", flat=True) 1360 table = f" {alias.name}" if alias.name else "" 1361 columns = f" AS {columns}" if columns else "" 1362 op_sql = self.seg(f"LATERAL VIEW{' OUTER' if expression.args.get('outer') else ''}") 1363 return f"{op_sql}{self.sep()}{this}{table}{columns}" 1364 1365 alias = self.sql(expression, "alias") 1366 alias = f" AS {alias}" if alias else "" 1367 return f"LATERAL {this}{alias}"
1377 def setitem_sql(self, expression: exp.SetItem) -> str: 1378 kind = self.sql(expression, "kind") 1379 kind = f"{kind} " if kind else "" 1380 this = self.sql(expression, "this") 1381 expressions = self.expressions(expression) 1382 collate = self.sql(expression, "collate") 1383 collate = f" COLLATE {collate}" if collate else "" 1384 global_ = "GLOBAL " if expression.args.get("global") else "" 1385 return f"{global_}{kind}{this}{expressions}{collate}"
1396 def lock_sql(self, expression: exp.Lock) -> str: 1397 if not self.LOCKING_READS_SUPPORTED: 1398 self.unsupported("Locking reads using 'FOR UPDATE/SHARE' are not supported") 1399 return "" 1400 1401 lock_type = "FOR UPDATE" if expression.args["update"] else "FOR SHARE" 1402 expressions = self.expressions(expression, flat=True) 1403 expressions = f" OF {expressions}" if expressions else "" 1404 wait = expression.args.get("wait") 1405 1406 if wait is not None: 1407 if isinstance(wait, exp.Literal): 1408 wait = f" WAIT {self.sql(wait)}" 1409 else: 1410 wait = " NOWAIT" if wait else " SKIP LOCKED" 1411 1412 return f"{lock_type}{expressions}{wait or ''}"
1414 def literal_sql(self, expression: exp.Literal) -> str: 1415 text = expression.this or "" 1416 if expression.is_string: 1417 text = text.replace(self.quote_end, self._escaped_quote_end) 1418 if self.pretty: 1419 text = text.replace("\n", self.SENTINEL_LINE_BREAK) 1420 text = f"{self.quote_start}{text}{self.quote_end}" 1421 return text
1423 def loaddata_sql(self, expression: exp.LoadData) -> str: 1424 local = " LOCAL" if expression.args.get("local") else "" 1425 inpath = f" INPATH {self.sql(expression, 'inpath')}" 1426 overwrite = " OVERWRITE" if expression.args.get("overwrite") else "" 1427 this = f" INTO TABLE {self.sql(expression, 'this')}" 1428 partition = self.sql(expression, "partition") 1429 partition = f" {partition}" if partition else "" 1430 input_format = self.sql(expression, "input_format") 1431 input_format = f" INPUTFORMAT {input_format}" if input_format else "" 1432 serde = self.sql(expression, "serde") 1433 serde = f" SERDE {serde}" if serde else "" 1434 return f"LOAD DATA{local}{inpath}{overwrite}{this}{partition}{input_format}{serde}"
1456 def ordered_sql(self, expression: exp.Ordered) -> str: 1457 desc = expression.args.get("desc") 1458 asc = not desc 1459 1460 nulls_first = expression.args.get("nulls_first") 1461 nulls_last = not nulls_first 1462 nulls_are_large = self.null_ordering == "nulls_are_large" 1463 nulls_are_small = self.null_ordering == "nulls_are_small" 1464 nulls_are_last = self.null_ordering == "nulls_are_last" 1465 1466 sort_order = " DESC" if desc else "" 1467 nulls_sort_change = "" 1468 if nulls_first and ( 1469 (asc and nulls_are_large) or (desc and nulls_are_small) or nulls_are_last 1470 ): 1471 nulls_sort_change = " NULLS FIRST" 1472 elif ( 1473 nulls_last 1474 and ((asc and nulls_are_small) or (desc and nulls_are_large)) 1475 and not nulls_are_last 1476 ): 1477 nulls_sort_change = " NULLS LAST" 1478 1479 if nulls_sort_change and not self.NULL_ORDERING_SUPPORTED: 1480 self.unsupported( 1481 "Sorting in an ORDER BY on NULLS FIRST/NULLS LAST is not supported by this dialect" 1482 ) 1483 nulls_sort_change = "" 1484 1485 return f"{self.sql(expression, 'this')}{sort_order}{nulls_sort_change}"
1487 def matchrecognize_sql(self, expression: exp.MatchRecognize) -> str: 1488 partition = self.partition_by_sql(expression) 1489 order = self.sql(expression, "order") 1490 measures = self.expressions(expression, key="measures") 1491 measures = self.seg(f"MEASURES{self.seg(measures)}") if measures else "" 1492 rows = self.sql(expression, "rows") 1493 rows = self.seg(rows) if rows else "" 1494 after = self.sql(expression, "after") 1495 after = self.seg(after) if after else "" 1496 pattern = self.sql(expression, "pattern") 1497 pattern = self.seg(f"PATTERN ({pattern})") if pattern else "" 1498 definition_sqls = [ 1499 f"{self.sql(definition, 'alias')} AS {self.sql(definition, 'this')}" 1500 for definition in expression.args.get("define", []) 1501 ] 1502 definitions = self.expressions(sqls=definition_sqls) 1503 define = self.seg(f"DEFINE{self.seg(definitions)}") if definitions else "" 1504 body = "".join( 1505 ( 1506 partition, 1507 order, 1508 measures, 1509 rows, 1510 after, 1511 pattern, 1512 define, 1513 ) 1514 ) 1515 alias = self.sql(expression, "alias") 1516 alias = f" {alias}" if alias else "" 1517 return f"{self.seg('MATCH_RECOGNIZE')} {self.wrap(body)}{alias}"
1519 def query_modifiers(self, expression: exp.Expression, *sqls: str) -> str: 1520 limit = expression.args.get("limit") 1521 1522 if self.LIMIT_FETCH == "LIMIT" and isinstance(limit, exp.Fetch): 1523 limit = exp.Limit(expression=limit.args.get("count")) 1524 elif self.LIMIT_FETCH == "FETCH" and isinstance(limit, exp.Limit): 1525 limit = exp.Fetch(direction="FIRST", count=limit.expression) 1526 1527 fetch = isinstance(limit, exp.Fetch) 1528 1529 return csv( 1530 *sqls, 1531 *[self.sql(join) for join in expression.args.get("joins") or []], 1532 self.sql(expression, "match"), 1533 *[self.sql(lateral) for lateral in expression.args.get("laterals") or []], 1534 self.sql(expression, "where"), 1535 self.sql(expression, "group"), 1536 self.sql(expression, "having"), 1537 *self.after_having_modifiers(expression), 1538 self.sql(expression, "order"), 1539 self.sql(expression, "offset") if fetch else self.sql(limit), 1540 self.sql(limit) if fetch else self.sql(expression, "offset"), 1541 *self.after_limit_modifiers(expression), 1542 sep="", 1543 )
1558 def select_sql(self, expression: exp.Select) -> str: 1559 hint = self.sql(expression, "hint") 1560 distinct = self.sql(expression, "distinct") 1561 distinct = f" {distinct}" if distinct else "" 1562 kind = expression.args.get("kind") 1563 kind = f" AS {kind}" if kind else "" 1564 expressions = self.expressions(expression) 1565 expressions = f"{self.sep()}{expressions}" if expressions else expressions 1566 sql = self.query_modifiers( 1567 expression, 1568 f"SELECT{hint}{distinct}{kind}{expressions}", 1569 self.sql(expression, "into", comment=False), 1570 self.sql(expression, "from", comment=False), 1571 ) 1572 return self.prepend_ctes(expression, sql)
1580 def star_sql(self, expression: exp.Star) -> str: 1581 except_ = self.expressions(expression, key="except", flat=True) 1582 except_ = f"{self.seg(self.STAR_MAPPING['except'])} ({except_})" if except_ else "" 1583 replace = self.expressions(expression, key="replace", flat=True) 1584 replace = f"{self.seg(self.STAR_MAPPING['replace'])} ({replace})" if replace else "" 1585 return f"*{except_}{replace}"
1602 def subquery_sql(self, expression: exp.Subquery, sep: str = " AS ") -> str: 1603 alias = self.sql(expression, "alias") 1604 alias = f"{sep}{alias}" if alias else "" 1605 1606 pivots = self.expressions(expression, key="pivots", sep=" ", flat=True) 1607 pivots = f" {pivots}" if pivots else "" 1608 1609 sql = self.query_modifiers(expression, self.wrap(expression), alias, pivots) 1610 return self.prepend_ctes(expression, sql)
1627 def unnest_sql(self, expression: exp.Unnest) -> str: 1628 args = self.expressions(expression, flat=True) 1629 alias = expression.args.get("alias") 1630 if alias and self.unnest_column_only: 1631 columns = alias.columns 1632 alias = self.sql(columns[0]) if columns else "" 1633 else: 1634 alias = self.sql(expression, "alias") 1635 alias = f" AS {alias}" if alias else alias 1636 ordinality = " WITH ORDINALITY" if expression.args.get("ordinality") else "" 1637 offset = expression.args.get("offset") 1638 offset = f" WITH OFFSET AS {self.sql(offset)}" if offset else "" 1639 return f"UNNEST({args}){ordinality}{alias}{offset}"
1645 def window_sql(self, expression: exp.Window) -> str: 1646 this = self.sql(expression, "this") 1647 1648 partition = self.partition_by_sql(expression) 1649 1650 order = expression.args.get("order") 1651 order_sql = self.order_sql(order, flat=True) if order else "" 1652 1653 partition_sql = partition + " " if partition and order else partition 1654 1655 spec = expression.args.get("spec") 1656 spec_sql = " " + self.windowspec_sql(spec) if spec else "" 1657 1658 alias = self.sql(expression, "alias") 1659 over = self.sql(expression, "over") or "OVER" 1660 this = f"{this} {'AS' if expression.arg_key == 'windows' else over}" 1661 1662 first = expression.args.get("first") 1663 if first is not None: 1664 first = " FIRST " if first else " LAST " 1665 first = first or "" 1666 1667 if not partition and not order and not spec and alias: 1668 return f"{this} {alias}" 1669 1670 window_args = alias + first + partition_sql + order_sql + spec_sql 1671 1672 return f"{this} ({window_args.strip()})"
def
partition_by_sql( self, expression: sqlglot.expressions.Window | sqlglot.expressions.MatchRecognize) -> str:
1678 def windowspec_sql(self, expression: exp.WindowSpec) -> str: 1679 kind = self.sql(expression, "kind") 1680 start = csv(self.sql(expression, "start"), self.sql(expression, "start_side"), sep=" ") 1681 end = ( 1682 csv(self.sql(expression, "end"), self.sql(expression, "end_side"), sep=" ") 1683 or "CURRENT ROW" 1684 ) 1685 return f"{kind} BETWEEN {start} AND {end}"
1716 def case_sql(self, expression: exp.Case) -> str: 1717 this = self.sql(expression, "this") 1718 statements = [f"CASE {this}" if this else "CASE"] 1719 1720 for e in expression.args["ifs"]: 1721 statements.append(f"WHEN {self.sql(e, 'this')}") 1722 statements.append(f"THEN {self.sql(e, 'true')}") 1723 1724 default = self.sql(expression, "default") 1725 1726 if default: 1727 statements.append(f"ELSE {default}") 1728 1729 statements.append("END") 1730 1731 if self.pretty and self.text_width(statements) > self._max_text_width: 1732 return self.indent("\n".join(statements), skip_first=True, skip_last=True) 1733 1734 return " ".join(statements)
1751 def trim_sql(self, expression: exp.Trim) -> str: 1752 trim_type = self.sql(expression, "position") 1753 1754 if trim_type == "LEADING": 1755 return self.func("LTRIM", expression.this) 1756 elif trim_type == "TRAILING": 1757 return self.func("RTRIM", expression.this) 1758 else: 1759 return self.func("TRIM", expression.this, expression.expression)
1770 def foreignkey_sql(self, expression: exp.ForeignKey) -> str: 1771 expressions = self.expressions(expression, flat=True) 1772 reference = self.sql(expression, "reference") 1773 reference = f" {reference}" if reference else "" 1774 delete = self.sql(expression, "delete") 1775 delete = f" ON DELETE {delete}" if delete else "" 1776 update = self.sql(expression, "update") 1777 update = f" ON UPDATE {update}" if update else "" 1778 return f"FOREIGN KEY ({expressions}){reference}{delete}{update}"
1780 def primarykey_sql(self, expression: exp.ForeignKey) -> str: 1781 expressions = self.expressions(expression, flat=True) 1782 options = self.expressions(expression, key="options", flat=True, sep=" ") 1783 options = f" {options}" if options else "" 1784 return f"PRIMARY KEY ({expressions}){options}"
1799 def jsonobject_sql(self, expression: exp.JSONObject) -> str: 1800 expressions = self.expressions(expression) 1801 null_handling = expression.args.get("null_handling") 1802 null_handling = f" {null_handling}" if null_handling else "" 1803 unique_keys = expression.args.get("unique_keys") 1804 if unique_keys is not None: 1805 unique_keys = f" {'WITH' if unique_keys else 'WITHOUT'} UNIQUE KEYS" 1806 else: 1807 unique_keys = "" 1808 return_type = self.sql(expression, "return_type") 1809 return_type = f" RETURNING {return_type}" if return_type else "" 1810 format_json = " FORMAT JSON" if expression.args.get("format_json") else "" 1811 encoding = self.sql(expression, "encoding") 1812 encoding = f" ENCODING {encoding}" if encoding else "" 1813 return f"JSON_OBJECT({expressions}{null_handling}{unique_keys}{return_type}{format_json}{encoding})"
1815 def openjsoncolumndef_sql(self, expression: exp.OpenJSONColumnDef) -> str: 1816 this = self.sql(expression, "this") 1817 kind = self.sql(expression, "kind") 1818 path = self.sql(expression, "path") 1819 path = f" {path}" if path else "" 1820 as_json = " AS JSON" if expression.args.get("as_json") else "" 1821 return f"{this} {kind}{path}{as_json}"
1823 def openjson_sql(self, expression: exp.OpenJSON) -> str: 1824 this = self.sql(expression, "this") 1825 path = self.sql(expression, "path") 1826 path = f", {path}" if path else "" 1827 expressions = self.expressions(expression) 1828 with_ = ( 1829 f" WITH ({self.seg(self.indent(expressions), sep='')}{self.seg(')', sep='')}" 1830 if expressions 1831 else "" 1832 ) 1833 return f"OPENJSON({this}{path}){with_}"
1835 def in_sql(self, expression: exp.In) -> str: 1836 query = expression.args.get("query") 1837 unnest = expression.args.get("unnest") 1838 field = expression.args.get("field") 1839 is_global = " GLOBAL" if expression.args.get("is_global") else "" 1840 1841 if query: 1842 in_sql = self.wrap(query) 1843 elif unnest: 1844 in_sql = self.in_unnest_op(unnest) 1845 elif field: 1846 in_sql = self.sql(field) 1847 else: 1848 in_sql = f"({self.expressions(expression, flat=True)})" 1849 1850 return f"{self.sql(expression, 'this')}{is_global} IN {in_sql}"
1855 def interval_sql(self, expression: exp.Interval) -> str: 1856 unit = self.sql(expression, "unit") 1857 if not self.INTERVAL_ALLOWS_PLURAL_FORM: 1858 unit = self.TIME_PART_SINGULARS.get(unit.lower(), unit) 1859 unit = f" {unit}" if unit else "" 1860 1861 if self.SINGLE_STRING_INTERVAL: 1862 this = expression.this.name if expression.this else "" 1863 return f"INTERVAL '{this}{unit}'" if this else f"INTERVAL{unit}" 1864 1865 this = self.sql(expression, "this") 1866 if this: 1867 unwrapped = isinstance(expression.this, self.UNWRAPPED_INTERVAL_VALUES) 1868 this = f" {this}" if unwrapped else f" ({this})" 1869 1870 return f"INTERVAL{this}{unit}"
1875 def reference_sql(self, expression: exp.Reference) -> str: 1876 this = self.sql(expression, "this") 1877 expressions = self.expressions(expression, flat=True) 1878 expressions = f"({expressions})" if expressions else "" 1879 options = self.expressions(expression, key="options", flat=True, sep=" ") 1880 options = f" {options}" if options else "" 1881 return f"REFERENCES {this}{expressions}{options}"
1886 def paren_sql(self, expression: exp.Paren) -> str: 1887 if isinstance(expression.unnest(), exp.Select): 1888 sql = self.wrap(expression) 1889 else: 1890 sql = self.seg(self.indent(self.sql(expression, "this")), sep="") 1891 sql = f"({sql}{self.seg(')', sep='')}" 1892 1893 return self.prepend_ctes(expression, sql)
1923 def connector_sql(self, expression: exp.Connector, op: str) -> str: 1924 if not self.pretty: 1925 return self.binary(expression, op) 1926 1927 sqls = tuple( 1928 self.maybe_comment(self.sql(e), e, e.parent.comments or []) if i != 1 else self.sql(e) 1929 for i, e in enumerate(expression.flatten(unnest=False)) 1930 ) 1931 1932 sep = "\n" if self.text_width(sqls) > self._max_text_width else " " 1933 return f"{sep}{op} ".join(sqls)
1966 def comment_sql(self, expression: exp.Comment) -> str: 1967 this = self.sql(expression, "this") 1968 kind = expression.args["kind"] 1969 exists_sql = " IF EXISTS " if expression.args.get("exists") else " " 1970 expression_sql = self.sql(expression, "expression") 1971 return f"COMMENT{exists_sql}ON {kind} {this} IS {expression_sql}"
1973 def mergetreettlaction_sql(self, expression: exp.MergeTreeTTLAction) -> str: 1974 this = self.sql(expression, "this") 1975 delete = " DELETE" if expression.args.get("delete") else "" 1976 recompress = self.sql(expression, "recompress") 1977 recompress = f" RECOMPRESS {recompress}" if recompress else "" 1978 to_disk = self.sql(expression, "to_disk") 1979 to_disk = f" TO DISK {to_disk}" if to_disk else "" 1980 to_volume = self.sql(expression, "to_volume") 1981 to_volume = f" TO VOLUME {to_volume}" if to_volume else "" 1982 return f"{this}{delete}{recompress}{to_disk}{to_volume}"
1984 def mergetreettl_sql(self, expression: exp.MergeTreeTTL) -> str: 1985 where = self.sql(expression, "where") 1986 group = self.sql(expression, "group") 1987 aggregates = self.expressions(expression, key="aggregates") 1988 aggregates = self.seg("SET") + self.seg(aggregates) if aggregates else "" 1989 1990 if not (where or group or aggregates) and len(expression.expressions) == 1: 1991 return f"TTL {self.expressions(expression, flat=True)}" 1992 1993 return f"TTL{self.seg(self.expressions(expression))}{where}{group}{aggregates}"
2010 def altercolumn_sql(self, expression: exp.AlterColumn) -> str: 2011 this = self.sql(expression, "this") 2012 2013 dtype = self.sql(expression, "dtype") 2014 if dtype: 2015 collate = self.sql(expression, "collate") 2016 collate = f" COLLATE {collate}" if collate else "" 2017 using = self.sql(expression, "using") 2018 using = f" USING {using}" if using else "" 2019 return f"ALTER COLUMN {this} TYPE {dtype}{collate}{using}" 2020 2021 default = self.sql(expression, "default") 2022 if default: 2023 return f"ALTER COLUMN {this} SET DEFAULT {default}" 2024 2025 if not expression.args.get("drop"): 2026 self.unsupported("Unsupported ALTER COLUMN syntax") 2027 2028 return f"ALTER COLUMN {this} DROP DEFAULT"
2030 def renametable_sql(self, expression: exp.RenameTable) -> str: 2031 if not self.RENAME_TABLE_WITH_DB: 2032 # Remove db from tables 2033 expression = expression.transform( 2034 lambda n: exp.table_(n.this) if isinstance(n, exp.Table) else n 2035 ) 2036 this = self.sql(expression, "this") 2037 return f"RENAME TO {this}"
2039 def altertable_sql(self, expression: exp.AlterTable) -> str: 2040 actions = expression.args["actions"] 2041 2042 if isinstance(actions[0], exp.ColumnDef): 2043 actions = self.expressions(expression, key="actions", prefix="ADD COLUMN ") 2044 elif isinstance(actions[0], exp.Schema): 2045 actions = self.expressions(expression, key="actions", prefix="ADD COLUMNS ") 2046 elif isinstance(actions[0], exp.Delete): 2047 actions = self.expressions(expression, key="actions", flat=True) 2048 else: 2049 actions = self.expressions(expression, key="actions") 2050 2051 exists = " IF EXISTS" if expression.args.get("exists") else "" 2052 return f"ALTER TABLE{exists} {self.sql(expression, 'this')} {actions}"
2059 def addconstraint_sql(self, expression: exp.AddConstraint) -> str: 2060 this = self.sql(expression, "this") 2061 expression_ = self.sql(expression, "expression") 2062 add_constraint = f"ADD CONSTRAINT {this}" if this else "ADD" 2063 2064 enforced = expression.args.get("enforced") 2065 if enforced is not None: 2066 return f"{add_constraint} CHECK ({expression_}){' ENFORCED' if enforced else ''}" 2067 2068 return f"{add_constraint} {expression_}"
2184 def function_fallback_sql(self, expression: exp.Func) -> str: 2185 args = [] 2186 for arg_value in expression.args.values(): 2187 if isinstance(arg_value, list): 2188 for value in arg_value: 2189 args.append(value) 2190 else: 2191 args.append(arg_value) 2192 2193 return self.func(expression.sql_name(), *args)
2198 def format_args(self, *args: t.Optional[str | exp.Expression]) -> str: 2199 arg_sqls = tuple(self.sql(arg) for arg in args if arg is not None) 2200 if self.pretty and self.text_width(arg_sqls) > self._max_text_width: 2201 return self.indent("\n" + f",\n".join(arg_sqls) + "\n", skip_first=True, skip_last=True) 2202 return ", ".join(arg_sqls)
def
expressions( self, expression: Optional[sqlglot.expressions.Expression] = None, key: Optional[str] = None, sqls: Optional[List[str]] = None, flat: bool = False, indent: bool = True, sep: str = ', ', prefix: str = '') -> str:
2210 def expressions( 2211 self, 2212 expression: t.Optional[exp.Expression] = None, 2213 key: t.Optional[str] = None, 2214 sqls: t.Optional[t.List[str]] = None, 2215 flat: bool = False, 2216 indent: bool = True, 2217 sep: str = ", ", 2218 prefix: str = "", 2219 ) -> str: 2220 expressions = expression.args.get(key or "expressions") if expression else sqls 2221 2222 if not expressions: 2223 return "" 2224 2225 if flat: 2226 return sep.join(self.sql(e) for e in expressions) 2227 2228 num_sqls = len(expressions) 2229 2230 # These are calculated once in case we have the leading_comma / pretty option set, correspondingly 2231 pad = " " * self.pad 2232 stripped_sep = sep.strip() 2233 2234 result_sqls = [] 2235 for i, e in enumerate(expressions): 2236 sql = self.sql(e, comment=False) 2237 comments = self.maybe_comment("", e) if isinstance(e, exp.Expression) else "" 2238 2239 if self.pretty: 2240 if self._leading_comma: 2241 result_sqls.append(f"{sep if i > 0 else pad}{prefix}{sql}{comments}") 2242 else: 2243 result_sqls.append( 2244 f"{prefix}{sql}{stripped_sep if i + 1 < num_sqls else ''}{comments}" 2245 ) 2246 else: 2247 result_sqls.append(f"{prefix}{sql}{comments}{sep if i + 1 < num_sqls else ''}") 2248 2249 result_sql = "\n".join(result_sqls) if self.pretty else "".join(result_sqls) 2250 return self.indent(result_sql, skip_first=False) if indent else result_sql
def
op_expressions( self, op: str, expression: sqlglot.expressions.Expression, flat: bool = False) -> str:
2252 def op_expressions(self, op: str, expression: exp.Expression, flat: bool = False) -> str: 2253 flat = flat or isinstance(expression.parent, exp.Properties) 2254 expressions_sql = self.expressions(expression, flat=flat) 2255 if flat: 2256 return f"{op} {expressions_sql}" 2257 return f"{self.seg(op)}{self.sep() if expressions_sql else ''}{expressions_sql}"
2259 def naked_property(self, expression: exp.Property) -> str: 2260 property_name = exp.Properties.PROPERTY_TO_NAME.get(expression.__class__) 2261 if not property_name: 2262 self.unsupported(f"Unsupported property {expression.__class__.__name__}") 2263 return f"{property_name} {self.sql(expression, 'this')}"
2278 def userdefinedfunction_sql(self, expression: exp.UserDefinedFunction) -> str: 2279 this = self.sql(expression, "this") 2280 expressions = self.no_identify(self.expressions, expression) 2281 expressions = ( 2282 self.wrap(expressions) if expression.args.get("wrapped") else f" {expressions}" 2283 ) 2284 return f"{this}{expressions}"
2294 def when_sql(self, expression: exp.When) -> str: 2295 matched = "MATCHED" if expression.args["matched"] else "NOT MATCHED" 2296 source = " BY SOURCE" if self.MATCHED_BY_SOURCE and expression.args.get("source") else "" 2297 condition = self.sql(expression, "condition") 2298 condition = f" AND {condition}" if condition else "" 2299 2300 then_expression = expression.args.get("then") 2301 if isinstance(then_expression, exp.Insert): 2302 then = f"INSERT {self.sql(then_expression, 'this')}" 2303 if "expression" in then_expression.args: 2304 then += f" VALUES {self.sql(then_expression, 'expression')}" 2305 elif isinstance(then_expression, exp.Update): 2306 if isinstance(then_expression.args.get("expressions"), exp.Star): 2307 then = f"UPDATE {self.sql(then_expression, 'expressions')}" 2308 else: 2309 then = f"UPDATE SET {self.expressions(then_expression, flat=True)}" 2310 else: 2311 then = self.sql(then_expression) 2312 return f"WHEN {matched}{source}{condition} THEN {then}"
def
cached_generator( cache: Optional[Dict[int, str]] = None) -> Callable[[sqlglot.expressions.Expression], str]:
2327def cached_generator( 2328 cache: t.Optional[t.Dict[int, str]] = None 2329) -> t.Callable[[exp.Expression], str]: 2330 """Returns a cached generator.""" 2331 cache = {} if cache is None else cache 2332 generator = Generator(normalize=True, identify="safe") 2333 return lambda e: generator.generate(e, cache)
Returns a cached generator.