From 70ce50193cddd46ebb39cfa49a50569bb4c29752 Mon Sep 17 00:00:00 2001 From: Kuntal Ghosh Date: Fri, 17 Jan 2025 21:12:22 +0530 Subject: [PATCH 01/10] Update bug.yaml to include 5_X_Dev --- .github/ISSUE_TEMPLATE/bug.yaml | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/.github/ISSUE_TEMPLATE/bug.yaml b/.github/ISSUE_TEMPLATE/bug.yaml index 4a5f078b9e..15bce81c71 100644 --- a/.github/ISSUE_TEMPLATE/bug.yaml +++ b/.github/ISSUE_TEMPLATE/bug.yaml @@ -22,7 +22,8 @@ body: label: Version description: Which version of Babelfish are you running? options: - - BABEL_4_X_DEV (Default) + - BABEL_5_X_DEV (Default) + - BABEL_4_X_DEV - BABEL_3_X_DEV - BABEL_2_X_DEV - BABEL_1_X_DEV From 8f23703a87bf8c23e9c4c3b142283a981da7e761 Mon Sep 17 00:00:00 2001 From: Siddharth <75160225+SiddharthBITS@users.noreply.github.com> Date: Mon, 20 Jan 2025 10:27:07 +0530 Subject: [PATCH 02/10] [OSS-ONLY] Implementing hashcode and mode based caching (#3414) This commit implements a more efficient method of caching compilations. Cache now restored will now be guaranteed to compatible with the version and build configuration of compilations. This will save around 5-8 mins in version upgrade and dump restore tests. Key changes: Implemented new format for cache keys which includes github hashcode of corresponding engine branch and build mode to better identify the cache stored in a key. New format "ccache-engineHashcode-buildMode-extensionHashcode". Cache restoration handled by build-modified-postgres.yml and saving by save-ccache.yml composite actions. Removed timeStamp based caching. Task: BABEL-5564 Signed-off-by: Siddharth Sengar sensid@amazon.com --- .../build-modified-postgres/action.yml | 45 +++++++++++++++++-- .../dump-restore-util/action.yml | 4 ++ .../install-dependencies/action.yml | 10 ----- .../minor-version-upgrade-util/action.yml | 4 ++ .../composite-actions/save-ccache/action.yml | 39 ++++++++++++++++ .../setup-base-version/action.yml | 4 ++ .../setup-new-version/action.yml | 4 ++ .github/workflows/dotnet-tests.yml | 4 ++ .../workflows/jdbc-tests-single-db-mode.yml | 4 ++ .github/workflows/major-version-upgrade.yml | 23 +++++----- .github/workflows/minor-version-upgrade.yml | 4 ++ .github/workflows/tap-tests.yml | 15 ++++++- 12 files changed, 134 insertions(+), 26 deletions(-) create mode 100644 .github/composite-actions/save-ccache/action.yml diff --git a/.github/composite-actions/build-modified-postgres/action.yml b/.github/composite-actions/build-modified-postgres/action.yml index cbd7f086b9..26ac521394 100644 --- a/.github/composite-actions/build-modified-postgres/action.yml +++ b/.github/composite-actions/build-modified-postgres/action.yml @@ -24,11 +24,11 @@ inputs: runs: using: "composite" steps: - - name: Checkout, Build, and Install the Modified PostgreSQL Instance and Run Tests + - name: Checkout Modified PostgreSQL for Babelfish run: | cd .. rm -rf postgresql_modified_for_babelfish - + if [[ $GITHUB_EVENT_NAME == "pull_request" ]]; then if [[ ${{inputs.engine_branch}} == "latest" ]]; then ENGINE_BRANCH=$GITHUB_HEAD_REF @@ -44,10 +44,47 @@ runs: fi REPOSITORY_OWNER=$GITHUB_REPOSITORY_OWNER fi - $GITHUB_WORKSPACE/.github/scripts/clone_engine_repo "$REPOSITORY_OWNER" "$ENGINE_BRANCH" cd postgresql_modified_for_babelfish - git rev-parse HEAD + rm -rf ~/.ccache + if [[ ${{inputs.tap_tests}} == "yes" ]]; then + echo "CRESTORE_KEY=$(git rev-parse --short HEAD)-tapTest" >> $GITHUB_ENV + elif [[ ${{inputs.code_coverage}} == "yes" ]]; then + echo "CRESTORE_KEY=$(git rev-parse --short HEAD)-coverage" >> $GITHUB_ENV + elif [[ ${{inputs.release_mode}} == "yes" ]]; then + echo "CRESTORE_KEY=$(git rev-parse --short HEAD)-release" >> $GITHUB_ENV + else + echo "CRESTORE_KEY=$(git rev-parse --short HEAD)-default" >> $GITHUB_ENV + fi + shell: bash + + - uses: actions/cache/restore@v4 + id: restore-ccache + if: ${{ github.event_name == 'pull_request' }} || ${{ inputs.code_coverage == 'yes' }} + with: + path: + ~/.ccache + key: + random-random + restore-keys: + ccache-${{ env.CRESTORE_KEY }} + + - name: Save cache if cache hit fails in pull requests + if: ${{ github.event_name == 'pull_request' }} + run: | + if [[ '${{ steps.restore-ccache.outputs.cache-matched-key }}' == '' ]]; then + echo "SAVE_CCACHE=1" >> $GITHUB_ENV + elif [[ ${{ 'steps.restore-ccache.outputs.cache-matched-key' }} != '' ]]; then + echo "SAVE_CCACHE=" >> $GITHUB_ENV + fi + shell: bash + + - name: Build and Install the Modified PostgreSQL Instance and Run Tests + run: | + echo "${{env.SAVE_CCACHE}}" + echo "${{ steps.restore-ccache.outputs.cache-matched-key }}" + cd .. + cd postgresql_modified_for_babelfish if [[ ${{inputs.tap_tests}} == "yes" ]]; then ./configure CC='ccache gcc' --prefix=$HOME/${{ inputs.install_dir }}/ --with-python PYTHON=/usr/bin/python3.8 --enable-cassert CFLAGS="-ggdb" --with-libxml --with-uuid=ossp --with-icu --enable-tap-tests --with-gssapi elif [[ ${{inputs.code_coverage}} == "yes" ]]; then diff --git a/.github/composite-actions/dump-restore-util/action.yml b/.github/composite-actions/dump-restore-util/action.yml index 5d83d28972..fb73b5aeeb 100644 --- a/.github/composite-actions/dump-restore-util/action.yml +++ b/.github/composite-actions/dump-restore-util/action.yml @@ -327,6 +327,10 @@ runs: sqlcmd -S localhost -U jdbc_user -P 12345678 -Q "SELECT @@version GO" shell: bash + - name: Save cache + if: always() + uses: ./.github/composite-actions/save-ccache + - name: Run Verify Tests if: always() && steps.run-pg_dump-restore.outcome == 'success' && inputs.is_final_ver == 'true' uses: ./.github/composite-actions/run-verify-tests diff --git a/.github/composite-actions/install-dependencies/action.yml b/.github/composite-actions/install-dependencies/action.yml index de0912e518..8f32d6f0d5 100644 --- a/.github/composite-actions/install-dependencies/action.yml +++ b/.github/composite-actions/install-dependencies/action.yml @@ -15,14 +15,4 @@ runs: sudo /usr/sbin/update-ccache-symlinks echo 'export PATH="/usr/lib/ccache:$PATH"' | tee -a ~/.bashrc source ~/.bashrc && echo $PATH - echo "NOW=$(date +'%Y-%m-%dT%H:%M:%S')" >> $GITHUB_ENV shell: bash - - - name: Restore ccache - id: cache-compiler - uses: actions/cache@v3 - with: - path: ~/.ccache - key: ccache-${{ runner.os }}-${{ env.NOW }} - restore-keys: | - ccache-${{ runner.os }} diff --git a/.github/composite-actions/minor-version-upgrade-util/action.yml b/.github/composite-actions/minor-version-upgrade-util/action.yml index 00a4d5e79d..66767d0452 100644 --- a/.github/composite-actions/minor-version-upgrade-util/action.yml +++ b/.github/composite-actions/minor-version-upgrade-util/action.yml @@ -48,6 +48,10 @@ runs: install_dir: ${{ inputs.install_dir }} extension_branch: ${{ inputs.extension_branch }} + - name: Save cache + if: always() && steps.build-extensions-newer == 'success' + uses: ./.github/composite-actions/save-ccache + # Not created and used composite action update-extensions here since, in the previous step it has # checked out a branch/tag which may not have the updated update-extension composite action - name: Update extensions diff --git a/.github/composite-actions/save-ccache/action.yml b/.github/composite-actions/save-ccache/action.yml new file mode 100644 index 0000000000..2409fbc903 --- /dev/null +++ b/.github/composite-actions/save-ccache/action.yml @@ -0,0 +1,39 @@ +name: 'Save ccache on push' + +runs: + using: "composite" + steps: + + - name: Setup new cache key + if: always() + run: | + echo "CCACHE_KEY=${{env.CRESTORE_KEY}}-$(git rev-parse --short HEAD)" >> $GITHUB_ENV + echo "Event : ${{ github.event_name }}" + echo "Save ccache : ${{ env.SAVE_CCACHE }}" + if [[ ${{ github.event_name != 'pull_request' || env.SAVE_CCACHE == 1 }} == true ]]; then + echo "Cache to be Saved" + echo "SAVE_CACHE_HERE=1" >> $GITHUB_ENV + else + echo "Cache shouldn't be Saved" + echo "SAVE_CACHE_HERE=0" >> $GITHUB_ENV + fi + shell: bash + + - name: Save ccache + uses: actions/cache/save@v4 + if: env.SAVE_CACHE_HERE == 1 + with: + path: + ~/.ccache + key: + ccache-${{ env.CCACHE_KEY }} + + - name: Clean ccache directory and unset env variables + if: always() + shell: bash + run: | + rm -rf ~/.ccache + echo "CCACHE_KEY=" >> $GITHUB_ENV + echo "SAVE_CCACHE=" >> $GITHUB_ENV + echo "SAVE_CACHE_HERE=" >> $GITHUB_ENV + echo "CRESTORE_KEY=" >> $GITHUB_ENV \ No newline at end of file diff --git a/.github/composite-actions/setup-base-version/action.yml b/.github/composite-actions/setup-base-version/action.yml index 628518778c..9d6f6b9612 100644 --- a/.github/composite-actions/setup-base-version/action.yml +++ b/.github/composite-actions/setup-base-version/action.yml @@ -221,6 +221,10 @@ runs: - uses: actions/checkout@v2 + - name: Save cache + if: always() && steps.jdbc-upgrade-tests.outcome == 'success' + uses: ./.github/composite-actions/save-ccache + - name: Install Python id: install-python if: ${{ matrix.upgrade-path.path[0] == 'source_latest' && steps.jdbc-upgrade-tests.outcome == 'success' }} diff --git a/.github/composite-actions/setup-new-version/action.yml b/.github/composite-actions/setup-new-version/action.yml index 2138d1cf41..aaa1c0adf0 100644 --- a/.github/composite-actions/setup-new-version/action.yml +++ b/.github/composite-actions/setup-new-version/action.yml @@ -64,6 +64,10 @@ runs: with: install_dir: ${{ inputs.pg_new_dir }} + - name: Save cache + if: always() && steps.build-postgis-extension == 'success' + uses: ./.github/composite-actions/save-ccache + - name: Setup new data directory id: setup-new-datadir if: always() && steps.build-postgis-extension.outcome == 'success' diff --git a/.github/workflows/dotnet-tests.yml b/.github/workflows/dotnet-tests.yml index 85fa9500f3..476d6e1f62 100644 --- a/.github/workflows/dotnet-tests.yml +++ b/.github/workflows/dotnet-tests.yml @@ -40,6 +40,10 @@ jobs: id: install-extensions if: always() && steps.build-postgis-extension.outcome == 'success' uses: ./.github/composite-actions/install-extensions + + - name: Save cache + if: always() && steps.install-extensions.outcome == 'success' + uses: ./.github/composite-actions/save-ccache - name: Run Dotnet Tests id: run-dotnet-tests diff --git a/.github/workflows/jdbc-tests-single-db-mode.yml b/.github/workflows/jdbc-tests-single-db-mode.yml index 8f470d66b5..eb36a0d9d2 100644 --- a/.github/workflows/jdbc-tests-single-db-mode.yml +++ b/.github/workflows/jdbc-tests-single-db-mode.yml @@ -102,6 +102,10 @@ jobs: ~/psql/data/logfile ~/psql/data_5433/logfile + - name: Save cache + if: always() && steps.replication.outcome == 'success' + uses: ./.github/composite-actions/save-ccache + # The test summary files contain paths with ':' characters, which is not allowed with the upload-artifact actions - name: Rename Test Summary Files id: test-file-rename diff --git a/.github/workflows/major-version-upgrade.yml b/.github/workflows/major-version-upgrade.yml index e98cedce61..7dd3f2dfcb 100644 --- a/.github/workflows/major-version-upgrade.yml +++ b/.github/workflows/major-version-upgrade.yml @@ -20,18 +20,11 @@ jobs: - name: Build Modified Postgres using ${{env.ENGINE_BRANCH_FROM}} id: build-modified-postgres-old + uses: ./.github/composite-actions/build-modified-postgres if: always() && steps.install-dependencies.outcome == 'success' - run: | - cd .. - git clone --branch ${{env.ENGINE_BRANCH_FROM}} https://github.com/babelfish-for-postgresql/postgresql_modified_for_babelfish.git - cd postgresql_modified_for_babelfish - ./configure --prefix=$HOME/${{env.OLD_INSTALL_DIR}} --with-python PYTHON=/usr/bin/python3.8 --enable-cassert CFLAGS="-ggdb" --with-libxml --with-uuid=ossp --with-icu - make clean - make -j 4 - make install - make check - cd contrib && make && sudo make install - shell: bash + with: + engine_branch: ${{ env.ENGINE_BRANCH_FROM }} + install_dir: ${{ env.OLD_INSTALL_DIR }} - name: Compile ANTLR id: compile-antlr @@ -130,6 +123,10 @@ jobs: - uses: actions/checkout@v2 + - name: Save cache + if: always() && steps.build-extensions-old.outcome == 'success' + uses: ./.github/composite-actions/save-ccache + - name: Build Modified Postgres using latest version id: build-modified-postgres-new if: always() && steps.install-extensions-old.outcome == 'success' @@ -172,6 +169,10 @@ jobs: uses: ./.github/composite-actions/build-postgis-extension with: install_dir: ${{env.NEW_INSTALL_DIR}} + + - name: Save cache + if: always() && steps.build-postgis-extension.outcome == 'success' + uses: ./.github/composite-actions/save-ccache - name: Setup new data directory id: setup-new-datadir diff --git a/.github/workflows/minor-version-upgrade.yml b/.github/workflows/minor-version-upgrade.yml index 3adc33bf2f..a5d41afda8 100644 --- a/.github/workflows/minor-version-upgrade.yml +++ b/.github/workflows/minor-version-upgrade.yml @@ -111,6 +111,10 @@ jobs: - uses: actions/checkout@v2 + - name: Save cache + if: always() && steps.build-extensions-older.outcome == 'success' + uses: ./.github/composite-actions/save-ccache + - name: Build and run tests for Postgres engine using latest engine id: build-modified-postgres-newer if: always() && steps.install-extensions-older.outcome == 'success' diff --git a/.github/workflows/tap-tests.yml b/.github/workflows/tap-tests.yml index e0bc7704dc..c4b024af1c 100644 --- a/.github/workflows/tap-tests.yml +++ b/.github/workflows/tap-tests.yml @@ -45,7 +45,8 @@ jobs: with: engine_branch: ${{env.ENGINE_BRANCH_16}} install_dir: ${{env.INSTALL_DIR_16}} - + + - name: Build Modified Postgres using ${{env.ENGINE_BRANCH_OLD}} id: build-modified-postgres-old if: always() && steps.build-modified-postgres-16.outcome == 'success' @@ -100,6 +101,8 @@ jobs: sudo make USE_PGXS=1 PG_CONFIG=~/psql_source/bin/pg_config install shell: bash + + - name: Build Extensions using ${{env.EXTENSION_BRANCH_OLD}} id: build-extensions-old if: always() && steps.build-postgis-extension-old.outcome == 'success' @@ -110,6 +113,10 @@ jobs: - uses: actions/checkout@v2 + - name: Save cache + if: always() && steps.build-extensions-old.outcome == 'success' + uses: ./.github/composite-actions/save-ccache + - name: Build Modified Postgres using latest version id: build-modified-postgres-new if: always() && steps.build-extensions-old.outcome == 'success' @@ -117,6 +124,8 @@ jobs: with: tap_tests: 'yes' install_dir: ${{env.NEW_INSTALL_DIR}} + + - name: Compile new ANTLR id: compile-new-antlr @@ -139,6 +148,10 @@ jobs: with: install_dir: ${{env.NEW_INSTALL_DIR}} + - name: Save cache + if: always() && steps.build-extensions-old.outcome == 'success' + uses: ./.github/composite-actions/save-ccache + - name: Run TAP Tests id: tap if: always() && steps.build-postgis-extension.outcome == 'success' From cd18f11e478f3ab8d37e67c6f9296b5199855b9f Mon Sep 17 00:00:00 2001 From: Roshan Kanwar Date: Tue, 21 Jan 2025 21:49:33 +0530 Subject: [PATCH 03/10] Add MIN and MAX aggregate support for MONEY datatype (#3410) This commit addresses the issue where SELECT...INTO with MIN and MAX aggregations on MONEY columns lost type information. The fix implements proper type preservation for these aggregate functions when used with MONEY datatypes. Key changes: Added support for MIN(money) -> money Added support for MAX(money) -> money Ensures type consistency in SELECT...INTO operations Task: BABEL-5479 Signed-off-by: Roshan Kanwar --- .../fixeddecimal--1.1.0_base_parallel.sql | 10 + .../sql/money/fixeddecimal--parallelaggs.sql | 14 + .../babelfish_common_helper--5.0.0--5.1.0.sql | 24 ++ test/JDBC/expected/BABEL-3006.out | 4 +- .../expected/money_aggregate-vu-cleanup.out | 113 +++++++ .../expected/money_aggregate-vu-prepare.out | 313 ++++++++++++++++++ .../expected/money_aggregate-vu-verify.out | 214 ++++++++++++ .../JDBC/input/money_aggregate-vu-cleanup.sql | 113 +++++++ .../JDBC/input/money_aggregate-vu-prepare.sql | 289 ++++++++++++++++ test/JDBC/input/money_aggregate-vu-verify.sql | 87 +++++ test/JDBC/upgrade/latest/schedule | 1 + .../expected_dependency.out | 2 + 12 files changed, 1182 insertions(+), 2 deletions(-) create mode 100644 test/JDBC/expected/money_aggregate-vu-cleanup.out create mode 100644 test/JDBC/expected/money_aggregate-vu-prepare.out create mode 100644 test/JDBC/expected/money_aggregate-vu-verify.out create mode 100644 test/JDBC/input/money_aggregate-vu-cleanup.sql create mode 100644 test/JDBC/input/money_aggregate-vu-prepare.sql create mode 100644 test/JDBC/input/money_aggregate-vu-verify.sql diff --git a/contrib/babelfishpg_common/sql/money/fixeddecimal--1.1.0_base_parallel.sql b/contrib/babelfishpg_common/sql/money/fixeddecimal--1.1.0_base_parallel.sql index 6d45a56a3c..1909bac03d 100755 --- a/contrib/babelfishpg_common/sql/money/fixeddecimal--1.1.0_base_parallel.sql +++ b/contrib/babelfishpg_common/sql/money/fixeddecimal--1.1.0_base_parallel.sql @@ -2005,3 +2005,13 @@ CREATE FUNCTION sys.smallmoneysmaller(sys.SMALLMONEY, sys.SMALLMONEY) RETURNS sys.SMALLMONEY AS 'babelfishpg_money', 'fixeddecimalsmaller' LANGUAGE C IMMUTABLE STRICT PARALLEL SAFE; + +CREATE FUNCTION sys.moneylarger(sys.MONEY, sys.MONEY) +RETURNS sys.MONEY +AS 'babelfishpg_money', 'fixeddecimallarger' +LANGUAGE C IMMUTABLE STRICT PARALLEL SAFE; + +CREATE FUNCTION sys.moneysmaller(sys.MONEY, sys.MONEY) +RETURNS sys.MONEY +AS 'babelfishpg_money', 'fixeddecimalsmaller' +LANGUAGE C IMMUTABLE STRICT PARALLEL SAFE; diff --git a/contrib/babelfishpg_common/sql/money/fixeddecimal--parallelaggs.sql b/contrib/babelfishpg_common/sql/money/fixeddecimal--parallelaggs.sql index a4207326b0..99f9ae7145 100644 --- a/contrib/babelfishpg_common/sql/money/fixeddecimal--parallelaggs.sql +++ b/contrib/babelfishpg_common/sql/money/fixeddecimal--parallelaggs.sql @@ -80,3 +80,17 @@ CREATE AGGREGATE sys.max(sys.smallmoney) ( COMBINEFUNC = sys.smallmoneylarger, PARALLEL = SAFE ); + +CREATE AGGREGATE sys.min(sys.money) ( + SFUNC = sys.moneysmaller, + STYPE = sys.money, + COMBINEFUNC = sys.moneysmaller, + PARALLEL = SAFE +); + +CREATE AGGREGATE sys.max(sys.money) ( + SFUNC = sys.moneylarger, + STYPE = sys.money, + COMBINEFUNC = sys.moneylarger, + PARALLEL = SAFE +); diff --git a/contrib/babelfishpg_common/sql/upgrades/babelfish_common_helper--5.0.0--5.1.0.sql b/contrib/babelfishpg_common/sql/upgrades/babelfish_common_helper--5.0.0--5.1.0.sql index 6fdacf9827..d9d49f53e7 100644 --- a/contrib/babelfishpg_common/sql/upgrades/babelfish_common_helper--5.0.0--5.1.0.sql +++ b/contrib/babelfishpg_common/sql/upgrades/babelfish_common_helper--5.0.0--5.1.0.sql @@ -103,5 +103,29 @@ CREATE OPERATOR sys.% ( END IF; END $$; +CREATE OR REPLACE FUNCTION sys.moneylarger(sys.MONEY, sys.MONEY) +RETURNS sys.MONEY +AS 'babelfishpg_money', 'fixeddecimallarger' +LANGUAGE C IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.moneysmaller(sys.MONEY, sys.MONEY) +RETURNS sys.MONEY +AS 'babelfishpg_money', 'fixeddecimalsmaller' +LANGUAGE C IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE AGGREGATE sys.min(sys.money) ( + SFUNC = sys.moneysmaller, + STYPE = sys.money, + COMBINEFUNC = sys.moneysmaller, + PARALLEL = SAFE +); + +CREATE OR REPLACE AGGREGATE sys.max(sys.money) ( + SFUNC = sys.moneylarger, + STYPE = sys.money, + COMBINEFUNC = sys.moneylarger, + PARALLEL = SAFE +); + -- Reset search_path to not affect any subsequent scripts SELECT set_config('search_path', trim(leading 'sys, ' from current_setting('search_path')), false); diff --git a/test/JDBC/expected/BABEL-3006.out b/test/JDBC/expected/BABEL-3006.out index 4cc0f5cc03..38290f2689 100644 --- a/test/JDBC/expected/BABEL-3006.out +++ b/test/JDBC/expected/BABEL-3006.out @@ -153,7 +153,7 @@ select cast(pg_typeof(m) as varchar(20)) d from (select min(d) as m from t3006_m go ~~START~~ varchar -fixeddecimal +money ~~END~~ ~~START~~ @@ -173,7 +173,7 @@ select cast(pg_typeof(m) as varchar(20)) d from (select max(d) as m from t3006_m go ~~START~~ varchar -fixeddecimal +money ~~END~~ ~~START~~ diff --git a/test/JDBC/expected/money_aggregate-vu-cleanup.out b/test/JDBC/expected/money_aggregate-vu-cleanup.out new file mode 100644 index 0000000000..525ac6d5fc --- /dev/null +++ b/test/JDBC/expected/money_aggregate-vu-cleanup.out @@ -0,0 +1,113 @@ +DROP PROCEDURE IF EXISTS get_column_info_p1; +GO + +DROP TABLE IF EXISTS ResultTable1; +GO + +DROP TABLE IF EXISTS ResultTable2; +GO + +DROP TABLE IF EXISTS ResultTable3; +GO + +DROP TABLE IF EXISTS ResultTable4; +GO + +DROP TABLE IF EXISTS ResultTable5; +GO + +DROP TABLE IF EXISTS ResultTable6; +GO + +DROP TABLE IF EXISTS ResultTable7; +GO + +DROP TABLE IF EXISTS ResultTable8; +GO + +DROP TABLE IF EXISTS ResultTable9; +GO + +DROP TABLE IF EXISTS ResultTable10; +GO + +DROP TABLE IF EXISTS EmptyMoneyTable; +GO + +DROP TABLE IF EXISTS ResultTableEmpty; +GO + +DROP TABLE IF EXISTS ExtremeMoneyTable; +GO + +DROP TABLE IF EXISTS ResultTableExtreme; +GO + +DROP TABLE IF EXISTS MixedNullMoneyTable; +GO + +DROP TABLE IF EXISTS ResultTableMixedNull; +GO + +DROP TABLE IF EXISTS OverflowMoneyTable; +GO + +DROP TABLE IF EXISTS ResultTableOverflow; +GO + +DROP TABLE IF EXISTS NonMoneyTable; +GO + +DROP TABLE IF EXISTS ResultTableNonMoney; +GO + +-- Clean up Check Constraint Test +DROP TABLE IF EXISTS ResultTableCheck; +GO + +DROP TABLE IF EXISTS CheckConstraintMoneyTable; +GO + +-- Clean up Complex Dependent Objects Tests +DROP TABLE IF EXISTS ResultTableView; +GO + +DROP TABLE IF EXISTS ResultTableFunction; +GO + +DROP VIEW IF EXISTS MoneyView; +GO + +DROP FUNCTION IF EXISTS GetTotalMoney; +GO + +DROP PROCEDURE IF EXISTS InsertMoney; +GO + +-- Clean up Indexed View Test +DROP TABLE IF EXISTS ResultTableIndexedView; +GO + +DROP VIEW IF EXISTS IndexedMoneyView; +GO + +DROP TABLE IF EXISTS IndexedViewBaseTable; +GO + +DROP TABLE IF EXISTS CurrencyMoneyTable; +GO + +DROP TABLE IF EXISTS ResultTableCurrency1; +GO + +DROP TABLE IF EXISTS ResultTableCurrency2; +GO + +DROP TABLE IF EXISTS ResultTableCurrency3; +GO + +DROP TABLE IF EXISTS ResultTableCurrency4; +GO + +DROP TABLE IF EXISTS TestMoneyTable; +GO diff --git a/test/JDBC/expected/money_aggregate-vu-prepare.out b/test/JDBC/expected/money_aggregate-vu-prepare.out new file mode 100644 index 0000000000..e7b0529d4a --- /dev/null +++ b/test/JDBC/expected/money_aggregate-vu-prepare.out @@ -0,0 +1,313 @@ +CREATE TABLE TestMoneyTable ( + ID INT IDENTITY(1,1) PRIMARY KEY, + Amount MONEY, + Description NVARCHAR(100) +); +GO + +-- Insert test data +INSERT INTO TestMoneyTable (Amount, Description) VALUES +(100.50, 'Item 1'), +(200.75, 'Item 2'), +(150.25, 'Item 3'), +(300.00, 'Item 4'), +(250.50, 'Item 5'), +(NULL, 'Null Amount'); +GO +~~ROW COUNT: 6~~ + + +CREATE PROCEDURE get_column_info_p1 + @table_name text +AS +BEGIN + SELECT c.[name] AS column_name, + t.[name] AS [type_name], + c.[max_length], + c.[precision], + c.[scale] + FROM sys.columns c + INNER JOIN sys.types t + ON c.user_type_id = t.user_type_id + WHERE object_id = object_id(@table_name) + ORDER BY c.[name]; +END +GO + +-- Test Case 1: MAX aggregation +SELECT MAX(Amount) AS MaxAmount +INTO ResultTable1 +FROM TestMoneyTable; +GO + +-- Test Case 2: MIN aggregation +SELECT MIN(Amount) AS MinAmount +INTO ResultTable2 +FROM TestMoneyTable; +GO + +-- Test Case 3: AVG aggregation +SELECT AVG(Amount) AS AvgAmount +INTO ResultTable3 +FROM TestMoneyTable; +GO + +-- Test Case 4: SUM aggregation +SELECT SUM(Amount) AS TotalAmount +INTO ResultTable4 +FROM TestMoneyTable; +GO + +-- Test Case 5: COUNT aggregation (should remain as INT) +SELECT COUNT(Amount) AS CountAmount +INTO ResultTable5 +FROM TestMoneyTable; +GO + +-- Test Case 6: Multiple aggregations in one query +SELECT + MAX(Amount) AS MaxAmount, + MIN(Amount) AS MinAmount, + AVG(Amount) AS AvgAmount, + SUM(Amount) AS TotalAmount, + COUNT(Amount) AS CountAmount +INTO ResultTable6 +FROM TestMoneyTable; +GO + +-- Test Case 7: Aggregation with GROUP BY +SELECT + Description, + MAX(Amount) AS MaxAmount +INTO ResultTable7 +FROM TestMoneyTable +GROUP BY Description; +GO + +-- Test Case 8: Aggregation with subquery +SELECT MaxAmount +INTO ResultTable8 +FROM ( + SELECT MAX(Amount) AS MaxAmount + FROM TestMoneyTable +) AS Subquery; +GO + +-- Test Case 9: Aggregation with HAVING clause +SELECT + Description, + MAX(Amount) AS MaxAmount +INTO ResultTable9 +FROM TestMoneyTable +GROUP BY Description +HAVING MAX(Amount) > 200; +GO + +-- Test Case 10: Aggregation with calculated MONEY column +SELECT + MAX(Amount * 2) AS DoubleMaxAmount +INTO ResultTable10 +FROM TestMoneyTable; +GO + +-- Negative Test Case: Empty table +CREATE TABLE EmptyMoneyTable (Amount MONEY); +GO + +SELECT MAX(Amount) AS MaxAmount +INTO ResultTableEmpty +FROM EmptyMoneyTable; +GO + +-- Edge Test Case: Extreme values +CREATE TABLE ExtremeMoneyTable (Amount MONEY); +GO + +INSERT INTO ExtremeMoneyTable VALUES +(922337203685477.5807), -- Maximum positive value for MONEY +(-922337203685477.5808); -- Minimum negative value for MONEY +GO +~~ROW COUNT: 2~~ + + +SELECT MAX(Amount) AS MaxAmount, MIN(Amount) AS MinAmount +INTO ResultTableExtreme +FROM ExtremeMoneyTable; +GO + +-- Arbitrary Test Case: Mixing NULL and non-NULL values +CREATE TABLE MixedNullMoneyTable (Amount MONEY); +GO + +INSERT INTO MixedNullMoneyTable VALUES +(100.00), (NULL), (200.00), (NULL), (300.00); +GO +~~ROW COUNT: 5~~ + + +SELECT + AVG(Amount) AS AvgAmount, + SUM(Amount) AS TotalAmount, + COUNT(Amount) AS CountNonNull, + COUNT(*) AS CountAll +INTO ResultTableMixedNull +FROM MixedNullMoneyTable; +GO + +-- Edge Test Case: Aggregating calculated values that exceed MONEY range +CREATE TABLE OverflowMoneyTable (Amount MONEY); +GO + +INSERT INTO OverflowMoneyTable VALUES +(922337203685477), (922337203685477); +GO +~~ROW COUNT: 2~~ + + +SELECT SUM(Amount) AS TotalAmount +INTO ResultTableOverflow +FROM OverflowMoneyTable; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: fixeddecimal out of range)~~ + + +-- Negative Test Case: Trying to aggregate non-MONEY column as MONEY +CREATE TABLE NonMoneyTable (Amount VARCHAR(20)); +GO + +INSERT INTO NonMoneyTable VALUES ('100.00'), ('200.00'); +GO +~~ROW COUNT: 2~~ + + +SELECT SUM(CAST(Amount AS MONEY)) AS TotalAmount +INTO ResultTableNonMoney +FROM NonMoneyTable; +GO + +-- Check Constraint Test +CREATE TABLE CheckConstraintMoneyTable ( + ID INT PRIMARY KEY, + Amount MONEY CHECK (Amount > 0 AND Amount < 1000) +); +GO + +INSERT INTO CheckConstraintMoneyTable VALUES (1, 100.00), (2, 200.00), (3, 300.00); +GO +~~ROW COUNT: 3~~ + + +SELECT MAX(Amount) AS MaxCheckAmount +INTO ResultTableCheck +FROM CheckConstraintMoneyTable; +GO + +-- Complex Dependent Objects Test +CREATE VIEW MoneyView AS SELECT MAX(Amount) as Amount FROM TestMoneyTable; +GO + +CREATE FUNCTION GetTotalMoney() +RETURNS MONEY +AS +BEGIN + DECLARE @Total MONEY; + SELECT @Total = SUM(Amount) FROM TestMoneyTable; + RETURN @Total; +END; +GO + +CREATE PROCEDURE InsertMoney + @Amount MONEY +AS +BEGIN + INSERT INTO TestMoneyTable (Amount, Description) VALUES (@Amount, 'From Procedure'); +END; +GO + +EXEC InsertMoney 400.00; +GO +~~ROW COUNT: 1~~ + + +SELECT MAX(Amount) AS MaxViewAmount +INTO ResultTableView +FROM MoneyView; +GO + +SELECT GetTotalMoney() AS TotalFunctionAmount +INTO ResultTableFunction; +GO + +-- Indexed View Test +CREATE TABLE IndexedViewBaseTable ( + ID INT PRIMARY KEY, + Amount MONEY +); +GO + +INSERT INTO IndexedViewBaseTable VALUES (1, 100.00), (2, 200.00), (3, 300.00); +GO +~~ROW COUNT: 3~~ + + +CREATE VIEW IndexedMoneyView +WITH SCHEMABINDING +AS +SELECT ID, Amount, COUNT_BIG(*) AS Count +FROM IndexedViewBaseTable +GROUP BY ID, Amount; +GO + +SELECT MAX(Amount) AS MaxIndexedViewAmount +INTO ResultTableIndexedView +FROM IndexedMoneyView; +GO + +-- Currency Symbol Test Cases +CREATE TABLE CurrencyMoneyTable ( + ID INT IDENTITY(1,1), + Amount MONEY +); +GO + +-- Insert values with different currency symbols +INSERT INTO CurrencyMoneyTable (Amount) VALUES +('$100.50'), +('£200.75'), +('€150.25'), +('¥300.00'), +('₹250.50'), +('CHF 175.25'); +GO +~~ERROR (Code: 293)~~ + +~~ERROR (Message: invalid characters found: cannot cast value "CHF 175.25" to money)~~ + + +-- Test different aggregations with currency symbols +SELECT MAX(Amount) AS MaxAmount +INTO ResultTableCurrency1 +FROM CurrencyMoneyTable; +GO + +SELECT MIN(Amount) AS MinAmount +INTO ResultTableCurrency2 +FROM CurrencyMoneyTable; +GO + +SELECT SUM(Amount) AS TotalAmount +INTO ResultTableCurrency3 +FROM CurrencyMoneyTable; +GO + +-- Test with mixed currency symbols in calculations +SELECT + MAX(Amount) AS MaxAmount, + MIN(Amount) AS MinAmount, + AVG(Amount) AS AvgAmount, + SUM(Amount) * 1.1 AS TotalWithMarkup +INTO ResultTableCurrency4 +FROM CurrencyMoneyTable; +GO diff --git a/test/JDBC/expected/money_aggregate-vu-verify.out b/test/JDBC/expected/money_aggregate-vu-verify.out new file mode 100644 index 0000000000..866fbead8c --- /dev/null +++ b/test/JDBC/expected/money_aggregate-vu-verify.out @@ -0,0 +1,214 @@ +-- MAX() +EXEC get_column_info_p1 'ResultTable1'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +maxamount#!#money#!#8#!#19#!#4 +~~END~~ + + +-- MIN() +EXEC get_column_info_p1 'ResultTable2'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +minamount#!#money#!#8#!#19#!#4 +~~END~~ + + +-- AVG() +EXEC get_column_info_p1 'ResultTable3'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +avgamount#!#money#!#8#!#19#!#4 +~~END~~ + + +-- SUM() +EXEC get_column_info_p1 'ResultTable4'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +totalamount#!#money#!#8#!#19#!#4 +~~END~~ + + +-- COUNT() +EXEC get_column_info_p1 'ResultTable5'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +countamount#!#int#!#4#!#10#!#0 +~~END~~ + + +-- Mix of different aggregates (MAX, MIN, AVG, SUM, COUNT) +EXEC get_column_info_p1 'ResultTable6'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +avgamount#!#money#!#8#!#19#!#4 +countamount#!#int#!#4#!#10#!#0 +maxamount#!#money#!#8#!#19#!#4 +minamount#!#money#!#8#!#19#!#4 +totalamount#!#money#!#8#!#19#!#4 +~~END~~ + + +-- MAX() with GROUP BY clause +EXEC get_column_info_p1 'ResultTable7'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +description#!#nvarchar#!#200#!#0#!#0 +maxamount#!#money#!#8#!#19#!#4 +~~END~~ + + +-- Aggregation with subquery +EXEC get_column_info_p1 'ResultTable8'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +maxamount#!#money#!#8#!#19#!#4 +~~END~~ + + +-- Aggregation with HAVING clause +EXEC get_column_info_p1 'ResultTable9'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +description#!#nvarchar#!#200#!#0#!#0 +maxamount#!#money#!#8#!#19#!#4 +~~END~~ + + +-- Aggregation with calculated MONEY column +EXEC get_column_info_p1 'ResultTable10'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +doublemaxamount#!#money#!#8#!#19#!#4 +~~END~~ + + +-- Negative Test Case: Empty table +EXEC get_column_info_p1 'ResultTableEmpty'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +maxamount#!#money#!#8#!#19#!#4 +~~END~~ + + +-- Negative Test Case: Trying to aggregate non-MONEY column as MONEY +EXEC get_column_info_p1 'ResultTableNonMoney'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +totalamount#!#money#!#8#!#19#!#4 +~~END~~ + + +-- Edge Test Case: Extreme values +EXEC get_column_info_p1 'ResultTableExtreme'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +maxamount#!#money#!#8#!#19#!#4 +minamount#!#money#!#8#!#19#!#4 +~~END~~ + + +-- Arbitrary Test Case: Mixing NULL and non-NULL values +EXEC get_column_info_p1 'ResultTableMixedNull'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +avgamount#!#money#!#8#!#19#!#4 +countall#!#int#!#4#!#10#!#0 +countnonnull#!#int#!#4#!#10#!#0 +totalamount#!#money#!#8#!#19#!#4 +~~END~~ + + +-- Edge Test Case: Aggregating calculated values that exceed MONEY range +EXEC get_column_info_p1 'ResultTableOverflow'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +~~END~~ + + +-- Verify Check Constraint Test +EXEC get_column_info_p1 'ResultTableCheck'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +maxcheckamount#!#money#!#8#!#19#!#4 +~~END~~ + + +-- Verify Complex Dependent Objects Tests +EXEC get_column_info_p1 'ResultTableView'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +maxviewamount#!#money#!#8#!#19#!#4 +~~END~~ + + +EXEC get_column_info_p1 'ResultTableFunction'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +totalfunctionamount#!#money#!#8#!#19#!#4 +~~END~~ + + +-- Verify Indexed View Test +EXEC get_column_info_p1 'ResultTableIndexedView'; +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +maxindexedviewamount#!#money#!#8#!#19#!#4 +~~END~~ + + +-- Verify currency symbol test results +EXEC get_column_info_p1 'ResultTableCurrency1' +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +maxamount#!#money#!#8#!#19#!#4 +~~END~~ + + +EXEC get_column_info_p1 'ResultTableCurrency2' +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +minamount#!#money#!#8#!#19#!#4 +~~END~~ + + +EXEC get_column_info_p1 'ResultTableCurrency3' +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +totalamount#!#money#!#8#!#19#!#4 +~~END~~ + + +EXEC get_column_info_p1 'ResultTableCurrency4' +GO +~~START~~ +varchar#!#varchar#!#smallint#!#tinyint#!#tinyint +avgamount#!#money#!#8#!#19#!#4 +maxamount#!#money#!#8#!#19#!#4 +minamount#!#money#!#8#!#19#!#4 +totalwithmarkup#!#numeric#!#17#!#38#!#38 +~~END~~ + diff --git a/test/JDBC/input/money_aggregate-vu-cleanup.sql b/test/JDBC/input/money_aggregate-vu-cleanup.sql new file mode 100644 index 0000000000..525ac6d5fc --- /dev/null +++ b/test/JDBC/input/money_aggregate-vu-cleanup.sql @@ -0,0 +1,113 @@ +DROP PROCEDURE IF EXISTS get_column_info_p1; +GO + +DROP TABLE IF EXISTS ResultTable1; +GO + +DROP TABLE IF EXISTS ResultTable2; +GO + +DROP TABLE IF EXISTS ResultTable3; +GO + +DROP TABLE IF EXISTS ResultTable4; +GO + +DROP TABLE IF EXISTS ResultTable5; +GO + +DROP TABLE IF EXISTS ResultTable6; +GO + +DROP TABLE IF EXISTS ResultTable7; +GO + +DROP TABLE IF EXISTS ResultTable8; +GO + +DROP TABLE IF EXISTS ResultTable9; +GO + +DROP TABLE IF EXISTS ResultTable10; +GO + +DROP TABLE IF EXISTS EmptyMoneyTable; +GO + +DROP TABLE IF EXISTS ResultTableEmpty; +GO + +DROP TABLE IF EXISTS ExtremeMoneyTable; +GO + +DROP TABLE IF EXISTS ResultTableExtreme; +GO + +DROP TABLE IF EXISTS MixedNullMoneyTable; +GO + +DROP TABLE IF EXISTS ResultTableMixedNull; +GO + +DROP TABLE IF EXISTS OverflowMoneyTable; +GO + +DROP TABLE IF EXISTS ResultTableOverflow; +GO + +DROP TABLE IF EXISTS NonMoneyTable; +GO + +DROP TABLE IF EXISTS ResultTableNonMoney; +GO + +-- Clean up Check Constraint Test +DROP TABLE IF EXISTS ResultTableCheck; +GO + +DROP TABLE IF EXISTS CheckConstraintMoneyTable; +GO + +-- Clean up Complex Dependent Objects Tests +DROP TABLE IF EXISTS ResultTableView; +GO + +DROP TABLE IF EXISTS ResultTableFunction; +GO + +DROP VIEW IF EXISTS MoneyView; +GO + +DROP FUNCTION IF EXISTS GetTotalMoney; +GO + +DROP PROCEDURE IF EXISTS InsertMoney; +GO + +-- Clean up Indexed View Test +DROP TABLE IF EXISTS ResultTableIndexedView; +GO + +DROP VIEW IF EXISTS IndexedMoneyView; +GO + +DROP TABLE IF EXISTS IndexedViewBaseTable; +GO + +DROP TABLE IF EXISTS CurrencyMoneyTable; +GO + +DROP TABLE IF EXISTS ResultTableCurrency1; +GO + +DROP TABLE IF EXISTS ResultTableCurrency2; +GO + +DROP TABLE IF EXISTS ResultTableCurrency3; +GO + +DROP TABLE IF EXISTS ResultTableCurrency4; +GO + +DROP TABLE IF EXISTS TestMoneyTable; +GO diff --git a/test/JDBC/input/money_aggregate-vu-prepare.sql b/test/JDBC/input/money_aggregate-vu-prepare.sql new file mode 100644 index 0000000000..f70c6e0852 --- /dev/null +++ b/test/JDBC/input/money_aggregate-vu-prepare.sql @@ -0,0 +1,289 @@ +CREATE TABLE TestMoneyTable ( + ID INT IDENTITY(1,1) PRIMARY KEY, + Amount MONEY, + Description NVARCHAR(100) +); +GO + +-- Insert test data +INSERT INTO TestMoneyTable (Amount, Description) VALUES +(100.50, 'Item 1'), +(200.75, 'Item 2'), +(150.25, 'Item 3'), +(300.00, 'Item 4'), +(250.50, 'Item 5'), +(NULL, 'Null Amount'); +GO + +CREATE PROCEDURE get_column_info_p1 + @table_name text +AS +BEGIN + SELECT c.[name] AS column_name, + t.[name] AS [type_name], + c.[max_length], + c.[precision], + c.[scale] + FROM sys.columns c + INNER JOIN sys.types t + ON c.user_type_id = t.user_type_id + WHERE object_id = object_id(@table_name) + ORDER BY c.[name]; +END +GO + +-- Test Case 1: MAX aggregation +SELECT MAX(Amount) AS MaxAmount +INTO ResultTable1 +FROM TestMoneyTable; +GO + +-- Test Case 2: MIN aggregation +SELECT MIN(Amount) AS MinAmount +INTO ResultTable2 +FROM TestMoneyTable; +GO + +-- Test Case 3: AVG aggregation +SELECT AVG(Amount) AS AvgAmount +INTO ResultTable3 +FROM TestMoneyTable; +GO + +-- Test Case 4: SUM aggregation +SELECT SUM(Amount) AS TotalAmount +INTO ResultTable4 +FROM TestMoneyTable; +GO + +-- Test Case 5: COUNT aggregation (should remain as INT) +SELECT COUNT(Amount) AS CountAmount +INTO ResultTable5 +FROM TestMoneyTable; +GO + +-- Test Case 6: Multiple aggregations in one query +SELECT + MAX(Amount) AS MaxAmount, + MIN(Amount) AS MinAmount, + AVG(Amount) AS AvgAmount, + SUM(Amount) AS TotalAmount, + COUNT(Amount) AS CountAmount +INTO ResultTable6 +FROM TestMoneyTable; +GO + +-- Test Case 7: Aggregation with GROUP BY +SELECT + Description, + MAX(Amount) AS MaxAmount +INTO ResultTable7 +FROM TestMoneyTable +GROUP BY Description; +GO + +-- Test Case 8: Aggregation with subquery +SELECT MaxAmount +INTO ResultTable8 +FROM ( + SELECT MAX(Amount) AS MaxAmount + FROM TestMoneyTable +) AS Subquery; +GO + +-- Test Case 9: Aggregation with HAVING clause +SELECT + Description, + MAX(Amount) AS MaxAmount +INTO ResultTable9 +FROM TestMoneyTable +GROUP BY Description +HAVING MAX(Amount) > 200; +GO + +-- Test Case 10: Aggregation with calculated MONEY column +SELECT + MAX(Amount * 2) AS DoubleMaxAmount +INTO ResultTable10 +FROM TestMoneyTable; +GO + +-- Negative Test Case: Empty table +CREATE TABLE EmptyMoneyTable (Amount MONEY); +GO + +SELECT MAX(Amount) AS MaxAmount +INTO ResultTableEmpty +FROM EmptyMoneyTable; +GO + +-- Edge Test Case: Extreme values +CREATE TABLE ExtremeMoneyTable (Amount MONEY); +GO + +INSERT INTO ExtremeMoneyTable VALUES +(922337203685477.5807), -- Maximum positive value for MONEY +(-922337203685477.5808); -- Minimum negative value for MONEY +GO + +SELECT MAX(Amount) AS MaxAmount, MIN(Amount) AS MinAmount +INTO ResultTableExtreme +FROM ExtremeMoneyTable; +GO + +-- Arbitrary Test Case: Mixing NULL and non-NULL values +CREATE TABLE MixedNullMoneyTable (Amount MONEY); +GO + +INSERT INTO MixedNullMoneyTable VALUES +(100.00), (NULL), (200.00), (NULL), (300.00); +GO + +SELECT + AVG(Amount) AS AvgAmount, + SUM(Amount) AS TotalAmount, + COUNT(Amount) AS CountNonNull, + COUNT(*) AS CountAll +INTO ResultTableMixedNull +FROM MixedNullMoneyTable; +GO + +-- Edge Test Case: Aggregating calculated values that exceed MONEY range +CREATE TABLE OverflowMoneyTable (Amount MONEY); +GO + +INSERT INTO OverflowMoneyTable VALUES +(922337203685477), (922337203685477); +GO + +SELECT SUM(Amount) AS TotalAmount +INTO ResultTableOverflow +FROM OverflowMoneyTable; +GO + +-- Negative Test Case: Trying to aggregate non-MONEY column as MONEY +CREATE TABLE NonMoneyTable (Amount VARCHAR(20)); +GO + +INSERT INTO NonMoneyTable VALUES ('100.00'), ('200.00'); +GO + +SELECT SUM(CAST(Amount AS MONEY)) AS TotalAmount +INTO ResultTableNonMoney +FROM NonMoneyTable; +GO + +-- Check Constraint Test +CREATE TABLE CheckConstraintMoneyTable ( + ID INT PRIMARY KEY, + Amount MONEY CHECK (Amount > 0 AND Amount < 1000) +); +GO + +INSERT INTO CheckConstraintMoneyTable VALUES (1, 100.00), (2, 200.00), (3, 300.00); +GO + +SELECT MAX(Amount) AS MaxCheckAmount +INTO ResultTableCheck +FROM CheckConstraintMoneyTable; +GO + +-- Complex Dependent Objects Test +CREATE VIEW MoneyView AS SELECT MAX(Amount) as Amount FROM TestMoneyTable; +GO + +CREATE FUNCTION GetTotalMoney() +RETURNS MONEY +AS +BEGIN + DECLARE @Total MONEY; + SELECT @Total = SUM(Amount) FROM TestMoneyTable; + RETURN @Total; +END; +GO + +CREATE PROCEDURE InsertMoney + @Amount MONEY +AS +BEGIN + INSERT INTO TestMoneyTable (Amount, Description) VALUES (@Amount, 'From Procedure'); +END; +GO + +EXEC InsertMoney 400.00; +GO + +SELECT MAX(Amount) AS MaxViewAmount +INTO ResultTableView +FROM MoneyView; +GO + +SELECT GetTotalMoney() AS TotalFunctionAmount +INTO ResultTableFunction; +GO + +-- Indexed View Test +CREATE TABLE IndexedViewBaseTable ( + ID INT PRIMARY KEY, + Amount MONEY +); +GO + +INSERT INTO IndexedViewBaseTable VALUES (1, 100.00), (2, 200.00), (3, 300.00); +GO + +CREATE VIEW IndexedMoneyView +WITH SCHEMABINDING +AS +SELECT ID, Amount, COUNT_BIG(*) AS Count +FROM IndexedViewBaseTable +GROUP BY ID, Amount; +GO + +SELECT MAX(Amount) AS MaxIndexedViewAmount +INTO ResultTableIndexedView +FROM IndexedMoneyView; +GO + +-- Currency Symbol Test Cases +CREATE TABLE CurrencyMoneyTable ( + ID INT IDENTITY(1,1), + Amount MONEY +); +GO + +-- Insert values with different currency symbols +INSERT INTO CurrencyMoneyTable (Amount) VALUES +('$100.50'), +('£200.75'), +('€150.25'), +('¥300.00'), +('₹250.50'), +('CHF 175.25'); +GO + +-- Test different aggregations with currency symbols +SELECT MAX(Amount) AS MaxAmount +INTO ResultTableCurrency1 +FROM CurrencyMoneyTable; +GO + +SELECT MIN(Amount) AS MinAmount +INTO ResultTableCurrency2 +FROM CurrencyMoneyTable; +GO + +SELECT SUM(Amount) AS TotalAmount +INTO ResultTableCurrency3 +FROM CurrencyMoneyTable; +GO + +-- Test with mixed currency symbols in calculations +SELECT + MAX(Amount) AS MaxAmount, + MIN(Amount) AS MinAmount, + AVG(Amount) AS AvgAmount, + SUM(Amount) * 1.1 AS TotalWithMarkup +INTO ResultTableCurrency4 +FROM CurrencyMoneyTable; +GO diff --git a/test/JDBC/input/money_aggregate-vu-verify.sql b/test/JDBC/input/money_aggregate-vu-verify.sql new file mode 100644 index 0000000000..ee40a1a0c2 --- /dev/null +++ b/test/JDBC/input/money_aggregate-vu-verify.sql @@ -0,0 +1,87 @@ +-- MAX() +EXEC get_column_info_p1 'ResultTable1'; +GO + +-- MIN() +EXEC get_column_info_p1 'ResultTable2'; +GO + +-- AVG() +EXEC get_column_info_p1 'ResultTable3'; +GO + +-- SUM() +EXEC get_column_info_p1 'ResultTable4'; +GO + +-- COUNT() +EXEC get_column_info_p1 'ResultTable5'; +GO + +-- Mix of different aggregates (MAX, MIN, AVG, SUM, COUNT) +EXEC get_column_info_p1 'ResultTable6'; +GO + +-- MAX() with GROUP BY clause +EXEC get_column_info_p1 'ResultTable7'; +GO + +-- Aggregation with subquery +EXEC get_column_info_p1 'ResultTable8'; +GO + +-- Aggregation with HAVING clause +EXEC get_column_info_p1 'ResultTable9'; +GO + +-- Aggregation with calculated MONEY column +EXEC get_column_info_p1 'ResultTable10'; +GO + +-- Negative Test Case: Empty table +EXEC get_column_info_p1 'ResultTableEmpty'; +GO + +-- Negative Test Case: Trying to aggregate non-MONEY column as MONEY +EXEC get_column_info_p1 'ResultTableNonMoney'; +GO + +-- Edge Test Case: Extreme values +EXEC get_column_info_p1 'ResultTableExtreme'; +GO + +-- Arbitrary Test Case: Mixing NULL and non-NULL values +EXEC get_column_info_p1 'ResultTableMixedNull'; +GO + +-- Edge Test Case: Aggregating calculated values that exceed MONEY range +EXEC get_column_info_p1 'ResultTableOverflow'; +GO + +-- Verify Check Constraint Test +EXEC get_column_info_p1 'ResultTableCheck'; +GO + +-- Verify Complex Dependent Objects Tests +EXEC get_column_info_p1 'ResultTableView'; +GO + +EXEC get_column_info_p1 'ResultTableFunction'; +GO + +-- Verify Indexed View Test +EXEC get_column_info_p1 'ResultTableIndexedView'; +GO + +-- Verify currency symbol test results +EXEC get_column_info_p1 'ResultTableCurrency1' +GO + +EXEC get_column_info_p1 'ResultTableCurrency2' +GO + +EXEC get_column_info_p1 'ResultTableCurrency3' +GO + +EXEC get_column_info_p1 'ResultTableCurrency4' +GO diff --git a/test/JDBC/upgrade/latest/schedule b/test/JDBC/upgrade/latest/schedule index 0534700c09..542dcd93d9 100644 --- a/test/JDBC/upgrade/latest/schedule +++ b/test/JDBC/upgrade/latest/schedule @@ -13,6 +13,7 @@ atn2 ATTIMEZONE-dep AVG-Aggregate-common AVG-Aggregate-Dep +money_aggregate BABEL-1062 BABEL-1189 BABEL-1206 diff --git a/test/python/expected/upgrade_validation/expected_dependency.out b/test/python/expected/upgrade_validation/expected_dependency.out index acc487ddcf..d51bf0aca3 100644 --- a/test/python/expected/upgrade_validation/expected_dependency.out +++ b/test/python/expected/upgrade_validation/expected_dependency.out @@ -539,6 +539,8 @@ Function sys.max_connections() Function sys.microsoftversion() Function sys.money_sqlvariant(sys.fixeddecimal) Function sys.money_sqlvariant(sys.money) +Function sys.moneylarger(sys.money,sys.money) +Function sys.moneysmaller(sys.money,sys.money) Function sys.month(anyelement) Function sys.nchar_larger(sys."nchar",sys."nchar") Function sys.nchar_smaller(sys."nchar",sys."nchar") From a716f729c9906ea7f44a4520cd0295da1cf383eb Mon Sep 17 00:00:00 2001 From: Dipesh Dhameliya Date: Wed, 22 Jan 2025 15:41:49 +0530 Subject: [PATCH 04/10] Clean up left over objects properly (#3325) This commit aims to clean up left over objects. Task: BABEL-5472 Signed-off-by: Dipesh Dhameliya --- test/JDBC/expected/BABEL-3952-vu-verify.out | 3 +++ test/JDBC/expected/BABEL-3953-datetrunc-vu-verify.out | 3 +++ test/JDBC/expected/Test-Identity-vu-cleanup.out | 3 +++ test/JDBC/expected/Test-sp_reset_connection.out | 4 +++- test/JDBC/expected/babel_ddl.out | 2 ++ test/JDBC/expected/babel_unicode_charset.out | 2 ++ .../expected/parallel_query/Test-sp_reset_connection.out | 2 ++ test/JDBC/expected/sys-eomonth-vu-cleanup.out | 3 +++ test/JDBC/expected/sys-index_columns-vu-cleanup.out | 3 +++ test/JDBC/expected/table_variable_xact_errors.out | 3 +++ .../table_variable_xact_errors_isolation_snapshot.out | 3 +++ .../expected/table_variable_xact_errors_xact_abort_on.out | 3 +++ test/JDBC/expected/todatetimeoffset.out | 2 ++ test/JDBC/input/BABEL-3952-vu-verify.sql | 5 ++++- test/JDBC/input/Test-Identity-vu-cleanup.sql | 3 +++ test/JDBC/input/babel_ddl.sql | 4 +++- test/JDBC/input/babel_unicode_charset.sql | 2 ++ test/JDBC/input/functions/BABEL-3953-datetrunc-vu-verify.sql | 3 +++ test/JDBC/input/functions/sys-eomonth-vu-cleanup.sql | 3 +++ test/JDBC/input/sp_columns_100.sql | 2 +- .../JDBC/input/storedProcedures/Test-sp_reset_connection.mix | 2 ++ .../input/table_variables/table_variable_xact_errors.sql | 3 +++ test/JDBC/input/todatetimeoffset.sql | 2 ++ test/JDBC/input/views/sys-index_columns-vu-cleanup.sql | 3 +++ test/JDBC/parallel_query_jdbc_schedule | 2 -- 25 files changed, 64 insertions(+), 6 deletions(-) diff --git a/test/JDBC/expected/BABEL-3952-vu-verify.out b/test/JDBC/expected/BABEL-3952-vu-verify.out index 947b9bc072..a145d48455 100644 --- a/test/JDBC/expected/BABEL-3952-vu-verify.out +++ b/test/JDBC/expected/BABEL-3952-vu-verify.out @@ -651,3 +651,6 @@ time 12:24:00.0000000 ~~END~~ + +DROP TABLE IF EXISTS dbucket +GO diff --git a/test/JDBC/expected/BABEL-3953-datetrunc-vu-verify.out b/test/JDBC/expected/BABEL-3953-datetrunc-vu-verify.out index 4c15424174..cd50a213e6 100644 --- a/test/JDBC/expected/BABEL-3953-datetrunc-vu-verify.out +++ b/test/JDBC/expected/BABEL-3953-datetrunc-vu-verify.out @@ -440,6 +440,9 @@ time ~~END~~ +DROP TABLE IF EXISTS dtrunc +GO + SET DATEFIRST 1 SELECT DATETRUNC(ISO_WEEK, CAST('2020-09-13 21:32:32.23' as datetime2)) SELECT DATETRUNC(WEEK, CAST('2020-09-13 21:32:32.23' as datetime2)) diff --git a/test/JDBC/expected/Test-Identity-vu-cleanup.out b/test/JDBC/expected/Test-Identity-vu-cleanup.out index 75afc12aa6..e4520c8120 100644 --- a/test/JDBC/expected/Test-Identity-vu-cleanup.out +++ b/test/JDBC/expected/Test-Identity-vu-cleanup.out @@ -28,6 +28,9 @@ GO DROP PROCEDURE test_identity_vu_prepare_p5 GO +DROP VIEW scope_identity_view +GO + DROP TABLE test_identity_vu_prepare_t1 GO diff --git a/test/JDBC/expected/Test-sp_reset_connection.out b/test/JDBC/expected/Test-sp_reset_connection.out index b66e9f8585..8613fa3094 100644 --- a/test/JDBC/expected/Test-sp_reset_connection.out +++ b/test/JDBC/expected/Test-sp_reset_connection.out @@ -48,6 +48,8 @@ GO int ~~END~~ +DROP TABLE IF EXISTS sp_reset_connection_test_table; +GO -- 3. Test temp tables are deleted on reset CREATE TABLE #babel_temp_table (ID INT identity(1,1), Data INT) @@ -653,7 +655,7 @@ Result (cost=0.00..0.01 rows=1 width=4) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.085 ms +Babelfish T-SQL Batch Parsing Time: 0.075 ms ~~END~~ diff --git a/test/JDBC/expected/babel_ddl.out b/test/JDBC/expected/babel_ddl.out index 6516fdb48c..bce9329768 100644 --- a/test/JDBC/expected/babel_ddl.out +++ b/test/JDBC/expected/babel_ddl.out @@ -397,3 +397,5 @@ drop table computed_column_t1; GO drop table computed_column_t2; GO +drop table computed_column_error; +GO diff --git a/test/JDBC/expected/babel_unicode_charset.out b/test/JDBC/expected/babel_unicode_charset.out index aebc4be79c..47f35949ec 100644 --- a/test/JDBC/expected/babel_unicode_charset.out +++ b/test/JDBC/expected/babel_unicode_charset.out @@ -44,3 +44,5 @@ nvarchar 世界 ~~END~~ +drop table if exists unicode_test; +go diff --git a/test/JDBC/expected/parallel_query/Test-sp_reset_connection.out b/test/JDBC/expected/parallel_query/Test-sp_reset_connection.out index 4f6728f974..fde23af56a 100644 --- a/test/JDBC/expected/parallel_query/Test-sp_reset_connection.out +++ b/test/JDBC/expected/parallel_query/Test-sp_reset_connection.out @@ -48,6 +48,8 @@ GO int ~~END~~ +DROP TABLE IF EXISTS sp_reset_connection_test_table; +GO -- 3. Test temp tables are deleted on reset CREATE TABLE #babel_temp_table (ID INT identity(1,1), Data INT) diff --git a/test/JDBC/expected/sys-eomonth-vu-cleanup.out b/test/JDBC/expected/sys-eomonth-vu-cleanup.out index 0a998c56df..41a60d99ce 100644 --- a/test/JDBC/expected/sys-eomonth-vu-cleanup.out +++ b/test/JDBC/expected/sys-eomonth-vu-cleanup.out @@ -9,3 +9,6 @@ GO DROP PROCEDURE IF EXISTS GetEndOfNextMonthDate_EOMONTH; GO + +DROP Table eomonth_datestable +GO diff --git a/test/JDBC/expected/sys-index_columns-vu-cleanup.out b/test/JDBC/expected/sys-index_columns-vu-cleanup.out index 61ce66ee9d..294d775025 100644 --- a/test/JDBC/expected/sys-index_columns-vu-cleanup.out +++ b/test/JDBC/expected/sys-index_columns-vu-cleanup.out @@ -7,6 +7,9 @@ GO USE master GO +DROP table sys_index_columns_vu_prepare_t1 +GO + DROP TABLE sys_index_columns_vu_prepare_t3; GO diff --git a/test/JDBC/expected/table_variable_xact_errors.out b/test/JDBC/expected/table_variable_xact_errors.out index 76be1e58aa..33fe2bf459 100644 --- a/test/JDBC/expected/table_variable_xact_errors.out +++ b/test/JDBC/expected/table_variable_xact_errors.out @@ -682,6 +682,9 @@ GO ~~ERROR (Message: missing FROM-clause entry for table "i")~~ +DROP TABLE mytab +GO + DROP PROCEDURE myproc GO diff --git a/test/JDBC/expected/table_variable_xact_errors_isolation_snapshot.out b/test/JDBC/expected/table_variable_xact_errors_isolation_snapshot.out index 8125502bfe..a8130a4216 100644 --- a/test/JDBC/expected/table_variable_xact_errors_isolation_snapshot.out +++ b/test/JDBC/expected/table_variable_xact_errors_isolation_snapshot.out @@ -684,6 +684,9 @@ GO ~~ERROR (Message: missing FROM-clause entry for table "i")~~ +DROP TABLE mytab +GO + DROP PROCEDURE myproc GO diff --git a/test/JDBC/expected/table_variable_xact_errors_xact_abort_on.out b/test/JDBC/expected/table_variable_xact_errors_xact_abort_on.out index 9ba774fff4..6856aa3031 100644 --- a/test/JDBC/expected/table_variable_xact_errors_xact_abort_on.out +++ b/test/JDBC/expected/table_variable_xact_errors_xact_abort_on.out @@ -666,6 +666,9 @@ GO ~~ERROR (Message: missing FROM-clause entry for table "i")~~ +DROP TABLE mytab +GO + DROP PROCEDURE myproc GO diff --git a/test/JDBC/expected/todatetimeoffset.out b/test/JDBC/expected/todatetimeoffset.out index 6d672abebb..ee49f0f4bd 100644 --- a/test/JDBC/expected/todatetimeoffset.out +++ b/test/JDBC/expected/todatetimeoffset.out @@ -601,3 +601,5 @@ GO ~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ +drop table tem +GO diff --git a/test/JDBC/input/BABEL-3952-vu-verify.sql b/test/JDBC/input/BABEL-3952-vu-verify.sql index b60101ef34..448054ea1a 100644 --- a/test/JDBC/input/BABEL-3952-vu-verify.sql +++ b/test/JDBC/input/BABEL-3952-vu-verify.sql @@ -261,4 +261,7 @@ Create table dbucket(a time) insert into dbucket (a) values(date_bucket(minute,12, CAST('12:32:23.23' as time))) Select * from dbucket Select date_bucket(second,10, a) from dbucket -GO \ No newline at end of file +GO + +DROP TABLE IF EXISTS dbucket +GO diff --git a/test/JDBC/input/Test-Identity-vu-cleanup.sql b/test/JDBC/input/Test-Identity-vu-cleanup.sql index 75afc12aa6..e4520c8120 100644 --- a/test/JDBC/input/Test-Identity-vu-cleanup.sql +++ b/test/JDBC/input/Test-Identity-vu-cleanup.sql @@ -28,6 +28,9 @@ GO DROP PROCEDURE test_identity_vu_prepare_p5 GO +DROP VIEW scope_identity_view +GO + DROP TABLE test_identity_vu_prepare_t1 GO diff --git a/test/JDBC/input/babel_ddl.sql b/test/JDBC/input/babel_ddl.sql index 72015f2b77..d5367fdd35 100644 --- a/test/JDBC/input/babel_ddl.sql +++ b/test/JDBC/input/babel_ddl.sql @@ -253,4 +253,6 @@ GO drop table computed_column_t1; GO drop table computed_column_t2; -GO \ No newline at end of file +GO +drop table computed_column_error; +GO diff --git a/test/JDBC/input/babel_unicode_charset.sql b/test/JDBC/input/babel_unicode_charset.sql index 8cc45cbfdd..ff56f55eff 100644 --- a/test/JDBC/input/babel_unicode_charset.sql +++ b/test/JDBC/input/babel_unicode_charset.sql @@ -18,3 +18,5 @@ select "你好世界" from unicode_test with(nolock); go select 中文列名 from unicode_test with(nolock); go +drop table if exists unicode_test; +go diff --git a/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-verify.sql b/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-verify.sql index ebefb27462..224197178f 100644 --- a/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-verify.sql +++ b/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-verify.sql @@ -168,6 +168,9 @@ Select * from dtrunc Select datetrunc(second, a) from dtrunc GO +DROP TABLE IF EXISTS dtrunc +GO + SET DATEFIRST 1 SELECT DATETRUNC(ISO_WEEK, CAST('2020-09-13 21:32:32.23' as datetime2)) SELECT DATETRUNC(WEEK, CAST('2020-09-13 21:32:32.23' as datetime2)) diff --git a/test/JDBC/input/functions/sys-eomonth-vu-cleanup.sql b/test/JDBC/input/functions/sys-eomonth-vu-cleanup.sql index 0a998c56df..41a60d99ce 100644 --- a/test/JDBC/input/functions/sys-eomonth-vu-cleanup.sql +++ b/test/JDBC/input/functions/sys-eomonth-vu-cleanup.sql @@ -9,3 +9,6 @@ GO DROP PROCEDURE IF EXISTS GetEndOfNextMonthDate_EOMONTH; GO + +DROP Table eomonth_datestable +GO diff --git a/test/JDBC/input/sp_columns_100.sql b/test/JDBC/input/sp_columns_100.sql index 534eb5881c..e2e0d018df 100644 --- a/test/JDBC/input/sp_columns_100.sql +++ b/test/JDBC/input/sp_columns_100.sql @@ -1,4 +1,4 @@ --- sla_for_parallel_query_enforced 2000000 +-- sla_for_parallel_query_enforced 300000 -- create tables with most of the datatypes create table var(a char(10), b nchar(9), c nvarchar(8), d varchar(7), e text, f ntext, g varbinary(10), h binary(9), i image, j xml) go diff --git a/test/JDBC/input/storedProcedures/Test-sp_reset_connection.mix b/test/JDBC/input/storedProcedures/Test-sp_reset_connection.mix index 57cc553bc7..b6c0be0731 100644 --- a/test/JDBC/input/storedProcedures/Test-sp_reset_connection.mix +++ b/test/JDBC/input/storedProcedures/Test-sp_reset_connection.mix @@ -24,6 +24,8 @@ COMMIT TRANSACTION GO SELECT * FROM sp_reset_connection_test_table GO +DROP TABLE IF EXISTS sp_reset_connection_test_table; +GO -- 3. Test temp tables are deleted on reset CREATE TABLE #babel_temp_table (ID INT identity(1,1), Data INT) diff --git a/test/JDBC/input/table_variables/table_variable_xact_errors.sql b/test/JDBC/input/table_variables/table_variable_xact_errors.sql index e5abf4577b..19ce8c0871 100644 --- a/test/JDBC/input/table_variables/table_variable_xact_errors.sql +++ b/test/JDBC/input/table_variables/table_variable_xact_errors.sql @@ -484,6 +484,9 @@ GO EXECUTE myproc2 GO +DROP TABLE mytab +GO + DROP PROCEDURE myproc GO diff --git a/test/JDBC/input/todatetimeoffset.sql b/test/JDBC/input/todatetimeoffset.sql index cd0ccffa38..5ab1db217f 100644 --- a/test/JDBC/input/todatetimeoffset.sql +++ b/test/JDBC/input/todatetimeoffset.sql @@ -241,3 +241,5 @@ GO Select todatetimeoffset('10000-12-31 23:12:00.123 +00:00',743) GO +drop table tem +GO diff --git a/test/JDBC/input/views/sys-index_columns-vu-cleanup.sql b/test/JDBC/input/views/sys-index_columns-vu-cleanup.sql index 388239e528..3e56be98ec 100644 --- a/test/JDBC/input/views/sys-index_columns-vu-cleanup.sql +++ b/test/JDBC/input/views/sys-index_columns-vu-cleanup.sql @@ -7,6 +7,9 @@ GO USE master GO +DROP table sys_index_columns_vu_prepare_t1 +GO + DROP TABLE sys_index_columns_vu_prepare_t3; GO diff --git a/test/JDBC/parallel_query_jdbc_schedule b/test/JDBC/parallel_query_jdbc_schedule index 2a5f9ba88d..84997b3888 100644 --- a/test/JDBC/parallel_query_jdbc_schedule +++ b/test/JDBC/parallel_query_jdbc_schedule @@ -28,6 +28,4 @@ ignore#!#BABEL-3013 ignore#!#BABEL-SP_TABLE_PRIVILEGES ignore#!#ISC-Columns-vu-verify ignore#!#four-part-names-vu-verify -#TODO: BABEL-5472 -ignore#!#sp_columns_100 From f60d3c05e80c2511e260eaf54dec1c0c4c9f2920 Mon Sep 17 00:00:00 2001 From: Sharu Goel <30777678+thephantomthief@users.noreply.github.com> Date: Wed, 22 Jan 2025 19:47:30 +0530 Subject: [PATCH 05/10] Fix IDENTITY_INSERT to work cross-db (#3402) Previously, passing three part object names to SET IDENTITY_INSERT was throwing an error. In this commit, if the relation name is a three part name, we will parse the catalog name and set the IDENTITY_INSERT property for the relation in that catalog. Also with this commit, we will check if current user has permission to SET IDENTITY_INSERT for the relation. Task: BABEL-3212 Signed-off-by: Sharu Goel --- contrib/babelfishpg_tsql/src/pl_handler.c | 126 ++++-- .../BABEL-IDENTITY.out | 368 +++++++++++++++++- ...{BABEL-IDENTITY.sql => BABEL-IDENTITY.mix} | 240 ++++++++++++ 3 files changed, 689 insertions(+), 45 deletions(-) rename test/JDBC/{sql_expected => expected}/BABEL-IDENTITY.out (71%) rename test/JDBC/input/{BABEL-IDENTITY.sql => BABEL-IDENTITY.mix} (69%) diff --git a/contrib/babelfishpg_tsql/src/pl_handler.c b/contrib/babelfishpg_tsql/src/pl_handler.c index 0aa7710819..13892e6116 100644 --- a/contrib/babelfishpg_tsql/src/pl_handler.c +++ b/contrib/babelfishpg_tsql/src/pl_handler.c @@ -317,6 +317,19 @@ check_identity_insert(char** newval, void **extra, GucSource source) return true; } +static void +throw_error_for_identity_insert(char *database, char *schema, char* object) +{ + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("Cannot find the object \"%s%s%s%s%s\" because it does not exist or you do not have permissions.", + database ? database : "", + database ? "." : "", + schema ? schema : "", + schema ? "." : "", + object))); +} + static void assign_identity_insert(const char *newval, void *extra) { @@ -335,6 +348,10 @@ assign_identity_insert(const char *newval, void *extra) char *id_insert_rel_name = NULL; char *id_insert_schema_name = NULL; char *cur_db_name; + char *catalog_name = NULL; + char *logical_schema_name = NULL; + char *curr_user_if_cross_db = NULL; + Oid curr_user_id = InvalidOid; cur_db_name = get_cur_db_name(); @@ -362,40 +379,61 @@ assign_identity_insert(const char *newval, void *extra) option_flag = (char *) linitial(elemlist); rel_name = (char *) lsecond(elemlist); + /* Use catalog name if provided */ + if (list_length(elemlist) == 4) + { + catalog_name = (char *) lfourth(elemlist); + + if(!DbidIsValid(get_db_id(catalog_name))) + { + /* Get schema name for error message */ + logical_schema_name = (char *) lthird(elemlist); + throw_error_for_identity_insert(catalog_name, logical_schema_name, rel_name); + } + + cur_db_name = catalog_name; + curr_user_if_cross_db = get_user_for_database(cur_db_name); + + /* + * User in cross-db case can be NULL if login has no user + * that it can use to connect to that database. We should + * throw permission denied error in that case + */ + if (!curr_user_if_cross_db) + throw_error_for_identity_insert(catalog_name, logical_schema_name, rel_name); + } + /* Check the user provided schema value */ if (list_length(elemlist) >= 3) { - schema_name = (char *) lthird(elemlist); + logical_schema_name = (char *) lthird(elemlist); if (cur_db_name) schema_name = get_physical_schema_name(cur_db_name, - schema_name); + logical_schema_name); + + /* If no schema name is provided, we should use default schema */ + if (!schema_name) + { + char *user_name = NULL; + + /* If catalog name is not NULL, it is cross-db */ + if (catalog_name) + user_name = curr_user_if_cross_db; + else + user_name = GetUserNameFromId(GetUserId(), false); + + schema_name = get_physical_schema_name(cur_db_name, + get_authid_user_ext_schema_name(cur_db_name, user_name)); + } schema_oid = LookupExplicitNamespace(schema_name, true); if (!OidIsValid(schema_oid)) - ereport(ERROR, - (errcode(ERRCODE_UNDEFINED_SCHEMA), - errmsg("schema \"%s\" does not exist", - schema_name))); + throw_error_for_identity_insert(catalog_name, logical_schema_name, rel_name); rel_oid = get_relname_relid(rel_name, schema_oid); if (!OidIsValid(rel_oid)) - ereport(ERROR, - (errcode(ERRCODE_UNDEFINED_TABLE), - errmsg("relation \"%s\" does not exist", - rel_name))); - } - - /* Check the catalog name then ignore it */ - if (list_length(elemlist) == 4) - { - char *catalog_name = (char *) lfourth(elemlist); - - if (strcmp(catalog_name, get_database_name(MyDatabaseId)) != 0) - ereport(ERROR, - (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("cross-database references are not implemented: \"%s.%s.%s\"", - catalog_name, schema_name, rel_name))); + throw_error_for_identity_insert(catalog_name, logical_schema_name, rel_name); } /* If schema is not provided, find it from the search path. */ @@ -407,15 +445,51 @@ assign_identity_insert(const char *newval, void *extra) */ rel_oid = RelnameGetRelid(rel_name); if (!OidIsValid(rel_oid)) - ereport(ERROR, - (errcode(ERRCODE_UNDEFINED_TABLE), - errmsg("relation \"%s\" does not exist", - rel_name))); + throw_error_for_identity_insert(catalog_name, logical_schema_name, rel_name); schema_oid = get_rel_namespace(rel_oid); schema_name = get_namespace_name(schema_oid); } + /* If catalog name is not NULL, it is cross-db */ + if (catalog_name) + curr_user_id = get_role_oid(curr_user_if_cross_db, false); + else + curr_user_id = GetUserId(); + + /* Check if the physical schema is actually associated with current logical database */ + /* Ignore for temporary tables */ + if (schema_name && !isTempNamespace(get_namespace_oid(schema_name, false))) + { + Datum datum; + int16 db_id; + bool isnull; + HeapTuple tuple = SearchSysCache1(SYSNAMESPACENAME, CStringGetDatum(schema_name)); + + if (!HeapTupleIsValid(tuple)) + throw_error_for_identity_insert(catalog_name, logical_schema_name, rel_name); + + datum = SysCacheGetAttr(SYSNAMESPACENAME, tuple, Anum_namespace_ext_dbid, &isnull); + db_id = DatumGetInt16(datum); + + if (!DbidIsValid(db_id) || db_id != get_db_id(cur_db_name)) + throw_error_for_identity_insert(catalog_name, logical_schema_name, rel_name); + + ReleaseSysCache(tuple); + } + + /* + * For SET IDENTITY_INSERT, ALTER permission on relation is needed. In + * Babelfish, current user has ALTER permission on relation if either: + * + * 1. User is owner of object + * 2. User is member of db_ddladmin or db_owner database role + */ + if (!(object_ownercheck(RelationRelationId, rel_oid, curr_user_id) || + has_privs_of_role(curr_user_id, get_db_ddladmin_oid(cur_db_name, false)) || + has_privs_of_role(curr_user_id, get_db_owner_oid(cur_db_name, false)))) + throw_error_for_identity_insert(catalog_name, logical_schema_name, rel_name); + /* Process assignment logic */ if (strcmp(option_flag, "on") == 0) { diff --git a/test/JDBC/sql_expected/BABEL-IDENTITY.out b/test/JDBC/expected/BABEL-IDENTITY.out similarity index 71% rename from test/JDBC/sql_expected/BABEL-IDENTITY.out rename to test/JDBC/expected/BABEL-IDENTITY.out index c47efad5fe..b7f3d9fa50 100644 --- a/test/JDBC/sql_expected/BABEL-IDENTITY.out +++ b/test/JDBC/expected/BABEL-IDENTITY.out @@ -137,19 +137,19 @@ SET IDENTITY_INSERT test_table2 ON; go ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: relation "test_table2" does not exist)~~ +~~ERROR (Message: Cannot find the object "test_table2" because it does not exist or you do not have permissions.)~~ SET IDENTITY_INSERT fake_schema.test_table1 ON; go ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: schema "master_fake_schema" does not exist)~~ +~~ERROR (Message: Cannot find the object "fake_schema.test_table1" because it does not exist or you do not have permissions.)~~ SET IDENTITY_INSERT fake_db.dbo.test_table1 ON; go ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: cross-database references are not implemented: "fake_db.master_dbo.test_table1")~~ +~~ERROR (Message: Cannot find the object "fake_db.dbo.test_table1" because it does not exist or you do not have permissions.)~~ CREATE TABLE dbo.test_table2 (test_id INT IDENTITY(7,2), test_col1 INT); @@ -763,7 +763,7 @@ Index Scan using test_id_index_pkey on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 14.214 ms +Babelfish T-SQL Batch Parsing Time: 9.792 ms ~~END~~ @@ -778,7 +778,7 @@ Index Scan using test_id_index_pkey on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 8.005 ms +Babelfish T-SQL Batch Parsing Time: 3.872 ms ~~END~~ @@ -793,7 +793,7 @@ Index Scan using test_id_index_pkey on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 11.694 ms +Babelfish T-SQL Batch Parsing Time: 4.621 ms ~~END~~ @@ -808,7 +808,7 @@ Index Scan using test_id_index_pkey on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 67.645 ms +Babelfish T-SQL Batch Parsing Time: 42.064 ms ~~END~~ @@ -825,7 +825,7 @@ Bitmap Heap Scan on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 8.888 ms +Babelfish T-SQL Batch Parsing Time: 9.045 ms ~~END~~ @@ -840,7 +840,7 @@ Seq Scan on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 1.746 ms +Babelfish T-SQL Batch Parsing Time: 2.038 ms ~~END~~ @@ -857,7 +857,7 @@ Bitmap Heap Scan on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 8.471 ms +Babelfish T-SQL Batch Parsing Time: 9.868 ms ~~END~~ @@ -873,7 +873,7 @@ Index Scan using test_id_index_pkey on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.360 ms +Babelfish T-SQL Batch Parsing Time: 0.577 ms ~~END~~ @@ -888,7 +888,7 @@ Seq Scan on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 2.401 ms +Babelfish T-SQL Batch Parsing Time: 2.833 ms ~~END~~ @@ -903,7 +903,7 @@ Index Scan using test_id_index_tinyint_pkey on test_id_index_tinyint ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.229 ms +Babelfish T-SQL Batch Parsing Time: 0.302 ms ~~END~~ @@ -918,7 +918,7 @@ Index Scan using test_id_index_smallint_pkey on test_id_index_smallint ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.178 ms +Babelfish T-SQL Batch Parsing Time: 0.229 ms ~~END~~ @@ -933,7 +933,7 @@ Index Scan using test_id_index_bigint_pkey on test_id_index_bigint ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.175 ms +Babelfish T-SQL Batch Parsing Time: 0.226 ms ~~END~~ @@ -948,7 +948,7 @@ Index Scan using test_id_index_numeric_pkey on test_id_index_numeric ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.175 ms +Babelfish T-SQL Batch Parsing Time: 0.223 ms ~~END~~ @@ -974,7 +974,7 @@ Index Scan using test_numeric_index_no_id_pkey on test_numeric_index_no_id ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.169 ms +Babelfish T-SQL Batch Parsing Time: 0.290 ms ~~END~~ @@ -1194,7 +1194,7 @@ Index Only Scan using babel_3384_test_pkey on babel_3384_test ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.187 ms +Babelfish T-SQL Batch Parsing Time: 0.171 ms ~~END~~ select id from babel_3384_test WHERE id = @@IDENTITY @@ -1208,7 +1208,7 @@ Index Only Scan using babel_3384_test_pkey on babel_3384_test ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.159 ms +Babelfish T-SQL Batch Parsing Time: 0.164 ms ~~END~~ @@ -1232,3 +1232,333 @@ int DROP TABLE babel_3384_test GO + +-- tsql +CREATE DATABASE identity_insert_db +GO + +USE identity_insert_db +GO + +CREATE LOGIN identity_insert_l1 WITH PASSWORD = '123' +GO + +CREATE USER identity_insert_u1 FOR LOGIN identity_insert_l1 WITH DEFAULT_SCHEMA = identity_insert_sch +GO + +CREATE SCHEMA identity_insert_sch AUTHORIZATION identity_insert_u1 +GO + +CREATE TABLE identity_insert_t1 (a int identity, b int) +GO + +-- Three part name: wrong catalog name. Should throw error +SET IDENTITY_INSERT wrong_db.dbo.identity_insert_t1 ON +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot find the object "wrong_db.dbo.identity_insert_t1" because it does not exist or you do not have permissions.)~~ + + +-- Three part name: wrong schema name. Should throw error +SET IDENTITY_INSERT identity_insert_db.wrong_sch.identity_insert_t1 ON +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot find the object "identity_insert_db.wrong_sch.identity_insert_t1" because it does not exist or you do not have permissions.)~~ + + +-- Three part name: wrong table name. Should throw error +SET IDENTITY_INSERT identity_insert_db.dbo.wrong_t1 ON +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot find the object "identity_insert_db.dbo.wrong_t1" because it does not exist or you do not have permissions.)~~ + + +-- Three part name: omit database name. Should throw syntax error +SET IDENTITY_INSERT .dbo.wrong_t1 ON +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: syntax error at or near ".")~~ + + +-- Three part name: omit schema name. Should throw syntax error +SET IDENTITY_INSERT identity_insert_db..wrong_t1 ON +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: syntax error at or near "..")~~ + + +-- Three part name: omit both database and schema name. Should throw syntax error +SET IDENTITY_INSERT ..wrong_t1 ON +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: syntax error at or near "..")~~ + + +-- Should fail as IDENTITY_INSERT is OFF by default +INSERT INTO identity_insert_t1 (a, b) VALUES (2, 102); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot insert a non-DEFAULT value into column "a")~~ + + +-- Three-part name: catalog name = current database +SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 ON +GO + +-- Should not fail +INSERT INTO identity_insert_t1 (a, b) VALUES (3, 103); +GO +~~ROW COUNT: 1~~ + + +SELECT * FROM identity_insert_t1 ORDER BY a +GO +~~START~~ +int#!#int +3#!#103 +~~END~~ + + +USE master +GO + +-- Three-part name: catalog name != current database (cross-db) +SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 OFF +GO + +-- Should fail +INSERT INTO identity_insert_db.dbo.identity_insert_t1 (a, b) VALUES (4, 104); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot insert a non-DEFAULT value into column "a")~~ + + +-- tsql user=identity_insert_l1 password=123 +USE master +GO + +-- User does not have ALTER permission on table +-- Three-part name: catalog name != current database (cross-db). Should throw error +SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 ON +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot find the object "identity_insert_db.dbo.identity_insert_t1" because it does not exist or you do not have permissions.)~~ + + +-- tsql +-- Add user as member of db_owner +USE identity_insert_db +GO + +ALTER ROLE db_owner ADD MEMBER identity_insert_u1 +GO + +-- tsql user=identity_insert_l1 password=123 +-- Should now have permission +SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 OFF +GO + +-- Should fail +INSERT INTO identity_insert_db.dbo.identity_insert_t1 (a, b) VALUES (5, 105); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot insert a non-DEFAULT value into column "a")~~ + + +-- tsql +-- Drop from db_owner, give all supported GRANTs. Should still not have permission to set IDENTITY_INSERT +USE identity_insert_db +GO + +ALTER ROLE db_owner DROP MEMBER identity_insert_u1 +GO + +GRANT SELECT, INSERT, UPDATE, DELETE ON OBJECT :: identity_insert_t1 TO identity_insert_u1 +GO + +GRANT SELECT, INSERT, UPDATE, DELETE ON SCHEMA :: dbo TO identity_insert_u1 +GO + +-- tsql user=identity_insert_l1 password=123 +-- Should not have permission. Should give error +SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 ON +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot find the object "identity_insert_db.dbo.identity_insert_t1" because it does not exist or you do not have permissions.)~~ + + +-- tsql +-- Revoke all the GRANTs. Add user as a member of db_ddladmin. Should now have permission to set IDENTITY_INSERT +USE identity_insert_db +GO + +REVOKE SELECT, INSERT, UPDATE, DELETE ON OBJECT :: identity_insert_t1 FROM identity_insert_u1 +GO + +REVOKE SELECT, INSERT, UPDATE, DELETE ON SCHEMA :: dbo FROM identity_insert_u1 +GO + +ALTER ROLE db_ddladmin ADD MEMBER identity_insert_u1 +GO + +-- tsql user=identity_insert_l1 password=123 +-- Should now have permission +SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 OFF +GO + +-- Should fail +INSERT INTO identity_insert_db.dbo.identity_insert_t1 (a, b) VALUES (6, 106); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot insert a non-DEFAULT value into column "a")~~ + + +-- tsql +-- Remove user as a member of db_ddladmin. Should not have permission to set IDENTITY_INSERT +USE identity_insert_db +GO + +ALTER ROLE db_ddladmin DROP MEMBER identity_insert_u1 +GO + +-- tsql user=identity_insert_l1 password=123 +-- Should not have permission. Should give error +SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 ON +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot find the object "identity_insert_db.dbo.identity_insert_t1" because it does not exist or you do not have permissions.)~~ + + +-- Create a table in schema where user is owner +USE identity_insert_db +GO + +CREATE TABLE identity_insert_sch.identity_insert_t2 (c int identity, d int) +GO + +SELECT USER_NAME(), IS_MEMBER('db_owner'), IS_MEMBER('db_ddladmin') +GO +~~START~~ +nvarchar#!#int#!#int +identity_insert_u1#!#0#!#0 +~~END~~ + + +USE master +GO + +SELECT USER_NAME(), IS_MEMBER('db_owner'), IS_MEMBER('db_ddladmin') +GO +~~START~~ +nvarchar#!#int#!#int +guest#!#0#!#0 +~~END~~ + + +-- Even though user is not member of db_owner, db_ddladmin roles, as owner of table it can set IDENTITY_INSERT +-- Three part name +SET IDENTITY_INSERT identity_insert_db.identity_insert_sch.identity_insert_t2 ON +GO + +USE identity_insert_db +GO + +-- Should not fail +INSERT INTO identity_insert_t2 (c, d) VALUES (1, 101); +GO +~~ROW COUNT: 1~~ + + +SELECT * FROM identity_insert_t2 +GO +~~START~~ +int#!#int +1#!#101 +~~END~~ + + +DROP TABLE identity_insert_t2 +GO + +-- psql +-- Need to terminate active session before cleaning up the login +SELECT pg_terminate_backend(pid) FROM pg_stat_get_activity(NULL) +WHERE sys.suser_name(usesysid) = 'identity_insert_l1' AND backend_type = 'client backend' AND usesysid IS NOT NULL; +GO +~~START~~ +bool +t +~~END~~ + + +-- Wait to sync with another session +SELECT pg_sleep(1); +GO +~~START~~ +void + +~~END~~ + + +-- tsql +USE identity_insert_db +GO + +DROP TABLE identity_insert_t1 +GO + +DROP SCHEMA identity_insert_sch +GO + +DROP USER identity_insert_u1 +GO + +DROP LOGIN identity_insert_l1 +GO + +USE master +GO + +DROP DATABASE identity_insert_db +GO + +-- We should ensure physical schema found corresponds to appropriate logical database +CREATE DATABASE master_ident_ins +GO + +USE master_ident_ins +GO + +CREATE TABLE ident_t1 (a int identity, b int) +GO + +-- Should not fail because relation exists +SET IDENTITY_INSERT master_ident_ins.dbo.ident_t1 ON +GO + +-- Should fail because relation does not exist +SET IDENTITY_INSERT master.ident_ins_dbo.ident_t1 ON +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot find the object "master.ident_ins_dbo.ident_t1" because it does not exist or you do not have permissions.)~~ + + +USE master +GO + +DROP DATABASE master_ident_ins +GO diff --git a/test/JDBC/input/BABEL-IDENTITY.sql b/test/JDBC/input/BABEL-IDENTITY.mix similarity index 69% rename from test/JDBC/input/BABEL-IDENTITY.sql rename to test/JDBC/input/BABEL-IDENTITY.mix index bdceafa914..d95a9b3061 100644 --- a/test/JDBC/input/BABEL-IDENTITY.sql +++ b/test/JDBC/input/BABEL-IDENTITY.mix @@ -557,3 +557,243 @@ GO DROP TABLE babel_3384_test GO + +-- tsql +CREATE DATABASE identity_insert_db +GO + +USE identity_insert_db +GO + +CREATE LOGIN identity_insert_l1 WITH PASSWORD = '123' +GO + +CREATE USER identity_insert_u1 FOR LOGIN identity_insert_l1 WITH DEFAULT_SCHEMA = identity_insert_sch +GO + +CREATE SCHEMA identity_insert_sch AUTHORIZATION identity_insert_u1 +GO + +CREATE TABLE identity_insert_t1 (a int identity, b int) +GO + +-- Three part name: wrong catalog name. Should throw error +SET IDENTITY_INSERT wrong_db.dbo.identity_insert_t1 ON +GO + +-- Three part name: wrong schema name. Should throw error +SET IDENTITY_INSERT identity_insert_db.wrong_sch.identity_insert_t1 ON +GO + +-- Three part name: wrong table name. Should throw error +SET IDENTITY_INSERT identity_insert_db.dbo.wrong_t1 ON +GO + +-- Three part name: omit database name. Should throw syntax error +SET IDENTITY_INSERT .dbo.wrong_t1 ON +GO + +-- Three part name: omit schema name. Should throw syntax error +SET IDENTITY_INSERT identity_insert_db..wrong_t1 ON +GO + +-- Three part name: omit both database and schema name. Should throw syntax error +SET IDENTITY_INSERT ..wrong_t1 ON +GO + +-- Should fail as IDENTITY_INSERT is OFF by default +INSERT INTO identity_insert_t1 (a, b) VALUES (2, 102); +GO + +-- Three-part name: catalog name = current database +SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 ON +GO + +-- Should not fail +INSERT INTO identity_insert_t1 (a, b) VALUES (3, 103); +GO + +SELECT * FROM identity_insert_t1 ORDER BY a +GO + +USE master +GO + +-- Three-part name: catalog name != current database (cross-db) +SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 OFF +GO + +-- Should fail +INSERT INTO identity_insert_db.dbo.identity_insert_t1 (a, b) VALUES (4, 104); +GO + +-- tsql user=identity_insert_l1 password=123 +USE master +GO + +-- User does not have ALTER permission on table +-- Three-part name: catalog name != current database (cross-db). Should throw error +SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 ON +GO + +-- tsql +-- Add user as member of db_owner +USE identity_insert_db +GO + +ALTER ROLE db_owner ADD MEMBER identity_insert_u1 +GO + +-- tsql user=identity_insert_l1 password=123 +-- Should now have permission +SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 OFF +GO + +-- Should fail +INSERT INTO identity_insert_db.dbo.identity_insert_t1 (a, b) VALUES (5, 105); +GO + +-- tsql +-- Drop from db_owner, give all supported GRANTs. Should still not have permission to set IDENTITY_INSERT +USE identity_insert_db +GO + +ALTER ROLE db_owner DROP MEMBER identity_insert_u1 +GO + +GRANT SELECT, INSERT, UPDATE, DELETE ON OBJECT :: identity_insert_t1 TO identity_insert_u1 +GO + +GRANT SELECT, INSERT, UPDATE, DELETE ON SCHEMA :: dbo TO identity_insert_u1 +GO + +-- tsql user=identity_insert_l1 password=123 +-- Should not have permission. Should give error +SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 ON +GO + +-- tsql +-- Revoke all the GRANTs. Add user as a member of db_ddladmin. Should now have permission to set IDENTITY_INSERT +USE identity_insert_db +GO + +REVOKE SELECT, INSERT, UPDATE, DELETE ON OBJECT :: identity_insert_t1 FROM identity_insert_u1 +GO + +REVOKE SELECT, INSERT, UPDATE, DELETE ON SCHEMA :: dbo FROM identity_insert_u1 +GO + +ALTER ROLE db_ddladmin ADD MEMBER identity_insert_u1 +GO + +-- tsql user=identity_insert_l1 password=123 +-- Should now have permission +SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 OFF +GO + +-- Should fail +INSERT INTO identity_insert_db.dbo.identity_insert_t1 (a, b) VALUES (6, 106); +GO + +-- tsql +-- Remove user as a member of db_ddladmin. Should not have permission to set IDENTITY_INSERT +USE identity_insert_db +GO + +ALTER ROLE db_ddladmin DROP MEMBER identity_insert_u1 +GO + +-- tsql user=identity_insert_l1 password=123 +-- Should not have permission. Should give error +SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 ON +GO + +-- Create a table in schema where user is owner +USE identity_insert_db +GO + +CREATE TABLE identity_insert_sch.identity_insert_t2 (c int identity, d int) +GO + +SELECT USER_NAME(), IS_MEMBER('db_owner'), IS_MEMBER('db_ddladmin') +GO + +USE master +GO + +SELECT USER_NAME(), IS_MEMBER('db_owner'), IS_MEMBER('db_ddladmin') +GO + +-- Even though user is not member of db_owner, db_ddladmin roles, as owner of table it can set IDENTITY_INSERT +-- Three part name +SET IDENTITY_INSERT identity_insert_db.identity_insert_sch.identity_insert_t2 ON +GO + +USE identity_insert_db +GO + +-- Should not fail +INSERT INTO identity_insert_t2 (c, d) VALUES (1, 101); +GO + +SELECT * FROM identity_insert_t2 +GO + +DROP TABLE identity_insert_t2 +GO + +-- psql +-- Need to terminate active session before cleaning up the login +SELECT pg_terminate_backend(pid) FROM pg_stat_get_activity(NULL) +WHERE sys.suser_name(usesysid) = 'identity_insert_l1' AND backend_type = 'client backend' AND usesysid IS NOT NULL; +GO + +-- Wait to sync with another session +SELECT pg_sleep(1); +GO + +-- tsql +USE identity_insert_db +GO + +DROP TABLE identity_insert_t1 +GO + +DROP SCHEMA identity_insert_sch +GO + +DROP USER identity_insert_u1 +GO + +DROP LOGIN identity_insert_l1 +GO + +USE master +GO + +DROP DATABASE identity_insert_db +GO + +-- We should ensure physical schema found corresponds to appropriate logical database +CREATE DATABASE master_ident_ins +GO + +USE master_ident_ins +GO + +CREATE TABLE ident_t1 (a int identity, b int) +GO + +-- Should not fail because relation exists +SET IDENTITY_INSERT master_ident_ins.dbo.ident_t1 ON +GO + +-- Should fail because relation does not exist +SET IDENTITY_INSERT master.ident_ins_dbo.ident_t1 ON +GO + +USE master +GO + +DROP DATABASE master_ident_ins +GO From 2c6aa5a2de6740e12529f0c3b0818f793efca0d2 Mon Sep 17 00:00:00 2001 From: Tanzeel Khan <140405735+tanscorpio7@users.noreply.github.com> Date: Mon, 27 Jan 2025 22:29:56 +0530 Subject: [PATCH 06/10] configure postgres without readline (#3430) Configure postgres engine without readline in github actions test and fix engine clone script which as failing because $HEAD_OWNER does not return correct value of user who created the PR so use ${{ github.event.pull_request.head.repo.owner.login }} instead #### Engine Change https://github.com/babelfish-for-postgresql/postgresql_modified_for_babelfish/pull/520 #### Extensios Change https://github.com/babelfish-for-postgresql/babelfish_extensions/pull/3430 Signed-off-by: Tanzeel Khan --- .../build-modified-postgres/action.yml | 10 +++++----- 1 file changed, 5 insertions(+), 5 deletions(-) diff --git a/.github/composite-actions/build-modified-postgres/action.yml b/.github/composite-actions/build-modified-postgres/action.yml index 26ac521394..f9299f30fc 100644 --- a/.github/composite-actions/build-modified-postgres/action.yml +++ b/.github/composite-actions/build-modified-postgres/action.yml @@ -35,7 +35,7 @@ runs: else ENGINE_BRANCH=${{inputs.engine_branch}} fi - REPOSITORY_OWNER=$HEAD_OWNER + REPOSITORY_OWNER=${{ github.event.pull_request.head.repo.owner.login }} else if [[ ${{inputs.engine_branch}} == "latest" ]]; then ENGINE_BRANCH=$GITHUB_REF_NAME @@ -86,13 +86,13 @@ runs: cd .. cd postgresql_modified_for_babelfish if [[ ${{inputs.tap_tests}} == "yes" ]]; then - ./configure CC='ccache gcc' --prefix=$HOME/${{ inputs.install_dir }}/ --with-python PYTHON=/usr/bin/python3.8 --enable-cassert CFLAGS="-ggdb" --with-libxml --with-uuid=ossp --with-icu --enable-tap-tests --with-gssapi + ./configure CC='ccache gcc' --prefix=$HOME/${{ inputs.install_dir }}/ --with-python PYTHON=/usr/bin/python3.8 --without-readline --enable-cassert CFLAGS="-ggdb" --with-libxml --with-uuid=ossp --with-icu --enable-tap-tests --with-gssapi elif [[ ${{inputs.code_coverage}} == "yes" ]]; then - ./configure CC='ccache gcc' --prefix=$HOME/${{ inputs.install_dir }}/ --with-python PYTHON=/usr/bin/python3.8 --enable-coverage --enable-cassert CFLAGS="-ggdb" --with-libxml --with-uuid=ossp --with-icu + ./configure CC='ccache gcc' --prefix=$HOME/${{ inputs.install_dir }}/ --with-python PYTHON=/usr/bin/python3.8 --without-readline --enable-coverage --enable-cassert CFLAGS="-ggdb" --with-libxml --with-uuid=ossp --with-icu elif [[ ${{inputs.release_mode}} == "yes" ]]; then - ./configure CC='ccache gcc' --prefix=$HOME/${{ inputs.install_dir }}/ --with-python PYTHON=/usr/bin/python3.8 CFLAGS="-ggdb -O2" --with-libxml --with-uuid=ossp --with-icu + ./configure CC='ccache gcc' --prefix=$HOME/${{ inputs.install_dir }}/ --with-python PYTHON=/usr/bin/python3.8 CFLAGS="-ggdb -O2" --without-readline --with-libxml --with-uuid=ossp --with-icu else - ./configure CC='ccache gcc' --prefix=$HOME/${{ inputs.install_dir }}/ --with-python PYTHON=/usr/bin/python3.8 --enable-cassert CFLAGS="-ggdb" --with-libxml --with-uuid=ossp --with-icu + ./configure CC='ccache gcc' --prefix=$HOME/${{ inputs.install_dir }}/ --with-python PYTHON=/usr/bin/python3.8 --without-readline --enable-cassert CFLAGS="-ggdb" --with-libxml --with-uuid=ossp --with-icu fi make -j 4 make install From cb12c965bc4377b6acafc71c61b34432f5a50cd6 Mon Sep 17 00:00:00 2001 From: Nirmit Shah <44708230+shah-nirmit@users.noreply.github.com> Date: Tue, 28 Jan 2025 10:59:58 +0530 Subject: [PATCH 07/10] Fix float to varchar/char casting and coversion (#3413) We were using CoerceViaIO path before to cast float to varchar/char , added a new cast which will always display only upto 6 decimal digits, and rounding results when more decimal digits are present Fix Formatting when using to_char function inside CONVERT function for float->string . Also we were not compute the number of decimal digits to be shown properly in case the value before decimal is 0. Issues Resolved: BABEL-5459 Signed-off-by: Nirmit Shah --- .../babelfish_common_helper--5.0.0--5.1.0.sql | 26 ++ contrib/babelfishpg_common/sql/varchar.sql | 16 + contrib/babelfishpg_common/src/varchar.c | 102 ++++++ .../sql/sys_function_helpers.sql | 12 +- .../babelfishpg_tsql--5.0.0--5.1.0.sql | 73 ++++ contrib/babelfishpg_tsql/src/pltsql_coerce.c | 4 - test/JDBC/expected/BABEL-1193.out | 6 +- test/JDBC/expected/BABEL-889-vu-verify.out | 2 +- test/JDBC/expected/BABEL-889.out | 2 +- test/JDBC/expected/babel_function.out | 2 +- .../chinese_prc_ci_as/BABEL-889-vu-verify.out | 2 +- .../chinese_prc_ci_as/BABEL-889.out | 2 +- .../chinese_prc_ci_as/babel_function.out | 2 +- .../japanese_ci_as/BABEL-889-vu-verify.out | 2 +- .../japanese_ci_as/BABEL-889.out | 2 +- ..._conv_float_to_varchar_char-vu-cleanup.out | 17 + ..._conv_float_to_varchar_char-vu-prepare.out | 182 +++++++++ ...t_conv_float_to_varchar_char-vu-verify.out | 346 ++++++++++++++++++ ...to_varchar_char_before_17_3-vu-cleanup.out | 17 + ...to_varchar_char_before_17_3-vu-prepare.out | 182 +++++++++ ..._to_varchar_char_before_17_3-vu-verify.out | 346 ++++++++++++++++++ ..._conv_float_to_varchar_char-vu-cleanup.sql | 17 + ..._conv_float_to_varchar_char-vu-prepare.sql | 178 +++++++++ ...t_conv_float_to_varchar_char-vu-verify.sql | 147 ++++++++ ...to_varchar_char_before_17_3-vu-cleanup.sql | 17 + ...to_varchar_char_before_17_3-vu-prepare.sql | 178 +++++++++ ..._to_varchar_char_before_17_3-vu-verify.sql | 147 ++++++++ test/JDBC/jdbc_schedule | 3 + test/JDBC/upgrade/13_4/schedule | 1 + test/JDBC/upgrade/13_5/schedule | 1 + test/JDBC/upgrade/13_6/schedule | 1 + test/JDBC/upgrade/13_7/schedule | 1 + test/JDBC/upgrade/13_8/schedule | 1 + test/JDBC/upgrade/13_9/schedule | 1 + 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_15/schedule | 1 + test/JDBC/upgrade/14_16/schedule | 1 + test/JDBC/upgrade/14_3/schedule | 1 + test/JDBC/upgrade/14_5/schedule | 1 + test/JDBC/upgrade/14_6/schedule | 1 + test/JDBC/upgrade/14_7/schedule | 1 + test/JDBC/upgrade/14_8/schedule | 1 + test/JDBC/upgrade/14_9/schedule | 1 + test/JDBC/upgrade/15_1/schedule | 1 + test/JDBC/upgrade/15_10/schedule | 1 + test/JDBC/upgrade/15_11/schedule | 1 + test/JDBC/upgrade/15_2/schedule | 1 + test/JDBC/upgrade/15_3/schedule | 1 + 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/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/16_6/schedule | 1 + test/JDBC/upgrade/16_7/schedule | 1 + test/JDBC/upgrade/17_2/schedule | 1 + test/JDBC/upgrade/latest/schedule | 1 + 64 files changed, 2048 insertions(+), 20 deletions(-) create mode 100644 test/JDBC/expected/test_conv_float_to_varchar_char-vu-cleanup.out create mode 100644 test/JDBC/expected/test_conv_float_to_varchar_char-vu-prepare.out create mode 100644 test/JDBC/expected/test_conv_float_to_varchar_char-vu-verify.out create mode 100644 test/JDBC/expected/test_conv_float_to_varchar_char_before_17_3-vu-cleanup.out create mode 100644 test/JDBC/expected/test_conv_float_to_varchar_char_before_17_3-vu-prepare.out create mode 100644 test/JDBC/expected/test_conv_float_to_varchar_char_before_17_3-vu-verify.out create mode 100644 test/JDBC/input/functions/test_conv_float_to_varchar_char-vu-cleanup.sql create mode 100644 test/JDBC/input/functions/test_conv_float_to_varchar_char-vu-prepare.sql create mode 100644 test/JDBC/input/functions/test_conv_float_to_varchar_char-vu-verify.sql create mode 100644 test/JDBC/input/functions/test_conv_float_to_varchar_char_before_17_3-vu-cleanup.sql create mode 100644 test/JDBC/input/functions/test_conv_float_to_varchar_char_before_17_3-vu-prepare.sql create mode 100644 test/JDBC/input/functions/test_conv_float_to_varchar_char_before_17_3-vu-verify.sql diff --git a/contrib/babelfishpg_common/sql/upgrades/babelfish_common_helper--5.0.0--5.1.0.sql b/contrib/babelfishpg_common/sql/upgrades/babelfish_common_helper--5.0.0--5.1.0.sql index d9d49f53e7..ee9d218a49 100644 --- a/contrib/babelfishpg_common/sql/upgrades/babelfish_common_helper--5.0.0--5.1.0.sql +++ b/contrib/babelfishpg_common/sql/upgrades/babelfish_common_helper--5.0.0--5.1.0.sql @@ -49,6 +49,16 @@ RETURNS sys.BPCHAR AS 'babelfishpg_common', 'fixeddecimal2bpchar' LANGUAGE C IMMUTABLE STRICT PARALLEL SAFE; +CREATE OR REPLACE FUNCTION sys.float82varchar(pg_catalog.float8, integer, BOOLEAN) +RETURNS sys.VARCHAR +AS 'babelfishpg_common', 'float82varchar' +LANGUAGE C IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.float82bpchar(pg_catalog.float8, integer, BOOLEAN) +RETURNS sys.BPCHAR +AS 'babelfishpg_common', 'float82bpchar' +LANGUAGE C IMMUTABLE STRICT PARALLEL SAFE; + DO $$ DECLARE exception_message text; @@ -103,6 +113,22 @@ CREATE OPERATOR sys.% ( END IF; END $$; +DO $$ +DECLARE + exception_message text; +BEGIN +CREATE CAST (pg_catalog.float8 AS sys.VARCHAR) +WITH FUNCTION sys.float82varchar(pg_catalog.float8, integer, BOOLEAN) AS IMPLICIT; + +CREATE CAST (pg_catalog.float8 AS sys.BPCHAR) +WITH FUNCTION sys.float82bpchar(pg_catalog.float8, integer, BOOLEAN) AS IMPLICIT; +EXCEPTION WHEN duplicate_object THEN + GET STACKED DIAGNOSTICS + exception_message = MESSAGE_TEXT; + RAISE WARNING '%', exception_message; +END; +$$; + CREATE OR REPLACE FUNCTION sys.moneylarger(sys.MONEY, sys.MONEY) RETURNS sys.MONEY AS 'babelfishpg_money', 'fixeddecimallarger' diff --git a/contrib/babelfishpg_common/sql/varchar.sql b/contrib/babelfishpg_common/sql/varchar.sql index 8974452819..04eb192ed1 100644 --- a/contrib/babelfishpg_common/sql/varchar.sql +++ b/contrib/babelfishpg_common/sql/varchar.sql @@ -349,3 +349,19 @@ CREATE OR REPLACE AGGREGATE sys.min(sys.NVARCHAR) combinefunc = sys.nvarchar_smaller, parallel = safe ); + +CREATE OR REPLACE FUNCTION sys.float82varchar(pg_catalog.float8, integer, BOOLEAN) +RETURNS sys.VARCHAR +AS 'babelfishpg_common', 'float82varchar' +LANGUAGE C IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.float82bpchar(pg_catalog.float8, integer, BOOLEAN) +RETURNS sys.BPCHAR +AS 'babelfishpg_common', 'float82bpchar' +LANGUAGE C IMMUTABLE STRICT PARALLEL SAFE; + +CREATE CAST (pg_catalog.float8 AS sys.VARCHAR) +WITH FUNCTION sys.float82varchar(pg_catalog.float8, integer, BOOLEAN) AS IMPLICIT; + +CREATE CAST (pg_catalog.float8 AS sys.BPCHAR) +WITH FUNCTION sys.float82bpchar(pg_catalog.float8, integer, BOOLEAN) AS IMPLICIT; diff --git a/contrib/babelfishpg_common/src/varchar.c b/contrib/babelfishpg_common/src/varchar.c index c90145fda9..0827e2205d 100644 --- a/contrib/babelfishpg_common/src/varchar.c +++ b/contrib/babelfishpg_common/src/varchar.c @@ -17,6 +17,7 @@ #include "access/hash.h" #include "collation.h" +#include "common/shortest_dec.h" #include "catalog/pg_collation.h" #include "catalog/pg_type.h" #include "encoding/encoding.h" @@ -562,6 +563,8 @@ PG_FUNCTION_INFO_V1(varchar2money); PG_FUNCTION_INFO_V1(varchar2numeric); PG_FUNCTION_INFO_V1(fixeddecimal2varchar); PG_FUNCTION_INFO_V1(fixeddecimal2bpchar); +PG_FUNCTION_INFO_V1(float82varchar); +PG_FUNCTION_INFO_V1(float82bpchar); /***************************************************************************** * varchar - varchar(n) @@ -1188,6 +1191,105 @@ fixeddecimal2bpchar(PG_FUNCTION_ARGS) #undef FIXEDDECIMAL_2_VARCHAR_MULTIPLIER #undef FIXEDDECIMAL_2_VARCHAR_SCALE +Datum +float82varchar(PG_FUNCTION_ARGS) +{ + float8 num = PG_GETARG_FLOAT8(0); + int32 typmod = PG_GETARG_INT32(1); + /* When No Typmod is defined Default Length is 30 */ + int maxlen = (typmod == -1) ? 30 : (typmod - VARHDRSZ); + Datum res; + /* 32 length as double_to_shortest_decimal_buf always returns string with length less that 30*/ + char *ascii = (char *) palloc0(32); + + /* round to 6 decimal digits */ + if (unlikely(isinf(num)|| isnan(num))) + { + ereport(ERROR, + (errcode(ERRCODE_DATA_EXCEPTION), + errmsg("Error Converting Float Value to String."))); + } + else + { + num = round(num * 1000000.0) / 1000000.0; + } + + double_to_shortest_decimal_buf(num, ascii); + + /* Check if the number fits within the specified length */ + if (maxlen > 0) + { + size_t str_len = strlen(ascii); + if (str_len > maxlen) + { + ereport(ERROR, + (errcode(ERRCODE_STRING_DATA_RIGHT_TRUNCATION), + errmsg("There is insufficient result space to convert a float value to varchar/nvarchar."))); + } + } + + res = DirectFunctionCall3(varcharin, + CStringGetDatum(ascii), + ObjectIdGetDatum(0), + Int32GetDatum(typmod)); + + PG_RETURN_DATUM(res); + +} + +Datum +float82bpchar(PG_FUNCTION_ARGS) +{ + float8 num = PG_GETARG_FLOAT8(0); + int32 typmod = PG_GETARG_INT32(1); + /* When No Typmod is defined Default Length is 30 */ + int maxlen = (typmod == -1) ? 30 : (typmod - VARHDRSZ); + Datum res; + /* 32 length as double_to_shortest_decimal_buf always returns string with length less that 30*/ + char *ascii = (char *) palloc0(32); + char *buf_padded; + int str_len = -1; + + /* Handle special cases */ + if (unlikely(isinf(num)|| isnan(num))) + { + ereport(ERROR, + (errcode(ERRCODE_DATA_EXCEPTION), + errmsg("Error Converting Float Value to String."))); + } + else + { + num = round(num * 1000000.0) / 1000000.0; + } + + double_to_shortest_decimal_buf(num, ascii); + + /* Check if the number fits within the specified length */ + if (maxlen > 0) + { + str_len = strlen(ascii); + if (str_len > maxlen) + { + ereport(ERROR, + (errcode(ERRCODE_STRING_DATA_RIGHT_TRUNCATION), + errmsg("There is insufficient result space to convert a float value to char/nchar."))); + } + } + + /* Left pad float value with the spaces */ + buf_padded = (char *) palloc0(maxlen + 1); + memset(buf_padded, ' ', maxlen - str_len); + memcpy(buf_padded + maxlen - str_len, ascii, str_len); + + res = DirectFunctionCall3(bpcharin, + CStringGetDatum(buf_padded), + ObjectIdGetDatum(0), + Int32GetDatum(typmod)); + + PG_RETURN_DATUM(res); + +} + /***************************************************************************** * bpchar - char() * *****************************************************************************/ diff --git a/contrib/babelfishpg_tsql/sql/sys_function_helpers.sql b/contrib/babelfishpg_tsql/sql/sys_function_helpers.sql index 7ede7974fe..e87cbc868d 100644 --- a/contrib/babelfishpg_tsql/sql/sys_function_helpers.sql +++ b/contrib/babelfishpg_tsql/sql/sys_function_helpers.sql @@ -10975,13 +10975,15 @@ BEGIN END IF; IF (v_floatval >= 999999.5) THEN v_format := '9D99999EEEE'; - v_result := to_char(v_sign * ceiling(v_floatval), v_format); + v_result := to_char(v_sign::NUMERIC * ceiling(v_floatval), v_format); v_result := to_char(substring(v_result, 1, 8)::NUMERIC, 'FM9D99999')::NUMERIC::TEXT || substring(v_result, 9); ELSE - if (6 - v_integral_digits < v_decimal_digits) THEN - v_decimal_digits := 6 - v_integral_digits; - END IF; - v_format := (pow(10, v_integral_digits)-1)::TEXT || 'D'; + IF (6 - v_integral_digits < v_decimal_digits) AND (trunc(abs(v_floatval)) != 0) THEN + v_decimal_digits := 6 - v_integral_digits; + ELSIF (6 - v_integral_digits < v_decimal_digits) THEN + v_decimal_digits := 6; + END IF; + v_format := (pow(10, v_integral_digits)-10)::TEXT || 'D'; IF (v_decimal_digits > 0) THEN v_format := v_format || (pow(10, v_decimal_digits)-1)::TEXT; END IF; diff --git a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--5.0.0--5.1.0.sql b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--5.0.0--5.1.0.sql index 626a131906..0fd7d0c289 100644 --- a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--5.0.0--5.1.0.sql +++ b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--5.0.0--5.1.0.sql @@ -5486,6 +5486,79 @@ BEGIN END; $$; +CREATE OR REPLACE FUNCTION sys.babelfish_try_conv_float_to_string(IN p_datatype TEXT, + IN p_floatval FLOAT, + IN p_style NUMERIC DEFAULT 0) +RETURNS TEXT +AS +$BODY$ +DECLARE + v_style SMALLINT; + v_format VARCHAR COLLATE "C"; + v_floatval NUMERIC := abs(p_floatval); + v_digits SMALLINT; + v_integral_digits SMALLINT; + v_decimal_digits SMALLINT; + v_sign SMALLINT := sign(p_floatval); + v_result TEXT; + v_res_length SMALLINT; + MASK_REGEXP CONSTANT VARCHAR COLLATE "C" := '^\s*(?:character varying)\s*\(\s*(\d+|MAX)\s*\)\s*$'; +BEGIN + v_style := floor(p_style)::SMALLINT; + IF (v_style = 0) THEN + v_digits := length(v_floatval::NUMERIC::TEXT); + v_decimal_digits := scale(v_floatval); + IF (v_decimal_digits > 0) THEN + v_integral_digits := v_digits - v_decimal_digits - 1; + ELSE + v_integral_digits := v_digits; + END IF; + IF (v_floatval >= 999999.5) THEN + v_format := '9D99999EEEE'; + v_result := to_char(v_sign::NUMERIC * ceiling(v_floatval), v_format); + v_result := to_char(substring(v_result, 1, 8)::NUMERIC, 'FM9D99999')::NUMERIC::TEXT || substring(v_result, 9); + ELSE + IF (6 - v_integral_digits < v_decimal_digits) AND (trunc(abs(v_floatval)) != 0) THEN + v_decimal_digits := 6 - v_integral_digits; + ELSIF (6 - v_integral_digits < v_decimal_digits) THEN + v_decimal_digits := 6; + END IF; + v_format := (pow(10, v_integral_digits)-10)::TEXT || 'D'; + IF (v_decimal_digits > 0) THEN + v_format := v_format || (pow(10, v_decimal_digits)-1)::TEXT; + END IF; + v_result := to_char(p_floatval, v_format); + END IF; + ELSIF (v_style = 1) THEN + v_format := '9D9999999EEEE'; + v_result := to_char(p_floatval, v_format); + ELSIF (v_style = 2) THEN + v_format := '9D999999999999999EEEE'; + v_result := to_char(p_floatval, v_format); + ELSIF (v_style = 3) THEN + v_format := '9D9999999999999999EEEE'; + v_result := to_char(p_floatval, v_format); + ELSE + RAISE invalid_parameter_value; + END IF; + + v_res_length := substring(p_datatype COLLATE "C", MASK_REGEXP)::SMALLINT; + IF v_res_length IS NULL THEN + RETURN v_result; + ELSE + RETURN rpad(v_result, v_res_length, ' '); + END IF; +EXCEPTION + WHEN invalid_parameter_value THEN + RAISE USING MESSAGE := pg_catalog.format('%s is not a valid style number when converting from FLOAT to a character string.', v_style), + DETAIL := 'Use of incorrect "style" parameter value during conversion process.', + HINT := 'Change "style" parameter to the proper value and try again.'; +END; +$BODY$ +LANGUAGE plpgsql +STABLE +RETURNS NULL ON NULL INPUT; + -- 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); diff --git a/contrib/babelfishpg_tsql/src/pltsql_coerce.c b/contrib/babelfishpg_tsql/src/pltsql_coerce.c index e01e4dc2d3..e79183e978 100644 --- a/contrib/babelfishpg_tsql/src/pltsql_coerce.c +++ b/contrib/babelfishpg_tsql/src/pltsql_coerce.c @@ -300,10 +300,6 @@ tsql_cast_raw_info_t tsql_cast_raw_infos[] = {TSQL_CAST_WITHOUT_FUNC_ENTRY, "pg_catalog", "float4", "sys", "varchar", NULL, 'i', 'i'}, /* float8 -> string via I/O */ {TSQL_CAST_WITHOUT_FUNC_ENTRY, "pg_catalog", "float8", "pg_catalog", "text", NULL, 'i', 'i'}, - {TSQL_CAST_WITHOUT_FUNC_ENTRY, "pg_catalog", "float8", "pg_catalog", "bpchar", NULL, 'i', 'i'}, - {TSQL_CAST_WITHOUT_FUNC_ENTRY, "pg_catalog", "float8", "sys", "bpchar", NULL, 'i', 'i'}, - {TSQL_CAST_WITHOUT_FUNC_ENTRY, "pg_catalog", "float8", "pg_catalog", "varchar", NULL, 'i', 'i'}, - {TSQL_CAST_WITHOUT_FUNC_ENTRY, "pg_catalog", "float8", "sys", "varchar", NULL, 'i', 'i'}, /* numeric -> string via I/O */ {TSQL_CAST_WITHOUT_FUNC_ENTRY, "pg_catalog", "numeric", "pg_catalog", "text", NULL, 'i', 'i'}, {TSQL_CAST_WITHOUT_FUNC_ENTRY, "pg_catalog", "numeric", "pg_catalog", "bpchar", NULL, 'i', 'i'}, diff --git a/test/JDBC/expected/BABEL-1193.out b/test/JDBC/expected/BABEL-1193.out index 5f992ada80..a81750592a 100644 --- a/test/JDBC/expected/BABEL-1193.out +++ b/test/JDBC/expected/BABEL-1193.out @@ -237,9 +237,9 @@ SELECT * FROM t15; GO ~~START~~ char#!#char#!#char#!#char#!#char#!#char#!#char#!#char -12 #!#4553 #!#123456 #!#12.345 #!#2344.456 #!#12.34 #!# 456.33#!# 1123.68 --12 #!#-1234 #!#-123456 #!#-12.345 #!#-2344.456 #!#12.34 #!# -456.33#!# -1123.68 -0 #!#0 #!#0 #!#0 #!#0 #!#0.00 #!# 0.00#!# 0.00 +12 #!#4553 #!#123456 #!#12.345 #!# 2344.456#!#12.34 #!# 456.33#!# 1123.68 +-12 #!#-1234 #!#-123456 #!#-12.345 #!# -2344.456#!#12.34 #!# -456.33#!# -1123.68 +0 #!#0 #!#0 #!#0 #!# 0#!#0.00 #!# 0.00#!# 0.00 ~~END~~ diff --git a/test/JDBC/expected/BABEL-889-vu-verify.out b/test/JDBC/expected/BABEL-889-vu-verify.out index 56422dd062..071565cbc7 100644 --- a/test/JDBC/expected/BABEL-889-vu-verify.out +++ b/test/JDBC/expected/BABEL-889-vu-verify.out @@ -86,7 +86,7 @@ select cast(cast(cast('3.1415926' as float) as sql_variant) as varchar); go ~~START~~ varchar -3.1415926 +3.141593 ~~END~~ -- real diff --git a/test/JDBC/expected/BABEL-889.out b/test/JDBC/expected/BABEL-889.out index 56422dd062..071565cbc7 100644 --- a/test/JDBC/expected/BABEL-889.out +++ b/test/JDBC/expected/BABEL-889.out @@ -86,7 +86,7 @@ select cast(cast(cast('3.1415926' as float) as sql_variant) as varchar); go ~~START~~ varchar -3.1415926 +3.141593 ~~END~~ -- real diff --git a/test/JDBC/expected/babel_function.out b/test/JDBC/expected/babel_function.out index be2ced538e..0d2e6398ee 100644 --- a/test/JDBC/expected/babel_function.out +++ b/test/JDBC/expected/babel_function.out @@ -297,7 +297,7 @@ select TRY_CONVERT(varchar(30), CAST('11234561231231.234' AS float), 0); GO ~~START~~ varchar - +1.12346e+13 ~~END~~ select TRY_CONVERT(varchar(30), CAST('11234561231231.234'AS float), 1); diff --git a/test/JDBC/expected/non_default_server_collation/chinese_prc_ci_as/BABEL-889-vu-verify.out b/test/JDBC/expected/non_default_server_collation/chinese_prc_ci_as/BABEL-889-vu-verify.out index 99fe97cd61..3710c45261 100644 --- a/test/JDBC/expected/non_default_server_collation/chinese_prc_ci_as/BABEL-889-vu-verify.out +++ b/test/JDBC/expected/non_default_server_collation/chinese_prc_ci_as/BABEL-889-vu-verify.out @@ -86,7 +86,7 @@ select cast(cast(cast('3.1415926' as float) as sql_variant) as varchar); go ~~START~~ varchar -3.1415926 +3.141593 ~~END~~ -- real diff --git a/test/JDBC/expected/non_default_server_collation/chinese_prc_ci_as/BABEL-889.out b/test/JDBC/expected/non_default_server_collation/chinese_prc_ci_as/BABEL-889.out index 99fe97cd61..3710c45261 100644 --- a/test/JDBC/expected/non_default_server_collation/chinese_prc_ci_as/BABEL-889.out +++ b/test/JDBC/expected/non_default_server_collation/chinese_prc_ci_as/BABEL-889.out @@ -86,7 +86,7 @@ select cast(cast(cast('3.1415926' as float) as sql_variant) as varchar); go ~~START~~ varchar -3.1415926 +3.141593 ~~END~~ -- real diff --git a/test/JDBC/expected/non_default_server_collation/chinese_prc_ci_as/babel_function.out b/test/JDBC/expected/non_default_server_collation/chinese_prc_ci_as/babel_function.out index 285db065e5..cd3b7fd394 100644 --- a/test/JDBC/expected/non_default_server_collation/chinese_prc_ci_as/babel_function.out +++ b/test/JDBC/expected/non_default_server_collation/chinese_prc_ci_as/babel_function.out @@ -297,7 +297,7 @@ select TRY_CONVERT(varchar(30), CAST('11234561231231.234' AS float), 0); GO ~~START~~ varchar - +1.12346e+13 ~~END~~ select TRY_CONVERT(varchar(30), CAST('11234561231231.234'AS float), 1); diff --git a/test/JDBC/expected/non_default_server_collation/japanese_ci_as/BABEL-889-vu-verify.out b/test/JDBC/expected/non_default_server_collation/japanese_ci_as/BABEL-889-vu-verify.out index 8f5a82e081..5306cd1def 100644 --- a/test/JDBC/expected/non_default_server_collation/japanese_ci_as/BABEL-889-vu-verify.out +++ b/test/JDBC/expected/non_default_server_collation/japanese_ci_as/BABEL-889-vu-verify.out @@ -86,7 +86,7 @@ select cast(cast(cast('3.1415926' as float) as sql_variant) as varchar); go ~~START~~ varchar -3.1415926 +3.141593 ~~END~~ -- real diff --git a/test/JDBC/expected/non_default_server_collation/japanese_ci_as/BABEL-889.out b/test/JDBC/expected/non_default_server_collation/japanese_ci_as/BABEL-889.out index 8f5a82e081..5306cd1def 100644 --- a/test/JDBC/expected/non_default_server_collation/japanese_ci_as/BABEL-889.out +++ b/test/JDBC/expected/non_default_server_collation/japanese_ci_as/BABEL-889.out @@ -86,7 +86,7 @@ select cast(cast(cast('3.1415926' as float) as sql_variant) as varchar); go ~~START~~ varchar -3.1415926 +3.141593 ~~END~~ -- real diff --git a/test/JDBC/expected/test_conv_float_to_varchar_char-vu-cleanup.out b/test/JDBC/expected/test_conv_float_to_varchar_char-vu-cleanup.out new file mode 100644 index 0000000000..64c951e702 --- /dev/null +++ b/test/JDBC/expected/test_conv_float_to_varchar_char-vu-cleanup.out @@ -0,0 +1,17 @@ +DROP TABLE TestResults +DROP VIEW float_char_v1; +DROP VIEW float_char_v2; +DROP FUNCTION float_char_f1; +DROP FUNCTION float_char_f2; +DROP PROCEDURE float_char_p1; +DROP TABLE float_char_t1; +DROP TABLE float_char_t2; +DROP TABLE TestResults_1 +DROP VIEW float_varchar_v1; +DROP VIEW float_varchar_v2; +DROP FUNCTION float_varchar_f1; +DROP FUNCTION float_varchar_f2; +DROP PROCEDURE float_varchar_p1; +DROP TABLE float_varchar_t1; +DROP TABLE float_varchar_t2; +GO diff --git a/test/JDBC/expected/test_conv_float_to_varchar_char-vu-prepare.out b/test/JDBC/expected/test_conv_float_to_varchar_char-vu-prepare.out new file mode 100644 index 0000000000..8e40cb6e59 --- /dev/null +++ b/test/JDBC/expected/test_conv_float_to_varchar_char-vu-prepare.out @@ -0,0 +1,182 @@ +CREATE TABLE float_char_t1 ( + ID INT IDENTITY(1,1), + FloatValue FLOAT, + Description VARCHAR(100) +); +GO +-- Create dependent objects for testing +-- 1. View that uses CAST +CREATE VIEW float_char_v1 +AS +SELECT + CAST(CAST('-123.456325678543' AS FLOAT) AS CHAR(30)) AS CastValue, + CAST(CAST('-123.456325678543' AS FLOAT(53)) AS CHAR(30)) AS CastValue2 +GO + +-- 2. View that uses CONVERT +CREATE VIEW float_char_v2 +AS +SELECT + CONVERT(CHAR(30), CAST('-123.456325678543' as FLOAT)) AS ConvertValue, + CONVERT(CHAR(30), CAST('-123.456325678543' as FLOAT(53))) AS ConvertValue2 +GO + +-- 3. Function using CAST +CREATE FUNCTION float_char_f1 +( + @FloatInput FLOAT +) +RETURNS VARCHAR(30) +AS +BEGIN + RETURN CAST(@FloatInput AS CHAR(30)) +END; +GO + +-- 4. Function using CONVERT +CREATE FUNCTION float_char_f2 +( + @FloatInput FLOAT +) +RETURNS VARCHAR(30) +AS +BEGIN + RETURN CONVERT(CHAR(30), @FloatInput) +END; +GO + +CREATE PROCEDURE float_char_p1 + @FloatInput FLOAT +AS +BEGIN + SELECT + CAST(@FloatInput AS CHAR(30)) AS CastResult, + CONVERT(CHAR(30), @FloatInput) AS ConvertResult +END; +GO + +-- Insert test data +INSERT INTO float_char_t1 (FloatValue, Description) VALUES + (123.456, 'Standard positive decimal'), + (-123.456, 'Negative decimal'), + (0.0, 'Zero value'), + (1E10, 'Scientific notation - large'), + (1E-10, 'Scientific notation - small'), + (9999999999.99, 'Large decimal'), + (0.000000001, 'Very small decimal'), + (NULL, 'NULL Value') +GO +~~ROW COUNT: 8~~ + + + +CREATE TABLE TestResults ( + TestID INT IDENTITY(1,1), + TestCategory VARCHAR(50), + TestName VARCHAR(100), + TestScenario VARCHAR(200), + ExpectedResult VARCHAR(50), + ActualResult VARCHAR(50), + TestStatus VARCHAR(20) +); +GO + + +CREATE TABLE float_varchar_t1 ( + ID INT IDENTITY(1,1), + FloatValue FLOAT, + Description VARCHAR(100) +); +GO +-- Create dependent objects for testing +-- 1. View that uses CAST +CREATE VIEW float_varchar_v1 +AS +SELECT + CAST(CAST('-123.456325678543' AS FLOAT) AS VARCHAR(30)) AS CastValue, + CAST(CAST('-123.456325678543' AS FLOAT(53)) AS VARCHAR(30)) AS CastValue2 +GO + +-- 2. View that uses CONVERT +CREATE VIEW float_varchar_v2 +AS +SELECT + CONVERT(VARCHAR(30), CAST('-123.456325678543' as FLOAT)) AS ConvertValue, + CONVERT(VARCHAR(30), CAST('-123.456325678543' as FLOAT(53))) AS ConvertValue2 +GO + +-- 3. Function using CAST +CREATE FUNCTION float_varchar_f1 +( + @FloatInput FLOAT +) +RETURNS VARCHAR(30) +AS +BEGIN + RETURN CAST(@FloatInput AS VARCHAR(30)) +END; +GO + +-- 4. Function using CONVERT +CREATE FUNCTION float_varchar_f2 +( + @FloatInput FLOAT +) +RETURNS VARCHAR(30) +AS +BEGIN + RETURN CONVERT(VARCHAR(30), @FloatInput) +END; +GO + +CREATE PROCEDURE float_varchar_p1 + @FloatInput FLOAT +AS +BEGIN + SELECT + CAST(@FloatInput AS VARCHAR(30)) AS CastResult, + CONVERT(VARCHAR(30), @FloatInput) AS ConvertResult +END; +GO + +-- Insert test data +INSERT INTO float_varchar_t1 (FloatValue, Description) VALUES + (123.456, 'Standard positive decimal'), + (-123.456, 'Negative decimal'), + (0.0, 'Zero value'), + (1E10, 'Scientific notation - large'), + (1E-10, 'Scientific notation - small'), + (9999999999.99, 'Large decimal'), + (0.000000001, 'Very small decimal'), + (NULL, 'NULL Value') +GO +~~ROW COUNT: 8~~ + + + +CREATE TABLE TestResults_1 ( + TestID INT IDENTITY(1,1), + TestCategory VARCHAR(50), + TestName VARCHAR(100), + TestScenario VARCHAR(200), + ExpectedResult VARCHAR(50), + ActualResult VARCHAR(50), + TestStatus VARCHAR(20) +); +GO + +CREATE TABLE float_char_t2 +( + a char(30), + check (cast(a as float) > 0) +) +GO + +CREATE TABLE float_varchar_t2 +( + a varchar(30), + check (cast(a as float) > 0) +) +GO + + diff --git a/test/JDBC/expected/test_conv_float_to_varchar_char-vu-verify.out b/test/JDBC/expected/test_conv_float_to_varchar_char-vu-verify.out new file mode 100644 index 0000000000..fbcc3fa121 --- /dev/null +++ b/test/JDBC/expected/test_conv_float_to_varchar_char-vu-verify.out @@ -0,0 +1,346 @@ + + + + + + +-- TEST FOR CHAR +DECLARE @TestCases TABLE ( + FloatValue FLOAT, + ScenarioDescription VARCHAR(200) +); +INSERT INTO @TestCases +SELECT FloatValue, Description FROM float_char_t1; +-- 1. Test Direct CAST/CONVERT +INSERT INTO TestResults (TestCategory, TestName, TestScenario, ExpectedResult, ActualResult) +SELECT + 'Direct Conversion', + 'CAST vs CONVERT', + tc.ScenarioDescription, + CAST(tc.FloatValue AS CHAR(30)), + CONVERT(CHAR(30), tc.FloatValue) +FROM @TestCases tc; +-- Display Results by Category +SELECT + TestCategory, + TestName, + TestScenario, + ExpectedResult, + ActualResult, + TestStatus +FROM TestResults +ORDER BY TestCategory, TestID; +-- Test Stored Procedure Execution +DECLARE @FloatValue FLOAT; +DECLARE cur CURSOR FOR SELECT FloatValue FROM @TestCases; +OPEN cur; +FETCH NEXT FROM cur INTO @FloatValue; +WHILE @@FETCH_STATUS = 0 +BEGIN + EXEC float_char_p1 @FloatValue; + FETCH NEXT FROM cur INTO @FloatValue; +END +CLOSE cur; +DEALLOCATE cur; +GO +~~ROW COUNT: 8~~ + +~~ROW COUNT: 8~~ + +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar#!#varchar +Direct Conversion#!#CAST vs CONVERT#!#Standard positive decimal#!# 123.456#!# 123.456 #!# +Direct Conversion#!#CAST vs CONVERT#!#Negative decimal#!# -123.456#!#-123.456 #!# +Direct Conversion#!#CAST vs CONVERT#!#Zero value#!# 0#!# 0 #!# +Direct Conversion#!#CAST vs CONVERT#!#Scientific notation - large#!# 10000000000#!#1e+10 #!# +Direct Conversion#!#CAST vs CONVERT#!#Scientific notation - small#!# 0#!# 0.000000 #!# +Direct Conversion#!#CAST vs CONVERT#!#Large decimal#!# 9999999999.99#!#1e+10 #!# +Direct Conversion#!#CAST vs CONVERT#!#Very small decimal#!# 0#!# 0.000000 #!# +Direct Conversion#!#CAST vs CONVERT#!#NULL Value#!##!##!# +~~END~~ + +~~START~~ +char#!#char + 123.456#!# 123.456 +~~END~~ + +~~START~~ +char#!#char + -123.456#!#-123.456 +~~END~~ + +~~START~~ +char#!#char + 0#!# 0 +~~END~~ + +~~START~~ +char#!#char + 10000000000#!#1e+10 +~~END~~ + +~~START~~ +char#!#char + 0#!# 0.000000 +~~END~~ + +~~START~~ +char#!#char + 9999999999.99#!#1e+10 +~~END~~ + +~~START~~ +char#!#char + 0#!# 0.000000 +~~END~~ + +~~START~~ +char#!#char +#!# +~~END~~ + + +-- 2. Test Views +SELECT * FROM float_char_v1; +SELECT * FROM float_char_v2; +GO +~~START~~ +char#!#char + -123.456326#!# -123.456326 +~~END~~ + +~~START~~ +char#!#char +-123.456 #!#-123.456 +~~END~~ + + +-- 3. Test Functions +SELECT float_char_f1('123.4567') +SELECT float_char_f2('123.4567') +GO +~~START~~ +varchar + 123.4567 +~~END~~ + +~~START~~ +varchar + 123.457 +~~END~~ + + + + + + + + + +-- TEST FOR VARCHAR +DECLARE @TestCases TABLE ( + FloatValue FLOAT, + ScenarioDescription VARCHAR(200) +); +INSERT INTO @TestCases +SELECT FloatValue, Description FROM float_varchar_t1; +-- 1. Test Direct CAST/CONVERT +INSERT INTO TestResults_1 (TestCategory, TestName, TestScenario, ExpectedResult, ActualResult) +SELECT + 'Direct Conversion', + 'CAST vs CONVERT', + tc.ScenarioDescription, + CAST(tc.FloatValue AS VARCHAR(30)), + CONVERT(VARCHAR(30), tc.FloatValue) +FROM @TestCases tc; +-- Display Results by Category +SELECT + TestCategory, + TestName, + TestScenario, + ExpectedResult, + ActualResult, + TestStatus +FROM TestResults_1 +ORDER BY TestCategory, TestID; +-- Test Stored Procedure Execution +DECLARE @FloatValue FLOAT; +DECLARE cur CURSOR FOR SELECT FloatValue FROM @TestCases; +OPEN cur; +FETCH NEXT FROM cur INTO @FloatValue; +WHILE @@FETCH_STATUS = 0 +BEGIN + EXEC float_varchar_p1 @FloatValue; + FETCH NEXT FROM cur INTO @FloatValue; +END +CLOSE cur; +DEALLOCATE cur; +GO +~~ROW COUNT: 8~~ + +~~ROW COUNT: 8~~ + +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar#!#varchar +Direct Conversion#!#CAST vs CONVERT#!#Standard positive decimal#!#123.456#!# 123.456 #!# +Direct Conversion#!#CAST vs CONVERT#!#Negative decimal#!#-123.456#!#-123.456 #!# +Direct Conversion#!#CAST vs CONVERT#!#Zero value#!#0#!# 0 #!# +Direct Conversion#!#CAST vs CONVERT#!#Scientific notation - large#!#10000000000#!#1e+10 #!# +Direct Conversion#!#CAST vs CONVERT#!#Scientific notation - small#!#0#!# 0.000000 #!# +Direct Conversion#!#CAST vs CONVERT#!#Large decimal#!#9999999999.99#!#1e+10 #!# +Direct Conversion#!#CAST vs CONVERT#!#Very small decimal#!#0#!# 0.000000 #!# +Direct Conversion#!#CAST vs CONVERT#!#NULL Value#!##!##!# +~~END~~ + +~~START~~ +varchar#!#varchar +123.456#!# 123.456 +~~END~~ + +~~START~~ +varchar#!#varchar +-123.456#!#-123.456 +~~END~~ + +~~START~~ +varchar#!#varchar +0#!# 0 +~~END~~ + +~~START~~ +varchar#!#varchar +10000000000#!#1e+10 +~~END~~ + +~~START~~ +varchar#!#varchar +0#!# 0.000000 +~~END~~ + +~~START~~ +varchar#!#varchar +9999999999.99#!#1e+10 +~~END~~ + +~~START~~ +varchar#!#varchar +0#!# 0.000000 +~~END~~ + +~~START~~ +varchar#!#varchar +#!# +~~END~~ + + + +-- 2. Test Views +SELECT * FROM float_varchar_v1; +SELECT * FROM float_varchar_v2; +GO +~~START~~ +varchar#!#varchar +-123.456326#!#-123.456326 +~~END~~ + +~~START~~ +varchar#!#varchar +-123.456 #!#-123.456 +~~END~~ + + +-- 3. Test Functions +SELECT float_varchar_f1('123.4567') +SELECT float_varchar_f2('123.4567') +GO +~~START~~ +varchar +123.4567 +~~END~~ + +~~START~~ +varchar + 123.457 +~~END~~ + + +-- 4. Test Convert/CAST in WHERE +SELECT COUNT(*) FROM float_varchar_t1 where length(CAST(FloatValue as VARCHAR)) < 8; +GO +~~START~~ +int +4 +~~END~~ + +SELECT COUNT(*) FROM float_varchar_t1 WHERE length(CONVERT(VARCHAR(30),FloatValue)) = 30; +GO +~~START~~ +int +7 +~~END~~ + + +-- 5. Test Insuffiecient String Length +SELECT CAST(CAST('214555.32435254' AS FLOAT) AS VARCHAR(5)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: There is insufficient result space to convert a float value to varchar/nvarchar.)~~ + +SELECT CAST(CAST('214555.32435254' AS FLOAT) AS CHAR(5)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: There is insufficient result space to convert a float value to char/nchar.)~~ + + +-- 6. Test Special Values +SELECT CAST(CAST('NaN' as Float) as VARCHAR(30)) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Error Converting Float Value to String.)~~ + +SELECT CAST(CAST('NaN' as Float) as CHAR(30)) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Error Converting Float Value to String.)~~ + +SELECT CAST(CAST('Inf' as Float) as VARCHAR) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Error Converting Float Value to String.)~~ + +SELECT CAST(CAST('Inf' as Float) as CHAR) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Error Converting Float Value to String.)~~ + + +-- 7. Test Constraints +INSERT INTO float_char_t2 VALUES('-1.245243') +GO +~~ERROR (Code: 547)~~ + +~~ERROR (Message: new row for relation "float_char_t2" violates check constraint "float_char_t2_a_check")~~ + +INSERT INTO float_varchar_t2 VALUES('-1.245243') +GO +~~ERROR (Code: 547)~~ + +~~ERROR (Message: new row for relation "float_varchar_t2" violates check constraint "float_varchar_t2_a_check")~~ + + +-- 8. Test With Variables +DECLARE @flt1 Float = 1.3242335 +DECLARE @flt2 Float = -54235.4322 +SELECT cast(@flt1*@flt2 as varchar(30)),cast(@flt1/@flt2 as varchar(30)),cast(@flt1+@flt2 as char(30)),cast(@flt1/@flt2 as char(30)) +GO +~~START~~ +varchar#!#varchar#!#char#!#char +-71820.376206#!#-2.4e-05#!# -54234.107967#!# -2.4e-05 +~~END~~ + diff --git a/test/JDBC/expected/test_conv_float_to_varchar_char_before_17_3-vu-cleanup.out b/test/JDBC/expected/test_conv_float_to_varchar_char_before_17_3-vu-cleanup.out new file mode 100644 index 0000000000..64c951e702 --- /dev/null +++ b/test/JDBC/expected/test_conv_float_to_varchar_char_before_17_3-vu-cleanup.out @@ -0,0 +1,17 @@ +DROP TABLE TestResults +DROP VIEW float_char_v1; +DROP VIEW float_char_v2; +DROP FUNCTION float_char_f1; +DROP FUNCTION float_char_f2; +DROP PROCEDURE float_char_p1; +DROP TABLE float_char_t1; +DROP TABLE float_char_t2; +DROP TABLE TestResults_1 +DROP VIEW float_varchar_v1; +DROP VIEW float_varchar_v2; +DROP FUNCTION float_varchar_f1; +DROP FUNCTION float_varchar_f2; +DROP PROCEDURE float_varchar_p1; +DROP TABLE float_varchar_t1; +DROP TABLE float_varchar_t2; +GO diff --git a/test/JDBC/expected/test_conv_float_to_varchar_char_before_17_3-vu-prepare.out b/test/JDBC/expected/test_conv_float_to_varchar_char_before_17_3-vu-prepare.out new file mode 100644 index 0000000000..cdf0d43521 --- /dev/null +++ b/test/JDBC/expected/test_conv_float_to_varchar_char_before_17_3-vu-prepare.out @@ -0,0 +1,182 @@ +CREATE TABLE float_char_t1 ( + ID INT IDENTITY(1,1), + FloatValue FLOAT, + Description VARCHAR(100) +); +GO +-- Create dependent objects for testing +-- 1. View that uses CAST +CREATE VIEW float_char_v1 +AS +SELECT + CAST(CAST('-123.456325678543' AS FLOAT) AS CHAR(30)) AS CastValue, + CAST(CAST('-123.456325678543' AS FLOAT(53)) AS CHAR(30)) AS CastValue2 +GO + +-- 2. View that uses CONVERT +CREATE VIEW float_char_v2 +AS +SELECT + CONVERT(CHAR(30), CAST('-123.456' as FLOAT)) AS ConvertValue, + CONVERT(CHAR(30), CAST('-123.456' as FLOAT(53))) AS ConvertValue2 +GO + +-- 3. Function using CAST +CREATE FUNCTION float_char_f1 +( + @FloatInput FLOAT +) +RETURNS VARCHAR(30) +AS +BEGIN + RETURN CAST(@FloatInput AS CHAR(30)) +END; +GO + +-- 4. Function using CONVERT +CREATE FUNCTION float_char_f2 +( + @FloatInput FLOAT +) +RETURNS VARCHAR(30) +AS +BEGIN + RETURN CONVERT(CHAR(30), @FloatInput) +END; +GO + +CREATE PROCEDURE float_char_p1 + @FloatInput FLOAT +AS +BEGIN + SELECT + CAST(@FloatInput AS CHAR(30)) AS CastResult, + CONVERT(CHAR(30), @FloatInput) AS ConvertResult +END; +GO + +-- Insert test data +INSERT INTO float_char_t1 (FloatValue, Description) VALUES + (123.456, 'Standard positive decimal'), + (-123.456, 'Negative decimal'), + (0.0, 'Zero value'), + (1E10, 'Scientific notation - large'), + (1E-10, 'Scientific notation - small'), + (9999999999.99, 'Large decimal'), + (0.000000001, 'Very small decimal'), + (NULL, 'NULL Value') +GO +~~ROW COUNT: 8~~ + + + +CREATE TABLE TestResults ( + TestID INT IDENTITY(1,1), + TestCategory VARCHAR(50), + TestName VARCHAR(100), + TestScenario VARCHAR(200), + ExpectedResult VARCHAR(50), + ActualResult VARCHAR(50), + TestStatus VARCHAR(20) +); +GO + + +CREATE TABLE float_varchar_t1 ( + ID INT IDENTITY(1,1), + FloatValue FLOAT, + Description VARCHAR(100) +); +GO +-- Create dependent objects for testing +-- 1. View that uses CAST +CREATE VIEW float_varchar_v1 +AS +SELECT + CAST(CAST('-123.456325678543' AS FLOAT) AS VARCHAR(30)) AS CastValue, + CAST(CAST('-123.456325678543' AS FLOAT(53)) AS VARCHAR(30)) AS CastValue2 +GO + +-- 2. View that uses CONVERT +CREATE VIEW float_varchar_v2 +AS +SELECT + CONVERT(VARCHAR(30), CAST('-123.456325678543' as FLOAT)) AS ConvertValue, + CONVERT(VARCHAR(30), CAST('-123.456325678543' as FLOAT(53))) AS ConvertValue2 +GO + +-- 3. Function using CAST +CREATE FUNCTION float_varchar_f1 +( + @FloatInput FLOAT +) +RETURNS VARCHAR(30) +AS +BEGIN + RETURN CAST(@FloatInput AS VARCHAR(30)) +END; +GO + +-- 4. Function using CONVERT +CREATE FUNCTION float_varchar_f2 +( + @FloatInput FLOAT +) +RETURNS VARCHAR(30) +AS +BEGIN + RETURN CONVERT(VARCHAR(30), @FloatInput) +END; +GO + +CREATE PROCEDURE float_varchar_p1 + @FloatInput FLOAT +AS +BEGIN + SELECT + CAST(@FloatInput AS VARCHAR(30)) AS CastResult, + CONVERT(VARCHAR(30), @FloatInput) AS ConvertResult +END; +GO + +-- Insert test data +INSERT INTO float_varchar_t1 (FloatValue, Description) VALUES + (123.456, 'Standard positive decimal'), + (-123.456, 'Negative decimal'), + (0.0, 'Zero value'), + (1E10, 'Scientific notation - large'), + (1E-10, 'Scientific notation - small'), + (9999999999.99, 'Large decimal'), + (0.000000001, 'Very small decimal'), + (NULL, 'NULL Value') +GO +~~ROW COUNT: 8~~ + + + +CREATE TABLE TestResults_1 ( + TestID INT IDENTITY(1,1), + TestCategory VARCHAR(50), + TestName VARCHAR(100), + TestScenario VARCHAR(200), + ExpectedResult VARCHAR(50), + ActualResult VARCHAR(50), + TestStatus VARCHAR(20) +); +GO + +CREATE TABLE float_char_t2 +( + a char(30), + check (cast(a as float) > 0) +) +GO + +CREATE TABLE float_varchar_t2 +( + a varchar(30), + check (cast(a as float) > 0) +) +GO + + diff --git a/test/JDBC/expected/test_conv_float_to_varchar_char_before_17_3-vu-verify.out b/test/JDBC/expected/test_conv_float_to_varchar_char_before_17_3-vu-verify.out new file mode 100644 index 0000000000..405727ae04 --- /dev/null +++ b/test/JDBC/expected/test_conv_float_to_varchar_char_before_17_3-vu-verify.out @@ -0,0 +1,346 @@ + + + + + + +-- TEST FOR CHAR +DECLARE @TestCases TABLE ( + FloatValue FLOAT, + ScenarioDescription VARCHAR(200) +); +INSERT INTO @TestCases +SELECT FloatValue, Description FROM float_char_t1; +-- 1. Test Direct CAST/CONVERT +INSERT INTO TestResults (TestCategory, TestName, TestScenario, ExpectedResult, ActualResult) +SELECT + 'Direct Conversion', + 'CAST vs CONVERT', + tc.ScenarioDescription, + CAST(tc.FloatValue AS CHAR(30)), + CONVERT(CHAR(30), tc.FloatValue) +FROM @TestCases tc; +-- Display Results by Category +SELECT + TestCategory, + TestName, + TestScenario, + ExpectedResult, + ActualResult, + TestStatus +FROM TestResults +ORDER BY TestCategory, TestID; +-- Test Stored Procedure Execution +DECLARE @FloatValue FLOAT; +DECLARE cur CURSOR FOR SELECT FloatValue FROM @TestCases; +OPEN cur; +FETCH NEXT FROM cur INTO @FloatValue; +WHILE @@FETCH_STATUS = 0 +BEGIN + EXEC float_char_p1 @FloatValue; + FETCH NEXT FROM cur INTO @FloatValue; +END +CLOSE cur; +DEALLOCATE cur; +GO +~~ROW COUNT: 8~~ + +~~ROW COUNT: 8~~ + +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar#!#varchar +Direct Conversion#!#CAST vs CONVERT#!#Standard positive decimal#!# 123.456#!# 123.456 #!# +Direct Conversion#!#CAST vs CONVERT#!#Negative decimal#!# -123.456#!#-123.456 #!# +Direct Conversion#!#CAST vs CONVERT#!#Zero value#!# 0#!# 0 #!# +Direct Conversion#!#CAST vs CONVERT#!#Scientific notation - large#!# 10000000000#!#1e+10 #!# +Direct Conversion#!#CAST vs CONVERT#!#Scientific notation - small#!# 0#!# 0.000000 #!# +Direct Conversion#!#CAST vs CONVERT#!#Large decimal#!# 9999999999.99#!#1e+10 #!# +Direct Conversion#!#CAST vs CONVERT#!#Very small decimal#!# 0#!# 0.000000 #!# +Direct Conversion#!#CAST vs CONVERT#!#NULL Value#!##!##!# +~~END~~ + +~~START~~ +char#!#char + 123.456#!# 123.456 +~~END~~ + +~~START~~ +char#!#char + -123.456#!#-123.456 +~~END~~ + +~~START~~ +char#!#char + 0#!# 0 +~~END~~ + +~~START~~ +char#!#char + 10000000000#!#1e+10 +~~END~~ + +~~START~~ +char#!#char + 0#!# 0.000000 +~~END~~ + +~~START~~ +char#!#char + 9999999999.99#!#1e+10 +~~END~~ + +~~START~~ +char#!#char + 0#!# 0.000000 +~~END~~ + +~~START~~ +char#!#char +#!# +~~END~~ + + +-- 2. Test Views +SELECT * FROM float_char_v1; +SELECT * FROM float_char_v2; +GO +~~START~~ +char#!#char +-123.456325678543 #!#-123.456325678543 +~~END~~ + +~~START~~ +char#!#char +-123.456 #!#-123.456 +~~END~~ + + +-- 3. Test Functions +SELECT float_char_f1('123.4567') +SELECT float_char_f2('123.4567') +GO +~~START~~ +varchar + 123.4567 +~~END~~ + +~~START~~ +varchar + 123.457 +~~END~~ + + + + + + + + + +-- TEST FOR VARCHAR +DECLARE @TestCases TABLE ( + FloatValue FLOAT, + ScenarioDescription VARCHAR(200) +); +INSERT INTO @TestCases +SELECT FloatValue, Description FROM float_varchar_t1; +-- 1. Test Direct CAST/CONVERT +INSERT INTO TestResults_1 (TestCategory, TestName, TestScenario, ExpectedResult, ActualResult) +SELECT + 'Direct Conversion', + 'CAST vs CONVERT', + tc.ScenarioDescription, + CAST(tc.FloatValue AS VARCHAR(30)), + CONVERT(VARCHAR(30), tc.FloatValue) +FROM @TestCases tc; +-- Display Results by Category +SELECT + TestCategory, + TestName, + TestScenario, + ExpectedResult, + ActualResult, + TestStatus +FROM TestResults_1 +ORDER BY TestCategory, TestID; +-- Test Stored Procedure Execution +DECLARE @FloatValue FLOAT; +DECLARE cur CURSOR FOR SELECT FloatValue FROM @TestCases; +OPEN cur; +FETCH NEXT FROM cur INTO @FloatValue; +WHILE @@FETCH_STATUS = 0 +BEGIN + EXEC float_varchar_p1 @FloatValue; + FETCH NEXT FROM cur INTO @FloatValue; +END +CLOSE cur; +DEALLOCATE cur; +GO +~~ROW COUNT: 8~~ + +~~ROW COUNT: 8~~ + +~~START~~ +varchar#!#varchar#!#varchar#!#varchar#!#varchar#!#varchar +Direct Conversion#!#CAST vs CONVERT#!#Standard positive decimal#!#123.456#!# 123.456 #!# +Direct Conversion#!#CAST vs CONVERT#!#Negative decimal#!#-123.456#!#-123.456 #!# +Direct Conversion#!#CAST vs CONVERT#!#Zero value#!#0#!# 0 #!# +Direct Conversion#!#CAST vs CONVERT#!#Scientific notation - large#!#10000000000#!#1e+10 #!# +Direct Conversion#!#CAST vs CONVERT#!#Scientific notation - small#!#0#!# 0.000000 #!# +Direct Conversion#!#CAST vs CONVERT#!#Large decimal#!#9999999999.99#!#1e+10 #!# +Direct Conversion#!#CAST vs CONVERT#!#Very small decimal#!#0#!# 0.000000 #!# +Direct Conversion#!#CAST vs CONVERT#!#NULL Value#!##!##!# +~~END~~ + +~~START~~ +varchar#!#varchar +123.456#!# 123.456 +~~END~~ + +~~START~~ +varchar#!#varchar +-123.456#!#-123.456 +~~END~~ + +~~START~~ +varchar#!#varchar +0#!# 0 +~~END~~ + +~~START~~ +varchar#!#varchar +10000000000#!#1e+10 +~~END~~ + +~~START~~ +varchar#!#varchar +0#!# 0.000000 +~~END~~ + +~~START~~ +varchar#!#varchar +9999999999.99#!#1e+10 +~~END~~ + +~~START~~ +varchar#!#varchar +0#!# 0.000000 +~~END~~ + +~~START~~ +varchar#!#varchar +#!# +~~END~~ + + + +-- 2. Test Views +SELECT * FROM float_varchar_v1; +SELECT * FROM float_varchar_v2; +GO +~~START~~ +varchar#!#varchar +-123.456325678543#!#-123.456325678543 +~~END~~ + +~~START~~ +varchar#!#varchar +-123.456 #!#-123.456 +~~END~~ + + +-- 3. Test Functions +SELECT float_varchar_f1('123.4567') +SELECT float_varchar_f2('123.4567') +GO +~~START~~ +varchar +123.4567 +~~END~~ + +~~START~~ +varchar + 123.457 +~~END~~ + + +-- 4. Test Convert/CAST in WHERE +SELECT COUNT(*) FROM float_varchar_t1 where length(CAST(FloatValue as VARCHAR)) < 8; +GO +~~START~~ +int +4 +~~END~~ + +SELECT COUNT(*) FROM float_varchar_t1 WHERE length(CONVERT(VARCHAR(30),FloatValue)) = 30; +GO +~~START~~ +int +7 +~~END~~ + + +-- 5. Test Insuffiecient String Length +SELECT CAST(CAST('214555.32435254' AS FLOAT) AS VARCHAR(5)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: There is insufficient result space to convert a float value to varchar/nvarchar.)~~ + +SELECT CAST(CAST('214555.32435254' AS FLOAT) AS CHAR(5)); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: There is insufficient result space to convert a float value to char/nchar.)~~ + + +-- 6. Test Special Values +SELECT CAST(CAST('NaN' as Float) as VARCHAR(30)) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Error Converting Float Value to String.)~~ + +SELECT CAST(CAST('NaN' as Float) as CHAR(30)) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Error Converting Float Value to String.)~~ + +SELECT CAST(CAST('Inf' as Float) as VARCHAR) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Error Converting Float Value to String.)~~ + +SELECT CAST(CAST('Inf' as Float) as CHAR) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Error Converting Float Value to String.)~~ + + +-- 7. Test Constraints +INSERT INTO float_char_t2 VALUES('-1.245243') +GO +~~ERROR (Code: 547)~~ + +~~ERROR (Message: new row for relation "float_char_t2" violates check constraint "float_char_t2_a_check")~~ + +INSERT INTO float_varchar_t2 VALUES('-1.245243') +GO +~~ERROR (Code: 547)~~ + +~~ERROR (Message: new row for relation "float_varchar_t2" violates check constraint "float_varchar_t2_a_check")~~ + + +-- 8. Test With Variables +DECLARE @flt1 Float = 1.3242335 +DECLARE @flt2 Float = -54235.4322 +SELECT cast(@flt1*@flt2 as varchar(30)),cast(@flt1/@flt2 as varchar(30)),cast(@flt1+@flt2 as char(30)),cast(@flt1/@flt2 as char(30)) +GO +~~START~~ +varchar#!#varchar#!#char#!#char +-71820.376206#!#-2.4e-05#!# -54234.107967#!# -2.4e-05 +~~END~~ + diff --git a/test/JDBC/input/functions/test_conv_float_to_varchar_char-vu-cleanup.sql b/test/JDBC/input/functions/test_conv_float_to_varchar_char-vu-cleanup.sql new file mode 100644 index 0000000000..b50bea2a66 --- /dev/null +++ b/test/JDBC/input/functions/test_conv_float_to_varchar_char-vu-cleanup.sql @@ -0,0 +1,17 @@ +DROP TABLE TestResults +DROP VIEW float_char_v1; +DROP VIEW float_char_v2; +DROP FUNCTION float_char_f1; +DROP FUNCTION float_char_f2; +DROP PROCEDURE float_char_p1; +DROP TABLE float_char_t1; +DROP TABLE float_char_t2; +DROP TABLE TestResults_1 +DROP VIEW float_varchar_v1; +DROP VIEW float_varchar_v2; +DROP FUNCTION float_varchar_f1; +DROP FUNCTION float_varchar_f2; +DROP PROCEDURE float_varchar_p1; +DROP TABLE float_varchar_t1; +DROP TABLE float_varchar_t2; +GO \ No newline at end of file diff --git a/test/JDBC/input/functions/test_conv_float_to_varchar_char-vu-prepare.sql b/test/JDBC/input/functions/test_conv_float_to_varchar_char-vu-prepare.sql new file mode 100644 index 0000000000..7fab411910 --- /dev/null +++ b/test/JDBC/input/functions/test_conv_float_to_varchar_char-vu-prepare.sql @@ -0,0 +1,178 @@ +CREATE TABLE float_char_t1 ( + ID INT IDENTITY(1,1), + FloatValue FLOAT, + Description VARCHAR(100) +); +GO +-- Create dependent objects for testing +-- 1. View that uses CAST +CREATE VIEW float_char_v1 +AS +SELECT + CAST(CAST('-123.456325678543' AS FLOAT) AS CHAR(30)) AS CastValue, + CAST(CAST('-123.456325678543' AS FLOAT(53)) AS CHAR(30)) AS CastValue2 +GO + +-- 2. View that uses CONVERT +CREATE VIEW float_char_v2 +AS +SELECT + CONVERT(CHAR(30), CAST('-123.456325678543' as FLOAT)) AS ConvertValue, + CONVERT(CHAR(30), CAST('-123.456325678543' as FLOAT(53))) AS ConvertValue2 +GO + +-- 3. Function using CAST +CREATE FUNCTION float_char_f1 +( + @FloatInput FLOAT +) +RETURNS VARCHAR(30) +AS +BEGIN + RETURN CAST(@FloatInput AS CHAR(30)) +END; +GO + +-- 4. Function using CONVERT +CREATE FUNCTION float_char_f2 +( + @FloatInput FLOAT +) +RETURNS VARCHAR(30) +AS +BEGIN + RETURN CONVERT(CHAR(30), @FloatInput) +END; +GO + +CREATE PROCEDURE float_char_p1 + @FloatInput FLOAT +AS +BEGIN + SELECT + CAST(@FloatInput AS CHAR(30)) AS CastResult, + CONVERT(CHAR(30), @FloatInput) AS ConvertResult +END; +GO + +-- Insert test data +INSERT INTO float_char_t1 (FloatValue, Description) VALUES + (123.456, 'Standard positive decimal'), + (-123.456, 'Negative decimal'), + (0.0, 'Zero value'), + (1E10, 'Scientific notation - large'), + (1E-10, 'Scientific notation - small'), + (9999999999.99, 'Large decimal'), + (0.000000001, 'Very small decimal'), + (NULL, 'NULL Value') +GO + + +CREATE TABLE TestResults ( + TestID INT IDENTITY(1,1), + TestCategory VARCHAR(50), + TestName VARCHAR(100), + TestScenario VARCHAR(200), + ExpectedResult VARCHAR(50), + ActualResult VARCHAR(50), + TestStatus VARCHAR(20) +); +GO + + +CREATE TABLE float_varchar_t1 ( + ID INT IDENTITY(1,1), + FloatValue FLOAT, + Description VARCHAR(100) +); +GO +-- Create dependent objects for testing +-- 1. View that uses CAST +CREATE VIEW float_varchar_v1 +AS +SELECT + CAST(CAST('-123.456325678543' AS FLOAT) AS VARCHAR(30)) AS CastValue, + CAST(CAST('-123.456325678543' AS FLOAT(53)) AS VARCHAR(30)) AS CastValue2 +GO + +-- 2. View that uses CONVERT +CREATE VIEW float_varchar_v2 +AS +SELECT + CONVERT(VARCHAR(30), CAST('-123.456325678543' as FLOAT)) AS ConvertValue, + CONVERT(VARCHAR(30), CAST('-123.456325678543' as FLOAT(53))) AS ConvertValue2 +GO + +-- 3. Function using CAST +CREATE FUNCTION float_varchar_f1 +( + @FloatInput FLOAT +) +RETURNS VARCHAR(30) +AS +BEGIN + RETURN CAST(@FloatInput AS VARCHAR(30)) +END; +GO + +-- 4. Function using CONVERT +CREATE FUNCTION float_varchar_f2 +( + @FloatInput FLOAT +) +RETURNS VARCHAR(30) +AS +BEGIN + RETURN CONVERT(VARCHAR(30), @FloatInput) +END; +GO + +CREATE PROCEDURE float_varchar_p1 + @FloatInput FLOAT +AS +BEGIN + SELECT + CAST(@FloatInput AS VARCHAR(30)) AS CastResult, + CONVERT(VARCHAR(30), @FloatInput) AS ConvertResult +END; +GO + +-- Insert test data +INSERT INTO float_varchar_t1 (FloatValue, Description) VALUES + (123.456, 'Standard positive decimal'), + (-123.456, 'Negative decimal'), + (0.0, 'Zero value'), + (1E10, 'Scientific notation - large'), + (1E-10, 'Scientific notation - small'), + (9999999999.99, 'Large decimal'), + (0.000000001, 'Very small decimal'), + (NULL, 'NULL Value') +GO + + +CREATE TABLE TestResults_1 ( + TestID INT IDENTITY(1,1), + TestCategory VARCHAR(50), + TestName VARCHAR(100), + TestScenario VARCHAR(200), + ExpectedResult VARCHAR(50), + ActualResult VARCHAR(50), + TestStatus VARCHAR(20) +); +GO + +CREATE TABLE float_char_t2 +( + a char(30), + check (cast(a as float) > 0) +) +GO + +CREATE TABLE float_varchar_t2 +( + a varchar(30), + check (cast(a as float) > 0) +) +GO + + diff --git a/test/JDBC/input/functions/test_conv_float_to_varchar_char-vu-verify.sql b/test/JDBC/input/functions/test_conv_float_to_varchar_char-vu-verify.sql new file mode 100644 index 0000000000..12cb37ad5d --- /dev/null +++ b/test/JDBC/input/functions/test_conv_float_to_varchar_char-vu-verify.sql @@ -0,0 +1,147 @@ +-- TEST FOR CHAR +DECLARE @TestCases TABLE ( + FloatValue FLOAT, + ScenarioDescription VARCHAR(200) +); + +INSERT INTO @TestCases +SELECT FloatValue, Description FROM float_char_t1; + +-- 1. Test Direct CAST/CONVERT +INSERT INTO TestResults (TestCategory, TestName, TestScenario, ExpectedResult, ActualResult) +SELECT + 'Direct Conversion', + 'CAST vs CONVERT', + tc.ScenarioDescription, + CAST(tc.FloatValue AS CHAR(30)), + CONVERT(CHAR(30), tc.FloatValue) +FROM @TestCases tc; + +-- Display Results by Category +SELECT + TestCategory, + TestName, + TestScenario, + ExpectedResult, + ActualResult, + TestStatus +FROM TestResults +ORDER BY TestCategory, TestID; + +-- Test Stored Procedure Execution +DECLARE @FloatValue FLOAT; +DECLARE cur CURSOR FOR SELECT FloatValue FROM @TestCases; +OPEN cur; + +FETCH NEXT FROM cur INTO @FloatValue; +WHILE @@FETCH_STATUS = 0 +BEGIN + EXEC float_char_p1 @FloatValue; + FETCH NEXT FROM cur INTO @FloatValue; +END + +CLOSE cur; +DEALLOCATE cur; +GO + +-- 2. Test Views +SELECT * FROM float_char_v1; +SELECT * FROM float_char_v2; +GO + +-- 3. Test Functions +SELECT float_char_f1('123.4567') +SELECT float_char_f2('123.4567') +GO + +-- TEST FOR VARCHAR + +DECLARE @TestCases TABLE ( + FloatValue FLOAT, + ScenarioDescription VARCHAR(200) +); + +INSERT INTO @TestCases +SELECT FloatValue, Description FROM float_varchar_t1; + +-- 1. Test Direct CAST/CONVERT +INSERT INTO TestResults_1 (TestCategory, TestName, TestScenario, ExpectedResult, ActualResult) +SELECT + 'Direct Conversion', + 'CAST vs CONVERT', + tc.ScenarioDescription, + CAST(tc.FloatValue AS VARCHAR(30)), + CONVERT(VARCHAR(30), tc.FloatValue) +FROM @TestCases tc; + +-- Display Results by Category +SELECT + TestCategory, + TestName, + TestScenario, + ExpectedResult, + ActualResult, + TestStatus +FROM TestResults_1 +ORDER BY TestCategory, TestID; + +-- Test Stored Procedure Execution +DECLARE @FloatValue FLOAT; +DECLARE cur CURSOR FOR SELECT FloatValue FROM @TestCases; +OPEN cur; + +FETCH NEXT FROM cur INTO @FloatValue; +WHILE @@FETCH_STATUS = 0 +BEGIN + EXEC float_varchar_p1 @FloatValue; + FETCH NEXT FROM cur INTO @FloatValue; +END + +CLOSE cur; +DEALLOCATE cur; +GO + + +-- 2. Test Views +SELECT * FROM float_varchar_v1; +SELECT * FROM float_varchar_v2; +GO + +-- 3. Test Functions +SELECT float_varchar_f1('123.4567') +SELECT float_varchar_f2('123.4567') +GO + +-- 4. Test Convert/CAST in WHERE +SELECT COUNT(*) FROM float_varchar_t1 where length(CAST(FloatValue as VARCHAR)) < 8; +GO +SELECT COUNT(*) FROM float_varchar_t1 WHERE length(CONVERT(VARCHAR(30),FloatValue)) = 30; +GO + +-- 5. Test Insuffiecient String Length +SELECT CAST(CAST('214555.32435254' AS FLOAT) AS VARCHAR(5)); +GO +SELECT CAST(CAST('214555.32435254' AS FLOAT) AS CHAR(5)); +GO + +-- 6. Test Special Values +SELECT CAST(CAST('NaN' as Float) as VARCHAR(30)) +GO +SELECT CAST(CAST('NaN' as Float) as CHAR(30)) +GO +SELECT CAST(CAST('Inf' as Float) as VARCHAR) +GO +SELECT CAST(CAST('Inf' as Float) as CHAR) +GO + +-- 7. Test Constraints +INSERT INTO float_char_t2 VALUES('-1.245243') +GO +INSERT INTO float_varchar_t2 VALUES('-1.245243') +GO + +-- 8. Test With Variables +DECLARE @flt1 Float = 1.3242335 +DECLARE @flt2 Float = -54235.4322 +SELECT cast(@flt1*@flt2 as varchar(30)),cast(@flt1/@flt2 as varchar(30)),cast(@flt1+@flt2 as char(30)),cast(@flt1/@flt2 as char(30)) +GO \ No newline at end of file diff --git a/test/JDBC/input/functions/test_conv_float_to_varchar_char_before_17_3-vu-cleanup.sql b/test/JDBC/input/functions/test_conv_float_to_varchar_char_before_17_3-vu-cleanup.sql new file mode 100644 index 0000000000..b50bea2a66 --- /dev/null +++ b/test/JDBC/input/functions/test_conv_float_to_varchar_char_before_17_3-vu-cleanup.sql @@ -0,0 +1,17 @@ +DROP TABLE TestResults +DROP VIEW float_char_v1; +DROP VIEW float_char_v2; +DROP FUNCTION float_char_f1; +DROP FUNCTION float_char_f2; +DROP PROCEDURE float_char_p1; +DROP TABLE float_char_t1; +DROP TABLE float_char_t2; +DROP TABLE TestResults_1 +DROP VIEW float_varchar_v1; +DROP VIEW float_varchar_v2; +DROP FUNCTION float_varchar_f1; +DROP FUNCTION float_varchar_f2; +DROP PROCEDURE float_varchar_p1; +DROP TABLE float_varchar_t1; +DROP TABLE float_varchar_t2; +GO \ No newline at end of file diff --git a/test/JDBC/input/functions/test_conv_float_to_varchar_char_before_17_3-vu-prepare.sql b/test/JDBC/input/functions/test_conv_float_to_varchar_char_before_17_3-vu-prepare.sql new file mode 100644 index 0000000000..72f524c046 --- /dev/null +++ b/test/JDBC/input/functions/test_conv_float_to_varchar_char_before_17_3-vu-prepare.sql @@ -0,0 +1,178 @@ +CREATE TABLE float_char_t1 ( + ID INT IDENTITY(1,1), + FloatValue FLOAT, + Description VARCHAR(100) +); +GO +-- Create dependent objects for testing +-- 1. View that uses CAST +CREATE VIEW float_char_v1 +AS +SELECT + CAST(CAST('-123.456325678543' AS FLOAT) AS CHAR(30)) AS CastValue, + CAST(CAST('-123.456325678543' AS FLOAT(53)) AS CHAR(30)) AS CastValue2 +GO + +-- 2. View that uses CONVERT +CREATE VIEW float_char_v2 +AS +SELECT + CONVERT(CHAR(30), CAST('-123.456' as FLOAT)) AS ConvertValue, + CONVERT(CHAR(30), CAST('-123.456' as FLOAT(53))) AS ConvertValue2 +GO + +-- 3. Function using CAST +CREATE FUNCTION float_char_f1 +( + @FloatInput FLOAT +) +RETURNS VARCHAR(30) +AS +BEGIN + RETURN CAST(@FloatInput AS CHAR(30)) +END; +GO + +-- 4. Function using CONVERT +CREATE FUNCTION float_char_f2 +( + @FloatInput FLOAT +) +RETURNS VARCHAR(30) +AS +BEGIN + RETURN CONVERT(CHAR(30), @FloatInput) +END; +GO + +CREATE PROCEDURE float_char_p1 + @FloatInput FLOAT +AS +BEGIN + SELECT + CAST(@FloatInput AS CHAR(30)) AS CastResult, + CONVERT(CHAR(30), @FloatInput) AS ConvertResult +END; +GO + +-- Insert test data +INSERT INTO float_char_t1 (FloatValue, Description) VALUES + (123.456, 'Standard positive decimal'), + (-123.456, 'Negative decimal'), + (0.0, 'Zero value'), + (1E10, 'Scientific notation - large'), + (1E-10, 'Scientific notation - small'), + (9999999999.99, 'Large decimal'), + (0.000000001, 'Very small decimal'), + (NULL, 'NULL Value') +GO + + +CREATE TABLE TestResults ( + TestID INT IDENTITY(1,1), + TestCategory VARCHAR(50), + TestName VARCHAR(100), + TestScenario VARCHAR(200), + ExpectedResult VARCHAR(50), + ActualResult VARCHAR(50), + TestStatus VARCHAR(20) +); +GO + + +CREATE TABLE float_varchar_t1 ( + ID INT IDENTITY(1,1), + FloatValue FLOAT, + Description VARCHAR(100) +); +GO +-- Create dependent objects for testing +-- 1. View that uses CAST +CREATE VIEW float_varchar_v1 +AS +SELECT + CAST(CAST('-123.456325678543' AS FLOAT) AS VARCHAR(30)) AS CastValue, + CAST(CAST('-123.456325678543' AS FLOAT(53)) AS VARCHAR(30)) AS CastValue2 +GO + +-- 2. View that uses CONVERT +CREATE VIEW float_varchar_v2 +AS +SELECT + CONVERT(VARCHAR(30), CAST('-123.456325678543' as FLOAT)) AS ConvertValue, + CONVERT(VARCHAR(30), CAST('-123.456325678543' as FLOAT(53))) AS ConvertValue2 +GO + +-- 3. Function using CAST +CREATE FUNCTION float_varchar_f1 +( + @FloatInput FLOAT +) +RETURNS VARCHAR(30) +AS +BEGIN + RETURN CAST(@FloatInput AS VARCHAR(30)) +END; +GO + +-- 4. Function using CONVERT +CREATE FUNCTION float_varchar_f2 +( + @FloatInput FLOAT +) +RETURNS VARCHAR(30) +AS +BEGIN + RETURN CONVERT(VARCHAR(30), @FloatInput) +END; +GO + +CREATE PROCEDURE float_varchar_p1 + @FloatInput FLOAT +AS +BEGIN + SELECT + CAST(@FloatInput AS VARCHAR(30)) AS CastResult, + CONVERT(VARCHAR(30), @FloatInput) AS ConvertResult +END; +GO + +-- Insert test data +INSERT INTO float_varchar_t1 (FloatValue, Description) VALUES + (123.456, 'Standard positive decimal'), + (-123.456, 'Negative decimal'), + (0.0, 'Zero value'), + (1E10, 'Scientific notation - large'), + (1E-10, 'Scientific notation - small'), + (9999999999.99, 'Large decimal'), + (0.000000001, 'Very small decimal'), + (NULL, 'NULL Value') +GO + + +CREATE TABLE TestResults_1 ( + TestID INT IDENTITY(1,1), + TestCategory VARCHAR(50), + TestName VARCHAR(100), + TestScenario VARCHAR(200), + ExpectedResult VARCHAR(50), + ActualResult VARCHAR(50), + TestStatus VARCHAR(20) +); +GO + +CREATE TABLE float_char_t2 +( + a char(30), + check (cast(a as float) > 0) +) +GO + +CREATE TABLE float_varchar_t2 +( + a varchar(30), + check (cast(a as float) > 0) +) +GO + + diff --git a/test/JDBC/input/functions/test_conv_float_to_varchar_char_before_17_3-vu-verify.sql b/test/JDBC/input/functions/test_conv_float_to_varchar_char_before_17_3-vu-verify.sql new file mode 100644 index 0000000000..12cb37ad5d --- /dev/null +++ b/test/JDBC/input/functions/test_conv_float_to_varchar_char_before_17_3-vu-verify.sql @@ -0,0 +1,147 @@ +-- TEST FOR CHAR +DECLARE @TestCases TABLE ( + FloatValue FLOAT, + ScenarioDescription VARCHAR(200) +); + +INSERT INTO @TestCases +SELECT FloatValue, Description FROM float_char_t1; + +-- 1. Test Direct CAST/CONVERT +INSERT INTO TestResults (TestCategory, TestName, TestScenario, ExpectedResult, ActualResult) +SELECT + 'Direct Conversion', + 'CAST vs CONVERT', + tc.ScenarioDescription, + CAST(tc.FloatValue AS CHAR(30)), + CONVERT(CHAR(30), tc.FloatValue) +FROM @TestCases tc; + +-- Display Results by Category +SELECT + TestCategory, + TestName, + TestScenario, + ExpectedResult, + ActualResult, + TestStatus +FROM TestResults +ORDER BY TestCategory, TestID; + +-- Test Stored Procedure Execution +DECLARE @FloatValue FLOAT; +DECLARE cur CURSOR FOR SELECT FloatValue FROM @TestCases; +OPEN cur; + +FETCH NEXT FROM cur INTO @FloatValue; +WHILE @@FETCH_STATUS = 0 +BEGIN + EXEC float_char_p1 @FloatValue; + FETCH NEXT FROM cur INTO @FloatValue; +END + +CLOSE cur; +DEALLOCATE cur; +GO + +-- 2. Test Views +SELECT * FROM float_char_v1; +SELECT * FROM float_char_v2; +GO + +-- 3. Test Functions +SELECT float_char_f1('123.4567') +SELECT float_char_f2('123.4567') +GO + +-- TEST FOR VARCHAR + +DECLARE @TestCases TABLE ( + FloatValue FLOAT, + ScenarioDescription VARCHAR(200) +); + +INSERT INTO @TestCases +SELECT FloatValue, Description FROM float_varchar_t1; + +-- 1. Test Direct CAST/CONVERT +INSERT INTO TestResults_1 (TestCategory, TestName, TestScenario, ExpectedResult, ActualResult) +SELECT + 'Direct Conversion', + 'CAST vs CONVERT', + tc.ScenarioDescription, + CAST(tc.FloatValue AS VARCHAR(30)), + CONVERT(VARCHAR(30), tc.FloatValue) +FROM @TestCases tc; + +-- Display Results by Category +SELECT + TestCategory, + TestName, + TestScenario, + ExpectedResult, + ActualResult, + TestStatus +FROM TestResults_1 +ORDER BY TestCategory, TestID; + +-- Test Stored Procedure Execution +DECLARE @FloatValue FLOAT; +DECLARE cur CURSOR FOR SELECT FloatValue FROM @TestCases; +OPEN cur; + +FETCH NEXT FROM cur INTO @FloatValue; +WHILE @@FETCH_STATUS = 0 +BEGIN + EXEC float_varchar_p1 @FloatValue; + FETCH NEXT FROM cur INTO @FloatValue; +END + +CLOSE cur; +DEALLOCATE cur; +GO + + +-- 2. Test Views +SELECT * FROM float_varchar_v1; +SELECT * FROM float_varchar_v2; +GO + +-- 3. Test Functions +SELECT float_varchar_f1('123.4567') +SELECT float_varchar_f2('123.4567') +GO + +-- 4. Test Convert/CAST in WHERE +SELECT COUNT(*) FROM float_varchar_t1 where length(CAST(FloatValue as VARCHAR)) < 8; +GO +SELECT COUNT(*) FROM float_varchar_t1 WHERE length(CONVERT(VARCHAR(30),FloatValue)) = 30; +GO + +-- 5. Test Insuffiecient String Length +SELECT CAST(CAST('214555.32435254' AS FLOAT) AS VARCHAR(5)); +GO +SELECT CAST(CAST('214555.32435254' AS FLOAT) AS CHAR(5)); +GO + +-- 6. Test Special Values +SELECT CAST(CAST('NaN' as Float) as VARCHAR(30)) +GO +SELECT CAST(CAST('NaN' as Float) as CHAR(30)) +GO +SELECT CAST(CAST('Inf' as Float) as VARCHAR) +GO +SELECT CAST(CAST('Inf' as Float) as CHAR) +GO + +-- 7. Test Constraints +INSERT INTO float_char_t2 VALUES('-1.245243') +GO +INSERT INTO float_varchar_t2 VALUES('-1.245243') +GO + +-- 8. Test With Variables +DECLARE @flt1 Float = 1.3242335 +DECLARE @flt2 Float = -54235.4322 +SELECT cast(@flt1*@flt2 as varchar(30)),cast(@flt1/@flt2 as varchar(30)),cast(@flt1+@flt2 as char(30)),cast(@flt1/@flt2 as char(30)) +GO \ No newline at end of file diff --git a/test/JDBC/jdbc_schedule b/test/JDBC/jdbc_schedule index 79ebd44a95..4a8193757e 100644 --- a/test/JDBC/jdbc_schedule +++ b/test/JDBC/jdbc_schedule @@ -541,3 +541,6 @@ ignore#!#trim-before-15_11-or-16_7-vu-cleanup # getting timed out (TODO: BABEL-5353) ignore#!#BABEL-SP_TABLE_PRIVILEGES +ignore#!#test_conv_float_to_varchar_char_before_17_3-vu-prepare +ignore#!#test_conv_float_to_varchar_char_before_17_3-vu-verify +ignore#!#test_conv_float_to_varchar_char_before_17_3-vu-cleanup diff --git a/test/JDBC/upgrade/13_4/schedule b/test/JDBC/upgrade/13_4/schedule index 28be24e611..317b2ec23f 100644 --- a/test/JDBC/upgrade/13_4/schedule +++ b/test/JDBC/upgrade/13_4/schedule @@ -261,3 +261,4 @@ test_conv_string_to_time-before-13_6 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/13_5/schedule b/test/JDBC/upgrade/13_5/schedule index 5acee2a549..2c81336eed 100644 --- a/test/JDBC/upgrade/13_5/schedule +++ b/test/JDBC/upgrade/13_5/schedule @@ -314,3 +314,4 @@ test_conv_string_to_time-before-13_6 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/13_6/schedule b/test/JDBC/upgrade/13_6/schedule index 4ff704ba42..d6c4b61232 100644 --- a/test/JDBC/upgrade/13_6/schedule +++ b/test/JDBC/upgrade/13_6/schedule @@ -371,3 +371,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/13_7/schedule b/test/JDBC/upgrade/13_7/schedule index f0278d816e..88bd994bd6 100644 --- a/test/JDBC/upgrade/13_7/schedule +++ b/test/JDBC/upgrade/13_7/schedule @@ -364,3 +364,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/13_8/schedule b/test/JDBC/upgrade/13_8/schedule index f0278d816e..88bd994bd6 100644 --- a/test/JDBC/upgrade/13_8/schedule +++ b/test/JDBC/upgrade/13_8/schedule @@ -364,3 +364,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/13_9/schedule b/test/JDBC/upgrade/13_9/schedule index 1cc5cb05a0..79b145074e 100644 --- a/test/JDBC/upgrade/13_9/schedule +++ b/test/JDBC/upgrade/13_9/schedule @@ -369,3 +369,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/14_10/schedule b/test/JDBC/upgrade/14_10/schedule index 37c135f2b3..bea9386eae 100644 --- a/test/JDBC/upgrade/14_10/schedule +++ b/test/JDBC/upgrade/14_10/schedule @@ -482,3 +482,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/14_11/schedule b/test/JDBC/upgrade/14_11/schedule index 3c1042f26c..f192776b45 100644 --- a/test/JDBC/upgrade/14_11/schedule +++ b/test/JDBC/upgrade/14_11/schedule @@ -480,3 +480,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/14_12/schedule b/test/JDBC/upgrade/14_12/schedule index db76784604..b6f4ebff34 100644 --- a/test/JDBC/upgrade/14_12/schedule +++ b/test/JDBC/upgrade/14_12/schedule @@ -481,3 +481,4 @@ smalldatetime_date_cmp-before-15_5-16_1 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/14_13/schedule b/test/JDBC/upgrade/14_13/schedule index d8301d95f0..51acd8e8dd 100644 --- a/test/JDBC/upgrade/14_13/schedule +++ b/test/JDBC/upgrade/14_13/schedule @@ -481,3 +481,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/14_15/schedule b/test/JDBC/upgrade/14_15/schedule index c2f052fd6f..f71cce5a7a 100644 --- a/test/JDBC/upgrade/14_15/schedule +++ b/test/JDBC/upgrade/14_15/schedule @@ -477,3 +477,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/14_16/schedule b/test/JDBC/upgrade/14_16/schedule index 1b97ac7a1f..2e1b9b23c2 100644 --- a/test/JDBC/upgrade/14_16/schedule +++ b/test/JDBC/upgrade/14_16/schedule @@ -477,3 +477,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/14_3/schedule b/test/JDBC/upgrade/14_3/schedule index f4c209a8b9..95c7c73378 100644 --- a/test/JDBC/upgrade/14_3/schedule +++ b/test/JDBC/upgrade/14_3/schedule @@ -400,3 +400,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/14_5/schedule b/test/JDBC/upgrade/14_5/schedule index 88ab9ca47d..4d0a030f6a 100644 --- a/test/JDBC/upgrade/14_5/schedule +++ b/test/JDBC/upgrade/14_5/schedule @@ -412,3 +412,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/14_6/schedule b/test/JDBC/upgrade/14_6/schedule index 5e4c018db9..668b3bc5c6 100644 --- a/test/JDBC/upgrade/14_6/schedule +++ b/test/JDBC/upgrade/14_6/schedule @@ -450,3 +450,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/14_7/schedule b/test/JDBC/upgrade/14_7/schedule index a491439b90..76f305ecf9 100644 --- a/test/JDBC/upgrade/14_7/schedule +++ b/test/JDBC/upgrade/14_7/schedule @@ -472,3 +472,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/14_8/schedule b/test/JDBC/upgrade/14_8/schedule index 62ebc35d70..8492e55a28 100644 --- a/test/JDBC/upgrade/14_8/schedule +++ b/test/JDBC/upgrade/14_8/schedule @@ -474,3 +474,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/14_9/schedule b/test/JDBC/upgrade/14_9/schedule index 0fabe83c90..e89b52c6d2 100644 --- a/test/JDBC/upgrade/14_9/schedule +++ b/test/JDBC/upgrade/14_9/schedule @@ -477,3 +477,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/15_1/schedule b/test/JDBC/upgrade/15_1/schedule index f26a07e637..7331c96a1f 100644 --- a/test/JDBC/upgrade/15_1/schedule +++ b/test/JDBC/upgrade/15_1/schedule @@ -450,3 +450,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/15_10/schedule b/test/JDBC/upgrade/15_10/schedule index 111b1abe45..f7520e90a6 100644 --- a/test/JDBC/upgrade/15_10/schedule +++ b/test/JDBC/upgrade/15_10/schedule @@ -567,3 +567,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/15_11/schedule b/test/JDBC/upgrade/15_11/schedule index d12f63299a..cc0c19c076 100644 --- a/test/JDBC/upgrade/15_11/schedule +++ b/test/JDBC/upgrade/15_11/schedule @@ -567,3 +567,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/15_2/schedule b/test/JDBC/upgrade/15_2/schedule index 6dbf65eaf2..8ab7270c03 100644 --- a/test/JDBC/upgrade/15_2/schedule +++ b/test/JDBC/upgrade/15_2/schedule @@ -486,3 +486,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/15_3/schedule b/test/JDBC/upgrade/15_3/schedule index c1d37bb6a2..0328c1cbe8 100644 --- a/test/JDBC/upgrade/15_3/schedule +++ b/test/JDBC/upgrade/15_3/schedule @@ -506,3 +506,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/15_4/schedule b/test/JDBC/upgrade/15_4/schedule index c30db810dc..fd42af9476 100644 --- a/test/JDBC/upgrade/15_4/schedule +++ b/test/JDBC/upgrade/15_4/schedule @@ -519,3 +519,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/15_5/schedule b/test/JDBC/upgrade/15_5/schedule index c9c8e505e7..da6bdb1e22 100644 --- a/test/JDBC/upgrade/15_5/schedule +++ b/test/JDBC/upgrade/15_5/schedule @@ -552,3 +552,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 \ No newline at end of file diff --git a/test/JDBC/upgrade/15_6/schedule b/test/JDBC/upgrade/15_6/schedule index 70cab1e70c..a4d1e9a064 100644 --- a/test/JDBC/upgrade/15_6/schedule +++ b/test/JDBC/upgrade/15_6/schedule @@ -568,3 +568,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/15_7/schedule b/test/JDBC/upgrade/15_7/schedule index a2df0dae73..519e6af87e 100644 --- a/test/JDBC/upgrade/15_7/schedule +++ b/test/JDBC/upgrade/15_7/schedule @@ -576,3 +576,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/15_8/schedule b/test/JDBC/upgrade/15_8/schedule index ff0de7da33..408c3074d2 100644 --- a/test/JDBC/upgrade/15_8/schedule +++ b/test/JDBC/upgrade/15_8/schedule @@ -567,3 +567,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/16_1/schedule b/test/JDBC/upgrade/16_1/schedule index 619eeb10f5..c3f017e2f3 100644 --- a/test/JDBC/upgrade/16_1/schedule +++ b/test/JDBC/upgrade/16_1/schedule @@ -561,3 +561,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/16_2/schedule b/test/JDBC/upgrade/16_2/schedule index 1cdb53bf26..7d530ddf51 100644 --- a/test/JDBC/upgrade/16_2/schedule +++ b/test/JDBC/upgrade/16_2/schedule @@ -577,3 +577,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/16_3/schedule b/test/JDBC/upgrade/16_3/schedule index e399d98911..13ede98567 100644 --- a/test/JDBC/upgrade/16_3/schedule +++ b/test/JDBC/upgrade/16_3/schedule @@ -581,3 +581,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/16_4/schedule b/test/JDBC/upgrade/16_4/schedule index 47ff20eae6..7ad9c88eca 100644 --- a/test/JDBC/upgrade/16_4/schedule +++ b/test/JDBC/upgrade/16_4/schedule @@ -594,3 +594,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/16_6/schedule b/test/JDBC/upgrade/16_6/schedule index 55ab206982..3dd601b882 100644 --- a/test/JDBC/upgrade/16_6/schedule +++ b/test/JDBC/upgrade/16_6/schedule @@ -597,3 +597,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/16_7/schedule b/test/JDBC/upgrade/16_7/schedule index 565f51aafb..b032220bb2 100644 --- a/test/JDBC/upgrade/16_7/schedule +++ b/test/JDBC/upgrade/16_7/schedule @@ -602,3 +602,4 @@ db_owner BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/17_2/schedule b/test/JDBC/upgrade/17_2/schedule index a8acf2a3b7..b943032078 100644 --- a/test/JDBC/upgrade/17_2/schedule +++ b/test/JDBC/upgrade/17_2/schedule @@ -600,3 +600,4 @@ test_conv_string_to_time-before-17_3 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char_before_17_3 diff --git a/test/JDBC/upgrade/latest/schedule b/test/JDBC/upgrade/latest/schedule index 542dcd93d9..12f59365e2 100644 --- a/test/JDBC/upgrade/latest/schedule +++ b/test/JDBC/upgrade/latest/schedule @@ -598,3 +598,4 @@ BABEL-2961 BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo +test_conv_float_to_varchar_char From a04d8ad3545cd40184bddcc4c29b9be2939d8c69 Mon Sep 17 00:00:00 2001 From: Sharu Goel <30777678+thephantomthief@users.noreply.github.com> Date: Wed, 29 Jan 2025 17:43:00 +0530 Subject: [PATCH 08/10] Cross-db insert on table with identity throws permission error on inserting in identity column (#3436) Previously, INSERTs on identity columns would throw permission denied on sequence error if the relation name is referenced as a three part object name and the database name in the qualified object name is not the current database name. To fix this, when we are about to proceed with the identity insert, we will first identify it is a cross database scenario. If it is, we will change the current role as the session user. Task: BABEL-5585 Signed-off-by: Sharu Goel goelshar@amazon.com --- contrib/babelfishpg_tsql/src/pl_exec.c | 58 ++++++++++++++++++++++- contrib/babelfishpg_tsql/src/pl_handler.c | 4 ++ test/JDBC/expected/BABEL-IDENTITY.out | 54 +++++++++++---------- test/JDBC/input/BABEL-IDENTITY.mix | 13 +++-- 4 files changed, 98 insertions(+), 31 deletions(-) diff --git a/contrib/babelfishpg_tsql/src/pl_exec.c b/contrib/babelfishpg_tsql/src/pl_exec.c index e09c927b80..f1133ce86e 100644 --- a/contrib/babelfishpg_tsql/src/pl_exec.c +++ b/contrib/babelfishpg_tsql/src/pl_exec.c @@ -5483,6 +5483,53 @@ pltsql_update_identity_insert_sequence(PLtsql_expr *expr) Oid seqid = InvalidOid; SPITupleTable *tuptable = SPI_tuptable; uint64 n_processed = SPI_processed; + bool is_cross_db = false; + char *schema_name = NULL; + HeapTuple schema_tuple; + Oid current_user_id = InvalidOid; + + schema_name = get_namespace_name(get_rel_namespace(tsql_identity_insert.rel_oid)); + schema_tuple = SearchSysCache1(SYSNAMESPACENAME, CStringGetDatum(schema_name)); + + if (HeapTupleIsValid(schema_tuple)) + { + Datum datum; + int16 db_id; + bool isnull; + + datum = SysCacheGetAttr(SYSNAMESPACENAME, schema_tuple, Anum_namespace_ext_dbid, &isnull); + db_id = DatumGetInt16(datum); + + if(!DbidIsValid(db_id)) + ereport(ERROR, + (errcode(ERRCODE_INTERNAL_ERROR), + errmsg("dbid in babelfish_namespace_ext catalog doesn't exists in babelfish_sysdatabases catalog"))); + + if (db_id != get_cur_db_id()) + { + char *db_name = get_db_name(db_id); + char *user = get_user_for_database(db_name); + + if (user) + { + is_cross_db = true; + pfree(db_name); + pfree(user); + } + else + { + char *login = GetUserNameFromId(GetSessionUserId(), false); + ereport(ERROR, + (errcode(ERRCODE_UNDEFINED_DATABASE), + errmsg("The server principal \"%s\" is not able to access " + "the database \"%s\" under the current security context", + login, db_name))); + } + + } + + ReleaseSysCache(schema_tuple); + } /* Get the identity column name */ rel = RelationIdGetRelation(tsql_identity_insert.rel_oid); @@ -5566,6 +5613,12 @@ pltsql_update_identity_insert_sequence(PLtsql_expr *expr) PG_TRY(); { + if (is_cross_db) + { + current_user_id = GetUserId(); + SetCurrentRoleId(GetSessionUserId(), false); + } + /* * We want the T-SQL behavior of setval function. * Please check the variable definition for @@ -5590,6 +5643,9 @@ pltsql_update_identity_insert_sequence(PLtsql_expr *expr) { /* reset the value */ pltsql_setval_identity_mode = false; + + if (is_cross_db) + SetCurrentRoleId(current_user_id, false); } PG_END_TRY(); @@ -10473,4 +10529,4 @@ pltsql_assign_var(PG_FUNCTION_ARGS) PG_RETURN_NULL(); PG_RETURN_DATUM(data); -} \ No newline at end of file +} diff --git a/contrib/babelfishpg_tsql/src/pl_handler.c b/contrib/babelfishpg_tsql/src/pl_handler.c index 13892e6116..e6c73a09dc 100644 --- a/contrib/babelfishpg_tsql/src/pl_handler.c +++ b/contrib/babelfishpg_tsql/src/pl_handler.c @@ -400,7 +400,11 @@ assign_identity_insert(const char *newval, void *extra) * throw permission denied error in that case */ if (!curr_user_if_cross_db) + { + /* Get schema name for error message */ + logical_schema_name = (char *) lthird(elemlist); throw_error_for_identity_insert(catalog_name, logical_schema_name, rel_name); + } } /* Check the user provided schema value */ diff --git a/test/JDBC/expected/BABEL-IDENTITY.out b/test/JDBC/expected/BABEL-IDENTITY.out index b7f3d9fa50..4f8f42660a 100644 --- a/test/JDBC/expected/BABEL-IDENTITY.out +++ b/test/JDBC/expected/BABEL-IDENTITY.out @@ -763,7 +763,7 @@ Index Scan using test_id_index_pkey on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 9.792 ms +Babelfish T-SQL Batch Parsing Time: 9.564 ms ~~END~~ @@ -778,7 +778,7 @@ Index Scan using test_id_index_pkey on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 3.872 ms +Babelfish T-SQL Batch Parsing Time: 3.754 ms ~~END~~ @@ -793,7 +793,7 @@ Index Scan using test_id_index_pkey on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 4.621 ms +Babelfish T-SQL Batch Parsing Time: 4.633 ms ~~END~~ @@ -808,7 +808,7 @@ Index Scan using test_id_index_pkey on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 42.064 ms +Babelfish T-SQL Batch Parsing Time: 42.276 ms ~~END~~ @@ -825,7 +825,7 @@ Bitmap Heap Scan on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 9.045 ms +Babelfish T-SQL Batch Parsing Time: 5.772 ms ~~END~~ @@ -840,7 +840,7 @@ Seq Scan on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 2.038 ms +Babelfish T-SQL Batch Parsing Time: 1.271 ms ~~END~~ @@ -857,7 +857,7 @@ Bitmap Heap Scan on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 9.868 ms +Babelfish T-SQL Batch Parsing Time: 5.620 ms ~~END~~ @@ -873,7 +873,7 @@ Index Scan using test_id_index_pkey on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.577 ms +Babelfish T-SQL Batch Parsing Time: 0.312 ms ~~END~~ @@ -888,7 +888,7 @@ Seq Scan on test_id_index ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 2.833 ms +Babelfish T-SQL Batch Parsing Time: 1.654 ms ~~END~~ @@ -903,7 +903,7 @@ Index Scan using test_id_index_tinyint_pkey on test_id_index_tinyint ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.302 ms +Babelfish T-SQL Batch Parsing Time: 0.194 ms ~~END~~ @@ -918,7 +918,7 @@ Index Scan using test_id_index_smallint_pkey on test_id_index_smallint ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.229 ms +Babelfish T-SQL Batch Parsing Time: 0.165 ms ~~END~~ @@ -933,7 +933,7 @@ Index Scan using test_id_index_bigint_pkey on test_id_index_bigint ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.226 ms +Babelfish T-SQL Batch Parsing Time: 0.160 ms ~~END~~ @@ -948,7 +948,7 @@ Index Scan using test_id_index_numeric_pkey on test_id_index_numeric ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.223 ms +Babelfish T-SQL Batch Parsing Time: 0.159 ms ~~END~~ @@ -974,7 +974,7 @@ Index Scan using test_numeric_index_no_id_pkey on test_numeric_index_no_id ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.290 ms +Babelfish T-SQL Batch Parsing Time: 0.191 ms ~~END~~ @@ -1194,7 +1194,7 @@ Index Only Scan using babel_3384_test_pkey on babel_3384_test ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.171 ms +Babelfish T-SQL Batch Parsing Time: 0.165 ms ~~END~~ select id from babel_3384_test WHERE id = @@IDENTITY @@ -1208,7 +1208,7 @@ Index Only Scan using babel_3384_test_pkey on babel_3384_test ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.164 ms +Babelfish T-SQL Batch Parsing Time: 0.208 ms ~~END~~ @@ -1318,11 +1318,17 @@ GO ~~ROW COUNT: 1~~ +INSERT INTO identity_insert_db.dbo.identity_insert_t1 (a, b) VALUES (3, 103); +GO +~~ROW COUNT: 1~~ + + SELECT * FROM identity_insert_t1 ORDER BY a GO ~~START~~ int#!#int 3#!#103 +3#!#103 ~~END~~ @@ -1364,15 +1370,13 @@ GO -- tsql user=identity_insert_l1 password=123 -- Should now have permission -SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 OFF +SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 ON GO --- Should fail +-- Should not fail INSERT INTO identity_insert_db.dbo.identity_insert_t1 (a, b) VALUES (5, 105); GO -~~ERROR (Code: 33557097)~~ - -~~ERROR (Message: cannot insert a non-DEFAULT value into column "a")~~ +~~ROW COUNT: 1~~ -- tsql @@ -1473,15 +1477,15 @@ guest#!#0#!#0 SET IDENTITY_INSERT identity_insert_db.identity_insert_sch.identity_insert_t2 ON GO -USE identity_insert_db -GO - -- Should not fail -INSERT INTO identity_insert_t2 (c, d) VALUES (1, 101); +INSERT INTO identity_insert_db.identity_insert_sch.identity_insert_t2 (c, d) VALUES (1, 101); GO ~~ROW COUNT: 1~~ +USE identity_insert_db +GO + SELECT * FROM identity_insert_t2 GO ~~START~~ diff --git a/test/JDBC/input/BABEL-IDENTITY.mix b/test/JDBC/input/BABEL-IDENTITY.mix index d95a9b3061..79b1d36954 100644 --- a/test/JDBC/input/BABEL-IDENTITY.mix +++ b/test/JDBC/input/BABEL-IDENTITY.mix @@ -613,6 +613,9 @@ GO INSERT INTO identity_insert_t1 (a, b) VALUES (3, 103); GO +INSERT INTO identity_insert_db.dbo.identity_insert_t1 (a, b) VALUES (3, 103); +GO + SELECT * FROM identity_insert_t1 ORDER BY a GO @@ -646,10 +649,10 @@ GO -- tsql user=identity_insert_l1 password=123 -- Should now have permission -SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 OFF +SET IDENTITY_INSERT identity_insert_db.dbo.identity_insert_t1 ON GO --- Should fail +-- Should not fail INSERT INTO identity_insert_db.dbo.identity_insert_t1 (a, b) VALUES (5, 105); GO @@ -729,11 +732,11 @@ GO SET IDENTITY_INSERT identity_insert_db.identity_insert_sch.identity_insert_t2 ON GO -USE identity_insert_db +-- Should not fail +INSERT INTO identity_insert_db.identity_insert_sch.identity_insert_t2 (c, d) VALUES (1, 101); GO --- Should not fail -INSERT INTO identity_insert_t2 (c, d) VALUES (1, 101); +USE identity_insert_db GO SELECT * FROM identity_insert_t2 From c3511c99b7e44aba611649c383abbc737f76cd33 Mon Sep 17 00:00:00 2001 From: Kristian Lejao <1741885+lejaokri@users.noreply.github.com> Date: Sun, 2 Feb 2025 21:57:33 -0800 Subject: [PATCH 09/10] Fixed expected file due to community commit ef2b70994 (#3443) Also fixed some testcase diff due to ordering because of parallel execution. Confirmed the plans are different. Signed-off-by: Kristian Lejao --- test/JDBC/expected/BABEL-2998.out | 18 ++- test/JDBC/expected/BABEL-LIKE2ILIKE.out | 1 + .../db_collation/BABEL-LIKE2ILIKE.out | 1 + .../chinese_prc_ci_as/BABEL-LIKE2ILIKE.out | 1 + .../expected/parallel_query/BABEL-2843.out | 34 ++--- .../expected/parallel_query/BABEL-3248.out | 2 +- .../expected/parallel_query/BABEL_3571.out | 18 +-- .../expected/parallel_query/BABEL_4940.out | 24 ++-- .../parallel_query/TestHalfvecDatatype.out | 88 ++++++------ .../parallel_query/TestSparsevecDatatype.out | 22 +-- .../parallel_query/TestVectorDatatype.out | 136 +++++++++--------- .../parallel_query/babel_collection.out | 38 ++--- .../cast_eliminate-vu-verify.out | 31 ++-- .../charindex_replace_patindex-vu-verify.out | 4 +- .../test_dynamic_local_vars.out | 8 +- test/JDBC/input/BABEL-2998.mix | 6 + test/JDBC/input/BABEL-LIKE2ILIKE.sql | 1 + 17 files changed, 221 insertions(+), 212 deletions(-) diff --git a/test/JDBC/expected/BABEL-2998.out b/test/JDBC/expected/BABEL-2998.out index de030d1724..510d323d54 100644 --- a/test/JDBC/expected/BABEL-2998.out +++ b/test/JDBC/expected/BABEL-2998.out @@ -3,11 +3,12 @@ SELECT CAST('1' AS CHAR(10)) AS Col1 UNION SELECT NULL AS Col1 +ORDER BY Col1 GO ~~START~~ char -1 +1 ~~END~~ @@ -15,11 +16,12 @@ SELECT CAST('1' AS CHAR(10)) AS Col1 UNION ALL SELECT NULL AS Col1 GROUP BY Col1 +ORDER BY Col1 GO ~~START~~ char -1 +1 ~~END~~ @@ -27,11 +29,12 @@ char SELECT CAST('1' AS CHAR(10)) AS Col1 UNION SELECT CAST(NULL AS CHAR(10)) AS Col1 +ORDER BY Col1 GO ~~START~~ char -1 +1 ~~END~~ @@ -39,11 +42,12 @@ SELECT CAST('1' AS CHAR(10)) AS Col1 UNION ALL SELECT CONVERT(CHAR(10), NULL) AS Col1 GROUP BY Col1 +ORDER BY Col1 GO ~~START~~ char -1 +1 ~~END~~ @@ -51,22 +55,24 @@ SELECT CAST('1' AS CHAR(10)) AS Col1 UNION ALL SELECT CAST(NULL AS CHAR(10)) AS Col1 GROUP BY Col1 +ORDER BY Col1 GO ~~START~~ char -1 +1 ~~END~~ SELECT CAST('1' AS CHAR(10)) AS Col1 UNION SELECT CONVERT(CHAR(10), NULL) AS Col1 +ORDER BY Col1 GO ~~START~~ char -1 +1 ~~END~~ diff --git a/test/JDBC/expected/BABEL-LIKE2ILIKE.out b/test/JDBC/expected/BABEL-LIKE2ILIKE.out index 57aad91e4d..f0edb0b3b1 100644 --- a/test/JDBC/expected/BABEL-LIKE2ILIKE.out +++ b/test/JDBC/expected/BABEL-LIKE2ILIKE.out @@ -177,6 +177,7 @@ int with p1 as (select c1 from like_tesing1 where c1 LIKE '__Ć_'), p2 as (select c3 from like_tesing1 where c3 LIKE 'äƀ__') select * from p1 union all select * from p2 +order by 1 GO ~~START~~ nvarchar diff --git a/test/JDBC/expected/db_collation/BABEL-LIKE2ILIKE.out b/test/JDBC/expected/db_collation/BABEL-LIKE2ILIKE.out index 910a558b8a..015f78559d 100644 --- a/test/JDBC/expected/db_collation/BABEL-LIKE2ILIKE.out +++ b/test/JDBC/expected/db_collation/BABEL-LIKE2ILIKE.out @@ -182,6 +182,7 @@ int with p1 as (select c1 from like_tesing1 where c1 LIKE '__Ć_'), p2 as (select c3 from like_tesing1 where c3 LIKE 'äƀ__') select * from p1 union all select * from p2 +order by 1 GO ~~START~~ nvarchar diff --git a/test/JDBC/expected/non_default_server_collation/chinese_prc_ci_as/BABEL-LIKE2ILIKE.out b/test/JDBC/expected/non_default_server_collation/chinese_prc_ci_as/BABEL-LIKE2ILIKE.out index f70b4e5e9d..f8ef156946 100644 --- a/test/JDBC/expected/non_default_server_collation/chinese_prc_ci_as/BABEL-LIKE2ILIKE.out +++ b/test/JDBC/expected/non_default_server_collation/chinese_prc_ci_as/BABEL-LIKE2ILIKE.out @@ -178,6 +178,7 @@ int with p1 as (select c1 from like_tesing1 where c1 LIKE '__Ć_'), p2 as (select c3 from like_tesing1 where c3 LIKE 'äƀ__') select * from p1 union all select * from p2 +order by 1 GO ~~START~~ nvarchar diff --git a/test/JDBC/expected/parallel_query/BABEL-2843.out b/test/JDBC/expected/parallel_query/BABEL-2843.out index 6d51d11170..917ef6dc02 100644 --- a/test/JDBC/expected/parallel_query/BABEL-2843.out +++ b/test/JDBC/expected/parallel_query/BABEL-2843.out @@ -35,7 +35,7 @@ text Query Text: select 1 Gather (cost=0.00..0.01 rows=1 width=4) (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Result (cost=0.00..0.01 rows=1 width=4) (actual rows=1 loops=1) ~~END~~ @@ -51,8 +51,8 @@ text Query Text: select * from babel_2843_t1 where b1 = 1 Gather (cost=0.00..19.11 rows=11 width=8) (actual rows=0 loops=1) Workers Planned: 3 - Workers Launched: 3 - -> Parallel Seq Scan on babel_2843_t1 (cost=0.00..19.11 rows=4 width=8) (actual rows=0 loops=4) + Workers Launched: 0 + -> Parallel Seq Scan on babel_2843_t1 (cost=0.00..19.11 rows=4 width=8) (actual rows=0 loops=1) Filter: (b1 = 1) ~~END~~ @@ -78,7 +78,7 @@ int#!#int ~~START~~ xml - select * from babel_2843_t1 where b1 = 1 Gather false false 0.00 19.11 11 8 0 1 3 3 false Seq Scan Outer true false babel_2843_t1 babel_2843_t1 0.00 19.11 4 8 0 4 (b1 = 1) 0 + select * from babel_2843_t1 where b1 = 1 Gather false false 0.00 19.11 11 8 0 1 3 0 false Seq Scan Outer true false babel_2843_t1 babel_2843_t1 0.00 19.11 4 8 0 1 (b1 = 1) 0 ~~END~~ @@ -103,7 +103,7 @@ int#!#int ~~START~~ text -{ "Query Text": "select * from babel_2843_t1 where b1 = 1", "Plan": { "Node Type": "Gather", "Parallel Aware": false, "Async Capable": false, "Startup Cost": 0.00, "Total Cost": 19.11, "Plan Rows": 11, "Plan Width": 8, "Actual Rows": 0, "Actual Loops": 1, "Workers Planned": 3, "Workers Launched": 3, "Single Copy": false, "Plans": [ { "Node Type": "Seq Scan", "Parent Relationship": "Outer", "Parallel Aware": true, "Async Capable": false, "Relation Name": "babel_2843_t1", "Alias": "babel_2843_t1", "Startup Cost": 0.00, "Total Cost": 19.11, "Plan Rows": 4, "Plan Width": 8, "Actual Rows": 0, "Actual Loops": 4, "Filter": "(b1 = 1)", "Rows Removed by Filter": 0, "Workers": [ ] } ] }, "Triggers": [ ]} +{ "Query Text": "select * from babel_2843_t1 where b1 = 1", "Plan": { "Node Type": "Gather", "Parallel Aware": false, "Async Capable": false, "Startup Cost": 0.00, "Total Cost": 19.11, "Plan Rows": 11, "Plan Width": 8, "Actual Rows": 0, "Actual Loops": 1, "Workers Planned": 3, "Workers Launched": 0, "Single Copy": false, "Plans": [ { "Node Type": "Seq Scan", "Parent Relationship": "Outer", "Parallel Aware": true, "Async Capable": false, "Relation Name": "babel_2843_t1", "Alias": "babel_2843_t1", "Startup Cost": 0.00, "Total Cost": 19.11, "Plan Rows": 4, "Plan Width": 8, "Actual Rows": 0, "Actual Loops": 1, "Filter": "(b1 = 1)", "Rows Removed by Filter": 0 } ] }, "Triggers": [ ]} ~~END~~ @@ -128,7 +128,7 @@ int#!#int ~~START~~ text -Query Text: "select * from babel_2843_t1 where b1 = 1"Plan: Node Type: "Gather" Parallel Aware: false Async Capable: false Startup Cost: 0.00 Total Cost: 19.11 Plan Rows: 11 Plan Width: 8 Actual Rows: 0 Actual Loops: 1 Workers Planned: 3 Workers Launched: 3 Single Copy: false Plans: - Node Type: "Seq Scan" Parent Relationship: "Outer" Parallel Aware: true Async Capable: false Relation Name: "babel_2843_t1" Alias: "babel_2843_t1" Startup Cost: 0.00 Total Cost: 19.11 Plan Rows: 4 Plan Width: 8 Actual Rows: 0 Actual Loops: 4 Filter: "(b1 = 1)" Rows Removed by Filter: 0 Workers: Triggers: +Query Text: "select * from babel_2843_t1 where b1 = 1"Plan: Node Type: "Gather" Parallel Aware: false Async Capable: false Startup Cost: 0.00 Total Cost: 19.11 Plan Rows: 11 Plan Width: 8 Actual Rows: 0 Actual Loops: 1 Workers Planned: 3 Workers Launched: 0 Single Copy: false Plans: - Node Type: "Seq Scan" Parent Relationship: "Outer" Parallel Aware: true Async Capable: false Relation Name: "babel_2843_t1" Alias: "babel_2843_t1" Startup Cost: 0.00 Total Cost: 19.11 Plan Rows: 4 Plan Width: 8 Actual Rows: 0 Actual Loops: 1 Filter: "(b1 = 1)" Rows Removed by Filter: 0Triggers: ~~END~~ @@ -193,8 +193,8 @@ text Query Text: select * from babel_2843_t1 Gather (cost=0.00..17.29 rows=2260 width=8) (actual rows=2 loops=1) Workers Planned: 3 - Workers Launched: 3 - -> Parallel Seq Scan on babel_2843_t1 (cost=0.00..17.29 rows=729 width=8) (actual rows=0 loops=4) + Workers Launched: 0 + -> Parallel Seq Scan on babel_2843_t1 (cost=0.00..17.29 rows=729 width=8) (actual rows=2 loops=1) ~~END~~ ~~START~~ @@ -207,8 +207,8 @@ text Query Text: select * from babel_2843_t2 Gather (cost=0.00..17.29 rows=2260 width=8) (actual rows=1 loops=1) Workers Planned: 3 - Workers Launched: 3 - -> Parallel Seq Scan on babel_2843_t2 (cost=0.00..17.29 rows=729 width=8) (actual rows=0 loops=4) + Workers Launched: 0 + -> Parallel Seq Scan on babel_2843_t2 (cost=0.00..17.29 rows=729 width=8) (actual rows=1 loops=1) ~~END~~ @@ -239,10 +239,10 @@ text Query Text: select * from babel_2843_t1 where a1 = "@param" Gather (cost=0.00..19.11 rows=11 width=8) (actual rows=1 loops=1) Workers Planned: 3 - Workers Launched: 3 - -> Parallel Seq Scan on babel_2843_t1 (cost=0.00..19.11 rows=4 width=8) (actual rows=0 loops=4) + Workers Launched: 0 + -> Parallel Seq Scan on babel_2843_t1 (cost=0.00..19.11 rows=4 width=8) (actual rows=1 loops=1) Filter: (a1 = 1) - Rows Removed by Filter: 0 + Rows Removed by Filter: 2 ~~END~~ drop procedure babel_2843_proc; @@ -362,7 +362,7 @@ text Query Text: select 1 Gather (cost=0.00..0.01 rows=1 width=4) (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Result (cost=0.00..0.01 rows=1 width=4) (actual rows=1 loops=1) ~~END~~ @@ -388,10 +388,10 @@ text Query Text: select * from babel_2843_t1 where a1 = "@param" Gather (cost=0.00..19.11 rows=11 width=8) (actual rows=1 loops=1) Workers Planned: 3 - Workers Launched: 3 - -> Parallel Seq Scan on babel_2843_t1 (cost=0.00..19.11 rows=4 width=8) (actual rows=0 loops=4) + Workers Launched: 0 + -> Parallel Seq Scan on babel_2843_t1 (cost=0.00..19.11 rows=4 width=8) (actual rows=1 loops=1) Filter: (a1 = 2) - Rows Removed by Filter: 0 + Rows Removed by Filter: 2 ~~END~~ diff --git a/test/JDBC/expected/parallel_query/BABEL-3248.out b/test/JDBC/expected/parallel_query/BABEL-3248.out index b72dce8754..03426fdfd4 100644 --- a/test/JDBC/expected/parallel_query/BABEL-3248.out +++ b/test/JDBC/expected/parallel_query/BABEL-3248.out @@ -84,7 +84,7 @@ text Query Text: select 1 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Result (actual rows=1 loops=1) ~~END~~ diff --git a/test/JDBC/expected/parallel_query/BABEL_3571.out b/test/JDBC/expected/parallel_query/BABEL_3571.out index 736f7e4274..ca56a8337e 100644 --- a/test/JDBC/expected/parallel_query/BABEL_3571.out +++ b/test/JDBC/expected/parallel_query/BABEL_3571.out @@ -221,7 +221,7 @@ text Query Text: SELECT * FROM babel_3571_1 ORDER BY id1 Gather (actual rows=5 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using babel_3571_1_id1_key on babel_3571_1 (actual rows=5 loops=1) ~~END~~ @@ -242,7 +242,7 @@ text Query Text: SELECT * FROM babel_3571_2 ORDER BY id1 Gather (actual rows=5 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using babel_3571_2_id1_id2_key on babel_3571_2 (actual rows=5 loops=1) ~~END~~ @@ -263,7 +263,7 @@ text Query Text: SELECT * FROM babel_3571_3 ORDER BY id1 Gather (actual rows=5 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using babel_3571_3_unique_idxbabel_35df79da2a42216884edca5a4a798829ce on babel_3571_3 (actual rows=5 loops=1) ~~END~~ @@ -481,7 +481,7 @@ text Query Text: SELECT * FROM babel_3571_1 ORDER BY id1 Gather (actual rows=5 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using babel_3571_1_id1_key on babel_3571_1 (actual rows=5 loops=1) ~~END~~ @@ -502,7 +502,7 @@ text Query Text: SELECT * FROM babel_3571_2 ORDER BY id1 Gather (actual rows=5 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using babel_3571_2_id1_id2_key on babel_3571_2 (actual rows=5 loops=1) ~~END~~ @@ -524,7 +524,7 @@ text Query Text: SELECT * FROM babel_3571_3 ORDER BY id1 Gather (actual rows=6 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan Backward using babel_3571_3_unique_idx on babel_3571_3 (actual rows=6 loops=1) ~~END~~ @@ -790,7 +790,7 @@ text Query Text: SELECT * FROM babel_3571_1 ORDER BY id1 Gather (actual rows=5 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using babel_3571_1_id1_key on babel_3571_1 (actual rows=5 loops=1) ~~END~~ @@ -811,7 +811,7 @@ text Query Text: SELECT * FROM babel_3571_2 ORDER BY id1 Gather (actual rows=5 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using babel_3571_2_id1_key on babel_3571_2 (actual rows=5 loops=1) ~~END~~ @@ -832,7 +832,7 @@ text Query Text: SELECT * FROM babel_3571_3 ORDER BY id1 Gather (actual rows=5 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using babel_3571_3_unique_idxbabel_35df79da2a42216884edca5a4a798829ce on babel_3571_3 (actual rows=5 loops=1) ~~END~~ diff --git a/test/JDBC/expected/parallel_query/BABEL_4940.out b/test/JDBC/expected/parallel_query/BABEL_4940.out index e2cc1eebb5..b3aed755a5 100644 --- a/test/JDBC/expected/parallel_query/BABEL_4940.out +++ b/test/JDBC/expected/parallel_query/BABEL_4940.out @@ -117,7 +117,7 @@ text Query Text: SELECT TOP 10 * FROM babel_4940_t1 ORDER BY id Gather (actual rows=10 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Limit (actual rows=10 loops=1) -> Index Scan using babel_4940_t1_pkey on babel_4940_t1 (actual rows=10 loops=1) @@ -144,7 +144,7 @@ text Query Text: SELECT TOP 10 * FROM babel_4940_t1 ORDER BY id DESC Gather (actual rows=10 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Limit (actual rows=10 loops=1) -> Index Scan Backward using babel_4940_t1_pkey on babel_4940_t1 (actual rows=10 loops=1) @@ -171,7 +171,7 @@ text Query Text: SELECT TOP 10 * FROM babel_4940_t2 ORDER BY id Gather (actual rows=10 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Limit (actual rows=10 loops=1) -> Index Scan using babel_4940_t2_pkey on babel_4940_t2 (actual rows=10 loops=1) @@ -198,7 +198,7 @@ text Query Text: SELECT TOP 10 * FROM babel_4940_t2 ORDER BY id DESC Gather (actual rows=10 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Limit (actual rows=10 loops=1) -> Index Scan Backward using babel_4940_t2_pkey on babel_4940_t2 (actual rows=10 loops=1) @@ -225,7 +225,7 @@ text Query Text: SELECT TOP 10 * FROM babel_4940_t3 ORDER BY id, id1 Gather (actual rows=10 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Limit (actual rows=10 loops=1) -> Index Scan using babel_4940_t3_pkey on babel_4940_t3 (actual rows=10 loops=1) @@ -252,7 +252,7 @@ text Query Text: SELECT TOP 10 * FROM babel_4940_t3 ORDER BY id DESC, id1 DESC Gather (actual rows=10 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Limit (actual rows=10 loops=1) -> Index Scan Backward using babel_4940_t3_pkey on babel_4940_t3 (actual rows=10 loops=1) @@ -279,7 +279,7 @@ text Query Text: SELECT TOP 10 * FROM babel_4940_t4 ORDER BY id Gather (actual rows=10 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Limit (actual rows=10 loops=1) -> Index Scan using babel_4940_t4_pkey on babel_4940_t4 (actual rows=10 loops=1) @@ -306,7 +306,7 @@ text Query Text: SELECT TOP 10 * FROM babel_4940_t4 ORDER BY id DESC Gather (actual rows=10 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Limit (actual rows=10 loops=1) -> Index Scan Backward using babel_4940_t4_pkey on babel_4940_t4 (actual rows=10 loops=1) @@ -333,7 +333,7 @@ text Query Text: SELECT TOP 10 * FROM babel_4940_t5 ORDER BY id Gather (actual rows=10 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Limit (actual rows=10 loops=1) -> Index Scan using c on babel_4940_t5 (actual rows=10 loops=1) @@ -360,7 +360,7 @@ text Query Text: SELECT TOP 10 * FROM babel_4940_t5 ORDER BY id DESC Gather (actual rows=10 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Limit (actual rows=10 loops=1) -> Index Scan Backward using c on babel_4940_t5 (actual rows=10 loops=1) @@ -387,7 +387,7 @@ text Query Text: SELECT TOP 10 * FROM babel_4940_t6 ORDER BY id, id1 DESC Gather (actual rows=10 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Limit (actual rows=10 loops=1) -> Index Scan using c1 on babel_4940_t6 (actual rows=10 loops=1) @@ -414,7 +414,7 @@ text Query Text: SELECT TOP 10 * FROM babel_4940_t6 ORDER BY id DESC, id1 ASC Gather (actual rows=10 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Limit (actual rows=10 loops=1) -> Index Scan Backward using c1 on babel_4940_t6 (actual rows=10 loops=1) diff --git a/test/JDBC/expected/parallel_query/TestHalfvecDatatype.out b/test/JDBC/expected/parallel_query/TestHalfvecDatatype.out index 82d2db25c5..fd42d6f139 100644 --- a/test/JDBC/expected/parallel_query/TestHalfvecDatatype.out +++ b/test/JDBC/expected/parallel_query/TestHalfvecDatatype.out @@ -966,7 +966,7 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <-> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=4 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=4 loops=1) Order By: (val <-> '[3,3,3]'::halfvec) @@ -985,7 +985,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <-> (SELECT CAST(NULL as halfvec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=4 loops=1) @@ -1007,7 +1007,7 @@ text Query Text: SELECT COUNT(*) FROM halfvec_table Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Seq Scan on halfvec_table (actual rows=5 loops=1) @@ -1028,7 +1028,7 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <-> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=0 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=0 loops=1) Order By: (val <-> '[3,3,3]'::halfvec) @@ -1091,7 +1091,7 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <#> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=4 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=4 loops=1) Order By: (val <#> '[3,3,3]'::halfvec) @@ -1110,7 +1110,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <#> (SELECT CAST(NULL as halfvec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=4 loops=1) @@ -1175,7 +1175,7 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <=> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=3 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=3 loops=1) Order By: (val <=> '[3,3,3]'::halfvec) @@ -1194,7 +1194,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <=> CAST('[0,0,0]' AS halfvec) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=3 loops=1) @@ -1214,7 +1214,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <=> (SELECT CAST(NULL as halfvec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=3 loops=1) @@ -1280,7 +1280,7 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <+> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=4 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=4 loops=1) Order By: (val <+> '[3,3,3]'::halfvec) @@ -1299,7 +1299,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <+> (SELECT CAST(NULL as halfvec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=4 loops=1) @@ -1365,7 +1365,7 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <-> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=4 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=4 loops=1) Order By: (val <-> '[3,3,3]'::halfvec) @@ -1384,7 +1384,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <-> (SELECT CAST(NULL as halfvec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=4 loops=1) @@ -1406,7 +1406,7 @@ text Query Text: SELECT COUNT(*) FROM halfvec_table Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Seq Scan on halfvec_table (actual rows=5 loops=1) @@ -1427,7 +1427,7 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <-> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=0 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=0 loops=1) Order By: (val <-> '[3,3,3]'::halfvec) @@ -1495,11 +1495,11 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <#> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=5 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Sort (actual rows=5 loops=1) Sort Key: ((val <#> '[3,3,3]'::halfvec)) - Worker 0: Sort Method: quicksort Memory: 25kB + Sort Method: quicksort Memory: 25kB -> Seq Scan on halfvec_table (actual rows=5 loops=1) ~~END~~ @@ -1516,12 +1516,12 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <#> (SELECT CAST(NULL as halfvec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Sort (actual rows=5 loops=1) Sort Key: ((halfvec_table.val <#> (InitPlan 1).col1)) - Worker 0: Sort Method: quicksort Memory: 25kB + Sort Method: quicksort Memory: 25kB InitPlan 1 -> Result (actual rows=1 loops=1) -> Seq Scan on halfvec_table (actual rows=5 loops=1) @@ -1583,7 +1583,7 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <=> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=3 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=3 loops=1) Order By: (val <=> '[3,3,3]'::halfvec) @@ -1602,7 +1602,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <=> CAST('[0,0,0]' AS halfvec) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=3 loops=1) @@ -1622,7 +1622,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <=> (SELECT CAST(NULL as halfvec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=3 loops=1) @@ -2786,7 +2786,7 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <-> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=4 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=4 loops=1) Order By: (val <-> '[3,3,3]'::halfvec) @@ -2805,7 +2805,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <-> (SELECT CAST(NULL as halfvec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=4 loops=1) @@ -2827,7 +2827,7 @@ text Query Text: SELECT COUNT(*) FROM halfvec_table Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Seq Scan on halfvec_table (actual rows=5 loops=1) @@ -2848,7 +2848,7 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <-> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=0 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=0 loops=1) Order By: (val <-> '[3,3,3]'::halfvec) @@ -2911,7 +2911,7 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <#> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=4 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=4 loops=1) Order By: (val <#> '[3,3,3]'::halfvec) @@ -2930,7 +2930,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <#> (SELECT CAST(NULL as halfvec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=4 loops=1) @@ -2995,7 +2995,7 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <=> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=3 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=3 loops=1) Order By: (val <=> '[3,3,3]'::halfvec) @@ -3014,7 +3014,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <=> CAST('[0,0,0]' AS halfvec) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=3 loops=1) @@ -3034,7 +3034,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <=> (SELECT CAST(NULL as halfvec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=3 loops=1) @@ -3100,7 +3100,7 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <+> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=4 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=4 loops=1) Order By: (val <+> '[3,3,3]'::halfvec) @@ -3119,7 +3119,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <+> (SELECT CAST(NULL as halfvec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=4 loops=1) @@ -3185,7 +3185,7 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <-> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=4 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=4 loops=1) Order By: (val <-> '[3,3,3]'::halfvec) @@ -3204,7 +3204,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <-> (SELECT CAST(NULL as halfvec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=4 loops=1) @@ -3226,7 +3226,7 @@ text Query Text: SELECT COUNT(*) FROM halfvec_table Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Seq Scan on halfvec_table (actual rows=5 loops=1) @@ -3247,7 +3247,7 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <-> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=0 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=0 loops=1) Order By: (val <-> '[3,3,3]'::halfvec) @@ -3315,11 +3315,11 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <#> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=5 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Sort (actual rows=5 loops=1) Sort Key: ((val <#> '[3,3,3]'::halfvec)) - Worker 0: Sort Method: quicksort Memory: 25kB + Sort Method: quicksort Memory: 25kB -> Seq Scan on halfvec_table (actual rows=5 loops=1) ~~END~~ @@ -3336,12 +3336,12 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <#> (SELECT CAST(NULL as halfvec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Sort (actual rows=5 loops=1) Sort Key: ((halfvec_table.val <#> (InitPlan 1).col1)) - Worker 0: Sort Method: quicksort Memory: 25kB + Sort Method: quicksort Memory: 25kB InitPlan 1 -> Result (actual rows=1 loops=1) -> Seq Scan on halfvec_table (actual rows=5 loops=1) @@ -3403,7 +3403,7 @@ text Query Text: SELECT * FROM halfvec_table ORDER BY val <=> CAST('[3,3,3]' AS halfvec) NULLS LAST Gather (actual rows=3 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=3 loops=1) Order By: (val <=> '[3,3,3]'::halfvec) @@ -3422,7 +3422,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <=> CAST('[0,0,0]' AS halfvec) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=3 loops=1) @@ -3442,7 +3442,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM halfvec_table ORDER BY val <=> (SELECT CAST(NULL as halfvec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxhalfvec_table7f9bec28bc8902d45d905788d7aa59a1 on halfvec_table (actual rows=3 loops=1) diff --git a/test/JDBC/expected/parallel_query/TestSparsevecDatatype.out b/test/JDBC/expected/parallel_query/TestSparsevecDatatype.out index 35d8e7b133..b8132870c5 100644 --- a/test/JDBC/expected/parallel_query/TestSparsevecDatatype.out +++ b/test/JDBC/expected/parallel_query/TestSparsevecDatatype.out @@ -1049,7 +1049,7 @@ text Query Text: SELECT * FROM sparsevec_table ORDER BY val <-> CAST('{1:3,2:3,3:3}/3' AS sparsevec) NULLS LAST Gather (actual rows=4 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxsparsevec_table7f9bec28bc8902d45d905788d7aa59a1 on sparsevec_table (actual rows=4 loops=1) Order By: (val <-> '{1:3,2:3,3:3}/3'::sparsevec) @@ -1068,7 +1068,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM sparsevec_table ORDER BY val <-> (SELECT CAST(NULL as sparsevec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxsparsevec_table7f9bec28bc8902d45d905788d7aa59a1 on sparsevec_table (actual rows=4 loops=1) @@ -1090,7 +1090,7 @@ text Query Text: SELECT COUNT(*) FROM sparsevec_table Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Seq Scan on sparsevec_table (actual rows=5 loops=1) @@ -1111,7 +1111,7 @@ text Query Text: SELECT * FROM sparsevec_table ORDER BY val <-> CAST('{1:3,2:3,3:3}/3' AS sparsevec) NULLS LAST Gather (actual rows=0 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxsparsevec_table7f9bec28bc8902d45d905788d7aa59a1 on sparsevec_table (actual rows=0 loops=1) Order By: (val <-> '{1:3,2:3,3:3}/3'::sparsevec) @@ -1174,7 +1174,7 @@ text Query Text: SELECT * FROM sparsevec_table ORDER BY val <#> CAST('{1:3,2:3,3:3}/3' AS sparsevec) NULLS LAST Gather (actual rows=4 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxsparsevec_table7f9bec28bc8902d45d905788d7aa59a1 on sparsevec_table (actual rows=4 loops=1) Order By: (val <#> '{1:3,2:3,3:3}/3'::sparsevec) @@ -1193,7 +1193,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM sparsevec_table ORDER BY val <#> (SELECT CAST(NULL as sparsevec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxsparsevec_table7f9bec28bc8902d45d905788d7aa59a1 on sparsevec_table (actual rows=4 loops=1) @@ -1258,7 +1258,7 @@ text Query Text: SELECT * FROM sparsevec_table ORDER BY val <=> CAST('{1:3,2:3,3:3}/3' AS sparsevec) NULLS LAST Gather (actual rows=3 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxsparsevec_table7f9bec28bc8902d45d905788d7aa59a1 on sparsevec_table (actual rows=3 loops=1) Order By: (val <=> '{1:3,2:3,3:3}/3'::sparsevec) @@ -1277,7 +1277,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM sparsevec_table ORDER BY val <=> CAST('{}/3' AS sparsevec) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxsparsevec_table7f9bec28bc8902d45d905788d7aa59a1 on sparsevec_table (actual rows=3 loops=1) @@ -1297,7 +1297,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM sparsevec_table ORDER BY val <=> (SELECT CAST(NULL as sparsevec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxsparsevec_table7f9bec28bc8902d45d905788d7aa59a1 on sparsevec_table (actual rows=3 loops=1) @@ -1363,7 +1363,7 @@ text Query Text: SELECT * FROM sparsevec_table ORDER BY val <+> CAST('{1:3,2:3,3:3}/3' AS sparsevec) NULLS LAST Gather (actual rows=4 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxsparsevec_table7f9bec28bc8902d45d905788d7aa59a1 on sparsevec_table (actual rows=4 loops=1) Order By: (val <+> '{1:3,2:3,3:3}/3'::sparsevec) @@ -1382,7 +1382,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM sparsevec_table ORDER BY val <+> (SELECT CAST(NULL as sparsevec)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxsparsevec_table7f9bec28bc8902d45d905788d7aa59a1 on sparsevec_table (actual rows=4 loops=1) diff --git a/test/JDBC/expected/parallel_query/TestVectorDatatype.out b/test/JDBC/expected/parallel_query/TestVectorDatatype.out index 6f74160ba0..ee396bd928 100644 --- a/test/JDBC/expected/parallel_query/TestVectorDatatype.out +++ b/test/JDBC/expected/parallel_query/TestVectorDatatype.out @@ -401,7 +401,7 @@ text Query Text: SELECT * FROM vector_table WHERE val = '[1,2,3]' Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Only Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=1 loops=1) Index Cond: (val = '[1,2,3]'::vector) @@ -421,7 +421,7 @@ text Query Text: SELECT TOP 1 * FROM vector_table ORDER BY val Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Limit (actual rows=1 loops=1) -> Index Only Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=1 loops=1) @@ -478,7 +478,7 @@ text Query Text: SELECT * FROM vector_table ORDER BY val <=> '[3,3,3]' NULLS LAST Gather (actual rows=2 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=2 loops=1) Order By: (val <=> '[3,3,3]'::vector) @@ -497,7 +497,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <=> '[0,0,0]' NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=2 loops=1) @@ -516,7 +516,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <=> (SELECT CAST(NULL as vector)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=2 loops=1) @@ -576,7 +576,7 @@ text Query Text: SELECT * FROM vector_table ORDER BY val <#> '[3,3,3]' NULLS LAST Gather (actual rows=3 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) Order By: (val <#> '[3,3,3]'::vector) @@ -595,7 +595,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <#> '[0,0,0]' NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) @@ -614,7 +614,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <#> (SELECT CAST(NULL as vector)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) @@ -674,7 +674,7 @@ text Query Text: SELECT * FROM vector_table ORDER BY val <-> '[3,3,3]' NULLS LAST Gather (actual rows=3 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) Order By: (val <-> '[3,3,3]'::vector) @@ -693,7 +693,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <-> '[0,0,0]' NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) @@ -712,7 +712,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <-> (SELECT CAST(NULL as vector)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) @@ -845,7 +845,7 @@ text Query Text: SELECT * FROM vector_table ORDER BY val <=> '[3,3,3]' NULLS LAST Gather (actual rows=3 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) Order By: (val <=> '[3,3,3]'::vector) @@ -864,7 +864,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <=> '[0,0,0]' NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) @@ -884,7 +884,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <=> (SELECT CAST(NULL as vector)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) @@ -950,7 +950,7 @@ text Query Text: SELECT * FROM vector_table ORDER BY val <#> '[3,3,3]' NULLS LAST Gather (actual rows=4 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idx2vector_table8408d573e4ed8cfc5bc30f15b5393f14 on vector_table (actual rows=4 loops=1) Order By: (val <#> '[3,3,3]'::vector) @@ -969,7 +969,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <#> '[0,0,0]' NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idx2vector_table8408d573e4ed8cfc5bc30f15b5393f14 on vector_table (actual rows=4 loops=1) @@ -989,7 +989,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <#> (SELECT CAST(NULL as vector)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idx2vector_table8408d573e4ed8cfc5bc30f15b5393f14 on vector_table (actual rows=4 loops=1) @@ -1055,7 +1055,7 @@ text Query Text: SELECT * FROM vector_table ORDER BY val <-> '[3,3,3]' NULLS LAST Gather (actual rows=4 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=4 loops=1) Order By: (val <-> '[3,3,3]'::vector) @@ -1074,7 +1074,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <-> '[0,0,0]' NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=4 loops=1) @@ -1094,7 +1094,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <-> (SELECT CAST(NULL as vector)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=4 loops=1) @@ -1375,7 +1375,7 @@ text Query Text: SELECT * FROM vector_table1 ORDER BY val <=> '[3,3,3]' NULLS LAST Gather (actual rows=0 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxvector_table17f9bec28bc8902d45d905788d7aa59a1 on vector_table1 (actual rows=0 loops=1) Order By: (val <=> '[3,3,3]'::vector) @@ -1394,7 +1394,7 @@ text Query Text: SELECT t1.*, t2.* FROM vector_table1 as t1 JOIN vector_table2 as t2 ON t1.a = t2.a ORDER BY t1.val <=> '[0,0,0]' NULLS LAST Gather (actual rows=0 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Nested Loop (actual rows=0 loops=1) Join Filter: (t1.a = t2.a) @@ -1417,19 +1417,15 @@ text Query Text: SELECT t1.* FROM vector_table1 as t1 JOIN vector_table2 as t2 ON t1.a = t2.a ORDER BY t1.val <=> '[0,0,0]', t2.val <=> '[1,1,1]' Gather Merge (actual rows=0 loops=1) Workers Planned: 3 - Workers Launched: 3 - -> Sort (actual rows=0 loops=4) + Workers Launched: 0 + -> Sort (actual rows=0 loops=1) Sort Key: ((t1.val <=> '[0,0,0]'::vector)) NULLS FIRST, ((t2.val <=> '[1,1,1]'::vector)) NULLS FIRST Sort Method: quicksort Memory: 25kB - Worker 0: Sort Method: quicksort Memory: 25kB - Worker 1: Sort Method: quicksort Memory: 25kB - Worker 2: Sort Method: quicksort Memory: 25kB - -> Parallel Hash Join (actual rows=0 loops=4) + -> Parallel Hash Join (actual rows=0 loops=1) Hash Cond: (t1.a = t2.a) - -> Parallel Seq Scan on vector_table1 t1 (never executed) - -> Parallel Hash (actual rows=0 loops=4) - Buckets: 2048 Batches: 1 Memory Usage: 0kB - -> Parallel Seq Scan on vector_table2 t2 (actual rows=0 loops=1) + -> Parallel Seq Scan on vector_table1 t1 (actual rows=0 loops=1) + -> Parallel Hash (never executed) + -> Parallel Seq Scan on vector_table2 t2 (never executed) ~~END~~ @@ -1444,7 +1440,7 @@ text Query Text: SELECT t1.* FROM vector_table1 as t1 JOIN table3 as t2 ON t1.a = t2.a ORDER BY val <=> '[0,0,0]' NULLS LAST Gather (actual rows=0 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Nested Loop (actual rows=0 loops=1) Join Filter: (t1.a = t2.a) @@ -1466,16 +1462,16 @@ text Query Text: SELECT t1.* FROM vector_table1 as t1 JOIN table3 as t2 ON t1.a = t2.a ORDER BY val <=> '[0,0,0]', t2.a Gather (actual rows=0 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Sort (actual rows=0 loops=1) Sort Key: ((t1.val <=> '[0,0,0]'::vector)) NULLS FIRST, t1.a NULLS FIRST - Worker 0: Sort Method: quicksort Memory: 25kB + Sort Method: quicksort Memory: 25kB -> Merge Join (actual rows=0 loops=1) Merge Cond: (t1.a = t2.a) -> Sort (actual rows=0 loops=1) Sort Key: t1.a - Worker 0: Sort Method: quicksort Memory: 25kB + Sort Method: quicksort Memory: 25kB -> Seq Scan on vector_table1 t1 (actual rows=0 loops=1) -> Sort (never executed) Sort Key: t2.a @@ -2072,7 +2068,7 @@ text Query Text: SELECT * FROM vector_table WHERE val = '[1,2,3]' Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Only Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=1 loops=1) Index Cond: (val = '[1,2,3]'::vector) @@ -2092,7 +2088,7 @@ text Query Text: SELECT TOP 1 * FROM vector_table ORDER BY val Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Limit (actual rows=1 loops=1) -> Index Only Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=1 loops=1) @@ -2149,7 +2145,7 @@ text Query Text: SELECT * FROM vector_table ORDER BY val <=> '[3,3,3]' NULLS LAST Gather (actual rows=2 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=2 loops=1) Order By: (val <=> '[3,3,3]'::vector) @@ -2168,7 +2164,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <=> '[0,0,0]' NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=2 loops=1) @@ -2187,7 +2183,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <=> (SELECT CAST(NULL as vector)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=2 loops=1) @@ -2247,7 +2243,7 @@ text Query Text: SELECT * FROM vector_table ORDER BY val <#> '[3,3,3]' NULLS LAST Gather (actual rows=3 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) Order By: (val <#> '[3,3,3]'::vector) @@ -2266,7 +2262,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <#> '[0,0,0]' NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) @@ -2285,7 +2281,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <#> (SELECT CAST(NULL as vector)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) @@ -2345,7 +2341,7 @@ text Query Text: SELECT * FROM vector_table ORDER BY val <-> '[3,3,3]' NULLS LAST Gather (actual rows=3 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) Order By: (val <-> '[3,3,3]'::vector) @@ -2364,7 +2360,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <-> '[0,0,0]' NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) @@ -2383,7 +2379,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <-> (SELECT CAST(NULL as vector)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) @@ -2516,7 +2512,7 @@ text Query Text: SELECT * FROM vector_table ORDER BY val <=> '[3,3,3]' NULLS LAST Gather (actual rows=3 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) Order By: (val <=> '[3,3,3]'::vector) @@ -2535,7 +2531,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <=> '[0,0,0]' NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) @@ -2555,7 +2551,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <=> (SELECT CAST(NULL as vector)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=3 loops=1) @@ -2621,7 +2617,7 @@ text Query Text: SELECT * FROM vector_table ORDER BY val <#> '[3,3,3]' NULLS LAST Gather (actual rows=4 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idx2vector_table8408d573e4ed8cfc5bc30f15b5393f14 on vector_table (actual rows=4 loops=1) Order By: (val <#> '[3,3,3]'::vector) @@ -2640,7 +2636,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <#> '[0,0,0]' NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idx2vector_table8408d573e4ed8cfc5bc30f15b5393f14 on vector_table (actual rows=4 loops=1) @@ -2660,7 +2656,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <#> (SELECT CAST(NULL as vector)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idx2vector_table8408d573e4ed8cfc5bc30f15b5393f14 on vector_table (actual rows=4 loops=1) @@ -2726,7 +2722,7 @@ text Query Text: SELECT * FROM vector_table ORDER BY val <-> '[3,3,3]' NULLS LAST Gather (actual rows=4 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=4 loops=1) Order By: (val <-> '[3,3,3]'::vector) @@ -2745,7 +2741,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <-> '[0,0,0]' NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=4 loops=1) @@ -2765,7 +2761,7 @@ text Query Text: SELECT COUNT(*) FROM (SELECT * FROM vector_table ORDER BY val <-> (SELECT CAST(NULL as vector)) NULLS LAST) t2 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Aggregate (actual rows=1 loops=1) -> Index Scan using idxvector_table7f9bec28bc8902d45d905788d7aa59a1 on vector_table (actual rows=4 loops=1) @@ -3046,7 +3042,7 @@ text Query Text: SELECT * FROM vector_table1 ORDER BY val <=> '[3,3,3]' NULLS LAST Gather (actual rows=0 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using idxvector_table17f9bec28bc8902d45d905788d7aa59a1 on vector_table1 (actual rows=0 loops=1) Order By: (val <=> '[3,3,3]'::vector) @@ -3065,7 +3061,7 @@ text Query Text: SELECT t1.*, t2.* FROM vector_table1 as t1 JOIN vector_table2 as t2 ON t1.a = t2.a ORDER BY t1.val <=> '[0,0,0]' NULLS LAST Gather (actual rows=0 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Nested Loop (actual rows=0 loops=1) Join Filter: (t1.a = t2.a) @@ -3088,19 +3084,15 @@ text Query Text: SELECT t1.* FROM vector_table1 as t1 JOIN vector_table2 as t2 ON t1.a = t2.a ORDER BY t1.val <=> '[0,0,0]', t2.val <=> '[1,1,1]' Gather Merge (actual rows=0 loops=1) Workers Planned: 3 - Workers Launched: 3 - -> Sort (actual rows=0 loops=4) + Workers Launched: 0 + -> Sort (actual rows=0 loops=1) Sort Key: ((t1.val <=> '[0,0,0]'::vector)) NULLS FIRST, ((t2.val <=> '[1,1,1]'::vector)) NULLS FIRST Sort Method: quicksort Memory: 25kB - Worker 0: Sort Method: quicksort Memory: 25kB - Worker 1: Sort Method: quicksort Memory: 25kB - Worker 2: Sort Method: quicksort Memory: 25kB - -> Parallel Hash Join (actual rows=0 loops=4) + -> Parallel Hash Join (actual rows=0 loops=1) Hash Cond: (t1.a = t2.a) - -> Parallel Seq Scan on vector_table1 t1 (never executed) - -> Parallel Hash (actual rows=0 loops=4) - Buckets: 2048 Batches: 1 Memory Usage: 0kB - -> Parallel Seq Scan on vector_table2 t2 (actual rows=0 loops=1) + -> Parallel Seq Scan on vector_table1 t1 (actual rows=0 loops=1) + -> Parallel Hash (never executed) + -> Parallel Seq Scan on vector_table2 t2 (never executed) ~~END~~ @@ -3115,7 +3107,7 @@ text Query Text: SELECT t1.* FROM vector_table1 as t1 JOIN table3 as t2 ON t1.a = t2.a ORDER BY val <=> '[0,0,0]' NULLS LAST Gather (actual rows=0 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Nested Loop (actual rows=0 loops=1) Join Filter: (t1.a = t2.a) @@ -3137,16 +3129,16 @@ text Query Text: SELECT t1.* FROM vector_table1 as t1 JOIN table3 as t2 ON t1.a = t2.a ORDER BY val <=> '[0,0,0]', t2.a Gather (actual rows=0 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Sort (actual rows=0 loops=1) Sort Key: ((t1.val <=> '[0,0,0]'::vector)) NULLS FIRST, t1.a NULLS FIRST - Worker 0: Sort Method: quicksort Memory: 25kB + Sort Method: quicksort Memory: 25kB -> Merge Join (actual rows=0 loops=1) Merge Cond: (t1.a = t2.a) -> Sort (actual rows=0 loops=1) Sort Key: t1.a - Worker 0: Sort Method: quicksort Memory: 25kB + Sort Method: quicksort Memory: 25kB -> Seq Scan on vector_table1 t1 (actual rows=0 loops=1) -> Sort (never executed) Sort Key: t2.a diff --git a/test/JDBC/expected/parallel_query/babel_collection.out b/test/JDBC/expected/parallel_query/babel_collection.out index 37712f8dde..625126286e 100644 --- a/test/JDBC/expected/parallel_query/babel_collection.out +++ b/test/JDBC/expected/parallel_query/babel_collection.out @@ -192,7 +192,7 @@ Gather (cost=11.40..24.02 rows=3 width=32) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 8.108 ms +Babelfish T-SQL Batch Parsing Time: 0.140 ms ~~END~~ @@ -210,7 +210,7 @@ Gather (cost=11.40..25.07 rows=1 width=32) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.179 ms +Babelfish T-SQL Batch Parsing Time: 0.096 ms ~~END~~ @@ -228,7 +228,7 @@ Gather (cost=11.40..25.07 rows=1 width=32) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.137 ms +Babelfish T-SQL Batch Parsing Time: 0.114 ms ~~END~~ @@ -246,7 +246,7 @@ Gather (cost=11.40..24.02 rows=5 width=32) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.131 ms +Babelfish T-SQL Batch Parsing Time: 0.092 ms ~~END~~ @@ -264,7 +264,7 @@ Gather (cost=11.41..24.03 rows=26 width=32) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.136 ms +Babelfish T-SQL Batch Parsing Time: 0.089 ms ~~END~~ @@ -283,7 +283,7 @@ Gather (cost=11.40..25.07 rows=1 width=32) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.148 ms +Babelfish T-SQL Batch Parsing Time: 0.094 ms ~~END~~ select c1 from testing4 where c1 LIKE 'äb%'; @@ -300,7 +300,7 @@ Gather (cost=11.40..25.07 rows=1 width=32) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.137 ms +Babelfish T-SQL Batch Parsing Time: 0.097 ms ~~END~~ select c1 from testing4 where c1 LIKE 'äḃĆ_'; @@ -317,7 +317,7 @@ Gather (cost=11.40..25.07 rows=1 width=32) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.141 ms +Babelfish T-SQL Batch Parsing Time: 0.098 ms ~~END~~ @@ -336,7 +336,7 @@ Gather (cost=11.56..24.18 rows=647 width=32) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 1.528 ms +Babelfish T-SQL Batch Parsing Time: 0.100 ms ~~END~~ @@ -354,7 +354,7 @@ Gather (cost=11.56..25.23 rows=648 width=32) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.137 ms +Babelfish T-SQL Batch Parsing Time: 0.091 ms ~~END~~ @@ -372,7 +372,7 @@ Gather (cost=11.55..25.22 rows=592 width=32) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.141 ms +Babelfish T-SQL Batch Parsing Time: 0.131 ms ~~END~~ @@ -392,7 +392,7 @@ Gather (cost=11.40..25.07 rows=1 width=32) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.151 ms +Babelfish T-SQL Batch Parsing Time: 0.098 ms ~~END~~ @@ -410,7 +410,7 @@ Gather (cost=11.40..25.07 rows=1 width=32) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.128 ms +Babelfish T-SQL Batch Parsing Time: 0.092 ms ~~END~~ @@ -490,8 +490,8 @@ select * from p1 union all select * from p2; GO ~~START~~ nvarchar -äbĆD äƀCd +äbĆD ~~END~~ -- test case expression @@ -545,7 +545,7 @@ Gather (cost=10000000000.00..10000000027.00 rows=7 width=32) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.166 ms +Babelfish T-SQL Batch Parsing Time: 0.086 ms ~~END~~ SET babelfish_showplan_all OFF; @@ -589,7 +589,7 @@ Gather (cost=10000000000.00..10000000027.00 rows=7 width=32) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.148 ms +Babelfish T-SQL Batch Parsing Time: 0.082 ms ~~END~~ SET babelfish_showplan_all OFF; @@ -616,7 +616,7 @@ Gather (cost=0.00..0.00 rows=0 width=0) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.140 ms +Babelfish T-SQL Batch Parsing Time: 0.082 ms ~~END~~ SET babelfish_showplan_all OFF; @@ -646,7 +646,7 @@ Gather (cost=10000000000.00..10000000033.80 rows=1 width=32) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.151 ms +Babelfish T-SQL Batch Parsing Time: 0.089 ms ~~END~~ SET babelfish_showplan_all OFF; @@ -675,7 +675,7 @@ Gather (cost=10000000000.00..10000000033.80 rows=1 width=32) ~~START~~ text -Babelfish T-SQL Batch Parsing Time: 0.163 ms +Babelfish T-SQL Batch Parsing Time: 0.089 ms ~~END~~ SET babelfish_showplan_all OFF; diff --git a/test/JDBC/expected/parallel_query/cast_eliminate-vu-verify.out b/test/JDBC/expected/parallel_query/cast_eliminate-vu-verify.out index 38b174bcbb..d35812f6ac 100644 --- a/test/JDBC/expected/parallel_query/cast_eliminate-vu-verify.out +++ b/test/JDBC/expected/parallel_query/cast_eliminate-vu-verify.out @@ -340,12 +340,13 @@ text Query Text: SELECT * FROM cast_eliminate WHERE (CAST(CAST(ROID AS BIGINT) AS BIGINT) = 3 OR CAST(CAST(ROID AS INT) AS BIGINT) = 2147483647) AND CAST(CAST(s_int AS INT) AS BIGINT) != 32767 Gather (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Bitmap Heap Scan on cast_eliminate (actual rows=1 loops=1) Recheck Cond: ((roid = 3) OR (roid = 2147483647)) Filter: (((s_int)::integer)::bigint <> 32767) Rows Removed by Filter: 1 + Heap Blocks: exact=1 -> BitmapOr (actual rows=0 loops=1) -> Bitmap Index Scan on cast_eliminate_pkey (actual rows=1 loops=1) Index Cond: (roid = 3) @@ -366,10 +367,10 @@ text Query Text: SELECT * FROM cast_eliminate WHERE CAST(CAST(s_int AS INT) AS BIGINT) >= 2394 AND CAST(CAST(ROID AS BIGINT) AS SMALLINT) >= 3 Gather (actual rows=1 loops=1) Workers Planned: 3 - Workers Launched: 3 - -> Parallel Seq Scan on cast_eliminate (actual rows=0 loops=4) + Workers Launched: 0 + -> Parallel Seq Scan on cast_eliminate (actual rows=1 loops=1) Filter: ((s_int >= 2394) AND (((roid)::bigint)::smallint >= 3)) - Rows Removed by Filter: 1 + Rows Removed by Filter: 4 ~~END~~ @@ -385,10 +386,10 @@ text Query Text: SELECT * FROM cast_eliminate WHERE -32768 = CAST(s_int AS INT) Gather (actual rows=1 loops=1) Workers Planned: 3 - Workers Launched: 3 - -> Parallel Seq Scan on cast_eliminate (actual rows=0 loops=4) + Workers Launched: 0 + -> Parallel Seq Scan on cast_eliminate (actual rows=1 loops=1) Filter: ('-32768'::integer = s_int) - Rows Removed by Filter: 1 + Rows Removed by Filter: 4 ~~END~~ @@ -404,10 +405,10 @@ text Query Text: SELECT * FROM cast_eliminate WHERE -32768 = CAST(CAST(s_int AS INT) AS BIGINT) Gather (actual rows=1 loops=1) Workers Planned: 3 - Workers Launched: 3 - -> Parallel Seq Scan on cast_eliminate (actual rows=0 loops=4) + Workers Launched: 0 + -> Parallel Seq Scan on cast_eliminate (actual rows=1 loops=1) Filter: ('-32768'::integer = s_int) - Rows Removed by Filter: 1 + Rows Removed by Filter: 4 ~~END~~ @@ -427,8 +428,8 @@ text Query Text: SELECT * FROM cast_eliminate WHERE -32768 < CAST(CAST(s_int AS INT) AS BIGINT) OR CAST(ROID AS BIGINT) = -2147483648 Gather (actual rows=5 loops=1) Workers Planned: 3 - Workers Launched: 3 - -> Parallel Seq Scan on cast_eliminate (actual rows=1 loops=4) + Workers Launched: 0 + -> Parallel Seq Scan on cast_eliminate (actual rows=5 loops=1) Filter: (('-32768'::integer < s_int) OR (roid = '-2147483648'::integer)) ~~END~~ @@ -444,10 +445,10 @@ text Query Text: SELECT * FROM cast_eliminate WHERE -9223372036854775808 = CAST(s_int AS BIGINT) Gather (actual rows=0 loops=1) Workers Planned: 3 - Workers Launched: 3 - -> Parallel Seq Scan on cast_eliminate (actual rows=0 loops=4) + Workers Launched: 0 + -> Parallel Seq Scan on cast_eliminate (actual rows=0 loops=1) Filter: ('-9223372036854775808'::bigint = s_int) - Rows Removed by Filter: 1 + Rows Removed by Filter: 5 ~~END~~ diff --git a/test/JDBC/expected/parallel_query/charindex_replace_patindex-vu-verify.out b/test/JDBC/expected/parallel_query/charindex_replace_patindex-vu-verify.out index 1dbbd9f011..a2c317fbba 100644 --- a/test/JDBC/expected/parallel_query/charindex_replace_patindex-vu-verify.out +++ b/test/JDBC/expected/parallel_query/charindex_replace_patindex-vu-verify.out @@ -170,7 +170,7 @@ text Query Text: SELECT * FROM babel_5144_t1 WHERE [replaced] = sys.replace('abc?è?ÈdedEDEabcd', 'de', '##') Gather (actual rows=2 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using babel_5144_idx1babel_5144_t145234637e3ecc830cb4dde1fe866640f on babel_5144_t1 (actual rows=2 loops=1) Index Cond: ((replaced)::"varchar" = 'abc?è?È######abcd'::"varchar") @@ -221,7 +221,7 @@ text Query Text: SELECT * FROM babel_5144_t3 WHERE [replaced] = sys.replace('abc?è?ÈdedEDEabcd', 'de', '##') Gather (actual rows=2 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Index Scan using babel_5144_idx3babel_5144_t313c3a4389779eae0c4b18abc08f95caa on babel_5144_t3 (actual rows=2 loops=1) Index Cond: ((replaced)::"varchar" = 'abc?è?È######abcd'::"varchar") diff --git a/test/JDBC/expected/parallel_query/test_dynamic_local_vars.out b/test/JDBC/expected/parallel_query/test_dynamic_local_vars.out index 1c3c7a78ab..6eb4ca8033 100644 --- a/test/JDBC/expected/parallel_query/test_dynamic_local_vars.out +++ b/test/JDBC/expected/parallel_query/test_dynamic_local_vars.out @@ -1351,7 +1351,7 @@ text Query Text: select "@i", "@j" Gather (cost=0.00..0.01 rows=1 width=8) (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Result (cost=0.00..0.01 rows=1 width=8) (actual rows=1 loops=1) ~~END~~ @@ -1379,7 +1379,7 @@ text Query Text: select "@i" Gather (cost=0.00..0.01 rows=1 width=4) (actual rows=1 loops=1) Workers Planned: 1 - Workers Launched: 1 + Workers Launched: 0 Single Copy: true -> Result (cost=0.00..0.01 rows=1 width=4) (actual rows=1 loops=1) ~~END~~ @@ -1536,8 +1536,8 @@ text Query Text: select * from local_var_tst where id = "@a" Gather (cost=0.00..20.28 rows=13 width=4) (actual rows=1 loops=1) Workers Planned: 3 - Workers Launched: 3 - -> Parallel Seq Scan on local_var_tst (cost=0.00..20.28 rows=4 width=4) (actual rows=0 loops=4) + Workers Launched: 0 + -> Parallel Seq Scan on local_var_tst (cost=0.00..20.28 rows=4 width=4) (actual rows=1 loops=1) Filter: (id = 1) ~~END~~ diff --git a/test/JDBC/input/BABEL-2998.mix b/test/JDBC/input/BABEL-2998.mix index 9420ce93d2..4c784fd001 100644 --- a/test/JDBC/input/BABEL-2998.mix +++ b/test/JDBC/input/BABEL-2998.mix @@ -3,35 +3,41 @@ SELECT CAST('1' AS CHAR(10)) AS Col1 UNION SELECT NULL AS Col1 +ORDER BY Col1 GO SELECT CAST('1' AS CHAR(10)) AS Col1 UNION ALL SELECT NULL AS Col1 GROUP BY Col1 +ORDER BY Col1 GO -- taking suggestion from above error, added explicit CAST and CONVERT SELECT CAST('1' AS CHAR(10)) AS Col1 UNION SELECT CAST(NULL AS CHAR(10)) AS Col1 +ORDER BY Col1 GO SELECT CAST('1' AS CHAR(10)) AS Col1 UNION ALL SELECT CONVERT(CHAR(10), NULL) AS Col1 GROUP BY Col1 +ORDER BY Col1 GO SELECT CAST('1' AS CHAR(10)) AS Col1 UNION ALL SELECT CAST(NULL AS CHAR(10)) AS Col1 GROUP BY Col1 +ORDER BY Col1 GO SELECT CAST('1' AS CHAR(10)) AS Col1 UNION SELECT CONVERT(CHAR(10), NULL) AS Col1 +ORDER BY Col1 GO -- psql diff --git a/test/JDBC/input/BABEL-LIKE2ILIKE.sql b/test/JDBC/input/BABEL-LIKE2ILIKE.sql index fe6dd65418..c59d7ad29f 100644 --- a/test/JDBC/input/BABEL-LIKE2ILIKE.sql +++ b/test/JDBC/input/BABEL-LIKE2ILIKE.sql @@ -58,6 +58,7 @@ GO with p1 as (select c1 from like_tesing1 where c1 LIKE '__Ć_'), p2 as (select c3 from like_tesing1 where c3 LIKE 'äƀ__') select * from p1 union all select * from p2 +order by 1 GO -- test case expression select c1,(case when c1 LIKE 'j%' then 1 when c1 NOT LIKE 'j%' then 2 end) from like_tesing1 From 376cf488804fa02f9b1db5bbfbe74e98627fe96c Mon Sep 17 00:00:00 2001 From: Anikait Agrawal <54908236+Anikait143@users.noreply.github.com> Date: Mon, 3 Feb 2025 14:48:16 +0530 Subject: [PATCH 10/10] Fix upgrade test schedule from 16_7 (#3447) * Fix upgrade test schedule from 16_7 --------- Signed-off-by: Anikait Agrawal --- test/JDBC/upgrade/16_7/schedule | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/test/JDBC/upgrade/16_7/schedule b/test/JDBC/upgrade/16_7/schedule index b032220bb2..dea5841160 100644 --- a/test/JDBC/upgrade/16_7/schedule +++ b/test/JDBC/upgrade/16_7/schedule @@ -602,4 +602,4 @@ db_owner BABEL-5031 test_conv_money_to_varchar fixeddecimal_modulo -test_conv_float_to_varchar_char_before_17_3 +test_conv_float_to_varchar_char