case.sql 6.1 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265
  1. --
  2. -- CASE
  3. -- Test the case statement
  4. --
  5. CREATE TABLE CASE_TBL (
  6. i integer,
  7. f double precision
  8. );
  9. CREATE TABLE CASE2_TBL (
  10. i integer,
  11. j integer
  12. );
  13. INSERT INTO CASE_TBL VALUES (1, 10.1);
  14. INSERT INTO CASE_TBL VALUES (2, 20.2);
  15. INSERT INTO CASE_TBL VALUES (3, -30.3);
  16. INSERT INTO CASE_TBL VALUES (4, NULL);
  17. INSERT INTO CASE2_TBL VALUES (1, -1);
  18. INSERT INTO CASE2_TBL VALUES (2, -2);
  19. INSERT INTO CASE2_TBL VALUES (3, -3);
  20. INSERT INTO CASE2_TBL VALUES (2, -4);
  21. INSERT INTO CASE2_TBL VALUES (1, NULL);
  22. INSERT INTO CASE2_TBL VALUES (NULL, -6);
  23. --
  24. -- Simplest examples without tables
  25. --
  26. SELECT '3' AS "One",
  27. CASE
  28. WHEN 1 < 2 THEN 3
  29. END AS "Simple WHEN";
  30. SELECT '<NULL>' AS "One",
  31. CASE
  32. WHEN 1 > 2 THEN 3
  33. END AS "Simple default";
  34. SELECT '3' AS "One",
  35. CASE
  36. WHEN 1 < 2 THEN 3
  37. ELSE 4
  38. END AS "Simple ELSE";
  39. SELECT '4' AS "One",
  40. CASE
  41. WHEN 1 > 2 THEN 3
  42. ELSE 4
  43. END AS "ELSE default";
  44. SELECT '6' AS "One",
  45. CASE
  46. WHEN 1 > 2 THEN 3
  47. WHEN 4 < 5 THEN 6
  48. ELSE 7
  49. END AS "Two WHEN with default";
  50. SELECT '7' AS "None",
  51. CASE WHEN random() < 0 THEN 1
  52. END AS "NULL on no matches";
  53. -- Constant-expression folding shouldn't evaluate unreachable subexpressions
  54. SELECT CASE WHEN 1=0 THEN 1/0 WHEN 1=1 THEN 1 ELSE 2/0 END;
  55. SELECT CASE 1 WHEN 0 THEN 1/0 WHEN 1 THEN 1 ELSE 2/0 END;
  56. -- However we do not currently suppress folding of potentially
  57. -- reachable subexpressions
  58. SELECT CASE WHEN i > 100 THEN 1/0 ELSE 0 END FROM case_tbl;
  59. -- Test for cases involving untyped literals in test expression
  60. SELECT CASE 'a' WHEN 'a' THEN 1 ELSE 2 END;
  61. --
  62. -- Examples of targets involving tables
  63. --
  64. SELECT
  65. CASE
  66. WHEN i >= 3 THEN i
  67. END AS ">= 3 or Null"
  68. FROM CASE_TBL;
  69. SELECT
  70. CASE WHEN i >= 3 THEN (i + i)
  71. ELSE i
  72. END AS "Simplest Math"
  73. FROM CASE_TBL;
  74. SELECT i AS "Value",
  75. CASE WHEN (i < 0) THEN 'small'
  76. WHEN (i = 0) THEN 'zero'
  77. WHEN (i = 1) THEN 'one'
  78. WHEN (i = 2) THEN 'two'
  79. ELSE 'big'
  80. END AS "Category"
  81. FROM CASE_TBL;
  82. SELECT
  83. CASE WHEN ((i < 0) or (i < 0)) THEN 'small'
  84. WHEN ((i = 0) or (i = 0)) THEN 'zero'
  85. WHEN ((i = 1) or (i = 1)) THEN 'one'
  86. WHEN ((i = 2) or (i = 2)) THEN 'two'
  87. ELSE 'big'
  88. END AS "Category"
  89. FROM CASE_TBL;
  90. --
  91. -- Examples of qualifications involving tables
  92. --
  93. --
  94. -- NULLIF() and COALESCE()
  95. -- Shorthand forms for typical CASE constructs
  96. -- defined in the SQL standard.
  97. --
  98. SELECT * FROM CASE_TBL WHERE COALESCE(f,i) = 4;
  99. SELECT * FROM CASE_TBL WHERE NULLIF(f,i) = 2;
  100. SELECT COALESCE(a.f, b.i, b.j)
  101. FROM CASE_TBL a, CASE2_TBL b;
  102. SELECT *
  103. FROM CASE_TBL a, CASE2_TBL b
  104. WHERE COALESCE(a.f, b.i, b.j) = 2;
  105. SELECT NULLIF(a.i,b.i) AS "NULLIF(a.i,b.i)",
  106. NULLIF(b.i, 4) AS "NULLIF(b.i,4)"
  107. FROM CASE_TBL a, CASE2_TBL b;
  108. SELECT *
  109. FROM CASE_TBL a, CASE2_TBL b
  110. WHERE COALESCE(f,b.i) = 2;
  111. -- Tests for constant subexpression simplification
  112. explain (costs off)
  113. SELECT * FROM CASE_TBL WHERE NULLIF(1, 2) = 2;
  114. explain (costs off)
  115. SELECT * FROM CASE_TBL WHERE NULLIF(1, 1) IS NOT NULL;
  116. explain (costs off)
  117. SELECT * FROM CASE_TBL WHERE NULLIF(1, null) = 2;
  118. --
  119. -- Examples of updates involving tables
  120. --
  121. UPDATE CASE_TBL
  122. SET i = CASE WHEN i >= 3 THEN (- i)
  123. ELSE (2 * i) END;
  124. SELECT * FROM CASE_TBL;
  125. UPDATE CASE_TBL
  126. SET i = CASE WHEN i >= 2 THEN (2 * i)
  127. ELSE (3 * i) END;
  128. SELECT * FROM CASE_TBL;
  129. UPDATE CASE_TBL
  130. SET i = CASE WHEN b.i >= 2 THEN (2 * j)
  131. ELSE (3 * j) END
  132. FROM CASE2_TBL b
  133. WHERE j = -CASE_TBL.i;
  134. SELECT * FROM CASE_TBL;
  135. --
  136. -- Nested CASE expressions
  137. --
  138. -- This test exercises a bug caused by aliasing econtext->caseValue_isNull
  139. -- with the isNull argument of the inner CASE's CaseExpr evaluation. After
  140. -- evaluating the vol(null) expression in the inner CASE's second WHEN-clause,
  141. -- the isNull flag for the case test value incorrectly became true, causing
  142. -- the third WHEN-clause not to match. The volatile function calls are needed
  143. -- to prevent constant-folding in the planner, which would hide the bug.
  144. -- Wrap this in a single transaction so the transient '=' operator doesn't
  145. -- cause problems in concurrent sessions
  146. BEGIN;
  147. CREATE FUNCTION vol(text) returns text as
  148. 'begin return $1; end' language plpgsql volatile;
  149. SELECT CASE
  150. (CASE vol('bar')
  151. WHEN 'foo' THEN 'it was foo!'
  152. WHEN vol(null) THEN 'null input'
  153. WHEN 'bar' THEN 'it was bar!' END
  154. )
  155. WHEN 'it was foo!' THEN 'foo recognized'
  156. WHEN 'it was bar!' THEN 'bar recognized'
  157. ELSE 'unrecognized' END;
  158. -- In this case, we can't inline the SQL function without confusing things.
  159. CREATE DOMAIN foodomain AS text;
  160. CREATE FUNCTION volfoo(text) returns foodomain as
  161. 'begin return $1::foodomain; end' language plpgsql volatile;
  162. CREATE FUNCTION inline_eq(foodomain, foodomain) returns boolean as
  163. 'SELECT CASE $2::text WHEN $1::text THEN true ELSE false END' language sql;
  164. CREATE OPERATOR = (procedure = inline_eq,
  165. leftarg = foodomain, rightarg = foodomain);
  166. SELECT CASE volfoo('bar') WHEN 'foo'::foodomain THEN 'is foo' ELSE 'is not foo' END;
  167. ROLLBACK;
  168. -- Test multiple evaluation of a CASE arg that is a read/write object (#14472)
  169. -- Wrap this in a single transaction so the transient '=' operator doesn't
  170. -- cause problems in concurrent sessions
  171. BEGIN;
  172. CREATE DOMAIN arrdomain AS int[];
  173. CREATE FUNCTION make_ad(int,int) returns arrdomain as
  174. 'declare x arrdomain;
  175. begin
  176. x := array[$1,$2];
  177. return x;
  178. end' language plpgsql volatile;
  179. CREATE FUNCTION ad_eq(arrdomain, arrdomain) returns boolean as
  180. 'begin return array_eq($1, $2); end' language plpgsql;
  181. CREATE OPERATOR = (procedure = ad_eq,
  182. leftarg = arrdomain, rightarg = arrdomain);
  183. SELECT CASE make_ad(1,2)
  184. WHEN array[2,4]::arrdomain THEN 'wrong'
  185. WHEN array[2,5]::arrdomain THEN 'still wrong'
  186. WHEN array[1,2]::arrdomain THEN 'right'
  187. END;
  188. ROLLBACK;
  189. -- Test interaction of CASE with ArrayCoerceExpr (bug #15471)
  190. BEGIN;
  191. CREATE TYPE casetestenum AS ENUM ('e', 'f', 'g');
  192. SELECT
  193. CASE 'foo'::text
  194. WHEN 'foo' THEN ARRAY['a', 'b', 'c', 'd'] || enum_range(NULL::casetestenum)::text[]
  195. ELSE ARRAY['x', 'y']
  196. END;
  197. ROLLBACK;
  198. --
  199. -- Clean up
  200. --
  201. DROP TABLE CASE_TBL;
  202. DROP TABLE CASE2_TBL;