1-- Currently this tests polymorphic aggregates and indirectly does some 2-- testing of polymorphic SQL functions. It ought to be extended. 3-- Tests for other features related to function-calling have snuck in, too. 4 5 6-- Legend: 7----------- 8-- A = type is ANY 9-- P = type is polymorphic 10-- N = type is non-polymorphic 11-- B = aggregate base type 12-- S = aggregate state type 13-- R = aggregate return type 14-- 1 = arg1 of a function 15-- 2 = arg2 of a function 16-- ag = aggregate 17-- tf = trans (state) function 18-- ff = final function 19-- rt = return type of a function 20-- -> = implies 21-- => = allowed 22-- !> = not allowed 23-- E = exists 24-- NE = not-exists 25-- 26-- Possible states: 27-- ---------------- 28-- B = (A || P || N) 29-- when (B = A) -> (tf2 = NE) 30-- S = (P || N) 31-- ff = (E || NE) 32-- tf1 = (P || N) 33-- tf2 = (NE || P || N) 34-- R = (P || N) 35 36-- create functions for use as tf and ff with the needed combinations of 37-- argument polymorphism, but within the constraints of valid aggregate 38-- functions, i.e. tf arg1 and tf return type must match 39 40-- polymorphic single arg transfn 41CREATE FUNCTION stfp(anyarray) RETURNS anyarray AS 42'select $1' LANGUAGE SQL; 43-- non-polymorphic single arg transfn 44CREATE FUNCTION stfnp(int[]) RETURNS int[] AS 45'select $1' LANGUAGE SQL; 46 47-- dual polymorphic transfn 48CREATE FUNCTION tfp(anyarray,anyelement) RETURNS anyarray AS 49'select $1 || $2' LANGUAGE SQL; 50-- dual non-polymorphic transfn 51CREATE FUNCTION tfnp(int[],int) RETURNS int[] AS 52'select $1 || $2' LANGUAGE SQL; 53 54-- arg1 only polymorphic transfn 55CREATE FUNCTION tf1p(anyarray,int) RETURNS anyarray AS 56'select $1' LANGUAGE SQL; 57-- arg2 only polymorphic transfn 58CREATE FUNCTION tf2p(int[],anyelement) RETURNS int[] AS 59'select $1' LANGUAGE SQL; 60 61-- multi-arg polymorphic 62CREATE FUNCTION sum3(anyelement,anyelement,anyelement) returns anyelement AS 63'select $1+$2+$3' language sql strict; 64 65-- finalfn polymorphic 66CREATE FUNCTION ffp(anyarray) RETURNS anyarray AS 67'select $1' LANGUAGE SQL; 68-- finalfn non-polymorphic 69CREATE FUNCTION ffnp(int[]) returns int[] as 70'select $1' LANGUAGE SQL; 71 72-- Try to cover all the possible states: 73-- 74-- Note: in Cases 1 & 2, we are trying to return P. Therefore, if the transfn 75-- is stfnp, tfnp, or tf2p, we must use ffp as finalfn, because stfnp, tfnp, 76-- and tf2p do not return P. Conversely, in Cases 3 & 4, we are trying to 77-- return N. Therefore, if the transfn is stfp, tfp, or tf1p, we must use ffnp 78-- as finalfn, because stfp, tfp, and tf1p do not return N. 79-- 80-- Case1 (R = P) && (B = A) 81-- ------------------------ 82-- S tf1 83-- ------- 84-- N N 85-- should CREATE 86CREATE AGGREGATE myaggp01a(*) (SFUNC = stfnp, STYPE = int4[], 87 FINALFUNC = ffp, INITCOND = '{}'); 88 89-- P N 90-- should ERROR: stfnp(anyarray) not matched by stfnp(int[]) 91CREATE AGGREGATE myaggp02a(*) (SFUNC = stfnp, STYPE = anyarray, 92 FINALFUNC = ffp, INITCOND = '{}'); 93 94-- N P 95-- should CREATE 96CREATE AGGREGATE myaggp03a(*) (SFUNC = stfp, STYPE = int4[], 97 FINALFUNC = ffp, INITCOND = '{}'); 98CREATE AGGREGATE myaggp03b(*) (SFUNC = stfp, STYPE = int4[], 99 INITCOND = '{}'); 100 101-- P P 102-- should ERROR: we have no way to resolve S 103CREATE AGGREGATE myaggp04a(*) (SFUNC = stfp, STYPE = anyarray, 104 FINALFUNC = ffp, INITCOND = '{}'); 105CREATE AGGREGATE myaggp04b(*) (SFUNC = stfp, STYPE = anyarray, 106 INITCOND = '{}'); 107 108 109-- Case2 (R = P) && ((B = P) || (B = N)) 110-- ------------------------------------- 111-- S tf1 B tf2 112-- ----------------------- 113-- N N N N 114-- should CREATE 115CREATE AGGREGATE myaggp05a(BASETYPE = int, SFUNC = tfnp, STYPE = int[], 116 FINALFUNC = ffp, INITCOND = '{}'); 117 118-- N N N P 119-- should CREATE 120CREATE AGGREGATE myaggp06a(BASETYPE = int, SFUNC = tf2p, STYPE = int[], 121 FINALFUNC = ffp, INITCOND = '{}'); 122 123-- N N P N 124-- should ERROR: tfnp(int[], anyelement) not matched by tfnp(int[], int) 125CREATE AGGREGATE myaggp07a(BASETYPE = anyelement, SFUNC = tfnp, STYPE = int[], 126 FINALFUNC = ffp, INITCOND = '{}'); 127 128-- N N P P 129-- should CREATE 130CREATE AGGREGATE myaggp08a(BASETYPE = anyelement, SFUNC = tf2p, STYPE = int[], 131 FINALFUNC = ffp, INITCOND = '{}'); 132 133-- N P N N 134-- should CREATE 135CREATE AGGREGATE myaggp09a(BASETYPE = int, SFUNC = tf1p, STYPE = int[], 136 FINALFUNC = ffp, INITCOND = '{}'); 137CREATE AGGREGATE myaggp09b(BASETYPE = int, SFUNC = tf1p, STYPE = int[], 138 INITCOND = '{}'); 139 140-- N P N P 141-- should CREATE 142CREATE AGGREGATE myaggp10a(BASETYPE = int, SFUNC = tfp, STYPE = int[], 143 FINALFUNC = ffp, INITCOND = '{}'); 144CREATE AGGREGATE myaggp10b(BASETYPE = int, SFUNC = tfp, STYPE = int[], 145 INITCOND = '{}'); 146 147-- N P P N 148-- should ERROR: tf1p(int[],anyelement) not matched by tf1p(anyarray,int) 149CREATE AGGREGATE myaggp11a(BASETYPE = anyelement, SFUNC = tf1p, STYPE = int[], 150 FINALFUNC = ffp, INITCOND = '{}'); 151CREATE AGGREGATE myaggp11b(BASETYPE = anyelement, SFUNC = tf1p, STYPE = int[], 152 INITCOND = '{}'); 153 154-- N P P P 155-- should ERROR: tfp(int[],anyelement) not matched by tfp(anyarray,anyelement) 156CREATE AGGREGATE myaggp12a(BASETYPE = anyelement, SFUNC = tfp, STYPE = int[], 157 FINALFUNC = ffp, INITCOND = '{}'); 158CREATE AGGREGATE myaggp12b(BASETYPE = anyelement, SFUNC = tfp, STYPE = int[], 159 INITCOND = '{}'); 160 161-- P N N N 162-- should ERROR: tfnp(anyarray, int) not matched by tfnp(int[],int) 163CREATE AGGREGATE myaggp13a(BASETYPE = int, SFUNC = tfnp, STYPE = anyarray, 164 FINALFUNC = ffp, INITCOND = '{}'); 165 166-- P N N P 167-- should ERROR: tf2p(anyarray, int) not matched by tf2p(int[],anyelement) 168CREATE AGGREGATE myaggp14a(BASETYPE = int, SFUNC = tf2p, STYPE = anyarray, 169 FINALFUNC = ffp, INITCOND = '{}'); 170 171-- P N P N 172-- should ERROR: tfnp(anyarray, anyelement) not matched by tfnp(int[],int) 173CREATE AGGREGATE myaggp15a(BASETYPE = anyelement, SFUNC = tfnp, 174 STYPE = anyarray, FINALFUNC = ffp, INITCOND = '{}'); 175 176-- P N P P 177-- should ERROR: tf2p(anyarray, anyelement) not matched by tf2p(int[],anyelement) 178CREATE AGGREGATE myaggp16a(BASETYPE = anyelement, SFUNC = tf2p, 179 STYPE = anyarray, FINALFUNC = ffp, INITCOND = '{}'); 180 181-- P P N N 182-- should ERROR: we have no way to resolve S 183CREATE AGGREGATE myaggp17a(BASETYPE = int, SFUNC = tf1p, STYPE = anyarray, 184 FINALFUNC = ffp, INITCOND = '{}'); 185CREATE AGGREGATE myaggp17b(BASETYPE = int, SFUNC = tf1p, STYPE = anyarray, 186 INITCOND = '{}'); 187 188-- P P N P 189-- should ERROR: tfp(anyarray, int) not matched by tfp(anyarray, anyelement) 190CREATE AGGREGATE myaggp18a(BASETYPE = int, SFUNC = tfp, STYPE = anyarray, 191 FINALFUNC = ffp, INITCOND = '{}'); 192CREATE AGGREGATE myaggp18b(BASETYPE = int, SFUNC = tfp, STYPE = anyarray, 193 INITCOND = '{}'); 194 195-- P P P N 196-- should ERROR: tf1p(anyarray, anyelement) not matched by tf1p(anyarray, int) 197CREATE AGGREGATE myaggp19a(BASETYPE = anyelement, SFUNC = tf1p, 198 STYPE = anyarray, FINALFUNC = ffp, INITCOND = '{}'); 199CREATE AGGREGATE myaggp19b(BASETYPE = anyelement, SFUNC = tf1p, 200 STYPE = anyarray, INITCOND = '{}'); 201 202-- P P P P 203-- should CREATE 204CREATE AGGREGATE myaggp20a(BASETYPE = anyelement, SFUNC = tfp, 205 STYPE = anyarray, FINALFUNC = ffp, INITCOND = '{}'); 206CREATE AGGREGATE myaggp20b(BASETYPE = anyelement, SFUNC = tfp, 207 STYPE = anyarray, INITCOND = '{}'); 208 209-- Case3 (R = N) && (B = A) 210-- ------------------------ 211-- S tf1 212-- ------- 213-- N N 214-- should CREATE 215CREATE AGGREGATE myaggn01a(*) (SFUNC = stfnp, STYPE = int4[], 216 FINALFUNC = ffnp, INITCOND = '{}'); 217CREATE AGGREGATE myaggn01b(*) (SFUNC = stfnp, STYPE = int4[], 218 INITCOND = '{}'); 219 220-- P N 221-- should ERROR: stfnp(anyarray) not matched by stfnp(int[]) 222CREATE AGGREGATE myaggn02a(*) (SFUNC = stfnp, STYPE = anyarray, 223 FINALFUNC = ffnp, INITCOND = '{}'); 224CREATE AGGREGATE myaggn02b(*) (SFUNC = stfnp, STYPE = anyarray, 225 INITCOND = '{}'); 226 227-- N P 228-- should CREATE 229CREATE AGGREGATE myaggn03a(*) (SFUNC = stfp, STYPE = int4[], 230 FINALFUNC = ffnp, INITCOND = '{}'); 231 232-- P P 233-- should ERROR: ffnp(anyarray) not matched by ffnp(int[]) 234CREATE AGGREGATE myaggn04a(*) (SFUNC = stfp, STYPE = anyarray, 235 FINALFUNC = ffnp, INITCOND = '{}'); 236 237 238-- Case4 (R = N) && ((B = P) || (B = N)) 239-- ------------------------------------- 240-- S tf1 B tf2 241-- ----------------------- 242-- N N N N 243-- should CREATE 244CREATE AGGREGATE myaggn05a(BASETYPE = int, SFUNC = tfnp, STYPE = int[], 245 FINALFUNC = ffnp, INITCOND = '{}'); 246CREATE AGGREGATE myaggn05b(BASETYPE = int, SFUNC = tfnp, STYPE = int[], 247 INITCOND = '{}'); 248 249-- N N N P 250-- should CREATE 251CREATE AGGREGATE myaggn06a(BASETYPE = int, SFUNC = tf2p, STYPE = int[], 252 FINALFUNC = ffnp, INITCOND = '{}'); 253CREATE AGGREGATE myaggn06b(BASETYPE = int, SFUNC = tf2p, STYPE = int[], 254 INITCOND = '{}'); 255 256-- N N P N 257-- should ERROR: tfnp(int[], anyelement) not matched by tfnp(int[], int) 258CREATE AGGREGATE myaggn07a(BASETYPE = anyelement, SFUNC = tfnp, STYPE = int[], 259 FINALFUNC = ffnp, INITCOND = '{}'); 260CREATE AGGREGATE myaggn07b(BASETYPE = anyelement, SFUNC = tfnp, STYPE = int[], 261 INITCOND = '{}'); 262 263-- N N P P 264-- should CREATE 265CREATE AGGREGATE myaggn08a(BASETYPE = anyelement, SFUNC = tf2p, STYPE = int[], 266 FINALFUNC = ffnp, INITCOND = '{}'); 267CREATE AGGREGATE myaggn08b(BASETYPE = anyelement, SFUNC = tf2p, STYPE = int[], 268 INITCOND = '{}'); 269 270-- N P N N 271-- should CREATE 272CREATE AGGREGATE myaggn09a(BASETYPE = int, SFUNC = tf1p, STYPE = int[], 273 FINALFUNC = ffnp, INITCOND = '{}'); 274 275-- N P N P 276-- should CREATE 277CREATE AGGREGATE myaggn10a(BASETYPE = int, SFUNC = tfp, STYPE = int[], 278 FINALFUNC = ffnp, INITCOND = '{}'); 279 280-- N P P N 281-- should ERROR: tf1p(int[],anyelement) not matched by tf1p(anyarray,int) 282CREATE AGGREGATE myaggn11a(BASETYPE = anyelement, SFUNC = tf1p, STYPE = int[], 283 FINALFUNC = ffnp, INITCOND = '{}'); 284 285-- N P P P 286-- should ERROR: tfp(int[],anyelement) not matched by tfp(anyarray,anyelement) 287CREATE AGGREGATE myaggn12a(BASETYPE = anyelement, SFUNC = tfp, STYPE = int[], 288 FINALFUNC = ffnp, INITCOND = '{}'); 289 290-- P N N N 291-- should ERROR: tfnp(anyarray, int) not matched by tfnp(int[],int) 292CREATE AGGREGATE myaggn13a(BASETYPE = int, SFUNC = tfnp, STYPE = anyarray, 293 FINALFUNC = ffnp, INITCOND = '{}'); 294CREATE AGGREGATE myaggn13b(BASETYPE = int, SFUNC = tfnp, STYPE = anyarray, 295 INITCOND = '{}'); 296 297-- P N N P 298-- should ERROR: tf2p(anyarray, int) not matched by tf2p(int[],anyelement) 299CREATE AGGREGATE myaggn14a(BASETYPE = int, SFUNC = tf2p, STYPE = anyarray, 300 FINALFUNC = ffnp, INITCOND = '{}'); 301CREATE AGGREGATE myaggn14b(BASETYPE = int, SFUNC = tf2p, STYPE = anyarray, 302 INITCOND = '{}'); 303 304-- P N P N 305-- should ERROR: tfnp(anyarray, anyelement) not matched by tfnp(int[],int) 306CREATE AGGREGATE myaggn15a(BASETYPE = anyelement, SFUNC = tfnp, 307 STYPE = anyarray, FINALFUNC = ffnp, INITCOND = '{}'); 308CREATE AGGREGATE myaggn15b(BASETYPE = anyelement, SFUNC = tfnp, 309 STYPE = anyarray, INITCOND = '{}'); 310 311-- P N P P 312-- should ERROR: tf2p(anyarray, anyelement) not matched by tf2p(int[],anyelement) 313CREATE AGGREGATE myaggn16a(BASETYPE = anyelement, SFUNC = tf2p, 314 STYPE = anyarray, FINALFUNC = ffnp, INITCOND = '{}'); 315CREATE AGGREGATE myaggn16b(BASETYPE = anyelement, SFUNC = tf2p, 316 STYPE = anyarray, INITCOND = '{}'); 317 318-- P P N N 319-- should ERROR: ffnp(anyarray) not matched by ffnp(int[]) 320CREATE AGGREGATE myaggn17a(BASETYPE = int, SFUNC = tf1p, STYPE = anyarray, 321 FINALFUNC = ffnp, INITCOND = '{}'); 322 323-- P P N P 324-- should ERROR: tfp(anyarray, int) not matched by tfp(anyarray, anyelement) 325CREATE AGGREGATE myaggn18a(BASETYPE = int, SFUNC = tfp, STYPE = anyarray, 326 FINALFUNC = ffnp, INITCOND = '{}'); 327 328-- P P P N 329-- should ERROR: tf1p(anyarray, anyelement) not matched by tf1p(anyarray, int) 330CREATE AGGREGATE myaggn19a(BASETYPE = anyelement, SFUNC = tf1p, 331 STYPE = anyarray, FINALFUNC = ffnp, INITCOND = '{}'); 332 333-- P P P P 334-- should ERROR: ffnp(anyarray) not matched by ffnp(int[]) 335CREATE AGGREGATE myaggn20a(BASETYPE = anyelement, SFUNC = tfp, 336 STYPE = anyarray, FINALFUNC = ffnp, INITCOND = '{}'); 337 338-- multi-arg polymorphic 339CREATE AGGREGATE mysum2(anyelement,anyelement) (SFUNC = sum3, 340 STYPE = anyelement, INITCOND = '0'); 341 342-- create test data for polymorphic aggregates 343create temp table t(f1 int, f2 int[], f3 text); 344insert into t values(1,array[1],'a'); 345insert into t values(1,array[11],'b'); 346insert into t values(1,array[111],'c'); 347insert into t values(2,array[2],'a'); 348insert into t values(2,array[22],'b'); 349insert into t values(2,array[222],'c'); 350insert into t values(3,array[3],'a'); 351insert into t values(3,array[3],'b'); 352 353-- test the successfully created polymorphic aggregates 354select f3, myaggp01a(*) from t group by f3 order by f3; 355select f3, myaggp03a(*) from t group by f3 order by f3; 356select f3, myaggp03b(*) from t group by f3 order by f3; 357select f3, myaggp05a(f1) from t group by f3 order by f3; 358select f3, myaggp06a(f1) from t group by f3 order by f3; 359select f3, myaggp08a(f1) from t group by f3 order by f3; 360select f3, myaggp09a(f1) from t group by f3 order by f3; 361select f3, myaggp09b(f1) from t group by f3 order by f3; 362select f3, myaggp10a(f1) from t group by f3 order by f3; 363select f3, myaggp10b(f1) from t group by f3 order by f3; 364select f3, myaggp20a(f1) from t group by f3 order by f3; 365select f3, myaggp20b(f1) from t group by f3 order by f3; 366select f3, myaggn01a(*) from t group by f3 order by f3; 367select f3, myaggn01b(*) from t group by f3 order by f3; 368select f3, myaggn03a(*) from t group by f3 order by f3; 369select f3, myaggn05a(f1) from t group by f3 order by f3; 370select f3, myaggn05b(f1) from t group by f3 order by f3; 371select f3, myaggn06a(f1) from t group by f3 order by f3; 372select f3, myaggn06b(f1) from t group by f3 order by f3; 373select f3, myaggn08a(f1) from t group by f3 order by f3; 374select f3, myaggn08b(f1) from t group by f3 order by f3; 375select f3, myaggn09a(f1) from t group by f3 order by f3; 376select f3, myaggn10a(f1) from t group by f3 order by f3; 377select mysum2(f1, f1 + 1) from t; 378 379-- test inlining of polymorphic SQL functions 380create function bleat(int) returns int as $$ 381begin 382 raise notice 'bleat %', $1; 383 return $1; 384end$$ language plpgsql; 385 386create function sql_if(bool, anyelement, anyelement) returns anyelement as $$ 387select case when $1 then $2 else $3 end $$ language sql; 388 389-- Note this would fail with integer overflow, never mind wrong bleat() output, 390-- if the CASE expression were not successfully inlined 391select f1, sql_if(f1 > 0, bleat(f1), bleat(f1 + 1)) from int4_tbl; 392 393select q2, sql_if(q2 > 0, q2, q2 + 1) from int8_tbl; 394 395-- another sort of polymorphic aggregate 396 397CREATE AGGREGATE array_larger_accum (anyarray) 398( 399 sfunc = array_larger, 400 stype = anyarray, 401 initcond = '{}' 402); 403 404SELECT array_larger_accum(i) 405FROM (VALUES (ARRAY[1,2]), (ARRAY[3,4])) as t(i); 406 407SELECT array_larger_accum(i) 408FROM (VALUES (ARRAY[row(1,2),row(3,4)]), (ARRAY[row(5,6),row(7,8)])) as t(i); 409 410-- another kind of polymorphic aggregate 411 412create function add_group(grp anyarray, ad anyelement, size integer) 413 returns anyarray 414 as $$ 415begin 416 if grp is null then 417 return array[ad]; 418 end if; 419 if array_upper(grp, 1) < size then 420 return grp || ad; 421 end if; 422 return grp; 423end; 424$$ 425 language plpgsql immutable; 426 427create aggregate build_group(anyelement, integer) ( 428 SFUNC = add_group, 429 STYPE = anyarray 430); 431 432select build_group(q1,3) from int8_tbl; 433 434-- this should fail because stype isn't compatible with arg 435create aggregate build_group(int8, integer) ( 436 SFUNC = add_group, 437 STYPE = int2[] 438); 439 440-- but we can make a non-poly agg from a poly sfunc if types are OK 441create aggregate build_group(int8, integer) ( 442 SFUNC = add_group, 443 STYPE = int8[] 444); 445 446-- check proper resolution of data types for polymorphic transfn/finalfn 447 448create function first_el_transfn(anyarray, anyelement) returns anyarray as 449'select $1 || $2' language sql immutable; 450 451create function first_el(anyarray) returns anyelement as 452'select $1[1]' language sql strict immutable; 453 454create aggregate first_el_agg_f8(float8) ( 455 SFUNC = array_append, 456 STYPE = float8[], 457 FINALFUNC = first_el 458); 459 460create aggregate first_el_agg_any(anyelement) ( 461 SFUNC = first_el_transfn, 462 STYPE = anyarray, 463 FINALFUNC = first_el 464); 465 466select first_el_agg_f8(x::float8) from generate_series(1,10) x; 467select first_el_agg_any(x) from generate_series(1,10) x; 468select first_el_agg_f8(x::float8) over(order by x) from generate_series(1,10) x; 469select first_el_agg_any(x) over(order by x) from generate_series(1,10) x; 470 471-- check that we can apply functions taking ANYARRAY to pg_stats 472select distinct array_ndims(histogram_bounds) from pg_stats 473where histogram_bounds is not null; 474 475-- such functions must protect themselves if varying element type isn't OK 476-- (WHERE clause here is to avoid possibly getting a collation error instead) 477select max(histogram_bounds) from pg_stats where tablename = 'pg_am'; 478 479-- test variadic polymorphic functions 480 481create function myleast(variadic anyarray) returns anyelement as $$ 482 select min($1[i]) from generate_subscripts($1,1) g(i) 483$$ language sql immutable strict; 484 485select myleast(10, 1, 20, 33); 486select myleast(1.1, 0.22, 0.55); 487select myleast('z'::text); 488select myleast(); -- fail 489 490-- test with variadic call parameter 491select myleast(variadic array[1,2,3,4,-1]); 492select myleast(variadic array[1.1, -5.5]); 493 494--test with empty variadic call parameter 495select myleast(variadic array[]::int[]); 496 497-- an example with some ordinary arguments too 498create function concat(text, variadic anyarray) returns text as $$ 499 select array_to_string($2, $1); 500$$ language sql immutable strict; 501 502select concat('%', 1, 2, 3, 4, 5); 503select concat('|', 'a'::text, 'b', 'c'); 504select concat('|', variadic array[1,2,33]); 505select concat('|', variadic array[]::int[]); 506 507drop function concat(text, anyarray); 508 509-- mix variadic with anyelement 510create function formarray(anyelement, variadic anyarray) returns anyarray as $$ 511 select array_prepend($1, $2); 512$$ language sql immutable strict; 513 514select formarray(1,2,3,4,5); 515select formarray(1.1, variadic array[1.2,55.5]); 516select formarray(1.1, array[1.2,55.5]); -- fail without variadic 517select formarray(1, 'x'::text); -- fail, type mismatch 518select formarray(1, variadic array['x'::text]); -- fail, type mismatch 519 520drop function formarray(anyelement, variadic anyarray); 521 522-- test pg_typeof() function 523select pg_typeof(null); -- unknown 524select pg_typeof(0); -- integer 525select pg_typeof(0.0); -- numeric 526select pg_typeof(1+1 = 2); -- boolean 527select pg_typeof('x'); -- unknown 528select pg_typeof('' || ''); -- text 529select pg_typeof(pg_typeof(0)); -- regtype 530select pg_typeof(array[1.2,55.5]); -- numeric[] 531select pg_typeof(myleast(10, 1, 20, 33)); -- polymorphic input 532 533-- test functions with default parameters 534 535-- test basic functionality 536create function dfunc(a int = 1, int = 2) returns int as $$ 537 select $1 + $2; 538$$ language sql; 539 540select dfunc(); 541select dfunc(10); 542select dfunc(10, 20); 543select dfunc(10, 20, 30); -- fail 544 545drop function dfunc(); -- fail 546drop function dfunc(int); -- fail 547drop function dfunc(int, int); -- ok 548 549-- fail: defaults must be at end of argument list 550create function dfunc(a int = 1, b int) returns int as $$ 551 select $1 + $2; 552$$ language sql; 553 554-- however, this should work: 555create function dfunc(a int = 1, out sum int, b int = 2) as $$ 556 select $1 + $2; 557$$ language sql; 558 559select dfunc(); 560 561-- verify it lists properly 562\df dfunc 563 564drop function dfunc(int, int); 565 566-- check implicit coercion 567create function dfunc(a int DEFAULT 1.0, int DEFAULT '-1') returns int as $$ 568 select $1 + $2; 569$$ language sql; 570select dfunc(); 571 572create function dfunc(a text DEFAULT 'Hello', b text DEFAULT 'World') returns text as $$ 573 select $1 || ', ' || $2; 574$$ language sql; 575 576select dfunc(); -- fail: which dfunc should be called? int or text 577select dfunc('Hi'); -- ok 578select dfunc('Hi', 'City'); -- ok 579select dfunc(0); -- ok 580select dfunc(10, 20); -- ok 581 582drop function dfunc(int, int); 583drop function dfunc(text, text); 584 585create function dfunc(int = 1, int = 2) returns int as $$ 586 select 2; 587$$ language sql; 588 589create function dfunc(int = 1, int = 2, int = 3, int = 4) returns int as $$ 590 select 4; 591$$ language sql; 592 593-- Now, dfunc(nargs = 2) and dfunc(nargs = 4) are ambiguous when called 594-- with 0 to 2 arguments. 595 596select dfunc(); -- fail 597select dfunc(1); -- fail 598select dfunc(1, 2); -- fail 599select dfunc(1, 2, 3); -- ok 600select dfunc(1, 2, 3, 4); -- ok 601 602drop function dfunc(int, int); 603drop function dfunc(int, int, int, int); 604 605-- default values are not allowed for output parameters 606create function dfunc(out int = 20) returns int as $$ 607 select 1; 608$$ language sql; 609 610-- polymorphic parameter test 611create function dfunc(anyelement = 'World'::text) returns text as $$ 612 select 'Hello, ' || $1::text; 613$$ language sql; 614 615select dfunc(); 616select dfunc(0); 617select dfunc(to_date('20081215','YYYYMMDD')); 618select dfunc('City'::text); 619 620drop function dfunc(anyelement); 621 622-- check defaults for variadics 623 624create function dfunc(a variadic int[]) returns int as 625$$ select array_upper($1, 1) $$ language sql; 626 627select dfunc(); -- fail 628select dfunc(10); 629select dfunc(10,20); 630 631create or replace function dfunc(a variadic int[] default array[]::int[]) returns int as 632$$ select array_upper($1, 1) $$ language sql; 633 634select dfunc(); -- now ok 635select dfunc(10); 636select dfunc(10,20); 637 638-- can't remove the default once it exists 639create or replace function dfunc(a variadic int[]) returns int as 640$$ select array_upper($1, 1) $$ language sql; 641 642\df dfunc 643 644drop function dfunc(a variadic int[]); 645 646-- Ambiguity should be reported only if there's not a better match available 647 648create function dfunc(int = 1, int = 2, int = 3) returns int as $$ 649 select 3; 650$$ language sql; 651 652create function dfunc(int = 1, int = 2) returns int as $$ 653 select 2; 654$$ language sql; 655 656create function dfunc(text) returns text as $$ 657 select $1; 658$$ language sql; 659 660-- dfunc(narg=2) and dfunc(narg=3) are ambiguous 661select dfunc(1); -- fail 662 663-- but this works since the ambiguous functions aren't preferred anyway 664select dfunc('Hi'); 665 666drop function dfunc(int, int, int); 667drop function dfunc(int, int); 668drop function dfunc(text); 669 670-- 671-- Tests for named- and mixed-notation function calling 672-- 673 674create function dfunc(a int, b int, c int = 0, d int = 0) 675 returns table (a int, b int, c int, d int) as $$ 676 select $1, $2, $3, $4; 677$$ language sql; 678 679select (dfunc(10,20,30)).*; 680select (dfunc(a := 10, b := 20, c := 30)).*; 681select * from dfunc(a := 10, b := 20); 682select * from dfunc(b := 10, a := 20); 683select * from dfunc(0); -- fail 684select * from dfunc(1,2); 685select * from dfunc(1,2,c := 3); 686select * from dfunc(1,2,d := 3); 687 688select * from dfunc(x := 20, b := 10, x := 30); -- fail, duplicate name 689select * from dfunc(10, b := 20, 30); -- fail, named args must be last 690select * from dfunc(x := 10, b := 20, c := 30); -- fail, unknown param 691select * from dfunc(10, 10, a := 20); -- fail, a overlaps positional parameter 692select * from dfunc(1,c := 2,d := 3); -- fail, no value for b 693 694drop function dfunc(int, int, int, int); 695 696-- test with different parameter types 697create function dfunc(a varchar, b numeric, c date = current_date) 698 returns table (a varchar, b numeric, c date) as $$ 699 select $1, $2, $3; 700$$ language sql; 701 702select (dfunc('Hello World', 20, '2009-07-25'::date)).*; 703select * from dfunc('Hello World', 20, '2009-07-25'::date); 704select * from dfunc(c := '2009-07-25'::date, a := 'Hello World', b := 20); 705select * from dfunc('Hello World', b := 20, c := '2009-07-25'::date); 706select * from dfunc('Hello World', c := '2009-07-25'::date, b := 20); 707select * from dfunc('Hello World', c := 20, b := '2009-07-25'::date); -- fail 708 709drop function dfunc(varchar, numeric, date); 710 711-- test out parameters with named params 712create function dfunc(a varchar = 'def a', out _a varchar, c numeric = NULL, out _c numeric) 713returns record as $$ 714 select $1, $2; 715$$ language sql; 716 717select (dfunc()).*; 718select * from dfunc(); 719select * from dfunc('Hello', 100); 720select * from dfunc(a := 'Hello', c := 100); 721select * from dfunc(c := 100, a := 'Hello'); 722select * from dfunc('Hello'); 723select * from dfunc('Hello', c := 100); 724select * from dfunc(c := 100); 725 726-- fail, can no longer change an input parameter's name 727create or replace function dfunc(a varchar = 'def a', out _a varchar, x numeric = NULL, out _c numeric) 728returns record as $$ 729 select $1, $2; 730$$ language sql; 731 732create or replace function dfunc(a varchar = 'def a', out _a varchar, numeric = NULL, out _c numeric) 733returns record as $$ 734 select $1, $2; 735$$ language sql; 736 737drop function dfunc(varchar, numeric); 738 739--fail, named parameters are not unique 740create function testfoo(a int, a int) returns int as $$ select 1;$$ language sql; 741create function testfoo(int, out a int, out a int) returns int as $$ select 1;$$ language sql; 742create function testfoo(out a int, inout a int) returns int as $$ select 1;$$ language sql; 743create function testfoo(a int, inout a int) returns int as $$ select 1;$$ language sql; 744 745-- valid 746create function testfoo(a int, out a int) returns int as $$ select $1;$$ language sql; 747select testfoo(37); 748drop function testfoo(int); 749create function testfoo(a int) returns table(a int) as $$ select $1;$$ language sql; 750select * from testfoo(37); 751drop function testfoo(int); 752 753-- test polymorphic params and defaults 754create function dfunc(a anyelement, b anyelement = null, flag bool = true) 755returns anyelement as $$ 756 select case when $3 then $1 else $2 end; 757$$ language sql; 758 759select dfunc(1,2); 760select dfunc('a'::text, 'b'); -- positional notation with default 761 762select dfunc(a := 1, b := 2); 763select dfunc(a := 'a'::text, b := 'b'); 764select dfunc(a := 'a'::text, b := 'b', flag := false); -- named notation 765 766select dfunc(b := 'b'::text, a := 'a'); -- named notation with default 767select dfunc(a := 'a'::text, flag := true); -- named notation with default 768select dfunc(a := 'a'::text, flag := false); -- named notation with default 769select dfunc(b := 'b'::text, a := 'a', flag := true); -- named notation 770 771select dfunc('a'::text, 'b', false); -- full positional notation 772select dfunc('a'::text, 'b', flag := false); -- mixed notation 773select dfunc('a'::text, 'b', true); -- full positional notation 774select dfunc('a'::text, 'b', flag := true); -- mixed notation 775 776-- ansi/sql syntax 777select dfunc(a => 1, b => 2); 778select dfunc(a => 'a'::text, b => 'b'); 779select dfunc(a => 'a'::text, b => 'b', flag => false); -- named notation 780 781select dfunc(b => 'b'::text, a => 'a'); -- named notation with default 782select dfunc(a => 'a'::text, flag => true); -- named notation with default 783select dfunc(a => 'a'::text, flag => false); -- named notation with default 784select dfunc(b => 'b'::text, a => 'a', flag => true); -- named notation 785 786select dfunc('a'::text, 'b', false); -- full positional notation 787select dfunc('a'::text, 'b', flag => false); -- mixed notation 788select dfunc('a'::text, 'b', true); -- full positional notation 789select dfunc('a'::text, 'b', flag => true); -- mixed notation 790 791-- this tests lexer edge cases around => 792select dfunc(a =>-1); 793select dfunc(a =>+1); 794select dfunc(a =>/**/1); 795select dfunc(a =>--comment to be removed by psql 796 1); 797-- need DO to protect the -- from psql 798do $$ 799 declare r integer; 800 begin 801 select dfunc(a=>-- comment 802 1) into r; 803 raise info 'r = %', r; 804 end; 805$$; 806 807-- check reverse-listing of named-arg calls 808CREATE VIEW dfview AS 809 SELECT q1, q2, 810 dfunc(q1,q2, flag := q1>q2) as c3, 811 dfunc(q1, flag := q1<q2, b := q2) as c4 812 FROM int8_tbl; 813 814select * from dfview; 815 816\d+ dfview 817 818drop view dfview; 819drop function dfunc(anyelement, anyelement, bool); 820