From 86c386eb5fd76bd78bee5bbc54cf56449576c23f Mon Sep 17 00:00:00 2001 From: Sumit Jaiswal <54075285+sumitj824@users.noreply.github.com> Date: Wed, 18 Sep 2024 17:16:53 +0530 Subject: [PATCH 1/3] [OSS-ONLY] Add instructions for running JDBC tests with single-db migration mode (#2942) This commit adds instructions for running JDBC tests with single-db migration mode. Signed-off-by: Sumit Jaiswal sumiji@amazon.com Co-authored-by: Sumit Jaiswal --- test/JDBC/README.md | 36 ++++++++++++++++++++++++++++++++++++ 1 file changed, 36 insertions(+) diff --git a/test/JDBC/README.md b/test/JDBC/README.md index cdd8ecfc08..e6cd1f72bf 100644 --- a/test/JDBC/README.md +++ b/test/JDBC/README.md @@ -20,6 +20,7 @@ The JDBC test framework for Babelfish uses the JDBC Driver for SQL Server for da - [Adding the test cases](#adding-the-test-cases) - [Reading the console output and diff](#reading-the-console-output-and-diff) - [Running Tests with Parallel Query Enabled](#running-tests-with-parallel-query-enabled) +- [Running Tests with Single-DB Migration Mode](#running-tests-with-single-db-migration-mode) - [Running Tests with Non Default Server Collation](#running-tests-with-non-default-server-collation) - [Running Tests with Non Default Database Collation](#running-tests-with-non-default-database-collation) @@ -463,6 +464,41 @@ After building the modified PostgreSQL engine and Babelfish extensions using the ``` If you encounter failing or crashing tests in the "JDBC tests with parallel query" GitHub workflow, consider adding the names of these problematic test cases to the `parallel_query_jdbc_schedule` file. Prefix these test case names with `ignore#!#`. As we work towards resolving these issues in the future, we will gradually remove these excluded tests from the `parallel_query_jdbc_schedule` scheduling file. +## Running Tests with Single-DB Migration Mode + +After building the modified PostgreSQL engine and Babelfish extensions using the [online instructions](../../contrib/README.md), you must: +1. Create a PostgreSQL database and initialize Babelfish extensions with single-db migration mode by adding following line in `postgres/data/postgresql.conf` and restart engine, then initialize Babelfish extensions using the [online instructions](../../contrib/README.md) + + ```bash + babelfishpg_tsql.migration_mode = 'single-db' + ``` +2. Before running JDBC tests, set the `isSingleDbMode` environment variable to `true`: + + ```bash + export isSingleDbMode=true + # Verify if isSingleDbMode is set to true + echo $isSingleDbMode + ``` +3. Now Run the tests: + ```bash + mvn test + ``` +4. How to add expected output for some test + 1. By default expected output of a test should be added into `expected` folder. + 2. If the expected output is different for single-db migration mode compared to multi-db migration mode, one can add a different expected output specially for single-db migration mode in `expected/single_db/` folder. Additionally, one needs to add `-- single_db_mode_expected` flag in the corresponding input file. + +5. To exclude some tests from running via the JDBC in single-db migration mode, you can add test-case name with prefix `ignore#!#` in `singledb_jdbc_schedule` file. + +6. Cleanup all the objects, users, roles and databases created while running the tests: + ```bash + ./cleanup.sh + ``` +7. Please note that whenever you had changed the migration mode and reinitialised Babelfish extensions. Update the `isSingleDbMode` environment variable with appropriate value and unset when migration mode is set to 'multi-db'. + ```bash + unset isSingleDbMode + ``` + This ensures that correct expected output is picked for current migration mode. + ## Running Tests with Non Default Server Collation After building the modified PostgreSQL engine and Babelfish extensions using the [online instructions](../../contrib/README.md), you must: From d1f445ece3268db7a1e2861a146325e1e447ae3e Mon Sep 17 00:00:00 2001 From: Rohit bhagat <65351720+rohit01010@users.noreply.github.com> Date: Thu, 19 Sep 2024 09:40:04 +0530 Subject: [PATCH 2/3] Fixed issue in SP_TABLES() when @table_name parameter has square brackets around underscore (#2940) Currently, SP_TABLES procedure does not support wild card [], which matches to any character that is specified in square bracket. Due to this SP_TABLES procedure returns different output when @table_name parameter value is table_1 and table[_]1. This issue exists because previously we were using helper function sp_tables_internal whose body language was plpgsql hence we were using PostgresSQL Like operator for comparison, which does not support square bracket wild card expression. Fixed the issue by removing this helper function and migrating this function logic inside the SP_TABLES procedure whose language is pltsql and Like operator in pltsql supports square bracket wild card. Task: BABEL-4128 Signed-off-by: Rohit Bhagat --- .../babelfishpg_tsql/sql/babelfishpg_tsql.sql | 98 +++---- .../babelfishpg_tsql--4.3.0--4.4.0.sql | 102 +++++++ .../expected/BABEL-SP_TABLES-vu-cleanup.out | 6 + .../expected/BABEL-SP_TABLES-vu-prepare.out | 6 + .../expected/BABEL-SP_TABLES-vu-verify.out | 126 +++++++- test/JDBC/expected/BABEL-SP_TABLES.out | 276 +++++++++++++++++- .../JDBC/input/BABEL-SP_TABLES-vu-cleanup.sql | 6 + .../JDBC/input/BABEL-SP_TABLES-vu-prepare.sql | 6 + test/JDBC/input/BABEL-SP_TABLES-vu-verify.sql | 48 ++- test/JDBC/input/BABEL-SP_TABLES.sql | 120 +++++++- .../expected_create.out | 2 - .../expected_drop.out | 1 + .../expected_dependency.out | 1 - 13 files changed, 725 insertions(+), 73 deletions(-) diff --git a/contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql b/contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql index 167b15cd9e..8a0721961b 100644 --- a/contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql +++ b/contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql @@ -912,63 +912,6 @@ AND has_schema_privilege(t1.relnamespace, 'USAGE') AND has_table_privilege(t1.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER'); GRANT SELECT ON sys.sp_tables_view TO PUBLIC; -CREATE OR REPLACE FUNCTION sys.sp_tables_internal( - in_table_name sys.nvarchar(384) = NULL, - in_table_owner sys.nvarchar(384) = NULL, - in_table_qualifier sys.sysname = NULL, - in_table_type sys.varchar(100) = NULL, - in_fusepattern sys.bit = '1') - RETURNS TABLE ( - out_table_qualifier sys.sysname, - out_table_owner sys.sysname, - out_table_name sys.sysname, - out_table_type sys.varchar(32), - out_remarks sys.varchar(254) - ) - AS $$ - DECLARE opt_table sys.varchar(16) = ''; - DECLARE opt_view sys.varchar(16) = ''; - DECLARE cs_as_in_table_type varchar COLLATE "C" = in_table_type; - BEGIN - IF upper(cs_as_in_table_type) LIKE '%''TABLE''%' THEN - opt_table = 'TABLE'; - END IF; - IF upper(cs_as_in_table_type) LIKE '%''VIEW''%' THEN - opt_view = 'VIEW'; - END IF; - IF in_fusepattern = 1 THEN - RETURN query - SELECT - CAST(table_qualifier AS sys.sysname) AS TABLE_QUALIFIER, - CAST(table_owner AS sys.sysname) AS TABLE_OWNER, - CAST(table_name AS sys.sysname) AS TABLE_NAME, - CAST(table_type AS sys.varchar(32)) AS TABLE_TYPE, - CAST(remarks AS sys.varchar(254)) AS REMARKS - FROM sys.sp_tables_view - WHERE (in_table_name IS NULL OR table_name LIKE in_table_name collate sys.database_default) - AND (in_table_owner IS NULL OR table_owner LIKE in_table_owner collate sys.database_default) - AND (in_table_qualifier IS NULL OR table_qualifier LIKE in_table_qualifier collate sys.database_default) - AND (cs_as_in_table_type IS NULL OR table_type = opt_table OR table_type = opt_view) - ORDER BY table_qualifier, table_owner, table_name; - ELSE - RETURN query - SELECT - CAST(table_qualifier AS sys.sysname) AS TABLE_QUALIFIER, - CAST(table_owner AS sys.sysname) AS TABLE_OWNER, - CAST(table_name AS sys.sysname) AS TABLE_NAME, - CAST(table_type AS sys.varchar(32)) AS TABLE_TYPE, - CAST(remarks AS sys.varchar(254)) AS REMARKS - FROM sys.sp_tables_view - WHERE (in_table_name IS NULL OR table_name = in_table_name collate sys.database_default) - AND (in_table_owner IS NULL OR table_owner = in_table_owner collate sys.database_default) - AND (in_table_qualifier IS NULL OR table_qualifier = in_table_qualifier collate sys.database_default) - AND (cs_as_in_table_type IS NULL OR table_type = opt_table OR table_type = opt_view) - ORDER BY table_qualifier, table_owner, table_name; - END IF; - END; -$$ -LANGUAGE plpgsql STABLE; - CREATE OR REPLACE PROCEDURE sys.sp_tables ( "@table_name" sys.nvarchar(384) = NULL, "@table_owner" sys.nvarchar(384) = NULL, @@ -997,13 +940,40 @@ BEGIN THROW 33557097, N'The database name component of the object qualifier must be the name of the current database.', 1; END - SELECT - CAST(out_table_qualifier AS sys.sysname) AS TABLE_QUALIFIER, - CAST(out_table_owner AS sys.sysname) AS TABLE_OWNER, - CAST(out_table_name AS sys.sysname) AS TABLE_NAME, - CAST(out_table_type AS sys.varchar(32)) AS TABLE_TYPE, - CAST(out_remarks AS sys.varchar(254)) AS REMARKS - FROM sys.sp_tables_internal(@table_name, @table_owner, @table_qualifier, CAST(@table_type AS varchar(100)), @fusepattern); + IF (@fusepattern = 1) + SELECT + CAST(table_qualifier AS sys.sysname) AS TABLE_QUALIFIER, + CAST(table_owner AS sys.sysname) AS TABLE_OWNER, + CAST(table_name AS sys.sysname) AS TABLE_NAME, + CAST(table_type AS sys.varchar(32)) AS TABLE_TYPE, + remarks AS REMARKS + FROM sys.sp_tables_view + WHERE (@table_name IS NULL OR table_name LIKE @table_name collate database_default) + AND (@table_owner IS NULL OR table_owner LIKE @table_owner collate database_default) + AND (@table_qualifier IS NULL OR table_qualifier LIKE @table_qualifier collate database_default) + AND ( + @table_type IS NULL OR + (CAST(@table_type AS varchar(100)) LIKE '%''TABLE''%' collate database_default AND table_type = 'TABLE' collate database_default) OR + (CAST(@table_type AS varchar(100)) LIKE '%''VIEW''%' collate database_default AND table_type = 'VIEW' collate database_default) + ) + ORDER BY TABLE_QUALIFIER, TABLE_OWNER, TABLE_NAME; + ELSE + SELECT + CAST(table_qualifier AS sys.sysname) AS TABLE_QUALIFIER, + CAST(table_owner AS sys.sysname) AS TABLE_OWNER, + CAST(table_name AS sys.sysname) AS TABLE_NAME, + CAST(table_type AS sys.varchar(32)) AS TABLE_TYPE, + remarks AS REMARKS + FROM sys.sp_tables_view + WHERE (@table_name IS NULL OR table_name = @table_name collate database_default) + AND (@table_owner IS NULL OR table_owner = @table_owner collate database_default) + AND (@table_qualifier IS NULL OR table_qualifier = @table_qualifier collate database_default) + AND ( + @table_type IS NULL OR + (CAST(@table_type AS varchar(100)) LIKE '%''TABLE''%' collate database_default AND table_type = 'TABLE' collate database_default) OR + (CAST(@table_type AS varchar(100)) LIKE '%''VIEW''%' collate database_default AND table_type = 'VIEW' collate database_default) + ) + ORDER BY TABLE_QUALIFIER, TABLE_OWNER, TABLE_NAME; END; $$ LANGUAGE 'pltsql'; diff --git a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.3.0--4.4.0.sql b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.3.0--4.4.0.sql index 2a4778f356..6ee5e56195 100644 --- a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.3.0--4.4.0.sql +++ b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.3.0--4.4.0.sql @@ -4,6 +4,33 @@ -- add 'sys' to search path for the convenience SELECT set_config('search_path', 'sys, '||current_setting('search_path'), false); +-- Drops an object if it does not have any dependent objects. +-- Is a temporary procedure for use by the upgrade script. Will be dropped at the end of the upgrade. +-- Please have this be one of the first statements executed in this upgrade script. +CREATE OR REPLACE PROCEDURE babelfish_drop_deprecated_object(object_type varchar, schema_name varchar, object_name varchar) AS +$$ +DECLARE + error_msg text; + query1 text; + query2 text; +BEGIN + + query1 := pg_catalog.format('alter extension babelfishpg_tsql drop %s %s.%s', object_type, schema_name, object_name); + query2 := pg_catalog.format('drop %s %s.%s', object_type, schema_name, object_name); + + execute query1; + execute query2; +EXCEPTION + when object_not_in_prerequisite_state then --if 'alter extension' statement fails + GET STACKED DIAGNOSTICS error_msg = MESSAGE_TEXT; + raise warning '%', error_msg; + when dependent_objects_still_exist then --if 'drop view' statement fails + GET STACKED DIAGNOSTICS error_msg = MESSAGE_TEXT; + raise warning '%', error_msg; +end +$$ +LANGUAGE plpgsql; + -- Please add your SQLs here /* * Note: These SQL statements may get executed multiple times specially when some features get backpatched. @@ -1755,6 +1782,81 @@ AND pg_get_serial_sequence(quote_ident(ext.nspname)||'.'||quote_ident(c.relname) AND has_sequence_privilege(pg_get_serial_sequence(quote_ident(ext.nspname)||'.'||quote_ident(c.relname), a.attname), 'USAGE,SELECT,UPDATE'); GRANT SELECT ON sys.identity_columns TO PUBLIC; +CREATE OR REPLACE PROCEDURE sys.sp_tables ( + "@table_name" sys.nvarchar(384) = NULL, + "@table_owner" sys.nvarchar(384) = NULL, + "@table_qualifier" sys.sysname = NULL, + "@table_type" sys.nvarchar(100) = NULL, + "@fusepattern" sys.bit = '1') +AS $$ +BEGIN + + -- Handle special case: Enumerate all databases when name and owner are blank but qualifier is '%' + IF (@table_qualifier = '%' AND @table_owner = '' AND @table_name = '') + BEGIN + SELECT + d.name AS TABLE_QUALIFIER, + CAST(NULL AS sys.sysname) AS TABLE_OWNER, + CAST(NULL AS sys.sysname) AS TABLE_NAME, + CAST(NULL AS sys.varchar(32)) AS TABLE_TYPE, + CAST(NULL AS sys.varchar(254)) AS REMARKS + FROM sys.databases d ORDER BY TABLE_QUALIFIER; + + RETURN; + END; + + IF (@table_qualifier != '' AND LOWER(@table_qualifier) != LOWER(sys.db_name())) + BEGIN + THROW 33557097, N'The database name component of the object qualifier must be the name of the current database.', 1; + END + + IF (@fusepattern = 1) + SELECT + CAST(table_qualifier AS sys.sysname) AS TABLE_QUALIFIER, + CAST(table_owner AS sys.sysname) AS TABLE_OWNER, + CAST(table_name AS sys.sysname) AS TABLE_NAME, + CAST(table_type AS sys.varchar(32)) AS TABLE_TYPE, + remarks AS REMARKS + FROM sys.sp_tables_view + WHERE (@table_name IS NULL OR table_name LIKE @table_name collate database_default) + AND (@table_owner IS NULL OR table_owner LIKE @table_owner collate database_default) + AND (@table_qualifier IS NULL OR table_qualifier LIKE @table_qualifier collate database_default) + AND ( + @table_type IS NULL OR + (CAST(@table_type AS varchar(100)) LIKE '%''TABLE''%' collate database_default AND table_type = 'TABLE' collate database_default) OR + (CAST(@table_type AS varchar(100)) LIKE '%''VIEW''%' collate database_default AND table_type = 'VIEW' collate database_default) + ) + ORDER BY TABLE_QUALIFIER, TABLE_OWNER, TABLE_NAME; + ELSE + SELECT + CAST(table_qualifier AS sys.sysname) AS TABLE_QUALIFIER, + CAST(table_owner AS sys.sysname) AS TABLE_OWNER, + CAST(table_name AS sys.sysname) AS TABLE_NAME, + CAST(table_type AS sys.varchar(32)) AS TABLE_TYPE, + remarks AS REMARKS + FROM sys.sp_tables_view + WHERE (@table_name IS NULL OR table_name = @table_name collate database_default) + AND (@table_owner IS NULL OR table_owner = @table_owner collate database_default) + AND (@table_qualifier IS NULL OR table_qualifier = @table_qualifier collate database_default) + AND ( + @table_type IS NULL OR + (CAST(@table_type AS varchar(100)) LIKE '%''TABLE''%' collate database_default AND table_type = 'TABLE' collate database_default) OR + (CAST(@table_type AS varchar(100)) LIKE '%''VIEW''%' collate database_default AND table_type = 'VIEW' collate database_default) + ) + ORDER BY TABLE_QUALIFIER, TABLE_OWNER, TABLE_NAME; +END; +$$ +LANGUAGE 'pltsql'; +GRANT EXECUTE ON PROCEDURE sys.sp_tables TO PUBLIC; + +ALTER FUNCTION sys.sp_tables_internal RENAME TO sp_tables_internal_deprecated_in_4_4_0; + +CALL sys.babelfish_drop_deprecated_object('function', 'sys', 'sp_tables_internal_deprecated_in_4_4_0'); + +-- Drops the temporary procedure used by the upgrade script. +-- Please have this be one of the last statements executed in this upgrade script. +DROP PROCEDURE sys.babelfish_drop_deprecated_object(varchar, varchar, varchar); + -- After upgrade, always run analyze for all babelfish catalogs. CALL sys.analyze_babelfish_catalogs(); diff --git a/test/JDBC/expected/BABEL-SP_TABLES-vu-cleanup.out b/test/JDBC/expected/BABEL-SP_TABLES-vu-cleanup.out index f8085c9b80..1b547bc5fb 100644 --- a/test/JDBC/expected/BABEL-SP_TABLES-vu-cleanup.out +++ b/test/JDBC/expected/BABEL-SP_TABLES-vu-cleanup.out @@ -5,6 +5,12 @@ drop view babel_sp_tables_vu_prepare_t_sptables5 go drop table babel_sp_tables_vu_prepare_t_sptables go +drop table babel_sp_tables_vu_prepare_t_s_tables2 +go +drop table babel_sp_tables_vu_prepare_t__tables2 +go +drop table babel_sp_tables_vu_prepare_test_escape_chars_sp_tables +go drop table babel_sp_tables_vu_prepare_MyTable1 go drop table [babel_sp_tables_vu_prepare_MyTable2] diff --git a/test/JDBC/expected/BABEL-SP_TABLES-vu-prepare.out b/test/JDBC/expected/BABEL-SP_TABLES-vu-prepare.out index 8b54845d4f..1bcc5c3211 100644 --- a/test/JDBC/expected/BABEL-SP_TABLES-vu-prepare.out +++ b/test/JDBC/expected/BABEL-SP_TABLES-vu-prepare.out @@ -10,6 +10,12 @@ create table babel_sp_tables_vu_prepare_t_sptables2(b int) go create table babel_sp_tables_vu_prepare_t_sotables2(c int) go +create table babel_sp_tables_vu_prepare_t_s_tables2(c int) +go +create table babel_sp_tables_vu_prepare_t__tables2(c int) +go +create table babel_sp_tables_vu_prepare_test_escape_chars_sp_tables(c int) +go create table babel_sp_tables_vu_prepare_MyTable1 (a int, b int, c int) go create table [babel_sp_tables_vu_prepare_MyTable2] ([a] int, [b] int, [c] int) diff --git a/test/JDBC/expected/BABEL-SP_TABLES-vu-verify.out b/test/JDBC/expected/BABEL-SP_TABLES-vu-verify.out index 2d36807b26..6ec05d1977 100644 --- a/test/JDBC/expected/BABEL-SP_TABLES-vu-verify.out +++ b/test/JDBC/expected/BABEL-SP_TABLES-vu-verify.out @@ -185,16 +185,19 @@ exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t_s_tables2' go ~~START~~ varchar#!#varchar#!#varchar#!#varchar#!#varchar +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_s_tables2#!#TABLE#!# babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_sotables2#!#TABLE#!# babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_sptables2#!#TABLE#!# ~~END~~ --- NOTE: Incorrect output with [] wildcards, see BABEL-2452 +-- NOTE: Incorrect output with [] wildcards, see BABEL-2452 -- Fixed in BABEL-4128 exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t_s[op]tables2' go ~~START~~ varchar#!#varchar#!#varchar#!#varchar#!#varchar +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_sotables2#!#TABLE#!# +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_sptables2#!#TABLE#!# ~~END~~ @@ -202,6 +205,8 @@ exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t_s[^o]tables2' go ~~START~~ varchar#!#varchar#!#varchar#!#varchar#!#varchar +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_s_tables2#!#TABLE#!# +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_sptables2#!#TABLE#!# ~~END~~ @@ -209,6 +214,125 @@ exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t_s[o-p]tables2' go ~~START~~ varchar#!#varchar#!#varchar#!#varchar#!#varchar +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_sotables2#!#TABLE#!# +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_sptables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t[_]sptables', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_sptables#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t[_]sptables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_sptables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t[_]sotables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_sotables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t[_]sptables5', @table_type = "'VIEW'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_sptables5#!#VIEW#!# +~~END~~ + + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t_s[_]tables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_s_tables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t[_]s[_]tables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_s_tables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t[_][_]tables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t__tables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t[__]tables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +~~END~~ + + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t[[_]]sptables', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +~~END~~ + + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_test\_escape_chars\_sp_tables', @table_type = "'TABLE'" +GO +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +~~END~~ + + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_test\_escape\_chars\_sp\_tables', @table_type = "'TABLE'" +GO +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +~~END~~ + + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_test_escape_chars_sp_tables', @table_type = "'TABLE'" +GO +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_test_escape_chars_sp_tables#!#TABLE#!# +~~END~~ + + +-- table type with mixed case +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t_s[_]tables2', @table_type = "'Table'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_s_tables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t_s[_]tables2', @table_type = "'tAbLe'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_s_tables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t_s[_]tables2', @table_type = "'table'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +babel_sp_tables_vu_prepare_db1#!#dbo#!#babel_sp_tables_vu_prepare_t_s_tables2#!#TABLE#!# ~~END~~ diff --git a/test/JDBC/expected/BABEL-SP_TABLES.out b/test/JDBC/expected/BABEL-SP_TABLES.out index 90b4892761..aa9cc46852 100644 --- a/test/JDBC/expected/BABEL-SP_TABLES.out +++ b/test/JDBC/expected/BABEL-SP_TABLES.out @@ -10,6 +10,12 @@ create table t_sptables2(b int) go create table t_sotables2(c int) go +create table t_s_tables2(c int) +go +create table t__tables2(c int) +go +create table test_escape_chars_sp_tables(c int) +go create table MyTable1 (a int, b int, c int) go create table [MyTable2] ([a] int, [b] int, [c] int) @@ -203,16 +209,19 @@ exec sp_tables @table_name = 't_s_tables2' go ~~START~~ varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_s_tables2#!#TABLE#!# db1#!#dbo#!#t_sotables2#!#TABLE#!# db1#!#dbo#!#t_sptables2#!#TABLE#!# ~~END~~ --- NOTE: Incorrect output with [] wildcards, see BABEL-2452 +-- NOTE: Incorrect output with [] wildcards, see BABEL-2452 -- Fixed in BABEL-4128 exec sp_tables @table_name = 't_s[op]tables2' go ~~START~~ varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_sotables2#!#TABLE#!# +db1#!#dbo#!#t_sptables2#!#TABLE#!# ~~END~~ @@ -220,6 +229,8 @@ exec sp_tables @table_name = 't_s[^o]tables2' go ~~START~~ varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_s_tables2#!#TABLE#!# +db1#!#dbo#!#t_sptables2#!#TABLE#!# ~~END~~ @@ -227,6 +238,125 @@ exec sp_tables @table_name = 't_s[o-p]tables2' go ~~START~~ varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_sotables2#!#TABLE#!# +db1#!#dbo#!#t_sptables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't[_]sptables', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_sptables#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't[_]sptables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_sptables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't[_]sotables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_sotables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't[_]sptables5', @table_type = "'VIEW'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_sptables5#!#VIEW#!# +~~END~~ + + +exec sp_tables @table_name = 't_s[_]tables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_s_tables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't[_]s[_]tables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_s_tables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't[_][_]tables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t__tables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't[__]tables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +~~END~~ + + +exec sp_tables @table_name = 't[[_]]sptables', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +~~END~~ + + +exec sp_tables @table_name = 'test\_escape_chars\_sp_tables', @table_type = "'TABLE'" +GO +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +~~END~~ + + +exec sp_tables @table_name = 'test\_escape\_chars\_sp\_tables', @table_type = "'TABLE'" +GO +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +~~END~~ + + +exec sp_tables @table_name = 'test_escape_chars_sp_tables', @table_type = "'TABLE'" +GO +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#test_escape_chars_sp_tables#!#TABLE#!# +~~END~~ + + +-- table type with mixed case +exec sp_tables @table_name = 't_s[_]tables2', @table_type = "'Table'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_s_tables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't_s[_]tables2', @table_type = "'tAbLe'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_s_tables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't_s[_]tables2', @table_type = "'table'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_s_tables2#!#TABLE#!# ~~END~~ @@ -378,6 +508,12 @@ drop table t_sptables2 go drop table t_sotables2 go +drop table t_s_tables2 +go +drop table t__tables2 +go +drop table test_escape_chars_sp_tables +go use master go drop table t_sptables @@ -398,6 +534,12 @@ create table t_sptables2(b int) go create table t_sotables2(c int) go +create table t_s_tables2(c int) +go +create table t__tables2(c int) +go +create table test_escape_chars_sp_tables(c int) +go create table MyTable1 (a int, b int, c int) go create table [MyTable2] ([a] int, [b] int, [c] int) @@ -591,16 +733,19 @@ exec sp_tables @table_name = 't_s_tables2' go ~~START~~ varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_s_tables2#!#TABLE#!# db1#!#dbo#!#t_sotables2#!#TABLE#!# db1#!#dbo#!#t_sptables2#!#TABLE#!# ~~END~~ --- NOTE: Incorrect output with [] wildcards, see BABEL-2452 +-- NOTE: Incorrect output with [] wildcards, see BABEL-2452 -- Fixed in BABEL-4128 exec sp_tables @table_name = 't_s[op]tables2' go ~~START~~ varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_sotables2#!#TABLE#!# +db1#!#dbo#!#t_sptables2#!#TABLE#!# ~~END~~ @@ -608,6 +753,8 @@ exec sp_tables @table_name = 't_s[^o]tables2' go ~~START~~ varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_s_tables2#!#TABLE#!# +db1#!#dbo#!#t_sptables2#!#TABLE#!# ~~END~~ @@ -615,6 +762,125 @@ exec sp_tables @table_name = 't_s[o-p]tables2' go ~~START~~ varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_sotables2#!#TABLE#!# +db1#!#dbo#!#t_sptables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't[_]sptables', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_sptables#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't[_]sptables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_sptables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't[_]sotables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_sotables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't[_]sptables5', @table_type = "'VIEW'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_sptables5#!#VIEW#!# +~~END~~ + + +exec sp_tables @table_name = 't_s[_]tables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_s_tables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't[_]s[_]tables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_s_tables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't[_][_]tables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t__tables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't[__]tables2', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +~~END~~ + + +exec sp_tables @table_name = 't[[_]]sptables', @table_type = "'TABLE'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +~~END~~ + + +exec sp_tables @table_name = 'test\_escape_chars\_sp_tables', @table_type = "'TABLE'" +GO +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +~~END~~ + + +exec sp_tables @table_name = 'test\_escape\_chars\_sp\_tables', @table_type = "'TABLE'" +GO +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +~~END~~ + + +exec sp_tables @table_name = 'test_escape_chars_sp_tables', @table_type = "'TABLE'" +GO +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#test_escape_chars_sp_tables#!#TABLE#!# +~~END~~ + + +-- table type with mixed case +exec sp_tables @table_name = 't_s[_]tables2', @table_type = "'Table'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_s_tables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't_s[_]tables2', @table_type = "'tAbLe'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_s_tables2#!#TABLE#!# +~~END~~ + + +exec sp_tables @table_name = 't_s[_]tables2', @table_type = "'table'" +go +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar +db1#!#dbo#!#t_s_tables2#!#TABLE#!# ~~END~~ @@ -766,6 +1032,12 @@ drop table t_sptables2 go drop table t_sotables2 go +drop table t_s_tables2 +go +drop table t__tables2 +go +drop table test_escape_chars_sp_tables +go use master go drop table t_sptables diff --git a/test/JDBC/input/BABEL-SP_TABLES-vu-cleanup.sql b/test/JDBC/input/BABEL-SP_TABLES-vu-cleanup.sql index 1f676e3fad..a909bbc898 100644 --- a/test/JDBC/input/BABEL-SP_TABLES-vu-cleanup.sql +++ b/test/JDBC/input/BABEL-SP_TABLES-vu-cleanup.sql @@ -5,6 +5,12 @@ drop view babel_sp_tables_vu_prepare_t_sptables5 go drop table babel_sp_tables_vu_prepare_t_sptables go +drop table babel_sp_tables_vu_prepare_t_s_tables2 +go +drop table babel_sp_tables_vu_prepare_t__tables2 +go +drop table babel_sp_tables_vu_prepare_test_escape_chars_sp_tables +go drop table babel_sp_tables_vu_prepare_MyTable1 go drop table [babel_sp_tables_vu_prepare_MyTable2] diff --git a/test/JDBC/input/BABEL-SP_TABLES-vu-prepare.sql b/test/JDBC/input/BABEL-SP_TABLES-vu-prepare.sql index 0de03822c7..61856ca08e 100644 --- a/test/JDBC/input/BABEL-SP_TABLES-vu-prepare.sql +++ b/test/JDBC/input/BABEL-SP_TABLES-vu-prepare.sql @@ -10,6 +10,12 @@ create table babel_sp_tables_vu_prepare_t_sptables2(b int) go create table babel_sp_tables_vu_prepare_t_sotables2(c int) go +create table babel_sp_tables_vu_prepare_t_s_tables2(c int) +go +create table babel_sp_tables_vu_prepare_t__tables2(c int) +go +create table babel_sp_tables_vu_prepare_test_escape_chars_sp_tables(c int) +go create table babel_sp_tables_vu_prepare_MyTable1 (a int, b int, c int) go create table [babel_sp_tables_vu_prepare_MyTable2] ([a] int, [b] int, [c] int) diff --git a/test/JDBC/input/BABEL-SP_TABLES-vu-verify.sql b/test/JDBC/input/BABEL-SP_TABLES-vu-verify.sql index 35d317409a..5cea0f1cf8 100644 --- a/test/JDBC/input/BABEL-SP_TABLES-vu-verify.sql +++ b/test/JDBC/input/BABEL-SP_TABLES-vu-verify.sql @@ -75,7 +75,7 @@ go exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t_s_tables2' go --- NOTE: Incorrect output with [] wildcards, see BABEL-2452 +-- NOTE: Incorrect output with [] wildcards, see BABEL-2452 -- Fixed in BABEL-4128 exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t_s[op]tables2' go @@ -85,6 +85,52 @@ go exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t_s[o-p]tables2' go +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t[_]sptables', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t[_]sptables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t[_]sotables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t[_]sptables5', @table_type = "'VIEW'" +go + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t_s[_]tables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t[_]s[_]tables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t[_][_]tables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t[__]tables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t[[_]]sptables', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_test\_escape_chars\_sp_tables', @table_type = "'TABLE'" +GO + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_test\_escape\_chars\_sp\_tables', @table_type = "'TABLE'" +GO + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_test_escape_chars_sp_tables', @table_type = "'TABLE'" +GO + +-- table type with mixed case +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t_s[_]tables2', @table_type = "'Table'" +go + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t_s[_]tables2', @table_type = "'tAbLe'" +go + +exec sp_tables @table_name = 'babel_sp_tables_vu_prepare_t_s[_]tables2', @table_type = "'table'" +go + -- unnamed invocation exec sp_tables 'babel_sp_tables_vu_prepare_t_sptables', 'dbo', 'babel_sp_tables_vu_prepare_db1' go diff --git a/test/JDBC/input/BABEL-SP_TABLES.sql b/test/JDBC/input/BABEL-SP_TABLES.sql index d675fdf0bf..3afcf7c2d8 100644 --- a/test/JDBC/input/BABEL-SP_TABLES.sql +++ b/test/JDBC/input/BABEL-SP_TABLES.sql @@ -10,6 +10,12 @@ create table t_sptables2(b int) go create table t_sotables2(c int) go +create table t_s_tables2(c int) +go +create table t__tables2(c int) +go +create table test_escape_chars_sp_tables(c int) +go create table MyTable1 (a int, b int, c int) go create table [MyTable2] ([a] int, [b] int, [c] int) @@ -93,7 +99,7 @@ go exec sp_tables @table_name = 't_s_tables2' go --- NOTE: Incorrect output with [] wildcards, see BABEL-2452 +-- NOTE: Incorrect output with [] wildcards, see BABEL-2452 -- Fixed in BABEL-4128 exec sp_tables @table_name = 't_s[op]tables2' go @@ -103,6 +109,52 @@ go exec sp_tables @table_name = 't_s[o-p]tables2' go +exec sp_tables @table_name = 't[_]sptables', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 't[_]sptables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 't[_]sotables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 't[_]sptables5', @table_type = "'VIEW'" +go + +exec sp_tables @table_name = 't_s[_]tables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 't[_]s[_]tables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 't[_][_]tables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 't[__]tables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 't[[_]]sptables', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 'test\_escape_chars\_sp_tables', @table_type = "'TABLE'" +GO + +exec sp_tables @table_name = 'test\_escape\_chars\_sp\_tables', @table_type = "'TABLE'" +GO + +exec sp_tables @table_name = 'test_escape_chars_sp_tables', @table_type = "'TABLE'" +GO + +-- table type with mixed case +exec sp_tables @table_name = 't_s[_]tables2', @table_type = "'Table'" +go + +exec sp_tables @table_name = 't_s[_]tables2', @table_type = "'tAbLe'" +go + +exec sp_tables @table_name = 't_s[_]tables2', @table_type = "'table'" +go + -- unnamed invocation exec sp_tables 't_sptables', 'dbo', 'db1' go @@ -166,6 +218,12 @@ drop table t_sptables2 go drop table t_sotables2 go +drop table t_s_tables2 +go +drop table t__tables2 +go +drop table test_escape_chars_sp_tables +go use master go drop table t_sptables @@ -186,6 +244,12 @@ create table t_sptables2(b int) go create table t_sotables2(c int) go +create table t_s_tables2(c int) +go +create table t__tables2(c int) +go +create table test_escape_chars_sp_tables(c int) +go create table MyTable1 (a int, b int, c int) go create table [MyTable2] ([a] int, [b] int, [c] int) @@ -269,7 +333,7 @@ go exec sp_tables @table_name = 't_s_tables2' go --- NOTE: Incorrect output with [] wildcards, see BABEL-2452 +-- NOTE: Incorrect output with [] wildcards, see BABEL-2452 -- Fixed in BABEL-4128 exec sp_tables @table_name = 't_s[op]tables2' go @@ -279,6 +343,52 @@ go exec sp_tables @table_name = 't_s[o-p]tables2' go +exec sp_tables @table_name = 't[_]sptables', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 't[_]sptables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 't[_]sotables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 't[_]sptables5', @table_type = "'VIEW'" +go + +exec sp_tables @table_name = 't_s[_]tables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 't[_]s[_]tables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 't[_][_]tables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 't[__]tables2', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 't[[_]]sptables', @table_type = "'TABLE'" +go + +exec sp_tables @table_name = 'test\_escape_chars\_sp_tables', @table_type = "'TABLE'" +GO + +exec sp_tables @table_name = 'test\_escape\_chars\_sp\_tables', @table_type = "'TABLE'" +GO + +exec sp_tables @table_name = 'test_escape_chars_sp_tables', @table_type = "'TABLE'" +GO + +-- table type with mixed case +exec sp_tables @table_name = 't_s[_]tables2', @table_type = "'Table'" +go + +exec sp_tables @table_name = 't_s[_]tables2', @table_type = "'tAbLe'" +go + +exec sp_tables @table_name = 't_s[_]tables2', @table_type = "'table'" +go + -- unnamed invocation exec sp_tables 't_sptables', 'dbo', 'db1' go @@ -342,6 +452,12 @@ drop table t_sptables2 go drop table t_sotables2 go +drop table t_s_tables2 +go +drop table t__tables2 +go +drop table test_escape_chars_sp_tables +go use master go drop table t_sptables diff --git a/test/python/expected/sql_validation_framework/expected_create.out b/test/python/expected/sql_validation_framework/expected_create.out index ed0f2dd312..88557a42fe 100644 --- a/test/python/expected/sql_validation_framework/expected_create.out +++ b/test/python/expected/sql_validation_framework/expected_create.out @@ -42,7 +42,6 @@ Could not find tests for function sys.sp_releaseapplock_function Could not find tests for function sys.sp_special_columns_length_helper Could not find tests for function sys.sp_special_columns_precision_helper Could not find tests for function sys.sp_special_columns_scale_helper -Could not find tests for function sys.sp_tables_internal Could not find tests for function sys.suser_id_internal Could not find tests for function sys.suser_name_internal Could not find tests for function sys.systypes_precision_helper @@ -157,7 +156,6 @@ Could not find upgrade tests for function sys.sp_releaseapplock_function Could not find upgrade tests for function sys.sp_special_columns_length_helper Could not find upgrade tests for function sys.sp_special_columns_precision_helper Could not find upgrade tests for function sys.sp_special_columns_scale_helper -Could not find upgrade tests for function sys.sp_tables_internal Could not find upgrade tests for function sys.suser_id_internal Could not find upgrade tests for function sys.suser_name_internal Could not find upgrade tests for function sys.systypes_precision_helper diff --git a/test/python/expected/sql_validation_framework/expected_drop.out b/test/python/expected/sql_validation_framework/expected_drop.out index 92d73d2703..243d664edf 100644 --- a/test/python/expected/sql_validation_framework/expected_drop.out +++ b/test/python/expected/sql_validation_framework/expected_drop.out @@ -65,6 +65,7 @@ Unexpected drop found for procedure sys.babelfish_drop_deprecated_object in file Unexpected drop found for procedure sys.babelfish_drop_deprecated_object in file babelfishpg_tsql--4.0.0--4.1.0.sql Unexpected drop found for procedure sys.babelfish_drop_deprecated_object in file babelfishpg_tsql--4.1.0--4.2.0.sql Unexpected drop found for procedure sys.babelfish_drop_deprecated_object in file babelfishpg_tsql--4.2.0--4.3.0.sql +Unexpected drop found for procedure sys.babelfish_drop_deprecated_object in file babelfishpg_tsql--4.3.0--4.4.0.sql Unexpected drop found for procedure sys.babelfish_drop_deprecated_table in file babelfishpg_tsql--2.1.0--2.2.0.sql Unexpected drop found for procedure sys.babelfish_drop_deprecated_view in file babelfishpg_tsql--1.0.0--1.1.0.sql Unexpected drop found for procedure sys.babelfish_drop_deprecated_view in file babelfishpg_tsql--2.1.0--2.2.0.sql diff --git a/test/python/expected/upgrade_validation/expected_dependency.out b/test/python/expected/upgrade_validation/expected_dependency.out index 5a82564bc2..8ff508f5bb 100644 --- a/test/python/expected/upgrade_validation/expected_dependency.out +++ b/test/python/expected/upgrade_validation/expected_dependency.out @@ -637,7 +637,6 @@ Function sys.sp_releaseapplock_function(character varying,character varying,char Function sys.sp_special_columns_length_helper(text,integer,smallint,bigint) Function sys.sp_special_columns_precision_helper(text,integer,smallint,bigint) Function sys.sp_special_columns_scale_helper(text,integer) -Function sys.sp_tables_internal(sys.nvarchar,sys.nvarchar,sys.sysname,sys."varchar",sys."bit") Function sys.sql_variant_property(sys.sql_variant,sys."varchar") Function sys.sqlvariant_bbfbinary(sys.sql_variant) Function sys.sqlvariant_bigint(sys.sql_variant) From 576373c5a2b8d87d99a898e0f65de689d07551a7 Mon Sep 17 00:00:00 2001 From: Anikait Agrawal <54908236+Anikait143@users.noreply.github.com> Date: Thu, 19 Sep 2024 13:46:26 +0530 Subject: [PATCH 3/3] Fix date functions to take into account the timezone setting (#2947) Issues - When the timezone parameter group setting is set to something other than the default UTC, Babelfish date related functions like SYSDATETIME(), SYSDATETIMEOFFSET(), GETDATE() and CURRENT_TIMESTAMP don't take it into account, while they should. The same issue occurs with a session-level timezone parameter. SYSDATETIMEOFFSET() function returns datetimeoffset which does not store timezone due to incorrect casting function. Changes made to fix the issues - Added appropriate CAST from TIMESTAMP to respective return types of date functions to ensure proper accounting for timezone setting. Added timestamptz_datetimeoffset function for converting timestamp with time zone to datetimeoffset. It ensures to store timezone property similar to timestamptz_datetime2 and timestamptz_datetime functions. Task: BABEL-5069 Signed-off-by: Anikait Agrawal --- .../src/babelfishpg_common.c | 4 +- .../src/babelfishpg_common.h | 4 +- .../babelfishpg_common/src/datetimeoffset.c | 38 ++ .../babelfishpg_common/src/datetimeoffset.h | 5 +- contrib/babelfishpg_tsql/runtime/functions.c | 12 +- ...getdate-before-15_9-or-16_5-vu-cleanup.out | 29 + ...getdate-before-15_9-or-16_5-vu-prepare.out | 139 ++++ .../getdate-before-15_9-or-16_5-vu-verify.out | 79 +++ test/JDBC/expected/getdate-vu-cleanup.out | 36 ++ test/JDBC/expected/getdate-vu-prepare.out | 125 ++++ test/JDBC/expected/getdate-vu-verify.out | 601 ++++++++++++++++++ ...getdate-before-15_9-or-16_5-vu-cleanup.sql | 29 + ...getdate-before-15_9-or-16_5-vu-prepare.sql | 139 ++++ ...getdate-before-15_9-or-16_5-vu-verify.sql} | 0 test/JDBC/input/getdate-vu-cleanup.sql | 38 +- test/JDBC/input/getdate-vu-prepare.sql | 113 ++++ test/JDBC/input/getdate-vu-verify.mix | 200 ++++++ test/JDBC/jdbc_schedule | 3 + test/JDBC/upgrade/13_4/schedule | 2 +- test/JDBC/upgrade/13_5/schedule | 2 +- test/JDBC/upgrade/13_6/schedule | 2 +- test/JDBC/upgrade/13_7/schedule | 2 +- test/JDBC/upgrade/13_8/schedule | 2 +- test/JDBC/upgrade/13_9/schedule | 2 +- test/JDBC/upgrade/14_10/schedule | 1 + test/JDBC/upgrade/14_11/schedule | 1 + test/JDBC/upgrade/14_12/schedule | 1 + test/JDBC/upgrade/14_13/schedule | 1 + test/JDBC/upgrade/14_14/schedule | 1 + test/JDBC/upgrade/14_3/schedule | 1 + test/JDBC/upgrade/14_5/schedule | 2 +- test/JDBC/upgrade/14_6/schedule | 2 +- test/JDBC/upgrade/14_7/schedule | 2 +- test/JDBC/upgrade/14_8/schedule | 2 +- test/JDBC/upgrade/14_9/schedule | 2 +- test/JDBC/upgrade/15_1/schedule | 2 +- test/JDBC/upgrade/15_2/schedule | 2 +- test/JDBC/upgrade/15_3/schedule | 2 +- test/JDBC/upgrade/15_4/schedule | 1 + test/JDBC/upgrade/15_5/schedule | 1 + test/JDBC/upgrade/15_6/schedule | 1 + test/JDBC/upgrade/15_7/schedule | 1 + test/JDBC/upgrade/15_8/schedule | 1 + test/JDBC/upgrade/15_9/schedule | 1 + test/JDBC/upgrade/16_1/schedule | 1 + test/JDBC/upgrade/16_2/schedule | 1 + test/JDBC/upgrade/16_3/schedule | 1 + test/JDBC/upgrade/16_4/schedule | 1 + test/JDBC/upgrade/latest/schedule | 1 + .../expected_dependency.out | 11 - 50 files changed, 1615 insertions(+), 35 deletions(-) create mode 100644 test/JDBC/expected/getdate-before-15_9-or-16_5-vu-cleanup.out create mode 100644 test/JDBC/expected/getdate-before-15_9-or-16_5-vu-prepare.out create mode 100644 test/JDBC/expected/getdate-before-15_9-or-16_5-vu-verify.out create mode 100644 test/JDBC/input/getdate-before-15_9-or-16_5-vu-cleanup.sql create mode 100644 test/JDBC/input/getdate-before-15_9-or-16_5-vu-prepare.sql rename test/JDBC/input/{getdate-vu-verify.sql => getdate-before-15_9-or-16_5-vu-verify.sql} (100%) create mode 100644 test/JDBC/input/getdate-vu-verify.mix diff --git a/contrib/babelfishpg_common/src/babelfishpg_common.c b/contrib/babelfishpg_common/src/babelfishpg_common.c index 70a931a7c2..4e6fd71f1e 100644 --- a/contrib/babelfishpg_common/src/babelfishpg_common.c +++ b/contrib/babelfishpg_common/src/babelfishpg_common.c @@ -191,7 +191,9 @@ get_common_utility_plugin(void) common_utility_plugin_var.is_tsql_rowversion_or_timestamp_datatype = &is_tsql_rowversion_or_timestamp_datatype; common_utility_plugin_var.datetime_in_str = &datetime_in_str; common_utility_plugin_var.datetime2sqlvariant = &datetime2sqlvariant; - common_utility_plugin_var.timestamp_datetimeoffset = ×tamp_datetimeoffset; + common_utility_plugin_var.timestamptz_datetimeoffset = ×tamptz_datetimeoffset; + common_utility_plugin_var.timestamptz_datetime2 = ×tamptz_datetime2; + common_utility_plugin_var.timestamptz_datetime = ×tamptz_datetime; common_utility_plugin_var.datetimeoffset_timestamp = &datetimeoffset_timestamp; common_utility_plugin_var.tinyint2sqlvariant = &tinyint2sqlvariant; common_utility_plugin_var.translate_pg_type_to_tsql = &translate_pg_type_to_tsql; diff --git a/contrib/babelfishpg_common/src/babelfishpg_common.h b/contrib/babelfishpg_common/src/babelfishpg_common.h index e3c821031d..7d147e8e0d 100644 --- a/contrib/babelfishpg_common/src/babelfishpg_common.h +++ b/contrib/babelfishpg_common/src/babelfishpg_common.h @@ -63,7 +63,9 @@ typedef struct common_utility_plugin bool (*is_tsql_rowversion_or_timestamp_datatype) (Oid oid); Datum (*datetime_in_str) (char *str, Node *escontext); Datum (*datetime2sqlvariant) (PG_FUNCTION_ARGS); - Datum (*timestamp_datetimeoffset) (PG_FUNCTION_ARGS); + Datum (*timestamptz_datetimeoffset) (PG_FUNCTION_ARGS); + Datum (*timestamptz_datetime2) (PG_FUNCTION_ARGS); + Datum (*timestamptz_datetime) (PG_FUNCTION_ARGS); Datum (*datetimeoffset_timestamp) (PG_FUNCTION_ARGS); Datum (*tinyint2sqlvariant) (PG_FUNCTION_ARGS); Datum (*translate_pg_type_to_tsql) (PG_FUNCTION_ARGS); diff --git a/contrib/babelfishpg_common/src/datetimeoffset.c b/contrib/babelfishpg_common/src/datetimeoffset.c index 73924f167a..c78a5444d0 100644 --- a/contrib/babelfishpg_common/src/datetimeoffset.c +++ b/contrib/babelfishpg_common/src/datetimeoffset.c @@ -52,6 +52,7 @@ PG_FUNCTION_INFO_V1(datetimeoffset_mi); PG_FUNCTION_INFO_V1(datetimeoffset_hash); PG_FUNCTION_INFO_V1(datetimeoffset_hash_extended); +PG_FUNCTION_INFO_V1(timestamptz_datetimeoffset); PG_FUNCTION_INFO_V1(timestamp_datetimeoffset); PG_FUNCTION_INFO_V1(datetimeoffset_timestamp); PG_FUNCTION_INFO_V1(date_datetimeoffset); @@ -643,6 +644,43 @@ timestamp_datetimeoffset(PG_FUNCTION_ARGS) PG_RETURN_DATETIMEOFFSET(result); } +/* timestamptz_datetimeoffset() + * Convert timestamp with time zone to datetimeoffset + */ +Datum +timestamptz_datetimeoffset(PG_FUNCTION_ARGS) +{ + TimestampTz timestamp = PG_GETARG_TIMESTAMPTZ(0); + Timestamp time; + tsql_datetimeoffset *result; + + struct pg_tm tt, + *tm = &tt; + fsec_t fsec; + int tz = 0; + + if (TIMESTAMP_NOT_FINITE(timestamp)) + time = timestamp; + else + { + if (timestamp2tm(timestamp, &tz, tm, &fsec, NULL, NULL) != 0) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("data out of range for datetimeoffset"))); + if (tm2timestamp(tm, fsec, NULL, &time) != 0) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("data out of range for datetimeoffset"))); + } + + result = (tsql_datetimeoffset *) palloc(DATETIMEOFFSET_LEN); + result->tsql_ts = time; + result->tsql_tz = (int16) tz / 60; + CheckDatetimeoffsetRange(result, fcinfo->context); + + PG_RETURN_DATETIMEOFFSET(result); +} + /* datetimeoffset_timestamp() * Convert datetimeoffset to timestamp */ diff --git a/contrib/babelfishpg_common/src/datetimeoffset.h b/contrib/babelfishpg_common/src/datetimeoffset.h index 0380344586..3a1cd5ebf1 100644 --- a/contrib/babelfishpg_common/src/datetimeoffset.h +++ b/contrib/babelfishpg_common/src/datetimeoffset.h @@ -8,6 +8,7 @@ #ifndef DATETIMEOFFSET_H #define DATETIMEOFFSET_H #include "fmgr.h" // check if necessary +#include "utils/timestamp.h" /* datetimeoffset size in bytes */ #define DATETIMEOFFSET_LEN MAXALIGN(sizeof(tsql_datetimeoffset)) @@ -25,7 +26,9 @@ extern void AdjustTimestampForSmallDatetime(Timestamp *time); extern void CheckSmalldatetimeRange(const Timestamp time, Node *escontext); extern void CheckDatetimeRange(const Timestamp time, Node *escontext); extern void CheckDatetime2Range(const Timestamp time, Node *escontext); -extern Datum timestamp_datetimeoffset(PG_FUNCTION_ARGS); +extern Datum timestamptz_datetimeoffset(PG_FUNCTION_ARGS); +extern Datum timestamptz_datetime2(PG_FUNCTION_ARGS); +extern Datum timestamptz_datetime(PG_FUNCTION_ARGS); extern Datum datetimeoffset_timestamp(PG_FUNCTION_ARGS); typedef struct tsql_datetimeoffset { diff --git a/contrib/babelfishpg_tsql/runtime/functions.c b/contrib/babelfishpg_tsql/runtime/functions.c index 5571e54f5f..7b0a10f9b2 100644 --- a/contrib/babelfishpg_tsql/runtime/functions.c +++ b/contrib/babelfishpg_tsql/runtime/functions.c @@ -943,21 +943,21 @@ Datum getutcdate(PG_FUNCTION_ARGS) Datum getdate_internal(PG_FUNCTION_ARGS) { - PG_RETURN_DATUM(DirectFunctionCall2(timestamp_trunc,CStringGetTextDatum("millisecond"), - TimestampTzGetDatum(GetCurrentStatementStartTimestamp()))); + PG_RETURN_DATUM(DirectFunctionCall1(common_utility_plugin_ptr->timestamptz_datetime, + DirectFunctionCall2(timestamptz_trunc,CStringGetTextDatum("millisecond"), + TimestampTzGetDatum(GetCurrentStatementStartTimestamp())))); } Datum sysdatetime(PG_FUNCTION_ARGS) { - PG_RETURN_TIMESTAMPTZ(GetCurrentStatementStartTimestamp()); + PG_RETURN_DATUM(DirectFunctionCall1(common_utility_plugin_ptr->timestamptz_datetime2, + TimestampTzGetDatum(GetCurrentStatementStartTimestamp()))); } Datum sysdatetimeoffset(PG_FUNCTION_ARGS) { - - - PG_RETURN_DATUM(DirectFunctionCall1(common_utility_plugin_ptr->timestamp_datetimeoffset, + PG_RETURN_DATUM(DirectFunctionCall1(common_utility_plugin_ptr->timestamptz_datetimeoffset, TimestampTzGetDatum(GetCurrentStatementStartTimestamp()))); } diff --git a/test/JDBC/expected/getdate-before-15_9-or-16_5-vu-cleanup.out b/test/JDBC/expected/getdate-before-15_9-or-16_5-vu-cleanup.out new file mode 100644 index 0000000000..d4ee9cf6b3 --- /dev/null +++ b/test/JDBC/expected/getdate-before-15_9-or-16_5-vu-cleanup.out @@ -0,0 +1,29 @@ +DROP PROCEDURE sysdatetime_dep_proc +go + +DROP PROCEDURE sysdatetimeoffset_dep_proc +go + +DROP PROCEDURE sysutcdatetime_dep_proc +go + +DROP PROCEDURE getdate_dep_proc +go + +DROP PROCEDURE getutcdate_dep_proc +go + +DROP VIEW sysdatetime_dep_view +go + +DROP VIEW sysdatetimeoffset_dep_view +go + +DROP VIEW sysutcdatetime_dep_view +go + +DROP VIEW getdate_dep_view +go + +DROP VIEW getutcdate_dep_view +go diff --git a/test/JDBC/expected/getdate-before-15_9-or-16_5-vu-prepare.out b/test/JDBC/expected/getdate-before-15_9-or-16_5-vu-prepare.out new file mode 100644 index 0000000000..2cbd5e1691 --- /dev/null +++ b/test/JDBC/expected/getdate-before-15_9-or-16_5-vu-prepare.out @@ -0,0 +1,139 @@ +Create procedure sysdatetime_dep_proc +AS + WITH + Pass0 as (select sys.sysdatetime() as C union all select sys.sysdatetime()), --2 rows + Pass1 as (select sys.sysdatetime() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.sysdatetime() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.sysdatetime() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.sysdatetime() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sys.sysdatetime() +GO + +Create procedure sysdatetimeoffset_dep_proc +AS + WITH + Pass0 as (select sys.sysdatetimeoffset() as C union all select sys.sysdatetimeoffset()), --2 rows + Pass1 as (select sys.sysdatetimeoffset() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.sysdatetimeoffset() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.sysdatetimeoffset() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.sysdatetimeoffset() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sys.sysdatetimeoffset() +GO + +Create procedure sysutcdatetime_dep_proc +AS + WITH + Pass0 as (select sys.sysutcdatetime() as C union all select sys.sysutcdatetime()), --2 rows + Pass1 as (select sys.sysutcdatetime() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.sysutcdatetime() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.sysutcdatetime() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.sysutcdatetime() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sysutcdatetime() +GO + +Create procedure getdate_dep_proc +AS + WITH + Pass0 as (select sys.getdate() as C union all select sys.getdate()), --2 rows + Pass1 as (select sys.getdate() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.getdate() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.getdate() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.getdate() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sys.getdate() +GO + +Create procedure getutcdate_dep_proc +AS + WITH + Pass0 as (select sys.getutcdate() as C union all select sys.getutcdate()), --2 rows + Pass1 as (select sys.getutcdate() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.getutcdate() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.getutcdate() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.getutcdate() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sys.getutcdate() +GO + +Create view sysdatetime_dep_view +AS + WITH + Pass0 as (select sys.sysdatetime() as C union all select sys.sysdatetime()), --2 rows + Pass1 as (select sys.sysdatetime() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.sysdatetime() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.sysdatetime() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.sysdatetime() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sys.sysdatetime() +GO + +Create view sysdatetimeoffset_dep_view +AS + WITH + Pass0 as (select sys.sysdatetimeoffset() as C union all select sys.sysdatetimeoffset()), --2 rows + Pass1 as (select sys.sysdatetimeoffset() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.sysdatetimeoffset() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.sysdatetimeoffset() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.sysdatetimeoffset() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sys.sysdatetimeoffset() +GO + +Create view sysutcdatetime_dep_view +AS + WITH + Pass0 as (select sys.sysutcdatetime() as C union all select sys.sysutcdatetime()), --2 rows + Pass1 as (select sys.sysutcdatetime() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.sysutcdatetime() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.sysutcdatetime() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.sysutcdatetime() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sysutcdatetime() +GO + +Create view getdate_dep_view +AS + WITH + Pass0 as (select sys.getdate() as C union all select sys.getdate()), --2 rows + Pass1 as (select sys.getdate() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.getdate() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.getdate() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.getdate() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sys.getdate() +GO + +Create view getutcdate_dep_view +AS + WITH + Pass0 as (select sys.getutcdate() as C union all select sys.getutcdate()), --2 rows + Pass1 as (select sys.getutcdate() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.getutcdate() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.getutcdate() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.getutcdate() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sys.getutcdate() +GO diff --git a/test/JDBC/expected/getdate-before-15_9-or-16_5-vu-verify.out b/test/JDBC/expected/getdate-before-15_9-or-16_5-vu-verify.out new file mode 100644 index 0000000000..740b70ebb7 --- /dev/null +++ b/test/JDBC/expected/getdate-before-15_9-or-16_5-vu-verify.out @@ -0,0 +1,79 @@ +exec sysdatetime_dep_proc +go +~~START~~ +int +65536 +~~END~~ + + +exec sysdatetimeoffset_dep_proc +go +~~START~~ +int +65536 +~~END~~ + + +exec sysutcdatetime_dep_proc +go +~~START~~ +int +65536 +~~END~~ + + +exec getdate_dep_proc +go +~~START~~ +int +65536 +~~END~~ + + +exec getutcdate_dep_proc +go +~~START~~ +int +65536 +~~END~~ + + +Select * from sysdatetime_dep_view +go +~~START~~ +int +65536 +~~END~~ + + +select * from sysdatetimeoffset_dep_view +go +~~START~~ +int +65536 +~~END~~ + + +select * from sysutcdatetime_dep_view +go +~~START~~ +int +65536 +~~END~~ + + +select * from getdate_dep_view +go +~~START~~ +int +65536 +~~END~~ + + +select * from getutcdate_dep_view +go +~~START~~ +int +65536 +~~END~~ + diff --git a/test/JDBC/expected/getdate-vu-cleanup.out b/test/JDBC/expected/getdate-vu-cleanup.out index d4ee9cf6b3..6f2cf8fa97 100644 --- a/test/JDBC/expected/getdate-vu-cleanup.out +++ b/test/JDBC/expected/getdate-vu-cleanup.out @@ -27,3 +27,39 @@ go DROP VIEW getutcdate_dep_view go + +DROP PROCEDURE dbo.GetSysDatetimeDiff +go + +DROP PROCEDURE dbo.GetSysDatetimeOffsetDiff +go + +DROP PROCEDURE dbo.GetDateDiff +go + +DROP PROCEDURE dbo.GetCurrTimestampDiff +go + +DROP VIEW dbo.datetimediffView +go + +DROP TRIGGER trgdatetimediff +go + +DROP TABLE trgdatetimediffTestTab +go + +DROP TABLE datetimediffTable +go + +DROP FUNCTION dbo.GetSysDatetimeDiffFunc +go + +DROP FUNCTION dbo.GetSysDatetimeOffsetDiffFunc +go + +DROP FUNCTION dbo.GetDateDiffFunc +go + +DROP FUNCTION dbo.GetCurrTimestampDiffFunc +go diff --git a/test/JDBC/expected/getdate-vu-prepare.out b/test/JDBC/expected/getdate-vu-prepare.out index 2cbd5e1691..610ea43b18 100644 --- a/test/JDBC/expected/getdate-vu-prepare.out +++ b/test/JDBC/expected/getdate-vu-prepare.out @@ -137,3 +137,128 @@ AS FROM Tally WHERE min_getdate = sys.getutcdate() GO + +CREATE PROCEDURE dbo.GetSysDatetimeDiff +AS +BEGIN + DECLARE @x datetime2 = SYSDATETIME(); + select set_config('timezone', 'US/Pacific', false); + DECLARE @y datetime2 = SYSDATETIME() + select set_config('timezone', 'UTC', false); + SELECT DATEDIFF(MINUTE, @y, @x); +END; +GO + +CREATE PROCEDURE dbo.GetSysDatetimeOffsetDiff +AS +BEGIN + DECLARE @x datetime2 = sysdatetimeoffset(); + select set_config('timezone', 'US/Pacific', false); + DECLARE @y datetime2 = sysdatetimeoffset() + select set_config('timezone', 'UTC', false); + SELECT DATEDIFF(MINUTE, @y, @x); +END; +GO + +CREATE PROCEDURE dbo.GetDateDiff +AS +BEGIN + DECLARE @x datetime2 = getdate(); + select set_config('timezone', 'US/Pacific', false); + DECLARE @y datetime2 = getdate() + select set_config('timezone', 'UTC', false); + SELECT DATEDIFF(MINUTE, @y, @x); +END; +GO + +CREATE PROCEDURE dbo.GetCurrTimestampDiff +AS +BEGIN + DECLARE @x datetime2 = CURRENT_TIMESTAMP; + select set_config('timezone', 'US/Pacific', false); + DECLARE @y datetime2 = CURRENT_TIMESTAMP + select set_config('timezone', 'UTC', false); + SELECT DATEDIFF(MINUTE, @y, @x); +END; +GO + +CREATE TABLE datetimediffTable(sysdatetime int, sysdatetimeoffset int, getdate int, currtimestamp int) +GO + +DECLARE @sysdatetime1 datetime2, @sysdatetimeoffset1 datetime2, @getdate1 datetime2, @currtimestamp1 datetime2; +DECLARE @sysdatetime2 datetime2, @sysdatetimeoffset2 datetime2, @getdate2 datetime2, @currtimestamp2 datetime2; +SELECT @sysdatetime1 = SYSDATETIME(), @sysdatetimeoffset1 = sysdatetimeoffset(), @getdate1 = getdate(), @currtimestamp1 = CURRENT_TIMESTAMP; +select set_config('timezone', 'US/Pacific', false); +SELECT @sysdatetime2 = SYSDATETIME(), @sysdatetimeoffset2 = sysdatetimeoffset(), @getdate2 = getdate(), @currtimestamp2 = CURRENT_TIMESTAMP; +select set_config('timezone', 'UTC', false); +INSERT INTO datetimediffTable values (DATEDIFF(MINUTE, @sysdatetime2, @sysdatetime1), DATEDIFF(MINUTE, @sysdatetimeoffset2, @sysdatetimeoffset1), DATEDIFF(MINUTE, @getdate2, @getdate1), DATEDIFF(MINUTE, @currtimestamp2, @currtimestamp1)) +GO +~~START~~ +text +US/Pacific +~~END~~ + +~~START~~ +text +UTC +~~END~~ + +~~ROW COUNT: 1~~ + + +CREATE VIEW dbo.datetimediffView AS SELECT * FROM datetimediffTable; +GO + +CREATE FUNCTION dbo.GetSysDatetimeDiffFunc(@sysdatetime1 datetime2) +RETURNS int +AS +BEGIN + DECLARE @x datetime2 = SYSDATETIME(); + RETURN DATEDIFF(MINUTE, @sysdatetime1, @x); +END; +GO + +CREATE FUNCTION dbo.GetSysDatetimeOffsetDiffFunc(@sysdatetimeoffset1 datetime2) +RETURNS int +AS +BEGIN + DECLARE @x datetime2 = sysdatetimeoffset(); + RETURN DATEDIFF(MINUTE, @sysdatetimeoffset1, @x); +END; +GO + +CREATE FUNCTION dbo.GetDateDiffFunc(@getdate1 datetime2) +RETURNS int +AS +BEGIN + DECLARE @x datetime2 = getdate(); + RETURN DATEDIFF(MINUTE, @getdate1, @x); +END; +GO + +CREATE FUNCTION dbo.GetCurrTimestampDiffFunc(@currtimestamp1 datetime2) +RETURNS int +AS +BEGIN + DECLARE @x datetime2 = CURRENT_TIMESTAMP; + RETURN DATEDIFF(MINUTE, @currtimestamp1, @x); +END; +GO + +CREATE TABLE trgdatetimediffTestTab(sysdatetime int, sysdatetimeoffset int, getdate int, currtimestamp int) +GO + +CREATE TRIGGER trgdatetimediff +ON datetimediffTable +AFTER INSERT +AS +BEGIN + DECLARE @sysdatetime1 datetime2, @sysdatetimeoffset1 datetime2, @getdate1 datetime2, @currtimestamp1 datetime2; + DECLARE @sysdatetime2 datetime2, @sysdatetimeoffset2 datetime2, @getdate2 datetime2, @currtimestamp2 datetime2; + SELECT @sysdatetime1 = SYSDATETIME(), @sysdatetimeoffset1 = sysdatetimeoffset(), @getdate1 = getdate(), @currtimestamp1 = CURRENT_TIMESTAMP; + select set_config('timezone', 'US/Pacific', false); + SELECT @sysdatetime2 = SYSDATETIME(), @sysdatetimeoffset2 = sysdatetimeoffset(), @getdate2 = getdate(), @currtimestamp2 = CURRENT_TIMESTAMP; + select set_config('timezone', 'UTC', false); + INSERT INTO trgdatetimediffTestTab values (DATEDIFF(MINUTE, @sysdatetime2, @sysdatetime1), DATEDIFF(MINUTE, @sysdatetimeoffset2, @sysdatetimeoffset1), DATEDIFF(MINUTE, @getdate2, @getdate1), DATEDIFF(MINUTE, @currtimestamp2, @currtimestamp1)) +END; +GO diff --git a/test/JDBC/expected/getdate-vu-verify.out b/test/JDBC/expected/getdate-vu-verify.out index 740b70ebb7..4b0fc6b2f0 100644 --- a/test/JDBC/expected/getdate-vu-verify.out +++ b/test/JDBC/expected/getdate-vu-verify.out @@ -77,3 +77,604 @@ int 65536 ~~END~~ + +declare @x datetime2 = sysdatetime() +select set_config('timezone', 'US/Pacific', false); +declare @y datetime2 = sysdatetime() +select set_config('timezone', 'UTC', false); +select DATEDIFF(MINUTE, @y, @x) +go +~~START~~ +text +US/Pacific +~~END~~ + +~~START~~ +text +UTC +~~END~~ + +~~START~~ +int +420 +~~END~~ + + +declare @x datetime2 = sysdatetimeoffset() +select set_config('timezone', 'US/Pacific', false); +declare @y datetime2 = sysdatetimeoffset() +select set_config('timezone', 'UTC', false); +select DATEDIFF(MINUTE, @y, @x) +go +~~START~~ +text +US/Pacific +~~END~~ + +~~START~~ +text +UTC +~~END~~ + +~~START~~ +int +420 +~~END~~ + + +declare @x datetime2 = getdate() +select set_config('timezone', 'US/Pacific', false); +declare @y datetime2 = getdate() +select set_config('timezone', 'UTC', false); +select DATEDIFF(MINUTE, @y, @x) +go +~~START~~ +text +US/Pacific +~~END~~ + +~~START~~ +text +UTC +~~END~~ + +~~START~~ +int +420 +~~END~~ + + +declare @x datetime2 = CURRENT_TIMESTAMP +select set_config('timezone', 'US/Pacific', false); +declare @y datetime2 = CURRENT_TIMESTAMP +select set_config('timezone', 'UTC', false); +select DATEDIFF(MINUTE, @y, @x) +go +~~START~~ +text +US/Pacific +~~END~~ + +~~START~~ +text +UTC +~~END~~ + +~~START~~ +int +420 +~~END~~ + + +declare @x datetime2 = sysdatetime() AT TIME ZONE 'Pacific Standard Time' +declare @y datetime2 = sysdatetime() AT TIME ZONE 'UTC' +select DATEDIFF(MINUTE, @y, @x) +go +~~START~~ +int +0 +~~END~~ + + +declare @x datetime2 = sysdatetimeoffset() AT TIME ZONE 'Pacific Standard Time' +declare @y datetime2 = sysdatetimeoffset() AT TIME ZONE 'UTC' +select DATEDIFF(MINUTE, @y, @x) +go +~~START~~ +int +-420 +~~END~~ + + +declare @x datetime2 = getdate() AT TIME ZONE 'Pacific Standard Time' +declare @y datetime2 = getdate() AT TIME ZONE 'UTC' +select DATEDIFF(MINUTE, @y, @x) +go +~~START~~ +int +0 +~~END~~ + + +declare @x datetime2 = CURRENT_TIMESTAMP AT TIME ZONE 'Pacific Standard Time' +declare @y datetime2 = CURRENT_TIMESTAMP AT TIME ZONE 'UTC' +select DATEDIFF(MINUTE, @y, @x) +go +~~START~~ +int +0 +~~END~~ + + +EXEC dbo.GetSysDatetimeDiff; +go +~~START~~ +text +US/Pacific +~~END~~ + +~~START~~ +text +UTC +~~END~~ + +~~START~~ +int +420 +~~END~~ + + +EXEC dbo.GetSysDatetimeOffsetDiff; +go +~~START~~ +text +US/Pacific +~~END~~ + +~~START~~ +text +UTC +~~END~~ + +~~START~~ +int +420 +~~END~~ + + +EXEC dbo.GetDateDiff; +go +~~START~~ +text +US/Pacific +~~END~~ + +~~START~~ +text +UTC +~~END~~ + +~~START~~ +int +420 +~~END~~ + + +EXEC dbo.GetCurrTimestampDiff; +go +~~START~~ +text +US/Pacific +~~END~~ + +~~START~~ +text +UTC +~~END~~ + +~~START~~ +int +420 +~~END~~ + + +SELECT * from dbo.datetimediffView; +go +~~START~~ +int#!#int#!#int#!#int +420#!#420#!#420#!#420 +~~END~~ + + +declare @x datetime2 = SYSDATETIME(); +select set_config('timezone', 'US/Pacific', false); +select dbo.GetSysDatetimeDiffFunc(@x) +select set_config('timezone', 'UTC', false); +go +~~START~~ +text +US/Pacific +~~END~~ + +~~START~~ +int +-420 +~~END~~ + +~~START~~ +text +UTC +~~END~~ + + +declare @x datetime2 = sysdatetimeoffset(); +select set_config('timezone', 'US/Pacific', false); +select dbo.GetSysDatetimeOffsetDiffFunc(@x) +select set_config('timezone', 'UTC', false); +go +~~START~~ +text +US/Pacific +~~END~~ + +~~START~~ +int +-420 +~~END~~ + +~~START~~ +text +UTC +~~END~~ + + +declare @x datetime2 = getdate(); +select set_config('timezone', 'US/Pacific', false); +select dbo.GetDateDiffFunc(@x) +select set_config('timezone', 'UTC', false); +go +~~START~~ +text +US/Pacific +~~END~~ + +~~START~~ +int +-420 +~~END~~ + +~~START~~ +text +UTC +~~END~~ + + +declare @x datetime2 = CURRENT_TIMESTAMP; +select set_config('timezone', 'US/Pacific', false); +select dbo.GetCurrTimestampDiffFunc(@x) +select set_config('timezone', 'UTC', false); +go +~~START~~ +text +US/Pacific +~~END~~ + +~~START~~ +int +-420 +~~END~~ + +~~START~~ +text +UTC +~~END~~ + + +INSERT INTO datetimediffTable values (0, 0, 0, 0) +go +~~START~~ +text +US/Pacific +~~END~~ + +~~START~~ +text +UTC +~~END~~ + +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +SELECT * from trgdatetimediffTestTab; +go +~~START~~ +int#!#int#!#int#!#int +420#!#420#!#420#!#420 +~~END~~ + + +-- psql +SET timezone = '+05:30'; +select sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +GO +~~START~~ +interval +-05:30:00 +~~END~~ + +~~START~~ +interval +-05:30:00 +~~END~~ + +~~START~~ +interval +-05:30:00 +~~END~~ + +~~START~~ +interval +-05:30:00 +~~END~~ + + +SET timezone = DEFAULT; +select sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +GO +~~START~~ +interval +00:00:00 +~~END~~ + +~~START~~ +interval +00:00:00 +~~END~~ + +~~START~~ +interval +00:00:00 +~~END~~ + +~~START~~ +interval +00:00:00 +~~END~~ + + +SET timezone = 'Asia/Kolkata'; +select sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +GO +~~START~~ +interval +05:30:00 +~~END~~ + +~~START~~ +interval +05:30:00 +~~END~~ + +~~START~~ +interval +05:30:00 +~~END~~ + +~~START~~ +interval +05:30:00 +~~END~~ + + +SET timezone = +5.5; +select sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +GO +~~START~~ +interval +05:30:00 +~~END~~ + +~~START~~ +interval +05:30:00 +~~END~~ + +~~START~~ +interval +05:30:00 +~~END~~ + +~~START~~ +interval +05:30:00 +~~END~~ + + +SET TIME ZONE '+05:30'; +select sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +GO +~~START~~ +interval +-05:30:00 +~~END~~ + +~~START~~ +interval +-05:30:00 +~~END~~ + +~~START~~ +interval +-05:30:00 +~~END~~ + +~~START~~ +interval +-05:30:00 +~~END~~ + + +SET TIME ZONE DEFAULT; +select sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +GO +~~START~~ +interval +00:00:00 +~~END~~ + +~~START~~ +interval +00:00:00 +~~END~~ + +~~START~~ +interval +00:00:00 +~~END~~ + +~~START~~ +interval +00:00:00 +~~END~~ + + +SET TIME ZONE +5.5; +select sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +GO +~~START~~ +interval +05:30:00 +~~END~~ + +~~START~~ +interval +05:30:00 +~~END~~ + +~~START~~ +interval +05:30:00 +~~END~~ + +~~START~~ +interval +05:30:00 +~~END~~ + + +SET TIME ZONE 'Asia/Kolkata'; +select sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +GO +~~START~~ +interval +05:30:00 +~~END~~ + +~~START~~ +interval +05:30:00 +~~END~~ + +~~START~~ +interval +05:30:00 +~~END~~ + +~~START~~ +interval +05:30:00 +~~END~~ + + +SET timezone = DEFAULT; +BEGIN; +SET LOCAL TIME ZONE 'Asia/Kolkata'; +SELECT sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +COMMIT; +GO +~~START~~ +interval +05:30:00 +~~END~~ + +~~START~~ +interval +05:30:00 +~~END~~ + +~~START~~ +interval +05:30:00 +~~END~~ + +~~START~~ +interval +05:30:00 +~~END~~ + + +SELECT * from master_dbo.datetimediffView; +GO +~~START~~ +int4#!#int4#!#int4#!#int4 +420#!#420#!#420#!#420 +0#!#0#!#0#!#0 +~~END~~ + + +SET TIME ZONE 'Asia/Kolkata'; +select master_dbo.GetSysDatetimeOffsetDiffFunc(CAST(sys.sysdatetimeoffset() AS sys.datetime2)); +select master_dbo.GetSysDatetimeDiffFunc(sys.SYSDATETIME()); +select master_dbo.GetDateDiffFunc(sys.getdate()); +select master_dbo.GetCurrTimestampDiffFunc(CAST(CURRENT_TIMESTAMP AS sys.datetime2)); +SET timezone = DEFAULT; +GO +~~START~~ +int4 +0 +~~END~~ + +~~START~~ +int4 +0 +~~END~~ + +~~START~~ +int4 +0 +~~END~~ + +~~START~~ +int4 +0 +~~END~~ + diff --git a/test/JDBC/input/getdate-before-15_9-or-16_5-vu-cleanup.sql b/test/JDBC/input/getdate-before-15_9-or-16_5-vu-cleanup.sql new file mode 100644 index 0000000000..de6154af0b --- /dev/null +++ b/test/JDBC/input/getdate-before-15_9-or-16_5-vu-cleanup.sql @@ -0,0 +1,29 @@ +DROP PROCEDURE sysdatetime_dep_proc +go + +DROP PROCEDURE sysdatetimeoffset_dep_proc +go + +DROP PROCEDURE sysutcdatetime_dep_proc +go + +DROP PROCEDURE getdate_dep_proc +go + +DROP PROCEDURE getutcdate_dep_proc +go + +DROP VIEW sysdatetime_dep_view +go + +DROP VIEW sysdatetimeoffset_dep_view +go + +DROP VIEW sysutcdatetime_dep_view +go + +DROP VIEW getdate_dep_view +go + +DROP VIEW getutcdate_dep_view +go \ No newline at end of file diff --git a/test/JDBC/input/getdate-before-15_9-or-16_5-vu-prepare.sql b/test/JDBC/input/getdate-before-15_9-or-16_5-vu-prepare.sql new file mode 100644 index 0000000000..2cbd5e1691 --- /dev/null +++ b/test/JDBC/input/getdate-before-15_9-or-16_5-vu-prepare.sql @@ -0,0 +1,139 @@ +Create procedure sysdatetime_dep_proc +AS + WITH + Pass0 as (select sys.sysdatetime() as C union all select sys.sysdatetime()), --2 rows + Pass1 as (select sys.sysdatetime() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.sysdatetime() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.sysdatetime() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.sysdatetime() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sys.sysdatetime() +GO + +Create procedure sysdatetimeoffset_dep_proc +AS + WITH + Pass0 as (select sys.sysdatetimeoffset() as C union all select sys.sysdatetimeoffset()), --2 rows + Pass1 as (select sys.sysdatetimeoffset() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.sysdatetimeoffset() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.sysdatetimeoffset() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.sysdatetimeoffset() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sys.sysdatetimeoffset() +GO + +Create procedure sysutcdatetime_dep_proc +AS + WITH + Pass0 as (select sys.sysutcdatetime() as C union all select sys.sysutcdatetime()), --2 rows + Pass1 as (select sys.sysutcdatetime() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.sysutcdatetime() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.sysutcdatetime() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.sysutcdatetime() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sysutcdatetime() +GO + +Create procedure getdate_dep_proc +AS + WITH + Pass0 as (select sys.getdate() as C union all select sys.getdate()), --2 rows + Pass1 as (select sys.getdate() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.getdate() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.getdate() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.getdate() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sys.getdate() +GO + +Create procedure getutcdate_dep_proc +AS + WITH + Pass0 as (select sys.getutcdate() as C union all select sys.getutcdate()), --2 rows + Pass1 as (select sys.getutcdate() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.getutcdate() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.getutcdate() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.getutcdate() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sys.getutcdate() +GO + +Create view sysdatetime_dep_view +AS + WITH + Pass0 as (select sys.sysdatetime() as C union all select sys.sysdatetime()), --2 rows + Pass1 as (select sys.sysdatetime() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.sysdatetime() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.sysdatetime() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.sysdatetime() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sys.sysdatetime() +GO + +Create view sysdatetimeoffset_dep_view +AS + WITH + Pass0 as (select sys.sysdatetimeoffset() as C union all select sys.sysdatetimeoffset()), --2 rows + Pass1 as (select sys.sysdatetimeoffset() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.sysdatetimeoffset() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.sysdatetimeoffset() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.sysdatetimeoffset() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sys.sysdatetimeoffset() +GO + +Create view sysutcdatetime_dep_view +AS + WITH + Pass0 as (select sys.sysutcdatetime() as C union all select sys.sysutcdatetime()), --2 rows + Pass1 as (select sys.sysutcdatetime() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.sysutcdatetime() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.sysutcdatetime() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.sysutcdatetime() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sysutcdatetime() +GO + +Create view getdate_dep_view +AS + WITH + Pass0 as (select sys.getdate() as C union all select sys.getdate()), --2 rows + Pass1 as (select sys.getdate() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.getdate() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.getdate() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.getdate() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sys.getdate() +GO + +Create view getutcdate_dep_view +AS + WITH + Pass0 as (select sys.getutcdate() as C union all select sys.getutcdate()), --2 rows + Pass1 as (select sys.getutcdate() as C from Pass0 as A, Pass0 as B),--4 rows + Pass2 as (select sys.getutcdate() as C from Pass1 as A, Pass1 as B),--16 rows + Pass3 as (select sys.getutcdate() as C from Pass2 as A, Pass2 as B),--256 rows + Pass4 as (select sys.getutcdate() as C from Pass3 as A, Pass3 as B),--65536 rows + Tally as (select row_number() over(order by C) as Number, min(C) over () as min_getdate from Pass4) + SELECT count(min_getdate) + FROM Tally + WHERE min_getdate = sys.getutcdate() +GO diff --git a/test/JDBC/input/getdate-vu-verify.sql b/test/JDBC/input/getdate-before-15_9-or-16_5-vu-verify.sql similarity index 100% rename from test/JDBC/input/getdate-vu-verify.sql rename to test/JDBC/input/getdate-before-15_9-or-16_5-vu-verify.sql diff --git a/test/JDBC/input/getdate-vu-cleanup.sql b/test/JDBC/input/getdate-vu-cleanup.sql index de6154af0b..6f2cf8fa97 100644 --- a/test/JDBC/input/getdate-vu-cleanup.sql +++ b/test/JDBC/input/getdate-vu-cleanup.sql @@ -26,4 +26,40 @@ DROP VIEW getdate_dep_view go DROP VIEW getutcdate_dep_view -go \ No newline at end of file +go + +DROP PROCEDURE dbo.GetSysDatetimeDiff +go + +DROP PROCEDURE dbo.GetSysDatetimeOffsetDiff +go + +DROP PROCEDURE dbo.GetDateDiff +go + +DROP PROCEDURE dbo.GetCurrTimestampDiff +go + +DROP VIEW dbo.datetimediffView +go + +DROP TRIGGER trgdatetimediff +go + +DROP TABLE trgdatetimediffTestTab +go + +DROP TABLE datetimediffTable +go + +DROP FUNCTION dbo.GetSysDatetimeDiffFunc +go + +DROP FUNCTION dbo.GetSysDatetimeOffsetDiffFunc +go + +DROP FUNCTION dbo.GetDateDiffFunc +go + +DROP FUNCTION dbo.GetCurrTimestampDiffFunc +go diff --git a/test/JDBC/input/getdate-vu-prepare.sql b/test/JDBC/input/getdate-vu-prepare.sql index 2cbd5e1691..98f032ae0f 100644 --- a/test/JDBC/input/getdate-vu-prepare.sql +++ b/test/JDBC/input/getdate-vu-prepare.sql @@ -137,3 +137,116 @@ AS FROM Tally WHERE min_getdate = sys.getutcdate() GO + +CREATE PROCEDURE dbo.GetSysDatetimeDiff +AS +BEGIN + DECLARE @x datetime2 = SYSDATETIME(); + select set_config('timezone', 'US/Pacific', false); + DECLARE @y datetime2 = SYSDATETIME() + select set_config('timezone', 'UTC', false); + SELECT DATEDIFF(MINUTE, @y, @x); +END; +GO + +CREATE PROCEDURE dbo.GetSysDatetimeOffsetDiff +AS +BEGIN + DECLARE @x datetime2 = sysdatetimeoffset(); + select set_config('timezone', 'US/Pacific', false); + DECLARE @y datetime2 = sysdatetimeoffset() + select set_config('timezone', 'UTC', false); + SELECT DATEDIFF(MINUTE, @y, @x); +END; +GO + +CREATE PROCEDURE dbo.GetDateDiff +AS +BEGIN + DECLARE @x datetime2 = getdate(); + select set_config('timezone', 'US/Pacific', false); + DECLARE @y datetime2 = getdate() + select set_config('timezone', 'UTC', false); + SELECT DATEDIFF(MINUTE, @y, @x); +END; +GO + +CREATE PROCEDURE dbo.GetCurrTimestampDiff +AS +BEGIN + DECLARE @x datetime2 = CURRENT_TIMESTAMP; + select set_config('timezone', 'US/Pacific', false); + DECLARE @y datetime2 = CURRENT_TIMESTAMP + select set_config('timezone', 'UTC', false); + SELECT DATEDIFF(MINUTE, @y, @x); +END; +GO + +CREATE TABLE datetimediffTable(sysdatetime int, sysdatetimeoffset int, getdate int, currtimestamp int) +GO + +DECLARE @sysdatetime1 datetime2, @sysdatetimeoffset1 datetime2, @getdate1 datetime2, @currtimestamp1 datetime2; +DECLARE @sysdatetime2 datetime2, @sysdatetimeoffset2 datetime2, @getdate2 datetime2, @currtimestamp2 datetime2; +SELECT @sysdatetime1 = SYSDATETIME(), @sysdatetimeoffset1 = sysdatetimeoffset(), @getdate1 = getdate(), @currtimestamp1 = CURRENT_TIMESTAMP; +select set_config('timezone', 'US/Pacific', false); +SELECT @sysdatetime2 = SYSDATETIME(), @sysdatetimeoffset2 = sysdatetimeoffset(), @getdate2 = getdate(), @currtimestamp2 = CURRENT_TIMESTAMP; +select set_config('timezone', 'UTC', false); +INSERT INTO datetimediffTable values (DATEDIFF(MINUTE, @sysdatetime2, @sysdatetime1), DATEDIFF(MINUTE, @sysdatetimeoffset2, @sysdatetimeoffset1), DATEDIFF(MINUTE, @getdate2, @getdate1), DATEDIFF(MINUTE, @currtimestamp2, @currtimestamp1)) +GO + +CREATE VIEW dbo.datetimediffView AS SELECT * FROM datetimediffTable; +GO + +CREATE FUNCTION dbo.GetSysDatetimeDiffFunc(@sysdatetime1 datetime2) +RETURNS int +AS +BEGIN + DECLARE @x datetime2 = SYSDATETIME(); + RETURN DATEDIFF(MINUTE, @sysdatetime1, @x); +END; +GO + +CREATE FUNCTION dbo.GetSysDatetimeOffsetDiffFunc(@sysdatetimeoffset1 datetime2) +RETURNS int +AS +BEGIN + DECLARE @x datetime2 = sysdatetimeoffset(); + RETURN DATEDIFF(MINUTE, @sysdatetimeoffset1, @x); +END; +GO + +CREATE FUNCTION dbo.GetDateDiffFunc(@getdate1 datetime2) +RETURNS int +AS +BEGIN + DECLARE @x datetime2 = getdate(); + RETURN DATEDIFF(MINUTE, @getdate1, @x); +END; +GO + +CREATE FUNCTION dbo.GetCurrTimestampDiffFunc(@currtimestamp1 datetime2) +RETURNS int +AS +BEGIN + DECLARE @x datetime2 = CURRENT_TIMESTAMP; + RETURN DATEDIFF(MINUTE, @currtimestamp1, @x); +END; +GO + +CREATE TABLE trgdatetimediffTestTab(sysdatetime int, sysdatetimeoffset int, getdate int, currtimestamp int) +GO + +CREATE TRIGGER trgdatetimediff +ON datetimediffTable +AFTER INSERT +AS +BEGIN + DECLARE @sysdatetime1 datetime2, @sysdatetimeoffset1 datetime2, @getdate1 datetime2, @currtimestamp1 datetime2; + DECLARE @sysdatetime2 datetime2, @sysdatetimeoffset2 datetime2, @getdate2 datetime2, @currtimestamp2 datetime2; + SELECT @sysdatetime1 = SYSDATETIME(), @sysdatetimeoffset1 = sysdatetimeoffset(), @getdate1 = getdate(), @currtimestamp1 = CURRENT_TIMESTAMP; + select set_config('timezone', 'US/Pacific', false); + SELECT @sysdatetime2 = SYSDATETIME(), @sysdatetimeoffset2 = sysdatetimeoffset(), @getdate2 = getdate(), @currtimestamp2 = CURRENT_TIMESTAMP; + select set_config('timezone', 'UTC', false); + INSERT INTO trgdatetimediffTestTab values (DATEDIFF(MINUTE, @sysdatetime2, @sysdatetime1), DATEDIFF(MINUTE, @sysdatetimeoffset2, @sysdatetimeoffset1), DATEDIFF(MINUTE, @getdate2, @getdate1), DATEDIFF(MINUTE, @currtimestamp2, @currtimestamp1)) +END; +GO diff --git a/test/JDBC/input/getdate-vu-verify.mix b/test/JDBC/input/getdate-vu-verify.mix new file mode 100644 index 0000000000..b3f4ead6e1 --- /dev/null +++ b/test/JDBC/input/getdate-vu-verify.mix @@ -0,0 +1,200 @@ +exec sysdatetime_dep_proc +go + +exec sysdatetimeoffset_dep_proc +go + +exec sysutcdatetime_dep_proc +go + +exec getdate_dep_proc +go + +exec getutcdate_dep_proc +go + +Select * from sysdatetime_dep_view +go + +select * from sysdatetimeoffset_dep_view +go + +select * from sysutcdatetime_dep_view +go + +select * from getdate_dep_view +go + +select * from getutcdate_dep_view +go + +declare @x datetime2 = sysdatetime() +select set_config('timezone', 'US/Pacific', false); +declare @y datetime2 = sysdatetime() +select set_config('timezone', 'UTC', false); +select DATEDIFF(MINUTE, @y, @x) +go + +declare @x datetime2 = sysdatetimeoffset() +select set_config('timezone', 'US/Pacific', false); +declare @y datetime2 = sysdatetimeoffset() +select set_config('timezone', 'UTC', false); +select DATEDIFF(MINUTE, @y, @x) +go + +declare @x datetime2 = getdate() +select set_config('timezone', 'US/Pacific', false); +declare @y datetime2 = getdate() +select set_config('timezone', 'UTC', false); +select DATEDIFF(MINUTE, @y, @x) +go + +declare @x datetime2 = CURRENT_TIMESTAMP +select set_config('timezone', 'US/Pacific', false); +declare @y datetime2 = CURRENT_TIMESTAMP +select set_config('timezone', 'UTC', false); +select DATEDIFF(MINUTE, @y, @x) +go + +declare @x datetime2 = sysdatetime() AT TIME ZONE 'Pacific Standard Time' +declare @y datetime2 = sysdatetime() AT TIME ZONE 'UTC' +select DATEDIFF(MINUTE, @y, @x) +go + +declare @x datetime2 = sysdatetimeoffset() AT TIME ZONE 'Pacific Standard Time' +declare @y datetime2 = sysdatetimeoffset() AT TIME ZONE 'UTC' +select DATEDIFF(MINUTE, @y, @x) +go + +declare @x datetime2 = getdate() AT TIME ZONE 'Pacific Standard Time' +declare @y datetime2 = getdate() AT TIME ZONE 'UTC' +select DATEDIFF(MINUTE, @y, @x) +go + +declare @x datetime2 = CURRENT_TIMESTAMP AT TIME ZONE 'Pacific Standard Time' +declare @y datetime2 = CURRENT_TIMESTAMP AT TIME ZONE 'UTC' +select DATEDIFF(MINUTE, @y, @x) +go + +EXEC dbo.GetSysDatetimeDiff; +go + +EXEC dbo.GetSysDatetimeOffsetDiff; +go + +EXEC dbo.GetDateDiff; +go + +EXEC dbo.GetCurrTimestampDiff; +go + +SELECT * from dbo.datetimediffView; +go + +declare @x datetime2 = SYSDATETIME(); +select set_config('timezone', 'US/Pacific', false); +select dbo.GetSysDatetimeDiffFunc(@x) +select set_config('timezone', 'UTC', false); +go + +declare @x datetime2 = sysdatetimeoffset(); +select set_config('timezone', 'US/Pacific', false); +select dbo.GetSysDatetimeOffsetDiffFunc(@x) +select set_config('timezone', 'UTC', false); +go + +declare @x datetime2 = getdate(); +select set_config('timezone', 'US/Pacific', false); +select dbo.GetDateDiffFunc(@x) +select set_config('timezone', 'UTC', false); +go + +declare @x datetime2 = CURRENT_TIMESTAMP; +select set_config('timezone', 'US/Pacific', false); +select dbo.GetCurrTimestampDiffFunc(@x) +select set_config('timezone', 'UTC', false); +go + +INSERT INTO datetimediffTable values (0, 0, 0, 0) +go + +SELECT * from trgdatetimediffTestTab; +go + +-- psql +SET timezone = '+05:30'; +select sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +GO + +SET timezone = DEFAULT; +select sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +GO + +SET timezone = 'Asia/Kolkata'; +select sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +GO + +SET timezone = +5.5; +select sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +GO + +SET TIME ZONE '+05:30'; +select sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +GO + +SET TIME ZONE DEFAULT; +select sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +GO + +SET TIME ZONE +5.5; +select sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +GO + +SET TIME ZONE 'Asia/Kolkata'; +select sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +GO + +SET timezone = DEFAULT; +BEGIN; +SET LOCAL TIME ZONE 'Asia/Kolkata'; +SELECT sys.SYSDATETIME() - sys.SYSDATETIME() AT TIME ZONE 'UTC'; +select sys.getdate() - sys.getdate() AT TIME ZONE 'UTC'; +select CURRENT_TIMESTAMP - CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; +select CAST(sys.sysdatetimeoffset() AS sys.datetime2) - CAST(sys.sysdatetimeoffset() AS sys.datetime2) AT TIME ZONE 'UTC'; +COMMIT; +GO + +SELECT * from master_dbo.datetimediffView; +GO + +SET TIME ZONE 'Asia/Kolkata'; +select master_dbo.GetSysDatetimeOffsetDiffFunc(CAST(sys.sysdatetimeoffset() AS sys.datetime2)); +select master_dbo.GetSysDatetimeDiffFunc(sys.SYSDATETIME()); +select master_dbo.GetDateDiffFunc(sys.getdate()); +select master_dbo.GetCurrTimestampDiffFunc(CAST(CURRENT_TIMESTAMP AS sys.datetime2)); +SET timezone = DEFAULT; +GO diff --git a/test/JDBC/jdbc_schedule b/test/JDBC/jdbc_schedule index 795c4f4e0e..455bc5ced3 100644 --- a/test/JDBC/jdbc_schedule +++ b/test/JDBC/jdbc_schedule @@ -377,6 +377,9 @@ ignore#!#alter-procedure-15_8-or-16_4-vu-cleanup ignore#!#string_agg-before-15_9-or-16_5-vu-prepare ignore#!#string_agg-before-15_9-or-16_5-vu-verify ignore#!#string_agg-before-15_9-or-16_5-vu-cleanup +ignore#!#getdate-before-15_9-or-16_5-vu-cleanup +ignore#!#getdate-before-15_9-or-16_5-vu-prepare +ignore#!#getdate-before-15_9-or-16_5-vu-verify ignore#!#string_agg-before-14_5-vu-prepare ignore#!#string_agg-before-14_5-vu-verify ignore#!#string_agg-before-14_5-vu-cleanup diff --git a/test/JDBC/upgrade/13_4/schedule b/test/JDBC/upgrade/13_4/schedule index b37f02d849..1d38aee8a8 100644 --- a/test/JDBC/upgrade/13_4/schedule +++ b/test/JDBC/upgrade/13_4/schedule @@ -220,7 +220,7 @@ timefromparts triggers_with_transaction BABEL-4046 table_constraint_wo_comma-before-15_6-or-16_2 -getdate +getdate-before-15_9-or-16_5 AUTO_ANALYZE-before-15-5-or-14-10 cast_eliminate order_by_offset_fetch_rows-before-15_6-or-16_2 diff --git a/test/JDBC/upgrade/13_5/schedule b/test/JDBC/upgrade/13_5/schedule index b154c7de17..593063108f 100644 --- a/test/JDBC/upgrade/13_5/schedule +++ b/test/JDBC/upgrade/13_5/schedule @@ -272,7 +272,7 @@ timefromparts triggers_with_transaction BABEL-4046 table_constraint_wo_comma-before-15_6-or-16_2 -getdate +getdate-before-15_9-or-16_5 AUTO_ANALYZE-before-15-5-or-14-10 cast_eliminate order_by_offset_fetch_rows-before-15_6-or-16_2 diff --git a/test/JDBC/upgrade/13_6/schedule b/test/JDBC/upgrade/13_6/schedule index c35b38509d..951a6e1491 100644 --- a/test/JDBC/upgrade/13_6/schedule +++ b/test/JDBC/upgrade/13_6/schedule @@ -327,7 +327,7 @@ timefromparts triggers_with_transaction BABEL-4046 table_constraint_wo_comma-before-15_6-or-16_2 -getdate +getdate-before-15_9-or-16_5 BABEL-4410 AUTO_ANALYZE-before-15-5-or-14-10 TestDatatypeAggSort diff --git a/test/JDBC/upgrade/13_7/schedule b/test/JDBC/upgrade/13_7/schedule index 9f7f2b456d..b878d790fe 100644 --- a/test/JDBC/upgrade/13_7/schedule +++ b/test/JDBC/upgrade/13_7/schedule @@ -321,7 +321,7 @@ timefromparts triggers_with_transaction BABEL-4046 table_constraint_wo_comma-before-15_6-or-16_2 -getdate +getdate-before-15_9-or-16_5 AUTO_ANALYZE-before-15-5-or-14-10 cast_eliminate order_by_offset_fetch_rows-before-15_6-or-16_2 diff --git a/test/JDBC/upgrade/13_8/schedule b/test/JDBC/upgrade/13_8/schedule index 4110ef1a11..119ecf99dc 100644 --- a/test/JDBC/upgrade/13_8/schedule +++ b/test/JDBC/upgrade/13_8/schedule @@ -321,7 +321,7 @@ timefromparts triggers_with_transaction BABEL-4046 table_constraint_wo_comma-before-15_6-or-16_2 -getdate +getdate-before-15_9-or-16_5 AUTO_ANALYZE-before-15-5-or-14-10 cast_eliminate order_by_offset_fetch_rows-before-15_6-or-16_2 diff --git a/test/JDBC/upgrade/13_9/schedule b/test/JDBC/upgrade/13_9/schedule index 87598a9c1e..37fdf67074 100644 --- a/test/JDBC/upgrade/13_9/schedule +++ b/test/JDBC/upgrade/13_9/schedule @@ -323,7 +323,7 @@ timefromparts triggers_with_transaction BABEL-4046 table_constraint_wo_comma-before-15_6-or-16_2 -getdate +getdate-before-15_9-or-16_5 BABEL-4410 AUTO_ANALYZE-before-15-5-or-14-10 cast_eliminate diff --git a/test/JDBC/upgrade/14_10/schedule b/test/JDBC/upgrade/14_10/schedule index 8361886fe1..beb43d8043 100644 --- a/test/JDBC/upgrade/14_10/schedule +++ b/test/JDBC/upgrade/14_10/schedule @@ -458,6 +458,7 @@ reverse-before-15_8-or-16_4 stuff-before-15_8-or-16_4 replicate-before-15_8-or-16_4 string_agg-before-15_9-or-16_5 +getdate-before-15_9-or-16_5 space binary-datatype-operators cast-varchar-to-time diff --git a/test/JDBC/upgrade/14_11/schedule b/test/JDBC/upgrade/14_11/schedule index 198278e520..c3e8018e36 100644 --- a/test/JDBC/upgrade/14_11/schedule +++ b/test/JDBC/upgrade/14_11/schedule @@ -456,6 +456,7 @@ reverse-before-15_8-or-16_4 stuff-before-15_8-or-16_4 replicate-before-15_8-or-16_4 string_agg-before-15_9-or-16_5 +getdate-before-15_9-or-16_5 space binary-datatype-operators cast-varchar-to-time diff --git a/test/JDBC/upgrade/14_12/schedule b/test/JDBC/upgrade/14_12/schedule index 0b30ad71f7..3a7f033ff2 100644 --- a/test/JDBC/upgrade/14_12/schedule +++ b/test/JDBC/upgrade/14_12/schedule @@ -457,6 +457,7 @@ reverse-before-15_8-or-16_4 stuff-before-15_8-or-16_4 replicate-before-15_8-or-16_4 string_agg-before-15_9-or-16_5 +getdate-before-15_9-or-16_5 space binary-datatype-operators cast-varchar-to-time diff --git a/test/JDBC/upgrade/14_13/schedule b/test/JDBC/upgrade/14_13/schedule index 2ba8238fb3..b382cf58a9 100644 --- a/test/JDBC/upgrade/14_13/schedule +++ b/test/JDBC/upgrade/14_13/schedule @@ -457,6 +457,7 @@ reverse-before-15_8-or-16_4 stuff-before-15_8-or-16_4 replicate-before-15_8-or-16_4 string_agg-before-15_9-or-16_5 +getdate-before-15_9-or-16_5 space binary-datatype-operators cast-varchar-to-time diff --git a/test/JDBC/upgrade/14_14/schedule b/test/JDBC/upgrade/14_14/schedule index 2ba8238fb3..b382cf58a9 100644 --- a/test/JDBC/upgrade/14_14/schedule +++ b/test/JDBC/upgrade/14_14/schedule @@ -457,6 +457,7 @@ reverse-before-15_8-or-16_4 stuff-before-15_8-or-16_4 replicate-before-15_8-or-16_4 string_agg-before-15_9-or-16_5 +getdate-before-15_9-or-16_5 space binary-datatype-operators cast-varchar-to-time diff --git a/test/JDBC/upgrade/14_3/schedule b/test/JDBC/upgrade/14_3/schedule index 1d1f2c701a..4022b96bac 100644 --- a/test/JDBC/upgrade/14_3/schedule +++ b/test/JDBC/upgrade/14_3/schedule @@ -378,6 +378,7 @@ reverse-before-15_8-or-16_4 stuff-before-15_8-or-16_4 replicate-before-15_8-or-16_4 string_agg-before-14_5 +getdate-before-15_9-or-16_5 space binary-datatype-operators cast-varchar-to-time diff --git a/test/JDBC/upgrade/14_5/schedule b/test/JDBC/upgrade/14_5/schedule index a232872e6e..7ee0776874 100644 --- a/test/JDBC/upgrade/14_5/schedule +++ b/test/JDBC/upgrade/14_5/schedule @@ -355,7 +355,7 @@ timefromparts triggers_with_transaction BABEL-4046 table_constraint_wo_comma-before-15_6-or-16_2 -getdate +getdate-before-15_9-or-16_5 BABEL_4330-before-15_8-or-16_4 BABEL-4410 AUTO_ANALYZE-before-15-5-or-14-10 diff --git a/test/JDBC/upgrade/14_6/schedule b/test/JDBC/upgrade/14_6/schedule index 001d5d63cd..ef7e3736b2 100644 --- a/test/JDBC/upgrade/14_6/schedule +++ b/test/JDBC/upgrade/14_6/schedule @@ -391,7 +391,7 @@ timefromparts triggers_with_transaction BABEL-4046 table_constraint_wo_comma-before-15_6-or-16_2 -getdate +getdate-before-15_9-or-16_5 BABEL_4330-before-15_8-or-16_4 BABEL-4410 AUTO_ANALYZE-before-15-5-or-14-10 diff --git a/test/JDBC/upgrade/14_7/schedule b/test/JDBC/upgrade/14_7/schedule index 9e84cc3153..b12f17b421 100644 --- a/test/JDBC/upgrade/14_7/schedule +++ b/test/JDBC/upgrade/14_7/schedule @@ -414,7 +414,7 @@ triggers_with_transaction datetimeoffset-timezone-before-15_3 BABEL-4046 table_constraint_wo_comma-before-15_6-or-16_2 -getdate +getdate-before-15_9-or-16_5 BABEL_4330-before-15_8-or-16_4 AUTO_ANALYZE-before-15-5-or-14-10 cast_eliminate diff --git a/test/JDBC/upgrade/14_8/schedule b/test/JDBC/upgrade/14_8/schedule index 5e5dbcf665..7be63b7d01 100644 --- a/test/JDBC/upgrade/14_8/schedule +++ b/test/JDBC/upgrade/14_8/schedule @@ -412,7 +412,7 @@ triggers_with_transaction datetimeoffset-timezone-before-15_3 BABEL-4046 table_constraint_wo_comma-before-15_6-or-16_2 -getdate +getdate-before-15_9-or-16_5 BABEL_4330-before-15_8-or-16_4 AUTO_ANALYZE-before-15-5-or-14-10 default_params diff --git a/test/JDBC/upgrade/14_9/schedule b/test/JDBC/upgrade/14_9/schedule index 4778a128b6..16572c3e0f 100644 --- a/test/JDBC/upgrade/14_9/schedule +++ b/test/JDBC/upgrade/14_9/schedule @@ -412,7 +412,7 @@ BABEL-3215 orderby BABEL-4046 table_constraint_wo_comma-before-15_6-or-16_2 -getdate +getdate-before-15_9-or-16_5 BABEL_4330-before-15_8-or-16_4 BABEL-4410 AUTO_ANALYZE-before-15-5-or-14-10 diff --git a/test/JDBC/upgrade/15_1/schedule b/test/JDBC/upgrade/15_1/schedule index 74ebe53ae8..8503cbdbb7 100644 --- a/test/JDBC/upgrade/15_1/schedule +++ b/test/JDBC/upgrade/15_1/schedule @@ -390,7 +390,7 @@ timefromparts triggers_with_transaction BABEL-4046 table_constraint_wo_comma-before-15_6-or-16_2 -getdate +getdate-before-15_9-or-16_5 BABEL_4330-before-15_8-or-16_4 AUTO_ANALYZE-before-15-5-or-14-10 default_params diff --git a/test/JDBC/upgrade/15_2/schedule b/test/JDBC/upgrade/15_2/schedule index c5b8b09331..9d4a234e17 100644 --- a/test/JDBC/upgrade/15_2/schedule +++ b/test/JDBC/upgrade/15_2/schedule @@ -420,7 +420,7 @@ triggers_with_transaction datetimeoffset-timezone-before-15_3 BABEL-4046 table_constraint_wo_comma-before-15_6-or-16_2 -getdate +getdate-before-15_9-or-16_5 BABEL_4330-before-15_8-or-16_4 BABEL-4410 AUTO_ANALYZE-before-15-5-or-14-10 diff --git a/test/JDBC/upgrade/15_3/schedule b/test/JDBC/upgrade/15_3/schedule index cfb48a6964..38ab04cc37 100644 --- a/test/JDBC/upgrade/15_3/schedule +++ b/test/JDBC/upgrade/15_3/schedule @@ -444,7 +444,7 @@ triggers_with_transaction datetimeoffset-timezone BABEL-4046 table_constraint_wo_comma-before-15_6-or-16_2 -getdate +getdate-before-15_9-or-16_5 BABEL_4330-before-15_8-or-16_4 AUTO_ANALYZE-before-15-5-or-14-10 default_params diff --git a/test/JDBC/upgrade/15_4/schedule b/test/JDBC/upgrade/15_4/schedule index 0547d5e7d4..b0fd286ccd 100644 --- a/test/JDBC/upgrade/15_4/schedule +++ b/test/JDBC/upgrade/15_4/schedule @@ -493,6 +493,7 @@ reverse-before-15_8-or-16_4 stuff-before-15_8-or-16_4 replicate-before-15_8-or-16_4 string_agg-before-15_9-or-16_5 +getdate-before-15_9-or-16_5 space binary-datatype-operators cast-varchar-to-time diff --git a/test/JDBC/upgrade/15_5/schedule b/test/JDBC/upgrade/15_5/schedule index 695fae7648..4727a5ff64 100644 --- a/test/JDBC/upgrade/15_5/schedule +++ b/test/JDBC/upgrade/15_5/schedule @@ -524,6 +524,7 @@ reverse-before-15_8-or-16_4 stuff-before-15_8-or-16_4 replicate-before-15_8-or-16_4 string_agg-before-15_9-or-16_5 +getdate-before-15_9-or-16_5 space binary-datatype-operators cast-varchar-to-time diff --git a/test/JDBC/upgrade/15_6/schedule b/test/JDBC/upgrade/15_6/schedule index 2e4a4ecc1a..8467d9e58f 100644 --- a/test/JDBC/upgrade/15_6/schedule +++ b/test/JDBC/upgrade/15_6/schedule @@ -540,6 +540,7 @@ reverse-before-15_8-or-16_4 stuff-before-15_8-or-16_4 replicate-before-15_8-or-16_4 string_agg-before-15_9-or-16_5 +getdate-before-15_9-or-16_5 space binary-datatype-operators cast-varchar-to-time diff --git a/test/JDBC/upgrade/15_7/schedule b/test/JDBC/upgrade/15_7/schedule index 294be77a1a..e57c0005ae 100644 --- a/test/JDBC/upgrade/15_7/schedule +++ b/test/JDBC/upgrade/15_7/schedule @@ -540,6 +540,7 @@ substring-before-15_8-or-16_4 BABEL-4815 reverse-before-15_8-or-16_4 string_agg-before-15_9-or-16_5 +getdate-before-15_9-or-16_5 stuff-before-15_8-or-16_4 BABEL-3401 babel_4328_datetime diff --git a/test/JDBC/upgrade/15_8/schedule b/test/JDBC/upgrade/15_8/schedule index 31b0dadbea..cfd2fe2b22 100644 --- a/test/JDBC/upgrade/15_8/schedule +++ b/test/JDBC/upgrade/15_8/schedule @@ -536,6 +536,7 @@ reverse stuff replicate string_agg-before-15_9-or-16_5 +getdate-before-15_9-or-16_5 space replace alter-procedure-15_8-or-16_4 diff --git a/test/JDBC/upgrade/15_9/schedule b/test/JDBC/upgrade/15_9/schedule index 6c12737b18..53920cf5c5 100644 --- a/test/JDBC/upgrade/15_9/schedule +++ b/test/JDBC/upgrade/15_9/schedule @@ -536,6 +536,7 @@ reverse stuff replicate string_agg +getdate space replace binary-datatype-operators diff --git a/test/JDBC/upgrade/16_1/schedule b/test/JDBC/upgrade/16_1/schedule index 681e716cd0..081876f1f1 100644 --- a/test/JDBC/upgrade/16_1/schedule +++ b/test/JDBC/upgrade/16_1/schedule @@ -532,6 +532,7 @@ reverse-before-15_8-or-16_4 stuff-before-15_8-or-16_4 replicate-before-15_8-or-16_4 string_agg-before-15_9-or-16_5 +getdate-before-15_9-or-16_5 space replace-before-15_8-or-16_4 binary-datatype-operators diff --git a/test/JDBC/upgrade/16_2/schedule b/test/JDBC/upgrade/16_2/schedule index 58c5d445f0..5267eff2b1 100644 --- a/test/JDBC/upgrade/16_2/schedule +++ b/test/JDBC/upgrade/16_2/schedule @@ -547,6 +547,7 @@ reverse-before-15_8-or-16_4 stuff-before-15_8-or-16_4 replicate-before-15_8-or-16_4 string_agg-before-15_9-or-16_5 +getdate-before-15_9-or-16_5 space replace-before-15_8-or-16_4 binary-datatype-operators diff --git a/test/JDBC/upgrade/16_3/schedule b/test/JDBC/upgrade/16_3/schedule index bf37628538..ded9725a5d 100644 --- a/test/JDBC/upgrade/16_3/schedule +++ b/test/JDBC/upgrade/16_3/schedule @@ -550,6 +550,7 @@ reverse-before-15_8-or-16_4 stuff-before-15_8-or-16_4 replicate-before-15_8-or-16_4 string_agg-before-15_9-or-16_5 +getdate-before-15_9-or-16_5 space replace-before-15_8-or-16_4 binary-datatype-operators diff --git a/test/JDBC/upgrade/16_4/schedule b/test/JDBC/upgrade/16_4/schedule index b0d434c603..ea84940651 100644 --- a/test/JDBC/upgrade/16_4/schedule +++ b/test/JDBC/upgrade/16_4/schedule @@ -562,6 +562,7 @@ reverse sys_sequences replicate string_agg-before-15_9-or-16_5 +getdate-before-15_9-or-16_5 space binary-datatype-operators cast-varchar-to-time diff --git a/test/JDBC/upgrade/latest/schedule b/test/JDBC/upgrade/latest/schedule index 4d6034a5a9..376ebda483 100644 --- a/test/JDBC/upgrade/latest/schedule +++ b/test/JDBC/upgrade/latest/schedule @@ -561,6 +561,7 @@ BABEL-5071 string_agg_within reverse string_agg +getdate sys_sequences replicate space diff --git a/test/python/expected/upgrade_validation/expected_dependency.out b/test/python/expected/upgrade_validation/expected_dependency.out index 8ff508f5bb..a4cd7f9aca 100644 --- a/test/python/expected/upgrade_validation/expected_dependency.out +++ b/test/python/expected/upgrade_validation/expected_dependency.out @@ -476,8 +476,6 @@ Function sys.get_host_os() Function sys.get_icu_major_version() Function sys.get_icu_minor_version() Function sys.get_valid_srids() -Function sys.getdate() -Function sys.getutcdate() Function sys.has_dbaccess(sys.sysname) Function sys.hashbpchar(sys.bpchar) Function sys.hashbytes(character varying,character varying) @@ -685,10 +683,7 @@ Function sys.suser_name() Function sys.suser_name_internal(oid) Function sys.suser_sid() Function sys.suser_sname() -Function sys.sysdatetime() -Function sys.sysdatetimeoffset() Function sys.systypes_precision_helper(text,smallint) -Function sys.sysutcdatetime() Function sys.text(sys.geography) Function sys.text(sys.geometry) Function sys.text_to_name(text) @@ -867,9 +862,6 @@ Operator sys.<(smallint,sys.fixeddecimal) Operator sys.<(sys."bit",integer) Operator sys.<(sys."bit",sys."bit") Operator sys.<(sys.bbf_varbinary,sys.bbf_varbinary) -Operator sys.<(sys.datetime,sys.datetime) -Operator sys.<(sys.datetime2,sys.datetime2) -Operator sys.<(sys.datetimeoffset,sys.datetimeoffset) Operator sys.<(sys.fixeddecimal,bigint) Operator sys.<(sys.fixeddecimal,integer) Operator sys.<(sys.fixeddecimal,numeric) @@ -926,9 +918,6 @@ Operator sys.=(integer,sys.fixeddecimal) Operator sys.=(numeric,sys.fixeddecimal) Operator sys.=(smallint,sys.fixeddecimal) Operator sys.=(sys."bit",sys."bit") -Operator sys.=(sys.datetime,sys.datetime) -Operator sys.=(sys.datetime2,sys.datetime2) -Operator sys.=(sys.datetimeoffset,sys.datetimeoffset) Operator sys.=(sys.fixeddecimal,bigint) Operator sys.=(sys.fixeddecimal,integer) Operator sys.=(sys.fixeddecimal,numeric)