/usr/share/perl5/SQL/Abstract/Limit.pm is in libsql-abstract-limit-perl 2:0.14.1-5.
This file is owned by root:root, with mode 0o644.
The actual contents of the file can be viewed below.
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 | package SQL::Abstract::Limit;
use strict;
use warnings;
use Carp();
use DBI::Const::GetInfoType ();
use SQL::Abstract 1.20;
use base 'SQL::Abstract';
=head1 NAME
SQL::Abstract::Limit - portable LIMIT emulation
=cut
our $VERSION = '0.141';
# additions / error reports welcome !
our %SyntaxMap = ( mssql => 'Top',
access => 'Top',
sybase => 'GenericSubQ',
oracle => 'RowNum',
db2 => 'FetchFirst',
ingres => '',
adabasd => '',
informix => 'Skip',
# asany => '',
# more recent MySQL versions support LimitOffset as well
mysql => 'LimitXY',
mysqlpp => 'LimitXY',
maxdb => 'LimitXY', # MySQL
pg => 'LimitOffset',
pgpp => 'LimitOffset',
sqlite => 'LimitOffset',
sqlite2 => 'LimitOffset',
interbase => 'RowsTo',
unify => '',
primebase => '',
mimer => '',
# anything that uses SQL::Statement can use LimitXY, I think
sprite => 'LimitXY',
wtsprite => 'LimitXY',
anydata => 'LimitXY',
csv => 'LimitXY',
ram => 'LimitXY',
dbm => 'LimitXY',
excel => 'LimitXY',
google => 'LimitXY',
);
=head1 SYNOPSIS
use SQL::Abstract::Limit;
my $sql = SQL::Abstract::Limit->new( limit_dialect => 'LimitOffset' );;
# or autodetect from a DBI $dbh:
my $sql = SQL::Abstract::Limit->new( limit_dialect => $dbh );
# or from a Class::DBI class:
my $sql = SQL::Abstract::Limit->new( limit_dialect => 'My::CDBI::App' );
# or object:
my $obj = My::CDBI::App->retrieve( $id );
my $sql = SQL::Abstract::Limit->new( limit_dialect => $obj );
# generate SQL:
my ( $stmt, @bind ) = $sql->select( $table, \@fields, \%where, \@order, $limit, $offset );
# Then, use these in your DBI statements
my $sth = $dbh->prepare( $stmt );
$sth->execute( @bind );
# Just generate the WHERE clause (only available for some syntaxes)
my ( $stmt, @bind ) = $sql->where( \%where, \@order, $limit, $offset );
=head1 DESCRIPTION
Portability layer for LIMIT emulation.
=over 4
=item new( case => 'lower', cmp => 'like', logic => 'and', convert => 'upper', limit_dialect => 'Top' )
All settings are optional.
=over 8
=item limit_dialect
Sets the default syntax model to use for emulating a C<LIMIT $rows OFFSET $offset>
clause. Default setting is C<GenericSubQ>. You can still pass other syntax
settings in method calls, this just sets the default. Possible values are:
LimitOffset PostgreSQL, SQLite
LimitXY MySQL, MaxDB, anything that uses SQL::Statement
LimitYX SQLite (optional)
RowsTo InterBase/FireBird
Top SQL/Server, MS Access
RowNum Oracle
FetchFirst DB2
Skip Informix
GenericSubQ Sybase, plus any databases not recognised by this module
$dbh a DBI database handle
CDBI subclass
CDBI object
other DBI-based thing
The first group are implemented by appending a short clause to the end of the
statement. The second group require more intricate wrapping of the original
statement in subselects.
You can pass a L<DBI|DBI> database handle, and the module will figure out which
dialect to use.
You can pass a L<Class::DBI|Class::DBI> subclass or object, and the module will
find the C<$dbh> and use it to find the dialect.
Anything else based on L<DBI|DBI> can be easily added by locating the C<$dbh>.
Patches or suggestions welcome.
=back
Other options are described in L<SQL::Abstract|SQL::Abstract>.
=item select( $table, \@fields, $where, [ \@order, [ $rows, [ $offset ], [ $dialect ] ] ] )
Same as C<SQL::Abstract::select>, but accepts additional C<$rows>, C<$offset>
and C<$dialect> parameters.
The C<$order> parameter is required if C<$rows> is specified.
The C<$fields> parameter is required, but can be set to C<undef>, C<''> or
C<'*'> (all these get set to C<'*'>).
The C<$where> parameter is also required. It can be a hashref
or an arrayref, or C<undef>.
=cut
sub select {
my $self = shift;
my $table = $self->_table(shift);
my $fields = shift;
my $where = shift; # if ref( $_[0] ) eq 'HASH';
my ( $order, $rows, $offset, $syntax ) = $self->_get_args( @_ );
$fields ||= '*'; # in case someone supplies '' or undef
# with no LIMIT parameters, defer to SQL::Abstract [ don't know why the first way fails ]
# return $self->SUPER::select( $table, $fields, $where, $order ) unless $rows;
return SQL::Abstract->new->select( $table, $fields, $where, $order ) unless $rows;
# with LIMIT parameters, get the basic SQL without the ORDER BY clause
my ( $sql, @bind ) = $self->SUPER::select( $table, $fields, $where );
my $syntax_name = $self->_find_syntax( $syntax );
$sql = $self->_emulate_limit( $syntax_name, $sql, $order, $rows, $offset );
return wantarray ? ( $sql, @bind ) : $sql;
}
=item where( [ $where, [ \@order, [ $rows, [ $offset ], [ $dialect ] ] ] ] )
Same as C<SQL::Abstract::where>, but accepts additional C<$rows>, C<$offset>
and C<$dialect> parameters.
Some SQL dialects support syntaxes that can be applied as simple phrases
tacked on to the end of the WHERE clause. These are:
LimitOffset
LimitXY
LimitYX
RowsTo
This method returns a modified WHERE clause, if the limit syntax is set to one
of these options (either in the call to C<where> or in the constructor), and
if C<$rows> is passed in.
Dies via C<croak> if you try to use it for other syntaxes.
C<$order> is required if C<$rows> is set.
C<$where> is required if any other parameters are specified. It can be a hashref
or an arrayref, or C<undef>.
Returns a regular C<WHERE> clause if no limits are set.
=cut
sub where
{
my $self = shift;
my $where = shift; # if ref( $_[0] ) eq 'HASH';
my ( $order, $rows, $offset, $syntax ) = $self->_get_args( @_ );
my ( $sql, @bind );
if ( $rows )
{
( $sql, @bind ) = $self->SUPER::where( $where );
my $syntax_name = $self->_find_syntax( $syntax );
Carp::croak( "can't build a stand-alone WHERE clause for $syntax_name" )
unless $syntax_name =~ /(?:LimitOffset|LimitXY|LimitYX|RowsTo)/i;
$sql = $self->_emulate_limit( $syntax_name, $sql, $order, $rows, $offset );
}
else
{
#
( $sql, @bind ) = $self->SUPER::where( $where, $order );
}
return wantarray ? ( $sql, @bind ) : $sql;
}
sub _get_args {
my $self = shift;
my $order = shift;
my $rows = shift;
my $offset = shift if ( $_[0] && $_[0] =~ /^\d+$/ );
my $syntax = shift || $self->_default_limit_syntax;
return $order, $rows, $offset, $syntax;
}
=item insert
=item update
=item delete
=item values
=item generate
See L<SQL::Abstract|SQL::Abstract> for these methods.
C<update> and C<delete> are not provided with any C<LIMIT> emulation in this
release, and no support is planned at the moment. But patches would be welcome.
=back
=cut
sub _default_limit_syntax { $_[0]->{limit_dialect} || 'GenericSubQ' }
sub _emulate_limit {
my ( $self, $syntax, $sql, $order, $rows, $offset ) = @_;
$offset ||= 0;
Carp::croak( "rows must be a number (got $rows)" ) unless $rows =~ /^\d+$/;
Carp::croak( "offset must be a number (got $offset)" ) unless $offset =~ /^\d+$/;
my $method = $self->can( 'emulate_limit' ) || "_$syntax";
$sql = $self->$method( $sql, $order, $rows, $offset );
return $sql;
}
sub _find_syntax
{
my ($self, $syntax) = @_;
# $syntax is a dialect name, database name, $dbh, or CDBI class or object
Carp::croak('no syntax') unless $syntax;
my $db;
# note: tests arranged so that the eval isn't run against a scalar $syntax
# see rt #15000
if (ref $syntax) # a $dbh or a CDBI object
{
if ( UNIVERSAL::isa($syntax => 'Class::DBI') )
{
$db = $self->_find_database_from_cdbi($syntax);
}
elsif ( eval { $syntax->{Driver}->{Name} } ) # or use isa DBI::db ?
{
$db = $self->_find_database_from_dbh($syntax);
}
}
else # string - CDBI class, db name, or dialect name
{
if (exists $SyntaxMap{lc $syntax})
{
# the name of a database
$db = $syntax;
}
elsif (UNIVERSAL::isa($syntax => 'Class::DBI'))
{
# a CDBI class
$db = $self->_find_database_from_cdbi($syntax);
}
else
{
# or it's already a syntax dialect
return $syntax;
}
}
return $self->_find_syntax_from_database($db) if $db;
# if you get here, you might like to provide a patch to determine the
# syntax model for your object or ref e.g. by getting at the $dbh stored in it
warn "can't determine syntax model for $syntax - using default";
return $self->_default_limit_syntax;
}
# most of this code modified from DBIx::AnyDBD::rebless
sub _find_database_from_dbh {
my ( $self, $dbh ) = @_;
my $driver = ucfirst( $dbh->{Driver}->{Name} ) || Carp::croak( "no driver in $dbh" );
if ( $driver eq 'Proxy' )
{
# Looking into the internals of DBD::Proxy is maybe a little questionable
( $driver ) = $dbh->{proxy_client}->{application} =~ /^DBI:(.+?):/;
}
# what about DBD::JDBC ?
my ( $odbc, $ado ) = ( $driver eq 'ODBC', $driver eq 'ADO' );
if ( $odbc || $ado )
{
my $name;
# $name = $dbh->func( 17, 'GetInfo' ) if $odbc;
$name = $dbh->get_info( $DBI::Const::GetInfoType::GetInfoType{SQL_DBMS_NAME} ) if $odbc;
$name = $dbh->{ado_conn}->Properties->Item( 'DBMS Name' )->Value if $ado;
die "can't determine driver name for ODBC or ADO handle: $dbh" unless $name;
CASE: {
$driver = 'MSSQL', last CASE if $name eq 'Microsoft SQL Server';
$driver = 'Sybase', last CASE if $name eq 'SQL Server';
$driver = 'Oracle', last CASE if $name =~ /Oracle/;
$driver = 'ASAny', last CASE if $name eq 'Adaptive Server Anywhere';
$driver = 'AdabasD', last CASE if $name eq 'ADABAS D';
# this should catch Access (ACCESS) and Informix (Informix)
$driver = lc( $name );
$driver =~ s/\b(\w)/uc($1)/eg;
$driver =~ s/\s+/_/g;
}
}
die "couldn't find DBD driver in $dbh" unless $driver;
# $driver now holds a string identifying the database server - in the future,
# it might return an object with extra information e.g. version
return $driver;
}
# $cdbi can be a class or object
sub _find_database_from_cdbi
{
my ($self, $cdbi) = @_;
# inherits from Ima::DBI
my ($dbh) = $cdbi->db_handles;
Carp::croak "no \$dbh in $cdbi" unless $dbh;
return $self->_find_database_from_dbh($dbh);
}
# currently expects a string (database moniker), but this may become an object
# with e.g. version string etc.
sub _find_syntax_from_database {
my ( $self, $db ) = @_;
my $syntax = $SyntaxMap{ lc( $db ) };
return $syntax if $syntax;
my $msg = defined $syntax ?
"no dialect known for $db - using GenericSubQ dialect" :
"unknown database $db - using GenericSubQ dialect";
warn $msg;
return 'GenericSubQ';
}
# DBIx::SearchBuilder LIMIT emulation:
# Oracle - RowNum
# Pg - LimitOffset
# Sybase - doesn't emulate
# Informix - First - but can only retrieve 1st page
# SQLite - default
# MySQL - default
# default - LIMIT $offset, $rows
# or LIMIT $rows
# if $offset == 0
# DBIx::Compat also tries, but only for the easy ones
# ---------------------------------
# LIMIT emulation routines
# utility for some emulations
sub _order_directions {
my ( $self, $order ) = @_;
return unless $order;
my $ref = ref $order;
my @order;
CASE: {
@order = @$order, last CASE if $ref eq 'ARRAY';
@order = ( $order ), last CASE unless $ref;
@order = ( $$order ), last CASE if $ref eq 'SCALAR';
Carp::croak __PACKAGE__ . ": Unsupported data struct $ref for ORDER BY";
}
my ( $order_by_up, $order_by_down );
foreach my $spec ( @order )
{
my @spec = split ' ', $spec;
Carp::croak( "bad column order spec: $spec" ) if @spec > 2;
push( @spec, 'ASC' ) unless @spec == 2;
my ( $col, $up ) = @spec; # or maybe down
$up = uc( $up );
Carp::croak( "bad direction: $up" ) unless $up =~ /^(?:ASC|DESC)$/;
$order_by_up .= ", $col $up";
my $down = $up eq 'ASC' ? 'DESC' : 'ASC';
$order_by_down .= ", $col $down";
}
s/^,/ORDER BY/ for ( $order_by_up, $order_by_down );
return $order_by_up, $order_by_down;
}
# From http://phplens.com/lens/adodb/tips_portable_sql.htm
# When writing SQL to retrieve the first 10 rows for paging, you could write...
# Database SQL Syntax
# DB2 select * from table fetch first 10 rows only
# Informix select first 10 * from table
# Microsoft SQL Server and Access select top 10 * from table
# MySQL and PostgreSQL select * from table limit 10
# Oracle 8i select * from (select * from table) where rownum <= 10
=head2 Limit emulation
The following dialects are available for emulating the LIMIT clause. In each
case, C<$sql> represents the SQL statement generated by C<SQL::Abstract::select>,
minus the ORDER BY clause, e.g.
SELECT foo, bar FROM my_table WHERE some_conditions
C<$sql_after_select> represents C<$sql> with the leading C<SELECT> keyword
removed.
C<order_cols_up> represents the sort column(s) and direction(s) specified in
the C<order> parameter.
C<order_cols_down> represents the opposite sort.
C<$last = $rows + $offset>
=over 4
=item LimitOffset
=over 8
=item Syntax
$sql ORDER BY order_cols_up LIMIT $rows OFFSET $offset
or
$sql ORDER BY order_cols_up LIMIT $rows
if C<$offset == 0>.
=item Databases
PostgreSQL
SQLite
=back
=cut
sub _LimitOffset {
my ( $self, $sql, $order, $rows, $offset ) = @_;
$sql .= $self->_order_by( $order ) . " LIMIT $rows";
$sql .= " OFFSET $offset" if +$offset;
return $sql;
}
=item LimitXY
=over 8
=item Syntax
$sql ORDER BY order_cols_up LIMIT $offset, $rows
or
$sql ORDER BY order_cols_up LIMIT $rows
if C<$offset == 0>.
=item Databases
MySQL
=back
=cut
sub _LimitXY {
my ( $self, $sql, $order, $rows, $offset ) = @_;
$sql .= $self->_order_by( $order ) . " LIMIT ";
$sql .= "$offset, " if +$offset;
$sql .= $rows;
return $sql;
}
=item LimitYX
=over 8
=item Syntax
$sql ORDER BY order_cols_up LIMIT $rows, $offset
or
$sql ORDER BY order_cols_up LIMIT $rows
if C<$offset == 0>.
=item Databases
SQLite understands this syntax, or LimitOffset. If autodetecting the
dialect, it will be set to LimitOffset.
=back
=cut
sub _LimitYX {
my ( $self, $sql, $order, $rows, $offset ) = @_;
$sql .= $self->_order_by( $order ) . " LIMIT $rows";
$sql .= " $offset" if +$offset;
return $sql;
}
=item RowsTo
=over 8
=item Syntax
$sql ORDER BY order_cols_up ROWS $offset TO $last
=item Databases
InterBase
FireBird
=back
=cut
# InterBase/FireBird
sub _RowsTo {
my ( $self, $sql, $order, $rows, $offset ) = @_;
my $last = $rows + $offset;
$sql .= $self->_order_by( $order ) . " ROWS $offset TO $last";
return $sql;
}
=item Top
=over 8
=item Syntax
SELECT * FROM
(
SELECT TOP $rows * FROM
(
SELECT TOP $last $sql_after_select
ORDER BY order_cols_up
) AS foo
ORDER BY order_cols_down
) AS bar
ORDER BY order_cols_up
=item Databases
SQL/Server
MS Access
=back
=cut
sub _Top {
my ( $self, $sql, $order, $rows, $offset ) = @_;
my $last = $rows + $offset;
my ( $order_by_up, $order_by_down ) = $self->_order_directions( $order );
$sql =~ s/^\s*(SELECT|select)//;
$sql = <<"";
SELECT * FROM
(
SELECT TOP $rows * FROM
(
SELECT TOP $last $sql $order_by_up
) AS foo
$order_by_down
) AS bar
$order_by_up
return $sql;
}
=item RowNum
=over 8
=item Syntax
Oracle numbers rows from 1, not zero, so here $offset has been incremented by 1.
SELECT * FROM
(
SELECT A.*, ROWNUM r FROM
(
$sql ORDER BY order_cols_up
) A
WHERE ROWNUM <= $last
) B
WHERE r >= $offset
=item Databases
Oracle
=back
=cut
sub _RowNum {
my ( $self, $sql, $order, $rows, $offset ) = @_;
# Oracle orders from 1 not zero
$offset++;
my $last = $rows + $offset;
my $order_by = $self->_order_by( $order );
$sql = <<"";
SELECT * FROM
(
SELECT A.*, ROWNUM r FROM
(
$sql $order_by
) A
WHERE ROWNUM < $last
) B
WHERE r >= $offset
return $sql;
}
# DBIx::SearchBuilder::Handle::Oracle does this:
# Transform an SQL query from:
#
# SELECT main.*
# FROM Tickets main
# WHERE ((main.EffectiveId = main.id))
# AND ((main.Type = 'ticket'))
# AND ( ( (main.Status = 'new')OR(main.Status = 'open') )
# AND ( (main.Queue = '1') ) )
#
# to:
#
# SELECT * FROM (
# SELECT limitquery.*,rownum limitrownum FROM (
# SELECT main.*
# FROM Tickets main
# WHERE ((main.EffectiveId = main.id))
# AND ((main.Type = 'ticket'))
# AND ( ( (main.Status = 'new')OR(main.Status = 'open') )
# AND ( (main.Queue = '1') ) )
# ) limitquery WHERE rownum <= 50
# ) WHERE limitrownum >= 1
#
#if ($per_page) {
# # Oracle orders from 1 not zero
# $first++;
# # Make current query a sub select
# $$statementref = "SELECT * FROM ( SELECT limitquery.*,rownum limitrownum FROM ( $$statementref ) limitquery WHERE rownum <= " . ($first + $per_page - 1) . " ) WHERE limitrownum >= " . $first;
#}
# DBIx::SQLEngine::Driver::Oracle does this:
#sub sql_limit {
# my $self = shift;
# my ( $limit, $offset, $sql, @params ) = @_;
#
# # remove tablealiases and group-functions from outer query properties
# my ($properties) = ($sql =~ /^\s*SELECT\s(.*?)\sFROM\s/i);
# $properties =~ s/[^\s]+\s*as\s*//ig;
# $properties =~ s/\w+\.//g;
#
# $offset ||= 0;
# my $position = ( $offset + $limit );
#
# $sql = <<"";
#SELECT $properties FROM (
# SELECT $properties, ROWNUM AS sqle_position FROM (
# $sql
# )
#)
#WHERE sqle_position > $offset AND sqle_position <= $position
#
# return ($sql, @params);
#}
=item FetchFirst
=over 8
=item Syntax
SELECT * FROM (
SELECT * FROM (
$sql
ORDER BY order_cols_up
FETCH FIRST $last ROWS ONLY
) foo
ORDER BY order_cols_down
FETCH FIRST $rows ROWS ONLY
) bar
ORDER BY order_cols_up
=item Databases
IBM DB2
=back
=cut
sub _FetchFirst {
my ( $self, $sql, $order, $rows, $offset ) = @_;
my $last = $rows + $offset;
my ( $order_by_up, $order_by_down ) = $self->_order_directions( $order );
$sql = <<"";
SELECT * FROM (
SELECT * FROM (
$sql
$order_by_up
FETCH FIRST $last ROWS ONLY
) foo
$order_by_down
FETCH FIRST $rows ROWS ONLY
) bar
$order_by_up
return $sql;
}
=item GenericSubQ
When all else fails, this should work for many databases, but it is probably
fairly slow.
This method relies on having a column with unique values as the first column in
the C<SELECT> clause (i.e. the first column in the C<\@fields> parameter). The
results will be sorted by that unique column, so any C<$order> parameter is
ignored, unless it matches the unique column, in which case the direction of
the sort is honoured.
=over 8
=item Syntax
SELECT field_list FROM $table X WHERE where_clause AND
(
SELECT COUNT(*) FROM $table WHERE $pk > X.$pk
)
BETWEEN $offset AND $last
ORDER BY $pk $asc_desc
C<$pk> is the first column in C<field_list>.
C<$asc_desc> is the opposite direction to that specified in the method call. So
if you want the final results sorted C<ASC>, say so, and it gets flipped
internally, but the results come out as you'd expect. I think.
The C<BETWEEN $offset AND $last> clause is replaced with C<E<lt> $rows> if
<$offset == 0>.
=item Databases
Sybase
Anything not otherwise known to this module.
=back
=cut
sub _GenericSubQ {
my ( $self, $sql, $order, $rows, $offset ) = @_;
my $last = $rows + $offset;
my $order_by = $self->_order_by( $order );
my ( $pk, $table ) = $sql =~ /^\s*SELECT\s+(\w+),?.*\sFROM\s+([\w]+)/i;
#warn "pk: $pk";
#warn "table: $table";
# get specified sort order and swap it to get the expected output (I think?)
my ( $asc_desc ) = $order_by =~ /\b$pk\s+(ASC|DESC)\s*/i;
$asc_desc = uc( $asc_desc ) || 'ASC';
$asc_desc = $asc_desc eq 'ASC' ? 'DESC' : 'ASC';
$sql =~ s/FROM $table /FROM $table X /;
my $limit = $offset ? "BETWEEN $offset AND $last" : "< $rows";
$sql = <<"";
$sql AND
(
SELECT COUNT(*) FROM $table WHERE $pk > X.$pk
)
$limit
ORDER BY $pk $asc_desc
return $sql;
}
=begin notes
1st page:
SELECT id, field1, fieldn
FROM table_xyz X
WHERE
(
SELECT COUNT(*) FROM table_xyz WHERE id > X.id
)
< 100
ORDER BY id DESC
Next page:
SELECT id, field1, fieldn
FROM table_xyz X
WHERE
(
SELECT COUNT(*) FROM table_xyz WHERE id > X.id
)
BETWEEN 100 AND 199
ORDER BY id DESC
http://expertanswercenter.techtarget.com/eac/knowledgebaseAnswer/0,,sid63_gci978197,00.html
We can adapt the generic Top N query to this task. I would not use the generic
method when TOP or LIMIT is available, but you're right, the previous answer
is incomplete without this.
Using the same table and column names, the top 100 ids are given by:
SELECT id, field1, fieldn FROM table_xyz X
WHERE ( SELECT COUNT(*)
FROM table_xyz
WHERE id > X.id ) < 100
ORDER BY id DESC
The subquery is correlated, which means that it will be evaluated for each row
of the outer query. The subquery says "count the number of rows that have an
id that is greater than this id." Note that the sort order is descending, so
we are looking for ids that are greater, i.e. higher up in the result set. If
that number is less than 100, then this row must be one of the top 100. Simple,
eh? Unfortunately, it runs quite slowly. Furthermore, it takes ties into
consideration, which is good, but this means that the number of rows returned
isn't always going to be exactly 100 -- there will be extra rows if there are
ties extending across the 100th place.
Next, we need the second set of 100:
select id
, field1
, fieldn
from table_xyz X
where ( select count(*)
from table_xyz
where id > X.id ) between 100 and 199
order by id desc
See the pattern? Note that the same caveat applies about ties that extend
across 200th place.
=end notes
=begin notes
=item First
=over 8
=item Syntax
Looks to be identical to C<Top>, e.g. C<SELECT FIRST 10 * FROM table>. Can
probably be implemented in a very similar way, but not done yet.
=item Databases
Informix
=back
sub _First {
my ( $self, $sql, $order, $rows, $offset ) = @_;
die 'FIRST not implemented';
# fetch first 20 rows
# might need to add to regex in 'where' method
}
=end notes
=cut
=item Skip
=over 8
=item Syntax
select skip 5 limit 5 * from customer
which will take rows 6 through 10 in the select.
=item Databases
Informix
=back
=cut
sub _Skip {
my ( $self, $sql, $order, $rows, $offset ) = @_;
my $last = $rows + $offset;
my ( $order_by_up, $order_by_down ) = $self->_order_directions( $order );
$sql =~ s/^\s*(SELECT|select)//;
$sql = "select skip $offset limit $rows ".$sql." ".$self->_order_by( $order );
return $sql;
}
1;
__END__
=back
=head1 SUBCLASSING
You can create your own syntax by making a subclass that provides an
C<emulate_limit> method. This might be useful if you are using stored procedures
to provide more efficient paging.
=over 4
=item emulate_limit( $self, $sql, $order, $rows, $offset )
=over 4
=item $sql
This is the SQL statement built by L<SQL::Abstract|SQL::Abstract>, but without
the ORDER BY clause, e.g.
SELECT foo, bar FROM my_table WHERE conditions
or just
WHERE conditions
if calling C<where> instead of C<select>.
=item $order
The C<order> parameter passed to the C<select> or C<where> call. You can get
an C<ORDER BY> clause from this by calling
my $order_by = $self->_order_by( $order );
You can get a pair of C<ORDER BY> clauses that sort in opposite directions by
saying
my ( $up, $down ) = $self->_order_directions( $order );
=back
The method should return a suitably modified SQL statement.
=back
=head1 AUTO-DETECTING THE DIALECT
The C<$dialect> parameter that can be passed to the constructor or to the
C<select> and C<where> methods can be a number of things. The module will
attempt to determine the appropriate syntax to use.
Supported C<$dialect> things are:
dialect name (e.g. LimitOffset, RowsTo, Top etc.)
database moniker (e.g. Oracle, SQLite etc.)
DBI database handle
Class::DBI subclass or object
=head1 CAVEATS
Paging results sets is a complicated undertaking, with several competing factors
to take into account. This module does B<not> magically give you the optimum
paging solution for your situation. It gives you a solution that may be good
enough in many situations. But if your tables are large, the SQL generated here
will often not be efficient. Or if your queries involve joins or other
complications, you will probably need to look elsewhere.
But if your tables aren't too huge, and your queries straightforward, you can
just plug this module in and move on to your next task.
=head1 ACKNOWLEDGEMENTS
Thanks to Aaron Johnson for the Top syntax model (SQL/Server and MS Access).
Thanks to Emanuele Zeppieri for the IBM DB2 syntax model.
Thanks to Paul Falbe for the Informix implementation.
=head1 TODO
Find more syntaxes to implement.
Test the syntaxes against real databases. I only have access to MySQL. Reports
of success or failure would be great.
=head1 DEPENDENCIES
L<SQL::Abstract|SQL::Abstract>,
L<DBI::Const::GetInfoType|DBI::Const::GetInfoType>,
L<Carp|Carp>.
=head1 SEE ALSO
L<DBIx::SQLEngine|DBIx::SQLEngine>,
L<DBIx::SearchBuilder|DBIx::SearchBuilder>,
L<DBIx::RecordSet|DBIx::RecordSet>.
=head1 BUGS
Please report all bugs via the CPAN Request Tracker at
L<http://rt.cpan.org/NoAuth/Bugs.html?Dist=SQL-Abstract-Limit>.
=head1 COPYRIGHT AND LICENSE
Copyright 2004 by David Baird.
This library is free software; you can redistribute it and/or modify
it under the same terms as Perl itself.
=head1 AUTHOR
David Baird, C<cpan@riverside-cms.co.uk>
=head1 HOW IS IT DONE ELSEWHERE
A few CPAN modules do this for a few databases, but the most comprehensive
seem to be DBIx::SQLEngine, DBIx::SearchBuilder and DBIx::RecordSet.
Have a look in the source code for my notes on how these modules tackle
similar problems.
=begin notes
=over 4
=item DBIx::SearchBuilder::Handle::Oracle
Transform an SQL query from:
SELECT main.*
FROM Tickets main
WHERE ((main.EffectiveId = main.id))
AND ((main.Type = 'ticket'))
AND ( ( (main.Status = 'new')OR(main.Status = 'open') )
AND ( (main.Queue = '1') ) )
to:
SELECT * FROM (
SELECT limitquery.*,rownum limitrownum FROM (
SELECT main.*
FROM Tickets main
WHERE ((main.EffectiveId = main.id))
AND ((main.Type = 'ticket'))
AND ( ( (main.Status = 'new')OR(main.Status = 'open') )
AND ( (main.Queue = '1') ) )
) limitquery WHERE rownum <= 50
) WHERE limitrownum >= 1
if ($per_page) {
# Oracle orders from 1 not zero
$first++;
# Make current query a sub select
$$statementref = "SELECT * FROM ( SELECT limitquery.*,rownum limitrownum FROM ( $$statementref ) limitquery WHERE rownum <= " . ($first + $per_page - 1) . " ) WHERE limitrownum >= " . $first;
}
=item DBIx::SQLEngine::Driver
sub sql_limit {
my $self = shift;
my ( $limit, $offset, $sql, @params ) = @_;
$sql .= " limit $limit" if $limit;
$sql .= " offset $offset" if $offset;
return ($sql, @params);
}
=item DBIx::SQLEngine::Driver::AnyData
Also:
DBIx::SQLEngine::Driver::CSV
Adds support for SQL select limit clause.
TODO: Needs workaround to support offset.
sub sql_limit {
my $self = shift;
my ( $limit, $offset, $sql, @params ) = @_;
# You can't apply "limit" to non-table fetches
$sql .= " limit $limit" if ( $sql =~ / from / );
return ($sql, @params);
}
=item DBIx::SQLEngine::Driver::Informix - Support DBD::Informix and DBD::ODBC/Informix
=item sql_limit()
Not yet supported. Perhaps we should use "first $maxrows" and throw out the first $offset?
=back
=cut
sub sql_limit {
confess("Not yet supported")
}
=item DBIx::SQLEngine::Driver::MSSQL - Support DBD::ODBC with Microsoft SQL Server
=item sql_limit()
Adds support for SQL select limit clause.
=back
=cut
sub sql_limit {
my $self = shift;
my ( $limit, $offset, $sql, @params ) = @_;
# You can't apply "limit" to non-table fetches like "select LAST_INSERT_ID"
if ( $sql =~ /\bfrom\b/ and defined $limit or defined $offset) {
$sql .= " limit $limit" if $limit;
$sql .= " offset $offset" if $offset;
}
return ($sql, @params);
}
=item DBIx::SQLEngine::Driver::Mysql - Support DBD::mysql
=item sql_limit()
Adds support for SQL select limit clause.
=back
=cut
sub sql_limit {
my $self = shift;
my ( $limit, $offset, $sql, @params ) = @_;
# You can't apply "limit" to non-table fetches like "select LAST_INSERT_ID"
if ( $sql =~ /\bfrom\b/ and $limit or $offset) {
$limit ||= 1_000_000; # MySQL select with offset requires a limit
$sql .= " limit " . ( $offset ? "$offset," : '' ) . $limit;
}
return ($sql, @params);
}
=item DBIx::SQLEngine::Driver::Oracle - Support DBD::Oracle and DBD::ODBC/Oracle
=item sql_limit()
Adds support for SQL select limit clause.
Implemented as a subselect with ROWNUM.
=back
=cut
sub sql_limit {
my $self = shift;
my ( $limit, $offset, $sql, @params ) = @_;
# remove tablealiases and group-functions from outer query properties
my ($properties) = ($sql =~ /^\s*SELECT\s(.*?)\sFROM\s/i);
$properties =~ s/[^\s]+\s*as\s*//ig;
$properties =~ s/\w+\.//g;
$offset ||= 0;
my $position = ( $offset + $limit );
$sql = <<"";
SELECT $properties FROM (
SELECT $properties, ROWNUM AS sqle_position FROM (
$sql
)
)
WHERE sqle_position > $offset AND sqle_position <= $position
return ($sql, @params);
}
=item DBIx::SQLEngine::Driver::Pg - Support DBD::Pg
=head2 sql_limit
$sqldb->sql_limit( $limit, $offset, $sql, @params ) : $sql, @params
Adds support for SQL select limit clause.
=cut
sub sql_limit {
my $self = shift;
my ( $limit, $offset, $sql, @params ) = @_;
# You can't apply "limit" to non-table fetches like "select LAST_INSERT_ID"
if ( $sql =~ /\bfrom\b/ and defined $limit or defined $offset) {
$sql .= " limit $limit" if $limit;
$sql .= " offset $offset" if $offset;
}
return ($sql, @params);
}
=item DBIx::SQLEngine::Driver::SQLite - Support DBD::SQLite driver
=head2 sql_limit
Adds support for SQL select limit clause.
=cut
sub sql_limit {
my $self = shift;
my ( $limit, $offset, $sql, @params ) = @_;
# You can't apply "limit" to non-table fetches like "select LAST_INSERT_ID"
if ( $sql =~ /\bfrom\b/ and defined $limit or defined $offset) {
$sql .= " limit $limit" if $limit;
$sql .= " offset $offset" if $offset;
}
return ($sql, @params);
}
=item DBIx::SQLEngine::Driver::Sybase - Extends SQLEngine for DBMS Idiosyncrasies
=item sql_limit()
Not yet supported.
See http://www.isug.com/Sybase_FAQ/ASE/section6.2.html#6.2.12
=back
=cut
sub sql_limit {
confess("Not yet supported")
}
=item DBIx::SQLEngine::Driver::Sybase::MSSQL - Support DBD::Sybase with Microsoft SQL
Nothing.
=back
=cut
=end notes
|