From 8fbdb9a03db5a66bcf5c0c287e9d0bb23d421f53 Mon Sep 17 00:00:00 2001 From: dr-wolf Date: Thu, 4 Feb 2016 14:48:43 +0200 Subject: [PATCH 1/5] Oracle JDBC test suit --- contrib/storage-jdbc/pom.xml | 6 ++ .../jdbc/TestJdbcPluginWithOracleIT.java | 88 +++++++++++++++++++ .../resources/bootstrap-storage-plugins.json | 10 ++- .../src/test/resources/oracle-test-data.sql | 72 +++++++++++++++ 4 files changed, 175 insertions(+), 1 deletion(-) create mode 100644 contrib/storage-jdbc/src/test/java/org/apache/drill/exec/store/jdbc/TestJdbcPluginWithOracleIT.java create mode 100644 contrib/storage-jdbc/src/test/resources/oracle-test-data.sql diff --git a/contrib/storage-jdbc/pom.xml b/contrib/storage-jdbc/pom.xml index 3c38d07ae68..3a3e91b819b 100755 --- a/contrib/storage-jdbc/pom.xml +++ b/contrib/storage-jdbc/pom.xml @@ -80,6 +80,12 @@ ${mysql.connector.version} test + + com.oracle + ojdbc7 + 12.1.0.2 + test + diff --git a/contrib/storage-jdbc/src/test/java/org/apache/drill/exec/store/jdbc/TestJdbcPluginWithOracleIT.java b/contrib/storage-jdbc/src/test/java/org/apache/drill/exec/store/jdbc/TestJdbcPluginWithOracleIT.java new file mode 100644 index 00000000000..7196059ed2b --- /dev/null +++ b/contrib/storage-jdbc/src/test/java/org/apache/drill/exec/store/jdbc/TestJdbcPluginWithOracleIT.java @@ -0,0 +1,88 @@ +/* + * Licensed to the Apache Software Foundation (ASF) under one + * or more contributor license agreements. See the NOTICE file + * distributed with this work for additional information + * regarding copyright ownership. The ASF licenses this file + * to you under the Apache License, Version 2.0 (the + * "License"); you may not use this file except in compliance + * with the License. You may obtain a copy of the License at + * + * http://www.apache.org/licenses/LICENSE-2.0 + * + * Unless required by applicable law or agreed to in writing, software + * distributed under the License is distributed on an "AS IS" BASIS, + * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + * See the License for the specific language governing permissions and + * limitations under the License. + */ +package org.apache.drill.exec.store.jdbc; + +import org.apache.drill.PlanTestBase; +import org.joda.time.DateTime; +import org.junit.Test; + +/** + * JDBC storage plugin tests against Oracle. + */ +public class TestJdbcPluginWithOracleIT extends PlanTestBase { + + @Test + public void baseTest() throws Exception { + testBuilder() + .sqlQuery( + "select PERSON_ID, " + + "FIRST_NAME, LAST_NAME, ADDRESS, CITY, STATE_FIELD, ZIP, " + + "JSON_FIELD, SMALLINT_FIELD, NUMERIC_FIELD, BOOLEAN_FIELD, " + + "DOUBLE_FIELD, FLOAT_FIELD, REAL_FIELD, TIMESTAMP_FIELD, " + + "DATE_FIELD, TEXT_FIELD, NCHAR_FIELD, BLOB_FIELD, " + + "CLOB_FIELD, DECIMAL_FIELD, DEC_FIELD " + + "from oracle.`SYSTEM`.`person`") + .ordered() + .baselineColumns("PERSON_ID", + "FIRST_NAME", "LAST_NAME", "ADDRESS", "CITY", "STATE_FIELD", "ZIP", + "JSON_FIELD", "SMALLINT_FIELD", "NUMERIC_FIELD", "BOOLEAN_FIELD", + "DOUBLE_FIELD", "FLOAT_FIELD", "REAL_FIELD", "TIMESTAMP_FIELD", + "DATE_FIELD", "TEXT_FIELD", "NCHAR_FIELD", "BLOB_FIELD", + "CLOB_FIELD", "DECIMAL_FIELD", "DEC_FIELD") + .baselineValues(1.0, + "first_name_1", "last_name_1", "1401 John F Kennedy Blvd", "Philadelphia", "PA", 19107.0, + "{ a : 5, b : 6 }", 10.0, 123.0, 0.0, 1.34, 1.112, 1.224, new DateTime(2011, 2, 11, 23, 12, 12), + new DateTime(2015, 5, 2, 0, 0), + "It is a long established fact that a reader will be distracted by the readable content of a page when looking at its layout", + "1", "this is test".getBytes(), "n----", 123.0, 1.0) + .baselineValues(2.0, + "first_name_2", "last_name_2", "One Ferry Building", "San Francisco", "CA", 94111.0, + "{ name : Sem, surname : Sem }", 4.0, 45.0, 1.0, 2.54, 4.242, 4.252, new DateTime(2015, 12, 20, 23, 12, 12), + new DateTime(2015, 12, 1, 0, 0), "Some text", "1", "this is test2".getBytes(), "n!!!!", + 14.0, 0.0) + .baselineValues(3.0, + "first_name_3", "last_name_3", "176 Bowery", "New York", "NY", 10012.0, + "{ x : 12, y : 16 }", 0.0, 13.0, 0.0, 41.42, 2.421, 6.12, new DateTime(1901, 1, 1, 23, 12, 12), + new DateTime(2015, 5, 2, 12, 12, 30), "Some long text 3", "0", "this is test3".getBytes(), "n????", + 0.0, 1.0) + .baselineValues(5.0, + null, null, null, null, null, null, + null, null, null, null, null, null, + null, null, null, null, null, null, + null, null, null) + + .build().run(); + } + + @Test + public void pushdownJoin() throws Exception { + String query = "select x.person_id from (select person_id from oracle.`SYSTEM`.`person`) x " + + "join (select person_id from oracle.`SYSTEM`.`person`) y on x.person_id = y.person_id "; + testPlanMatchingPatterns(query, new String[]{ "JOIN" }, new String[]{ "Join" }); + } + + @Test + public void pushdownJoinAndFilter() throws Exception { + final String query = "select * from oracle.`SYSTEM`.`person` e " + + "inner join oracle.`SYSTEM`.`person` s on e.first_name = s.first_name " + + "where e.last_name <> 'hello'"; + + testPlanMatchingPatterns(query, new String[] { "INNER JOIN" }, new String[] { "Join", "Filter" }); + } + +} diff --git a/contrib/storage-jdbc/src/test/resources/bootstrap-storage-plugins.json b/contrib/storage-jdbc/src/test/resources/bootstrap-storage-plugins.json index add98084744..067223649ff 100755 --- a/contrib/storage-jdbc/src/test/resources/bootstrap-storage-plugins.json +++ b/contrib/storage-jdbc/src/test/resources/bootstrap-storage-plugins.json @@ -11,7 +11,15 @@ enabled : true, driver : "com.mysql.jdbc.Driver", url : "jdbc:mysql://localhost:${mysql.reserved.port}/${mysql.database.name}?user=root&password=root&useJDBCCompliantTimezoneShift=true" - } + }, + oracle : { + type : "jdbc", + enabled : true, + driver : "oracle.jdbc.OracleDriver", + url : "jdbc:oracle:thin:@192.168.0.100:1521/DRILHR", + username: "system", + password: "1111" + } } } diff --git a/contrib/storage-jdbc/src/test/resources/oracle-test-data.sql b/contrib/storage-jdbc/src/test/resources/oracle-test-data.sql new file mode 100644 index 00000000000..3599f46653c --- /dev/null +++ b/contrib/storage-jdbc/src/test/resources/oracle-test-data.sql @@ -0,0 +1,72 @@ +Create sequence id_sequencess +start with 1 +NOMAXVALUE; + +create table person ( + person_id NUMBER(10) NOT NULL, + + first_name VARCHAR(255), + last_name VARCHAR(255), + address VARCHAR(255), + city VARCHAR(255), + state_field CHAR(2), + zip INT, + + json_field VARCHAR(255), + + smallint_field SMALLINT, + numeric_field NUMERIC(10, 2), + boolean_field NUMBER(2), + double_field DOUBLE PRECISION, + float_field FLOAT, + real_field REAL, + + timestamp_field TIMESTAMP, + date_field DATE, + + + + text_field VARCHAR2(220), + nchar_field NCHAR, + blob_field BLOB, + clob_field CLOB, + + decimal_field DECIMAL, + dec_field DEC, + + constraint pk_person_id PRIMARY KEY(person_id) + +); + + +insert into person (person_id, first_name, last_name, address, city, state_field, zip, json_field, + smallint_field, numeric_field, boolean_field, double_field, float_field, real_field, + timestamp_field, date_field, text_field, nchar_field, blob_field, + clob_field, decimal_field, dec_field) + values(id_sequencess.nextval,'first_name_1', 'last_name_1', '1401 John F Kennedy Blvd', 'Philadelphia', 'PA', 19107, '{ a : 5, b : 6 }', + 10.01, 123, 0, 1.340, 1.112, 1.224, TO_TIMESTAMP('2011/02/11 23:12:12','YYYY/MM/DD HH24:MI:SS'), TO_DATE('2015/05/2', 'yyyy/mm/dd'), + 'It is a long established fact that a reader will be distracted by the readable content of a page when looking at its layout', + '1', utl_raw.cast_to_raw('this is test'), rpad('n',5,'-'), 123.25, 0.5 + ); + + +insert into person (person_id, first_name, last_name, address, city, state_field, zip, json_field, + smallint_field, numeric_field, boolean_field, double_field, float_field, real_field, + timestamp_field, date_field, text_field, nchar_field, blob_field, + clob_field, decimal_field, dec_field) + values(id_sequencess.nextval,'first_name_2', 'last_name_2', 'One Ferry Building', 'San Francisco', 'CA', 94111, '{ name : Sem, surname : Sem }', + 4.21, 45, 1, 2.540, 4.242, 4.252, TO_TIMESTAMP('2015/12/20 23:12:12','YYYY/MM/DD HH24:MI:SS'), TO_DATE('2015/12/1', 'yyyy/mm/dd'), 'Some text', '1', utl_raw.cast_to_raw('this is test2'), rpad('n',5,'!'), 13.656, 0.1 + ); + + +insert into person (person_id, first_name, last_name, address, city, state_field, zip, json_field, + smallint_field, numeric_field, boolean_field, double_field, float_field, real_field, + timestamp_field, date_field, text_field, nchar_field, blob_field, + clob_field, decimal_field, dec_field) + values(id_sequencess.nextval,'first_name_3', 'last_name_3', '176 Bowery', 'New York', 'NY', 10012, '{ x : 12, y : 16 }', + 0.41, 13, 0, 41.42, 2.421, 6.12, TO_TIMESTAMP('1901/01/01 23:12:12','YYYY/MM/DD HH24:MI:SS'), TO_DATE('2015/05/2 12:12:30', 'yyyy/mm/dd hh:mi:ss'), 'Some long text 3', + '0', utl_raw.cast_to_raw('this is test3'), rpad('n',5,'?'), 0.456, 1.0 + ); + +insert into person (person_id) values(5); + From 0fb251b3a02b09c44f4d6d717d9ef06abc0e263f Mon Sep 17 00:00:00 2001 From: dr-wolf Date: Thu, 4 Feb 2016 14:55:28 +0200 Subject: [PATCH 2/5] Drill func pushdown test --- .../exec/store/jdbc/TestJdbcPluginWithOracleIT.java | 10 ++++++++++ 1 file changed, 10 insertions(+) diff --git a/contrib/storage-jdbc/src/test/java/org/apache/drill/exec/store/jdbc/TestJdbcPluginWithOracleIT.java b/contrib/storage-jdbc/src/test/java/org/apache/drill/exec/store/jdbc/TestJdbcPluginWithOracleIT.java index 7196059ed2b..866d26161cc 100644 --- a/contrib/storage-jdbc/src/test/java/org/apache/drill/exec/store/jdbc/TestJdbcPluginWithOracleIT.java +++ b/contrib/storage-jdbc/src/test/java/org/apache/drill/exec/store/jdbc/TestJdbcPluginWithOracleIT.java @@ -84,5 +84,15 @@ public void pushdownJoinAndFilter() throws Exception { testPlanMatchingPatterns(query, new String[] { "INNER JOIN" }, new String[] { "Join", "Filter" }); } + + @Test + public void pushdownDrillFunc() throws Exception { + // Both subqueries use drill functions so join can not be pushed down to jdbc + final String query = "select x.first_name from " + + "(select CONVERT_TO(first_name, 'UTF8') first_name, person_id from oracle.`SYSTEM`.`person`) x join " + + "(select CONVERT_TO(first_name, 'UTF8') first_name, person_id from oracle.`SYSTEM`.`person`) y on x.person_id = y.person_id"; + + testPlanMatchingPatterns(query, new String[] { "Join" }, new String[] { "JOIN" }); + } } From d02bb019bd98c61efe4d06ce31b3db30eefa5cb6 Mon Sep 17 00:00:00 2001 From: dr-wolf Date: Thu, 4 Feb 2016 15:00:52 +0200 Subject: [PATCH 3/5] Driver config updated --- .../src/test/resources/bootstrap-storage-plugins.json | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/contrib/storage-jdbc/src/test/resources/bootstrap-storage-plugins.json b/contrib/storage-jdbc/src/test/resources/bootstrap-storage-plugins.json index 067223649ff..a91df96198b 100755 --- a/contrib/storage-jdbc/src/test/resources/bootstrap-storage-plugins.json +++ b/contrib/storage-jdbc/src/test/resources/bootstrap-storage-plugins.json @@ -16,7 +16,7 @@ type : "jdbc", enabled : true, driver : "oracle.jdbc.OracleDriver", - url : "jdbc:oracle:thin:@192.168.0.100:1521/DRILHR", + url : "jdbc:oracle:thin:@localhost:1521/ORCL", username: "system", password: "1111" } From ee982f1038919f28ba573cd7eb4c588ab15ed973 Mon Sep 17 00:00:00 2001 From: dr-wolf Date: Fri, 5 Feb 2016 06:30:51 -0700 Subject: [PATCH 4/5] Exclude jdbc oracle test and it's dependences from pom.xml and create profile --- contrib/storage-jdbc/pom.xml | 50 ++++++++++++++++--- .../jdbc/TestJdbcPluginWithOracleIT.java | 2 +- 2 files changed, 45 insertions(+), 7 deletions(-) diff --git a/contrib/storage-jdbc/pom.xml b/contrib/storage-jdbc/pom.xml index 3a3e91b819b..3e8a3cc69a9 100755 --- a/contrib/storage-jdbc/pom.xml +++ b/contrib/storage-jdbc/pom.xml @@ -80,12 +80,6 @@ ${mysql.connector.version} test - - com.oracle - ojdbc7 - 12.1.0.2 - test - @@ -117,6 +111,11 @@ + + + **/TestJdbcPluginWithOracleIT.java + + @@ -285,4 +284,43 @@ + + + oracle + + false + + + + + org.apache.maven.plugins + maven-failsafe-plugin + 2.18.1 + + + + integration-test + verify + + + + + + **/TestJdbcPluginWithOracleIT.java + + + + + + + + com.oracle + ojdbc7 + 12.1.0.2 + test + + + + + diff --git a/contrib/storage-jdbc/src/test/java/org/apache/drill/exec/store/jdbc/TestJdbcPluginWithOracleIT.java b/contrib/storage-jdbc/src/test/java/org/apache/drill/exec/store/jdbc/TestJdbcPluginWithOracleIT.java index 866d26161cc..d76c9b07ffe 100644 --- a/contrib/storage-jdbc/src/test/java/org/apache/drill/exec/store/jdbc/TestJdbcPluginWithOracleIT.java +++ b/contrib/storage-jdbc/src/test/java/org/apache/drill/exec/store/jdbc/TestJdbcPluginWithOracleIT.java @@ -84,7 +84,7 @@ public void pushdownJoinAndFilter() throws Exception { testPlanMatchingPatterns(query, new String[] { "INNER JOIN" }, new String[] { "Join", "Filter" }); } - + @Test public void pushdownDrillFunc() throws Exception { // Both subqueries use drill functions so join can not be pushed down to jdbc From f4a69e1d0fce2e123098a0ad1827a27032b6842b Mon Sep 17 00:00:00 2001 From: dr-wolf Date: Mon, 8 Feb 2016 07:49:42 -0700 Subject: [PATCH 5/5] Add more test queries to oracle test suit and fix profile config in pom.xml --- contrib/storage-jdbc/pom.xml | 39 +- .../jdbc/TestJdbcPluginWithOracleIT.java | 163 ++++++ .../src/test/resources/oracle-testhr-data.sql | 537 ++++++++++++++++++ 3 files changed, 713 insertions(+), 26 deletions(-) create mode 100644 contrib/storage-jdbc/src/test/resources/oracle-testhr-data.sql diff --git a/contrib/storage-jdbc/pom.xml b/contrib/storage-jdbc/pom.xml index 3e8a3cc69a9..50a74bc515a 100755 --- a/contrib/storage-jdbc/pom.xml +++ b/contrib/storage-jdbc/pom.xml @@ -111,11 +111,6 @@ - - - **/TestJdbcPluginWithOracleIT.java - - @@ -276,7 +271,7 @@ ${mysql.database.name} - **/*IT.java + **/*DerbyIT.java, **/*MySQLIT.java @@ -291,26 +286,18 @@ false - - - org.apache.maven.plugins - maven-failsafe-plugin - 2.18.1 - - - - integration-test - verify - - - - - - **/TestJdbcPluginWithOracleIT.java - - - - + + + + maven-failsafe-plugin + + + **/*IT.java + + + + + diff --git a/contrib/storage-jdbc/src/test/java/org/apache/drill/exec/store/jdbc/TestJdbcPluginWithOracleIT.java b/contrib/storage-jdbc/src/test/java/org/apache/drill/exec/store/jdbc/TestJdbcPluginWithOracleIT.java index d76c9b07ffe..bd4b1f5cfc7 100644 --- a/contrib/storage-jdbc/src/test/java/org/apache/drill/exec/store/jdbc/TestJdbcPluginWithOracleIT.java +++ b/contrib/storage-jdbc/src/test/java/org/apache/drill/exec/store/jdbc/TestJdbcPluginWithOracleIT.java @@ -95,4 +95,167 @@ public void pushdownDrillFunc() throws Exception { testPlanMatchingPatterns(query, new String[] { "Join" }, new String[] { "JOIN" }); } + @Test + public void queryTest1() throws Exception { + testBuilder() + .sqlQuery( + "SELECT FIRST_NAME, LAST_NAME " + + "FROM oracle.`SYSTEM`.`EMPLOYEES` WHERE FIRST_NAME LIKE 'G%'") + .ordered() + .baselineColumns("FIRST_NAME", "LAST_NAME") + .baselineValues("Guy","Himuro") + .baselineValues("Gerald","Cambrault") + .baselineValues("Girard","Geoni") + .build() + .run(); + } + + @Test + public void queryTest2() throws Exception { + testBuilder() + .sqlQuery( + "SELECT DEPARTMENT_NAME, FIRST_NAME, CITY " + + "FROM oracle.`SYSTEM`.`DEPARTMENTS` D " + + "JOIN oracle.`SYSTEM`.`EMPLOYEES` E ON (D.MANAGER_ID=E.EMPLOYEE_ID) " + + "JOIN oracle.`SYSTEM`.`LOCATIONS` L USING (LOCATION_ID) WHERE FIRST_NAME LIKE 'A%'" ) + .ordered() + .baselineColumns("DEPARTMENT_NAME", "FIRST_NAME", "CITY") + .baselineValues("IT", "Alexander", "Southlake") + .baselineValues("Shipping", "Adam", "South San Francisco") + .build() + .run(); + } + + @Test + public void queryTest3() throws Exception { + testBuilder() + .sqlQuery( + "SELECT DEPARTMENT_ID, AVG(SALARY) AS AVGS " + + "FROM oracle.`SYSTEM`.`EMPLOYEES` WHERE COMMISSION_PCT IS NOT NULL GROUP BY DEPARTMENT_ID") + .ordered() + .baselineColumns("DEPARTMENT_ID", "AVGS") + .baselineValues(null, 7000.0) + .baselineValues(80.0, 8955.882352941177) + .build() + .run(); + } + + @Test + public void queryTest4() throws Exception { + testBuilder() + .sqlQuery( + "SELECT DEPARTMENT_ID, TO_CHAR(HIRE_DATE,'YYYY') AS DATAS " + + "FROM oracle.`SYSTEM`.`EMPLOYEES` WHERE DEPARTMENT_ID <= 20 " + + "GROUP BY DEPARTMENT_ID, TO_CHAR(HIRE_DATE, 'YYYY') ORDER BY DEPARTMENT_ID") + .ordered() + .baselineColumns("DEPARTMENT_ID", "DATAS") + .baselineValues(10.0, "1987") + .baselineValues(20.0, "1996") + .baselineValues(20.0, "1997") + .build() + .run(); + } + + @Test + public void queryTest5() throws Exception { + testBuilder() + .sqlQuery( + "SELECT JOB_ID, COUNT(JOB_ID) AS COUNTS, SUM(SALARY) AS SUMS, MAX(SALARY)-MIN(SALARY) SALARY " + + "FROM oracle.`SYSTEM`.`EMPLOYEES` WHERE JOB_ID = 'AD_VP' GROUP BY JOB_ID") + .ordered() + .baselineColumns("JOB_ID","COUNTS", "SUMS", "SALARY") + .baselineValues("AD_VP", 2.0, 34000.0, 0.0) + .build() + .run(); + } + + @Test + public void queryTest6() throws Exception { + testBuilder() + .sqlQuery( + "SELECT * FROM oracle.`SYSTEM`.`DEPARTMENTS` " + + "WHERE DEPARTMENT_ID IN (SELECT DEPARTMENT_ID FROM oracle.`SYSTEM`.`EMPLOYEES` " + + "WHERE EMPLOYEE_ID IN (SELECT EMPLOYEE_ID FROM oracle.`SYSTEM`.`JOB_HISTORY`) " + + "GROUP BY DEPARTMENT_ID HAVING MAX(SALARY) >10000)") + .ordered() + .baselineColumns("DEPARTMENT_ID","DEPARTMENT_NAME", "MANAGER_ID", "LOCATION_ID") + .baselineValues(30.0, "Purchasing", 114.0, 1700.0) + .baselineValues(90.0, "Executive", 100.0, 1700.0) + .baselineValues(20.0, "Marketing", 201.0, 1800.0) + .build() + .run(); + } + + @Test + public void queryTest7() throws Exception { + testBuilder() + .sqlQuery( + "SELECT JH.* " + + "FROM oracle.`SYSTEM`.`JOB_HISTORY` JH " + + "JOIN oracle.`SYSTEM`.`EMPLOYEES` E ON (JH.EMPLOYEE_ID = E.EMPLOYEE_ID) WHERE SALARY > 15000" + ) + .ordered() + .baselineColumns("EMPLOYEE_ID", "START_DATE", "END_DATE", "JOB_ID", "DEPARTMENT_ID") + .baselineValues(102.0, new DateTime(1993, 1, 13, 0, 0), new DateTime(1998, 7, 24, 0, 0), "AD_VP", 90.0) + .baselineValues(101.0, new DateTime(1989, 9, 21, 0, 0), new DateTime(1993, 10, 27, 0, 0), "AD_VP", 90.0) + .baselineValues(101.0, new DateTime(1993, 10, 28, 0, 0), new DateTime(1997, 3, 15, 0, 0), "AD_VP", 90.0) + .build() + .run(); + } + + @Test + public void pushdownQueryTest1() throws Exception { + String query = "select first_name, last_name " + + "from oracle.`SYSTEM`.`EMPLOYEES` where first_name like 'G%' "; + testPlanMatchingPatterns(query, new String[]{}, new String[]{"Like"}); + } + + @Test + public void pushdownQueryTest2() throws Exception { + String query = "select DEPARTMENT_NAME, FIRST_NAME, CITY " + + "from oracle.`SYSTEM`.`DEPARTMENTS` D " + + "join oracle.`SYSTEM`.`EMPLOYEES` E ON (D.MANAGER_ID=E.EMPLOYEE_ID) " + + "join oracle.`SYSTEM`.`LOCATIONS` L USING (LOCATION_ID) where FIRST_NAME like 'A%' "; + testPlanMatchingPatterns(query, new String[]{}, new String[]{"Join"}); + } + + @Test + public void pushdownQueryTest3() throws Exception { + String query = "select DEPARTMENT_ID, AVG(SALARY) as AVGS " + + "from oracle.`SYSTEM`.`EMPLOYEES` where COMMISSION_PCT IS NOT NULL group by DEPARTMENT_ID"; + testPlanMatchingPatterns(query, new String[]{}, new String[]{"Aggregate", "Filter"}); + } + + @Test + public void pushdownQueryTest4() throws Exception { + String query = "select DEPARTMENT_ID, TO_CHAR(HIRE_DATE,'YYYY') as DATAS " + + "from oracle.`SYSTEM`.`EMPLOYEES` where DEPARTMENT_ID <= 20 " + + "group by DEPARTMENT_ID, TO_CHAR(HIRE_DATE, 'YYYY') order by DEPARTMENT_ID"; + testPlanMatchingPatterns(query, new String[]{}, new String[]{"Filter"}); + } + + @Test + public void pushdownQueryTest5() throws Exception { + String query = "select JOB_ID, COUNT(JOB_ID) as COUNTS, SUM(SALARY) as SUMS, MAX(SALARY)-MIN(SALARY) SALARY " + + "from oracle.`SYSTEM`.`EMPLOYEES` where JOB_ID = 'AD_VP' group by JOB_ID "; + testPlanMatchingPatterns(query, new String[]{}, new String[]{"Aggregate"}); + } + + @Test + public void pushdownQueryTest6() throws Exception { + String query = "select * from oracle.`SYSTEM`.`DEPARTMENTS` " + + "where DEPARTMENT_ID IN (select DEPARTMENT_ID from oracle.`SYSTEM`.`EMPLOYEES` " + + "where EMPLOYEE_ID IN (select EMPLOYEE_ID from oracle.`SYSTEM`.`JOB_HISTORY`) " + + "group by DEPARTMENT_ID HAVING MAX(SALARY) >10000) "; + testPlanMatchingPatterns(query, new String[]{}, new String[]{"Filter"}); + } + + @Test + public void pushdownQueryTest7() throws Exception { + String query = "select JH.* " + + "from oracle.`SYSTEM`.`JOB_HISTORY` JH " + + "join oracle.`SYSTEM`.`EMPLOYEES` E ON (JH.EMPLOYEE_ID = E.EMPLOYEE_ID) where SALARY > 15000"; + testPlanMatchingPatterns(query, new String[]{}, new String[]{"Join", "Filter"}); + } + } diff --git a/contrib/storage-jdbc/src/test/resources/oracle-testhr-data.sql b/contrib/storage-jdbc/src/test/resources/oracle-testhr-data.sql new file mode 100644 index 00000000000..cac8ece0ec6 --- /dev/null +++ b/contrib/storage-jdbc/src/test/resources/oracle-testhr-data.sql @@ -0,0 +1,537 @@ +-- Generated by Oracle SQL Developer Data Modeler Version: 2.0.0 Build: 570 +-- at: 2009-06-29 12:05:54 +-- site: Oracle Database 11g +-- type: Oracle Database 11g + + +CREATE TABLE COUNTRIES + ( + COUNTRY_ID CHAR (2 BYTE) NOT NULL , + COUNTRY_NAME VARCHAR2 (40 BYTE) , + REGION_ID NUMBER + ) LOGGING +; + + + +COMMENT ON COLUMN COUNTRIES.COUNTRY_ID IS 'Primary key of countries table.' +; + +COMMENT ON COLUMN COUNTRIES.COUNTRY_NAME IS 'Country name' +; + +COMMENT ON COLUMN COUNTRIES.REGION_ID IS 'Region ID for the country. Foreign key to region_id column in the departments table.' +; + +ALTER TABLE COUNTRIES + ADD CONSTRAINT COUNTRY_C_ID_PK PRIMARY KEY ( COUNTRY_ID ) ; + + +CREATE TABLE DEPARTMENTS + ( + DEPARTMENT_ID NUMBER (4) NOT NULL , + DEPARTMENT_NAME VARCHAR2 (30 BYTE) NOT NULL , + MANAGER_ID NUMBER (6) , + LOCATION_ID NUMBER (4) + ) LOGGING +; + + + +COMMENT ON COLUMN DEPARTMENTS.DEPARTMENT_ID IS 'Primary key column of departments table.' +; + +COMMENT ON COLUMN DEPARTMENTS.DEPARTMENT_NAME IS 'A not null column that shows name of a department. Administration, +Marketing, Purchasing, Human Resources, Shipping, IT, Executive, Public +Relations, Sales, Finance, and Accounting. ' +; + +COMMENT ON COLUMN DEPARTMENTS.MANAGER_ID IS 'Manager_id of a department. Foreign key to employee_id column of employees table. The manager_id column of the employee table references this column.' +; + +COMMENT ON COLUMN DEPARTMENTS.LOCATION_ID IS 'Location id where a department is located. Foreign key to location_id column of locations table.' +; +CREATE INDEX DEPT_LOCATION_IX ON DEPARTMENTS + ( + LOCATION_ID ASC + ) + NOLOGGING + NOCOMPRESS + NOPARALLEL +; + +ALTER TABLE DEPARTMENTS + ADD CONSTRAINT DEPT_ID_PK PRIMARY KEY ( DEPARTMENT_ID ) ; + + +CREATE TABLE EMPLOYEES + ( + EMPLOYEE_ID NUMBER (6) NOT NULL , + FIRST_NAME VARCHAR2 (20 BYTE) , + LAST_NAME VARCHAR2 (25 BYTE) NOT NULL , + EMAIL VARCHAR2 (25 BYTE) NOT NULL , + PHONE_NUMBER VARCHAR2 (20 BYTE) , + HIRE_DATE DATE NOT NULL , + JOB_ID VARCHAR2 (10 BYTE) NOT NULL , + SALARY NUMBER (8,2) , + COMMISSION_PCT NUMBER (2,2) , + MANAGER_ID NUMBER (6) , + DEPARTMENT_ID NUMBER (4) + ) LOGGING +; + + + +COMMENT ON COLUMN EMPLOYEES.EMPLOYEE_ID IS 'Primary key of employees table.' +; + +COMMENT ON COLUMN EMPLOYEES.FIRST_NAME IS 'First name of the employee. A not null column.' +; + +COMMENT ON COLUMN EMPLOYEES.LAST_NAME IS 'Last name of the employee. A not null column.' +; + +COMMENT ON COLUMN EMPLOYEES.EMAIL IS 'Email id of the employee' +; + +COMMENT ON COLUMN EMPLOYEES.PHONE_NUMBER IS 'Phone number of the employee; includes country code and area code' +; + +COMMENT ON COLUMN EMPLOYEES.HIRE_DATE IS 'Date when the employee started on this job. A not null column.' +; + +COMMENT ON COLUMN EMPLOYEES.JOB_ID IS 'Current job of the employee; foreign key to job_id column of the +jobs table. A not null column.' +; + +COMMENT ON COLUMN EMPLOYEES.SALARY IS 'Monthly salary of the employee. Must be greater +than zero (enforced by constraint emp_salary_min)' +; + +COMMENT ON COLUMN EMPLOYEES.COMMISSION_PCT IS 'Commission percentage of the employee; Only employees in sales +department elgible for commission percentage' +; + +COMMENT ON COLUMN EMPLOYEES.MANAGER_ID IS 'Manager id of the employee; has same domain as manager_id in +departments table. Foreign key to employee_id column of employees table. +(useful for reflexive joins and CONNECT BY query)' +; + +COMMENT ON COLUMN EMPLOYEES.DEPARTMENT_ID IS 'Department id where employee works; foreign key to department_id +column of the departments table' +; +CREATE INDEX EMP_DEPARTMENT_IX ON EMPLOYEES + ( + DEPARTMENT_ID ASC + ) + NOLOGGING + NOCOMPRESS + NOPARALLEL +; +CREATE INDEX EMP_NAME_IX ON EMPLOYEES + ( + LAST_NAME ASC , + FIRST_NAME ASC + ) + NOLOGGING + NOCOMPRESS + NOPARALLEL +; +CREATE INDEX EMP_JOB_IX ON EMPLOYEES + ( + JOB_ID ASC + ) + NOLOGGING + NOCOMPRESS + NOPARALLEL +; +CREATE INDEX EMP_MANAGER_IX ON EMPLOYEES + ( + MANAGER_ID ASC + ) + NOLOGGING + NOCOMPRESS + NOPARALLEL +; + +ALTER TABLE EMPLOYEES + ADD CONSTRAINT EMP_EMP_ID_PK PRIMARY KEY ( EMPLOYEE_ID ) ; + +ALTER TABLE EMPLOYEES + ADD CONSTRAINT EMP_EMAIL_UK UNIQUE ( EMAIL ) +; + + +CREATE TABLE JOBS + ( + JOB_ID VARCHAR2 (10 BYTE) NOT NULL , + JOB_TITLE VARCHAR2 (35 BYTE) NOT NULL , + MIN_SALARY NUMBER (6) , + MAX_SALARY NUMBER (6) + ) LOGGING +; + + + +COMMENT ON COLUMN JOBS.JOB_ID IS 'Primary key of jobs table.' +; + +COMMENT ON COLUMN JOBS.JOB_TITLE IS 'A not null column that shows job title, e.g. AD_VP, FI_ACCOUNTANT' +; + +COMMENT ON COLUMN JOBS.MIN_SALARY IS 'Minimum salary for a job title.' +; + +COMMENT ON COLUMN JOBS.MAX_SALARY IS 'Maximum salary for a job title' +; + +ALTER TABLE JOBS + ADD CONSTRAINT JOB_ID_PK PRIMARY KEY ( JOB_ID ) ; + + +CREATE TABLE JOB_HISTORY + ( + EMPLOYEE_ID NUMBER (6) NOT NULL , + START_DATE DATE NOT NULL , + END_DATE DATE NOT NULL , + JOB_ID VARCHAR2 (10 BYTE) NOT NULL , + DEPARTMENT_ID NUMBER (4) + ) LOGGING +; + + + +ALTER TABLE JOB_HISTORY + ADD CONSTRAINT JHIST_DATE_INTERVAL + CHECK (end_date > start_date) + INITIALLY IMMEDIATE + ENABLE + VALIDATE +; + + +COMMENT ON COLUMN JOB_HISTORY.EMPLOYEE_ID IS 'A not null column in the complex primary key employee_id+start_date. +Foreign key to employee_id column of the employee table' +; + +COMMENT ON COLUMN JOB_HISTORY.START_DATE IS 'A not null column in the complex primary key employee_id+start_date. +Must be less than the end_date of the job_history table. (enforced by +constraint jhist_date_interval)' +; + +COMMENT ON COLUMN JOB_HISTORY.END_DATE IS 'Last day of the employee in this job role. A not null column. Must be +greater than the start_date of the job_history table. +(enforced by constraint jhist_date_interval)' +; + +COMMENT ON COLUMN JOB_HISTORY.JOB_ID IS 'Job role in which the employee worked in the past; foreign key to +job_id column in the jobs table. A not null column.' +; + +COMMENT ON COLUMN JOB_HISTORY.DEPARTMENT_ID IS 'Department id in which the employee worked in the past; foreign key to deparment_id column in the departments table' +; +CREATE INDEX JHIST_JOB_IX ON JOB_HISTORY + ( + JOB_ID ASC + ) + NOLOGGING + NOCOMPRESS + NOPARALLEL +; +CREATE INDEX JHIST_EMPLOYEE_IX ON JOB_HISTORY + ( + EMPLOYEE_ID ASC + ) + NOLOGGING + NOCOMPRESS + NOPARALLEL +; +CREATE INDEX JHIST_DEPARTMENT_IX ON JOB_HISTORY + ( + DEPARTMENT_ID ASC + ) + NOLOGGING + NOCOMPRESS + NOPARALLEL +; + +ALTER TABLE JOB_HISTORY + ADD CONSTRAINT JHIST_EMP_ID_ST_DATE_PK PRIMARY KEY ( EMPLOYEE_ID, START_DATE ) ; + + +CREATE TABLE LOCATIONS + ( + LOCATION_ID NUMBER (4) NOT NULL , + STREET_ADDRESS VARCHAR2 (40 BYTE) , + POSTAL_CODE VARCHAR2 (12 BYTE) , + CITY VARCHAR2 (30 BYTE) NOT NULL , + STATE_PROVINCE VARCHAR2 (25 BYTE) , + COUNTRY_ID CHAR (2 BYTE) + ) LOGGING +; + + + +COMMENT ON COLUMN LOCATIONS.LOCATION_ID IS 'Primary key of locations table' +; + +COMMENT ON COLUMN LOCATIONS.STREET_ADDRESS IS 'Street address of an office, warehouse, or production site of a company. +Contains building number and street name' +; + +COMMENT ON COLUMN LOCATIONS.POSTAL_CODE IS 'Postal code of the location of an office, warehouse, or production site +of a company. ' +; + +COMMENT ON COLUMN LOCATIONS.CITY IS 'A not null column that shows city where an office, warehouse, or +production site of a company is located. ' +; + +COMMENT ON COLUMN LOCATIONS.STATE_PROVINCE IS 'State or Province where an office, warehouse, or production site of a +company is located.' +; + +COMMENT ON COLUMN LOCATIONS.COUNTRY_ID IS 'Country where an office, warehouse, or production site of a company is +located. Foreign key to country_id column of the countries table.' +; +CREATE INDEX LOC_CITY_IX ON LOCATIONS + ( + CITY ASC + ) + NOLOGGING + NOCOMPRESS + NOPARALLEL +; +CREATE INDEX LOC_COUNTRY_IX ON LOCATIONS + ( + COUNTRY_ID ASC + ) + NOLOGGING + NOCOMPRESS + NOPARALLEL +; +CREATE INDEX LOC_STATE_PROVINCE_IX ON LOCATIONS + ( + STATE_PROVINCE ASC + ) + NOLOGGING + NOCOMPRESS + NOPARALLEL +; + +ALTER TABLE LOCATIONS + ADD CONSTRAINT LOC_ID_PK PRIMARY KEY ( LOCATION_ID ) ; + + +CREATE TABLE REGIONS + ( + REGION_ID NUMBER NOT NULL , + REGION_NAME VARCHAR2 (25 BYTE) + ) LOGGING +; + + + +COMMENT ON COLUMN REGIONS.REGION_ID IS 'Primary key of regions table.' +; + +COMMENT ON COLUMN REGIONS.REGION_NAME IS 'Names of regions. Locations are in the countries of these regions.' +; + +ALTER TABLE REGIONS + ADD CONSTRAINT REG_ID_PK PRIMARY KEY ( REGION_ID ) ; + + + +ALTER TABLE COUNTRIES + ADD CONSTRAINT COUNTR_REG_FK FOREIGN KEY + ( + REGION_ID + ) + REFERENCES REGIONS + ( + REGION_ID + ) + NOT DEFERRABLE +; + + +ALTER TABLE DEPARTMENTS + ADD CONSTRAINT DEPT_LOC_FK FOREIGN KEY + ( + LOCATION_ID + ) + REFERENCES LOCATIONS + ( + LOCATION_ID + ) + NOT DEFERRABLE +; + + +ALTER TABLE DEPARTMENTS + ADD CONSTRAINT DEPT_MGR_FK FOREIGN KEY + ( + MANAGER_ID + ) + REFERENCES EMPLOYEES + ( + EMPLOYEE_ID + ) + NOT DEFERRABLE +; + + +ALTER TABLE EMPLOYEES + ADD CONSTRAINT EMP_DEPT_FK FOREIGN KEY + ( + DEPARTMENT_ID + ) + REFERENCES DEPARTMENTS + ( + DEPARTMENT_ID + ) + NOT DEFERRABLE +; + + +ALTER TABLE EMPLOYEES + ADD CONSTRAINT EMP_JOB_FK FOREIGN KEY + ( + JOB_ID + ) + REFERENCES JOBS + ( + JOB_ID + ) + NOT DEFERRABLE +; + + +ALTER TABLE EMPLOYEES + ADD CONSTRAINT EMP_MANAGER_FK FOREIGN KEY + ( + MANAGER_ID + ) + REFERENCES EMPLOYEES + ( + EMPLOYEE_ID + ) + NOT DEFERRABLE +; + + +ALTER TABLE JOB_HISTORY + ADD CONSTRAINT JHIST_DEPT_FK FOREIGN KEY + ( + DEPARTMENT_ID + ) + REFERENCES DEPARTMENTS + ( + DEPARTMENT_ID + ) + NOT DEFERRABLE +; + + +ALTER TABLE JOB_HISTORY + ADD CONSTRAINT JHIST_EMP_FK FOREIGN KEY + ( + EMPLOYEE_ID + ) + REFERENCES EMPLOYEES + ( + EMPLOYEE_ID + ) + NOT DEFERRABLE +; + + +ALTER TABLE JOB_HISTORY + ADD CONSTRAINT JHIST_JOB_FK FOREIGN KEY + ( + JOB_ID + ) + REFERENCES JOBS + ( + JOB_ID + ) + NOT DEFERRABLE +; + + +ALTER TABLE LOCATIONS + ADD CONSTRAINT LOC_C_ID_FK FOREIGN KEY + ( + COUNTRY_ID + ) + REFERENCES COUNTRIES + ( + COUNTRY_ID + ) + NOT DEFERRABLE +; + +CREATE OR REPLACE VIEW EMP_DETAILS_VIEW +AS +SELECT + e.employee_id, + e.job_id, + e.manager_id, + e.department_id, + d.location_id, + l.country_id, + e.first_name, + e.last_name, + e.salary, + e.commission_pct, + d.department_name, + j.job_title, + l.city, + l.state_province, + c.country_name, + r.region_name +FROM + employees e, + departments d, + jobs j, + locations l, + countries c, + regions r +WHERE e.department_id = d.department_id + AND d.location_id = l.location_id + AND l.country_id = c.country_id + AND c.region_id = r.region_id + AND j.job_id = e.job_id +WITH READ ONLY ; + + +-- Oracle SQL Developer Data Modeler Summary Report: +-- +-- CREATE TABLE 7 +-- CREATE INDEX 11 +-- ALTER TABLE 10 +-- CREATE VIEW 1 +-- CREATE PROCEDURE 0 +-- CREATE TRIGGER 0 +-- CREATE STRUCTURED TYPE 0 +-- CREATE COLLECTION TYPE 0 +-- CREATE CLUSTER 0 +-- CREATE CONTEXT 0 +-- CREATE DATABASE 0 +-- CREATE DIMENSION 0 +-- CREATE DIRECTORY 0 +-- CREATE DISK GROUP 0 +-- CREATE ROLE 0 +-- CREATE ROLLBACK SEGMENT 0 +-- CREATE SEQUENCE 0 +-- CREATE SNAPSHOT 0 +-- CREATE SYNONYM 0 +-- CREATE TABLESPACE 0 +-- CREATE USER 0 +-- +-- DROP TABLESPACE 0 +-- DROP DATABASE 0 +-- +-- ERRORS 0 +-- WARNINGS 0