From: Pallavi Sontakke Date: Wed, 9 Sep 2015 11:33:59 +0000 (+0530) Subject: Modifying existing UDF tests with some limitations conditions. X-Git-Url: http://git.postgresql.org/gitweb/?a=commitdiff_plain;h=refs%2Fheads%2Fxl_test;p=postgres-xl.git Modifying existing UDF tests with some limitations conditions. --- diff --git a/src/test/regress/expected/xl_user_defined_functions.out b/src/test/regress/expected/xl_user_defined_functions.out index 48af42c57a..72e0284998 100755 --- a/src/test/regress/expected/xl_user_defined_functions.out +++ b/src/test/regress/expected/xl_user_defined_functions.out @@ -230,7 +230,7 @@ select xl_nodename_from_id1(xc_node_id), * from xl_Pline1 order by slotname; -- Test the FOUND magic variable -- -- table distributed by hash on a by default -CREATE TABLE xl_found_test_tbl (a int, b int) ; +CREATE TABLE xl_found_test_tbl (a int unique, b int) ; create function xl_test_found() returns boolean as ' declare @@ -272,6 +272,9 @@ select xl_test_found(); t (1 row) +--DML is not supported when function is executed on the datanode, if function is executed on coordinator, DML works fine. e.g. Currently planner sends ‘select funcn() from ’ calls directly to datanode. +select xl_test_found() from xl_found_test_tbl; +ERROR: Postgres-XL does not support DML queries in PL/pgSQL on Datanodes select * from xl_found_test_tbl order by 1; a | b ---+----- @@ -283,6 +286,9 @@ select * from xl_found_test_tbl order by 1; 6 | 6 (6 rows) +truncate table xl_found_test_tbl; +insert into xl_found_test_tbl values (1, 1);--goes on datanode_1 +insert into xl_found_test_tbl values (4, 4);-- goes on datanode_2 -- -- Test set-returning functions for PL/pgSQL -- @@ -296,15 +302,21 @@ BEGIN RETURN; END;' language plpgsql; select * from xl_test_table_func_rec() order by 1; - a | b ----+----- - 1 | 100 - 2 | 2 - 3 | 3 - 4 | 4 - 5 | 5 - 6 | 6 -(6 rows) + a | b +---+--- + 1 | 1 + 4 | 4 +(2 rows) + +--Selection functions also do not work fine when they go directly on datanodes. There is no restriction/ error returned from XL here, however overall its behavior in such cases is different from Postgresql. +select xl_test_table_func_rec() from xl_found_test_tbl; + xl_test_table_func_rec +------------------------ + (1,1) + (4,4) + (1,1) + (4,4) +(4 rows) -- reads from just 1 node, reads from multiple nodes, writes to just node, writes to multiple nodes, writes to one node and then read again, do a join which requires data from one node, multiple nodes, use ddl etc --reads from multiple nodes @@ -318,26 +330,27 @@ BEGIN RETURN; END;' language plpgsql; select * from xl_test_table_func_row() order by 1; - a | b ----+----- - 1 | 100 - 2 | 2 - 3 | 3 - 4 | 4 - 5 | 5 - 6 | 6 -(6 rows) + a | b +---+--- + 1 | 1 + 4 | 4 +(2 rows) + +select xl_test_table_func_row() from xl_found_test_tbl order by 1; + xl_test_table_func_row +------------------------ + (1,1) + (1,1) + (4,4) + (4,4) +(4 rows) select xl_nodename_from_id1(xc_node_id), * from xl_found_test_tbl; - xl_nodename_from_id1 | a | b -----------------------+---+----- - datanode_1 | 2 | 2 - datanode_1 | 1 | 100 - datanode_1 | 5 | 5 - datanode_1 | 6 | 6 - datanode_2 | 3 | 3 - datanode_2 | 4 | 4 -(6 rows) + xl_nodename_from_id1 | a | b +----------------------+---+--- + datanode_1 | 1 | 1 + datanode_2 | 4 | 4 +(2 rows) --reads from just 1 node create function xl_read_from_one_node(name) returns setof xl_found_test_tbl as ' @@ -352,45 +365,68 @@ END;' language plpgsql; select xl_read_from_one_node('datanode_1'); xl_read_from_one_node ----------------------- - (2,2) - (1,100) - (5,5) - (6,6) -(4 rows) + (1,1) +(1 row) select xl_read_from_one_node('datanode_2'); xl_read_from_one_node ----------------------- - (3,3) + (4,4) +(1 row) + +select xl_read_from_one_node('datanode_1') from xl_found_test_tbl; + xl_read_from_one_node +----------------------- + (1,1) + (1,1) +(2 rows) + +select xl_read_from_one_node('datanode_2') from xl_found_test_tbl; + xl_read_from_one_node +----------------------- + (4,4) (4,4) (2 rows) update xl_found_test_tbl set b = a;--re-set --writes to just node -create function xl_write_to_one_node(name) returns void as ' +--Correlated update is not supported on non-distribution columns with function in where clause when distribution column is unique . It is allowed when distribution column is non-unique. +create function xl_write_to_one_node_unique_distribution_column(name) returns void as ' BEGIN update xl_found_test_tbl set b = b * 100 where a in (select a from xl_found_test_tbl where xl_nodename_from_id1(xc_node_id) = $1); RETURN; END;' language plpgsql; +select xl_write_to_one_node_unique_distribution_column('datanode_1'); +ERROR: could not plan this distributed update +DETAIL: correlated UPDATE or updating distribution column currently not supported in Postgres-XL. +CONTEXT: SQL statement "update xl_found_test_tbl set b = b * 100 where a in (select a from xl_found_test_tbl where xl_nodename_from_id1(xc_node_id) = $1)" +PL/pgSQL function xl_write_to_one_node_unique_distribution_column(name) line 3 at SQL statement +create table a_tbl(a int, b int); +insert into a_tbl values (1,1);-- goes on datanode_1 +insert into a_tbl values (4,4);-- goes on datanode_2 +create function xl_write_to_one_node(name) returns void as ' +BEGIN + update a_tbl set b = b * 100 where a in (select a from a_tbl where xl_nodename_from_id1(xc_node_id) = $1); + RETURN; +END;' language plpgsql; select xl_write_to_one_node('datanode_1'); xl_write_to_one_node ---------------------- (1 row) -select xl_nodename_from_id1(xc_node_id), * from xl_found_test_tbl; +select xl_nodename_from_id1(xc_node_id), * from a_tbl; xl_nodename_from_id1 | a | b ----------------------+---+----- - datanode_1 | 2 | 200 datanode_1 | 1 | 100 - datanode_1 | 5 | 500 - datanode_1 | 6 | 600 - datanode_2 | 3 | 3 datanode_2 | 4 | 4 -(6 rows) +(2 rows) update xl_found_test_tbl set b = a;--re-set +update a_tbl set b = a;--re-set +select xl_write_to_one_node('datanode_1') from xl_found_test_tbl; +ERROR: Postgres-XL does not support DML queries in PL/pgSQL on Datanodes --writes to multiple nodes create function xl_write_to_multiple_nodes() returns void as ' BEGIN @@ -406,22 +442,20 @@ select xl_write_to_multiple_nodes(); select xl_nodename_from_id1(xc_node_id), * from xl_found_test_tbl; xl_nodename_from_id1 | a | b ----------------------+---+----- - datanode_1 | 2 | 200 datanode_1 | 1 | 100 - datanode_1 | 5 | 500 - datanode_1 | 6 | 600 - datanode_2 | 3 | 300 datanode_2 | 4 | 400 -(6 rows) +(2 rows) update xl_found_test_tbl set b = a;--re-set +select xl_write_to_multiple_nodes() from xl_found_test_tbl; +ERROR: Postgres-XL does not support DML queries in PL/pgSQL on Datanodes --writes to one node and then read again, -create function xl_write_read_from_one_node(name) returns setof xl_found_test_tbl as ' +create function xl_write_read_from_one_node(name) returns setof a_tbl as ' DECLARE - row xl_found_test_tbl%ROWTYPE; + row a_tbl%ROWTYPE; BEGIN - update xl_found_test_tbl set b = b * 100 where a in (select a from xl_found_test_tbl where xl_nodename_from_id1(xc_node_id) = $1); - FOR row IN select * from xl_found_test_tbl where a in (select a from xl_found_test_tbl where xl_nodename_from_id1(xc_node_id) = $1) LOOP + update a_tbl set b = b * 100 where a in (select a from a_tbl where xl_nodename_from_id1(xc_node_id) = $1); + FOR row IN select * from a_tbl where a in (select a from a_tbl where xl_nodename_from_id1(xc_node_id) = $1) LOOP RETURN NEXT row; END LOOP; RETURN; @@ -429,38 +463,37 @@ END;' language plpgsql; select xl_write_read_from_one_node('datanode_1'); xl_write_read_from_one_node ----------------------------- - (2,200) (1,100) - (5,500) - (6,600) -(4 rows) +(1 row) -select xl_nodename_from_id1(xc_node_id), * from xl_found_test_tbl; +select xl_nodename_from_id1(xc_node_id), * from a_tbl; xl_nodename_from_id1 | a | b ----------------------+---+----- - datanode_1 | 2 | 200 datanode_1 | 1 | 100 - datanode_1 | 5 | 500 - datanode_1 | 6 | 600 - datanode_2 | 3 | 3 datanode_2 | 4 | 4 -(6 rows) +(2 rows) -update xl_found_test_tbl set b = a;--re-set +update a_tbl set b = a;--re-set +select xl_write_read_from_one_node('datanode_1') from a_tbl; +ERROR: Postgres-XL does not support DML queries in PL/pgSQL on Datanodes +select xl_nodename_from_id1(xc_node_id), * from a_tbl; + xl_nodename_from_id1 | a | b +----------------------+---+--- + datanode_1 | 1 | 1 + datanode_2 | 4 | 4 +(2 rows) + +update a_tbl set b = a;--re-set -- do a join which requires data from one node, -- table is replicated on both nodes. CREATE TABLE xl_join1_tbl (c int, d int) distribute by replication; insert into xl_join1_tbl values (1, 100); -insert into xl_join1_tbl values (2, 200); -insert into xl_join1_tbl values (3, 300); insert into xl_join1_tbl values (4, 400); -insert into xl_join1_tbl values (5, 500); -insert into xl_join1_tbl values (6, 600); create function xl_join_using_1node(name) returns void as ' BEGIN - update xl_found_test_tbl set b = xl_join1_tbl.d from xl_join1_tbl - where xl_join1_tbl.c in (select a from xl_found_test_tbl where xl_nodename_from_id1(xc_node_id) = $1) - and xl_found_test_tbl.a = xl_join1_tbl.c + update a_tbl set b = xl_join1_tbl.d from xl_join1_tbl + where xl_join1_tbl.c in (select a from a_tbl where xl_nodename_from_id1(xc_node_id) = $1) + and a_tbl.a = xl_join1_tbl.c and xl_join1_tbl.c <= 3; RETURN; END;' language plpgsql; @@ -470,53 +503,61 @@ select xl_join_using_1node('datanode_1'); (1 row) -select xl_nodename_from_id1(xc_node_id), * from xl_found_test_tbl; +select xl_nodename_from_id1(xc_node_id), * from a_tbl; xl_nodename_from_id1 | a | b ----------------------+---+----- - datanode_1 | 5 | 5 - datanode_1 | 6 | 6 - datanode_1 | 2 | 200 datanode_1 | 1 | 100 - datanode_2 | 3 | 3 datanode_2 | 4 | 4 -(6 rows) +(2 rows) -update xl_found_test_tbl set b = a;--re-set +update a_tbl set b = a;--re-set +select xl_join_using_1node('datanode_1') from xl_join1_tbl; +ERROR: Postgres-XL does not support DML queries in PL/pgSQL on Datanodes +select xl_nodename_from_id1(xc_node_id), * from a_tbl; + xl_nodename_from_id1 | a | b +----------------------+---+--- + datanode_1 | 1 | 1 + datanode_2 | 4 | 4 +(2 rows) + +update a_tbl set b = a;--re-set -- do a join which requires data from multiple nodes -- table distributed by hash(c) by default CREATE TABLE xl_join2_tbl (c int, d int); insert into xl_join2_tbl values (1, 100); -insert into xl_join2_tbl values (2, 200); -insert into xl_join2_tbl values (3, 300); insert into xl_join2_tbl values (4, 400); -insert into xl_join2_tbl values (5, 500); -insert into xl_join2_tbl values (6, 600); create function xl_join_using_more_nodes(name) returns void as ' BEGIN - update xl_found_test_tbl set b = xl_join2_tbl.d from xl_join2_tbl - where xl_join2_tbl.c in (select a from xl_found_test_tbl where xl_nodename_from_id1(xc_node_id) = $1) - and xl_found_test_tbl.a = xl_join2_tbl.c + update a_tbl set b = xl_join2_tbl.d from xl_join2_tbl + where xl_join2_tbl.c in (select a from a_tbl where xl_nodename_from_id1(xc_node_id) = $1) + and a_tbl.a = xl_join2_tbl.c and xl_join2_tbl.c >= 3; RETURN; END;' language plpgsql; -select xl_join_using_more_nodes('datanode_1'); +select xl_join_using_more_nodes('datanode_2'); xl_join_using_more_nodes -------------------------- (1 row) -select xl_nodename_from_id1(xc_node_id), * from xl_found_test_tbl; +select xl_nodename_from_id1(xc_node_id), * from a_tbl; xl_nodename_from_id1 | a | b ----------------------+---+----- - datanode_1 | 2 | 2 datanode_1 | 1 | 1 - datanode_1 | 5 | 500 - datanode_1 | 6 | 600 - datanode_2 | 3 | 3 - datanode_2 | 4 | 4 -(6 rows) + datanode_2 | 4 | 400 +(2 rows) -update xl_found_test_tbl set b = a;--re-set +update a_tbl set b = a;--re-set +select xl_join_using_more_nodes('datanode_1') from xl_join2_tbl; +ERROR: Postgres-XL does not support DML queries in PL/pgSQL on Datanodes +select xl_nodename_from_id1(xc_node_id), * from a_tbl; + xl_nodename_from_id1 | a | b +----------------------+---+--- + datanode_1 | 1 | 1 + datanode_2 | 4 | 4 +(2 rows) + +update a_tbl set b = a;--re-set -- use ddl etc --DDL Commands - Create - Drop - Alter - Rename - Truncate -- @@ -525,11 +566,7 @@ BEGIN /* table distributed by hash on a by default*/ CREATE TABLE xl_ddl_tbl1 (a int, b int) ; insert into xl_ddl_tbl1 values (1,1); - insert into xl_ddl_tbl1 values (2,2); - insert into xl_ddl_tbl1 values (3,3); insert into xl_ddl_tbl1 values (4,4); - insert into xl_ddl_tbl1 values (5,5); - insert into xl_ddl_tbl1 values (6,6); drop table xl_join2_tbl; @@ -537,11 +574,7 @@ BEGIN CREATE TABLE xl_join3_tbl (c int); insert into xl_join3_tbl values (1); - insert into xl_join3_tbl values (2); - insert into xl_join3_tbl values (3); insert into xl_join3_tbl values (4); - insert into xl_join3_tbl values (5); - insert into xl_join3_tbl values (6); alter table xl_join3_tbl add column d int; @@ -560,7 +593,7 @@ BEGIN RETURN; END;' language plpgsql; -select xl_ddl_commands('datanode_1'); +select xl_ddl_commands('datanode_2'); xl_ddl_commands ----------------- @@ -583,25 +616,104 @@ select xl_nodename_from_id1(xc_node_id), * from xl_join4_tbl; xl_nodename_from_id1 | c | d ----------------------+---+----- datanode_1 | 1 | 100 - datanode_1 | 2 | 200 - datanode_1 | 5 | 500 - datanode_1 | 6 | 600 - datanode_2 | 3 | 300 datanode_2 | 4 | 400 -(6 rows) +(2 rows) select xl_nodename_from_id1(xc_node_id), * from xl_ddl_tbl2; xl_nodename_from_id1 | a | b ----------------------+---+----- datanode_1 | 1 | 1 - datanode_1 | 2 | 2 - datanode_1 | 5 | 500 - datanode_1 | 6 | 600 - datanode_2 | 3 | 3 - datanode_2 | 4 | 4 -(6 rows) + datanode_2 | 4 | 400 +(2 rows) update xl_found_test_tbl set b = a;--re-set +drop TABLE xl_ddl_tbl1; +ERROR: table "xl_ddl_tbl1" does not exist +drop TABLE xl_ddl_tbl2; +drop TABLE xl_join3_tbl; +ERROR: table "xl_join3_tbl" does not exist +drop TABLE xl_join4_tbl; +insert into xl_join1_tbl values (1, 100); +insert into xl_join1_tbl values (4, 400); +--re-set all conditions +select xl_ddl_commands('datanode_2') from xl_join1_tbl; -- fails as DML query run on data-node +ERROR: Postgres-XL does not support DML queries in PL/pgSQL on Datanodes +-- function call from replicated table. func returns matching count between replicated and distributed table - where some go on datanode 1 and others on datanode 2. +-- replicated table +create table xl_replctd_tbl(r int, s int) distribute by replication; +insert into xl_replctd_tbl values (1,1); +insert into xl_replctd_tbl values (4,4); +-- distributed table - default distributed by hash on d +create table xl_dstrbtd_tbl(d int, e int); +insert into xl_dstrbtd_tbl values(1,1); +insert into xl_dstrbtd_tbl values(4,4); +select count(r) from xl_replctd_tbl where r in (select d from xl_dstrbtd_tbl); + count +------- + 2 +(1 row) + +create function xl_get_common_count() returns int as ' +declare + i int; +BEGIN + select count(r) from xl_replctd_tbl into i where r in (select d from xl_dstrbtd_tbl); + RETURN i; +END;' language plpgsql; +explain select xl_get_common_count() from xl_replctd_tbl; + QUERY PLAN +--------------------------------------------------------------------------------- + Remote Subquery Scan on all (datanode_1) (cost=0.00..597.60 rows=2260 width=0) + -> Seq Scan on xl_replctd_tbl (cost=0.00..597.60 rows=2260 width=0) +(2 rows) + +select xl_get_common_count() from xl_replctd_tbl; + xl_get_common_count +--------------------- + 2 + 2 +(2 rows) + +explain select xl_get_common_count(); + QUERY PLAN +------------------------------------------ + Result (cost=0.00..0.26 rows=1 width=0) +(1 row) + +select xl_get_common_count(); + xl_get_common_count +--------------------- + 2 +(1 row) + +explain select xl_get_common_count() from xl_dstrbtd_tbl; + QUERY PLAN +-------------------------------------------------------------------------------------------- + Remote Subquery Scan on all (datanode_1,datanode_2) (cost=0.00..597.60 rows=2260 width=0) + -> Seq Scan on xl_dstrbtd_tbl (cost=0.00..597.60 rows=2260 width=0) +(2 rows) + +select xl_get_common_count() from xl_dstrbtd_tbl; + xl_get_common_count +--------------------- + 2 + 2 +(2 rows) + +select xl_nodename_from_id1(xc_node_id), * from xl_replctd_tbl; + xl_nodename_from_id1 | r | s +----------------------+---+--- + datanode_2 | 1 | 1 + datanode_2 | 4 | 4 +(2 rows) + +select xl_nodename_from_id1(xc_node_id), * from xl_dstrbtd_tbl; + xl_nodename_from_id1 | d | e +----------------------+---+--- + datanode_1 | 1 | 1 + datanode_2 | 4 | 4 +(2 rows) + drop table xl_Pline1; drop function xl_nodename_from_id1(integer); drop function xl_insert_Pline_test(int); @@ -611,15 +723,22 @@ drop function xl_test_table_func_row(); drop function xl_test_table_func_rec(); drop function xl_test_found(); drop function xl_read_from_one_node(name); +drop function xl_write_to_one_node_unique_distribution_column(name); drop function xl_write_to_one_node(name); drop function xl_write_to_multiple_nodes(); drop function xl_write_read_from_one_node(name); drop function xl_join_using_1node(name); drop function xl_join_using_more_nodes(name); drop function xl_ddl_commands(name); +drop function xl_get_common_count(); drop TABLE xl_found_test_tbl; drop TABLE xl_ddl_tbl2; +ERROR: table "xl_ddl_tbl2" does not exist drop TABLE xl_join1_tbl; drop TABLE xl_join2_tbl; ERROR: table "xl_join2_tbl" does not exist drop TABLE xl_join4_tbl; +ERROR: table "xl_join4_tbl" does not exist +drop table xl_replctd_tbl; +drop table xl_dstrbtd_tbl; +drop table a_tbl; diff --git a/src/test/regress/sql/xl_user_defined_functions.sql b/src/test/regress/sql/xl_user_defined_functions.sql index d1790947ae..94b3e7a2b5 100755 --- a/src/test/regress/sql/xl_user_defined_functions.sql +++ b/src/test/regress/sql/xl_user_defined_functions.sql @@ -118,7 +118,7 @@ select xl_nodename_from_id1(xc_node_id), * from xl_Pline1 order by slotname; -- Test the FOUND magic variable -- -- table distributed by hash on a by default -CREATE TABLE xl_found_test_tbl (a int, b int) ; +CREATE TABLE xl_found_test_tbl (a int unique, b int) ; create function xl_test_found() returns boolean as ' @@ -157,8 +157,16 @@ create function xl_test_found() end;' language plpgsql; select xl_test_found(); + +--DML is not supported when function is executed on the datanode, if function is executed on coordinator, DML works fine. e.g. Currently planner sends ‘select funcn() from ’ calls directly to datanode. +select xl_test_found() from xl_found_test_tbl; + select * from xl_found_test_tbl order by 1; +truncate table xl_found_test_tbl; +insert into xl_found_test_tbl values (1, 1);--goes on datanode_1 +insert into xl_found_test_tbl values (4, 4);-- goes on datanode_2 + -- -- Test set-returning functions for PL/pgSQL -- @@ -175,6 +183,8 @@ END;' language plpgsql; select * from xl_test_table_func_rec() order by 1; +--Selection functions also do not work fine when they go directly on datanodes. There is no restriction/ error returned from XL here, however overall its behavior in such cases is different from Postgresql. +select xl_test_table_func_rec() from xl_found_test_tbl; -- reads from just 1 node, reads from multiple nodes, writes to just node, writes to multiple nodes, writes to one node and then read again, do a join which requires data from one node, multiple nodes, use ddl etc @@ -191,6 +201,8 @@ END;' language plpgsql; select * from xl_test_table_func_row() order by 1; +select xl_test_table_func_row() from xl_found_test_tbl order by 1; + select xl_nodename_from_id1(xc_node_id), * from xl_found_test_tbl; @@ -208,20 +220,42 @@ END;' language plpgsql; select xl_read_from_one_node('datanode_1'); select xl_read_from_one_node('datanode_2'); +select xl_read_from_one_node('datanode_1') from xl_found_test_tbl; +select xl_read_from_one_node('datanode_2') from xl_found_test_tbl; + update xl_found_test_tbl set b = a;--re-set --writes to just node -create function xl_write_to_one_node(name) returns void as ' + +--Correlated update is not supported on non-distribution columns with function in where clause when distribution column is unique . It is allowed when distribution column is non-unique. + +create function xl_write_to_one_node_unique_distribution_column(name) returns void as ' BEGIN update xl_found_test_tbl set b = b * 100 where a in (select a from xl_found_test_tbl where xl_nodename_from_id1(xc_node_id) = $1); RETURN; END;' language plpgsql; +select xl_write_to_one_node_unique_distribution_column('datanode_1'); + +create table a_tbl(a int, b int); + +insert into a_tbl values (1,1);-- goes on datanode_1 +insert into a_tbl values (4,4);-- goes on datanode_2 + +create function xl_write_to_one_node(name) returns void as ' +BEGIN + update a_tbl set b = b * 100 where a in (select a from a_tbl where xl_nodename_from_id1(xc_node_id) = $1); + RETURN; +END;' language plpgsql; + select xl_write_to_one_node('datanode_1'); -select xl_nodename_from_id1(xc_node_id), * from xl_found_test_tbl; +select xl_nodename_from_id1(xc_node_id), * from a_tbl; update xl_found_test_tbl set b = a;--re-set +update a_tbl set b = a;--re-set + +select xl_write_to_one_node('datanode_1') from xl_found_test_tbl; --writes to multiple nodes create function xl_write_to_multiple_nodes() returns void as ' @@ -236,14 +270,16 @@ select xl_nodename_from_id1(xc_node_id), * from xl_found_test_tbl; update xl_found_test_tbl set b = a;--re-set +select xl_write_to_multiple_nodes() from xl_found_test_tbl; + --writes to one node and then read again, -create function xl_write_read_from_one_node(name) returns setof xl_found_test_tbl as ' +create function xl_write_read_from_one_node(name) returns setof a_tbl as ' DECLARE - row xl_found_test_tbl%ROWTYPE; + row a_tbl%ROWTYPE; BEGIN - update xl_found_test_tbl set b = b * 100 where a in (select a from xl_found_test_tbl where xl_nodename_from_id1(xc_node_id) = $1); - FOR row IN select * from xl_found_test_tbl where a in (select a from xl_found_test_tbl where xl_nodename_from_id1(xc_node_id) = $1) LOOP + update a_tbl set b = b * 100 where a in (select a from a_tbl where xl_nodename_from_id1(xc_node_id) = $1); + FOR row IN select * from a_tbl where a in (select a from a_tbl where xl_nodename_from_id1(xc_node_id) = $1) LOOP RETURN NEXT row; END LOOP; RETURN; @@ -251,62 +287,71 @@ END;' language plpgsql; select xl_write_read_from_one_node('datanode_1'); -select xl_nodename_from_id1(xc_node_id), * from xl_found_test_tbl; +select xl_nodename_from_id1(xc_node_id), * from a_tbl; -update xl_found_test_tbl set b = a;--re-set +update a_tbl set b = a;--re-set + +select xl_write_read_from_one_node('datanode_1') from a_tbl; + +select xl_nodename_from_id1(xc_node_id), * from a_tbl; + +update a_tbl set b = a;--re-set -- do a join which requires data from one node, -- table is replicated on both nodes. CREATE TABLE xl_join1_tbl (c int, d int) distribute by replication; insert into xl_join1_tbl values (1, 100); -insert into xl_join1_tbl values (2, 200); -insert into xl_join1_tbl values (3, 300); insert into xl_join1_tbl values (4, 400); -insert into xl_join1_tbl values (5, 500); -insert into xl_join1_tbl values (6, 600); create function xl_join_using_1node(name) returns void as ' BEGIN - update xl_found_test_tbl set b = xl_join1_tbl.d from xl_join1_tbl - where xl_join1_tbl.c in (select a from xl_found_test_tbl where xl_nodename_from_id1(xc_node_id) = $1) - and xl_found_test_tbl.a = xl_join1_tbl.c + update a_tbl set b = xl_join1_tbl.d from xl_join1_tbl + where xl_join1_tbl.c in (select a from a_tbl where xl_nodename_from_id1(xc_node_id) = $1) + and a_tbl.a = xl_join1_tbl.c and xl_join1_tbl.c <= 3; RETURN; END;' language plpgsql; select xl_join_using_1node('datanode_1'); -select xl_nodename_from_id1(xc_node_id), * from xl_found_test_tbl; +select xl_nodename_from_id1(xc_node_id), * from a_tbl; -update xl_found_test_tbl set b = a;--re-set +update a_tbl set b = a;--re-set + +select xl_join_using_1node('datanode_1') from xl_join1_tbl; + +select xl_nodename_from_id1(xc_node_id), * from a_tbl; + +update a_tbl set b = a;--re-set -- do a join which requires data from multiple nodes -- table distributed by hash(c) by default CREATE TABLE xl_join2_tbl (c int, d int); insert into xl_join2_tbl values (1, 100); -insert into xl_join2_tbl values (2, 200); -insert into xl_join2_tbl values (3, 300); insert into xl_join2_tbl values (4, 400); -insert into xl_join2_tbl values (5, 500); -insert into xl_join2_tbl values (6, 600); - create function xl_join_using_more_nodes(name) returns void as ' BEGIN - update xl_found_test_tbl set b = xl_join2_tbl.d from xl_join2_tbl - where xl_join2_tbl.c in (select a from xl_found_test_tbl where xl_nodename_from_id1(xc_node_id) = $1) - and xl_found_test_tbl.a = xl_join2_tbl.c + update a_tbl set b = xl_join2_tbl.d from xl_join2_tbl + where xl_join2_tbl.c in (select a from a_tbl where xl_nodename_from_id1(xc_node_id) = $1) + and a_tbl.a = xl_join2_tbl.c and xl_join2_tbl.c >= 3; RETURN; END;' language plpgsql; -select xl_join_using_more_nodes('datanode_1'); +select xl_join_using_more_nodes('datanode_2'); -select xl_nodename_from_id1(xc_node_id), * from xl_found_test_tbl; +select xl_nodename_from_id1(xc_node_id), * from a_tbl; -update xl_found_test_tbl set b = a;--re-set +update a_tbl set b = a;--re-set + +select xl_join_using_more_nodes('datanode_1') from xl_join2_tbl; + +select xl_nodename_from_id1(xc_node_id), * from a_tbl; + +update a_tbl set b = a;--re-set -- use ddl etc --DDL Commands - Create - Drop - Alter - Rename - Truncate @@ -317,11 +362,7 @@ BEGIN /* table distributed by hash on a by default*/ CREATE TABLE xl_ddl_tbl1 (a int, b int) ; insert into xl_ddl_tbl1 values (1,1); - insert into xl_ddl_tbl1 values (2,2); - insert into xl_ddl_tbl1 values (3,3); insert into xl_ddl_tbl1 values (4,4); - insert into xl_ddl_tbl1 values (5,5); - insert into xl_ddl_tbl1 values (6,6); drop table xl_join2_tbl; @@ -329,11 +370,7 @@ BEGIN CREATE TABLE xl_join3_tbl (c int); insert into xl_join3_tbl values (1); - insert into xl_join3_tbl values (2); - insert into xl_join3_tbl values (3); insert into xl_join3_tbl values (4); - insert into xl_join3_tbl values (5); - insert into xl_join3_tbl values (6); alter table xl_join3_tbl add column d int; @@ -353,7 +390,7 @@ BEGIN RETURN; END;' language plpgsql; -select xl_ddl_commands('datanode_1'); +select xl_ddl_commands('datanode_2'); select xl_nodename_from_id1(xc_node_id), * from xl_join1_tbl; --truncated @@ -367,6 +404,59 @@ select xl_nodename_from_id1(xc_node_id), * from xl_ddl_tbl2; update xl_found_test_tbl set b = a;--re-set +drop TABLE xl_ddl_tbl1; + +drop TABLE xl_ddl_tbl2; + +drop TABLE xl_join3_tbl; + +drop TABLE xl_join4_tbl; + +insert into xl_join1_tbl values (1, 100); +insert into xl_join1_tbl values (4, 400); + +--re-set all conditions +select xl_ddl_commands('datanode_2') from xl_join1_tbl; -- fails as DML query run on data-node + +-- function call from replicated table. func returns matching count between replicated and distributed table - where some go on datanode 1 and others on datanode 2. + +-- replicated table +create table xl_replctd_tbl(r int, s int) distribute by replication; +insert into xl_replctd_tbl values (1,1); +insert into xl_replctd_tbl values (4,4); + +-- distributed table - default distributed by hash on d +create table xl_dstrbtd_tbl(d int, e int); + +insert into xl_dstrbtd_tbl values(1,1); +insert into xl_dstrbtd_tbl values(4,4); + +select count(r) from xl_replctd_tbl where r in (select d from xl_dstrbtd_tbl); + +create function xl_get_common_count() returns int as ' +declare + i int; +BEGIN + select count(r) from xl_replctd_tbl into i where r in (select d from xl_dstrbtd_tbl); + RETURN i; +END;' language plpgsql; + +explain select xl_get_common_count() from xl_replctd_tbl; + +select xl_get_common_count() from xl_replctd_tbl; + +explain select xl_get_common_count(); + +select xl_get_common_count(); + +explain select xl_get_common_count() from xl_dstrbtd_tbl; + +select xl_get_common_count() from xl_dstrbtd_tbl; + +select xl_nodename_from_id1(xc_node_id), * from xl_replctd_tbl; + +select xl_nodename_from_id1(xc_node_id), * from xl_dstrbtd_tbl; + drop table xl_Pline1; drop function xl_nodename_from_id1(integer); drop function xl_insert_Pline_test(int); @@ -376,15 +466,19 @@ drop function xl_test_table_func_row(); drop function xl_test_table_func_rec(); drop function xl_test_found(); drop function xl_read_from_one_node(name); +drop function xl_write_to_one_node_unique_distribution_column(name); drop function xl_write_to_one_node(name); drop function xl_write_to_multiple_nodes(); drop function xl_write_read_from_one_node(name); drop function xl_join_using_1node(name); drop function xl_join_using_more_nodes(name); drop function xl_ddl_commands(name); +drop function xl_get_common_count(); drop TABLE xl_found_test_tbl; drop TABLE xl_ddl_tbl2; drop TABLE xl_join1_tbl; drop TABLE xl_join2_tbl; drop TABLE xl_join4_tbl; - +drop table xl_replctd_tbl; +drop table xl_dstrbtd_tbl; +drop table a_tbl;