1d3835579Sdrh# 2022-05-13 2d3835579Sdrh# 3d3835579Sdrh# The author disclaims copyright to this source code. In place of 4d3835579Sdrh# a legal notice, here is a blessing: 5d3835579Sdrh# 6d3835579Sdrh# May you do good and not evil. 7d3835579Sdrh# May you find forgiveness for yourself and forgive others. 8d3835579Sdrh# May you share freely, never taking more than you give. 9d3835579Sdrh# 10d3835579Sdrh#*********************************************************************** 11d3835579Sdrh# 12d3835579Sdrh# This file implements tests for JOINs that use Bloom filters. 13d3835579Sdrh# 14d3835579Sdrh# The test case output is (mostly) all generated by PostgreSQL 14. This 15d3835579Sdrh# test module was created as follows: 16d3835579Sdrh# 17d3835579Sdrh# 1. Run a TCL script (included at the bottom of this file) that 18d3835579Sdrh# generates an input script for "psql" that will run man 19d3835579Sdrh# diverse tests on joins. 20d3835579Sdrh# 21d3835579Sdrh# 2. Run the script from step (1) through psql and collect the 22d3835579Sdrh# output. 23d3835579Sdrh# 24d3835579Sdrh# 3. Make a few minor global search-and-replace operations to convert 25d3835579Sdrh# the psql output into a form suitable for this test module. 26d3835579Sdrh# 27d3835579Sdrh# 4. Add this header, and the script content at the footer. 28d3835579Sdrh# 29d3835579Sdrhset testdir [file dirname $argv0] 30d3835579Sdrhsource $testdir/tester.tcl 31d3835579Sdrhdb nullvalue - 32d3835579Sdrhdb eval { 33d3835579Sdrh CREATE TABLE t1(a INT); 34d3835579Sdrh INSERT INTO t1 VALUES(1),(NULL); 35d3835579Sdrh CREATE TABLE t2(b INT); 36d3835579Sdrh INSERT INTO t2 VALUES(2),(NULL); 37d3835579Sdrh} 38d3835579Sdrhdo_execsql_test joinE-1 { 39d3835579Sdrh SELECT a, b 40d3835579Sdrh FROM t1 INNER JOIN t2 ON true 41d3835579Sdrh ORDER BY coalesce(a,b,3); 42d3835579Sdrh} { 43d3835579Sdrh 1 2 44d3835579Sdrh 1 - 45d3835579Sdrh - 2 46d3835579Sdrh - - 47d3835579Sdrh} 48d3835579Sdrhdo_execsql_test joinE-2 { 49d3835579Sdrh SELECT a, b 50d3835579Sdrh FROM t1 INNER JOIN t2 ON true WHERE a IS NULL 51d3835579Sdrh ORDER BY coalesce(a,b,3); 52d3835579Sdrh} { 53d3835579Sdrh - 2 54d3835579Sdrh - - 55d3835579Sdrh} 56d3835579Sdrhdo_execsql_test joinE-3 { 57d3835579Sdrh SELECT a, b 58d3835579Sdrh FROM t1 INNER JOIN t2 ON a IS NULL 59d3835579Sdrh ORDER BY coalesce(a,b,3); 60d3835579Sdrh} { 61d3835579Sdrh - 2 62d3835579Sdrh - - 63d3835579Sdrh} 64d3835579Sdrhdo_execsql_test joinE-4 { 65d3835579Sdrh SELECT a, b 66d3835579Sdrh FROM t1 INNER JOIN t2 ON true WHERE b IS NULL 67d3835579Sdrh ORDER BY coalesce(a,b,3); 68d3835579Sdrh} { 69d3835579Sdrh 1 - 70d3835579Sdrh - - 71d3835579Sdrh} 72d3835579Sdrhdo_execsql_test joinE-5 { 73d3835579Sdrh SELECT a, b 74d3835579Sdrh FROM t1 INNER JOIN t2 ON b IS NULL 75d3835579Sdrh ORDER BY coalesce(a,b,3); 76d3835579Sdrh} { 77d3835579Sdrh 1 - 78d3835579Sdrh - - 79d3835579Sdrh} 80d3835579Sdrhdo_execsql_test joinE-6 { 81d3835579Sdrh SELECT a, b 82d3835579Sdrh FROM t1 LEFT JOIN t2 ON true 83d3835579Sdrh ORDER BY coalesce(a,b,3); 84d3835579Sdrh} { 85d3835579Sdrh 1 2 86d3835579Sdrh 1 - 87d3835579Sdrh - 2 88d3835579Sdrh - - 89d3835579Sdrh} 90d3835579Sdrhdo_execsql_test joinE-7 { 91d3835579Sdrh SELECT a, b 92d3835579Sdrh FROM t1 LEFT JOIN t2 ON true WHERE a IS NULL 93d3835579Sdrh ORDER BY coalesce(a,b,3); 94d3835579Sdrh} { 95d3835579Sdrh - 2 96d3835579Sdrh - - 97d3835579Sdrh} 98d3835579Sdrhdo_execsql_test joinE-8 { 99d3835579Sdrh SELECT a, b 100d3835579Sdrh FROM t1 LEFT JOIN t2 ON a IS NULL 101d3835579Sdrh ORDER BY coalesce(a,b,3); 102d3835579Sdrh} { 103d3835579Sdrh 1 - 104d3835579Sdrh - 2 105d3835579Sdrh - - 106d3835579Sdrh} 107d3835579Sdrhdo_execsql_test joinE-9 { 108d3835579Sdrh SELECT a, b 109d3835579Sdrh FROM t1 LEFT JOIN t2 ON true WHERE b IS NULL 110d3835579Sdrh ORDER BY coalesce(a,b,3); 111d3835579Sdrh} { 112d3835579Sdrh 1 - 113d3835579Sdrh - - 114d3835579Sdrh} 115d3835579Sdrhdo_execsql_test joinE-10 { 116d3835579Sdrh SELECT a, b 117d3835579Sdrh FROM t1 LEFT JOIN t2 ON b IS NULL 118d3835579Sdrh ORDER BY coalesce(a,b,3); 119d3835579Sdrh} { 120d3835579Sdrh 1 - 121d3835579Sdrh - - 122d3835579Sdrh} 123d3835579Sdrhdo_execsql_test joinE-11 { 124d3835579Sdrh SELECT a, b 125d3835579Sdrh FROM t1 RIGHT JOIN t2 ON true 126d3835579Sdrh ORDER BY coalesce(a,b,3); 127d3835579Sdrh} { 128d3835579Sdrh 1 2 129d3835579Sdrh 1 - 130d3835579Sdrh - 2 131d3835579Sdrh - - 132d3835579Sdrh} 133d3835579Sdrhdo_execsql_test joinE-12 { 134d3835579Sdrh SELECT a, b 135d3835579Sdrh FROM t1 RIGHT JOIN t2 ON true WHERE a IS NULL 136d3835579Sdrh ORDER BY coalesce(a,b,3); 137d3835579Sdrh} { 138d3835579Sdrh - 2 139d3835579Sdrh - - 140d3835579Sdrh} 141d3835579Sdrhdo_execsql_test joinE-13 { 142d3835579Sdrh SELECT a, b 143d3835579Sdrh FROM t1 RIGHT JOIN t2 ON a IS NULL 144d3835579Sdrh ORDER BY coalesce(a,b,3); 145d3835579Sdrh} { 146d3835579Sdrh - 2 147d3835579Sdrh - - 148d3835579Sdrh} 149d3835579Sdrhdo_execsql_test joinE-14 { 150d3835579Sdrh SELECT a, b 151d3835579Sdrh FROM t1 RIGHT JOIN t2 ON true WHERE b IS NULL 152d3835579Sdrh ORDER BY coalesce(a,b,3); 153d3835579Sdrh} { 154d3835579Sdrh 1 - 155d3835579Sdrh - - 156d3835579Sdrh} 157d3835579Sdrhdo_execsql_test joinE-15 { 158d3835579Sdrh SELECT a, b 159d3835579Sdrh FROM t1 RIGHT JOIN t2 ON b IS NULL 160d3835579Sdrh ORDER BY coalesce(a,b,3); 161d3835579Sdrh} { 162d3835579Sdrh 1 - 163d3835579Sdrh - 2 164d3835579Sdrh - - 165d3835579Sdrh} 166d3835579Sdrhdo_execsql_test joinE-16 { 167d3835579Sdrh SELECT a, b 168d3835579Sdrh FROM t1 FULL JOIN t2 ON true 169d3835579Sdrh ORDER BY coalesce(a,b,3); 170d3835579Sdrh} { 171d3835579Sdrh 1 2 172d3835579Sdrh 1 - 173d3835579Sdrh - 2 174d3835579Sdrh - - 175d3835579Sdrh} 176d3835579Sdrhdo_execsql_test joinE-17 { 177d3835579Sdrh SELECT a, b 178d3835579Sdrh FROM t1 FULL JOIN t2 ON true WHERE a IS NULL 179d3835579Sdrh ORDER BY coalesce(a,b,3); 180d3835579Sdrh} { 181d3835579Sdrh - 2 182d3835579Sdrh - - 183d3835579Sdrh} 184d3835579Sdrh 185d3835579Sdrh# PG-14 is unable to perform this join. It says: FULL JOIN is only 186d3835579Sdrh# supported with merge-joinable or hash-joinable join conditions 187d3835579Sdrh# 188d3835579Sdrh# do_execsql_test joinE-18 { 189d3835579Sdrh# SELECT a, b 190d3835579Sdrh# FROM t1 FULL JOIN t2 ON a IS NULL 191d3835579Sdrh# ORDER BY coalesce(a,b,3); 192d3835579Sdrh# } { 193d3835579Sdrh# } 194d3835579Sdrh 195d3835579Sdrhdo_execsql_test joinE-19 { 196d3835579Sdrh SELECT a, b 197d3835579Sdrh FROM t1 FULL JOIN t2 ON true WHERE b IS NULL 198d3835579Sdrh ORDER BY coalesce(a,b,3); 199d3835579Sdrh} { 200d3835579Sdrh 1 - 201d3835579Sdrh - - 202d3835579Sdrh} 203d3835579Sdrh 204d3835579Sdrh# PG-14 is unable to perform this join. It says: FULL JOIN is only 205d3835579Sdrh# supported with merge-joinable or hash-joinable join conditions 206d3835579Sdrh# 207d3835579Sdrh# do_execsql_test joinE-20 { 208d3835579Sdrh# SELECT a, b 209d3835579Sdrh# FROM t1 FULL JOIN t2 ON b IS NULL 210d3835579Sdrh# ORDER BY coalesce(a,b,3); 211d3835579Sdrh# } { 212d3835579Sdrh# } 213d3835579Sdrh 214d3835579Sdrhdb eval { 215d3835579Sdrh DELETE FROM t1; 216d3835579Sdrh INSERT INTO t1 VALUES(1); 217d3835579Sdrh DELETE FROM t2; 218d3835579Sdrh INSERT INTO t2 VALUES(NULL); 219d3835579Sdrh} 220d3835579Sdrh 221d3835579Sdrhdo_execsql_test joinE-21 { 222d3835579Sdrh SELECT a, b 223d3835579Sdrh FROM t1 INNER JOIN t2 ON true 224d3835579Sdrh ORDER BY coalesce(a,b,3); 225d3835579Sdrh} { 226d3835579Sdrh 1 - 227d3835579Sdrh} 228d3835579Sdrhdo_execsql_test joinE-22 { 229d3835579Sdrh SELECT a, b 230d3835579Sdrh FROM t1 INNER JOIN t2 ON true WHERE a IS NULL 231d3835579Sdrh ORDER BY coalesce(a,b,3); 232d3835579Sdrh} { 233d3835579Sdrh} 234d3835579Sdrhdo_execsql_test joinE-23 { 235d3835579Sdrh SELECT a, b 236d3835579Sdrh FROM t1 INNER JOIN t2 ON a IS NULL 237d3835579Sdrh ORDER BY coalesce(a,b,3); 238d3835579Sdrh} { 239d3835579Sdrh} 240d3835579Sdrhdo_execsql_test joinE-24 { 241d3835579Sdrh SELECT a, b 242d3835579Sdrh FROM t1 INNER JOIN t2 ON true WHERE b IS NULL 243d3835579Sdrh ORDER BY coalesce(a,b,3); 244d3835579Sdrh} { 245d3835579Sdrh 1 - 246d3835579Sdrh} 247d3835579Sdrhdo_execsql_test joinE-25 { 248d3835579Sdrh SELECT a, b 249d3835579Sdrh FROM t1 INNER JOIN t2 ON b IS NULL 250d3835579Sdrh ORDER BY coalesce(a,b,3); 251d3835579Sdrh} { 252d3835579Sdrh 1 - 253d3835579Sdrh} 254d3835579Sdrhdo_execsql_test joinE-26 { 255d3835579Sdrh SELECT a, b 256d3835579Sdrh FROM t1 LEFT JOIN t2 ON true 257d3835579Sdrh ORDER BY coalesce(a,b,3); 258d3835579Sdrh} { 259d3835579Sdrh 1 - 260d3835579Sdrh} 261d3835579Sdrhdo_execsql_test joinE-27 { 262d3835579Sdrh SELECT a, b 263d3835579Sdrh FROM t1 LEFT JOIN t2 ON true WHERE a IS NULL 264d3835579Sdrh ORDER BY coalesce(a,b,3); 265d3835579Sdrh} { 266d3835579Sdrh} 267d3835579Sdrhdo_execsql_test joinE-28 { 268d3835579Sdrh SELECT a, b 269d3835579Sdrh FROM t1 LEFT JOIN t2 ON a IS NULL 270d3835579Sdrh ORDER BY coalesce(a,b,3); 271d3835579Sdrh} { 272d3835579Sdrh 1 - 273d3835579Sdrh} 274d3835579Sdrhdo_execsql_test joinE-29 { 275d3835579Sdrh SELECT a, b 276d3835579Sdrh FROM t1 LEFT JOIN t2 ON true WHERE b IS NULL 277d3835579Sdrh ORDER BY coalesce(a,b,3); 278d3835579Sdrh} { 279d3835579Sdrh 1 - 280d3835579Sdrh} 281d3835579Sdrhdo_execsql_test joinE-30 { 282d3835579Sdrh SELECT a, b 283d3835579Sdrh FROM t1 LEFT JOIN t2 ON b IS NULL 284d3835579Sdrh ORDER BY coalesce(a,b,3); 285d3835579Sdrh} { 286d3835579Sdrh 1 - 287d3835579Sdrh} 288d3835579Sdrhdo_execsql_test joinE-31 { 289d3835579Sdrh SELECT a, b 290d3835579Sdrh FROM t1 RIGHT JOIN t2 ON true 291d3835579Sdrh ORDER BY coalesce(a,b,3); 292d3835579Sdrh} { 293d3835579Sdrh 1 - 294d3835579Sdrh} 295d3835579Sdrh 296d3835579Sdrhdo_execsql_test joinE-32 { 297d3835579Sdrh SELECT a, b 298d3835579Sdrh FROM t1 RIGHT JOIN t2 ON true WHERE a IS NULL 299d3835579Sdrh ORDER BY coalesce(a,b,3); 300d3835579Sdrh} { 301d3835579Sdrh} 302d3835579Sdrh 303d3835579Sdrhdo_execsql_test joinE-33 { 304d3835579Sdrh SELECT a, b 305d3835579Sdrh FROM t1 RIGHT JOIN t2 ON a IS NULL 306d3835579Sdrh ORDER BY coalesce(a,b,3); 307d3835579Sdrh} { 308d3835579Sdrh - - 309d3835579Sdrh} 310d3835579Sdrhdo_execsql_test joinE-34 { 311d3835579Sdrh SELECT a, b 312d3835579Sdrh FROM t1 RIGHT JOIN t2 ON true WHERE b IS NULL 313d3835579Sdrh ORDER BY coalesce(a,b,3); 314d3835579Sdrh} { 315d3835579Sdrh 1 - 316d3835579Sdrh} 317d3835579Sdrhdo_execsql_test joinE-35 { 318d3835579Sdrh SELECT a, b 319d3835579Sdrh FROM t1 RIGHT JOIN t2 ON b IS NULL 320d3835579Sdrh ORDER BY coalesce(a,b,3); 321d3835579Sdrh} { 322d3835579Sdrh 1 - 323d3835579Sdrh} 324d3835579Sdrhdo_execsql_test joinE-36 { 325d3835579Sdrh SELECT a, b 326d3835579Sdrh FROM t1 FULL JOIN t2 ON true 327d3835579Sdrh ORDER BY coalesce(a,b,3); 328d3835579Sdrh} { 329d3835579Sdrh 1 - 330d3835579Sdrh} 331d3835579Sdrhdo_execsql_test joinE-37 { 332d3835579Sdrh SELECT a, b 333d3835579Sdrh FROM t1 FULL JOIN t2 ON true WHERE a IS NULL 334d3835579Sdrh ORDER BY coalesce(a,b,3); 335d3835579Sdrh} { 336d3835579Sdrh} 337d3835579Sdrh 338d3835579Sdrh# PG-14 is unable 339d3835579Sdrh# 340d3835579Sdrh# do_execsql_test joinE-38 { 341d3835579Sdrh# SELECT a, b 342d3835579Sdrh# FROM t1 FULL JOIN t2 ON a IS NULL 343d3835579Sdrh# ORDER BY coalesce(a,b,3); 344d3835579Sdrh# } { 345d3835579Sdrh# } 346d3835579Sdrh 347d3835579Sdrhdo_execsql_test joinE-39 { 348d3835579Sdrh SELECT a, b 349d3835579Sdrh FROM t1 FULL JOIN t2 ON true WHERE b IS NULL 350d3835579Sdrh ORDER BY coalesce(a,b,3); 351d3835579Sdrh} { 352d3835579Sdrh 1 - 353d3835579Sdrh} 354d3835579Sdrh 355d3835579Sdrh# PG-14 is unable 356d3835579Sdrh# do_execsql_test joinE-40 { 357d3835579Sdrh# SELECT a, b 358d3835579Sdrh# FROM t1 FULL JOIN t2 ON b IS NULL 359d3835579Sdrh# ORDER BY coalesce(a,b,3); 360d3835579Sdrh# } { 361d3835579Sdrh# } 362d3835579Sdrh 363d3835579Sdrhfinish_test 364*f8d2745fSdrh 365*f8d2745fSdrh############################################################################## 366*f8d2745fSdrh# This is the PG-14 test script generator 367*f8d2745fSdrh# 368*f8d2745fSdrh# puts " 369*f8d2745fSdrh# \\pset border off 370*f8d2745fSdrh# \\pset tuples_only on 371*f8d2745fSdrh# \\pset null - 372*f8d2745fSdrh# 373*f8d2745fSdrh# DROP TABLE IF EXISTS t1; 374*f8d2745fSdrh# DROP TABLE IF EXISTS t2; 375*f8d2745fSdrh# CREATE TABLE t1(a INT); 376*f8d2745fSdrh# INSERT INTO t1 VALUES(1),(NULL); 377*f8d2745fSdrh# CREATE TABLE t2(b INT); 378*f8d2745fSdrh# INSERT INTO t2 VALUES(2),(NULL); 379*f8d2745fSdrh# " 380*f8d2745fSdrh# 381*f8d2745fSdrh# proc echo {prefix txt} { 382*f8d2745fSdrh# regsub -all {\n} $txt \n$prefix txt 383*f8d2745fSdrh# puts "$prefix$txt" 384*f8d2745fSdrh# } 385*f8d2745fSdrh# 386*f8d2745fSdrh# set n 0 387*f8d2745fSdrh# set k 0 388*f8d2745fSdrh# foreach j1 {INNER LEFT RIGHT FULL} { 389*f8d2745fSdrh# foreach on1 { 390*f8d2745fSdrh# true 391*f8d2745fSdrh# {true WHERE a IS NULL} 392*f8d2745fSdrh# {a IS NULL} 393*f8d2745fSdrh# {true WHERE b IS NULL} 394*f8d2745fSdrh# {b IS NULL} 395*f8d2745fSdrh# } { 396*f8d2745fSdrh# 397*f8d2745fSdrh# incr n 398*f8d2745fSdrh# incr k 399*f8d2745fSdrh# set q1 "" 400*f8d2745fSdrh# append q1 "SELECT a, b\n" 401*f8d2745fSdrh# append q1 " FROM t1 $j1 JOIN t2 ON $on1\n" 402*f8d2745fSdrh# append q1 " ORDER BY coalesce(a,b,3);" 403*f8d2745fSdrh# 404*f8d2745fSdrh# echo "\\qecho " "do_execsql_test joinE-$n \{" 405*f8d2745fSdrh# echo "\\qecho X " $q1 406*f8d2745fSdrh# echo "\\qecho " "\} \{" 407*f8d2745fSdrh# puts $q1 408*f8d2745fSdrh# echo "\\qecho " "\}" 409*f8d2745fSdrh# 410*f8d2745fSdrh# } 411*f8d2745fSdrh# } 412*f8d2745fSdrh# 413*f8d2745fSdrh# puts " 414*f8d2745fSdrh# DELETE FROM t1; 415*f8d2745fSdrh# INSERT INTO t1 VALUES(1); 416*f8d2745fSdrh# DELETE FROM t2; 417*f8d2745fSdrh# INSERT INTO t2 VALUES(NULL); 418*f8d2745fSdrh# " 419*f8d2745fSdrh# 420*f8d2745fSdrh# foreach j1 {INNER LEFT RIGHT FULL} { 421*f8d2745fSdrh# foreach on1 { 422*f8d2745fSdrh# true 423*f8d2745fSdrh# {true WHERE a IS NULL} 424*f8d2745fSdrh# {a IS NULL} 425*f8d2745fSdrh# {true WHERE b IS NULL} 426*f8d2745fSdrh# {b IS NULL} 427*f8d2745fSdrh# } { 428*f8d2745fSdrh# 429*f8d2745fSdrh# incr n 430*f8d2745fSdrh# incr k 431*f8d2745fSdrh# set q1 "" 432*f8d2745fSdrh# append q1 "SELECT a, b\n" 433*f8d2745fSdrh# append q1 " FROM t1 $j1 JOIN t2 ON $on1\n" 434*f8d2745fSdrh# append q1 " ORDER BY coalesce(a,b,3);" 435*f8d2745fSdrh# 436*f8d2745fSdrh# echo "\\qecho " "do_execsql_test joinE-$n \{" 437*f8d2745fSdrh# echo "\\qecho X " $q1 438*f8d2745fSdrh# echo "\\qecho " "\} \{" 439*f8d2745fSdrh# puts $q1 440*f8d2745fSdrh# echo "\\qecho " "\}" 441*f8d2745fSdrh# 442*f8d2745fSdrh# } 443*f8d2745fSdrh# } 444