Skip to content

Commit

Permalink
Item9808: First pass at SQL Server. Mostly there, except regexp.
Browse files Browse the repository at this point in the history
git-svn-id: http://svn.foswiki.org/trunk/DBIStoreContrib@17268 0b4bb1d4-4e5a-0410-9cc4-b2b747904278
  • Loading branch information
CrawfordCurrie authored and CrawfordCurrie committed Feb 6, 2014
1 parent d36b05f commit 6b7da34
Show file tree
Hide file tree
Showing 6 changed files with 125 additions and 27 deletions.
5 changes: 5 additions & 0 deletions data/System/DBIStoreContrib.txt
Expand Up @@ -148,6 +148,11 @@ Here's an overview of the important bits of the contrib:
* =lib/Foswiki/Store/QueryAlgorithms/DBIStoreContrib.pm= - the query algorithm
* =lib/Foswiki/Store/SearchAlgorithms/DBIStoreContrib.pm= - the search algorithm

The subversion repository (but not the official release) contains a fixed version of DBI::Shell from CPAN. This
can be useful when debugging SQL server, or for simply understanding the tables. Run it using:

=perl -I <path to DBIStoreContrib checkout>/lib -MDBI::Shell <dsn from configure> <username> <password>=

---++ Info

| Author(s): | Crawford Currie http://c-dot.co.uk |
Expand Down
24 changes: 14 additions & 10 deletions lib/Foswiki/Contrib/DBIStoreContrib/DBIStore.pm
Expand Up @@ -26,11 +26,12 @@ use Error ':try';
use Assert;
use Encode;

use constant MONITOR => 0;
use constant MONITOR => 1;

# TODO: SMELL: convert to using $session->{store} perhaps?
our $db; # singleton instance of this class
our $personality; # personality module for the selected DSN
our ( $CQ, $TEXT );

our @TABLES = keys(%Foswiki::Meta::VALIDATE); # META: types

