1CREATE EXTENSION dblink; 2 3-- want context for notices 4\set SHOW_CONTEXT always 5 6CREATE TABLE foo(f1 int, f2 text, f3 text[], primary key (f1,f2)); 7INSERT INTO foo VALUES (0,'a','{"a0","b0","c0"}'); 8INSERT INTO foo VALUES (1,'b','{"a1","b1","c1"}'); 9INSERT INTO foo VALUES (2,'c','{"a2","b2","c2"}'); 10INSERT INTO foo VALUES (3,'d','{"a3","b3","c3"}'); 11INSERT INTO foo VALUES (4,'e','{"a4","b4","c4"}'); 12INSERT INTO foo VALUES (5,'f','{"a5","b5","c5"}'); 13INSERT INTO foo VALUES (6,'g','{"a6","b6","c6"}'); 14INSERT INTO foo VALUES (7,'h','{"a7","b7","c7"}'); 15INSERT INTO foo VALUES (8,'i','{"a8","b8","c8"}'); 16INSERT INTO foo VALUES (9,'j','{"a9","b9","c9"}'); 17 18-- misc utilities 19 20-- list the primary key fields 21SELECT * 22FROM dblink_get_pkey('foo'); 23 24-- build an insert statement based on a local tuple, 25-- replacing the primary key values with new ones 26SELECT dblink_build_sql_insert('foo','1 2',2,'{"0", "a"}','{"99", "xyz"}'); 27-- too many pk fields, should fail 28SELECT dblink_build_sql_insert('foo','1 2 3 4',4,'{"0", "a", "{a0,b0,c0}"}','{"99", "xyz", "{za0,zb0,zc0}"}'); 29 30-- build an update statement based on a local tuple, 31-- replacing the primary key values with new ones 32SELECT dblink_build_sql_update('foo','1 2',2,'{"0", "a"}','{"99", "xyz"}'); 33-- too many pk fields, should fail 34SELECT dblink_build_sql_update('foo','1 2 3 4',4,'{"0", "a", "{a0,b0,c0}"}','{"99", "xyz", "{za0,zb0,zc0}"}'); 35 36-- build a delete statement based on a local tuple, 37SELECT dblink_build_sql_delete('foo','1 2',2,'{"0", "a"}'); 38-- too many pk fields, should fail 39SELECT dblink_build_sql_delete('foo','1 2 3 4',4,'{"0", "a", "{a0,b0,c0}"}'); 40 41-- retest using a quoted and schema qualified table 42CREATE SCHEMA "MySchema"; 43CREATE TABLE "MySchema"."Foo"(f1 int, f2 text, f3 text[], primary key (f1,f2)); 44INSERT INTO "MySchema"."Foo" VALUES (0,'a','{"a0","b0","c0"}'); 45 46-- list the primary key fields 47SELECT * 48FROM dblink_get_pkey('"MySchema"."Foo"'); 49 50-- build an insert statement based on a local tuple, 51-- replacing the primary key values with new ones 52SELECT dblink_build_sql_insert('"MySchema"."Foo"','1 2',2,'{"0", "a"}','{"99", "xyz"}'); 53 54-- build an update statement based on a local tuple, 55-- replacing the primary key values with new ones 56SELECT dblink_build_sql_update('"MySchema"."Foo"','1 2',2,'{"0", "a"}','{"99", "xyz"}'); 57 58-- build a delete statement based on a local tuple, 59SELECT dblink_build_sql_delete('"MySchema"."Foo"','1 2',2,'{"0", "a"}'); 60 61CREATE FUNCTION connection_parameters() RETURNS text LANGUAGE SQL AS $f$ 62 SELECT $$dbname='$$||current_database()||$$' port=$$||current_setting('port'); 63$f$; 64 65-- regular old dblink 66SELECT * 67FROM dblink(connection_parameters(),'SELECT * FROM foo') AS t(a int, b text, c text[]) 68WHERE t.a > 7; 69 70-- should generate "connection not available" error 71SELECT * 72FROM dblink('SELECT * FROM foo') AS t(a int, b text, c text[]) 73WHERE t.a > 7; 74 75-- The first-level connection's backend will crash on exit given OpenLDAP 76-- [2.4.24, 2.4.31]. We won't see evidence of any crash until the victim 77-- process terminates and the postmaster responds. If process termination 78-- entails writing a core dump, that can take awhile. Wait for the process to 79-- vanish. At that point, the postmaster has called waitpid() on the crashed 80-- process, and it will accept no new connections until it has reinitialized 81-- the cluster. (We can't exploit pg_stat_activity, because the crash happens 82-- after the backend updates shared memory to reflect its impending exit.) 83DO $pl$ 84DECLARE 85 detail text; 86BEGIN 87 PERFORM wait_pid(crash_pid) 88 FROM dblink(connection_parameters(), $$ 89 SELECT pg_backend_pid() FROM dblink( 90 'service=test_ldap '||connection_parameters(), 91 -- This string concatenation is a hack to shoehorn a 92 -- set_pgservicefile call into the SQL statement. 93 'SELECT 1' || set_pgservicefile('pg_service.conf') 94 ) t(c int) 95 $$) AS t(crash_pid int); 96EXCEPTION WHEN OTHERS THEN 97 GET STACKED DIAGNOSTICS detail = PG_EXCEPTION_DETAIL; 98 -- Expected error in a non-LDAP build. 99 IF NOT detail LIKE 'syntax error in service file%' THEN RAISE; END IF; 100END 101$pl$; 102 103-- create a persistent connection 104SELECT dblink_connect(connection_parameters()); 105 106-- use the persistent connection 107SELECT * 108FROM dblink('SELECT * FROM foo') AS t(a int, b text, c text[]) 109WHERE t.a > 7; 110 111-- open a cursor with bad SQL and fail_on_error set to false 112SELECT dblink_open('rmt_foo_cursor','SELECT * FROM foobar',false); 113 114-- reset remote transaction state 115SELECT dblink_exec('ABORT'); 116 117-- open a cursor 118SELECT dblink_open('rmt_foo_cursor','SELECT * FROM foo'); 119 120-- close the cursor 121SELECT dblink_close('rmt_foo_cursor',false); 122 123-- open the cursor again 124SELECT dblink_open('rmt_foo_cursor','SELECT * FROM foo'); 125 126-- fetch some data 127SELECT * 128FROM dblink_fetch('rmt_foo_cursor',4) AS t(a int, b text, c text[]); 129 130SELECT * 131FROM dblink_fetch('rmt_foo_cursor',4) AS t(a int, b text, c text[]); 132 133-- this one only finds two rows left 134SELECT * 135FROM dblink_fetch('rmt_foo_cursor',4) AS t(a int, b text, c text[]); 136 137-- intentionally botch a fetch 138SELECT * 139FROM dblink_fetch('rmt_foobar_cursor',4,false) AS t(a int, b text, c text[]); 140 141-- reset remote transaction state 142SELECT dblink_exec('ABORT'); 143 144-- close the wrong cursor 145SELECT dblink_close('rmt_foobar_cursor',false); 146 147-- should generate 'cursor "rmt_foo_cursor" not found' error 148SELECT * 149FROM dblink_fetch('rmt_foo_cursor',4) AS t(a int, b text, c text[]); 150 151-- this time, 'cursor "rmt_foo_cursor" not found' as a notice 152SELECT * 153FROM dblink_fetch('rmt_foo_cursor',4,false) AS t(a int, b text, c text[]); 154 155-- close the persistent connection 156SELECT dblink_disconnect(); 157 158-- should generate "connection not available" error 159SELECT * 160FROM dblink('SELECT * FROM foo') AS t(a int, b text, c text[]) 161WHERE t.a > 7; 162 163-- put more data into our slave table, first using arbitrary connection syntax 164-- but truncate the actual return value so we can use diff to check for success 165SELECT substr(dblink_exec(connection_parameters(),'INSERT INTO foo VALUES(10,''k'',''{"a10","b10","c10"}'')'),1,6); 166 167-- create a persistent connection 168SELECT dblink_connect(connection_parameters()); 169 170-- put more data into our slave table, using persistent connection syntax 171-- but truncate the actual return value so we can use diff to check for success 172SELECT substr(dblink_exec('INSERT INTO foo VALUES(11,''l'',''{"a11","b11","c11"}'')'),1,6); 173 174-- let's see it 175SELECT * 176FROM dblink('SELECT * FROM foo') AS t(a int, b text, c text[]); 177 178-- bad remote select 179SELECT * 180FROM dblink('SELECT * FROM foobar',false) AS t(a int, b text, c text[]); 181 182-- change some data 183SELECT dblink_exec('UPDATE foo SET f3[2] = ''b99'' WHERE f1 = 11'); 184 185-- let's see it 186SELECT * 187FROM dblink('SELECT * FROM foo') AS t(a int, b text, c text[]) 188WHERE a = 11; 189 190-- botch a change to some other data 191SELECT dblink_exec('UPDATE foobar SET f3[2] = ''b99'' WHERE f1 = 11',false); 192 193-- delete some data 194SELECT dblink_exec('DELETE FROM foo WHERE f1 = 11'); 195 196-- let's see it 197SELECT * 198FROM dblink('SELECT * FROM foo') AS t(a int, b text, c text[]) 199WHERE a = 11; 200 201-- close the persistent connection 202SELECT dblink_disconnect(); 203 204-- 205-- tests for the new named persistent connection syntax 206-- 207 208-- should generate "missing "=" after "myconn" in connection info string" error 209SELECT * 210FROM dblink('myconn','SELECT * FROM foo') AS t(a int, b text, c text[]) 211WHERE t.a > 7; 212 213-- create a named persistent connection 214SELECT dblink_connect('myconn',connection_parameters()); 215 216-- use the named persistent connection 217SELECT * 218FROM dblink('myconn','SELECT * FROM foo') AS t(a int, b text, c text[]) 219WHERE t.a > 7; 220 221-- use the named persistent connection, but get it wrong 222SELECT * 223FROM dblink('myconn','SELECT * FROM foobar',false) AS t(a int, b text, c text[]) 224WHERE t.a > 7; 225 226-- create a second named persistent connection 227-- should error with "duplicate connection name" 228SELECT dblink_connect('myconn',connection_parameters()); 229 230-- create a second named persistent connection with a new name 231SELECT dblink_connect('myconn2',connection_parameters()); 232 233-- use the second named persistent connection 234SELECT * 235FROM dblink('myconn2','SELECT * FROM foo') AS t(a int, b text, c text[]) 236WHERE t.a > 7; 237 238-- close the second named persistent connection 239SELECT dblink_disconnect('myconn2'); 240 241-- open a cursor incorrectly 242SELECT dblink_open('myconn','rmt_foo_cursor','SELECT * FROM foobar',false); 243 244-- reset remote transaction state 245SELECT dblink_exec('myconn','ABORT'); 246 247-- test opening cursor in a transaction 248SELECT dblink_exec('myconn','BEGIN'); 249 250-- an open transaction will prevent dblink_open() from opening its own 251SELECT dblink_open('myconn','rmt_foo_cursor','SELECT * FROM foo'); 252 253-- this should not commit the transaction because the client opened it 254SELECT dblink_close('myconn','rmt_foo_cursor'); 255 256-- this should succeed because we have an open transaction 257SELECT dblink_exec('myconn','DECLARE xact_test CURSOR FOR SELECT * FROM foo'); 258 259-- commit remote transaction 260SELECT dblink_exec('myconn','COMMIT'); 261 262-- test automatic transactions for multiple cursor opens 263SELECT dblink_open('myconn','rmt_foo_cursor','SELECT * FROM foo'); 264 265-- the second cursor 266SELECT dblink_open('myconn','rmt_foo_cursor2','SELECT * FROM foo'); 267 268-- this should not commit the transaction 269SELECT dblink_close('myconn','rmt_foo_cursor2'); 270 271-- this should succeed because we have an open transaction 272SELECT dblink_exec('myconn','DECLARE xact_test CURSOR FOR SELECT * FROM foo'); 273 274-- this should commit the transaction 275SELECT dblink_close('myconn','rmt_foo_cursor'); 276 277-- this should fail because there is no open transaction 278SELECT dblink_exec('myconn','DECLARE xact_test CURSOR FOR SELECT * FROM foo'); 279 280-- reset remote transaction state 281SELECT dblink_exec('myconn','ABORT'); 282 283-- open a cursor 284SELECT dblink_open('myconn','rmt_foo_cursor','SELECT * FROM foo'); 285 286-- fetch some data 287SELECT * 288FROM dblink_fetch('myconn','rmt_foo_cursor',4) AS t(a int, b text, c text[]); 289 290SELECT * 291FROM dblink_fetch('myconn','rmt_foo_cursor',4) AS t(a int, b text, c text[]); 292 293-- this one only finds three rows left 294SELECT * 295FROM dblink_fetch('myconn','rmt_foo_cursor',4) AS t(a int, b text, c text[]); 296 297-- fetch some data incorrectly 298SELECT * 299FROM dblink_fetch('myconn','rmt_foobar_cursor',4,false) AS t(a int, b text, c text[]); 300 301-- reset remote transaction state 302SELECT dblink_exec('myconn','ABORT'); 303 304-- should generate 'cursor "rmt_foo_cursor" not found' error 305SELECT * 306FROM dblink_fetch('myconn','rmt_foo_cursor',4) AS t(a int, b text, c text[]); 307 308-- close the named persistent connection 309SELECT dblink_disconnect('myconn'); 310 311-- should generate "missing "=" after "myconn" in connection info string" error 312SELECT * 313FROM dblink('myconn','SELECT * FROM foo') AS t(a int, b text, c text[]) 314WHERE t.a > 7; 315 316-- create a named persistent connection 317SELECT dblink_connect('myconn',connection_parameters()); 318 319-- put more data into our slave table, using named persistent connection syntax 320-- but truncate the actual return value so we can use diff to check for success 321SELECT substr(dblink_exec('myconn','INSERT INTO foo VALUES(11,''l'',''{"a11","b11","c11"}'')'),1,6); 322 323-- let's see it 324SELECT * 325FROM dblink('myconn','SELECT * FROM foo') AS t(a int, b text, c text[]); 326 327-- change some data 328SELECT dblink_exec('myconn','UPDATE foo SET f3[2] = ''b99'' WHERE f1 = 11'); 329 330-- let's see it 331SELECT * 332FROM dblink('myconn','SELECT * FROM foo') AS t(a int, b text, c text[]) 333WHERE a = 11; 334 335-- delete some data 336SELECT dblink_exec('myconn','DELETE FROM foo WHERE f1 = 11'); 337 338-- let's see it 339SELECT * 340FROM dblink('myconn','SELECT * FROM foo') AS t(a int, b text, c text[]) 341WHERE a = 11; 342 343-- close the named persistent connection 344SELECT dblink_disconnect('myconn'); 345 346-- close the named persistent connection again 347-- should get 'connection "myconn" not available' error 348SELECT dblink_disconnect('myconn'); 349 350-- test asynchronous queries 351SELECT dblink_connect('dtest1', connection_parameters()); 352SELECT * from 353 dblink_send_query('dtest1', 'select * from foo where f1 < 3') as t1; 354 355SELECT dblink_connect('dtest2', connection_parameters()); 356SELECT * from 357 dblink_send_query('dtest2', 'select * from foo where f1 > 2 and f1 < 7') as t1; 358 359SELECT dblink_connect('dtest3', connection_parameters()); 360SELECT * from 361 dblink_send_query('dtest3', 'select * from foo where f1 > 6') as t1; 362 363CREATE TEMPORARY TABLE result AS 364(SELECT * from dblink_get_result('dtest1') as t1(f1 int, f2 text, f3 text[])) 365UNION 366(SELECT * from dblink_get_result('dtest2') as t2(f1 int, f2 text, f3 text[])) 367UNION 368(SELECT * from dblink_get_result('dtest3') as t3(f1 int, f2 text, f3 text[])) 369ORDER by f1; 370 371-- dblink_get_connections returns an array with elements in a machine-dependent 372-- ordering, so we must resort to unnesting and sorting for a stable result 373create function unnest(anyarray) returns setof anyelement 374language sql strict immutable as $$ 375select $1[i] from generate_series(array_lower($1,1), array_upper($1,1)) as i 376$$; 377 378SELECT * FROM unnest(dblink_get_connections()) ORDER BY 1; 379 380SELECT dblink_is_busy('dtest1'); 381 382SELECT dblink_disconnect('dtest1'); 383SELECT dblink_disconnect('dtest2'); 384SELECT dblink_disconnect('dtest3'); 385 386SELECT * from result; 387 388SELECT dblink_connect('dtest1', connection_parameters()); 389SELECT * from 390 dblink_send_query('dtest1', 'select * from foo where f1 < 3') as t1; 391 392SELECT dblink_cancel_query('dtest1'); 393SELECT dblink_error_message('dtest1'); 394SELECT dblink_disconnect('dtest1'); 395 396-- test foreign data wrapper functionality 397CREATE ROLE regress_dblink_user; 398DO $d$ 399 BEGIN 400 EXECUTE $$CREATE SERVER fdtest FOREIGN DATA WRAPPER dblink_fdw 401 OPTIONS (dbname '$$||current_database()||$$', 402 port '$$||current_setting('port')||$$' 403 )$$; 404 END; 405$d$; 406 407CREATE USER MAPPING FOR public SERVER fdtest 408 OPTIONS (server 'localhost'); -- fail, can't specify server here 409CREATE USER MAPPING FOR public SERVER fdtest OPTIONS (user :'USER'); 410 411GRANT USAGE ON FOREIGN SERVER fdtest TO regress_dblink_user; 412GRANT EXECUTE ON FUNCTION dblink_connect_u(text, text) TO regress_dblink_user; 413 414SET SESSION AUTHORIZATION regress_dblink_user; 415-- should fail 416SELECT dblink_connect('myconn', 'fdtest'); 417-- should succeed 418SELECT dblink_connect_u('myconn', 'fdtest'); 419SELECT * FROM dblink('myconn','SELECT * FROM foo') AS t(a int, b text, c text[]); 420 421\c - - 422REVOKE USAGE ON FOREIGN SERVER fdtest FROM regress_dblink_user; 423REVOKE EXECUTE ON FUNCTION dblink_connect_u(text, text) FROM regress_dblink_user; 424DROP USER regress_dblink_user; 425DROP USER MAPPING FOR public SERVER fdtest; 426DROP SERVER fdtest; 427 428-- test asynchronous notifications 429SELECT dblink_connect(connection_parameters()); 430 431--should return listen 432SELECT dblink_exec('LISTEN regression'); 433--should return listen 434SELECT dblink_exec('LISTEN foobar'); 435 436SELECT dblink_exec('NOTIFY regression'); 437SELECT dblink_exec('NOTIFY foobar'); 438 439SELECT notify_name, be_pid = (select t.be_pid from dblink('select pg_backend_pid()') as t(be_pid int)) AS is_self_notify, extra from dblink_get_notify(); 440 441SELECT * from dblink_get_notify(); 442 443SELECT dblink_disconnect(); 444 445-- test dropped columns in dblink_build_sql_insert, dblink_build_sql_update 446CREATE TEMP TABLE test_dropped 447( 448 col1 INT NOT NULL DEFAULT 111, 449 id SERIAL PRIMARY KEY, 450 col2 INT NOT NULL DEFAULT 112, 451 col2b INT NOT NULL DEFAULT 113 452); 453 454INSERT INTO test_dropped VALUES(default); 455 456ALTER TABLE test_dropped 457 DROP COLUMN col1, 458 DROP COLUMN col2, 459 ADD COLUMN col3 VARCHAR(10) NOT NULL DEFAULT 'foo', 460 ADD COLUMN col4 INT NOT NULL DEFAULT 42; 461 462SELECT dblink_build_sql_insert('test_dropped', '1', 1, 463 ARRAY['1'::TEXT], ARRAY['2'::TEXT]); 464 465SELECT dblink_build_sql_update('test_dropped', '1', 1, 466 ARRAY['1'::TEXT], ARRAY['2'::TEXT]); 467 468SELECT dblink_build_sql_delete('test_dropped', '1', 1, 469 ARRAY['2'::TEXT]); 470 471-- test local mimicry of remote GUC values that affect datatype I/O 472SET datestyle = ISO, MDY; 473SET intervalstyle = postgres; 474SET timezone = UTC; 475SELECT dblink_connect('myconn',connection_parameters()); 476SELECT dblink_exec('myconn', 'SET datestyle = GERMAN, DMY;'); 477 478-- single row synchronous case 479SELECT * 480FROM dblink('myconn', 481 'SELECT * FROM (VALUES (''12.03.2013 00:00:00+00'')) t') 482 AS t(a timestamptz); 483 484-- multi-row synchronous case 485SELECT * 486FROM dblink('myconn', 487 'SELECT * FROM 488 (VALUES (''12.03.2013 00:00:00+00''), 489 (''12.03.2013 00:00:00+00'')) t') 490 AS t(a timestamptz); 491 492-- single-row asynchronous case 493SELECT * 494FROM dblink_send_query('myconn', 495 'SELECT * FROM 496 (VALUES (''12.03.2013 00:00:00+00'')) t'); 497CREATE TEMPORARY TABLE result AS 498(SELECT * from dblink_get_result('myconn') as t(t timestamptz)) 499UNION ALL 500(SELECT * from dblink_get_result('myconn') as t(t timestamptz)); 501SELECT * FROM result; 502DROP TABLE result; 503 504-- multi-row asynchronous case 505SELECT * 506FROM dblink_send_query('myconn', 507 'SELECT * FROM 508 (VALUES (''12.03.2013 00:00:00+00''), 509 (''12.03.2013 00:00:00+00'')) t'); 510CREATE TEMPORARY TABLE result AS 511(SELECT * from dblink_get_result('myconn') as t(t timestamptz)) 512UNION ALL 513(SELECT * from dblink_get_result('myconn') as t(t timestamptz)) 514UNION ALL 515(SELECT * from dblink_get_result('myconn') as t(t timestamptz)); 516SELECT * FROM result; 517DROP TABLE result; 518 519-- Try an ambiguous interval 520SELECT dblink_exec('myconn', 'SET intervalstyle = sql_standard;'); 521SELECT * 522FROM dblink('myconn', 523 'SELECT * FROM (VALUES (''-1 2:03:04'')) i') 524 AS i(i interval); 525 526-- Try swapping to another format to ensure the GUCs are tracked 527-- properly through a change. 528CREATE TEMPORARY TABLE result (t timestamptz); 529 530SELECT dblink_exec('myconn', 'SET datestyle = ISO, MDY;'); 531INSERT INTO result 532 SELECT * 533 FROM dblink('myconn', 534 'SELECT * FROM (VALUES (''03.12.2013 00:00:00+00'')) t') 535 AS t(a timestamptz); 536 537SELECT dblink_exec('myconn', 'SET datestyle = GERMAN, DMY;'); 538INSERT INTO result 539 SELECT * 540 FROM dblink('myconn', 541 'SELECT * FROM (VALUES (''12.03.2013 00:00:00+00'')) t') 542 AS t(a timestamptz); 543 544SELECT * FROM result; 545 546DROP TABLE result; 547 548-- Check error throwing in dblink_fetch 549SELECT dblink_open('myconn','error_cursor', 550 'SELECT * FROM (VALUES (''1''), (''not an int'')) AS t(text);'); 551SELECT * 552FROM dblink_fetch('myconn','error_cursor', 1) AS t(i int); 553SELECT * 554FROM dblink_fetch('myconn','error_cursor', 1) AS t(i int); 555 556-- Make sure that the local settings have retained their values in spite 557-- of shenanigans on the connection. 558SHOW datestyle; 559SHOW intervalstyle; 560 561-- Clean up GUC-setting tests 562SELECT dblink_disconnect('myconn'); 563RESET datestyle; 564RESET intervalstyle; 565RESET timezone; 566