1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 784 785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907 908 909 910 911 912 913 914 915 916 917 918 919 920 921 922 923 924 925 926 927 928 929 930 931 932 933 934 935 936 937 938 939 940 941 942 943 944 945 946 947 948 949 950 951 952 953 954 955 956 957 958 959 960 961 962 963 964 965 966 967 968 969 970 971 972 973 974 975 976 977 978 979 980 981 982 983 984 985 986 987 988 989 990 991 992 993 994 995 996 997 998 999 1000 1001 1002 1003 1004 1005 1006 1007 1008 1009 1010 1011 1012 1013 1014 1015 1016 1017 1018 1019 1020 1021 1022 1023 1024 1025 1026 1027 1028 1029 1030 1031 1032 1033 1034 1035 1036 1037 1038 1039 1040 1041 1042 1043 1044 1045 1046 1047 1048 1049 1050 1051 1052 1053 1054 1055 1056 1057 1058 1059 1060 1061 1062 1063 1064 1065 1066 1067 1068 1069 1070 1071 1072 1073 1074 1075 1076 1077 1078 1079 1080 1081 1082 1083 1084 1085 1086 1087 1088 1089 1090 1091 1092 1093 1094 1095 1096 1097 1098 1099 1100 1101 1102 1103 1104 1105 1106 1107 1108 1109 1110 1111 1112 1113 1114 1115 1116 1117 1118 1119 1120 1121 1122 1123 1124 1125 1126 1127 1128 1129 1130 1131 1132 1133 1134 1135 1136 1137 1138 1139 1140 1141 1142 1143 1144 1145 1146 1147 1148 1149 1150 1151 1152 1153 1154 1155 1156 1157 1158 1159 1160 1161 1162 1163 1164 1165 1166 1167 1168 1169 1170 1171 1172 1173 1174 1175 1176 1177 1178 1179 1180 1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192 1193 1194 1195 1196 1197 1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216 1217 1218 1219 1220 1221 1222 1223 1224 1225 1226 1227 1228 1229 1230 1231 1232 1233 1234 1235 1236 1237 1238 1239 1240 1241 1242 1243 1244 1245 1246 1247 1248 1249 1250 1251 1252 1253 1254 1255 1256 1257 1258 1259 1260 1261 1262 1263 1264 1265 1266 1267 1268 1269 1270 1271 1272 1273 1274 1275 1276 1277 1278 1279 1280 1281 1282 1283 1284 1285 1286 1287 1288 1289 1290 1291 1292 1293 1294 1295 1296 1297 1298 1299 1300 1301 1302 1303 1304 1305 1306 1307 1308 1309 1310 1311 1312 1313 1314 1315 1316 1317 1318 1319 1320 1321 1322 1323 1324 1325 1326 1327 1328 1329 1330 1331 1332 1333 1334 1335 1336 1337 1338 1339 1340 1341 1342 1343 1344 1345 1346 1347 1348 1349 1350 1351 1352 1353 1354 1355 1356 1357 1358 1359 1360 1361 1362 1363 1364 1365 1366 1367 1368 1369 1370 1371 1372 1373 1374 1375 1376 1377 1378 1379 1380 1381 1382 1383 1384 1385 1386 1387 1388 1389 1390 1391 1392 1393 1394 1395 1396 1397 1398 1399 1400 1401 1402 1403 1404 1405 1406 1407 1408 1409 1410 1411 1412 1413 1414 1415 1416 1417 1418 1419 1420 1421 1422 1423 1424 1425 1426 1427 1428 1429 1430 1431 1432 1433 1434 1435 1436 1437 1438 1439 1440 1441 1442 1443 1444 1445 1446 1447 1448 1449 1450 1451 1452 1453 1454 1455 1456 1457 1458 1459 1460 1461 1462 1463 1464 1465 1466 1467 1468 1469 1470 1471 1472 1473 1474 1475 1476 1477 1478 1479 1480 1481 1482 1483 1484 1485 1486 1487 1488 1489 1490 1491 1492 1493 1494 1495 1496 1497 1498 1499 1500 1501 1502 1503 1504 1505 1506 1507 1508 1509 1510 1511 1512 1513 1514 1515 1516 1517 1518 1519 1520 1521 1522 1523 1524 1525 1526 1527 1528 1529 1530 1531 1532 1533 1534 1535 1536 1537 1538 1539 1540 1541 1542 1543 1544 1545 1546 1547 1548 1549 1550 1551 1552 1553 1554 1555 1556 1557 1558 1559 1560 1561 1562 1563 1564 1565 1566 1567 1568 1569 1570 1571
|
=begin
= PL/Ruby
* ((<Defining function in PL Ruby>))
* ((<Function returning SET (SFRM Materialize)>))
* ((<Function returning SET (ExprMultiResult)>))
* ((<Trigger procedures in PL Ruby>))
* ((<plruby_singleton_methods>))
* ((<Conversion>))
* ((<Class and modules>))
* ((<module PL>)) : general module
* ((<class PL::Plan>)) : class for prepared plans
* ((<class PL::Cursor>)) : class for cursors
* ((<class PL::Transaction>)) : class for transactions (8.0)
* ((<class BitString>))
* ((<class Tinterval>))
* ((<class NetAddr>))
* ((<class MacAddr>))
* ((<class Box>))
* ((<class Circle>))
* ((<class Path>))
* ((<class Point>))
* ((<class Polygon>))
* ((<class Segment>))
PL/Ruby is a loadable procedural language for the Postgres database
system that enable the Ruby language to create functions and trigger
procedures
Functions and triggers are singleton methods of the module PLtemp.
= WARNING
((*if PL/Ruby was compiled with ((%--disable-conversion%)),
all arguments (to the function or the triggers) are passed as string
values, except for NULL values represented by ((%Qnil%)).*))
((*In this case you must explicitely call a conversion function (like to_i)
if you want to use an argument as an integer*))
== Defining function in PL Ruby
To create a function in the PL/Ruby language use the syntax
CREATE FUNCTION funcname(arguments_type) RETURNS type AS '
# PL/Ruby function body
' LANGUAGE 'plruby';
when calling the function in a query, the arguments are given
in the array ((%args%)). To create a little max
function returning the higher of two int4 values write :
CREATE FUNCTION ruby_max(int4, int4) RETURNS int4 AS '
if args[0] > args[1]
return args[0]
else
return args[1]
end
' LANGUAGE 'plruby';
Tuple arguments are given as hash. Here is an example that defines
the overpaid_2 function (as found in the older Postgres documentation)
in PL/Ruby.
CREATE FUNCTION overpaid_2 (EMP) RETURNS bool AS '
args[0]["salary"] > 200000 ||
(args[0]["salary"] > 100000 && args[0]["age"] < 30)
' LANGUAGE 'plruby';
=== Warning : with PostgreSQL >= 7.4 "array" are given as a ruby Array
For example to define a function (int4[], int4) and return int4[],
in version < 7.4 you write
CREATE FUNCTION ruby_int4_accum(_int4, int4) RETURNS _int4 AS '
if /\\{(\\d+),(\\d+)\\}/ =~ args[0]
a, b = $1, $2
newsum = a + args[1]
newcnt = b + 1
else
raise "unexpected value #{args[0]}"
end
"{#{newsum},#{newcnt}}"
' LANGUAGE 'plruby';
This must now (>= 7.4) be written
CREATE FUNCTION ruby_int4_accum(_int4, int4) RETURNS _int4 AS '
a = args[0]
[a[0] + args[1], a[1] + 1]
' LANGUAGE 'plruby';
=== Release PostgreSQL 8.0
With this version, plruby can have named arguments and the previous functions
can be written
CREATE FUNCTION ruby_max(a int4, b int4) RETURNS int4 AS '
if a > b
a
else
b
end
' LANGUAGE 'plruby';
CREATE FUNCTION overpaid_2 (emp EMP) RETURNS bool AS '
emp["salary"] > 200000 ||
(emp["salary"] > 100000 && emp["age"] < 30)
' LANGUAGE 'plruby';
With this version, you can also use transaction. For example
plruby_test=# create table tu (a int, b int);
CREATE TABLE
plruby_test=# create or replace function tt(abort bool) returns bool as '
plruby_test'# transaction do |txn|
plruby_test'# PL.exec("insert into tu values (1, 2)")
plruby_test'# transaction do |txn1|
plruby_test'# PL.exec("insert into tu values (3, 4)")
plruby_test'# txn1.abort
plruby_test'# end
plruby_test'# PL.exec("insert into tu values (5, 6)")
plruby_test'# txn.abort if abort
plruby_test'# end
plruby_test'# abort
plruby_test'# ' language 'plruby';
CREATE FUNCTION
plruby_test=#
plruby_test=# select tt(true);
tt
----
t
(1 row)
plruby_test=# select * from tu;
a | b
---+---
(0 rows)
plruby_test=# select tt(false);
tt
----
f
(1 row)
plruby_test=# select * from tu;
a | b
---+---
1 | 2
5 | 6
(2 rows)
plruby_test=#
== Function returning SET (SFRM Materialize)
The return type must be declared as SETOF
The function must call ((%yield%)) to return rows or return a String which
must be a valid SELECT statement
For example to concatenate 2 rows create the function
plruby_test=# CREATE FUNCTION tu(varchar) RETURNS setof record
plruby_test-# AS '
plruby_test'# size = PL.column_name(args[0]).size
plruby_test'# res = nil
plruby_test'# PL::Plan.new("select * from #{args[0]}",
plruby_test'# "block" => 50).each do |row|
plruby_test'# if res.nil?
plruby_test'# res = row.values
plruby_test'# else
plruby_test'# res.concat row.values
plruby_test'# yield res
plruby_test'# res = nil
plruby_test'# end
plruby_test'# end
plruby_test'# if res
plruby_test'# res.concat Array.new(size)
plruby_test'# yield res
plruby_test'# end
plruby_test'# ' language 'plruby';
CREATE FUNCTION
plruby_test=#
plruby_test=# select * from tt;
a | b
---+----
1 | 2
3 | 4
5 | 6
7 | 8
9 | 10
(5 rows)
plruby_test=# select * from tu('tt') as tbl(a int, b int, c int, d int);
a | b | c | d
---+----+---+---
1 | 2 | 3 | 4
5 | 6 | 7 | 8
9 | 10 | |
(3 rows)
plruby_test=#
== Function returning SET (ExprMultiResult)
The return type must be declared as SETOF
The function is called until it returns nil
The method PL#context and PL#context= give the possibility to store information
between the call
For example
plruby_test=# create or replace function vv(int) returns setof int as '
plruby_test'# i = PL.context || 0
plruby_test'# if i >= args[0]
plruby_test'# nil
plruby_test'# else
plruby_test'# PL.context = i + 1
plruby_test'# end
plruby_test'# ' language plruby;
CREATE FUNCTION
plruby_test=#
plruby_test=# select * from uu;
b
---
2
(1 row)
plruby_test=#
plruby_test=# select *,vv(3) from uu;
b | vv
---+----
2 | 1
2 | 2
2 | 3
(3 rows)
plruby_test=#
== Trigger procedures in PL Ruby
Trigger procedures are defined in Postgres as functions without
arguments and a return type of trigger. In PL/Ruby the procedure is
called with 4 arguments :
:new (hash, tainted)
an hash containing the values of the new table row on INSERT/UPDATE
actions, or empty on DELETE.
:old (hash, tainted)
an hash containing the values of the old table row on UPDATE/DELETE
actions, or empty on INSERT
:args (array, tainted, frozen)
An array of the arguments to the procedure as given in the CREATE
TRIGGER statement
:tg (hash, tainted, frozen)
The following keys are defined
:name
The name of the trigger from the CREATE TRIGGER statement.
:relname
The name of the relation who has fired the trigger
:relid
The object ID of the table that caused the trigger procedure to be invoked.
:relatts
An array containing the name of the tables field.
:when
The constant ((%PL::BEFORE%)), ((%PL::AFTER%)) or
((%PL::UNKNOWN%)) depending on the event of the trigger call.
:level
The constant ((%PL::ROW%)) or ((%PL::STATEMENT%))
depending on the event of the trigger call.
:op
The constant ((%PL::INSERT%)), ((%PL::UPDATE%)) or
((%PL::DELETE%)) depending on the event of the trigger call.
The return value from a trigger procedure is one of the constant
((%PL::OK%)) or ((%PL::SKIP%)), or an hash. If the
return value is ((%PL::OK%)), the normal operation
(INSERT/UPDATE/DELETE) that fired this trigger will take
place. Obviously, ((%PL::SKIP%)) tells the trigger manager to
silently suppress the operation. The hash tells
PL/Ruby to return a modified row to the trigger manager that will be
inserted instead of the one given in ((%new%)) (INSERT/UPDATE
only). Needless to say that all this is only meaningful when the
trigger is BEFORE and FOR EACH ROW.
Here's a little example trigger procedure that forces an integer
value in a table to keep track of the # of updates that are performed
on the row. For new row's inserted, the value is initialized to 0 and
then incremented on every update operation :
CREATE FUNCTION trigfunc_modcount() RETURNS TRIGGER AS '
case tg["op"]
when PL::INSERT
new[args[0]] = 0
when PL::UPDATE
new[args[0]] = old[args[0]] + 1
else
return PL::OK
end
new
' LANGUAGE 'plruby';
CREATE TABLE mytab (num int4, modcnt int4, descr text);
CREATE TRIGGER trig_mytab_modcount BEFORE INSERT OR UPDATE ON mytab
FOR EACH ROW EXECUTE PROCEDURE trigfunc_modcount('modcnt');
A more complex example (extract from test_setup.sql in the distribution)
which use the global variable ((%$Plans%)) to store a prepared
plan
create function trig_pkey2_after() returns trigger as '
if ! $Plans.key?("plan_dta2_upd")
$Plans["plan_dta2_upd"] =
PL::Plan.new("update T_dta2
set ref1 = $3, ref2 = $4
where ref1 = $1 and ref2 = $2",
["int4", "varchar", "int4", "varchar" ]).save
$Plans["plan_dta2_del"] =
PL::Plan.new("delete from T_dta2
where ref1 = $1 and ref2 = $2",
["int4", "varchar"]).save
end
old_ref_follow = false
old_ref_delete = false
case tg["op"]
when PL::UPDATE
new["key2"] = new["key2"].upcase
old_ref_follow = (new["key1"] != old["key1"]) ||
(new["key2"] != old["key2"])
when PL::DELETE
old_ref_delete = true
end
if old_ref_follow
n = $Plans["plan_dta2_upd"].exec([old["key1"], old["key2"], new["key1"],
new["key2"]])
warn "updated #{n} entries in T_dta2 for new key in T_pkey2" if n != 0
end
if old_ref_delete
n = $Plans["plan_dta2_del"].exec([old["key1"], old["key2"]])
warn "deleted #{n} entries from T_dta2" if n != 0
end
PL::OK
' language 'plruby';
create trigger pkey2_after after update or delete on T_pkey2
for each row execute procedure
trig_pkey2_after();
== plruby_singleton_methods
Sometime it can be usefull to define methods (in pure Ruby) which can be
called from a PL/Ruby function or a PL/Ruby trigger.
In this case, you have 2 possibilities
* the "stupid" way (({:-) :-) :-)}))
just close the current definition of the function (or trigger) with a
(({end})) and define your singleton method without the final (({end}))
Here a small and useless example
plruby_test=# CREATE FUNCTION tutu() RETURNS int4 AS '
plruby_test'# toto(1, 3) + toto(4, 4)
plruby_test'# end
plruby_test'#
plruby_test'# def PLtemp.toto(a, b)
plruby_test'# a + b
plruby_test'# ' LANGUAGE 'plruby';
CREATE
plruby_test=# select tutu();
tutu
----
12
(1 row)
plruby_test=#
* create a table plruby_singleton_methods with the columns (name, args, body)
At load time, PL/Ruby look if it exist a table plruby_singleton_methods and if
found try, for each row, to define singleton methods with the template :
def PLtemp.#{name} (#{args})
#{body}
end
The previous example can be written (you have a more complete example in
test/plp/test_setup.sql)
plruby_test=# SELECT * FROM plruby_singleton_methods;
name|args|body
----+----+-----
toto|a, b|a + b
(1 row)
plruby_test=# CREATE FUNCTION tutu() RETURNS int4 AS '
plruby_test'# toto(1, 3) + toto(4, 4)
plruby_test'# ' LANGUAGE 'plruby';
CREATE
plruby_test=# select tutu();
tutu
----
12
(1 row)
plruby_test=#
* Another example, if PLRuby was compiled with --enable-conversion and it
exist a column with the name '***' then it can create a singleton method
from a PLRuby function
plruby_test=# select * from plruby_singleton_methods;
name | args | body
------+------+------
*** | |
(1 row)
plruby_test=# create function add_value(int, int) returns int as '
plruby_test'# args[0] + args[1]
plruby_test'# ' language 'plruby';
CREATE FUNCTION
plruby_test=#
plruby_test=# select add_value(10, 2);
add_value
-----------
12
(1 row)
plruby_test=#
plruby_test=# create function add_one(int) returns int as '
plruby_test'# add_value(args[0], 1)
plruby_test'# ' language 'plruby';
CREATE FUNCTION
plruby_test=#
plruby_test=# select add_one(11);
add_one
---------
12
(1 row)
plruby_test=#
== Conversion
If the conversions was not disabled (--disable-conversion), the following
conversions are made
PostgreSQL Ruby
---------- ----
OID Fixnum
INT2OID Fixnum
INT4OID Fixnum
INT8OID Fixnum (or Bignum)
FLOAT4OID Float
FLOAT8OID Float
CASHOID Float
NUMERICOID Float
BOOLOID true, false
ABSTIMEOID Time
RELTIMEOID Time
TIMEOID Time
TIMETZOID Time
TIMESTAMPOID Time
TIMESTAMPTZOID Time
DATEOID Time
INTERVALOID Time
TINTERVALOID Tinterval (new Ruby class)
BITOID BitString (new Ruby class)
VARBITOID BitString (new Ruby class)
INETOID NetAddr (new Ruby class)
CIDROID NetAddr (new Ruby class)
MACADDROID MacAddr (new Ruby class)
POINTOID Point (new Ruby class)
LSEGOID Segment (new Ruby class)
BOXOID Box (new Ruby class)
PATHOID Path (new Ruby class)
POLYGONOID Polygon (new Ruby class)
CIRCLEOID Circle (new Ruby class)
all others OID are converted to a String object
== Class and modules
=== Global
--- transaction {|txn| }
create a new transaction, yield an object ((%PL::Transaction%))
--- warn [level], message
Ruby interface to PostgreSQL elog()
Possible value for ((%level%)) are ((%NOTICE%)), ((%DEBUG%)) and ((%NOIND%))
Use ((%raise()%)) if you want to simulate ((%elog(ERROR, "...")%))
--- $Plans (hash, tainted)
can be used to store prepared plans.
=== module PL
general module
--- args_type
Return the type of the arguments given to the function
--- column_name(table)
Return the name of the columns for the table
--- column_type(table)
return the type of the columns for the table
--- context
Return the context (or nil) associated with a SETOF function
(ExprMultiResult)
--- context=
Set the context for a SETOF function (ExprMultiResult)
--- quote(string)
Duplicates all occurences of single quote and backslash
characters. It should be used when variables are used in the query
string given to spi_exec or spi_prepare (not for the value list on
execp).
--- result_name
Return the name of the columns for a function returning a SETOF
--- result_type
Return the type of the columns for a function returning a SETOF
or the type of the return value
--- result_size
Return the number of columns for a function returning a SETOF
--- result_description
Return the table description given to a function returning a SETOF
--- exec(string [, count [, type]])
--- spi_exec(string [, count [, type]])
Call parser/planner/optimizer/executor for query. The optional
((%count%)) value tells spi_exec the maximum number of rows to be
processed by the query.
:SELECT
If the query is a SELECT statement, an array is return (if count is
not specified or with a value > 1). Each element of this array is an
hash where the key is the column name.
If type is specified it can take the value
* "array" return for each column an array with the element
["name", "value", "type", "len", "typeid"]
* "hash" return for each column an hash with the keys
{"name", "value", "type", "len", "typeid"}
* "value" return all values
For example this procedure display all rows in the table pg_table.
CREATE FUNCTION pg_table_dis() RETURNS int4 AS '
res = PLruby.exec("select * from pg_class")
res.each do |x|
warn "======================"
x.each do |y, z|
warn "name = #{y} -- value = #{z}"
end
warn "======================"
end
return res.size
' LANGUAGE 'plruby';
A block can be specified, in this case a call to yield() will be
made.
If count is specified with the value 1, only the first row (or
FALSE if it fail) is returned as a hash. Here a little example :
CREATE FUNCTION pg_table_dis() RETURNS int4 AS '
PL.exec("select * from pg_class", 1) { |y, z|
warn "name = #{y} -- value = #{z}"
}
return 1
' LANGUAGE 'plruby';
Another example with count = 1
create table T_pkey1 (
skey1 int4,
skey2 varchar(20),
stxt varchar(40)
);
create function toto() returns bool as '
warn("=======")
PL.exec("select * from T_pkey1", 1, "hash") do |a|
warn(a.inspect)
end
warn("=======")
PL.exec("select * from T_pkey1", 1, "array") do |a|
warn(a.inspect)
end
warn("=======")
PL.exec("select * from T_pkey1", 1) do |a|
warn(a.inspect)
end
warn("=======")
return true
' language 'plruby';
plruby_test=# select toto();
NOTICE: =======
NOTICE: {"name"=>"skey1", "typeid"=>23, "type"=>"int4", "value"=>"12", "len"=>4}
NOTICE: {"name"=>"skey2", "typeid"=>1043, "type"=>"varchar", "value"=>"a", "len"=>20}
NOTICE: {"name"=>"stxt", "typeid"=>1043, "type"=>"varchar", "value"=>"b", "len"=>40}
NOTICE: =======
NOTICE: ["skey1", "12", "int4", 4, 23]
NOTICE: ["skey2", "a", "varchar", 20, 1043]
NOTICE: ["stxt", "b", "varchar", 40, 1043]
NOTICE: =======
NOTICE: ["skey1", "12"]
NOTICE: ["skey2", "a"]
NOTICE: ["stxt", "b"]
NOTICE: =======
toto
------
t
(1 row)
plruby_test=#
:SELECT INTO, INSERT, UPDATE, DELETE
return the number of rows insered, updated, deleted, ...
:UTILITY
return TRUE
--- prepare(string[, types])
--- spi_prepare(string[, types])
--- prepare(string, "types" => types, "count" => count, "output" => type, "tmp" => true)
Deprecated : See ((%PL::Plan::new%)) and ((%PL::Plan#save%))
Prepares AND SAVES a query plan for later execution. It is a bit
different from the C level SPI_prepare in that the plan is
automatically copied to the toplevel memory context.
If the query references arguments, the type names must be given as a
Ruby array of strings. The return value from prepare is a
((%PL::Plan%)) object to be used in subsequent calls to
((%PL::Plan#exec%)).
If the hash given has the keys ((%count%)), ((%output%)) these values
will be given to the subsequent calls to ((%each%))
=== class PL::Plan
class for prepared plan
--- initialize(string, "types" => types, "count" => count, "output" => type, "save" => false)
Prepares a query plan for later execution.
If the query references arguments, the type names must be given as a
Ruby array of strings.
If the hash given has the keys ((%output%)), ((%count%)) these values
will be given to the subsequent calls to ((%each%))
If ((%"save"%)) as a true value, the plan will be saved
--- exec(values, [count [, type]])
--- execp(values, [count [, type]])
--- exec("values" => values, "count" => count, "output" => type)
--- execp("values" => values, "count" => count, "output" => type)
Execute a prepared plan from ((%PL::PLan::new%)) with variable
substitution. The optional ((%count%)) value tells
((%PL::Plan#exec%)) the maximum number of rows to be processed by the
query.
If there was a typelist given to ((%PL::Plan::new%)), an array
of ((%values%)) of exactly the same length must be given to
((%PL::Plan#exec%)) as first argument. If the type list on
((%PL::Plan::new%)) was empty, this argument must be omitted.
If the query is a SELECT statement, the same as described for
((%PL#exec%)) happens for the loop-body and the variables for
the fields selected.
If type is specified it can take the values
* "array" return an array with the element ["name", "value", "type", "len", "typeid"]
* "hash" return an hash with the keys {"name", "value", "type", "len", "typeid"}
* "value" return an array with all values
Here's an example for a PL/Ruby function using a prepared plan :
CREATE FUNCTION t1_count(int4, int4) RETURNS int4 AS '
if ! $Plans.key?("plan")
# prepare the saved plan on the first call
$Plans["plan"] = PL::Plan.new("SELECT count(*) AS cnt FROM t1
WHERE num >= $1 AND num <= $2",
["int4", "int4"]).save
end
n = $Plans["plan"].exec([args[0], args[1]], 1)
n["cnt"]
' LANGUAGE 'plruby';
--- cursor(name = nil, "values" => values, "output" => type)
Create a new object PL::Cursor
If output is specified it can take the values
* "array" return an array with the element ["name", "value", "type", "len", "typeid"]
* "hash" return an hash with the keys {"name", "value", "type", "len", "typeid"}
* "value" return an array with all values
If there was a typelist given to ((%PL::Plan::new%)), an array
of ((%values%)) of exactly the same length must be given to
((%PL::Plan#cursor%))
--- each(values, [count [, type ]]) { ... }
--- fetch(values, [count [, type ]]) { ... }
--- each("values" => values, "count" => count, "output" => type) { ... }
--- fetch("values" => values, "count" => count, "output" => type) { ... }
Same then #exec but a call to SPI_cursor_open(), SPI_cursor_fetch() is made.
Can be used only with a block and a SELECT statement
create function toto() returns bool as '
plan = PL::Plan.new("select * from T_pkey1")
warn "=====> ALL"
plan.each do |x|
warn(x.inspect)
end
warn "=====> FIRST 2"
plan.each("count" => 2) do |x|
warn(x.inspect)
end
return true
' language 'plruby';
plruby_test=# select * from T_pkey1;
skey1 | skey2 | stxt
-------+-------+------
12 | a | b
24 | c | d
36 | e | f
(3 rows)
plruby_test=#
plruby_test=# select toto();
NOTICE: =====> ALL
NOTICE: {"skey1"=>"12", "skey2"=>"a", "stxt"=>"b"}
NOTICE: {"skey1"=>"24", "skey2"=>"c", "stxt"=>"d"}
NOTICE: {"skey1"=>"36", "skey2"=>"e", "stxt"=>"f"}
NOTICE: =====> FIRST 2
NOTICE: {"skey1"=>"12", "skey2"=>"a", "stxt"=>"b"}
NOTICE: {"skey1"=>"24", "skey2"=>"c", "stxt"=>"d"}
toto
------
t
(1 row)
plruby_test=#
--- release
Release a query plan
--- save
Save a query plan for later execution. The plan is copied to the
toplevel memory context.
=== class PL::Cursor
A cursor is created with the method PL::Plan#cursor
--- close
Closes a cursor
--- each {|row| ... }
Iterate over all rows (forward)
--- fetch(count = 1)
--- row(count = 1)
Fetches some rows from a cursor
if count > 0 fetch forward else backward
--- move(count)
Move a cursor : if count > 0 move forward else backward
--- reverse_each {|row| ... }
Iterate over all rows (backward)
--- rewind
Positions the cursor at the beginning of the table
=== class PL::Transaction
a transaction is created with the global function ((%transaction()%)). Only
available with PostgreSQL >= 8.0
--- abort
Abort the transaction
--- commit
Commit the transaction
=== class BitString
The class BitString implement the PostgreSQL type ((|bit|))
and ((|bit varying|))
The modules Comparable and Enumerable are included
--- from_string(string, length = strlen(string))
Convert a ((|String|)) to a ((|BitString|))
--- <=>(other)
comparison function for 2 ((|BitString|)) objects
All bits are considered and additional zero bits may make one string
smaller/larger than the other, even if their zero-padded values would
be the same.
--- +(other)
Concatenate ((|self|)) and ((|other|))
--- &(other)
AND operator
--- |(other)
OR operator
--- ^(other)
XOR operator
--- ~
NOT operator
--- <<(lshft)
LEFT SHIFT operator
--- >>(rshft)
RIGHT SHIFT operator
--- [](*args)
Element reference with the same syntax that for a ((|String|)) object
Return a ((|BitString|)) or a ((|Fixnum|)) 0, 1
bitstring[fixnum]
bitstring[fixnum, fixnum]
bitstring[range]
bitstring[regexp]
bitstring[regexp, fixnum]
bitstring[string]
bitstring[other_bitstring]
--- []=(*args)
Element assignment with the same syntax that for a ((|String|)) object
bitstring[fixnum] = fixnum
bitstring[fixnum] = string_or_bitstring
bitstring[fixnum, fixnum] = string_or_bitstring
bitstring[range] = string_or_bitstring
bitstring[regexp] = string_or_bitstring
bitstring[regexp, fixnum] = string_or_bitstring
bitstring[other_str] = string_or_bitstring
--- concat(other)
append ((|other|)) to ((|self|))
--- each
iterate other each bit
--- include?(other)
return ((|true|)) if ((|other|)) is included in ((|self|))
--- index(other)
return the position of ((|other|)) in ((|self|))
return ((|nil|)) if ((|other|)) is not included in ((|self|))
--- initialize(init, nbits = -1)
create a new ((|BitString|)) object with ((|nbits|)) bits
((|init|)) can be a ((|Fixnum|)) or a ((|String|))
For a ((|String|)) the first character can be 'x', 'X' for and
hexadecimal representation, or 'b', 'B' for a binary representation.
The default is a binary representation
--- length
return the length of ((|self|)) in bits
--- octet_length
return the length of ((|self|)) in octets
--- push(other)
append ((|other|)) to ((|self|))
--- to_i
convert ((|self|)) to a ((|Fixnum|))
--- to_s
convert ((|self|)) to a ((|String|))
=== class NetAddr
The class NetAddr implement the PostgreSQL type ((|inet|))
and ((|cidr|))
The module Comparable is included
--- from_string(string, cidr = false)
Convert a ((|String|)) to a ((|NetAddr|))
--- <=>(other)
comparison function for 2 ((|NetAddr|)) objects
comparison is first on the common bits of the network part, then on
the length of the network part, and then on the whole unmasked address.
--- abbrev
return the abbreviated display format as a ((|String|)) object
--- broadcast
return the broadcast address from the network
--- contain?(other)
return true if ((|other|)) is included in ((|self|))
--- contain_or_equal?(other)
return true if ((|other|)) is included in ((|self|)), or equal
--- contained?(other)
return true if ((|self|)) is included in ((|other|))
--- contained_or_equal?(other)
return true if ((|self|)) is included in ((|other|)), or equal
--- family
return the String "AF_INET" or "AF_INET6"
--- first
return the first address in the network
--- host
extract the IP address and return it as a ((|String|))
--- hostmask
return the host mask for network
--- initialize(string, cidr = false)
create a ((|NetAddr|)) from a ((|String|))
--- last
return the last address in the network
--- masklen
return the length of the netmask
--- netmask
return the netmask for the network
--- network
return the network part of the address
--- set_masklen(len)
return a new ((|NetAddr|)) with netmask length ((|len|))
--- to_s
return the string representation of the address
=== class MacAddr
The MacAddr implement the PostgreSQL type ((|macaddr|))
The module Comparable is included
--- from_string(string, cidr = false)
Convert a ((|String|)) to a ((|MacAddr|))
--- <=>(other)
comparison function for 2 ((|MacAddr|)) objects
--- initialize(string)
create a ((|MacAddr|)) from a ((|String|))
--- to_s
return the string representation of the MAC address
--- truncate
return a new object with the last 3 bytes set to zero
=== class Tinterval
The Tinterval implement the PostgreSQL type ((|tinterval|))
--- from_string(string)
Convert a ((|String|)) (PostgreSQL representation)
to a ((|Tinterval|))
--- high
return a ((|Time|)) which is the high value of the interval
--- high=(time)
set the high value for the interval
--- initialize(low, high)
create a ((|Tinterval|)) with the 2 ((|Time|)) objects
((|low|)) and ((|high|))
--- low
return a ((|Time|)) which is the low value of the interval
--- low=(time)
set the low value for the interval
--- to_s
return the string representation of the object
=== class Box
The Box implement the PostgreSQL type ((|box|))
The module Comparable is included
--- from_string(string)
Convert a ((|String|)) (PostgreSQL representation)
to a ((|Box|)) object
--- +(point)
translate (right, up) ((|self|))
--- -(point)
translate (left, down) ((|self|))
--- *(point)
scale and rotate ((|self|))
--- /(point)
scale and rotate ((|self|))
--- ===(other)
return true if the 2 boxes ((|self|)) and ((|other|)) are identical
--- <=>(other)
comparison operator for 2 Box based on the area of the 2 objects, i.e.
self.area <=> box.area
--- above?(other)
return true if ((|self|)) is above ((|other|))
--- area
return the area of the Box
--- below?(other)
return true if ((|self|)) is below ((|other|))
--- center
return the center point of the Box
--- closest(other)
closest point to ((|other|))
((|other|)) can be a Point, or Segment
--- contain?(other)
return true if ((|self|)) contain ((|other|))
--- contained?(other)
return true if ((|self|)) is contained by ((|other|))
--- diagonal
return a line Segment which happens to be the
positive-slope diagonal of Box
--- height
return the height of the Box (vertical magnitude)
--- in?(other)
return true if ((|self|)) is contained by ((|other|))
--- initialize(*args)
create a new Box object
((|args|)) can be 2 Point objects (low, high) or 4 Float objects
(low.x, low.y, high.x, high.y)
--- intersection(other)
returns the overlapping portion of two boxes,
or ((|nil|)) if they do not intersect.
--- intersect?(segment)
returns true if the Segment ((|segment|))
intersect with the Box
Segment completely inside box counts as intersection.
If you want only segments crossing box boundaries,
try converting Box to Path first.
--- left?(other)
return true if ((|self|)) is strictly left of ((|other|))
--- overlap?(other)
return true if ((|self|)) overlap ((|other|))
--- overleft?(other)
return true if the right edge of ((|self|)) is to the left of
the right edge of ((|other|))
--- overright?(other)
return true if the left edge of ((|self|)) is to the right of
the left edge of ((|other|))
--- right?(other)
return true if ((|self|)) is strictly right of ((|other|))
--- same?(other)
return true if the 2 boxes ((|self|)) and ((|other|)) are identical
--- to_circle
convert a Box to a Circle
--- to_point
return the center Point of the Box
--- to_polygon
convert a Box to a Polygon
--- to_segment
return a line Segment which happens to be the
positive-slope diagonal of Box
--- width
return the width of the Box (horizontal magnitude)
=== class Path
The Path implement the PostgreSQL type ((|path|))
The module Comparable is included
--- from_string(string)
Convert a ((|String|)) (PostgreSQL representation)
to a ((|Path|))
--- <<(path)
concatenate the two paths (only if they are both open)
--- +(point)
translate (right, up) ((|self|))
--- -(point)
translate (left, down) ((|self|))
--- *(point)
scale and rotate ((|self|))
--- /(point)
scale and rotate ((|self|))
--- <=>(other)
comparison function based on the path cardinality, i.e.
self.npoints <=> other.npoints
--- close
make a closed path
--- closed?
return true if ((|self|)) is a closed path
--- concat(path)
concatenate the two paths (only if they are both open)
--- initialize(points, closed = false)
create a new Path object from the Array of Point ((|points|))
--- length
return the length of ((|self|))
--- npoints
return the path cardinality
--- open
make an open path
--- to_polygon
convert ((|self|)) to a Polygon object
=== class Point
The Point implement the PostgreSQL type ((|point|))
The module Comparable is included
--- from_string(string)
Convert a ((|String|)) (PostgreSQL representation)
to a ((|Point|))
--- +(point)
translate (right, up) ((|self|))
--- -(point)
translate (left, down) ((|self|))
--- *(point)
scale and rotate ((|self|))
--- /(point)
scale and rotate ((|self|))
--- [](indice)
return the coordinate
((|indice|)) can have the value 0 or 1
--- []=(indice, value)
set the coordinate
((|indice|)) can have the value 0 or 1
--- ==(other)
return true if ((|self|)) and ((|other|)) are the same,
i.e. self.x == other.x && self.y == other.y
--- above?(other)
return true if ((|self|)) is above ((|other|)),
i.e. self.y > other.y
--- below?(other)
return true if ((|self|)) is below ((|other|)),
i.e. self.y < other.y
--- contained?(other)
return true if ((|self|)) is contained in ((|other|))
((|other|)) can be Point, Polygon or a Circle object
--- horizontal?(other)
return true if ((|self|)) and ((|other|)) are horizontal,
i.e. self.y == other.y
--- in?(other)
return true if ((|self|)) is contained in ((|other|))
((|other|)) can be Point, Polygon or a Circle object
--- initialize(x, y)
create a Point with the 2 Float object (x, y)
--- left?(other)
return true if ((|self|)) is at the left of ((|other|)),
i.e. self.x < other.x
--- on?(other)
return true if ((|self|)) is on ((|other|))
((|other|)) can be Point, Segment, Box or Path object
--- right?(other)
return true if ((|self|)) is at the right of ((|other|)),
i.e. self.x > other.x
--- vertical?(other)
return true if ((|self|)) and ((|other|)) are vertical,
i.e. self.x == other.x
--- x
return ((|x|)) for ((|self|))
--- x=(value)
set the ((|x|)) value for ((|self|))
--- y
return ((|y|)) for ((|self|))
--- y=(value)
set the ((|y|)) value for ((|self|))
=== class Segment
The Segment implement the PostgreSQL type ((|lseg|))
The module Comparable is included
--- from_string(string)
Convert a ((|String|)) (PostgreSQL representation)
to a ((|Segment|))
--- <=>(other)
comparison function for the 2 segments, returns
0 if self[0] == other[0] && self[1] == other[1]
1 if distance(self[0], self[1]) > distance(other[0], other[1])
-1 if distance(self[0], self[1]) < distance(other[0], other[1])
--- center
return the center of the segment
--- closest(other)
closest point to other
((|other|)) can be a Point, Segment or Box
With a point, take the closest endpoint
if the point is left, right, above, or below the segment, otherwise
find the intersection point of the segment and its perpendicular through
the point.
--- horizontal?
returns true if ((|self|)) is a horizontal Segment
--- initialize(point0, point1)
create a Segment from the 2 Point p0, p1
--- intersect?(other)
returns true if ((|self|)) and ((|other|)) intersect
--- intersection(other)
returns the Point where the 2 Segment ((|self|)) and ((|other|))
intersect or nil
--- length
return the length of ((|self|)), i.e. the distnace between the 2 points
--- on?(other)
return true if ((|self|)) is on ((|other|))
((|other|)) can be a Segment, or a Box object
--- parallel?(other)
returns true if the 2 Segment ((|self|)) and ((|other|))
are parallel
--- perpendicular?(other)
returns true if ((|self|)) is perpendicular to ((|other|))
--- to_point
conversion function to a Point, return the center of the segment
--- vertical?
returns true if ((|self|)) is a vertical Segment
=== class Polygon
The Polygon implement the PostgreSQL type ((|polygon|))
--- from_string(string)
Convert a ((|String|)) (PostgreSQL representation)
to a ((|Polygon|))
--- ==(other)
return true if ((|self|)) is the same as ((|other|)), i.e. all
the points are the same
--- center
return the center of ((|self|)), i.e. create a circle and return its
center
--- contain?(other)
return true if ((|self|)) contains ((|other|))
((|other|)) can be a Point or a Polygon
--- contained?(other)
return true if ((|self|)) is contained in ((|other|)) by determining
if ((|self|)) bounding box is contained by ((|other|))'s bounding box.
--- in?(other)
return true if ((|self|)) is contained in ((|other|)) by determining
if ((|self|)) bounding box is contained by ((|other|))'s bounding box.
--- initialize(points, closed = false)
create a new Polygon object from the Array of Point ((|points|))
--- left?(other)
return true if ((|self|)) is strictly left of ((|other|)), i.e.
the right most point of ((|self|)) is left of the left
most point of ((|other|))
--- overleft?(other)
return true if ((|self|)) is overlapping or left of ((|other|)),
i.e. the left most point of ((|self|)) is left of the right
most point of ((|other|))
--- overright?(other)
return true if ((|self|)) is overlapping or right of ((|other|)),
i.e. the right most point of ((|self|)) is right of the left
most point of ((|other|))
--- overlap?(other)
return true if ((|self|)) and ((|other|)) overlap by determining if
their bounding boxes overlap.
--- npoints
return the number of points in ((|self|))
--- right?(other)
return true if ((|self|)) is strictly right of ((|other|)), i.e.
the left most point of ((|self|)) is right of the left
most point of ((|other|))
--- same?(other)
return true if ((|self|)) is the same as ((|other|)), i.e. all
the points are the same
--- to_box
convert ((|self|)) to a Box
--- to_circle
convert ((|self|)) to a Circle
--- to_path
convert ((|self|)) to a Path
--- to_point
convert ((|self|)) to a Point by returning its center
=== class Circle
The Circle implement the PostgreSQL type ((|circle|))
The module Comparable is included
--- from_string(string)
Convert a ((|String|)) (PostgreSQL representation)
to a ((|Circle|))
--- +(point)
translate (right, up) ((|self|))
--- -(point)
translate (left, down) ((|self|))
--- *(point)
scale and rotate ((|self|))
--- /(point)
scale and rotate ((|self|))
--- <=>(other)
comparison function based on area,
i.e. self.area <=> other.area
--- area
return the area
--- above?(other)
return true if ((|self|)) is entirely above ((|other|))
--- below?(other)
return true if ((|self|)) is entirely below ((|other|))
--- contain?(other)
return true if ((|self|)) contain ((|other|))
--- contained?(other)
return true if ((|self|)) is contained in ((|other|))
--- diameter
return the diameter
--- initialize(center, radius)
create a Circle object with ((|center|)) and ((|radius|))
((|center|)) can be a Point or an Array [x, y]
--- overlap?(other)
return true if ((|self|)) overlap ((|other|))
--- overleft?(other)
return true if the right edge of ((|self|)) is to the left of
the right edge of ((|other|))
--- left?(other)
return true if ((|self|)) is strictly left of ((|other|))
--- overright?(other)
return true if the left edge of ((|self|)) is to the right of
the left edge of ((|other|))
--- radius
return the radius
--- right?(other)
return true if ((|self|)) is strictly right of ((|other|))
--- same?(other)
return true if ((|self|)) is the same than ((|other|)), i.e.
self.center == other.center && self.radius == other.radius
--- to_box
convert ((|self|)) to a Box
--- to_point
convert ((|self|)) to a Point by returning its center
--- to_polygon(npts)
convert ((|self|)) to a Polygon with ((|npts|)) Points
=end
|