[Bps-public-commit] dbix-searchbuilder branch, date-time-helpers, created. 1.59-6-g94ae8ce

Ruslan Zakirov ruz at bestpractical.com
Tue May 17 01:55:54 EDT 2011


The branch, date-time-helpers has been created
        at  94ae8ce5fc0d4ef232c2fd989340e55c1fcac2a0 (commit)

- Log -----------------------------------------------------------------
commit f545667ab56d1afb34a00bac13ea03d38932535c
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date:   Tue May 17 09:52:48 2011 +0400

    DateTime related SQL generators in handles

diff --git a/lib/DBIx/SearchBuilder/Handle.pm b/lib/DBIx/SearchBuilder/Handle.pm
index 96acb07..2067d37 100755
--- a/lib/DBIx/SearchBuilder/Handle.pm
+++ b/lib/DBIx/SearchBuilder/Handle.pm
@@ -1361,6 +1361,140 @@ sub Log {
 
 }
 
+=head2 SimpleDateTimeFunctions
+
+See L</DateTimeFunction> for details on supported functions.
+This method is for implementers of custom DB connectors.
+
+Returns hash reference with (function name, sql template) pairs.
+
+=cut
+
+sub SimpleDateTimeFunctions {
+    my $self = shift;
+    return {
+        datetime       => 'SUBSTR(?, 1,  19)',
+        time           => 'SUBSTR(?, 12,  8)',
+
+        hourly         => 'SUBSTR(?, 1,  13)',
+        hour           => 'SUBSTR(?, 12, 2 )',
+
+        date           => 'SUBSTR(?, 1,  10)',
+        daily          => 'SUBSTR(?, 1,  10)',
+
+        day            => 'SUBSTR(?, 9,  2 )',
+        dayofmonth     => 'SUBSTR(?, 9,  2 )',
+
+        monthly        => 'SUBSTR(?, 1,  7 )',
+        month          => 'SUBSTR(?, 6,  2 )',
+
+        annually       => 'SUBSTR(?, 1,  4 )',
+        year           => 'SUBSTR(?, 1,  4 )',
+    };
+}
+
+=head2 DateTimeFunction
+
+Takes named arguments:
+
+=over 4
+
+=item * Field - SQL expression date/time function should be applied
+to. Note that this argument is used as is without any kind of quoting.
+
+=item * Type - name of the function, see supported values below.
+
+=item * Timezone - optional hash reference with From and To values,
+see L</ConvertTimezoneFunction> for details.
+
+=back
+
+Returns SQL statement. Returns NULL if function is not supported.
+
+=head3 Supported functions
+
+Type value in L</DateTimeFunction> is case insesitive. Spaces,
+underscores and dashes are ignored. So 'date time', 'DateTime'
+and 'date_time' are all synonyms. The following functions are
+supported:
+
+=over 4
+
+=item * date time - as is, no conversion, except applying timezone
+conversion if it's provided.
+
+=item * time - time only
+
+=item * hourly - datetime prefix up to the hours, e.g. '2010-03-25 16'
+
+=item * hour - hour, 0 - 23
+
+=item * date - date only
+
+=item * daily - synonym for date
+
+=item * day of week - 0 - 6, 0 - Sunday
+
+=item * day - day of month, 1 - 31
+
+=item * day of month - synonym for day
+
+=item * day of year - 1 - 366, support is database dependent
+
+=item * month - 1 - 12
+
+=item * monthly - year and month prefix, e.g. '2010-11'
+
+=item * year - e.g. '2023'
+
+=item * annually - synonym for year
+
+=item * week of year - 0-53, presence of zero week, 1st week meaning
+and whether week starts on Monday or Sunday heavily depends on database.
+
+=back
+
+=cut
+
+sub DateTimeFunction {
+    my $self = shift;
+    my %args = (
+        Field => undef,
+        Type => undef,
+        Timezone => undef,
+        @_
+    );
+
+    my $res = $args{'Field'} || '?';
+    if ( $args{'Timezone'} ) {
+        $res = $self->ConvertTimezoneFunction(
+            %{ $args{'Timezone'} },
+            Field => $res,
+        );
+    }
+
+    my $norm_type = lc $args{'Type'};
+    $norm_type =~ s/[ _-]//g;
+    if ( my $template = $self->SimpleDateTimeFunctions->{ $norm_type } ) {
+        $template =~ s/\?/$res/;
+        $res = $template;
+    }
+    else {
+        return 'NULL';
+    }
+    return $res;
+}
+
+sub ConvertTimezoneFunction {
+    my $self = shift;
+    my %args = (
+        From  => 'UTC',
+        To    => undef,
+        Field => '',
+        @_
+    );
+    return $args{'Field'};
+}
 
 
 =head2 DESTROY
