Arrays and the PostgreSQL Query Planner
1 Feb 2016
Let's create two tables and see how they behave when we join them.
postgres@[local]:5432/postgres# create table t1 (id int, name text); CREATE TABLE postgres@[local]:5432/postgres# create table t2 (id int, name text); CREATE TABLE postgres@[local]:5432/postgres# insert into t1 select s.i, s.i::text from generate_series(1, 1000) as s(i); INSERT 0 1000 postgres@[local]:5432/postgres# insert into t2 select s.i, s.i::text from generate_series(1, 1000) as s(i); INSERT 0 1000
What's the query plan when we join these two tables on their id column?
postgres@[local]:5432/postgres# explain select * from t1 join t2 on t1.id = t2.id; rollback; ┌──────────────────────────────────────────────────────────────────┐ │ QUERY PLAN │ ├──────────────────────────────────────────────────────────────────┤ │ Hash Join (cost=27.50..56.25 rows=1000 width=14) │ │ Hash Cond: (t1.id = t2.id) │ │ -> Seq Scan on t1 (cost=0.00..15.00 rows=1000 width=7) │ │ -> Hash (cost=15.00..15.00 rows=1000 width=7) │ │ -> Seq Scan on t2 (cost=0.00..15.00 rows=1000 width=7) │ └──────────────────────────────────────────────────────────────────┘ (5 rows)
What's the query plan when we use an in clause instead?
postgres@[local]:5432/postgres# explain select * from t1 where id in (select id from t2); rollback; ┌──────────────────────────────────────────────────────────────────┐ │ QUERY PLAN │ ├──────────────────────────────────────────────────────────────────┤ │ Hash Semi Join (cost=27.50..56.25 rows=1000 width=7) │ │ Hash Cond: (t1.id = t2.id) │ │ -> Seq Scan on t1 (cost=0.00..15.00 rows=1000 width=7) │ │ -> Hash (cost=15.00..15.00 rows=1000 width=4) │ │ -> Seq Scan on t2 (cost=0.00..15.00 rows=1000 width=4) │ └──────────────────────────────────────────────────────────────────┘ (5 rows)
Same query plan. Nice. So PostgreSQL presumably treats the select statement inside the
in
clause as something table-ish.
How about when we give a long list in the in clause?
postgres@[local]:5432/postgres# explain select * from t1 where id in postgres-# (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25, postgres(# 26, 27, 28, 29, 30, 31, 32, 33, 34, 35, 36, 37, 38, 39, 40, 41, 42, 43, 44, 45, 46, 47, 48, postgres(# 49, 50, 51, 52, 53, 54, 55, 56, 57, 58, 59, 60, 61, 62, 63, 64, 65, 66, 67, 68, 69, 70, 71, postgres(# 72, 73, 74, 75, 76, 77, 78, 79, 80, 81, 82, 83, 84, 85, 86, 87, 88, 89, 90, 91, 92, 93, 94, postgres(# 95, 96, 97, 98, 99, 100, 101, 102, 103, 104, 105, 106, 107, 108, 109, 110, 111, 112, 113, 114, postgres(# 115, 116, 117, 118, 119, 120, 121, 122, 123, 124, 125, 126, 127, 128, 129, 130, 131, 132, 133, postgres(# 134, 135, 136, 137, 138, 139, 140, 141, 142, 143, 144, 145, 146, 147, 148, 149, 150, 151, 152, postgres(# 153, 154, 155, 156, 157, 158, 159, 160, 161, 162, 163, 164, 165, 166, 167, 168, 169, 170, 171, postgres(# 172, 173, 174, 175, 176, 177, 178, 179, 180, 181, 182, 183, 184, 185, 186, 187, 188, 189, 190, postgres(# 191, 192, 193, 194, 195, 196, 197, 198, 199, 200, 201, 202, 203, 204, 205, 206, 207, 208, 209); ┌───────────────────────────────────────────────────────────────────────────────────────────────────────────┐ │ QUERY PLAN │ ├───────────────────────────────────────────────────────────────────────────────────────────────────────────┤ │ Seq Scan on t1 (cost=0.00..276.25 rows=209 width=7) │ │ Filter: (id = ANY ('{1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,3…│ │…1,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,6…│ │…6,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,…│ │…101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,1…│ │…27,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,15…│ │…3,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179…│ │…,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,…│ │…206,207,208,209}'::integer[])) │ └───────────────────────────────────────────────────────────────────────────────────────────────────────────┘ (2 rows)
OK, we get any
in a filter.
How about when we make the contents of the in clause table-ish by unnesting them?
postgres-# explain select * from t1 where id in (select unnest (array[ postgres(# 1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25, postgres(# 26, 27, 28, 29, 30, 31, 32, 33, 34, 35, 36, 37, 38, 39, 40, 41, 42, 43, 44, 45, 46, 47, 48, postgres(# 49, 50, 51, 52, 53, 54, 55, 56, 57, 58, 59, 60, 61, 62, 63, 64, 65, 66, 67, 68, 69, 70, 71, postgres(# 72, 73, 74, 75, 76, 77, 78, 79, 80, 81, 82, 83, 84, 85, 86, 87, 88, 89, 90, 91, 92, 93, 94, postgres(# 95, 96, 97, 98, 99, 100, 101, 102, 103, 104, 105, 106, 107, 108, 109, 110, 111, 112, 113, 114, postgres(# 115, 116, 117, 118, 119, 120, 121, 122, 123, 124, 125, 126, 127, 128, 129, 130, 131, 132, 133, postgres(# 134, 135, 136, 137, 138, 139, 140, 141, 142, 143, 144, 145, 146, 147, 148, 149, 150, 151, 152, postgres(# 153, 154, 155, 156, 157, 158, 159, 160, 161, 162, 163, 164, 165, 166, 167, 168, 169, 170, 171, postgres(# 172, 173, 174, 175, 176, 177, 178, 179, 180, 181, 182, 183, 184, 185, 186, 187, 188, 189, 190, postgres(# 191, 192, 193, 194, 195, 196, 197, 198, 199, 200, 201, 202, 203, 204, 205, 206, 207, 208, 209])); ┌───────────────────────────────────────────────────────────────────────────────────────────────────────────┐ │ QUERY PLAN │ ├───────────────────────────────────────────────────────────────────────────────────────────────────────────┤ │ Hash Semi Join (cost=2.76..21.50 rows=100 width=7) │ │ Hash Cond: (t1.id = (unnest('{1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,2…│ │…8,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,6…│ │…3,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,9…│ │…8,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,…│ │…125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,1…│ │…51,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,17…│ │…7,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203…│ │…,204,205,206,207,208,209}'::integer[]))) │ │ -> Seq Scan on t1 (cost=0.00..15.00 rows=1000 width=7) │ │ -> Hash (cost=1.51..1.51 rows=100 width=4) │ │ -> Result (cost=0.00..0.51 rows=100 width=0) │ └───────────────────────────────────────────────────────────────────────────────────────────────────────────┘ (5 rows)
Ah, this looks more like the query plans we had for joins. Nice.