Skip to content

Commit 249fc66

Browse files
committed
feat: support position column in common sql query
1 parent 3c6a4fe commit 249fc66

File tree

3 files changed

+56
-0
lines changed

3 files changed

+56
-0
lines changed

src/query/sql/src/planner/binder/bind_context.rs

Lines changed: 9 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -296,6 +296,15 @@ impl BindContext {
296296
self.columns.push(column_binding);
297297
}
298298

299+
/// Assigns 1-based column positions for the current result columns.
300+
/// This is mainly used for derived tables/subqueries so that `$n` style
301+
/// ordinal references can resolve against their outputs.
302+
pub fn reset_result_column_positions(&mut self) {
303+
for (idx, column) in self.columns.iter_mut().enumerate() {
304+
column.column_position = Some(idx + 1);
305+
}
306+
}
307+
299308
/// Apply table alias like `SELECT * FROM t AS t1(a, b, c)`.
300309
/// This method will rename column bindings according to table alias.
301310
pub fn apply_table_alias(

src/query/sql/src/planner/binder/bind_query/bind.rs

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -101,6 +101,8 @@ impl Binder {
101101
s_expr = self.bind_materialized_cte(with, s_expr, bind_context.cte_context.clone())?;
102102
}
103103

104+
bind_context.reset_result_column_positions();
105+
104106
Ok((s_expr, bind_context))
105107
}
106108

tests/sqllogictests/suites/query/select.test

Lines changed: 45 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -243,3 +243,48 @@ drop table t2;
243243

244244
statement ok
245245
unset inlist_to_join_threshold
246+
247+
statement ok
248+
create or replace database column_position
249+
250+
statement ok
251+
use column_position
252+
253+
query
254+
select $1, $2 from (select 1 as a, 2 as b, 3 as c) as t
255+
----
256+
1 2
257+
258+
query
259+
select t.$1, t.$2 from (select number, number + 10 as n from numbers(3)) as t order by t.$1
260+
----
261+
0 10
262+
1 11
263+
2 12
264+
265+
statement ok
266+
create or replace table monthly_totals(empid int, amount int)
267+
268+
statement ok
269+
insert into monthly_totals values (1, 100), (1, 200), (2, 50), (2, 75)
270+
271+
query
272+
with totals as ( select empid, sum(amount) as total from monthly_totals group by empid ) select totals.$1, totals.$2 from totals order by totals.$1
273+
----
274+
1 300
275+
2 125
276+
277+
statement ok
278+
CREATE OR REPLACE TABLE monthly_sales(empid INT, amount INT, month TEXT);
279+
280+
statement ok
281+
INSERT INTO monthly_sales VALUES (1, 10000, 'JAN'), (1, 400, 'JAN'), (2, 4500, 'JAN'), (2, 35000, 'JAN'), (1, 5000, 'FEB'), (1, 3000, 'FEB'), (2, 200, 'FEB'), (2, 90500, 'FEB'), (1, 6000, 'MAR'), (1, 5000, 'MAR'), (2, 2500, 'MAR'), (2, 9500, 'MAR'), (1, 8000, 'APR'), (1, 10000, 'APR'), (2, 800, 'APR'), (2, 4500, 'APR');
282+
283+
query
284+
SELECT $1, $2, $3 FROM monthly_sales PIVOT(SUM(amount) FOR MONTH IN (SELECT DISTINCT month FROM monthly_sales)) ORDER BY EMPID
285+
----
286+
1 18000 8000
287+
2 5300 90700
288+
289+
statement ok
290+
drop database column_position

0 commit comments

Comments
 (0)