diff --git a/lib/DBIx/SearchBuilder/Handle/Pg.pm b/lib/DBIx/SearchBuilder/Handle/Pg.pm
index c038e0d..ce37b42 100755
--- a/lib/DBIx/SearchBuilder/Handle/Pg.pm
+++ b/lib/DBIx/SearchBuilder/Handle/Pg.pm
@@ -251,6 +251,54 @@ sub DistinctQuery {
     $$statementref = "SELECT main.* FROM $$statementref $group $order";
 }
 
+
+sub SimpleDateTimeFunctions {
+    my $self = shift;
+    return $self->{'_simple_date_time_functions'}
+        if $self->{'_simple_date_time_functions'};
+
+    my %res = %{ $self->SUPER::SimpleDateTimeFunctions(@_) };
+    s/SUBSTR\s*\(\s*\?/SUBSTR( CAST(? AS text)/ig for values %res;
+
+    return $self->{'_simple_date_time_functions'} ||= {
+        %res,
+        dayofweek  => "EXTRACT(DOW  FROM ?)", # 0-6, 0 - Sunday
+        dayofyear  => "EXTRACT(DOY  FROM ?)", # 1-366
+        # 1-53, 1st week January 4, week starts on Monay
+        weekofyear => "EXTRACT(WEEK FROM ?)",
+    };
+}
+
+=head2 ConvertTimezoneFunction
+
+Custom implementation of L<DBIx::SearchBuilder::Handle/ConvertTimezoneFunction>.
+
+In Pg time and timestamp data types may be "with time zone" or "without time zone".
+So if Field argument is timestamp "with time zone" then From argument is not
+required and is useless. Otherwise From argument identifies time zone of the Field
+argument that is "without time zone".
+
+For consistency with other DBs use timestamp columns without time zones and provide
+From argument.
+
+=cut
+
+sub ConvertTimezoneFunction {
+    my $self = shift;
+    my %args = (
+        From  => undef,
+        To    => undef,
+        Field => '',
+        @_
+    );
+    return $args{'Field'} if ($args{From}||'') eq ($args{'To'}||'');
+
+    my $dbh = $self->dbh;
+    my $res = $args{'Field'};
+    $res = "TIMEZONE($_, $res)" foreach $dbh->quote( $_ ), grep $_, @args{'From', 'To'};
+    return $res;
+}
+
 1;
 
 __END__
diff --git a/lib/DBIx/SearchBuilder/Handle/SQLite.pm b/lib/DBIx/SearchBuilder/Handle/SQLite.pm
index d78ba63..1f1c083 100644
--- a/lib/DBIx/SearchBuilder/Handle/SQLite.pm
+++ b/lib/DBIx/SearchBuilder/Handle/SQLite.pm
@@ -149,6 +149,15 @@ sub Fields {
     return @{ $cache->{ lc $table } || [] };
 }
 
+sub SimpleDateTimeFunctions {
+    my $self = shift;
+    return $self->{'_simple_date_time_functions'} ||= {
+        %{ $self->SUPER::SimpleDateTimeFunctions(@_) },
+        dayofweek  => "strftime('%w', ?)",
+        dayofyear  => "strftime('%j', ?)",
+        weekofyear => "strftime('%W', ?)",
+    };
+}
 
 1;
 
diff --git a/lib/DBIx/SearchBuilder/Handle/mysql.pm b/lib/DBIx/SearchBuilder/Handle/mysql.pm
index efaac1a..0ebcbec 100755
--- a/lib/DBIx/SearchBuilder/Handle/mysql.pm
+++ b/lib/DBIx/SearchBuilder/Handle/mysql.pm
@@ -137,6 +137,31 @@ sub Fields {
     return @{ $cache->{ lc $table } || [] };
 }
 
+sub SimpleDateTimeFunctions {
+    my $self = shift;
+    return $self->{'_simple_date_time_functions'} ||= {
+        %{ $self->SUPER::SimpleDateTimeFunctions(@_) },
+        dayofweek  => "DAYOFWEEK(?) - 1", # 1-7, 1 - Sunday
+        dayofyear  => "DAYOFYEAR(?)", # 1-366
+        weekofyear => "WEEK(?)", # skip mode argument, so it can be controlled in mysql config
+    };
+}
+
+
+sub ConvertTimezoneFunction {
+    my $self = shift;
+    my %args = (
+        From  => 'UTC',
+        To    => undef,
+        Field => '',
+        @_
+    );
+    return $args{'Field'} unless $args{From} && $args{'To'};
+    return $args{'Field'} if $args{From} eq $args{'To'};
+    my $dbh = $self->dbh;
+    $_ = $dbh->quote( $_ ) foreach @args{'From', 'To'};
+    return "CONVERT_TZ( $args{'Field'}, $args{'From'}, $args{'To'} )";
+}
 
 1;
 

commit 94ae8ce5fc0d4ef232c2fd989340e55c1fcac2a0
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date:   Tue May 17 09:54:15 2011 +0400

    tests for date time functions

diff --git a/t/02records_datetime.t b/t/02records_datetime.t
new file mode 100644
index 0000000..8ddfb5c
--- /dev/null
+++ b/t/02records_datetime.t
@@ -0,0 +1,295 @@
+#!/usr/bin/perl -w
+
+
+use strict;
+use warnings;
+use Test::More;
+BEGIN { require "t/utils.pl" }
+our (@AvailableDrivers);
+
+use constant TESTS_PER_DRIVER => 42;
+
+my $total = scalar(@AvailableDrivers) * TESTS_PER_DRIVER;
+plan tests => $total;
+
+foreach my $d ( @AvailableDrivers ) {
+SKIP: {
+    unless( has_schema( 'TestApp', $d ) ) {
+        skip "No schema for '$d' driver", TESTS_PER_DRIVER;
+    }
+    unless( should_test( $d ) ) {
+        skip "ENV is not defined for driver '$d'", TESTS_PER_DRIVER;
+    }
+
+    my $handle = get_handle( $d );
+    connect_handle( $handle );
+    isa_ok($handle->dbh, 'DBI::db');
+
+    my $ret = init_schema( 'TestApp', $handle );
+    isa_ok($ret,'DBI::st', "Inserted the schema. got a statement handle back");
+
+    my $count_all = init_data( 'TestApp::User', $handle );
+    ok( $count_all,  "init users data" );
+
+    my $users_obj = TestApp::Users->new( $handle );
+    isa_ok( $users_obj, 'DBIx::SearchBuilder' );
+    is( $users_obj->_Handle, $handle, "same handle as we used in constructor");
+
+# try to use $users_obj for all tests, after each call to CleanSlate it should look like new obj.
+# and test $obj->new syntax
+    my $clean_obj = $users_obj->new( $handle );
+    isa_ok( $clean_obj, 'DBIx::SearchBuilder' );
+
+    foreach my $type ('date time', 'DateTime', 'date_time', 'Date-Time') {
+        $users_obj->CleanSlate;
+        is_deeply( $users_obj, $clean_obj, 'after CleanSlate looks like new object');
+        is_deeply(
+            get_data( $users_obj, Type => $type ),
+            {
+                '' => undef,
+                '2011-05-20 19:53:23' => '2011-05-20 19:53:23',
+            },
+        );
+    }
+
+    $users_obj->CleanSlate;
+    is_deeply( $users_obj, $clean_obj, 'after CleanSlate looks like new object');
+    is_deeply(
+        get_data( $users_obj, Type => 'time' ),
+        {
+            '' => undef,
+            '2011-05-20 19:53:23' => '19:53:23',
+        },
+    );
+
+    $users_obj->CleanSlate;
+    is_deeply( $users_obj, $clean_obj, 'after CleanSlate looks like new object');
+    is_deeply(
+        get_data( $users_obj, Type => 'hourly' ),
+        {
+            '' => undef,
+            '2011-05-20 19:53:23' => '2011-05-20 19',
+        },
+    );
+
+    $users_obj->CleanSlate;
+    is_deeply( $users_obj, $clean_obj, 'after CleanSlate looks like new object');
+    is_deeply(
+        get_data( $users_obj, Type => 'hour' ),
+        {
+            '' => undef,
+            '2011-05-20 19:53:23' => '19',
+        },
+    );
+
+    foreach my $type ( 'date', 'daily' ) {
+        $users_obj->CleanSlate;
+        is_deeply( $users_obj, $clean_obj, 'after CleanSlate looks like new object');
+        is_deeply(
+            get_data( $users_obj, Type => $type ),
+            {
+                '' => undef,
+                '2011-05-20 19:53:23' => '2011-05-20',
+            },
+        );
+    }
+
+    $users_obj->CleanSlate;
+    is_deeply( $users_obj, $clean_obj, 'after CleanSlate looks like new object');
+    is_deeply(
+        get_data( $users_obj, Type => 'day of week' ),
+        {
+            '' => undef,
+            '2011-05-20 19:53:23' => '5',
+        },
+    );
+
+    foreach my $type ( 'day', 'DayOfMonth' ) {
+        $users_obj->CleanSlate;
+        is_deeply( $users_obj, $clean_obj, 'after CleanSlate looks like new object');
+        is_deeply(
+            get_data( $users_obj, Type => $type ),
+            {
+                '' => undef,
+                '2011-05-20 19:53:23' => '20',
+            },
+        );
+    }
+
+    $users_obj->CleanSlate;
+    is_deeply( $users_obj, $clean_obj, 'after CleanSlate looks like new object');
+    is_deeply(
+        get_data( $users_obj, Type => 'day of year' ),
+        {
+            '' => undef,
+            '2011-05-20 19:53:23' => '140',
+        },
+    );
+
+    $users_obj->CleanSlate;
+    is_deeply( $users_obj, $clean_obj, 'after CleanSlate looks like new object');
+    is_deeply(
+        get_data( $users_obj, Type => 'month' ),
+        {
+            '' => undef,
+            '2011-05-20 19:53:23' => '05',
+        },
+    );
+
+    $users_obj->CleanSlate;
+    is_deeply( $users_obj, $clean_obj, 'after CleanSlate looks like new object');
+    is_deeply(
+        get_data( $users_obj, Type => 'monthly' ),
+        {
+            '' => undef,
+            '2011-05-20 19:53:23' => '2011-05',
+        },
+    );
+
+    foreach my $type ( 'year', 'annually' ) {
+        $users_obj->CleanSlate;
+        is_deeply( $users_obj, $clean_obj, 'after CleanSlate looks like new object');
+        is_deeply(
+            get_data( $users_obj, Type => $type ),
+            {
+                '' => undef,
+                '2011-05-20 19:53:23' => '2011',
+            },
+        );
+    }
+
+    $users_obj->CleanSlate;
+    is_deeply( $users_obj, $clean_obj, 'after CleanSlate looks like new object');
+    is_deeply(
+        get_data( $users_obj, Type => 'week of year' ),
+        {
+            '' => undef,
+            '2011-05-20 19:53:23' => '20',
+        },
+    );
+
+    cleanup_schema( 'TestApp', $handle );
+}} # SKIP, foreach blocks
+
+
+sub get_data {
+    my $users = shift;
+    $users->UnLimit;
+    $users->Column( FIELD => 'Expires' );
+    my $column = $users->Column(
+        ALIAS => 'main',
+        FIELD => 'Expires',
+        FUNCTION => $users->_Handle->DateTimeFunction( @_ ),
+    );
+
+    my %res;
+    while ( my $user = $users->Next ) {
+        $res{ $user->Expires || '' } = $user->__Value( $column );
+    }
+    return \%res;
+}
+
+1;
+
+package TestApp;
+
+sub schema_mysql {
+<<EOF;
+CREATE TEMPORARY TABLE Users (
+    id integer AUTO_INCREMENT,
+    Expires DATETIME NULL,
+    PRIMARY KEY (id)
+)
+EOF
+
+}
+
+sub schema_pg {
+<<EOF;
+CREATE TEMPORARY TABLE Users (
+    id serial PRIMARY KEY,
+    Expires TIMESTAMP NULL
+)
+EOF
+
+}
+
+sub schema_sqlite {
+
+<<EOF;
+CREATE TABLE Users (
+    id integer primary key,
+    Expires TEXT NULL
+)
+EOF
+
+}
+
+#sub schema_oracle { [
+#    "CREATE SEQUENCE Users_seq",
+#    "CREATE TABLE Users (
+#        id integer CONSTRAINT Users_Key PRIMARY KEY,
+#        Login varchar(18) NOT NULL,
+#    )",
+#] }
+#
+#sub cleanup_schema_oracle { [
+#    "DROP SEQUENCE Users_seq",
+#    "DROP TABLE Users", 
+#] }
+
+
+1;
+
+package TestApp::User;
+
+use base $ENV{SB_TEST_CACHABLE}?
+    qw/DBIx::SearchBuilder::Record::Cachable/:
+    qw/DBIx::SearchBuilder::Record/;
+
+sub _Init {
+    my $self = shift;
+    my $handle = shift;
+    $self->Table('Users');
+    $self->_Handle($handle);
+}
+
+sub _ClassAccessible {
+    {   
+        id =>
+        {read => 1, type => 'int(11)' }, 
+        Expires =>
+        {read => 1, write => 1, type => 'datetime' },
+    }
+}
+
+sub init_data {
+    return (
+    [ 'Expires' ],
+    [ undef, ],
+    [ '2011-05-20 19:53:23',     ],
+    );
+}
+
+1;
+
+package TestApp::Users;
+
+# use TestApp::User;
+use base qw/DBIx::SearchBuilder/;
+
+sub _Init {
+    my $self = shift;
+    $self->SUPER::_Init( Handle => shift );
+    $self->Table('Users');
+}
+
+sub NewItem
+{
+    my $self = shift;
+    return TestApp::User->new( $self->_Handle );
+}
+
+1;
+
+

-----------------------------------------------------------------------



More information about the Bps-public-commit mailing list