Skip to content

Commit 13e2765

Browse files
srielaudtenedor
authored andcommitted
[SPARK-54343][DOCS] Docs for parameter markers, identifier improvements, string coalescing
### What changes were proposed in this pull request? * We document named an unnamed parameters and how to use them * We document the ability to coalesce string literals though chaing * We document the extended usage of teh IDENTIFIER clause ### Why are the changes needed? Sync the docs with the code. ### Does this PR introduce _any_ user-facing change? No ### How was this patch tested? Building of the docs and reviewing the pages ### Was this patch authored or co-authored using generative AI tooling? No Closes #53047 from srielau/param-rework-docs. Authored-by: Serge Rielau <serge@rielau.com> Signed-off-by: Daniel Tenedorio <daniel.tenedorio@databricks.com>
1 parent 59759f3 commit 13e2765

File tree

6 files changed

+304
-21
lines changed

6 files changed

+304
-21
lines changed

docs/_data/menu-sql.yaml

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -99,6 +99,8 @@
9999
url: sql-ref-literals.html
100100
- text: Null Semantics
101101
url: sql-ref-null-semantics.html
102+
- text: Parameter Markers
103+
url: sql-ref-parameter-markers.html
102104
- text: SQL Syntax
103105
url: sql-ref-syntax.html
104106
subitems:

docs/sql-ref-identifier-clause.md

Lines changed: 45 additions & 20 deletions
Original file line numberDiff line numberDiff line change
@@ -23,26 +23,54 @@ license: |
2323

2424
Converts a constant `STRING` expression into a SQL object name.
2525
The purpose of this clause is to allow for templating of identifiers in SQL statements without opening up the risk of SQL injection attacks.
26-
Typically, this clause is used with a parameter marker or a variable as argument.
26+
27+
The clause comes in two forms:
28+
29+
- When passed a string-literal, which may include a coalesced string of literals and parameter markers, it can be used anywhere an identifier or qualified identifier can be used.
30+
The usage of this form is encouraged.
31+
- When passed a more complex constant string expression, which may also include variables, it can be used in limited cases to reference dynamic SQL object references such as table names, column names, and function names.
32+
The usage of this form is discouraged unless necessary.
33+
For example you cannot use this form to parameterize a table or column alias, or a column name in a `CREATE TABLE` statement.
2734

2835
### Syntax
2936

3037
```sql
38+
IDENTIFIER ( strLiteral )
39+
3140
IDENTIFIER ( strExpr )
3241
```
3342

3443
### Parameters
3544

36-
- **strExpr**: A constant `STRING` expression. Typically, the expression includes a parameter marker.
45+
- **strLiteral**
3746

38-
### Returns
47+
A constant `STRING` literal which may include string coalescing of strings and string parameter markers.
48+
49+
The string must be a valid (qualified) identifier.
50+
51+
For example:
52+
53+
```
54+
IDENTIFIER('default.' :tablename)
55+
IDENTIFIER(:catalog '.' :namespace '.' :tablename '.' :columnname)
56+
IDENTIFIER(:rootdirectory '/data/' :tablename)
57+
```
3958

40-
A (qualified) identifier which can be used as a:
59+
- **strExpr**: A constant `STRING` expression. Typically, the expression includes a parameter marker or session variable.
4160

42-
- qualified table name
43-
- namespace name
44-
- function name
45-
- qualified column or attribute reference
61+
The string must be a valid (qualified) identifier.
62+
63+
For example:
64+
65+
```
66+
IDENTIFIER(session.schema || '.' || session.tablename)
67+
IDENTIFIER('`' || session.schema || '`.`' session.tablename || '`')
68+
IDENTIFIER(CONCAT(:catalog, '.', :namespace, '.', :tablename, '.', :columnname))
69+
```
70+
71+
### Returns
72+
73+
A (qualified) identifier.
4674

4775
### Examples
4876

