mirror of
https://github.com/apache/impala.git
synced 2026-01-02 21:00:35 -05:00
Row batches contain auxiliary memory that can reside in tuple pools, io buffers and now tuple streams. Like the other resources, these need to attached to row batches and transfered up the operator tree to make sure the tuple ptrs are always valid. Fixed bug in BufferedTupleStream to not delete blocks on read if it is pinned. Fixed PHJ bug with row batch boundaries causing current_probe_row_ to be NULL. Change-Id: I4c66d9961a117bfe3ed577de6170e875ea1feee7 Reviewed-on: http://gerrit.sjc.cloudera.com:8080/3983 Reviewed-by: Nong Li <nong@cloudera.com> Tested-by: jenkins Reviewed-on: http://gerrit.sjc.cloudera.com:8080/4157
306 lines
6.4 KiB
Plaintext
306 lines
6.4 KiB
Plaintext
====
|
|
---- QUERY
|
|
# Uncorrelated IN subquery
|
|
select a.id, a.int_col, a.string_col
|
|
from functional.alltypessmall a
|
|
where a.id in (select id from functional.alltypestiny where bool_col = false)
|
|
and a.id < 5
|
|
---- RESULTS
|
|
1,1,'1'
|
|
3,3,'3'
|
|
---- TYPES
|
|
INT, INT, STRING
|
|
====
|
|
---- QUERY
|
|
# Uncorrelated IN subquery with IS NOT NULL predicate
|
|
select a.id, a.int_col, a.string_col
|
|
from functional.alltypes a
|
|
where a.int_col in (select int_col from functional.alltypesagg where int_col is not null)
|
|
and a.id < 5
|
|
---- RESULTS
|
|
1,1,'1'
|
|
2,2,'2'
|
|
3,3,'3'
|
|
4,4,'4'
|
|
---- TYPES
|
|
INT, INT, STRING
|
|
====
|
|
---- QUERY
|
|
# Uncorrelated IN subquery with IS NULL predicate (empty result)
|
|
select a.id, a.int_col, a.string_col
|
|
from functional.alltypes a
|
|
where a.id in (select int_col from functional.alltypesagg where int_col is null)
|
|
and a.id < 5
|
|
---- RESULTS
|
|
---- TYPES
|
|
INT, INT, STRING
|
|
====
|
|
---- QUERY
|
|
# Uncorrelated NOT IN subquery
|
|
select id, year, month
|
|
from functional.alltypessmall
|
|
where id not in (select id from functional.alltypestiny where bool_col = false)
|
|
and id < 5
|
|
---- RESULTS
|
|
0,2009,1
|
|
2,2009,1
|
|
4,2009,1
|
|
---- TYPES
|
|
INT, INT, INT
|
|
====
|
|
---- QUERY
|
|
# Correlated IN subquery
|
|
select s.id, s.bool_col, s.int_col, s.date_string_col
|
|
from functional.alltypessmall s
|
|
where s.id in (select id from functional.alltypestiny t where t.int_col = s.int_col)
|
|
and s.bool_col = false
|
|
---- RESULTS
|
|
1,false,1,'01/01/09'
|
|
---- TYPES
|
|
INT, BOOLEAN, INT, STRING
|
|
====
|
|
---- QUERY
|
|
# Correlated NOT IN subquery
|
|
select s.id, s.bool_col, s.int_col
|
|
from functional.alltypessmall s
|
|
where s.id not in
|
|
(select id
|
|
from functional.alltypestiny t
|
|
where s.int_col = t.int_col and t.bool_col = false)
|
|
and s.id < 5
|
|
order by s.id
|
|
---- RESULTS
|
|
0,true,0
|
|
2,true,2
|
|
3,false,3
|
|
4,true,4
|
|
---- TYPES
|
|
INT, BOOLEAN, INT
|
|
====
|
|
---- QUERY
|
|
# Correlated EXISTS subquery
|
|
select count(*)
|
|
from functional.alltypestiny t
|
|
where exists (select * from functional.alltypessmall s where t.int_col = s.int_col)
|
|
and id < 4
|
|
---- RESULTS
|
|
4
|
|
---- TYPES
|
|
BIGINT
|
|
====
|
|
---- QUERY
|
|
# Correlated NOT EXISTS subquery
|
|
select id, int_col
|
|
from functional.alltypessmall t
|
|
where not exists (select 1 from functional.alltypestiny s where t.id = s.id)
|
|
and month = 1 and int_col < 5
|
|
order by id
|
|
---- RESULTS
|
|
10,0
|
|
11,1
|
|
12,2
|
|
13,3
|
|
14,4
|
|
20,0
|
|
21,1
|
|
22,2
|
|
23,3
|
|
24,4
|
|
---- TYPES
|
|
INT, INT
|
|
====
|
|
---- QUERY
|
|
# Uncorrelated aggregate subquery
|
|
select count(*) from
|
|
functional.alltypessmall t
|
|
where t.id < (select max(id) from functional.alltypestiny)
|
|
and t.bool_col = true
|
|
---- RESULTS
|
|
4
|
|
---- TYPES
|
|
BIGINT
|
|
====
|
|
---- QUERY
|
|
# Uncorrelated aggregate subquery with count
|
|
select id, int_col, year, month
|
|
from functional.alltypessmall
|
|
where int_col = (select count(*) from functional.alltypestiny)
|
|
order by id
|
|
---- RESULTS
|
|
8,8,2009,1
|
|
18,8,2009,1
|
|
33,8,2009,2
|
|
43,8,2009,2
|
|
58,8,2009,3
|
|
68,8,2009,3
|
|
83,8,2009,4
|
|
93,8,2009,4
|
|
---- TYPES
|
|
INT, INT, INT, INT
|
|
====
|
|
---- QUERY
|
|
# Correlated aggregate subquery
|
|
select id, int_col, year, month
|
|
from functional.alltypessmall s
|
|
where s.int_col = (select count(*) from functional.alltypestiny t where s.id = t.id)
|
|
order by id
|
|
---- RESULTS
|
|
1,1,2009,1
|
|
10,0,2009,1
|
|
20,0,2009,1
|
|
25,0,2009,2
|
|
35,0,2009,2
|
|
45,0,2009,2
|
|
50,0,2009,3
|
|
60,0,2009,3
|
|
70,0,2009,3
|
|
75,0,2009,4
|
|
85,0,2009,4
|
|
95,0,2009,4
|
|
---- TYPES
|
|
INT, INT, INT, INT
|
|
====
|
|
---- QUERY
|
|
# Multiple subquery predicates
|
|
select id, bool_col, int_col, date_string_col
|
|
from functional.alltypessmall s
|
|
where s.id in (select id from functional.alltypestiny where bool_col = true)
|
|
and exists
|
|
(select *
|
|
from functional.alltypesagg g
|
|
where s.int_col = g.int_col and g.bigint_col < 100)
|
|
and s.int_col < (select count(*) from functional.alltypes where month = 1)
|
|
---- RESULTS
|
|
2,true,2,'01/01/09'
|
|
4,true,4,'01/01/09'
|
|
6,true,6,'01/01/09'
|
|
---- TYPES
|
|
INT, BOOLEAN, INT, STRING
|
|
====
|
|
---- QUERY
|
|
# Multiple nesting levels
|
|
select month, count(*)
|
|
from functional.alltypessmall s
|
|
where id in
|
|
(select id
|
|
from functional.alltypestiny t
|
|
where t.int_col <
|
|
(select min(int_col)
|
|
from functional.alltypesagg a
|
|
where a.bool_col = false and exists
|
|
(select * from functional.alltypes b where b.id = a.id)))
|
|
group by month
|
|
---- RESULTS
|
|
1,4
|
|
---- TYPES
|
|
INT, BIGINT
|
|
====
|
|
---- QUERY
|
|
# Multiple tables in outer select block and in subqueries
|
|
select t.id, t.month, t.year
|
|
from functional.alltypestiny t left outer join functional.alltypessmall s
|
|
on s.id = t.id
|
|
where t.int_col <
|
|
(select avg(a.int_col) * 2
|
|
from functional.alltypesagg a left outer join functional.alltypes b
|
|
on a.bigint_col = b.bigint_col
|
|
where a.id = t.id and b.int_col < 10)
|
|
order by t.id
|
|
---- RESULTS
|
|
1,1,2009
|
|
2,2,2009
|
|
3,2,2009
|
|
4,3,2009
|
|
5,3,2009
|
|
6,4,2009
|
|
7,4,2009
|
|
---- TYPES
|
|
INT, INT, INT
|
|
====
|
|
---- QUERY
|
|
# Subquery in the WITH clause
|
|
with t as
|
|
(select *
|
|
from functional.alltypessmall
|
|
where id in
|
|
(select id
|
|
from functional.alltypestiny
|
|
where bool_col = false))
|
|
select id, month, year from t where t.int_col =
|
|
(select count(*) from functional.alltypestiny where id < 5)
|
|
---- RESULTS
|
|
5,1,2009
|
|
---- TYPES
|
|
INT, INT, INT
|
|
====
|
|
---- QUERY
|
|
# Subquery in an inline view
|
|
select s.id, s.year
|
|
from functional.alltypessmall s left outer join
|
|
(select *
|
|
from functional.alltypestiny t
|
|
where t.id in (select id from functional.alltypesagg)) b
|
|
on (s.id = b.id)
|
|
where s.int_col < (select max(int_col) from functional.alltypes) and s.id < 10
|
|
order by s.id
|
|
---- RESULTS
|
|
0,2009
|
|
1,2009
|
|
2,2009
|
|
3,2009
|
|
4,2009
|
|
5,2009
|
|
6,2009
|
|
7,2009
|
|
8,2009
|
|
---- TYPES
|
|
INT, INT
|
|
====
|
|
---- QUERY
|
|
# Subquery returning a decimal
|
|
select id, double_col
|
|
from functional.alltypestiny
|
|
where double_col < (select min(d3) from functional.decimal_tbl)
|
|
order by id
|
|
---- RESULTS
|
|
0,0
|
|
2,0
|
|
4,0
|
|
6,0
|
|
---- TYPES
|
|
INT, DOUBLE
|
|
====
|
|
---- QUERY
|
|
# Compare a decimal with the result of a subquery
|
|
select d1, d2, d3
|
|
from functional.decimal_tbl
|
|
where d3 < (select max(double_col) from functional.alltypestiny)
|
|
---- RESULTS
|
|
1234,2222,1.2345678900
|
|
---- TYPES
|
|
DECIMAL, DECIMAL, DECIMAL
|
|
====
|
|
---- QUERY
|
|
# Distinct in the outer select block
|
|
select distinct bool_col
|
|
from functional.alltypestiny t
|
|
where 1 < (select count(*) from functional.alltypessmall)
|
|
---- RESULTS
|
|
false
|
|
true
|
|
---- TYPES
|
|
BOOLEAN
|
|
====
|
|
---- QUERY
|
|
# Distinct with an unqualified star in the outer select block
|
|
select distinct *
|
|
from functional.alltypestiny t
|
|
where 1 < (select avg(distinct id) from functional.alltypessmall)
|
|
and id < 2
|
|
---- RESULTS
|
|
0,true,0,0,0,0,0,0,'01/01/09','0',2009-01-01 00:00:00,2009,1
|
|
1,false,1,1,1,10,1.100000023841858,10.1,'01/01/09','1',2009-01-01 00:01:00,2009,1
|
|
---- TYPES
|
|
INT, BOOLEAN, TINYINT, SMALLINT, INT, BIGINT, FLOAT, DOUBLE, STRING, STRING, TIMESTAMP, INT, INT
|
|
====
|