diff --git a/.github/workflows/maven.yml b/.github/workflows/maven.yml
index 291b849a2..9f528ccf9 100644
--- a/.github/workflows/maven.yml
+++ b/.github/workflows/maven.yml
@@ -58,7 +58,7 @@ jobs:
runs-on: ubuntu-latest
strategy:
matrix:
- profile: [ 'cockroachdb', 'mariadb', 'mysql', 'postgres', 'spanner', 'phoenix', 'sqlserver', 'sqlite' ]
+ profile: [ 'cockroachdb', 'mariadb', 'mysql', 'oracle', 'phoenix', 'postgres', 'spanner', 'sqlite', 'sqlserver' ]
steps:
- name: Checkout repo
uses: actions/checkout@v4
@@ -271,6 +271,83 @@ jobs:
fi
./scripts/check_histogram_results.sh results/histograms.json $ERRORS_THRESHOLD
+ ## ----------------------------------------------------------------------------------
+ ## ORACLE
+ ## ----------------------------------------------------------------------------------
+ oracle:
+ needs: package-and-upload
+ runs-on: ubuntu-latest
+ strategy:
+ fail-fast: false
+ matrix:
+ benchmark: [ 'auctionmark', 'epinions', 'hyadapt', 'otmetrics', 'resourcestresser', 'seats', 'sibench', 'smallbank', 'tatp', 'tpcc', 'twitter', 'voter', 'wikipedia', 'ycsb', 'templated' ]
+ services:
+ oracle:
+ image: gvenzl/oracle-xe:21.3.0-slim-faststart
+ ports:
+ - "1521:1521"
+ - "5500:5500"
+ env:
+ ORACLE_PASSWORD: password
+ ORACLE_CHARACTERSET: AL32UTF8
+ APP_USER: benchbase
+ APP_USER_PASSWORD: password
+ options: >-
+ --name oracle
+ --health-cmd "echo exit | sqlplus benchbase/password@xepdb1 | grep Connected"
+ --health-interval 10s
+ --health-timeout 5s
+ --health-retries 5
+ --health-start-period 5s
+ steps:
+ - name: Download artifact
+ uses: actions/download-artifact@v3
+ with:
+ name: benchbase-oracle
+
+ - name: Extract artifact
+ run: |
+ tar xvzf benchbase-oracle.tgz --strip-components=1
+
+ - name: Delete artifact
+ run: |
+ rm -rf benchbase-oracle.tgz
+
+ - name: Set up user reset script
+ run: |
+ docker cp config/oracle/scripts/reset.sql oracle:/opt/oracle/reset.sql
+
+ - name: Set up JDK
+ uses: actions/setup-java@v3
+ with:
+ java-version: ${{env.JAVA_VERSION}}
+ distribution: 'temurin'
+
+ - name: Run benchmark
+ run: |
+ docker exec oracle sqlplus "sys/password@xepdb1 as sysdba" @reset.sql
+ # For templated benchmarks, we need to preload some data for the test since by design, templated benchmarks do not support the 'load' operation
+ # In this case, we load the tpcc data.
+ if [[ ${{matrix.benchmark}} == templated ]]; then
+ java -jar benchbase.jar -b tpcc -c config/oracle/sample_tpcc_config.xml --create=true --load=true --execute=false --json-histograms results/histograms.json
+ java -jar benchbase.jar -b ${{matrix.benchmark}} -c config/oracle/sample_${{matrix.benchmark}}_config.xml --create=false --load=false --execute=true --json-histograms results/histograms.json
+ else
+ java -jar benchbase.jar -b ${{matrix.benchmark}} -c config/oracle/sample_${{matrix.benchmark}}_config.xml --create=true --load=true --execute=true --json-histograms results/histograms.json
+ fi
+ # FIXME: Reduce the error rate so we don't need these overrides.
+ if [ ${{matrix.benchmark}} == auctionmark ]; then
+ ERRORS_THRESHOLD=0.04
+ elif [ ${{matrix.benchmark}} == tatp ]; then
+ ERRORS_THRESHOLD=0.05
+ elif [ ${{matrix.benchmark}} == tpcc ]; then
+ ERRORS_THRESHOLD=0.03
+ elif [ ${{matrix.benchmark}} == resourcestresser ]; then
+ ERRORS_THRESHOLD=0.04
+ elif [ ${{matrix.benchmark}} == wikipedia ]; then
+ ERRORS_THRESHOLD=0.02
+ fi
+ ./scripts/check_histogram_results.sh results/histograms.json $ERRORS_THRESHOLD
+
## ----------------------------------------------------------------------------------
## POSTGRESQL
## ----------------------------------------------------------------------------------
diff --git a/config/oracle/sample_auctionmark_config.xml b/config/oracle/sample_auctionmark_config.xml
new file mode 100644
index 000000000..f5c28c75a
--- /dev/null
+++ b/config/oracle/sample_auctionmark_config.xml
@@ -0,0 +1,56 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ benchbase
+ password
+ TRANSACTION_SERIALIZABLE
+ 128
+
+
+ 1
+
+
+ 1
+
+
+
+ 10000
+ 45, 10, 20, 2, 1, 4, 10, 5, 3
+
+
+
+
+
+
+ GetItem
+
+
+ GetUserInfo
+
+
+ NewBid
+
+
+ NewComment
+
+
+ NewCommentResponse
+
+
+ NewFeedback
+
+
+ NewItem
+
+
+ NewPurchase
+
+
+ UpdateItem
+
+
+
\ No newline at end of file
diff --git a/config/oracle/sample_chbenchmark_config.xml b/config/oracle/sample_chbenchmark_config.xml
new file mode 100644
index 000000000..a9faa9615
--- /dev/null
+++ b/config/oracle/sample_chbenchmark_config.xml
@@ -0,0 +1,166 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ benchbase
+ password
+ TRANSACTION_SERIALIZABLE
+ 128
+
+
+ 1
+
+
+
+ 1
+
+
+
+ /benchmarks/gather_schema_stats_oracle.sql
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+ 200
+
+
+ 45,43,4,4,4
+ 3, 2, 3, 2, 5, 5, 5, 5, 5, 5, 5, 5, 5, 5, 5, 5, 5, 5, 5, 5, 5, 5
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+ Q1
+
+
+ Q2
+
+
+ Q3
+
+
+ Q4
+
+
+ Q5
+
+
+ Q6
+
+
+ Q7
+
+
+ Q8
+
+
+ Q9
+
+
+ Q10
+
+
+ Q11
+
+
+ Q12
+
+
+ Q13
+
+
+ Q14
+
+
+ Q15
+
+
+ Q16
+
+
+ Q17
+
+
+ Q18
+
+
+ Q19
+
+
+ Q20
+
+
+ Q21
+
+
+ Q22
+
+
+
+
+
+
+ NewOrder
+
+
+ Payment
+
+
+ OrderStatus
+
+
+ Delivery
+
+
+ StockLevel
+
+
+
diff --git a/config/oracle/sample_epinions_config.xml b/config/oracle/sample_epinions_config.xml
new file mode 100644
index 000000000..f898b9ec7
--- /dev/null
+++ b/config/oracle/sample_epinions_config.xml
@@ -0,0 +1,56 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ benchbase
+ password
+ TRANSACTION_SERIALIZABLE
+ 128
+
+
+ 1
+
+
+ 1
+
+
+
+ 10000
+ 10,10,10,10,10,10,10,10,20
+
+
+
+
+
+
+ GetReviewItemById
+
+
+ GetReviewsByUser
+
+
+ GetAverageRatingByTrustedUser
+
+
+ GetItemAverageRating
+
+
+ GetItemReviewsByTrustedUser
+
+
+ UpdateUserName
+
+
+ UpdateItemTitle
+
+
+ UpdateReviewRating
+
+
+ UpdateTrustRating
+
+
+
diff --git a/config/oracle/sample_hyadapt_config.xml b/config/oracle/sample_hyadapt_config.xml
new file mode 100644
index 000000000..bc00ba982
--- /dev/null
+++ b/config/oracle/sample_hyadapt_config.xml
@@ -0,0 +1,120 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ benchbase
+ password
+ TRANSACTION_SERIALIZABLE
+ 128
+
+ 1
+
+ 1
+
+
+
+ 10000
+ 1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1
+
+
+
+
+
+ MaxRecord1
+
+
+ MaxRecord2
+
+
+ MaxRecord3
+
+
+ MaxRecord4
+
+
+ MaxRecord5
+
+
+ MaxRecord6
+
+
+ MaxRecord7
+
+
+ MaxRecord8
+
+
+ MaxRecord9
+
+
+ MaxRecord10
+
+
+
+ ReadRecord1
+
+
+ ReadRecord2
+
+
+ ReadRecord3
+
+
+ ReadRecord4
+
+
+ ReadRecord5
+
+
+ ReadRecord6
+
+
+ ReadRecord7
+
+
+ ReadRecord8
+
+
+ ReadRecord9
+
+
+ ReadRecord10
+
+
+
+
+ SumRecord1
+
+
+ SumRecord2
+
+
+ SumRecord3
+
+
+ SumRecord4
+
+
+ SumRecord5
+
+
+ SumRecord6
+
+
+ SumRecord7
+
+
+ SumRecord8
+
+
+ SumRecord9
+
+
+ SumRecord10
+
+
+
+
diff --git a/config/oracle/sample_noop_config.xml b/config/oracle/sample_noop_config.xml
new file mode 100644
index 000000000..07e51d029
--- /dev/null
+++ b/config/oracle/sample_noop_config.xml
@@ -0,0 +1,33 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ system
+ password
+ TRANSACTION_SERIALIZABLE
+ 128
+
+
+
+ 1
+
+
+ 1
+
+
+
+ 1000
+ 100
+
+
+
+
+
+
+ NoOp
+
+
+
diff --git a/config/oracle/sample_otmetrics_config.xml b/config/oracle/sample_otmetrics_config.xml
new file mode 100644
index 000000000..ccf81ce93
--- /dev/null
+++ b/config/oracle/sample_otmetrics_config.xml
@@ -0,0 +1,31 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ benchbase
+ password
+ TRANSACTION_SERIALIZABLE
+
+ 2048
+ 0.1
+
+
+ 1
+
+
+
+ 10000
+ 100
+
+
+
+
+
+
+ GetSessionRange
+
+
+
diff --git a/config/oracle/sample_resourcestresser_config.xml b/config/oracle/sample_resourcestresser_config.xml
new file mode 100644
index 000000000..81dff7d61
--- /dev/null
+++ b/config/oracle/sample_resourcestresser_config.xml
@@ -0,0 +1,48 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ benchbase
+ password
+ TRANSACTION_SERIALIZABLE
+ 128
+
+
+ 1
+
+
+ 1
+
+
+
+ 10000
+ 16.66,16.66,16.66,16.66,16.66,16.7
+
+
+
+
+
+
+ CPU1
+
+
+ CPU2
+
+
+ IO1
+
+
+ IO2
+
+
+ Contention1
+
+
+ Contention2
+
+
+
+
diff --git a/config/oracle/sample_seats_config.xml b/config/oracle/sample_seats_config.xml
new file mode 100644
index 000000000..451e8a170
--- /dev/null
+++ b/config/oracle/sample_seats_config.xml
@@ -0,0 +1,47 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ benchbase
+ password
+ TRANSACTION_SERIALIZABLE
+ 128
+
+
+ 1
+
+
+ 1
+
+
+
+ 10000
+ 10, 10, 35, 20, 10, 15
+
+
+
+
+
+
+ DeleteReservation
+
+
+ FindFlights
+
+
+ FindOpenSeats
+
+
+ NewReservation
+
+
+ UpdateCustomer
+
+
+ UpdateReservation
+
+
+
diff --git a/config/oracle/sample_sibench_config.xml b/config/oracle/sample_sibench_config.xml
new file mode 100644
index 000000000..0e17ed871
--- /dev/null
+++ b/config/oracle/sample_sibench_config.xml
@@ -0,0 +1,34 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ benchbase
+ password
+ TRANSACTION_SERIALIZABLE
+ 128
+
+ 1
+
+
+ 1
+
+
+
+ unlimited
+ 50,50
+
+
+
+
+
+
+ MinRecord
+
+
+ UpdateRecord
+
+
+
diff --git a/config/oracle/sample_smallbank_config.xml b/config/oracle/sample_smallbank_config.xml
new file mode 100644
index 000000000..58180c175
--- /dev/null
+++ b/config/oracle/sample_smallbank_config.xml
@@ -0,0 +1,46 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ benchbase
+ password
+ TRANSACTION_SERIALIZABLE
+ 128
+
+ 1
+
+
+ 1
+
+
+
+ 100
+ 15,15,15,25,15,15
+
+
+
+
+
+
+ Amalgamate
+
+
+ Balance
+
+
+ DepositChecking
+
+
+ SendPayment
+
+
+ TransactSavings
+
+
+ WriteCheck
+
+
+
diff --git a/config/oracle/sample_tatp_config.xml b/config/oracle/sample_tatp_config.xml
new file mode 100644
index 000000000..0f84d6731
--- /dev/null
+++ b/config/oracle/sample_tatp_config.xml
@@ -0,0 +1,50 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ benchbase
+ password
+ TRANSACTION_SERIALIZABLE
+ 128
+
+
+ 1
+
+
+ 1
+
+
+
+ 10000
+ 2, 35, 10, 35, 2, 14, 2
+
+
+
+
+
+
+ DeleteCallForwarding
+
+
+ GetAccessData
+
+
+ GetNewDestination
+
+
+ GetSubscriberData
+
+
+ InsertCallForwarding
+
+
+ UpdateLocation
+
+
+ UpdateSubscriberData
+
+
+
diff --git a/config/oracle/sample_templated_config.xml b/config/oracle/sample_templated_config.xml
new file mode 100644
index 000000000..043cb413f
--- /dev/null
+++ b/config/oracle/sample_templated_config.xml
@@ -0,0 +1,49 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ benchbase
+ password
+ TRANSACTION_SERIALIZABLE
+ 128
+
+
+
+ data/templated/example.xml
+
+
+ 1
+
+
+
+ 100
+ 30,20,10,30,10
+
+
+
+
+
+
+ GetOrder
+
+
+ GetCust
+
+
+ GetCustNull
+
+
+ GetWarehouse
+
+
+ GetItemByPrice
+
+
+
diff --git a/config/oracle/sample_tpcc_config.xml b/config/oracle/sample_tpcc_config.xml
new file mode 100644
index 000000000..4e991f6be
--- /dev/null
+++ b/config/oracle/sample_tpcc_config.xml
@@ -0,0 +1,56 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ benchbase
+ password
+
+ TRANSACTION_SERIALIZABLE
+ 128
+ 1
+
+
+ 1
+
+
+ 1
+
+
+
+ 10000
+ 45,43,4,4,4
+
+
+
+
+
+
+ NewOrder
+
+
+
+
+ Payment
+
+
+
+
+ OrderStatus
+
+
+
+
+ Delivery
+
+
+
+
+ StockLevel
+
+
+
+
+
diff --git a/config/oracle/sample_tpch_config.xml b/config/oracle/sample_tpch_config.xml
new file mode 100644
index 000000000..4ab444e5a
--- /dev/null
+++ b/config/oracle/sample_tpch_config.xml
@@ -0,0 +1,140 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ benchbase
+ password
+ TRANSACTION_SERIALIZABLE
+ 1024
+
+
+ 0.1
+
+
+
+ /benchmarks/gather_schema_stats_oracle.sql
+
+
+ 1
+
+
+ true
+ unlimited
+ 1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1,1
+
+
+ true
+ unlimited
+ 0,1,0,1,0,1,0,1,0,1,0,1,0,1,0,1,0,1,0,1,0,1
+
+
+ true
+ unlimited
+ 1,0,1,0,1,0,1,0,1,0,1,0,1,0,1,0,1,0,1,0,1,0
+
+
+
+
+
+
+ odd
+ 1,0,1,0,1,0,1,0,1,0,1,0,1,0,1,0,1,0,1,0,1,0
+
+
+ even
+ 0,1,0,1,0,1,0,1,0,1,0,1,0,1,0,1,0,1,0,1,0,1
+
+
+
+ Q1
+ 1
+
+
+ Q2
+ 2
+
+
+ Q3
+ 3
+
+
+ Q4
+ 4
+
+
+ Q5
+ 5
+
+
+ Q6
+ 6
+
+
+ Q7
+ 7
+
+
+ Q8
+ 8
+
+
+ Q9
+ 9
+
+
+ Q10
+ 10
+
+
+ Q11
+ 11
+
+
+ Q12
+ 12
+
+
+ Q13
+ 13
+
+
+ Q14
+ 14
+
+
+ Q15
+ 15
+
+
+ Q16
+ 16
+
+
+ Q17
+ 17
+
+
+ Q18
+ 18
+
+
+ Q19
+ 19
+
+
+ Q20
+ 20
+
+
+ Q21
+ 21
+
+
+ Q22
+ 22
+
+
+
diff --git a/config/oracle/sample_twitter_config.xml b/config/oracle/sample_twitter_config.xml
new file mode 100644
index 000000000..a08996e02
--- /dev/null
+++ b/config/oracle/sample_twitter_config.xml
@@ -0,0 +1,50 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ benchbase
+ password
+ TRANSACTION_SERIALIZABLE
+ 128
+
+
+ 1
+
+
+
+ data/twitter/twitter_tweetids.txt
+ data/twitter/twitter_user_ids.txt
+ 10.1.
+
+
+ 1
+
+
+
+ 10000
+ 1,1,7,90,1
+
+
+
+
+
+
+ GetTweet
+
+
+ GetTweetsFromFollowing
+
+
+ GetFollowers
+
+
+ GetUserTweets
+
+
+ InsertTweet
+
+
+
diff --git a/config/oracle/sample_voter_config.xml b/config/oracle/sample_voter_config.xml
new file mode 100644
index 000000000..8428adcca
--- /dev/null
+++ b/config/oracle/sample_voter_config.xml
@@ -0,0 +1,31 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ benchbase
+ password
+ TRANSACTION_SERIALIZABLE
+ 128
+
+ 1
+
+
+ 1
+
+
+
+ 10000
+ 100
+
+
+
+
+
+
+ Vote
+
+
+
diff --git a/config/oracle/sample_wikipedia_config.xml b/config/oracle/sample_wikipedia_config.xml
new file mode 100644
index 000000000..3209b6775
--- /dev/null
+++ b/config/oracle/sample_wikipedia_config.xml
@@ -0,0 +1,45 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ benchbase
+ password
+
+ TRANSACTION_SERIALIZABLE
+ 1
+
+
+ 1
+
+
+ 1
+
+
+
+ 1000
+ 1,1,7,90,1
+
+
+
+
+
+
+ AddWatchList
+
+
+ RemoveWatchList
+
+
+ UpdatePage
+
+
+ GetPageAnonymous
+
+
+ GetPageAuthenticated
+
+
+
diff --git a/config/oracle/sample_ycsb_config.xml b/config/oracle/sample_ycsb_config.xml
new file mode 100644
index 000000000..06b1df9b6
--- /dev/null
+++ b/config/oracle/sample_ycsb_config.xml
@@ -0,0 +1,48 @@
+
+
+
+
+ ORACLE
+ oracle.jdbc.OracleDriver
+ jdbc:oracle:thin:@localhost:1521/xepdb1
+ benchbase
+ password
+
+ TRANSACTION_SERIALIZABLE
+ 128
+
+
+ 1
+
+
+ 1
+
+
+
+ 10000
+ 50,5,15,10,10,10
+
+
+
+
+
+
+ ReadRecord
+
+
+ InsertRecord
+
+
+ ScanRecord
+
+
+ UpdateRecord
+
+
+ DeleteRecord
+
+
+ ReadModifyWriteRecord
+
+
+
diff --git a/config/oracle/scripts/reset.sql b/config/oracle/scripts/reset.sql
new file mode 100644
index 000000000..7254298ea
--- /dev/null
+++ b/config/oracle/scripts/reset.sql
@@ -0,0 +1,12 @@
+-- This SQL file recreate Oracle DB user (benchbase/password) for sample configs
+-- This file is inteded to be copied into the OracleDB container, to be invoked later using sqlplus
+-- docker cp config/oracle/scripts/reset.sql oracle:/opt/oracle/reset.sql
+-- docker exec oracle sqlplus "sys/password@xepdb1 as sysdba" @reset.sql
+
+DROP USER benchbase CASCADE;
+CREATE USER benchbase IDENTIFIED BY password;
+GRANT CONNECT, RESOURCE, CREATE VIEW, UNLIMITED TABLESPACE TO benchbase;
+-- Resourcestresser benchmark for Oracle requires access to these two packages
+-- These will not be needed if running with user sys/system instead
+GRANT EXECUTE ON DBMS_CRYPTO TO benchbase;
+GRANT EXECUTE ON DBMS_LOCK TO benchbase;
diff --git a/docker/oracle/docker-compose.yml b/docker/oracle/docker-compose.yml
new file mode 100644
index 000000000..633657e0f
--- /dev/null
+++ b/docker/oracle/docker-compose.yml
@@ -0,0 +1,20 @@
+version: '3.5'
+
+services:
+ oracle:
+ image: gvenzl/oracle-xe:21.3.0-slim-faststart
+ container_name: oracle
+ ports:
+ - "1521:1521"
+ - "5500:5500"
+ environment:
+ - ORACLE_PASSWORD=password
+ - ORACLE_CHARACTERSET=AL32UTF8
+ - APP_USER=benchbase
+ - APP_USER_PASSWORD=password
+ healthcheck:
+ test: echo exit | sqlplus benchbase/password@xepdb1 | grep Connected
+ interval: 1s
+ timeout: 5s
+ retries: 30
+ start_period: 5s
\ No newline at end of file
diff --git a/docker/oracle/down.sh b/docker/oracle/down.sh
new file mode 100755
index 000000000..c8f703de5
--- /dev/null
+++ b/docker/oracle/down.sh
@@ -0,0 +1,7 @@
+#!/bin/bash
+
+set -eu
+scriptdir=$(dirname "$(readlink -f "$0")")
+cd "$scriptdir/"
+
+docker compose down --remove-orphans --volumes
diff --git a/docker/oracle/prune.sh b/docker/oracle/prune.sh
new file mode 100755
index 000000000..66b76933a
--- /dev/null
+++ b/docker/oracle/prune.sh
@@ -0,0 +1,7 @@
+#!/bin/bash
+
+set -eu
+scriptdir=$(dirname "$(readlink -f "$0")")
+cd "$scriptdir/"
+
+docker system prune -a -f --volumes
diff --git a/docker/oracle/reset.sql b/docker/oracle/reset.sql
new file mode 100644
index 000000000..08f15c426
--- /dev/null
+++ b/docker/oracle/reset.sql
@@ -0,0 +1,7 @@
+-- Non-DBA user specified in sample config file
+DROP USER benchbase CASCADE;
+CREATE USER benchbase IDENTIFIED BY password;
+GRANT CONNECT, RESOURCE, CREATE VIEW, UNLIMITED TABLESPACE TO benchbase;
+-- Resourcestresser benchmark requires these two packages from SYS
+GRANT EXECUTE ON DBMS_CRYPTO TO benchbase;
+GRANT EXECUTE ON DBMS_LOCK TO benchbase;
diff --git a/docker/oracle/up.sh b/docker/oracle/up.sh
new file mode 100755
index 000000000..d05249baf
--- /dev/null
+++ b/docker/oracle/up.sh
@@ -0,0 +1,7 @@
+#!/bin/bash
+
+set -eu
+scriptdir=$(dirname "$(readlink -f "$0")")
+cd "$scriptdir/"
+
+docker compose up -d
diff --git a/pom.xml b/pom.xml
index 67a569263..c3cc946bf 100644
--- a/pom.xml
+++ b/pom.xml
@@ -88,6 +88,22 @@
+
+
+ oracle
+
+ oracle
+
+
+
+
+ com.oracle.database.jdbc
+ ojdbc11
+ 21.5.0.0
+ runtime
+
+
+
mariadb
diff --git a/src/main/java/com/oltpbenchmark/api/BenchmarkModule.java b/src/main/java/com/oltpbenchmark/api/BenchmarkModule.java
index dcac10cf6..16a844e5e 100644
--- a/src/main/java/com/oltpbenchmark/api/BenchmarkModule.java
+++ b/src/main/java/com/oltpbenchmark/api/BenchmarkModule.java
@@ -110,10 +110,6 @@ public final void setAfterLoadScriptPath(String scriptPath) {
this.afterLoadScriptPath = scriptPath;
}
- public String getAfterLoadScriptPath() {
- return this.afterLoadScriptPath;
- }
-
// --------------------------------------------------------------------------
// IMPLEMENTING CLASS INTERFACE
// --------------------------------------------------------------------------
diff --git a/src/main/java/com/oltpbenchmark/api/Procedure.java b/src/main/java/com/oltpbenchmark/api/Procedure.java
index 35357e95f..fa9c711a8 100644
--- a/src/main/java/com/oltpbenchmark/api/Procedure.java
+++ b/src/main/java/com/oltpbenchmark/api/Procedure.java
@@ -37,6 +37,11 @@ public abstract class Procedure {
private final String procName;
private DatabaseType dbType;
+
+ public DatabaseType getDbType() {
+ return dbType;
+ }
+
private Map name_stmt_xref;
/**
diff --git a/src/main/java/com/oltpbenchmark/benchmarks/auctionmark/AuctionMarkLoader.java b/src/main/java/com/oltpbenchmark/benchmarks/auctionmark/AuctionMarkLoader.java
index ab373ac77..dae155a5e 100644
--- a/src/main/java/com/oltpbenchmark/benchmarks/auctionmark/AuctionMarkLoader.java
+++ b/src/main/java/com/oltpbenchmark/benchmarks/auctionmark/AuctionMarkLoader.java
@@ -40,6 +40,8 @@
import java.util.concurrent.TimeUnit;
import java.util.regex.Pattern;
+import com.oltpbenchmark.types.DatabaseType;
+
/**
* @author pavlo
* @author visawee
@@ -439,7 +441,9 @@ protected int populateRandomColumns(Object[] row) {
// STRINGS
for (Column catalog_col : this.random_str_cols) {
int size = catalog_col.getSize();
- row[catalog_col.getIndex()] = profile.rng.astring(profile.rng.nextInt(size - 1), size);
+ // This (0) can generate an empty string which is treated as NULL in Oracle DB
+ int start = getDatabaseType() == DatabaseType.ORACLE ? 1 : 0;
+ row[catalog_col.getIndex()] = profile.rng.astring(profile.rng.nextInt(start, size - 1), size);
cols++;
}
diff --git a/src/main/java/com/oltpbenchmark/benchmarks/auctionmark/procedures/LoadConfig.java b/src/main/java/com/oltpbenchmark/benchmarks/auctionmark/procedures/LoadConfig.java
index 67bf2d14f..8e724f0f5 100644
--- a/src/main/java/com/oltpbenchmark/benchmarks/auctionmark/procedures/LoadConfig.java
+++ b/src/main/java/com/oltpbenchmark/benchmarks/auctionmark/procedures/LoadConfig.java
@@ -21,6 +21,7 @@
import com.oltpbenchmark.api.SQLStmt;
import com.oltpbenchmark.benchmarks.auctionmark.AuctionMarkConstants;
import com.oltpbenchmark.benchmarks.auctionmark.util.ItemStatus;
+import com.oltpbenchmark.types.DatabaseType;
import com.oltpbenchmark.util.SQLUtil;
import java.sql.Connection;
@@ -83,6 +84,17 @@ public Config run(Connection conn) throws SQLException {
try (PreparedStatement preparedStatement = this.getPreparedStatement(conn, getConfigProfile)) {
try (ResultSet resultSet = preparedStatement.executeQuery()) {
configProfile = SQLUtil.toList(resultSet);
+ // Oracle DB DDL contains some CLOB fields (for LoadConfig procedures).
+ // These CLOB needs to be converted to String while the connection is alive.
+
+ // This CLOB conversion for Oracle needs to be done here, otherwise the conversion will be attempted
+ // by SQLUtil.getString(Object) after the connection closes, which will result in
+ // java.sql.SQLRecoverableException: Closed Connection.
+ if (getDbType() == DatabaseType.ORACLE) {
+ for (Object[] configProfileInstance: configProfile) {
+ configProfileInstance[3] = SQLUtil.clobToString(configProfileInstance[3]);
+ }
+ }
}
}
diff --git a/src/main/java/com/oltpbenchmark/benchmarks/resourcestresser/procedures/CPU1.java b/src/main/java/com/oltpbenchmark/benchmarks/resourcestresser/procedures/CPU1.java
index a1f527c53..95fe70c49 100644
--- a/src/main/java/com/oltpbenchmark/benchmarks/resourcestresser/procedures/CPU1.java
+++ b/src/main/java/com/oltpbenchmark/benchmarks/resourcestresser/procedures/CPU1.java
@@ -36,7 +36,7 @@ public class CPU1 extends Procedure {
for (int i = 1; i <= ResourceStresserWorker.CPU1_nestedLevel; ++i) {
complexClause = "md5(concat(" + complexClause + ",?))";
}
- cpuSelect = new SQLStmt("SELECT count(*) FROM (SELECT " + complexClause + " FROM " + ResourceStresserConstants.TABLENAME_CPUTABLE + " WHERE empid >= 0 AND empid < 100) AS T1");
+ cpuSelect = new SQLStmt("SELECT count(*) FROM (SELECT " + complexClause + " FROM " + ResourceStresserConstants.TABLENAME_CPUTABLE + " WHERE empid >= 0 AND empid < 100) T1");
}
public void run(Connection conn, int howManyPerTransaction, int sleepLength, int nestedLevel) throws SQLException {
diff --git a/src/main/java/com/oltpbenchmark/benchmarks/resourcestresser/procedures/CPU2.java b/src/main/java/com/oltpbenchmark/benchmarks/resourcestresser/procedures/CPU2.java
index 42d67f3e5..b6d515f12 100644
--- a/src/main/java/com/oltpbenchmark/benchmarks/resourcestresser/procedures/CPU2.java
+++ b/src/main/java/com/oltpbenchmark/benchmarks/resourcestresser/procedures/CPU2.java
@@ -36,7 +36,7 @@ public class CPU2 extends Procedure {
for (int i = 1; i <= ResourceStresserWorker.CPU2_nestedLevel; ++i) {
complexClause = "md5(concat(" + complexClause + ",?))";
}
- cpuSelect = new SQLStmt("SELECT count(*) FROM (SELECT " + complexClause + " FROM " + ResourceStresserConstants.TABLENAME_CPUTABLE + " WHERE empid >= 0 AND empid < 100) AS T2");
+ cpuSelect = new SQLStmt("SELECT count(*) FROM (SELECT " + complexClause + " FROM " + ResourceStresserConstants.TABLENAME_CPUTABLE + " WHERE empid >= 0 AND empid < 100) T2");
}
public void run(Connection conn, int howManyPerTransaction, int sleepLength, int nestedLevel) throws SQLException {
diff --git a/src/main/java/com/oltpbenchmark/benchmarks/seats/procedures/LoadConfig.java b/src/main/java/com/oltpbenchmark/benchmarks/seats/procedures/LoadConfig.java
index 1facacd11..309285716 100644
--- a/src/main/java/com/oltpbenchmark/benchmarks/seats/procedures/LoadConfig.java
+++ b/src/main/java/com/oltpbenchmark/benchmarks/seats/procedures/LoadConfig.java
@@ -20,6 +20,7 @@
import com.oltpbenchmark.api.Procedure;
import com.oltpbenchmark.api.SQLStmt;
import com.oltpbenchmark.benchmarks.seats.SEATSConstants;
+import com.oltpbenchmark.types.DatabaseType;
import com.oltpbenchmark.util.SQLUtil;
import java.sql.Connection;
@@ -67,6 +68,17 @@ public Config run(Connection conn) throws SQLException {
try (PreparedStatement preparedStatement = this.getPreparedStatement(conn, getConfigProfile)) {
try (ResultSet resultSet = preparedStatement.executeQuery()) {
configProfile = SQLUtil.toList(resultSet);
+ // Oracle DB DDL contains some CLOB fields (for LoadConfig procedures).
+ // These CLOB needs to be converted to String while the connection is alive.
+
+ // This CLOB conversion for Oracle needs to be done here, otherwise the conversion will be attempted
+ // by SQLUtil.getString(Object) after the connection closes, which will result in
+ // java.sql.SQLRecoverableException: Closed Connection.
+ if (getDbType() == DatabaseType.ORACLE) {
+ for (Object[] configProfileInstance: configProfile) {
+ configProfileInstance[1] = SQLUtil.clobToString(configProfileInstance[1]);
+ }
+ }
}
}
@@ -74,6 +86,17 @@ public Config run(Connection conn) throws SQLException {
try (PreparedStatement preparedStatement = this.getPreparedStatement(conn, getConfigHistogram)) {
try (ResultSet resultSet = preparedStatement.executeQuery()) {
histogram = SQLUtil.toList(resultSet);
+ // Oracle DB DDL contains some CLOB fields (for LoadConfig procedures).
+ // These CLOB needs to be converted to String while the connection is alive.
+
+ // This CLOB conversion for Oracle needs to be done here, otherwise the conversion will be attempted
+ // by SQLUtil.getString(Object) after the connection closes, which will result in
+ // java.sql.SQLRecoverableException: Closed Connection.
+ if (getDbType() == DatabaseType.ORACLE) {
+ for (Object[] histogramInstance: histogram) {
+ histogramInstance[1] = SQLUtil.clobToString(histogramInstance[1]);
+ }
+ }
}
}
diff --git a/src/main/java/com/oltpbenchmark/benchmarks/voter/procedures/Vote.java b/src/main/java/com/oltpbenchmark/benchmarks/voter/procedures/Vote.java
index 1694fa451..f1d057ca7 100644
--- a/src/main/java/com/oltpbenchmark/benchmarks/voter/procedures/Vote.java
+++ b/src/main/java/com/oltpbenchmark/benchmarks/voter/procedures/Vote.java
@@ -65,25 +65,24 @@ public class Vote extends Procedure {
// Checks if the vote is for a valid contestant
public final SQLStmt checkContestantStmt = new SQLStmt(
- "SELECT contestant_number FROM " + TABLENAME_CONTESTANTS + " WHERE contestant_number = ?;"
+ "SELECT contestant_number FROM " + TABLENAME_CONTESTANTS + " WHERE contestant_number = ?"
);
// Checks if the voter has exceeded their allowed number of votes
public final SQLStmt checkVoterStmt = new SQLStmt(
- "SELECT COUNT(*) FROM " + TABLENAME_VOTES + " WHERE phone_number = ?;"
+ "SELECT COUNT(*) FROM " + TABLENAME_VOTES + " WHERE phone_number = ?"
);
// Checks an area code to retrieve the corresponding state
public final SQLStmt checkStateStmt = new SQLStmt(
- "SELECT state FROM " + TABLENAME_LOCATIONS + " WHERE area_code = ?;"
+ "SELECT state FROM " + TABLENAME_LOCATIONS + " WHERE area_code = ?"
);
// Records a vote
public final SQLStmt insertVoteStmt = new SQLStmt(
"INSERT INTO " + TABLENAME_VOTES + " (vote_id, phone_number, state, contestant_number, created) " +
- "VALUES (?, ?, ?, ?, NOW());"
+ "VALUES (?, ?, ?, ?, NOW())"
);
-
public long run(Connection conn, long voteId, long phoneNumber, int contestantNumber, long maxVotesPerPhoneNumber) throws SQLException {
try (PreparedStatement ps = getPreparedStatement(conn, checkContestantStmt)) {
diff --git a/src/main/java/com/oltpbenchmark/benchmarks/wikipedia/WikipediaLoader.java b/src/main/java/com/oltpbenchmark/benchmarks/wikipedia/WikipediaLoader.java
index 3509e4012..fe2ead717 100644
--- a/src/main/java/com/oltpbenchmark/benchmarks/wikipedia/WikipediaLoader.java
+++ b/src/main/java/com/oltpbenchmark/benchmarks/wikipedia/WikipediaLoader.java
@@ -104,20 +104,22 @@ public void load(Connection conn) throws SQLException {
SQLUtil.setIdentityInsert(conn, getDatabaseType(), catalog_tbl, true);
String sql = SQLUtil.getInsertSQL(catalog_tbl, benchmark.getWorkloadConfiguration().getDatabaseType());
+ // Empty string which is treated as NULL in Oracle DB
+ String dummyString = getDatabaseType() == DatabaseType.ORACLE ? " " : "";
// load anonymous user
try (PreparedStatement stmt = conn.prepareStatement(sql)) {
int param = 1;
stmt.setInt(param++, WikipediaConstants.ANONYMOUS_USER_ID); // user_id
stmt.setString(param++, "Anonymous"); // user_name
- stmt.setString(param++, ""); // user_real_name
- stmt.setString(param++, ""); // user_password
- stmt.setString(param++, ""); // user_newpassword
+ stmt.setString(param++, dummyString); // user_real_name
+ stmt.setString(param++, dummyString); // user_password
+ stmt.setString(param++, dummyString); // user_newpassword
stmt.setNull(param++, JDBCType.VARCHAR.getVendorTypeNumber()); // user_newpass_time
- stmt.setString(param++, ""); // user_email
- stmt.setString(param++, ""); // user_options
- stmt.setString(param++, ""); // user_touched
- stmt.setString(param++, ""); // user_token
+ stmt.setString(param++, dummyString); // user_email
+ stmt.setString(param++, dummyString); // user_options
+ stmt.setString(param++, dummyString); // user_touched
+ stmt.setString(param++, dummyString); // user_token
stmt.setNull(param++, JDBCType.VARCHAR.getVendorTypeNumber()); // user_email_authenticated
stmt.setNull(param++, JDBCType.VARCHAR.getVendorTypeNumber()); // user_email_token
stmt.setNull(param++, JDBCType.VARCHAR.getVendorTypeNumber()); // user_email_token_expires
diff --git a/src/main/java/com/oltpbenchmark/util/SQLUtil.java b/src/main/java/com/oltpbenchmark/util/SQLUtil.java
index c0cd7e8c9..9574d6f3c 100644
--- a/src/main/java/com/oltpbenchmark/util/SQLUtil.java
+++ b/src/main/java/com/oltpbenchmark/util/SQLUtil.java
@@ -24,6 +24,8 @@
import org.slf4j.Logger;
import org.slf4j.LoggerFactory;
+import java.lang.reflect.InvocationTargetException;
+import java.lang.reflect.Method;
import java.math.BigDecimal;
import java.sql.Date;
import java.sql.*;
@@ -109,6 +111,15 @@ public static Double getDouble(Object obj) {
return (null);
}
+ public static String clobToString(Object obj) {
+ try {
+ Clob clob = (Clob) obj;
+ return clob.getSubString(1, (int) clob.length());
+ } catch (SQLException e) {
+ throw new RuntimeException(e);
+ }
+ }
+
public static String getString(Object obj) {
if (obj == null) {
return (null);
@@ -116,6 +127,8 @@ public static String getString(Object obj) {
if (obj instanceof String) {
return (String) obj;
+ } else if (obj instanceof BigDecimal bigDecimal) {
+ return bigDecimal.toString();
}
LOG.warn("BAD BAD BAD: returning null because getString does not support {}", obj.getClass());
@@ -123,6 +136,34 @@ public static String getString(Object obj) {
return (null);
}
+ /**
+ * Support for Oracle DB introduced TIMESTAMP fields in Oracle DDL (for example, auctionmark CONFIG_PROFILE table),
+ * which results in OJDBC-specific {@code oracle.sql.TIMESTAMP} object.
+ * {@link #getTimestamp(Object)} needs to be able to convert {@code oracle.sql.TIMESTAMP} into {@code java.sql.TIMESTAMP}.
+ *
+ * The main issue is that {@code oracle.sql.TIMESTAMP} is not available in JDBC, so trying to import and resolve the
+ * type normally will break other database profiles.
+ * This can be solved by loading OJDBC-specific class + method reflectively.
+ */
+ private static final Class> ORACLE_TIMESTAMP;
+ private static final Method TIMESTAMP_VALUE_METHOD;
+ static {
+ Method timestampValueMethod;
+ Class> oracleTimestamp;
+ try {
+ // If oracle.sql.TIMESTAMP can be loaded
+ oracleTimestamp = Class.forName("oracle.sql.TIMESTAMP");
+ // Then java.sql.Timestamp oracle.sql.TIMESTAMP.timestampValue() can be loaded
+ timestampValueMethod = oracleTimestamp.getDeclaredMethod("timestampValue");
+ } catch (ClassNotFoundException | NoSuchMethodException e) {
+ oracleTimestamp = null;
+ timestampValueMethod = null;
+ }
+ // If loading is successful then both variables won't be null.
+ TIMESTAMP_VALUE_METHOD = timestampValueMethod;
+ ORACLE_TIMESTAMP = oracleTimestamp;
+ }
+
/**
* Return a double from the given object
* Handles the different cases from the various DBMSs
@@ -139,6 +180,13 @@ public static Timestamp getTimestamp(Object obj) {
return (Timestamp) obj;
} else if (obj instanceof Date) {
return new Timestamp(((Date) obj).getTime());
+ } else if (ORACLE_TIMESTAMP != null && ORACLE_TIMESTAMP.isInstance(obj)) {
+ try {
+ // https://docs.oracle.com/en/database/oracle/oracle-database/21/jajdb/oracle/sql/TIMESTAMP.html#timestampValue__
+ return (Timestamp) TIMESTAMP_VALUE_METHOD.invoke(ORACLE_TIMESTAMP.cast(obj));
+ } catch (IllegalAccessException | InvocationTargetException e) {
+ throw new RuntimeException(e);
+ }
}
Long timestamp = SQLUtil.getLong(obj);
@@ -286,6 +334,7 @@ public static Object castValue(int sqlType, String value) {
}
case Types.DECIMAL:
case Types.REAL:
+ case Types.NUMERIC:
case Types.DOUBLE: {
ret = Double.parseDouble(value);
break;
diff --git a/src/main/resources/benchmarks/auctionmark/ddl-oracle.sql b/src/main/resources/benchmarks/auctionmark/ddl-oracle.sql
index c6fbbe845..34b0d7eb6 100644
--- a/src/main/resources/benchmarks/auctionmark/ddl-oracle.sql
+++ b/src/main/resources/benchmarks/auctionmark/ddl-oracle.sql
@@ -1,4 +1,3 @@
--- Drop all tables
BEGIN EXECUTE IMMEDIATE 'DROP TABLE CONFIG_PROFILE'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
BEGIN EXECUTE IMMEDIATE 'DROP TABLE REGION CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
BEGIN EXECUTE IMMEDIATE 'DROP TABLE USERACCT CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
@@ -18,7 +17,7 @@ BEGIN EXECUTE IMMEDIATE 'DROP TABLE USERACCT_ITEM CASCADE CONSTRAINTS'; EXCEPTIO
BEGIN EXECUTE IMMEDIATE 'DROP TABLE USERACCT_WATCH CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-- Create tables
--- ================================================================
+-- ================================================================
-- CONFIG_PROFILE
-- ================================================================
CREATE TABLE CONFIG_PROFILE (
@@ -35,14 +34,14 @@ CREATE TABLE CONFIG_PROFILE (
-- r_name Region's name
-- ================================================================
CREATE TABLE REGION (
- r_id INT NOT NULL,
- r_name VARCHAR(32),
+ r_id NUMBER(19, 0) NOT NULL,
+ r_name VARCHAR2(32),
PRIMARY KEY (r_id)
);
-- ================================================================
-- USERACCT
--- Represents user accounts
+-- Represents user accounts
-- u_id User ID
-- u_firstname User's first name
-- u_lastname User's last name
@@ -54,42 +53,42 @@ CREATE TABLE REGION (
-- u_r_id User's region ID
-- ================================================================
CREATE TABLE USERACCT (
- u_id INT NOT NULL,
- u_rating INT NOT NULL,
+ u_id VARCHAR2(128) NOT NULL,
+ u_rating NUMBER(19, 0) NOT NULL,
u_balance FLOAT NOT NULL,
u_comments INTEGER DEFAULT 0,
- u_r_id INT NOT NULL REFERENCES REGION (r_id),
+ u_r_id NUMBER(19, 0) NOT NULL REFERENCES REGION (r_id),
u_created TIMESTAMP,
u_updated TIMESTAMP,
- u_sattr0 VARCHAR(64),
- u_sattr1 VARCHAR(64),
- u_sattr2 VARCHAR(64),
- u_sattr3 VARCHAR(64),
- u_sattr4 VARCHAR(64),
- u_sattr5 VARCHAR(64),
- u_sattr6 VARCHAR(64),
- u_sattr7 VARCHAR(64),
- u_iattr0 INT DEFAULT NULL,
- u_iattr1 INT DEFAULT NULL,
- u_iattr2 INT DEFAULT NULL,
- u_iattr3 INT DEFAULT NULL,
- u_iattr4 INT DEFAULT NULL,
- u_iattr5 INT DEFAULT NULL,
- u_iattr6 INT DEFAULT NULL,
- u_iattr7 INT DEFAULT NULL,
+ u_sattr0 VARCHAR2(64),
+ u_sattr1 VARCHAR2(64),
+ u_sattr2 VARCHAR2(64),
+ u_sattr3 VARCHAR2(64),
+ u_sattr4 VARCHAR2(64),
+ u_sattr5 VARCHAR2(64),
+ u_sattr6 VARCHAR2(64),
+ u_sattr7 VARCHAR2(64),
+ u_iattr0 NUMBER(19, 0) DEFAULT NULL,
+ u_iattr1 NUMBER(19, 0) DEFAULT NULL,
+ u_iattr2 NUMBER(19, 0) DEFAULT NULL,
+ u_iattr3 NUMBER(19, 0) DEFAULT NULL,
+ u_iattr4 NUMBER(19, 0) DEFAULT NULL,
+ u_iattr5 NUMBER(19, 0) DEFAULT NULL,
+ u_iattr6 NUMBER(19, 0) DEFAULT NULL,
+ u_iattr7 NUMBER(19, 0) DEFAULT NULL,
PRIMARY KEY (u_id)
);
CREATE INDEX IDX_USERACCT_REGION ON USERACCT (u_id, u_r_id);
-- ================================================================
-- USERACCT_ATTRIBUTES
--- Represents user's attributes
+-- Represents user's attributes
-- ================================================================
CREATE TABLE USERACCT_ATTRIBUTES (
- ua_id INT NOT NULL,
- ua_u_id INT NOT NULL REFERENCES USERACCT (u_id),
- ua_name VARCHAR(32) NOT NULL,
- ua_value VARCHAR(32) NOT NULL,
+ ua_id NUMBER(19, 0) NOT NULL,
+ ua_u_id VARCHAR2(128) NOT NULL REFERENCES USERACCT (u_id),
+ ua_name VARCHAR2(32) NOT NULL,
+ ua_value VARCHAR2(32) NOT NULL,
u_created TIMESTAMP,
PRIMARY KEY (ua_id, ua_u_id)
);
@@ -102,9 +101,9 @@ CREATE TABLE USERACCT_ATTRIBUTES (
-- c_parent_id Parent category's ID
-- ================================================================
CREATE TABLE CATEGORY (
- c_id INT NOT NULL,
- c_name VARCHAR(50),
- c_parent_id INT REFERENCES CATEGORY (c_id),
+ c_id NUMBER(19, 0) NOT NULL,
+ c_name VARCHAR2(50),
+ c_parent_id NUMBER(19, 0) REFERENCES CATEGORY (c_id),
PRIMARY KEY (c_id)
);
@@ -116,9 +115,9 @@ CREATE TABLE CATEGORY (
-- gag_name Global attribute group's name
-- ================================================================
CREATE TABLE GLOBAL_ATTRIBUTE_GROUP (
- gag_id INT NOT NULL,
- gag_c_id INT NOT NULL REFERENCES CATEGORY (c_id),
- gag_name VARCHAR(100) NOT NULL,
+ gag_id VARCHAR2(128) NOT NULL,
+ gag_c_id NUMBER(19, 0) NOT NULL REFERENCES CATEGORY (c_id),
+ gag_name VARCHAR2(100) NOT NULL,
PRIMARY KEY (gag_id)
);
@@ -131,9 +130,9 @@ CREATE TABLE GLOBAL_ATTRIBUTE_GROUP (
-- gav_name Global attribute value's name
-- ================================================================
CREATE TABLE GLOBAL_ATTRIBUTE_VALUE (
- gav_id INT NOT NULL,
- gav_gag_id INT NOT NULL REFERENCES GLOBAL_ATTRIBUTE_GROUP (gag_id),
- gav_name VARCHAR(100) NOT NULL,
+ gav_id VARCHAR2(128) NOT NULL,
+ gav_gag_id VARCHAR2(128) NOT NULL REFERENCES GLOBAL_ATTRIBUTE_GROUP (gag_id),
+ gav_name VARCHAR2(100) NOT NULL,
PRIMARY KEY (gav_id, gav_gag_id)
);
@@ -156,31 +155,31 @@ CREATE TABLE GLOBAL_ATTRIBUTE_VALUE (
-- i_status Items' status (0 = open, 1 = wait for purchase, 2 = close)
-- ================================================================
CREATE TABLE ITEM (
- i_id INT NOT NULL,
- i_u_id INT NOT NULL REFERENCES USERACCT (u_id),
- i_c_id INT NOT NULL REFERENCES CATEGORY (c_id),
- i_name VARCHAR(100),
- i_description VARCHAR(1024),
- i_user_attributes VARCHAR(255) DEFAULT NULL,
+ i_id VARCHAR2(128) NOT NULL,
+ i_u_id VARCHAR2(128) NOT NULL REFERENCES USERACCT (u_id),
+ i_c_id NUMBER(19, 0) NOT NULL REFERENCES CATEGORY (c_id),
+ i_name VARCHAR2(100),
+ i_description VARCHAR2(1024),
+ i_user_attributes VARCHAR2(255) DEFAULT NULL,
i_initial_price FLOAT NOT NULL,
i_current_price FLOAT NOT NULL,
- i_num_bids INT,
- i_num_images INT,
- i_num_global_attrs INT,
- i_num_comments INT,
+ i_num_bids NUMBER(19, 0),
+ i_num_images NUMBER(19, 0),
+ i_num_global_attrs NUMBER(19, 0),
+ i_num_comments NUMBER(19, 0),
i_start_date TIMESTAMP,
i_end_date TIMESTAMP,
i_status INT DEFAULT 0,
i_created TIMESTAMP,
i_updated TIMESTAMP,
- i_iattr0 INT DEFAULT NULL,
- i_iattr1 INT DEFAULT NULL,
- i_iattr2 INT DEFAULT NULL,
- i_iattr3 INT DEFAULT NULL,
- i_iattr4 INT DEFAULT NULL,
- i_iattr5 INT DEFAULT NULL,
- i_iattr6 INT DEFAULT NULL,
- i_iattr7 INT DEFAULT NULL,
+ i_iattr0 NUMBER(19, 0) DEFAULT NULL,
+ i_iattr1 NUMBER(19, 0) DEFAULT NULL,
+ i_iattr2 NUMBER(19, 0) DEFAULT NULL,
+ i_iattr3 NUMBER(19, 0) DEFAULT NULL,
+ i_iattr4 NUMBER(19, 0) DEFAULT NULL,
+ i_iattr5 NUMBER(19, 0) DEFAULT NULL,
+ i_iattr6 NUMBER(19, 0) DEFAULT NULL,
+ i_iattr7 NUMBER(19, 0) DEFAULT NULL,
PRIMARY KEY (i_id, i_u_id)
);
CREATE INDEX IDX_ITEM_SELLER ON ITEM (i_u_id);
@@ -193,12 +192,12 @@ CREATE INDEX IDX_ITEM_SELLER ON ITEM (i_u_id);
-- ia_gav_id Global attribute value's ID
-- ================================================================
CREATE TABLE ITEM_ATTRIBUTE (
- ia_id INT NOT NULL,
- ia_i_id INT NOT NULL,
- ia_u_id INT NOT NULL,
- ia_gav_id INT NOT NULL,
- ia_gag_id INT NOT NULL,
- ia_sattr0 VARCHAR(64) DEFAULT NULL,
+ ia_id VARCHAR2(128) NOT NULL,
+ ia_i_id VARCHAR2(128) NOT NULL,
+ ia_u_id VARCHAR2(128) NOT NULL,
+ ia_gav_id VARCHAR2(128) NOT NULL,
+ ia_gag_id VARCHAR2(128) NOT NULL,
+ ia_sattr0 VARCHAR2(64) DEFAULT NULL,
FOREIGN KEY (ia_i_id, ia_u_id) REFERENCES ITEM (i_id, i_u_id),
FOREIGN KEY (ia_gav_id, ia_gag_id) REFERENCES GLOBAL_ATTRIBUTE_VALUE (gav_id, gav_gag_id),
PRIMARY KEY (ia_id, ia_i_id, ia_u_id)
@@ -212,10 +211,10 @@ CREATE TABLE ITEM_ATTRIBUTE (
-- ii_path Image's path
-- ================================================================
CREATE TABLE ITEM_IMAGE (
- ii_id INT NOT NULL,
- ii_i_id INT NOT NULL,
- ii_u_id INT NOT NULL,
- ii_sattr0 VARCHAR(128) NOT NULL,
+ ii_id VARCHAR2(128) NOT NULL,
+ ii_i_id VARCHAR2(128) NOT NULL,
+ ii_u_id VARCHAR2(128) NOT NULL,
+ ii_sattr0 VARCHAR2(128) NOT NULL,
FOREIGN KEY (ii_i_id, ii_u_id) REFERENCES ITEM (i_id, i_u_id),
PRIMARY KEY (ii_id, ii_i_id, ii_u_id)
);
@@ -231,17 +230,17 @@ CREATE TABLE ITEM_IMAGE (
-- ic_response Response from seller
-- ================================================================
CREATE TABLE ITEM_COMMENT (
- ic_id INT NOT NULL,
- ic_i_id INT NOT NULL,
- ic_u_id INT NOT NULL,
- ic_buyer_id INT NOT NULL REFERENCES USERACCT (u_id),
- ic_question VARCHAR(128) NOT NULL,
- ic_response VARCHAR(128) DEFAULT NULL,
+ ic_id NUMBER(19, 0) NOT NULL,
+ ic_i_id VARCHAR2(128) NOT NULL,
+ ic_u_id VARCHAR2(128) NOT NULL,
+ ic_buyer_id VARCHAR2(128) NOT NULL REFERENCES USERACCT (u_id),
+ ic_question VARCHAR2(128) NOT NULL,
+ ic_response VARCHAR2(128) DEFAULT NULL,
ic_created TIMESTAMP,
ic_updated TIMESTAMP,
FOREIGN KEY (ic_i_id, ic_u_id) REFERENCES ITEM (i_id, i_u_id),
PRIMARY KEY (ic_id, ic_i_id, ic_u_id)
-);
+);
-- CREATE INDEX IDX_ITEM_COMMENT ON ITEM_COMMENT (ic_i_id, ic_u_id);
-- ================================================================
@@ -256,10 +255,10 @@ CREATE TABLE ITEM_COMMENT (
-- ib_date Bid's date
-- ================================================================
CREATE TABLE ITEM_BID (
- ib_id INT NOT NULL,
- ib_i_id INT NOT NULL,
- ib_u_id INT NOT NULL,
- ib_buyer_id INT NOT NULL REFERENCES USERACCT (u_id),
+ ib_id NUMBER(19, 0) NOT NULL,
+ ib_i_id VARCHAR2(128) NOT NULL,
+ ib_u_id VARCHAR2(128) NOT NULL,
+ ib_buyer_id VARCHAR2(128) NOT NULL REFERENCES USERACCT (u_id),
ib_bid FLOAT NOT NULL,
ib_max_bid FLOAT NOT NULL,
ib_created TIMESTAMP,
@@ -273,11 +272,11 @@ CREATE TABLE ITEM_BID (
-- Cross-reference table to the current max bid for an auction
-- ================================================================
CREATE TABLE ITEM_MAX_BID (
- imb_i_id INT NOT NULL,
- imb_u_id INT NOT NULL,
- imb_ib_id INT NOT NULL,
- imb_ib_i_id INT NOT NULL,
- imb_ib_u_id INT NOT NULL,
+ imb_i_id VARCHAR2(128) NOT NULL,
+ imb_u_id VARCHAR2(128) NOT NULL,
+ imb_ib_id NUMBER(19, 0) NOT NULL,
+ imb_ib_i_id VARCHAR2(128) NOT NULL,
+ imb_ib_u_id VARCHAR2(128) NOT NULL,
imb_created TIMESTAMP,
imb_updated TIMESTAMP,
FOREIGN KEY (imb_i_id, imb_u_id) REFERENCES ITEM (i_id, i_u_id),
@@ -293,15 +292,15 @@ CREATE TABLE ITEM_MAX_BID (
-- ip_date Purchase's date
-- ================================================================
CREATE TABLE ITEM_PURCHASE (
- ip_id INT NOT NULL,
- ip_ib_id INT NOT NULL,
- ip_ib_i_id INT NOT NULL,
- ip_ib_u_id INT NOT NULL,
+ ip_id NUMBER(19, 0) NOT NULL,
+ ip_ib_id NUMBER(19, 0) NOT NULL,
+ ip_ib_i_id VARCHAR2(128) NOT NULL,
+ ip_ib_u_id VARCHAR2(128) NOT NULL,
ip_date TIMESTAMP,
FOREIGN KEY (ip_ib_id, ip_ib_i_id, ip_ib_u_id) REFERENCES ITEM_BID (ib_id, ib_i_id, ib_u_id),
- PRIMARY KEY (ip_id, ip_ib_id, ip_ib_i_id, ip_ib_u_id),
- UNIQUE (ip_ib_id, ip_ib_i_id, ip_ib_u_id)
+ PRIMARY KEY (ip_id, ip_ib_id, ip_ib_i_id, ip_ib_u_id)
);
+CREATE UNIQUE INDEX ids_item_purchase ON item_purchase(ip_ib_id, ip_ib_i_id, ip_ib_u_id);
-- ================================================================
-- USERACCT_FEEDBACK
@@ -315,13 +314,13 @@ CREATE TABLE ITEM_PURCHASE (
-- uf_comment Feedback by other user
-- ================================================================
CREATE TABLE USERACCT_FEEDBACK (
- uf_u_id INT NOT NULL REFERENCES USERACCT (u_id),
- uf_i_id INT NOT NULL,
- uf_i_u_id INT NOT NULL,
- uf_from_id INT NOT NULL REFERENCES USERACCT (u_id),
+ uf_u_id VARCHAR2(128) NOT NULL REFERENCES USERACCT (u_id),
+ uf_i_id VARCHAR2(128) NOT NULL,
+ uf_i_u_id VARCHAR2(128) NOT NULL,
+ uf_from_id VARCHAR2(128) NOT NULL REFERENCES USERACCT (u_id),
uf_rating NUMBER(5,0) NOT NULL,
uf_date TIMESTAMP,
- uf_sattr0 VARCHAR(80) NOT NULL,
+ uf_sattr0 VARCHAR2(80) NOT NULL,
FOREIGN KEY (uf_i_id, uf_i_u_id) REFERENCES ITEM (i_id, i_u_id),
PRIMARY KEY (uf_u_id, uf_i_id, uf_i_u_id, uf_from_id),
CHECK (uf_u_id <> uf_from_id)
@@ -332,13 +331,13 @@ CREATE TABLE USERACCT_FEEDBACK (
-- The items that a user has recently purchased
-- ================================================================
CREATE TABLE USERACCT_ITEM (
- ui_u_id INT NOT NULL REFERENCES USERACCT (u_id),
- ui_i_id INT NOT NULL,
- ui_i_u_id INT NOT NULL,
- ui_ip_id INT,
- ui_ip_ib_id INT,
- ui_ip_ib_i_id INT,
- ui_ip_ib_u_id INT,
+ ui_u_id VARCHAR2(128) NOT NULL REFERENCES USERACCT (u_id),
+ ui_i_id VARCHAR2(128) NOT NULL,
+ ui_i_u_id VARCHAR2(128) NOT NULL,
+ ui_ip_id NUMBER(19, 0),
+ ui_ip_ib_id NUMBER(19, 0),
+ ui_ip_ib_i_id VARCHAR2(128),
+ ui_ip_ib_u_id VARCHAR2(128),
ui_created TIMESTAMP,
FOREIGN KEY (ui_i_id, ui_i_u_id) REFERENCES ITEM (i_id, i_u_id),
FOREIGN KEY (ui_ip_id, ui_ip_ib_id, ui_ip_ib_i_id, ui_ip_ib_u_id) REFERENCES ITEM_PURCHASE (ip_id, ip_ib_id, ip_ib_i_id, ip_ib_u_id),
@@ -351,9 +350,9 @@ CREATE TABLE USERACCT_ITEM (
-- The items that a user is watching
-- ================================================================
CREATE TABLE USERACCT_WATCH (
- uw_u_id INT NOT NULL REFERENCES USERACCT (u_id),
- uw_i_id INT NOT NULL,
- uw_i_u_id INT NOT NULL,
+ uw_u_id VARCHAR2(128) NOT NULL REFERENCES USERACCT (u_id),
+ uw_i_id VARCHAR2(128) NOT NULL,
+ uw_i_u_id VARCHAR2(128) NOT NULL,
uw_created TIMESTAMP,
FOREIGN KEY (uw_i_id, uw_i_u_id) REFERENCES ITEM (i_id, i_u_id),
PRIMARY KEY (uw_u_id, uw_i_id, uw_i_u_id)
diff --git a/src/main/resources/benchmarks/auctionmark/dialect-oracle.xml b/src/main/resources/benchmarks/auctionmark/dialect-oracle.xml
index 983146fca..9423d8fc9 100644
--- a/src/main/resources/benchmarks/auctionmark/dialect-oracle.xml
+++ b/src/main/resources/benchmarks/auctionmark/dialect-oracle.xml
@@ -2,66 +2,83 @@
- SELECT i_id, i_current_price, i_end_date, i_num_bids, i_status FROM ITEM, CONFIG_PROFILE WHERE i_status = ? AND i_end_date <= cfp_loader_start AND ROWNUM <= 1000 ORDER BY i_end_date ASC
- SELECT i_id, i_current_price, i_end_date, i_num_bids, i_status FROM ITEM, CONFIG_PROFILE WHERE i_status = ? AND i_end_date > cfp_loader_start AND ROWNUM <= 1000 ORDER BY i_end_date ASC
+
+ SELECT i_id, i_current_price, i_end_date, i_num_bids, i_status FROM ITEM, CONFIG_PROFILE
+ WHERE i_status = ? AND i_end_date <= cfp_loader_start
+ ORDER BY i_end_date ASC FETCH NEXT 5000 ROWS ONLY
+
+
+ SELECT i_id, i_current_price, i_end_date, i_num_bids, i_status FROM ITEM, CONFIG_PROFILE
+ WHERE i_status = ? AND i_end_date > cfp_loader_start
+ ORDER BY i_end_date ASC FETCH NEXT 5000 ROWS ONLY
+
+
+
+
+ SELECT * FROM item_bid WHERE imb_i_id = ? AND imb_u_id = ?
+ ORDER BY ib_bid DESC FETCH NEXT 1 ROWS ONLY
+
+
+
+
+ SELECT i_u_id, i_name, i_current_price, i_num_bids, i_end_date, i_status FROM item
+ WHERE i_start_date BETWEEN ? AND ? AND i_status = ?
+ ORDER BY i_id ASC FETCH NEXT 100 ROWS ONLY
+
- SELECT i_id, i_u_id,i_name,i_current_price,i_num_bids,i_end_date,i_status
- uw_u_id, uw_created
- FROM USERACCT_WATCH, ITEM
- WHERE uw_u_id = ?
- AND uw_i_id = i_id AND uw_i_u_id = i_u_id
- AND ROWNUM <= 25
- ORDER BY i_end_date DESC
+ SELECT u_id, u_rating, u_created, u_balance, u_sattr0, u_sattr1, u_sattr2, u_sattr3, u_sattr4, r_name
+ FROM useracct, region
+ WHERE u_id = ? AND u_r_id = r_id
- SELECT u_id, u_rating, u_sattr0, u_sattr1, uf_rating, uf_date, uf_sattr0
- FROM USERACCT , USERACCT_FEEDBACK
- WHERE u_id = ? AND uf_u_id = u_id
- AND ROWNUM <= 25
- ORDER BY uf_date DESC
+ SELECT u_id, u_rating, u_sattr0, u_sattr1, uf_rating, uf_date, uf_sattr0
+ FROM USERACCT , USERACCT_FEEDBACK
+ WHERE u_id = ? AND uf_u_id = u_id
+ ORDER BY uf_date DESC
+ FETCH NEXT 25 ROWS ONLY
- SELECT i_id, i_u_id,i_name,i_current_price,i_num_bids,i_end_date,i_status,
- ic_id, ic_i_id, ic_u_id, ic_buyer_id, ic_question, ic_created
- FROM ITEM , ITEM_COMMENT
- WHERE i_u_id = ? AND i_status = ?
- AND i_id = ic_i_id AND i_u_id = ic_u_id AND ic_response IS NULL
- AND ROWNUM <= 25
- ORDER BY ic_created DESC
+ SELECT i_id, i_u_id,i_name,i_current_price,i_num_bids,i_end_date,i_status,
+ ic_id, ic_i_id, ic_u_id, ic_buyer_id, ic_question, ic_created
+ FROM ITEM , ITEM_COMMENT
+ WHERE i_u_id = ? AND i_status = ?
+ AND i_id = ic_i_id AND i_u_id = ic_u_id AND ic_response IS NULL
+ ORDER BY ic_created DESC
+ FETCH NEXT 25 ROWS ONLY
- SELECT i_id, i_u_id,i_name,i_current_price,i_num_bids,i_end_date,i_status
- FROM ITEM
- WHERE i_u_id = ?
- AND ROWNUM <= 25
- ORDER BY i_end_date DESC
+ SELECT i_id, i_u_id,i_name,i_current_price,i_num_bids,i_end_date,i_status
+ FROM ITEM
+ WHERE i_u_id = ?
+ ORDER BY i_end_date DESC
+ FETCH NEXT 25 ROWS ONLY
- SELECT i_id, i_u_id,i_name,i_current_price,i_num_bids,i_end_date,i_status
- FROM USERACCT_ITEM, ITEM
- WHERE ui_u_id = ?
- AND ui_i_id = i_id AND ui_i_u_id = i_u_id
- AND ROWNUM <= 25
- ORDER BY i_end_date DESC
+ SELECT i_id, i_u_id,i_name,i_current_price,i_num_bids,i_end_date,i_status
+ FROM USERACCT_ITEM, ITEM
+ WHERE ui_u_id = ?
+ AND ui_i_id = i_id AND ui_i_u_id = i_u_id
+ ORDER BY i_end_date DESC
+ FETCH NEXT 25 ROWS ONLY
- SELECT i_id, i_u_id,i_name,i_current_price,i_num_bids,i_end_date,i_status , uw_u_id, uw_created
- FROM USERACCT_WATCH, ITEM
- WHERE uw_u_id = ?
- AND uw_i_id = i_id AND uw_i_u_id = i_u_id
- AND ROWNUM <= 25
- ORDER BY i_end_date DESC
+ SELECT i_id, i_u_id,i_name,i_current_price,i_num_bids,i_end_date,i_status , uw_u_id, uw_created
+ FROM USERACCT_WATCH, ITEM
+ WHERE uw_u_id = ?
+ AND uw_i_id = i_id AND uw_i_u_id = i_u_id
+ ORDER BY i_end_date DESC
+ FETCH NEXT 25 ROWS ONLY
- SELECT i_id, i_u_id,i_name,i_current_price,i_num_bids,i_end_date,i_status
- FROM ITEM
- WHERE (i_start_date BETWEEN ? AND ?) AND i_status = ?
- AND ROWNUM <= 25
- ORDER BY i_id ASC
+ SELECT i_id, i_u_id,i_name,i_current_price,i_num_bids,i_end_date,i_status
+ FROM ITEM
+ WHERE (i_start_date BETWEEN ? AND ?) AND i_status = ?
+ ORDER BY i_id ASC
+ FETCH NEXT 100 ROWS ONLY
diff --git a/src/main/resources/benchmarks/chbenchmark/ddl-oracle.sql b/src/main/resources/benchmarks/chbenchmark/ddl-oracle.sql
new file mode 100644
index 000000000..7cb323154
--- /dev/null
+++ b/src/main/resources/benchmarks/chbenchmark/ddl-oracle.sql
@@ -0,0 +1,33 @@
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE supplier CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE nation CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE region CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+
+CREATE TABLE region (
+ r_regionkey int NOT NULL,
+ r_name char(55) NOT NULL,
+ r_comment char(152) NOT NULL,
+ PRIMARY KEY (r_regionkey)
+);
+
+CREATE TABLE nation (
+ n_nationkey int NOT NULL,
+ n_name char(25) NOT NULL,
+ n_regionkey int NOT NULL,
+ n_comment char(152) NOT NULL,
+ FOREIGN KEY (n_regionkey) REFERENCES region (r_regionkey) ON DELETE CASCADE,
+ PRIMARY KEY (n_nationkey)
+);
+CREATE INDEX n_rk ON nation (n_regionkey ASC);
+
+CREATE TABLE supplier (
+ su_suppkey int NOT NULL,
+ su_name char(25) NOT NULL,
+ su_address varchar(40) NOT NULL,
+ su_nationkey int NOT NULL,
+ su_phone char(15) NOT NULL,
+ su_acctbal numeric(12, 2) NOT NULL,
+ su_comment char(101) NOT NULL,
+ FOREIGN KEY (su_nationkey) REFERENCES nation (n_nationkey) ON DELETE CASCADE,
+ PRIMARY KEY (su_suppkey)
+);
+CREATE INDEX s_nk ON supplier (su_nationkey ASC);
diff --git a/src/main/resources/benchmarks/chbenchmark/dialect-oracle.xml b/src/main/resources/benchmarks/chbenchmark/dialect-oracle.xml
new file mode 100644
index 000000000..9d4559fd2
--- /dev/null
+++ b/src/main/resources/benchmarks/chbenchmark/dialect-oracle.xml
@@ -0,0 +1,205 @@
+
+
+
+
+
+ SELECT ol_number, sum(ol_quantity) AS sum_qty, sum(ol_amount) AS sum_amount, avg(ol_quantity) AS avg_qty,
+ avg(ol_amount) AS avg_amount, count(*) AS count_order
+ FROM order_line
+ WHERE ol_delivery_d > TO_DATE('2007-01-02 00:00:00', 'YYYY-MM-DD HH24:MI:SS')
+ GROUP BY ol_number
+ ORDER BY ol_number
+
+
+
+
+ SELECT su_suppkey, su_name, n_name, i_id, i_name, su_address, su_phone, su_comment
+ FROM item, supplier, stock, nation, region, (
+ SELECT s_i_id AS m_i_id, MIN(s_quantity) AS m_s_quantity
+ FROM stock, supplier, nation, region
+ WHERE MOD((s_w_id*s_i_id), 10000) = su_suppkey AND su_nationkey = n_nationkey
+ AND n_regionkey = r_regionkey AND r_name LIKE 'Europ%'
+ GROUP BY s_i_id) m
+ WHERE i_id = s_i_id AND MOD((s_w_id * s_i_id), 10000) = su_suppkey AND su_nationkey = n_nationkey
+ AND n_regionkey = r_regionkey AND i_data LIKE '%b' AND r_name LIKE 'Europ%' AND i_id=m_i_id
+ AND s_quantity = m_s_quantity
+ ORDER BY n_name, su_name, i_id
+
+
+
+
+ SELECT ol_o_id, ol_w_id, ol_d_id, sum(ol_amount) AS revenue, o_entry_d
+ FROM customer, new_order, oorder, order_line
+ WHERE c_state LIKE 'A%' AND c_id = o_c_id AND c_w_id = o_w_id AND c_d_id = o_d_id AND no_w_id = o_w_id
+ AND no_d_id = o_d_id AND no_o_id = o_id AND ol_w_id = o_w_id AND ol_d_id = o_d_id AND ol_o_id = o_id
+ AND o_entry_d > TO_DATE('2007-01-02 00:00:00', 'YYYY-MM-DD HH24:MI:SS')
+ GROUP BY ol_o_id, ol_w_id, ol_d_id, o_entry_d
+ ORDER BY revenue DESC , o_entry_d
+
+
+
+
+ SELECT n_name, sum(ol_amount) AS revenue
+ FROM customer, oorder, order_line, stock, supplier, nation, region
+ WHERE c_id = o_c_id AND c_w_id = o_w_id AND c_d_id = o_d_id AND ol_o_id = o_id AND ol_w_id = o_w_id
+ AND ol_d_id=o_d_id AND ol_w_id = s_w_id AND ol_i_id = s_i_id
+ AND MOD((s_w_id * s_i_id), 10000) = su_suppkey
+ AND ascii(substr(c_state, 1, 1)) = su_nationkey AND su_nationkey = n_nationkey AND n_regionkey = r_regionkey AND r_name = 'Europe'
+ AND o_entry_d >= TO_DATE('2007-01-02 00:00:00', 'YYYY-MM-DD HH24:MI:SS')
+ GROUP BY n_name ORDER BY revenue DESC
+
+
+
+
+ SELECT sum(ol_amount) AS revenue FROM order_line WHERE ol_delivery_d >= to_date('1999-01-01 00:00:00', 'YYYY-MM-DD HH24:MI:SS')
+ AND to_date('2020-01-01 00:00:00', 'YYYY-MM-DD HH24:MI:SS') > ol_delivery_d AND ol_quantity BETWEEN 1 AND 100000
+
+
+
+
+ SELECT su_nationkey AS supp_nation, substr(c_state, 1, 1) AS cust_nation, extract(YEAR FROM o_entry_d) AS l_year,
+ sum(ol_amount) AS revenue
+ FROM supplier, stock, order_line, oorder, customer, nation n1, nation n2
+ WHERE ol_supply_w_id = s_w_id AND ol_i_id = s_i_id AND MOD ((s_w_id * s_i_id), 10000) = su_suppkey
+ AND ol_w_id = o_w_id AND ol_d_id = o_d_id AND ol_o_id = o_id AND c_id = o_c_id AND c_w_id = o_w_id
+ AND c_d_id = o_d_id AND su_nationkey = n1.n_nationkey AND ascii(substr(c_state, 1, 1)) = n2.n_nationkey
+ AND (
+ (n1.n_name = 'Germany' AND n2.n_name = 'Cambodia')
+ OR
+ (n1.n_name = 'Cambodia' AND n2.n_name = 'Germany')
+ )
+ GROUP BY su_nationkey, cust_nation, l_year
+ ORDER BY su_nationkey, cust_nation, l_year
+
+
+
+
+ SELECT extract(YEAR FROM o_entry_d) AS l_year, sum(
+ CASE WHEN n2.n_name = 'Germany' THEN ol_amount ELSE 0 END
+ ) / sum(ol_amount) AS mkt_share
+ FROM item, supplier, stock, order_line, oorder, customer, nation n1, nation n2, region
+ WHERE i_id = s_i_id AND ol_i_id = s_i_id AND ol_supply_w_id = s_w_id AND MOD ((s_w_id * s_i_id), 10000) = su_suppkey
+ AND ol_w_id = o_w_id AND ol_d_id = o_d_id AND ol_o_id = o_id AND c_id = o_c_id AND c_w_id = o_w_id
+ AND c_d_id = o_d_id AND n1.n_nationkey = ascii(substr(c_state, 1, 1)) AND n1.n_regionkey = r_regionkey
+ AND 1000 > ol_i_id AND r_name = 'Europe' AND su_nationkey = n2.n_nationkey AND i_data LIKE '%b' AND i_id = ol_i_id
+ GROUP BY l_year ORDER BY l_year
+
+
+
+
+ SELECT n_name, extract(YEAR FROM o_entry_d) AS l_year, sum(ol_amount) AS sum_profit
+ FROM item, stock, supplier, order_line, oorder, nation
+ WHERE ol_i_id = s_i_id AND ol_supply_w_id = s_w_id AND MOD ((s_w_id * s_i_id), 10000) = su_suppkey
+ AND ol_w_id = o_w_id AND ol_d_id = o_d_id AND ol_o_id = o_id AND ol_i_id = i_id AND su_nationkey = n_nationkey
+ AND i_data LIKE '%bb'
+ GROUP BY n_name, l_year ORDER BY n_name, l_year DESC
+
+
+
+
+ SELECT c_id, c_last, sum(ol_amount) AS revenue, c_city, c_phone, n_name
+ FROM customer, oorder, order_line, nation
+ WHERE c_id = o_c_id AND c_w_id = o_w_id AND c_d_id = o_d_id AND ol_w_id = o_w_id AND ol_d_id = o_d_id
+ AND ol_o_id = o_id AND o_entry_d >= TO_DATE('2007-01-02 00:00:00', 'YYYY-MM-DD HH24:MI:SS')
+ AND ol_delivery_d >= o_entry_d AND n_nationkey = ascii(substr(c_state, 1, 1))
+ GROUP BY c_id, c_last, c_city, c_phone, n_name ORDER BY revenue DESC
+
+
+
+
+ SELECT o_ol_cnt, sum(CASE WHEN o_carrier_id = 1 OR o_carrier_id = 2 THEN 1 ELSE 0 END) AS high_line_count,
+ sum(CASE WHEN o_carrier_id != 1 AND o_carrier_id != 2 THEN 1 ELSE 0 END) AS low_line_count
+ FROM oorder, order_line
+ WHERE ol_w_id = o_w_id AND ol_d_id = o_d_id AND ol_o_id = o_id AND ol_delivery_d >= o_entry_d
+ AND TO_DATE('2020-01-01 00:00:00', 'YYYY-MM-DD HH24:MI:SS') > ol_delivery_d
+ GROUP BY o_ol_cnt ORDER BY o_ol_cnt
+
+
+
+
+ SELECT c_count, count(*) AS custdist FROM (
+ SELECT c_id, count(o_id) AS c_count
+ FROM customer LEFT OUTER JOIN oorder ON
+ (c_w_id = o_w_id AND c_d_id = o_d_id AND c_id = o_c_id AND o_carrier_id > 8)
+ GROUP BY c_id
+ )
+ GROUP BY c_count
+ ORDER BY custdist DESC, c_count DESC
+
+
+
+
+ SELECT (100.00 * sum(CASE WHEN i_data LIKE 'PR%' THEN ol_amount ELSE 0 END) / (1 + sum(ol_amount))) AS promo_revenue
+ FROM order_line, item
+ WHERE ol_i_id = i_id AND ol_delivery_d >= TO_DATE('2007-01-02 00:00:00', 'YYYY-MM-DD HH24:MI:SS')
+ AND TO_DATE('2020-01-02', 'YYYY-MM-DD HH24:MI:SS') > ol_delivery_d
+
+
+
+
+ CREATE view revenue0 (supplier_no, total_revenue) AS
+ SELECT mod((s_w_id * s_i_id),10000) as supplier_no, sum(ol_amount) as total_revenue
+ FROM order_line, stock
+ WHERE ol_i_id = s_i_id AND ol_supply_w_id = s_w_id
+ AND ol_delivery_d >= to_date('2007-01-02 00:00:00', 'YYYY-MM-DD HH24:MI:SS')
+ GROUP BY mod((s_w_id * s_i_id),10000)
+
+
+
+
+ SELECT i_name, substr(i_data, 1, 3) as brand, i_price, count(DISTINCT (mod((s_w_id * s_i_id),10000))) AS supplier_cnt
+ FROM stock, item
+ WHERE i_id = s_i_id AND i_data NOT LIKE 'zz%' AND (mod((s_w_id * s_i_id),10000) NOT IN
+ (SELECT su_suppkey FROM supplier WHERE su_comment LIKE '%bad%')
+ )
+ GROUP BY i_name, substr(i_data, 1, 3), i_price ORDER BY supplier_cnt DESC
+
+
+
+
+ SELECT sum(ol_amount) AS revenue
+ FROM order_line, item
+ WHERE (
+ ol_i_id = i_id AND i_data LIKE '%a' AND ol_quantity >= 1 AND 10 >= ol_quantity
+ AND i_price BETWEEN 1 AND 400000 AND ol_w_id IN (1, 2, 3)
+ ) OR (
+ ol_i_id = i_id AND i_data LIKE '%b' AND ol_quantity >= 1 AND 10 >= ol_quantity
+ AND i_price BETWEEN 1 AND 400000 AND ol_w_id IN (1, 2, 4)
+ ) OR (
+ ol_i_id = i_id AND i_data LIKE '%c' AND ol_quantity >= 1 AND 10 >= ol_quantity
+ AND i_price BETWEEN 1 AND 400000 AND ol_w_id IN (1, 5, 3)
+ )
+
+
+
+
+ SELECT su_name, su_address FROM supplier, nation
+ WHERE su_suppkey IN (
+ SELECT mod(s_i_id * s_w_id, 10000)
+ FROM stock INNER JOIN item ON i_id = s_i_id INNER JOIN order_line ON ol_i_id = s_i_id
+ WHERE ol_delivery_d > TO_DATE('2010-05-23 12:00:00', 'YYYY-MM-DD HH24:MI:SS') AND i_data LIKE 'co%'
+ GROUP BY s_i_id, s_w_id, s_quantity
+ HAVING 2*s_quantity > sum(ol_quantity)
+ ) AND su_nationkey = n_nationkey AND n_name = 'Germany'
+ ORDER BY su_name
+
+
+
+
+ SELECT substr(c_state,1,1) AS country, count(*) AS numcust, sum(c_balance) AS totacctbal
+ FROM customer
+ WHERE substr(c_phone,1,1) IN ('1', '2', '3', '4', '5', '6', '7')
+ AND c_balance > (
+ SELECT avg(c_balance)
+ FROM customer
+ WHERE c_balance > 0.00 AND substr(c_phone,1,1) IN ('1', '2', '3', '4', '5', '6', '7'))
+ AND NOT EXISTS (
+ SELECT * FROM oorder
+ WHERE o_c_id = c_id AND o_w_id = c_w_id AND o_d_id = c_d_id
+ )
+ GROUP BY substr(c_state,1,1)
+ ORDER BY substr(c_state,1,1)
+
+
+
+
\ No newline at end of file
diff --git a/src/main/resources/benchmarks/epinions/ddl-oracle.sql b/src/main/resources/benchmarks/epinions/ddl-oracle.sql
index 4b80c8c67..5e3db2b96 100644
--- a/src/main/resources/benchmarks/epinions/ddl-oracle.sql
+++ b/src/main/resources/benchmarks/epinions/ddl-oracle.sql
@@ -2,15 +2,15 @@
-- Drop all tables
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE "review"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE "review_rating"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE "trust"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE "item"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE "useracct"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE review CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE review_rating CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE trust CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE item CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE useracct CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-- create tables
-CREATE TABLE "useracct" (
+CREATE TABLE useracct (
u_id number(11,0) NOT NULL,
name varchar(128) NOT NULL,
email varchar(128) NOT NULL,
@@ -18,7 +18,7 @@ CREATE TABLE "useracct" (
PRIMARY KEY (u_id)
);
-CREATE TABLE "item" (
+CREATE TABLE item (
i_id number(11,0) NOT NULL,
title varchar(128) NOT NULL,
description varchar(512) DEFAULT NULL,
@@ -26,18 +26,18 @@ CREATE TABLE "item" (
PRIMARY KEY (i_id)
);
-CREATE TABLE "review" (
+CREATE TABLE review (
a_id number(11,0) NOT NULL,
- u_id number(11,0) NOT NULL REFERENCES "useracct" (u_id),
- i_id number(11,0) NOT NULL REFERENCES "item" (i_id),
+ u_id number(11,0) NOT NULL REFERENCES useracct (u_id),
+ i_id number(11,0) NOT NULL REFERENCES item (i_id),
rating number(11,0) DEFAULT NULL,
rank number(11,0) DEFAULT NULL,
- comment varchar(256) DEFAULT NULL,
+ "comment" varchar(256) DEFAULT NULL,
creation_date date DEFAULT NULL
);
-CREATE TABLE "review_rating" (
- u_id number(11,0) NOT NULL REFERENCES "useracct" (u_id),
+CREATE TABLE review_rating (
+ u_id number(11,0) NOT NULL REFERENCES useracct (u_id),
a_id number(11,0) NOT NULL,
rating number(11,0) NOT NULL,
status number(11,0) NOT NULL,
@@ -47,20 +47,20 @@ CREATE TABLE "review_rating" (
vertical_id number(11,0) DEFAULT NULL
);
-CREATE TABLE "trust" (
- source_u_id number(11,0) NOT NULL REFERENCES "useracct" (u_id),
- target_u_id number(11,0) NOT NULL REFERENCES "useracct" (u_id),
+CREATE TABLE trust (
+ source_u_id number(11,0) NOT NULL REFERENCES useracct (u_id),
+ target_u_id number(11,0) NOT NULL REFERENCES useracct (u_id),
trust number(11,0) NOT NULL,
creation_date date DEFAULT NULL
);
-- create indexes
-CREATE INDEX IDX_REVIEW_RATING_UID ON "review_rating" (u_id);
-CREATE INDEX IDX_REVIEW_RATING_AID ON "review_rating" (a_id);
-CREATE INDEX IDX_TRUST_SID ON "trust" (source_u_id);
-CREATE INDEX IDX_TRUST_TID ON "trust" (target_u_id);
-CREATE INDEX IDX_RATING_UID ON "review" (u_id);
-CREATE INDEX IDX_RATING_AID ON "review" (a_id);
-CREATE INDEX IDX_RATING_IID ON "review" (i_id);
+CREATE INDEX IDX_REVIEW_RATING_UID ON review_rating (u_id);
+CREATE INDEX IDX_REVIEW_RATING_AID ON review_rating (a_id);
+CREATE INDEX IDX_TRUST_SID ON trust (source_u_id);
+CREATE INDEX IDX_TRUST_TID ON trust (target_u_id);
+CREATE INDEX IDX_RATING_UID ON review (u_id);
+CREATE INDEX IDX_RATING_AID ON review (a_id);
+CREATE INDEX IDX_RATING_IID ON review (i_id);
diff --git a/src/main/resources/benchmarks/epinions/dialect-oracle.xml b/src/main/resources/benchmarks/epinions/dialect-oracle.xml
index 749c1901a..6f32b3b82 100644
--- a/src/main/resources/benchmarks/epinions/dialect-oracle.xml
+++ b/src/main/resources/benchmarks/epinions/dialect-oracle.xml
@@ -3,54 +3,56 @@
- SELECT avg(rating) FROM "review" r, "trust" t WHERE r.u_id=t.target_u_id AND r.i_id=? AND t.source_u_id=?
+ SELECT avg(rating) FROM review r, trust t WHERE r.u_id=t.target_u_id AND r.i_id=? AND t.source_u_id=?
- SELECT avg(rating) FROM "review" r WHERE r.i_id=?
+ SELECT avg(rating) FROM review r WHERE r.i_id=?
- SELECT * FROM "review" r WHERE r.i_id=? ORDER BY creation_date DESC
+ SELECT * FROM review r WHERE r.i_id=? ORDER BY creation_date DESC
- SELECT * FROM "trust" t WHERE t.source_u_id=?
+ SELECT * FROM trust t WHERE t.source_u_id=?
-
+
- SELECT * FROM "review" r, "item" i WHERE i.i_id = r.i_id and r.i_id=? AND ROWNUM <= 10
+ SELECT * FROM review r, item i WHERE i.i_id = r.i_id and r.i_id=?
ORDER BY rating DESC, r.creation_date DESC
+ FETCH NEXT 10 ROWS ONLY
- SELECT * FROM "review" r, "useracct" u WHERE u.u_id = r.u_id AND r.u_id=? AND ROWNUM <= 10
+ SELECT * FROM review r, useracct u WHERE u.u_id = r.u_id AND r.u_id=?
ORDER BY rating DESC, r.creation_date DESC
+ FETCH NEXT 10 ROWS ONLY
- UPDATE "item" SET title = ? WHERE i_id=?
+ UPDATE item SET title = ? WHERE i_id=?
- UPDATE "review" SET rating = ? WHERE i_id=? AND u_id=?
+ UPDATE review SET rating = ? WHERE i_id=? AND u_id=?
- UPDATE "trust" SET trust = ? WHERE source_u_id=? AND target_u_id=?
+ UPDATE trust SET trust = ? WHERE source_u_id=? AND target_u_id=?
- UPDATE "useracct" SET name = ? WHERE u_id=?
+ UPDATE useracct SET name = ? WHERE u_id=?
-
+
diff --git a/src/main/resources/benchmarks/gather_schema_stats_oracle.sql b/src/main/resources/benchmarks/gather_schema_stats_oracle.sql
new file mode 100644
index 000000000..0196f2cf6
--- /dev/null
+++ b/src/main/resources/benchmarks/gather_schema_stats_oracle.sql
@@ -0,0 +1,3 @@
+-- Gather optimizer statistics to improve performance
+-- Sample config for tpch/chbenchmark should already include afterload option to execute this query
+BEGIN dbms_stats.gather_schema_stats(ownname => 'benchbase', estimate_percent => dbms_stats.auto_sample_size, method_opt => 'for all columns size AUTO'); END;;
\ No newline at end of file
diff --git a/src/main/resources/benchmarks/hyadapt/ddl-oracle.sql b/src/main/resources/benchmarks/hyadapt/ddl-oracle.sql
new file mode 100644
index 000000000..3e49ee17b
--- /dev/null
+++ b/src/main/resources/benchmarks/hyadapt/ddl-oracle.sql
@@ -0,0 +1,255 @@
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE htable'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+
+CREATE TABLE htable (
+ h_key int PRIMARY KEY,
+ field1 int,
+ field2 int,
+ field3 int,
+ field4 int,
+ field5 int,
+ field6 int,
+ field7 int,
+ field8 int,
+ field9 int,
+ field10 int,
+ field11 int,
+ field12 int,
+ field13 int,
+ field14 int,
+ field15 int,
+ field16 int,
+ field17 int,
+ field18 int,
+ field19 int,
+ field20 int,
+ field21 int,
+ field22 int,
+ field23 int,
+ field24 int,
+ field25 int,
+ field26 int,
+ field27 int,
+ field28 int,
+ field29 int,
+ field30 int,
+ field31 int,
+ field32 int,
+ field33 int,
+ field34 int,
+ field35 int,
+ field36 int,
+ field37 int,
+ field38 int,
+ field39 int,
+ field40 int,
+ field41 int,
+ field42 int,
+ field43 int,
+ field44 int,
+ field45 int,
+ field46 int,
+ field47 int,
+ field48 int,
+ field49 int,
+ field50 int,
+ field51 int,
+ field52 int,
+ field53 int,
+ field54 int,
+ field55 int,
+ field56 int,
+ field57 int,
+ field58 int,
+ field59 int,
+ field60 int,
+ field61 int,
+ field62 int,
+ field63 int,
+ field64 int,
+ field65 int,
+ field66 int,
+ field67 int,
+ field68 int,
+ field69 int,
+ field70 int,
+ field71 int,
+ field72 int,
+ field73 int,
+ field74 int,
+ field75 int,
+ field76 int,
+ field77 int,
+ field78 int,
+ field79 int,
+ field80 int,
+ field81 int,
+ field82 int,
+ field83 int,
+ field84 int,
+ field85 int,
+ field86 int,
+ field87 int,
+ field88 int,
+ field89 int,
+ field90 int,
+ field91 int,
+ field92 int,
+ field93 int,
+ field94 int,
+ field95 int,
+ field96 int,
+ field97 int,
+ field98 int,
+ field99 int,
+ field100 int,
+ field101 int,
+ field102 int,
+ field103 int,
+ field104 int,
+ field105 int,
+ field106 int,
+ field107 int,
+ field108 int,
+ field109 int,
+ field110 int,
+ field111 int,
+ field112 int,
+ field113 int,
+ field114 int,
+ field115 int,
+ field116 int,
+ field117 int,
+ field118 int,
+ field119 int,
+ field120 int,
+ field121 int,
+ field122 int,
+ field123 int,
+ field124 int,
+ field125 int,
+ field126 int,
+ field127 int,
+ field128 int,
+ field129 int,
+ field130 int,
+ field131 int,
+ field132 int,
+ field133 int,
+ field134 int,
+ field135 int,
+ field136 int,
+ field137 int,
+ field138 int,
+ field139 int,
+ field140 int,
+ field141 int,
+ field142 int,
+ field143 int,
+ field144 int,
+ field145 int,
+ field146 int,
+ field147 int,
+ field148 int,
+ field149 int,
+ field150 int,
+ field151 int,
+ field152 int,
+ field153 int,
+ field154 int,
+ field155 int,
+ field156 int,
+ field157 int,
+ field158 int,
+ field159 int,
+ field160 int,
+ field161 int,
+ field162 int,
+ field163 int,
+ field164 int,
+ field165 int,
+ field166 int,
+ field167 int,
+ field168 int,
+ field169 int,
+ field170 int,
+ field171 int,
+ field172 int,
+ field173 int,
+ field174 int,
+ field175 int,
+ field176 int,
+ field177 int,
+ field178 int,
+ field179 int,
+ field180 int,
+ field181 int,
+ field182 int,
+ field183 int,
+ field184 int,
+ field185 int,
+ field186 int,
+ field187 int,
+ field188 int,
+ field189 int,
+ field190 int,
+ field191 int,
+ field192 int,
+ field193 int,
+ field194 int,
+ field195 int,
+ field196 int,
+ field197 int,
+ field198 int,
+ field199 int,
+ field200 int,
+ field201 int,
+ field202 int,
+ field203 int,
+ field204 int,
+ field205 int,
+ field206 int,
+ field207 int,
+ field208 int,
+ field209 int,
+ field210 int,
+ field211 int,
+ field212 int,
+ field213 int,
+ field214 int,
+ field215 int,
+ field216 int,
+ field217 int,
+ field218 int,
+ field219 int,
+ field220 int,
+ field221 int,
+ field222 int,
+ field223 int,
+ field224 int,
+ field225 int,
+ field226 int,
+ field227 int,
+ field228 int,
+ field229 int,
+ field230 int,
+ field231 int,
+ field232 int,
+ field233 int,
+ field234 int,
+ field235 int,
+ field236 int,
+ field237 int,
+ field238 int,
+ field239 int,
+ field240 int,
+ field241 int,
+ field242 int,
+ field243 int,
+ field244 int,
+ field245 int,
+ field246 int,
+ field247 int,
+ field248 int,
+ field249 int,
+ field250 int
+);
\ No newline at end of file
diff --git a/src/main/resources/benchmarks/noop/ddl-oracle.sql b/src/main/resources/benchmarks/noop/ddl-oracle.sql
new file mode 100644
index 000000000..e3065812d
--- /dev/null
+++ b/src/main/resources/benchmarks/noop/ddl-oracle.sql
@@ -0,0 +1,6 @@
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE fake'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+
+CREATE TABLE fake (
+ id INT NOT NULL,
+ PRIMARY KEY (id)
+);
diff --git a/src/main/resources/benchmarks/noop/dialect-oracle.xml b/src/main/resources/benchmarks/noop/dialect-oracle.xml
new file mode 100644
index 000000000..7a0a33e52
--- /dev/null
+++ b/src/main/resources/benchmarks/noop/dialect-oracle.xml
@@ -0,0 +1,10 @@
+
+
+
+
+
+ SELECT 1 FROM DUAL;
+
+
+
+
diff --git a/src/main/resources/benchmarks/otmetrics/ddl-oracle.sql b/src/main/resources/benchmarks/otmetrics/ddl-oracle.sql
new file mode 100644
index 000000000..910238521
--- /dev/null
+++ b/src/main/resources/benchmarks/otmetrics/ddl-oracle.sql
@@ -0,0 +1,39 @@
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE observations CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE types CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE sessions CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE sources CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+
+CREATE TABLE sources (
+ id INT NOT NULL,
+ name VARCHAR(128) NOT NULL UNIQUE,
+ comments VARCHAR(256) DEFAULT NULL,
+ created_time TIMESTAMP NOT NULL,
+ PRIMARY KEY (id)
+);
+
+CREATE TABLE types (
+ id INT NOT NULL,
+ category INT NOT NULL,
+ value_type INT NOT NULL,
+ name VARCHAR(64) NOT NULL,
+ comments VARCHAR(256) DEFAULT NULL,
+ PRIMARY KEY (id),
+ UNIQUE (category, name)
+);
+
+CREATE TABLE sessions (
+ id INT NOT NULL,
+ source_id INT NOT NULL REFERENCES sources (id),
+ agent VARCHAR(32) NOT NULL,
+ created_time TIMESTAMP NOT NULL,
+ PRIMARY KEY (id)
+);
+
+CREATE TABLE observations (
+ source_id INT NOT NULL REFERENCES sources (id),
+ session_id INT NOT NULL REFERENCES sessions (id),
+ type_id INT NOT NULL REFERENCES types (id),
+ value NUMBER(38) NOT NULL,
+ created_time TIMESTAMP NOT NULL
+);
+CREATE INDEX idx_observations_source_session ON observations (source_id, session_id, type_id);
\ No newline at end of file
diff --git a/src/main/resources/benchmarks/resourcestresser/ddl-oracle.sql b/src/main/resources/benchmarks/resourcestresser/ddl-oracle.sql
index 104503962..d72a84536 100644
--- a/src/main/resources/benchmarks/resourcestresser/ddl-oracle.sql
+++ b/src/main/resources/benchmarks/resourcestresser/ddl-oracle.sql
@@ -1,9 +1,9 @@
-- Drop all tables
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE "cputable"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE "iotable"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE "iotablesmallrow"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE "locktable"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE cputable'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE iotable'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE iotablesmallrow'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE locktable'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-- Create table
@@ -48,22 +48,20 @@ CREATE TABLE locktable (
-- Procedures
-create or replace
-function md5raw (text in varchar2)
-return varchar2 is
-hash_value varchar2(20);
-begin
- hash_value := dbms_obfuscation_toolkit.md5 (input_string => text);
- return hash_value;
-end;
+-- See https://docs.oracle.com/en/database/oracle/oracle-database/23/arpls/DBMS_CRYPTO.html
+-- DBMS_OBFUSCATION_TOOLKIT is deprecated, using DBMS_CRYPTO
+
+-- MD5 is deprecated for Oracle 23c onwards, potentially change to SHA-2 using DBMS_CRYPTO.HASH_SH256.
+-- The procedure name however should still be kept as "md5".
+
+-- Current (Oct 5, 2023) dialect file cannot change the function name as it can only change the SQL string
+-- inside SQLStmt, but related SQL for this procedure is constructed outside.
create or replace
function md5(text in varchar2)
-return varchar2 is
-hash_value varchar2(32);
-begin
- select lower(rawtohex(md5raw(text)))
- into hash_value
- from dual;
- return hash_value;
-end;
+return varchar2 is hash_value varchar2(32)
+;begin
+select lower(UTL_I18N.RAW_TO_CHAR (DBMS_CRYPTO.HASH(text, DBMS_CRYPTO.HASH_MD5), 'AL32UTF8'))
+into hash_value from dual
+;return hash_value
+;end;;
diff --git a/src/main/resources/benchmarks/seats/ddl-oracle.sql b/src/main/resources/benchmarks/seats/ddl-oracle.sql
index f3b8fda73..7bd420092 100644
--- a/src/main/resources/benchmarks/seats/ddl-oracle.sql
+++ b/src/main/resources/benchmarks/seats/ddl-oracle.sql
@@ -1,15 +1,15 @@
-- DROP TABLE
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE CONFIG_PROFILE'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE CONFIG_HISTOGRAMS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE AIRPORT_DISTANCE'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE FREQUENT_FLYER'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE RESERVATION'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE CONFIG_PROFILE CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE CONFIG_HISTOGRAMS CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE AIRPORT_DISTANCE CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE FREQUENT_FLYER CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE RESERVATION CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
BEGIN EXECUTE IMMEDIATE 'DROP TABLE AIRLINE CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE FLIGHT'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE CUSTOMER'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE AIRPORT'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE COUNTRY'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE FLIGHT CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE CUSTOMER CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE AIRPORT CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE COUNTRY CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
--
CREATE TABLE CONFIG_PROFILE (
CFP_SCALE_FACTOR FLOAT NOT NULL,
@@ -20,7 +20,7 @@ CREATE TABLE CONFIG_PROFILE (
CFP_FLIGHT_FUTURE_DAYS INT NOT NULL,
CFP_FLIGHT_OFFSET INT,
CFP_RESERVATION_OFFSET INT,
- CFP_NUM_RESERVATIONS INT NOT NULL,
+ CFP_NUM_RESERVATIONS NUMBER(19, 0) NOT NULL,
CFP_CODE_IDS_XREFS CLOB NOT NULL
);
@@ -34,7 +34,7 @@ CREATE TABLE CONFIG_HISTOGRAMS (
PRIMARY KEY (CFH_NAME)
);
---
+--
-- COUNTRY
--
CREATE TABLE COUNTRY (
@@ -121,7 +121,7 @@ CREATE TABLE AIRLINE (
-- CUSTOMER
--
CREATE TABLE CUSTOMER (
- C_ID NUMBER(19,0) NOT NULL,
+ C_ID VARCHAR2(128) NOT NULL,
C_ID_STR VARCHAR2(64) UNIQUE NOT NULL,
C_BASE_AP_ID NUMBER(19,0) REFERENCES AIRPORT (AP_ID),
C_BALANCE FLOAT NOT NULL,
@@ -172,7 +172,7 @@ CREATE TABLE CUSTOMER (
-- FREQUENT_FLYER
--
CREATE TABLE FREQUENT_FLYER (
- FF_C_ID NUMBER(19,0) NOT NULL REFERENCES CUSTOMER (C_ID),
+ FF_C_ID VARCHAR2(128) NOT NULL REFERENCES CUSTOMER (C_ID),
FF_AL_ID NUMBER(19,0) NOT NULL REFERENCES AIRLINE (AL_ID),
FF_C_ID_STR VARCHAR2(64) NOT NULL,
FF_SATTR00 VARCHAR2(32),
@@ -203,7 +203,7 @@ CREATE INDEX IDX_FF_CUSTOMER_ID ON FREQUENT_FLYER (FF_C_ID_STR);
-- FLIGHT
--
CREATE TABLE FLIGHT (
- F_ID NUMBER(19,0) NOT NULL,
+ F_ID VARCHAR2(128) NOT NULL,
F_AL_ID NUMBER(19,0) NOT NULL REFERENCES AIRLINE (AL_ID),
F_DEPART_AP_ID NUMBER(19,0) NOT NULL REFERENCES AIRPORT (AP_ID),
F_DEPART_TIME TIMESTAMP NOT NULL,
@@ -252,8 +252,8 @@ CREATE INDEX F_DEPART_TIME_IDX ON FLIGHT (F_DEPART_TIME);
--
CREATE TABLE RESERVATION (
R_ID NUMBER(19,0) NOT NULL,
- R_C_ID NUMBER(19,0) NOT NULL REFERENCES CUSTOMER (C_ID),
- R_F_ID NUMBER(19,0) NOT NULL REFERENCES FLIGHT (F_ID),
+ R_C_ID VARCHAR2(128) NOT NULL REFERENCES CUSTOMER (C_ID),
+ R_F_ID VARCHAR2(128) NOT NULL REFERENCES FLIGHT (F_ID),
R_SEAT NUMBER(19,0) NOT NULL,
R_PRICE FLOAT NOT NULL,
R_IATTR00 NUMBER(19,0),
diff --git a/src/main/resources/benchmarks/sibench/ddl-oracle.sql b/src/main/resources/benchmarks/sibench/ddl-oracle.sql
new file mode 100644
index 000000000..d3a7c75d8
--- /dev/null
+++ b/src/main/resources/benchmarks/sibench/ddl-oracle.sql
@@ -0,0 +1,6 @@
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE sitest'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+
+CREATE TABLE sitest (
+ id INT PRIMARY KEY,
+ value INT NOT NULL
+);
\ No newline at end of file
diff --git a/src/main/resources/benchmarks/sibench/dialect-oracle.xml b/src/main/resources/benchmarks/sibench/dialect-oracle.xml
new file mode 100644
index 000000000..ce4a98e7d
--- /dev/null
+++ b/src/main/resources/benchmarks/sibench/dialect-oracle.xml
@@ -0,0 +1,10 @@
+
+
+
+
+
+ SELECT id FROM sitest ORDER BY value ASC FETCH NEXT 1 ROWS ONLY
+
+
+
+
diff --git a/src/main/resources/benchmarks/smallbank/ddl-oracle.sql b/src/main/resources/benchmarks/smallbank/ddl-oracle.sql
new file mode 100644
index 000000000..a70d5b4cc
--- /dev/null
+++ b/src/main/resources/benchmarks/smallbank/ddl-oracle.sql
@@ -0,0 +1,24 @@
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE checking CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE savings CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE accounts CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+
+CREATE TABLE accounts (
+ custid NUMBER(19) NOT NULL,
+ name VARCHAR(64) NOT NULL,
+ CONSTRAINT pk_accounts PRIMARY KEY (custid)
+);
+CREATE INDEX idx_accounts_name ON accounts (name);
+
+CREATE TABLE savings (
+ custid NUMBER(19) NOT NULL,
+ bal NUMBER NOT NULL,
+ CONSTRAINT pk_savings PRIMARY KEY (custid),
+ FOREIGN KEY (custid) REFERENCES accounts (custid)
+);
+
+CREATE TABLE checking (
+ custid NUMBER(19) NOT NULL,
+ bal NUMBER NOT NULL,
+ CONSTRAINT pk_checking PRIMARY KEY (custid),
+ FOREIGN KEY (custid) REFERENCES accounts (custid)
+);
diff --git a/src/main/resources/benchmarks/tpch/ddl-oracle.sql b/src/main/resources/benchmarks/tpch/ddl-oracle.sql
new file mode 100644
index 000000000..7a7be7da2
--- /dev/null
+++ b/src/main/resources/benchmarks/tpch/ddl-oracle.sql
@@ -0,0 +1,127 @@
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE nation CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE region CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE part CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE supplier CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE partsupp CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE customer CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE orders CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE lineitem CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+
+CREATE TABLE region (
+ r_regionkey int NOT NULL,
+ r_name char(25) NOT NULL,
+ r_comment varchar2(152),
+ PRIMARY KEY (r_regionkey)
+);
+
+CREATE TABLE nation (
+ n_nationkey int NOT NULL,
+ n_name char(25) NOT NULL,
+ n_regionkey int NOT NULL,
+ n_comment varchar2(152),
+ PRIMARY KEY (n_nationkey),
+ FOREIGN KEY (n_regionkey) REFERENCES region (r_regionkey) ON DELETE CASCADE
+);
+
+CREATE INDEX n_rk ON nation (n_regionkey ASC);
+
+CREATE TABLE part (
+ p_partkey int NOT NULL,
+ p_name varchar2(55) NOT NULL,
+ p_mfgr char(25) NOT NULL,
+ p_brand char(10) NOT NULL,
+ p_type varchar2(25) NOT NULL,
+ p_size int NOT NULL,
+ p_container char(10) NOT NULL,
+ p_retailprice decimal(15, 2) NOT NULL,
+ p_comment varchar2(23) NOT NULL,
+ PRIMARY KEY (p_partkey)
+);
+
+
+CREATE TABLE supplier (
+ s_suppkey int NOT NULL,
+ s_name char(25) NOT NULL,
+ s_address varchar2(40) NOT NULL,
+ s_nationkey int NOT NULL,
+ s_phone char(15) NOT NULL,
+ s_acctbal decimal(15, 2) NOT NULL,
+ s_comment varchar2(101) NOT NULL,
+ PRIMARY KEY (s_suppkey),
+ FOREIGN KEY (s_nationkey) REFERENCES nation (n_nationkey) ON DELETE CASCADE
+);
+CREATE INDEX s_nk ON supplier (s_nationkey ASC);
+
+CREATE TABLE partsupp (
+ ps_partkey int NOT NULL,
+ ps_suppkey int NOT NULL,
+ ps_availqty int NOT NULL,
+ ps_supplycost decimal(15, 2) NOT NULL,
+ ps_comment varchar2(199) NOT NULL,
+ PRIMARY KEY (ps_partkey, ps_suppkey),
+ FOREIGN KEY (ps_partkey) REFERENCES part (p_partkey) ON DELETE CASCADE,
+ FOREIGN KEY (ps_suppkey) REFERENCES supplier (s_suppkey) ON DELETE CASCADE
+);
+CREATE INDEX ps_pk ON partsupp (ps_partkey ASC);
+CREATE INDEX ps_sk ON partsupp (ps_suppkey ASC);
+CREATE UNIQUE INDEX ps_sk_pk ON partsupp (ps_suppkey ASC, ps_partkey ASC);
+
+CREATE TABLE customer (
+ c_custkey int NOT NULL,
+ c_name varchar2(25) NOT NULL,
+ c_address varchar2(40) NOT NULL,
+ c_nationkey int NOT NULL,
+ c_phone char(15) NOT NULL,
+ c_acctbal decimal(15, 2) NOT NULL,
+ c_mktsegment char(10) NOT NULL,
+ c_comment varchar2(117) NOT NULL,
+ PRIMARY KEY (c_custkey),
+ FOREIGN KEY (c_nationkey) REFERENCES nation (n_nationkey) ON DELETE CASCADE
+);
+CREATE INDEX c_nk ON customer (c_nationkey ASC);
+
+CREATE TABLE orders (
+ o_orderkey int NOT NULL,
+ o_custkey int NOT NULL,
+ o_orderstatus char(1) NOT NULL,
+ o_totalprice decimal(15, 2) NOT NULL,
+ o_orderdate date NOT NULL,
+ o_orderpriority char(15) NOT NULL,
+ o_clerk char(15) NOT NULL,
+ o_shippriority int NOT NULL,
+ o_comment varchar2(79) NOT NULL,
+ PRIMARY KEY (o_orderkey),
+ FOREIGN KEY (o_custkey) REFERENCES customer (c_custkey) ON DELETE CASCADE
+);
+CREATE INDEX o_ck ON orders (o_custkey ASC);
+CREATE INDEX o_od ON orders (o_orderdate ASC);
+
+CREATE TABLE lineitem (
+ l_orderkey int NOT NULL,
+ l_partkey int NOT NULL,
+ l_suppkey int NOT NULL,
+ l_linenumber int NOT NULL,
+ l_quantity decimal(15, 2) NOT NULL,
+ l_extendedprice decimal(15, 2) NOT NULL,
+ l_discount decimal(15, 2) NOT NULL,
+ l_tax decimal(15, 2) NOT NULL,
+ l_returnflag char(1) NOT NULL,
+ l_linestatus char(1) NOT NULL,
+ l_shipdate date NOT NULL,
+ l_commitdate date NOT NULL,
+ l_receiptdate date NOT NULL,
+ l_shipinstruct char(25) NOT NULL,
+ l_shipmode char(10) NOT NULL,
+ l_comment varchar2(44) NOT NULL,
+ PRIMARY KEY (l_orderkey, l_linenumber),
+ FOREIGN KEY (l_orderkey) REFERENCES orders (o_orderkey) ON DELETE CASCADE,
+ FOREIGN KEY (l_partkey, l_suppkey) REFERENCES partsupp (ps_partkey, ps_suppkey) ON DELETE CASCADE
+);
+CREATE INDEX l_ok ON lineitem (l_orderkey ASC);
+CREATE INDEX l_pk ON lineitem (l_partkey ASC);
+CREATE INDEX l_sk ON lineitem (l_suppkey ASC);
+CREATE INDEX l_sd ON lineitem (l_shipdate ASC);
+CREATE INDEX l_cd ON lineitem (l_commitdate ASC);
+CREATE INDEX l_rd ON lineitem (l_receiptdate ASC);
+CREATE INDEX l_pk_sk ON lineitem (l_partkey ASC, l_suppkey ASC);
+CREATE INDEX l_sk_pk ON lineitem (l_suppkey ASC, l_partkey ASC);
diff --git a/src/main/resources/benchmarks/tpch/dialect-oracle.xml b/src/main/resources/benchmarks/tpch/dialect-oracle.xml
new file mode 100644
index 000000000..00d401c52
--- /dev/null
+++ b/src/main/resources/benchmarks/tpch/dialect-oracle.xml
@@ -0,0 +1,116 @@
+
+
+
+
+
+ SELECT l_returnflag, l_linestatus, sum(l_quantity) as sum_qty,
+ sum(l_extendedprice) as sum_base_price, sum(l_extendedprice * (1 - l_discount)) as sum_disc_price,
+ sum(l_extendedprice * (1 - l_discount) * (1 + l_tax)) as sum_charge,
+ avg(l_quantity) as avg_qty, avg(l_extendedprice) as avg_price, avg(l_discount) as avg_disc, count(*) as count_order
+ FROM lineitem
+ WHERE l_shipdate <= to_date('1998-12-01', 'YYYY-MM-DD') - ?
+ GROUP BY l_returnflag, l_linestatus
+ ORDER BY l_returnflag, l_linestatus
+
+
+
+
+ select s_acctbal, s_name, n_name, p_partkey, p_mfgr, s_address, s_phone, s_comment from part, supplier, partsupp, nation, region where p_partkey = ps_partkey and s_suppkey = ps_suppkey and p_size = ? and p_type like ? and s_nationkey = n_nationkey and n_regionkey = r_regionkey and r_name = ? and ps_supplycost = ( select min(ps_supplycost) from partsupp, supplier, nation, region where p_partkey = ps_partkey and s_suppkey = ps_suppkey and s_nationkey = n_nationkey and n_regionkey = r_regionkey and r_name = ? ) order by s_acctbal desc, n_name, s_name, p_partkey FETCH NEXT 100 ROWS ONLY
+
+
+
+
+ select l_orderkey, sum(l_extendedprice * (1 - l_discount)) as revenue, o_orderdate, o_shippriority from customer, orders, lineitem where c_mktsegment = ? and c_custkey = o_custkey and l_orderkey = o_orderkey and o_orderdate < ? and l_shipdate > ? group by l_orderkey, o_orderdate, o_shippriority order by revenue desc, o_orderdate FETCH NEXT 10 ROWS ONLY
+
+
+
+
+ select o_orderpriority, count(*) as order_count from orders where o_orderdate >= ? and o_orderdate < add_months(?, 3) and exists ( select * from lineitem where l_orderkey = o_orderkey and l_commitdate < l_receiptdate ) group by o_orderpriority order by o_orderpriority
+
+
+
+
+ SELECT n_name, SUM(l_extendedprice * (1 - l_discount)) as revenue from customer, orders, lineitem, supplier, nation, region WHERE c_custkey = o_custkey and l_orderkey = o_orderkey and l_suppkey = s_suppkey and c_nationkey = s_nationkey and s_nationkey = n_nationkey and n_regionkey = r_regionkey and r_name = ? and o_orderdate >= ? and add_months(?, 12) > o_orderdate group by n_name order by revenue DESC
+
+
+
+
+ select sum(l_extendedprice * l_discount) as revenue from lineitem where l_shipdate >= ? and add_months(?, 12) > l_shipdate and l_discount between ? - 0.01 and ? + 0.01 and l_quantity < ?
+
+
+
+
+ select supp_nation, cust_nation, l_year, sum(volume) as revenue
+ from (
+ select n1.n_name as supp_nation, n2.n_name as cust_nation, EXTRACT(YEAR FROM l_shipdate) AS l_year,
+ l_extendedprice * (1 - l_discount) as volume
+ from supplier, lineitem, orders, customer, nation n1, nation n2
+ where s_suppkey = l_suppkey and o_orderkey = l_orderkey and c_custkey = o_custkey
+ and s_nationkey = n1.n_nationkey and c_nationkey = n2.n_nationkey
+ and (
+ (n1.n_name = ? and n2.n_name = ?) or
+ (n1.n_name = ? and n2.n_name = ?)
+ )
+ and l_shipdate between to_date('1995-01-01', 'YYYY-MM-DD') and to_date('1996-12-31', 'YYYY-MM-DD')
+ )
+ group by supp_nation, cust_nation, l_year
+ order by supp_nation, cust_nation, l_year
+
+
+
+
+ select o_year, sum(case when nation = ? then volume else 0 end) / sum(volume) as mkt_share from ( select EXTRACT(YEAR FROM o_orderdate) as o_year, l_extendedprice * (1 - l_discount) as volume, n2.n_name as nation from part, supplier, lineitem, orders, customer, nation n1, nation n2, region where p_partkey = l_partkey and s_suppkey = l_suppkey and l_orderkey = o_orderkey and o_custkey = c_custkey and c_nationkey = n1.n_nationkey and n1.n_regionkey = r_regionkey and r_name = ? and s_nationkey = n2.n_nationkey and o_orderdate between to_date('1995-01-01', 'YYYY-MM-DD') and to_date('1996-12-31', 'YYYY-MM-DD') and p_type = ? ) group by o_year order by o_year
+
+
+
+
+ select nation, o_year, sum(amount) as sum_profit from ( select n_name as nation, EXTRACT(YEAR FROM o_orderdate) as o_year, l_extendedprice * (1 - l_discount) - ps_supplycost * l_quantity as amount from part, supplier, lineitem, partsupp, orders, nation where s_suppkey = l_suppkey and ps_suppkey = l_suppkey and ps_partkey = l_partkey and p_partkey = l_partkey and o_orderkey = l_orderkey and s_nationkey = n_nationkey and p_name like ? ) group by nation, o_year order by nation, o_year desc
+
+
+
+
+ select c_custkey, c_name, sum(l_extendedprice * (1 - l_discount)) as revenue, c_acctbal, n_name, c_address, c_phone, c_comment from customer, orders, lineitem, nation where c_custkey = o_custkey and l_orderkey = o_orderkey and o_orderdate >= ? and o_orderdate < add_months(?, 3) and l_returnflag = 'R' and c_nationkey = n_nationkey group by c_custkey, c_name, c_acctbal, c_phone, n_name, c_address, c_comment order by revenue desc FETCH NEXT 20 ROWS ONLY
+
+
+
+
+ select l_shipmode, sum(case when o_orderpriority = '1-URGENT' or o_orderpriority = '2-HIGH' then 1 else 0 end) as high_line_count, sum(case when o_orderpriority <> '1-URGENT' and o_orderpriority <> '2-HIGH' then 1 else 0 end) as low_line_count from orders, lineitem where o_orderkey = l_orderkey and l_shipmode in (?, ?) and l_commitdate < l_receiptdate and l_shipdate < l_commitdate and l_receiptdate >= ? and l_receiptdate < add_months(?, 1) group by l_shipmode order by l_shipmode
+
+
+
+
+ SELECT c_count, COUNT(*) AS custdist FROM (SELECT c_custkey, COUNT(o_orderkey) AS c_count FROM customer LEFT OUTER JOIN orders ON c_custkey = o_custkey AND o_comment NOT LIKE ? GROUP BY c_custkey) GROUP BY c_count ORDER BY custdist DESC, c_count DESC
+
+
+
+
+ select 100.00 * sum(case when p_type like 'PROMO%' then l_extendedprice * (1 - l_discount) else 0 end) / sum(l_extendedprice * (1 - l_discount)) as promo_revenue from lineitem, part where l_partkey = p_partkey and l_shipdate >= ? and l_shipdate < add_months(?, 1)
+
+
+
+
+ create view revenue0 (supplier_no, total_revenue) as select l_suppkey, sum(l_extendedprice * (1 - l_discount)) from lineitem where l_shipdate >= to_date(?, 'YYYY-MM-DD') and l_shipdate < add_months(to_date(?, 'YYYY-MM-DD'), 3) group by l_suppkey
+
+
+
+
+ select c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice, sum(l_quantity) from customer, orders, lineitem where o_orderkey in ( select l_orderkey from lineitem group by l_orderkey having sum(l_quantity) > ? ) and c_custkey = o_custkey and o_orderkey = l_orderkey group by c_name, c_custkey, o_orderkey, o_orderdate, o_totalprice order by o_totalprice desc, o_orderdate FETCH NEXT 100 ROWS ONLY
+
+
+
+
+ select s_name, s_address from supplier, nation where s_suppkey in ( select ps_suppkey from partsupp where ps_partkey in ( select p_partkey from part where p_name like ? ) and ps_availqty > ( select 0.5 * sum(l_quantity) from lineitem where l_partkey = ps_partkey and l_suppkey = ps_suppkey and l_shipdate >= ? and l_shipdate < add_months(?, 12) ) ) and s_nationkey = n_nationkey and n_name = ? order by s_name
+
+
+
+
+ select s_name, count(*) as numwait from supplier, lineitem l1, orders, nation where s_suppkey = l1.l_suppkey and o_orderkey = l1.l_orderkey and o_orderstatus = 'F' and l1.l_receiptdate > l1.l_commitdate and exists ( select * from lineitem l2 where l2.l_orderkey = l1.l_orderkey and l2.l_suppkey <> l1.l_suppkey ) and not exists ( select * from lineitem l3 where l3.l_orderkey = l1.l_orderkey and l3.l_suppkey <> l1.l_suppkey and l3.l_receiptdate > l3.l_commitdate ) and s_nationkey = n_nationkey and n_name = ? group by s_name order by numwait desc, s_name FETCH NEXT 100 ROWS ONLY
+
+
+
+
+ select cntrycode, count(*) as numcust, sum(c_acctbal) as totacctbal from ( select substr(c_phone, 1, 2) as cntrycode, c_acctbal from customer where substr(c_phone, 1, 2) in (?, ?, ?, ?, ?, ?, ?) and c_acctbal > ( select avg(c_acctbal) from customer where c_acctbal > 0.00 and substr(c_phone, 1, 2) in (?, ?, ?, ?, ?, ?, ?) ) and not exists ( select * from orders where o_custkey = c_custkey ) ) group by cntrycode order by cntrycode
+
+
+
+
\ No newline at end of file
diff --git a/src/main/resources/benchmarks/twitter/ddl-oracle.sql b/src/main/resources/benchmarks/twitter/ddl-oracle.sql
index 6ea8fa891..63e687a93 100644
--- a/src/main/resources/benchmarks/twitter/ddl-oracle.sql
+++ b/src/main/resources/benchmarks/twitter/ddl-oracle.sql
@@ -1,8 +1,8 @@
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE "added_tweets"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE "tweets"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE "user_profiles"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE added_tweets CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE tweets CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE user_profiles CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-CREATE TABLE "user_profiles" (
+CREATE TABLE user_profiles (
uuid int NOT NULL,
name varchar2(255) DEFAULT NULL,
email varchar2(255) DEFAULT NULL,
@@ -11,44 +11,44 @@ CREATE TABLE "user_profiles" (
followers number(11,0) DEFAULT NULL,
CONSTRAINT uid_key PRIMARY KEY (uuid)
);
-CREATE INDEX IDX_USER_FOLLOWERS ON "user_profiles" (followers);
-CREATE INDEX IDX_USER_PARTITION ON "user_profiles" (partitionid);
+CREATE INDEX IDX_USER_FOLLOWERS ON user_profiles (followers);
+CREATE INDEX IDX_USER_PARTITION ON user_profiles (partitionid);
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE "followers"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-CREATE TABLE "followers" (
- f1 int NOT NULL REFERENCES "user_profiles" (uid),
- f2 int NOT NULL REFERENCES "user_profiles" (uid),
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE followers CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+CREATE TABLE followers (
+ f1 int NOT NULL REFERENCES user_profiles (uuid),
+ f2 int NOT NULL REFERENCES user_profiles (uuid),
CONSTRAINT follower_key PRIMARY KEY (f1,f2)
);
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE "follows"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-CREATE TABLE "follows" (
- f1 int NOT NULL REFERENCES "user_profiles" (uid),
- f2 int NOT NULL REFERENCES "user_profiles" (uid),
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE follows CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+CREATE TABLE follows (
+ f1 int NOT NULL REFERENCES user_profiles (uuid),
+ f2 int NOT NULL REFERENCES user_profiles (uuid),
CONSTRAINT follows_key PRIMARY KEY (f1,f2)
);
-- TODO: id AUTO_INCREMENT
-CREATE TABLE "tweets" (
+CREATE TABLE tweets (
id number(19,0) NOT NULL,
- uuid int NOT NULL REFERENCES "user_profiles" (uuid),
+ uuid int NOT NULL REFERENCES user_profiles (uuid),
text char(140) NOT NULL,
createdate date DEFAULT NULL,
CONSTRAINT tweetid_key PRIMARY KEY (id)
);
-CREATE INDEX IDX_TWEETS_uuid ON "tweets" (uuid);
+CREATE INDEX IDX_TWEETS_uuid ON tweets (uuid);
-CREATE TABLE "added_tweets" (
+CREATE TABLE added_tweets (
id number(19,0) NOT NULL,
- uuid int NOT NULL REFERENCES "user_profiles" (uuid),
+ uuid int NOT NULL REFERENCES user_profiles (uuid),
text char(140) NOT NULL,
createdate date DEFAULT NULL,
CONSTRAINT new_tweet_id PRIMARY KEY (id)
);
-CREATE INDEX IDX_ADDED_TWEETS_uuid ON "added_tweets" (uuid);
+CREATE INDEX IDX_ADDED_TWEETS_uuid ON added_tweets (uuid);
-- sequence
DECLARE cnt NUMBER; BEGIN SELECT count(*) INTO cnt FROM all_sequences WHERE sequence_name = 'TWEET_IDSEQ'; IF cnt > 0 THEN EXECUTE IMMEDIATE 'DROP SEQUENCE TWEET_IDSEQ'; END IF; END;;
-create sequence tweet_idseq start with 1 increment by 1 nomaxvalue;
\ No newline at end of file
+create sequence tweet_idseq start with 1 increment by 1 nomaxvalue;
\ No newline at end of file
diff --git a/src/main/resources/benchmarks/twitter/dialect-oracle.xml b/src/main/resources/benchmarks/twitter/dialect-oracle.xml
index f853736f6..1b61888cb 100644
--- a/src/main/resources/benchmarks/twitter/dialect-oracle.xml
+++ b/src/main/resources/benchmarks/twitter/dialect-oracle.xml
@@ -3,33 +3,33 @@
- SELECT * FROM "tweets" WHERE id = ?
+ SELECT * FROM tweets WHERE id = ?
- SELECT f2 FROM "follows" WHERE f1 = ? AND ROWNUM <= 20
+ SELECT f2 FROM follows WHERE f1 = ? AND ROWNUM <= 20
- SELECT * FROM "tweets" WHERE uuid IN (??)
+ SELECT * FROM tweets WHERE uuid IN (??)
-
+
- SELECT f2 FROM "followers" WHERE f1 = ? AND ROWNUM <= 20
+ SELECT f2 FROM followers WHERE f1 = ? AND ROWNUM <= 20
- SELECT uuid, name FROM "user_profiles" WHERE uuid IN (??)
+ SELECT uuid, name FROM user_profiles WHERE uuid IN (??)
- SELECT * FROM "tweets" WHERE uuid = ? AND ROWNUM <= 10
+ SELECT * FROM tweets WHERE uuid = ? AND ROWNUM <= 10
- INSERT INTO "added_tweets" VALUES (tweet_idseq.nextval, ?, ?, ?)
+ INSERT INTO added_tweets VALUES (tweet_idseq.nextval, ?, ?, ?)
diff --git a/src/main/resources/benchmarks/voter/ddl-oracle.sql b/src/main/resources/benchmarks/voter/ddl-oracle.sql
new file mode 100644
index 000000000..bce127331
--- /dev/null
+++ b/src/main/resources/benchmarks/voter/ddl-oracle.sql
@@ -0,0 +1,37 @@
+BEGIN EXECUTE IMMEDIATE 'DROP VIEW v_votes_by_phone_number CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP VIEW v_votes_by_contestant_number_state CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE votes CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE area_code_state CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE contestants CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+
+CREATE TABLE contestants (
+ contestant_number INT NOT NULL,
+ contestant_name VARCHAR(50) NOT NULL,
+ PRIMARY KEY (contestant_number)
+);
+
+CREATE TABLE area_code_state (
+ area_code INT NOT NULL,
+ state VARCHAR(2) NOT NULL,
+ PRIMARY KEY (area_code)
+);
+
+CREATE TABLE votes (
+ vote_id NUMBER(19) NOT NULL,
+ phone_number NUMBER(19) NOT NULL,
+ state VARCHAR(2) NOT NULL,
+ contestant_number INT NOT NULL,
+ created TIMESTAMP(9) NOT NULL,
+ FOREIGN KEY (contestant_number) REFERENCES contestants (contestant_number) ON DELETE CASCADE
+);
+CREATE INDEX idx_votes_phone_number ON votes (phone_number);
+
+CREATE VIEW v_votes_by_phone_number (phone_number, num_votes) AS
+SELECT phone_number, COUNT(*)
+FROM votes
+GROUP BY phone_number;
+
+CREATE VIEW v_votes_by_contestant_number_state (contestant_number, state, num_votes) AS
+SELECT contestant_number, state, COUNT(*)
+FROM votes
+GROUP BY contestant_number, state;
\ No newline at end of file
diff --git a/src/main/resources/benchmarks/voter/dialect-oracle.xml b/src/main/resources/benchmarks/voter/dialect-oracle.xml
new file mode 100644
index 000000000..04eeaa9f3
--- /dev/null
+++ b/src/main/resources/benchmarks/voter/dialect-oracle.xml
@@ -0,0 +1,10 @@
+
+
+
+
+
+ INSERT INTO votes (vote_id, phone_number, state, contestant_number, created) VALUES (?, ?, ?, ?, CURRENT_TIMESTAMP)
+
+
+
+
diff --git a/src/main/resources/benchmarks/wikipedia/ddl-oracle.sql b/src/main/resources/benchmarks/wikipedia/ddl-oracle.sql
index 92d1087cd..3f9fd5910 100644
--- a/src/main/resources/benchmarks/wikipedia/ddl-oracle.sql
+++ b/src/main/resources/benchmarks/wikipedia/ddl-oracle.sql
@@ -3,21 +3,21 @@
ALTER SESSION SET NLS_LENGTH_SEMANTICS=CHAR;
-- Drop All tables
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE ipblocks'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE logging'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE page'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE page_restrictions'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE recentchanges'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE revision'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE text'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE useracct'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE user_groups'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-BEGIN EXECUTE IMMEDIATE 'DROP TABLE watchlist'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE ipblocks CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE logging CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE page CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE page_restrictions CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE recentchanges CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE revision CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE text CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE useracct CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE user_groups CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
+BEGIN EXECUTE IMMEDIATE 'DROP TABLE watchlist CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;;
-- Create tables
CREATE TABLE ipblocks (
-ipb_id number(10,0) NOT NULL,
+ipb_id number(10,0) GENERATED BY DEFAULT ON NULL AS IDENTITY NOT NULL,
ipb_address varchar2(255) NOT NULL,
ipb_user number(10,0) DEFAULT '0',
ipb_by number(10,0) DEFAULT '0',
@@ -39,7 +39,7 @@ UNIQUE (ipb_address,ipb_user,ipb_auto,ipb_anon_only)
);
CREATE TABLE logging (
-log_id number(10,0) NOT NULL,
+log_id number(10,0) GENERATED BY DEFAULT ON NULL AS IDENTITY NOT NULL,
log_type varchar2(32) NOT NULL,
log_action varchar2(32) NOT NULL,
log_timestamp varchar2(14) DEFAULT '19700101000000',
@@ -55,7 +55,7 @@ PRIMARY KEY (log_id)
);
CREATE TABLE page (
-page_id number(10,0) NOT NULL,
+page_id number(10,0) GENERATED BY DEFAULT ON NULL AS IDENTITY NOT NULL,
page_namespace number(10,0) NOT NULL,
page_title varchar2(255) NOT NULL,
page_restrictions varchar(255) NOT NULL,
@@ -83,7 +83,7 @@ UNIQUE (pr_page,pr_type)
);
CREATE TABLE recentchanges (
-rc_id number(10,0) NOT NULL,
+rc_id number(10,0) GENERATED BY DEFAULT ON NULL AS IDENTITY NOT NULL,
rc_timestamp varchar2(14) DEFAULT '',
rc_cur_time varchar2(14) DEFAULT '',
rc_user number(10,0) DEFAULT '0',
@@ -95,7 +95,7 @@ rc_minor number(3,0) DEFAULT '0',
rc_bot number(3,0) DEFAULT '0',
rc_new number(3,0) DEFAULT '0',
rc_cur_id number(10,0) DEFAULT '0',
-rc_this_oldid number(10,0) DEFAULT '0',
+rc_this_oldid number(19,0) DEFAULT '0',
rc_last_oldid number(10,0) DEFAULT '0',
rc_type number(3,0) DEFAULT '0',
rc_moved_to_ns number(3,0) DEFAULT '0',
@@ -113,7 +113,7 @@ PRIMARY KEY (rc_id)
);
CREATE TABLE revision (
-rev_id number(10,0) NOT NULL,
+rev_id number(10,0) GENERATED BY DEFAULT ON NULL AS IDENTITY NOT NULL,
rev_page number(10,0) NOT NULL,
rev_text_id number(10,0) NOT NULL,
rev_comment varchar2(1024) NOT NULL,
@@ -129,7 +129,7 @@ UNIQUE (rev_page,rev_id)
);
CREATE TABLE text (
-old_id number(10,0) NOT NULL,
+old_id int GENERATED BY DEFAULT ON NULL AS IDENTITY NOT NULL,
old_text clob NOT NULL,
old_flags varchar2(30) NOT NULL,
old_page number(10,0) DEFAULT NULL,
@@ -202,59 +202,4 @@ CREATE INDEX IDX_RC_IP ON recentchanges (rc_ip);
CREATE INDEX IDX_RC_NS_USER_TEXT ON recentchanges (rc_namespace,rc_user_text);
CREATE INDEX IDX_RC_USER_TEXT ON recentchanges (rc_user_text,rc_timestamp);
--- Sequences
-DECLARE cnt NUMBER; BEGIN SELECT count(*) INTO cnt FROM all_sequences WHERE sequence_name = 'IPBLOCKS_SEQ'; IF cnt > 0 THEN EXECUTE IMMEDIATE 'DROP SEQUENCE IPBLOCKS_SEQ'; END IF; END;;
-DECLARE cnt NUMBER; BEGIN SELECT count(*) INTO cnt FROM all_sequences WHERE sequence_name = 'LOGGING_SEQ'; IF cnt > 0 THEN EXECUTE IMMEDIATE 'DROP SEQUENCE LOGGING_SEQ'; END IF; END;;
-DECLARE cnt NUMBER; BEGIN SELECT count(*) INTO cnt FROM all_sequences WHERE sequence_name = 'PAGE_SEQ'; IF cnt > 0 THEN EXECUTE IMMEDIATE 'DROP SEQUENCE PAGE_SEQ'; END IF; END;;
-DECLARE cnt NUMBER; BEGIN SELECT count(*) INTO cnt FROM all_sequences WHERE sequence_name = 'PAGE_RESTRICTIONS_SEQ'; IF cnt > 0 THEN EXECUTE IMMEDIATE 'DROP SEQUENCE PAGE_RESTRICTIONS_SEQ'; END IF; END;;
-DECLARE cnt NUMBER; BEGIN SELECT count(*) INTO cnt FROM all_sequences WHERE sequence_name = 'RECENTCHANGES_SEQ'; IF cnt > 0 THEN EXECUTE IMMEDIATE 'DROP SEQUENCE RECENTCHANGES_SEQ'; END IF; END;;
-DECLARE cnt NUMBER; BEGIN SELECT count(*) INTO cnt FROM all_sequences WHERE sequence_name = 'REVISION_SEQ'; IF cnt > 0 THEN EXECUTE IMMEDIATE 'DROP SEQUENCE REVISION_SEQ'; END IF; END;;
-DECLARE cnt NUMBER; BEGIN SELECT count(*) INTO cnt FROM all_sequences WHERE sequence_name = 'TEXT_SEQ'; IF cnt > 0 THEN EXECUTE IMMEDIATE 'DROP SEQUENCE TEXT_SEQ'; END IF; END;;
-DECLARE cnt NUMBER; BEGIN SELECT count(*) INTO cnt FROM all_sequences WHERE sequence_name = 'USER_SEQ'; IF cnt > 0 THEN EXECUTE IMMEDIATE 'DROP SEQUENCE USER_SEQ'; END IF; END;;
-
-create sequence ipblocks_seq start with 1 increment by 1 nomaxvalue;
-create sequence logging_seq start with 1 increment by 1 nomaxvalue;
-create sequence page_seq start with 1 increment by 1 nomaxvalue;
-create sequence page_restrictions_seq start with 1 increment by 1 nomaxvalue;
-create sequence recentchanges_seq start with 1 increment by 1 nomaxvalue;
-create sequence revision_seq start with 1 increment by 1 nomaxvalue;
-create sequence text_seq start with 1 increment by 1 nomaxvalue;
-create sequence user_seq start with 1 increment by 1 nomaxvalue;
-
--- Sequences' triggers
-CREATE OR REPLACE TRIGGER user_seq_tr
-BEFORE INSERT ON useracct FOR EACH ROW
-WHEN (NEW.user_id IS NULL OR NEW.user_id = 0)
-BEGIN
-SELECT user_seq.NEXTVAL INTO :NEW.user_id FROM dual;END;;
-
-CREATE OR REPLACE TRIGGER page_seq_tr
-BEFORE INSERT ON page FOR EACH ROW
-WHEN (NEW.page_id IS NULL OR NEW.page_id = 0)
-BEGIN
-SELECT page_seq.NEXTVAL INTO :NEW.page_id FROM dual;END;;
-
-CREATE OR REPLACE TRIGGER text_seq_tr
-BEFORE INSERT ON text FOR EACH ROW
-WHEN (NEW.old_id IS NULL OR NEW.old_id = 0)
-BEGIN
-SELECT text_seq.NEXTVAL INTO :NEW.old_id FROM dual;END;;
-
-CREATE OR REPLACE TRIGGER revision_seq_tr
-BEFORE INSERT ON revision FOR EACH ROW
-WHEN (NEW.rev_id IS NULL OR NEW.rev_id = 0)
-BEGIN
-SELECT revision_seq.NEXTVAL INTO :NEW.rev_id FROM dual;END;;
-
-CREATE OR REPLACE TRIGGER recentchanges_seq_tr
-BEFORE INSERT ON recentchanges FOR EACH ROW
-WHEN (NEW.rc_id IS NULL OR NEW.rc_id = 0)
-BEGIN
-SELECT recentchanges_seq.NEXTVAL INTO :NEW.rc_id FROM dual;END;;
-
-CREATE OR REPLACE TRIGGER logging_seq_tr
-BEFORE INSERT ON logging FOR EACH ROW
-WHEN (NEW.log_id IS NULL OR NEW.log_id = 0)
-BEGIN
-SELECT logging_seq.NEXTVAL INTO :NEW.log_id FROM dual;END;;
diff --git a/src/main/resources/benchmarks/wikipedia/dialect-oracle.xml b/src/main/resources/benchmarks/wikipedia/dialect-oracle.xml
index 6b1f1f5f4..721247c9d 100644
--- a/src/main/resources/benchmarks/wikipedia/dialect-oracle.xml
+++ b/src/main/resources/benchmarks/wikipedia/dialect-oracle.xml
@@ -1,72 +1,29 @@
-
-
- INSERT /*+ ignore_row_on_dupkey_index(watchlist(wl_user,wl_namespace,wl_title)) */ INTO watchlist (wl_user,wl_namespace,wl_title,wl_notificationtimestamp) VALUES (?,?,?,NULL)
-
-
- UPDATE useracct SET user_touched = ? WHERE user_id = ?
-
-
-
-
- DELETE FROM watchlist WHERE wl_user = ? AND wl_namespace = ? AND wl_title = ?
-
-
- UPDATE useracct SET user_touched = ? WHERE user_id = ?
-
-
- SELECT * FROM page WHERE page_namespace = ? AND page_title = ? AND ROWNUM = 1
+ SELECT * FROM page WHERE page_namespace = ? AND page_title = ? FETCH NEXT 1 ROWS ONLY
- SELECT * FROM page,revision WHERE (page_id=rev_page) AND rev_page = ? AND page_id = ? AND (rev_id=page_latest) AND ROWNUM = 1
+ SELECT * FROM page,revision WHERE (page_id=rev_page) AND rev_page = ? AND page_id = ? AND (rev_id=page_latest) FETCH NEXT 1 ROWS ONLY
- SELECT old_text,old_flags FROM text WHERE old_id = ? AND ROWNUM = 1
-
-
-
-
- INSERT INTO text (old_id,old_page,old_text,old_flags) VALUES (text_seq.NEXTVAL,?,?,'utf-8')
-
-
- INSERT INTO revision (rev_id,rev_page,rev_text_id,rev_comment,rev_minor_edit,rev_user,rev_user_text,rev_timestamp,rev_deleted,rev_len,rev_parent_id)
- VALUES (revision_seq.NEXTVAL,?, ?, ? ,'0',?, ?, ? ,'0',?,?)
-
-
- INSERT INTO recentchanges (rc_id,rc_timestamp,rc_cur_time,rc_namespace,rc_title,rc_type,rc_minor,rc_cur_id,rc_user,rc_user_text,rc_comment,rc_this_oldid,
- rc_last_oldid,rc_bot,rc_moved_to_ns,rc_moved_to_title,rc_ip,rc_patrolled,rc_new,rc_old_len,rc_new_len,rc_deleted,rc_logid,rc_log_type,rc_log_action,rc_params)
- VALUES (recentchanges_seq.NEXTVAL,?, ?, ? , ? ,'0','0', ? , ? , ? ,'', ? , ? ,'0','0','',?,'1','0', ? , ? ,'0','0',NULL,'','')
-
-
- SELECT * FROM useracct WHERE user_id = ?
-
-
- UPDATE useracct SET user_editcount=user_editcount+1 WHERE user_id = ?
-
-
- UPDATE useracct SET user_touched = ? WHERE user_id = ?
-
-
- INSERT INTO logging (log_id,log_type,log_action,log_timestamp,log_user,log_user_text,log_namespace,log_title,log_page,log_comment,log_params)
- VALUES (logging_seq.NEXTVAL,'patrol','patrol',?,?,?,?,?,?,'',?)
+ SELECT old_text,old_flags FROM text WHERE old_id = ? FETCH NEXT 1 ROWS ONLY
- SELECT * FROM useracct WHERE user_id = ? AND ROWNUM = 1
+ SELECT * FROM useracct WHERE user_id = ? FETCH NEXT 1 ROWS ONLY
- SELECT * FROM page WHERE page_namespace = ? AND page_title = ? AND ROWNUM = 1
+ SELECT * FROM page WHERE page_namespace = ? AND page_title = ? FETCH NEXT 1 ROWS ONLY
- SELECT * FROM page, revision WHERE (page_id=rev_page) AND rev_page = ? AND page_id = ? AND (rev_id=page_latest) AND ROWNUM = 1
+ SELECT * FROM page, revision WHERE (page_id=rev_page) AND rev_page = ? AND page_id = ? AND (rev_id=page_latest) FETCH NEXT 1 ROWS ONLY
- SELECT old_text,old_flags FROM text WHERE old_id = ? AND ROWNUM = 1
+ SELECT old_text,old_flags FROM text WHERE old_id = ? FETCH NEXT 1 ROWS ONLY