@@ -88,7 +116,7 @@ spark.sql("SELECT * FROM IDENTIFIER(:myschema).mytab", args = Map("mychema" -> "
88116
[PARSE_SYNTAX_ERROR]
89117

90118
// Dropping a table with separate schema and table parameters.
91-
spark.sql("DROP TABLE IDENTIFIER(:myschema || '.' || :mytab)", args = Map("myschema" -> "default", "mytab" -> "tab1")).show()
119+
spark.sql("DROP TABLE IDENTIFIER(:myschema '.' :mytab)", args = Map("myschema" -> "default", "mytab" -> "tab1")).show()
92120

93121
// A parameterized column reference
94122
spark.sql("SELECT IDENTIFIER(:col) FROM VALUES(1) AS T(c1)", args = Map("col" -> "t.c1")).show()
@@ -117,18 +145,18 @@ DECLARE mytab = 'tab1';
117145
-- Creation of a table using variable.
118146
CREATE TABLE IDENTIFIER(mytab)(c1 INT);
119147

120-
DESCRIBE IDENTIFIER(mytab);
148+
EXECUTE IMMEDIATE 'DESCRIBE IDENTIFIER(:mytab)' USING mytab;
121149
+--------+---------+-------+
122150
|col_name|data_type|comment|
123151
+--------+---------+-------+
124152
| c1| int| NULL|
125153
+--------+---------+-------+
126154

127155
-- Altering a table with a fixed schema and a parameterized table name.
128-
ALTER TABLE IDENTIFIER('default.' || mytab) ADD COLUMN c2 INT;
156+
EXECUTE IMMEDIATE 'ALTER TABLE IDENTIFIER('default.' || :mytab) ADD COLUMN :col INT' USING mytab, 'c2' AS col;
129157

130158
SET VAR mytab = '`default`.`tab1`';
131-
DESCRIBE IDENTIFIER(mytab);
159+
EXECUTE IMMEDIATE 'DESCRIBE IDENTIFIER(:mytab)' USING mytab;
132160
+--------+---------+-------+
133161
|col_name|data_type|comment|
134162
+--------+---------+-------+
@@ -137,30 +165,27 @@ DESCRIBE IDENTIFIER(mytab);
137165
+--------+---------+-------+
138166

139167
-- A parameterized reference to a table in a query. This table name is qualified and uses back-ticks.
140-
SELECT * FROM IDENTIFIER(mytab);
168+
EXECUTE IMMEDIATE 'SELECT * FROM IDENTIFIER(mytab)' USING mytab;
141169
+---+---+
142170
| c1| c2|
143171
+---+---+
144-
+---+---+
145-
146172

147173
-- Dropping a table with separate schema and table parameters.
148174
DECLARE myschema = 'default';
149175
SET VAR mytab = 'tab1';
150-
DROP TABLE IDENTIFIER(myschema || '.' || mytab);
176+
EXECUTE IMMEDIATE 'DROP TABLE IDENTIFIER(:myschema '.' :mytab)' USING myschema, mytab;
151177

152178
-- A parameterized column reference
153-
DECLARE col = 't.c1';
154-
SELECT IDENTIFIER(col) FROM VALUES(1) AS T(c1);
179+
DECLARE col = 'c1';
180+
EXECUTE IMEMDIATE 'SELECT IDENTIFIER(:col) FROM VALUES(1) AS T(IDENTIFIER(:col))' USING col;
155181
+---+
156182
| c1|
157183
+---+
158184
| 1|
159185
+---+
160186

161187
-- Passing in a function name as a parameter
162-
DECLARE func = 'abs';
163-
SELECT IDENTIFIER(func)(-1);
188+
EXECUTE IMMEDIATE 'SELECT IDENTIFIER(:func)(-1)' USING 'abs' AS func;
164189
+-------+
165190
|abs(-1)|
166191
+-------+

docs/sql-ref-literals.md

Lines changed: 19 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -36,7 +36,7 @@ A string literal is used to specify a character string value.
3636
#### Syntax
3737

3838
```sql
39-
[ r ] { 'char [ ... ]' | "char [ ... ]" }
39+
[ r ] { 'char [ ... ]' | "char [ ... ]" } [ ... ]
4040
```
4141

4242
#### Parameters
@@ -65,6 +65,10 @@ The following escape sequences are recognized in regular string literals (withou
6565

6666
The unescaping rules above can be turned off by setting the SQL config `spark.sql.parser.escapedStringLiterals` to `true`.
6767

68+
Chains of string literals are coalesced into a single string literal.
69+
This can be useful when constructing strings that are too long to fit on a single line.
70+
It also allows mixing of string literals and parameter marker into a single string literal.
71+
6872
#### Examples
6973

7074
```sql
@@ -95,6 +99,20 @@ SELECT r"'\n' represents newline character." AS col;
9599
+----------------------------------+
96100
|'\n' represents newline character.|
97101
+----------------------------------+
102+
103+
SELECT 'Hello' ',' 'World!' AS col;
104+
+-------------+
105+
| col|
106+
+-------------+
107+
|Hello, World!|
108+
+-------------+
109+
110+
EXECUTE IMMEDIATE 'SELECT "Hello, " :p "!" AS col' USING 'World' AS p;
111+
+-------------+
112+
| col|
113+
+-------------+
114+
|Hello, World!|
115+
+-------------+
98116
```
99117
100118
### Binary Literal

0 commit comments

Comments
 (0)