Expand Down Expand Up @@ -116,6 +117,8 @@ sub _connect {

# Custom code to put DB's into ANSI mode and clean up error reporting
personality()->startup();
$CQ = personality()->string_quote();
$TEXT = personality()->text_type();

# Check if the DB is initialised with a quick sniff of the tables
# to see if all the ones we expect are there
Expand Down Expand Up @@ -151,7 +154,7 @@ SQL
sub _createTableForMETA {
my ( $this, $t ) = @_;
my $cols =
join( ",\n", map { " \"$_\" TEXT" } keys %{ $this->{schema}->{$t} } );
join( ",\n", map { " \"$_\" $TEXT" } keys %{ $this->{schema}->{$t} } );
$this->{handle}->do(<<SQL);
CREATE TABLE "$t" (
tid INT,
Expand All @@ -176,18 +179,18 @@ sub _createTables {
$this->{handle}->do(<<SQL);
CREATE TABLE topic (
tid INT PRIMARY KEY,
web TEXT,
name TEXT,
text TEXT,
raw TEXT,
web $TEXT,
name $TEXT,
text $TEXT,
raw $TEXT,
UNIQUE (tid)
)
SQL

# Now create the meta-table of known META: tables
$this->{handle}->do(<<SQL);
CREATE TABLE metatypes (
name TEXT
name $TEXT
)
SQL

Expand All @@ -196,7 +199,7 @@ SQL
print STDERR "Creating table for $t\n" if MONITOR;
$this->_createTableForMETA($t);
}
$this->{handle}->do('COMMIT');
$this->{handle}->do('COMMIT') if personality()->requires_COMMIT();
}

# Load all existing webs and topics into the cache DB (expensive)
Expand All @@ -208,7 +211,7 @@ sub _preload {
my $web = $wit->next();
$this->_preloadWeb( $web, $session );
}
$this->{handle}->do('COMMIT');
$this->{handle}->do('COMMIT') if personality()->requires_commit();
}

# Preload a single web - PRIVATE
Expand All @@ -219,9 +222,10 @@ sub _preloadWeb {
while ( $tit->hasNext() ) {
my $t = $tit->next();
my $topic = Foswiki::Meta->load( $session, $w, $t );
print STDERR "Preloading topic $w/$t\n"; # if MONITOR;
print STDERR "Preloading topic $w/$t\n" if MONITOR;
$this->insert($topic);
}

my $wit = $web->eachWeb();
while ( $wit->hasNext() ) {
$this->_preloadWeb( $w . '/' . $wit->next(), $session );
Expand Down
24 changes: 13 additions & 11 deletions lib/Foswiki/Contrib/DBIStoreContrib/HoistSQL.pm
Expand Up @@ -25,7 +25,7 @@ use Foswiki::Store::QueryAlgorithms::DBIStoreContrib ();
# A Foswiki query parser
our $parser;

use constant MONITOR => 0;
use constant MONITOR => 1;

# Type identifiers.
# FIRST 3 MUST BE KEPT IN LOCKSTEP WITH Foswiki::Infix::Node
Expand Down Expand Up @@ -104,7 +104,7 @@ END {
# _SELECT(__LINE__, pick, FROM =>, WHERE => etc )
sub _SELECT {
my ( $line, $pick, %opts ) = @_;
my $info = MONITOR ? "/*$line*/" : '';
my $info = MONITOR ? _personality()->make_comment($line) : '';
my $sql = "SELECT$info $pick";
while ( my ( $opt, $val ) = each %opts ) {

Expand Down Expand Up @@ -240,7 +240,7 @@ my %bop_map = (
# Special case
if ( $lhs eq 'NULL' ) {
if ( $rhs eq 'NULL' ) {
return ( '0=0', BOOLEAN );
return ( _personality->true(), BOOLEAN );
}
return ( "($rhs) IS NULL", BOOLEAN );
}
Expand Down Expand Up @@ -305,12 +305,12 @@ sub hoist {

# Top level selectors are relative to the 'topic' table
my %h = _hoist( $query, 'topic' );
my $alias = undef; #_alias(__LINE__);
my $alias = _alias(__LINE__); # SQL server requires this!
if ( $h{sql} =~ /^SELECT/ ) {
$h{sql} = "topic.tid IN (SELECT tid FROM ($h{sql}))";
$h{sql} = "topic.tid IN (SELECT tid FROM ($h{sql}) AS $alias)";
}
elsif ( $h{is_table_name} ) {
$h{sql} = "topic.tid in (SELECT tid FROM ($h{sql}))";
$h{sql} = "topic.tid in (SELECT tid FROM ($h{sql}) AS alias)";
}
elsif ( $h{type} == NUMBER ) {
$h{sql} = "($h{sql})!= 0";
Expand Down Expand Up @@ -586,7 +586,7 @@ sub _hoist {
FROM => _AS( $rhs{sql}, "x$rhs_alias" ) );
$result{sql} = _SELECT(
__LINE__,
_AS( "1=1" => $result{sel} ) . ",tid",
_AS( _personality()->true() => $result{sel} ) . ",tid",
FROM => _AS( _UNION( $lhs_sql, $rhs_sql ), $union_alias )
);
$result{type} = BOOLEAN;
Expand All @@ -606,7 +606,8 @@ sub _hoist {
if ( $optype == BOOLEAN ) {
$result{sql} = _SELECT(
__LINE__,
_AS( '1=1' => $result{sel} ) . ",$lhs_alias.tid",
_AS( _personality->true() => $result{sel} )
. ",$lhs_alias.tid",
FROM => _AS(
$lhs{sql} => $lhs_alias,
$rhs{sql} => $rhs_alias
Expand Down Expand Up @@ -643,7 +644,8 @@ sub _hoist {
if ( $optype == BOOLEAN ) {
$result{sql} = _SELECT(
__LINE__,
_AS( "1=1" => $result{sel} ) . ",$lhs_alias.tid",
_AS( _personality->true() => $result{sel} )
. ",$lhs_alias.tid",
FROM => _AS( $lhs{sql} => $lhs_alias ),
WHERE => $expr
);
Expand Down Expand Up @@ -674,7 +676,7 @@ sub _hoist {
if ( $optype == BOOLEAN ) {
$result{sql} = _SELECT(
__LINE__,
_AS( '1=1' => $result{sel} ) . ',tid',
_AS( _personality->true() => $result{sel} ) . ',tid',
FROM => _AS( $rhs{sql} => $rhs_alias ),
WHERE => $expr
);
Expand Down Expand Up @@ -709,7 +711,7 @@ sub _hoist {
if ( $optype == BOOLEAN ) {
$result{sql} = _SELECT(
__LINE__,
_AS( '1=1' => $result{sel} ) . ",tid",
_AS( _personality->true() => $result{sel} ) . ",tid",
FROM => _AS( $kid{sql} => $arg_alias ),
WHERE => $expr
);
Expand Down
63 changes: 58 additions & 5 deletions lib/Foswiki/Contrib/DBIStoreContrib/Personality.pm
Expand Up @@ -39,11 +39,24 @@ sub reserve {
map { $this->{reserved}->{$_} = 1 } @_;
}

# Execute any SQL commands required to start the DB in ANSI mode.
# The default is no specific setup.
=begin
---++ startup()
Execute any SQL commands required to start the DB in ANSI mode.
The default is no specific setup.
=cut

sub startup {
}

=begin TML
---+ table_exists(table_name [, table_name]*) -> boolean
Determine if a table exists
=cut

sub table_exists {
my $this = shift;
my $tables = join( ',', map { "'$_'" } @_ );
Expand All @@ -61,10 +74,34 @@ SQL

=begin TML
---++ require_COMMIT() -> $boolean
True if there is an automatic transaction opened that requires a commit.
The default is TRUE which works for SQLite, MySQL and Postgresql.
=cut

sub requires_COMMIT {
return 1;
}

=begin TML
---++ text_type() -> string
Get the name of the TEXT type, used to store variable-length strings.
=cut

sub text_type {
return 'TEXT';
}

=begin TML
---++ rgexp($lhs, $rhs) -> $sql
Construct an SQL expression to execute the given regular expression
match.
* =$rhs= - right hand side of the match
* $lhs - the regular expression (perl syntax)
* =$lhs= - the regular expression (perl syntax)
be different :-(
=cut
Expand All @@ -77,6 +114,7 @@ sub regexp {

=begin TML
---++ wildcard($lhs, $rhs) -> $sql
Construct an SQL expression that will match a Foswiki wildcard
name match.
Expand Down Expand Up @@ -124,6 +162,7 @@ sub wildcard {

=begin TML
---++ d2n($timestring) -> $isosecs
Convert a Foswiki time string to a number.
This implementation is for SQLite - there is no support in ANSI.
Expand All @@ -142,11 +181,13 @@ Calculate the character length of a string
=cut

sub length {
return "LENGTH($_[1])";
my ( $this, $s ) = @_;
return "LENGTH($s)";
}

=begin TML
---++ safe_id($id) -> $safeid
Make sure the ID is safe to use in this dialect of SQL.
Unsafe IDs should be quoted using the dialect's identifier
quoting rule. The default is to double-quote it.
Expand All @@ -163,6 +204,7 @@ sub safe_id {

=begin TML
---++ cast_to_numeric($sql) -> $sql
Cast a datum to a numeric type for comparison
=cut
Expand All @@ -174,17 +216,19 @@ sub cast_to_numeric {

=begin TML
---++ cast_to_string($sql) -> $sql
Cast a datum to a character string type for comparison
=cut

sub cast_to_text {
my ( $this, $d ) = @_;
return "CAST(($d) AS TEXT)";
return "CAST(($d) AS " . $this->text_type() . "TEXT)";
}

=begin TML
---++ string_quote() -> $quote_char
Quote character for character strings - default is '
=cut
Expand All @@ -193,6 +237,15 @@ sub string_quote {
return "'";
}

sub make_comment {
my $this = shift;
return '/*' . join( ' ', @_ ) . '*/';
}

sub true {
return '1=1';
}

1;
__DATA__
Expand Down
34 changes: 34 additions & 0 deletions lib/Foswiki/Contrib/DBIStoreContrib/Personality/ODBC.pm
Expand Up @@ -59,6 +59,40 @@ sub startup {
my $this = shift;

$this->{store}->{handle}->do('set QUOTED_IDENTIFIER ON');
$this->{store}->{handle}->do(<<'SQL');
ALTER FUNCTION make_number(@Val VARCHAR(MAX)) RETURNS FLOAT AS
BEGIN
DECLARE @Res AS FLOAT
IF ISNUMERIC(@Val) = 1
BEGIN
SET @Res = CONVERT(FLOAT, @Val)
END
ELSE
SET @Res = 0
RETURN @Res
END
SQL
}

sub cast_to_numeric {
my ( $this, $d ) = @_;
return "dbo.make_number($d)";
}

sub requires_COMMIT {
return 0;
}

sub text_type {
return "VARCHAR(MAX)";
}

sub make_comment {
return ''; # no support
}

sub true {
return 'CAST(1 AS BIT)';
}

1;
Expand Down
2 changes: 1 addition & 1 deletion lib/Foswiki/Contrib/DBIStoreContrib/Personality/Pg.pm
Expand Up @@ -34,7 +34,7 @@ sub startup {
my $this = shift;
$this->{store}->{handle}->do("SET client_min_messages = 'warning'");
$this->{store}->{handle}->do(<<'DO');
CREATE OR REPLACE FUNCTION make_number(TEXT) RETURNS NUMERIC as $$
CREATE OR REPLACE FUNCTION make_number(TEXT) RETURNS NUMERIC AS $$
DECLARE
i NUMERIC;
BEGIN
Expand Down

0 comments on commit 6b7da34

Please sign in to comment.