1-- 2-- Cursor regression tests 3-- 4 5BEGIN; 6 7DECLARE foo1 SCROLL CURSOR FOR SELECT * FROM tenk1 ORDER BY unique2; 8 9DECLARE foo2 SCROLL CURSOR FOR SELECT * FROM tenk2; 10 11DECLARE foo3 SCROLL CURSOR FOR SELECT * FROM tenk1 ORDER BY unique2; 12 13DECLARE foo4 SCROLL CURSOR FOR SELECT * FROM tenk2; 14 15DECLARE foo5 SCROLL CURSOR FOR SELECT * FROM tenk1 ORDER BY unique2; 16 17DECLARE foo6 SCROLL CURSOR FOR SELECT * FROM tenk2; 18 19DECLARE foo7 SCROLL CURSOR FOR SELECT * FROM tenk1 ORDER BY unique2; 20 21DECLARE foo8 SCROLL CURSOR FOR SELECT * FROM tenk2; 22 23DECLARE foo9 SCROLL CURSOR FOR SELECT * FROM tenk1 ORDER BY unique2; 24 25DECLARE foo10 SCROLL CURSOR FOR SELECT * FROM tenk2; 26 27DECLARE foo11 SCROLL CURSOR FOR SELECT * FROM tenk1 ORDER BY unique2; 28 29DECLARE foo12 SCROLL CURSOR FOR SELECT * FROM tenk2; 30 31DECLARE foo13 SCROLL CURSOR FOR SELECT * FROM tenk1 ORDER BY unique2; 32 33DECLARE foo14 SCROLL CURSOR FOR SELECT * FROM tenk2; 34 35DECLARE foo15 SCROLL CURSOR FOR SELECT * FROM tenk1 ORDER BY unique2; 36 37DECLARE foo16 SCROLL CURSOR FOR SELECT * FROM tenk2; 38 39DECLARE foo17 SCROLL CURSOR FOR SELECT * FROM tenk1 ORDER BY unique2; 40 41DECLARE foo18 SCROLL CURSOR FOR SELECT * FROM tenk2; 42 43DECLARE foo19 SCROLL CURSOR FOR SELECT * FROM tenk1 ORDER BY unique2; 44 45DECLARE foo20 SCROLL CURSOR FOR SELECT * FROM tenk2; 46 47DECLARE foo21 SCROLL CURSOR FOR SELECT * FROM tenk1 ORDER BY unique2; 48 49DECLARE foo22 SCROLL CURSOR FOR SELECT * FROM tenk2; 50 51DECLARE foo23 SCROLL CURSOR FOR SELECT * FROM tenk1 ORDER BY unique2; 52 53FETCH 1 in foo1; 54 55FETCH 2 in foo2; 56 57FETCH 3 in foo3; 58 59FETCH 4 in foo4; 60 61FETCH 5 in foo5; 62 63FETCH 6 in foo6; 64 65FETCH 7 in foo7; 66 67FETCH 8 in foo8; 68 69FETCH 9 in foo9; 70 71FETCH 10 in foo10; 72 73FETCH 11 in foo11; 74 75FETCH 12 in foo12; 76 77FETCH 13 in foo13; 78 79FETCH 14 in foo14; 80 81FETCH 15 in foo15; 82 83FETCH 16 in foo16; 84 85FETCH 17 in foo17; 86 87FETCH 18 in foo18; 88 89FETCH 19 in foo19; 90 91FETCH 20 in foo20; 92 93FETCH 21 in foo21; 94 95FETCH 22 in foo22; 96 97FETCH 23 in foo23; 98 99FETCH backward 1 in foo23; 100 101FETCH backward 2 in foo22; 102 103FETCH backward 3 in foo21; 104 105FETCH backward 4 in foo20; 106 107FETCH backward 5 in foo19; 108 109FETCH backward 6 in foo18; 110 111FETCH backward 7 in foo17; 112 113FETCH backward 8 in foo16; 114 115FETCH backward 9 in foo15; 116 117FETCH backward 10 in foo14; 118 119FETCH backward 11 in foo13; 120 121FETCH backward 12 in foo12; 122 123FETCH backward 13 in foo11; 124 125FETCH backward 14 in foo10; 126 127FETCH backward 15 in foo9; 128 129FETCH backward 16 in foo8; 130 131FETCH backward 17 in foo7; 132 133FETCH backward 18 in foo6; 134 135FETCH backward 19 in foo5; 136 137FETCH backward 20 in foo4; 138 139FETCH backward 21 in foo3; 140 141FETCH backward 22 in foo2; 142 143FETCH backward 23 in foo1; 144 145CLOSE foo1; 146 147CLOSE foo2; 148 149CLOSE foo3; 150 151CLOSE foo4; 152 153CLOSE foo5; 154 155CLOSE foo6; 156 157CLOSE foo7; 158 159CLOSE foo8; 160 161CLOSE foo9; 162 163CLOSE foo10; 164 165CLOSE foo11; 166 167CLOSE foo12; 168 169-- leave some cursors open, to test that auto-close works. 170 171-- record this in the system view as well (don't query the time field there 172-- however) 173SELECT name, statement, is_holdable, is_binary, is_scrollable FROM pg_cursors ORDER BY 1; 174 175END; 176 177SELECT name, statement, is_holdable, is_binary, is_scrollable FROM pg_cursors; 178 179-- 180-- NO SCROLL disallows backward fetching 181-- 182 183BEGIN; 184 185DECLARE foo24 NO SCROLL CURSOR FOR SELECT * FROM tenk1 ORDER BY unique2; 186 187FETCH 1 FROM foo24; 188 189FETCH BACKWARD 1 FROM foo24; -- should fail 190 191END; 192 193-- 194-- Cursors outside transaction blocks 195-- 196 197 198SELECT name, statement, is_holdable, is_binary, is_scrollable FROM pg_cursors; 199 200BEGIN; 201 202DECLARE foo25 SCROLL CURSOR WITH HOLD FOR SELECT * FROM tenk2; 203 204FETCH FROM foo25; 205 206FETCH FROM foo25; 207 208COMMIT; 209 210FETCH FROM foo25; 211 212FETCH BACKWARD FROM foo25; 213 214FETCH ABSOLUTE -1 FROM foo25; 215 216SELECT name, statement, is_holdable, is_binary, is_scrollable FROM pg_cursors; 217 218CLOSE foo25; 219 220-- 221-- ROLLBACK should close holdable cursors 222-- 223 224BEGIN; 225 226DECLARE foo26 CURSOR WITH HOLD FOR SELECT * FROM tenk1 ORDER BY unique2; 227 228ROLLBACK; 229 230-- should fail 231FETCH FROM foo26; 232 233-- 234-- Parameterized DECLARE needs to insert param values into the cursor portal 235-- 236 237BEGIN; 238 239CREATE FUNCTION declares_cursor(text) 240 RETURNS void 241 AS 'DECLARE c CURSOR FOR SELECT stringu1 FROM tenk1 WHERE stringu1 LIKE $1;' 242 LANGUAGE SQL; 243 244SELECT declares_cursor('AB%'); 245 246FETCH ALL FROM c; 247 248ROLLBACK; 249 250-- 251-- Test behavior of both volatile and stable functions inside a cursor; 252-- in particular we want to see what happens during commit of a holdable 253-- cursor 254-- 255 256create temp table tt1(f1 int); 257 258create function count_tt1_v() returns int8 as 259'select count(*) from tt1' language sql volatile; 260 261create function count_tt1_s() returns int8 as 262'select count(*) from tt1' language sql stable; 263 264begin; 265 266insert into tt1 values(1); 267 268declare c1 cursor for select count_tt1_v(), count_tt1_s(); 269 270insert into tt1 values(2); 271 272fetch all from c1; 273 274rollback; 275 276begin; 277 278insert into tt1 values(1); 279 280declare c2 cursor with hold for select count_tt1_v(), count_tt1_s(); 281 282insert into tt1 values(2); 283 284commit; 285 286delete from tt1; 287 288fetch all from c2; 289 290drop function count_tt1_v(); 291drop function count_tt1_s(); 292 293 294-- Create a cursor with the BINARY option and check the pg_cursors view 295BEGIN; 296SELECT name, statement, is_holdable, is_binary, is_scrollable FROM pg_cursors; 297DECLARE bc BINARY CURSOR FOR SELECT * FROM tenk1; 298SELECT name, statement, is_holdable, is_binary, is_scrollable FROM pg_cursors ORDER BY 1; 299ROLLBACK; 300 301-- We should not see the portal that is created internally to 302-- implement EXECUTE in pg_cursors 303PREPARE cprep AS 304 SELECT name, statement, is_holdable, is_binary, is_scrollable FROM pg_cursors; 305EXECUTE cprep; 306 307-- test CLOSE ALL; 308SELECT name FROM pg_cursors ORDER BY 1; 309CLOSE ALL; 310SELECT name FROM pg_cursors ORDER BY 1; 311BEGIN; 312DECLARE foo1 CURSOR WITH HOLD FOR SELECT 1; 313DECLARE foo2 CURSOR WITHOUT HOLD FOR SELECT 1; 314SELECT name FROM pg_cursors ORDER BY 1; 315CLOSE ALL; 316SELECT name FROM pg_cursors ORDER BY 1; 317COMMIT; 318 319-- 320-- Tests for updatable cursors 321-- 322 323CREATE TEMP TABLE uctest(f1 int, f2 text); 324INSERT INTO uctest VALUES (1, 'one'), (2, 'two'), (3, 'three'); 325SELECT * FROM uctest; 326 327-- Check DELETE WHERE CURRENT 328BEGIN; 329DECLARE c1 CURSOR FOR SELECT * FROM uctest; 330FETCH 2 FROM c1; 331DELETE FROM uctest WHERE CURRENT OF c1; 332-- should show deletion 333SELECT * FROM uctest; 334-- cursor did not move 335FETCH ALL FROM c1; 336-- cursor is insensitive 337MOVE BACKWARD ALL IN c1; 338FETCH ALL FROM c1; 339COMMIT; 340-- should still see deletion 341SELECT * FROM uctest; 342 343-- Check UPDATE WHERE CURRENT; this time use FOR UPDATE 344BEGIN; 345DECLARE c1 CURSOR FOR SELECT * FROM uctest FOR UPDATE; 346FETCH c1; 347UPDATE uctest SET f1 = 8 WHERE CURRENT OF c1; 348SELECT * FROM uctest; 349COMMIT; 350SELECT * FROM uctest; 351 352-- Check repeated-update and update-then-delete cases 353BEGIN; 354DECLARE c1 CURSOR FOR SELECT * FROM uctest; 355FETCH c1; 356UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1; 357SELECT * FROM uctest; 358UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1; 359SELECT * FROM uctest; 360-- insensitive cursor should not show effects of updates or deletes 361FETCH RELATIVE 0 FROM c1; 362DELETE FROM uctest WHERE CURRENT OF c1; 363SELECT * FROM uctest; 364DELETE FROM uctest WHERE CURRENT OF c1; -- no-op 365SELECT * FROM uctest; 366UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1; -- no-op 367SELECT * FROM uctest; 368FETCH RELATIVE 0 FROM c1; 369ROLLBACK; 370SELECT * FROM uctest; 371 372BEGIN; 373DECLARE c1 CURSOR FOR SELECT * FROM uctest FOR UPDATE; 374FETCH c1; 375UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1; 376SELECT * FROM uctest; 377UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1; 378SELECT * FROM uctest; 379DELETE FROM uctest WHERE CURRENT OF c1; 380SELECT * FROM uctest; 381DELETE FROM uctest WHERE CURRENT OF c1; -- no-op 382SELECT * FROM uctest; 383UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1; -- no-op 384SELECT * FROM uctest; 385--- sensitive cursors can't currently scroll back, so this is an error: 386FETCH RELATIVE 0 FROM c1; 387ROLLBACK; 388SELECT * FROM uctest; 389 390-- Check inheritance cases 391CREATE TEMP TABLE ucchild () inherits (uctest); 392INSERT INTO ucchild values(100, 'hundred'); 393SELECT * FROM uctest; 394 395BEGIN; 396DECLARE c1 CURSOR FOR SELECT * FROM uctest FOR UPDATE; 397FETCH 1 FROM c1; 398UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1; 399FETCH 1 FROM c1; 400UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1; 401FETCH 1 FROM c1; 402UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1; 403FETCH 1 FROM c1; 404COMMIT; 405SELECT * FROM uctest; 406 407-- Can update from a self-join, but only if FOR UPDATE says which to use 408BEGIN; 409DECLARE c1 CURSOR FOR SELECT * FROM uctest a, uctest b WHERE a.f1 = b.f1 + 5; 410FETCH 1 FROM c1; 411UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1; -- fail 412ROLLBACK; 413BEGIN; 414DECLARE c1 CURSOR FOR SELECT * FROM uctest a, uctest b WHERE a.f1 = b.f1 + 5 FOR UPDATE; 415FETCH 1 FROM c1; 416UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1; -- fail 417ROLLBACK; 418BEGIN; 419DECLARE c1 CURSOR FOR SELECT * FROM uctest a, uctest b WHERE a.f1 = b.f1 + 5 FOR SHARE OF a; 420FETCH 1 FROM c1; 421UPDATE uctest SET f1 = f1 + 10 WHERE CURRENT OF c1; 422SELECT * FROM uctest; 423ROLLBACK; 424 425-- Check various error cases 426 427DELETE FROM uctest WHERE CURRENT OF c1; -- fail, no such cursor 428DECLARE cx CURSOR WITH HOLD FOR SELECT * FROM uctest; 429DELETE FROM uctest WHERE CURRENT OF cx; -- fail, can't use held cursor 430BEGIN; 431DECLARE c CURSOR FOR SELECT * FROM tenk2; 432DELETE FROM uctest WHERE CURRENT OF c; -- fail, cursor on wrong table 433ROLLBACK; 434BEGIN; 435DECLARE c CURSOR FOR SELECT * FROM tenk2 FOR SHARE; 436DELETE FROM uctest WHERE CURRENT OF c; -- fail, cursor on wrong table 437ROLLBACK; 438BEGIN; 439DECLARE c CURSOR FOR SELECT * FROM tenk1 JOIN tenk2 USING (unique1); 440DELETE FROM tenk1 WHERE CURRENT OF c; -- fail, cursor is on a join 441ROLLBACK; 442BEGIN; 443DECLARE c CURSOR FOR SELECT f1,count(*) FROM uctest GROUP BY f1; 444DELETE FROM uctest WHERE CURRENT OF c; -- fail, cursor is on aggregation 445ROLLBACK; 446BEGIN; 447DECLARE c1 CURSOR FOR SELECT * FROM uctest; 448DELETE FROM uctest WHERE CURRENT OF c1; -- fail, no current row 449ROLLBACK; 450BEGIN; 451DECLARE c1 CURSOR FOR SELECT MIN(f1) FROM uctest FOR UPDATE; 452ROLLBACK; 453 454-- WHERE CURRENT OF may someday work with views, but today is not that day. 455-- For now, just make sure it errors out cleanly. 456CREATE TEMP VIEW ucview AS SELECT * FROM uctest; 457CREATE RULE ucrule AS ON DELETE TO ucview DO INSTEAD 458 DELETE FROM uctest WHERE f1 = OLD.f1; 459BEGIN; 460DECLARE c1 CURSOR FOR SELECT * FROM ucview; 461FETCH FROM c1; 462DELETE FROM ucview WHERE CURRENT OF c1; -- fail, views not supported 463ROLLBACK; 464 465-- Check WHERE CURRENT OF with an index-only scan 466BEGIN; 467EXPLAIN (costs off) 468DECLARE c1 CURSOR FOR SELECT stringu1 FROM onek WHERE stringu1 = 'DZAAAA'; 469DECLARE c1 CURSOR FOR SELECT stringu1 FROM onek WHERE stringu1 = 'DZAAAA'; 470FETCH FROM c1; 471DELETE FROM onek WHERE CURRENT OF c1; 472SELECT stringu1 FROM onek WHERE stringu1 = 'DZAAAA'; 473ROLLBACK; 474 475-- Check behavior with rewinding to a previous child scan node, 476-- as per bug #15395 477BEGIN; 478CREATE TABLE current_check (currentid int, payload text); 479CREATE TABLE current_check_1 () INHERITS (current_check); 480CREATE TABLE current_check_2 () INHERITS (current_check); 481INSERT INTO current_check_1 SELECT i, 'p' || i FROM generate_series(1,9) i; 482INSERT INTO current_check_2 SELECT i, 'P' || i FROM generate_series(10,19) i; 483 484DECLARE c1 SCROLL CURSOR FOR SELECT * FROM current_check; 485 486-- This tests the fetch-backwards code path 487FETCH ABSOLUTE 12 FROM c1; 488FETCH ABSOLUTE 8 FROM c1; 489DELETE FROM current_check WHERE CURRENT OF c1 RETURNING *; 490 491-- This tests the ExecutorRewind code path 492FETCH ABSOLUTE 13 FROM c1; 493FETCH ABSOLUTE 1 FROM c1; 494DELETE FROM current_check WHERE CURRENT OF c1 RETURNING *; 495 496SELECT * FROM current_check; 497ROLLBACK; 498 499-- Make sure snapshot management works okay, per bug report in 500-- 235395b90909301035v7228ce63q392931f15aa74b31@mail.gmail.com 501BEGIN; 502SET TRANSACTION ISOLATION LEVEL SERIALIZABLE; 503CREATE TABLE cursor (a int); 504INSERT INTO cursor VALUES (1); 505DECLARE c1 NO SCROLL CURSOR FOR SELECT * FROM cursor FOR UPDATE; 506UPDATE cursor SET a = 2; 507FETCH ALL FROM c1; 508COMMIT; 509DROP TABLE cursor; 510 511-- Check rewinding a cursor containing a stable function in LIMIT, 512-- per bug report in 8336843.9833.1399385291498.JavaMail.root@quick 513begin; 514create function nochange(int) returns int 515 as 'select $1 limit 1' language sql stable; 516declare c cursor for select * from int8_tbl limit nochange(3); 517fetch all from c; 518move backward all in c; 519fetch all from c; 520rollback; 521 522-- Check handling of non-backwards-scan-capable plans with scroll cursors 523begin; 524explain (costs off) declare c1 cursor for select (select 42) as x; 525explain (costs off) declare c1 scroll cursor for select (select 42) as x; 526declare c1 scroll cursor for select (select 42) as x; 527fetch all in c1; 528fetch backward all in c1; 529rollback; 530begin; 531explain (costs off) declare c2 cursor for select generate_series(1,3) as g; 532explain (costs off) declare c2 scroll cursor for select generate_series(1,3) as g; 533declare c2 scroll cursor for select generate_series(1,3) as g; 534fetch all in c2; 535fetch backward all in c2; 536rollback; 537