Commit a9890aa4 authored by Stanley Clark's avatar Stanley Clark
Browse files

Update to comparison (working DB2)

parent 230eda81
oracle/tpcds.sql
\ No newline at end of file
oracle/sql/tpcds.sql
oracle/ctl/*.log
\ No newline at end of file
# Comparison
First, generate TPC-DS data using `gen_tpcds.sh`.
Make sure to have cloned submodules using `git submodule update --init`.
Then, generate TPC-DS data using `gen_tpcds.sh`.
## Oracle VPD
......@@ -24,16 +25,20 @@ Connect via JDBC using username `sys as sysdba`.
## IBM DB2
* Setup the DB [Docker image](https://hub.docker.com/r/ibmcom/db2).
* Setup the DB [Docker image](https://hub.docker.com/r/ibmcom/db2)
* Install the IBM Data Server Runtime [Client](https://www.ibm.com/support/pages/download-initial-version-115-clients-and-drivers)
* Start the server Docker container using
```
docker run -itd --name DB2 \
--privileged=true
-p 50000:50000
-e LICENSE=accept
-e DB2INST1_PASSWORD=password
-e DBNAME=testdb
-v DB2Data:/database ibmcom/db2
```
```
docker run -itd --name DB2 \
--privileged=true \
-p 50000:50000 \
-e LICENSE=accept \
-e DB2INST1_PASSWORD=password \
-e DBNAME=testdb \
-v DB2Data:/database \
ibmcom/db2
docker run -itd --name DB2 --privileged=true -p 50000:50000 -e LICENSE=accept -e DB2INST1_PASSWORD=password -e DBNAME=testdb -v DB2Data:/database ibmcom/db2
```
* Run `ibm/populate.sh`
* Run `ibm/run.sh`
#!/usr/bin/env sh
# Create TPC-DS schema and users
cd ../../oracle || exit
echo @clean.sql | sqlplus sys/Oradoc_db1@ORCLCDB as sysdba
echo @employee.sql | sqlplus sys/Oradoc_db1@ORCLCDB as sysdba
echo @../tpc-des/tools/tpcds.sql | sqlplus sys/Oradoc_db1@ORCLCDB as sysdba
echo @users.sql | sqlplus sys/Oradoc_db1@ORCLPDB1 as sysdba
# Generate explain tables
docker exec -ti DB2 bash -c "su - db2inst1 db2 \"connect to testdb\" && cd sqllib/misc && db2 -tf EXPLAIN.DDL"
# Connect to DB2
db2 catalog tcpip node docker remote 0.0.0.0 server 50000
db2 catalog database testdb as testdb at node docker
docker exec -it DB2 useradd -m db2sec -g db2iadm1 -p "$(openssl passwd -crypt passwd1)"
db2 CONNECT TO testdb user db2sec using passwd1
db2 grant secadm on database to user db2inst1
db2 CONNECT TO testdb user db2inst1 using password
# DB2 users are OS users, so create them here
for i in $(seq 1 10);
do
docker exec -it DB2 useradd -m "user$i" -g db2iadm1 -p "$(openssl passwd -crypt passwd1)"
db2 grant dataaccess on database to user "user$i"
done
# Create TPC-DS schema, users and policies
db2 -t -f sql/clean.sql
db2 -t -f sql/employee.sql
db2 -t -f sql/policies.sql
db2 -t -f ../../tpc-ds/tools/tpcds.sql
# Import generated data to postgres instance
cd ctl || exit
for tableScript in *.ctl
for tableScript in ../../tpc-ds/tools/*.dat
do
echo "$tableScript"
sqlldr \'sys/Oradoc_db1@ORCLCDB as sysdba\' control="$tableScript"
db2 IMPORT FROM "$tableScript" OF DEL MODIFIED BY COLDEL\| INSERT INTO "$(basename "$tableScript" .dat)";
done
#!/usr/bin/env sh
for query in ../../queries-spjr/*.sql
do
for i in $(seq 1 10);
do
db2 CONNECT TO testdb user "user$i" using passwd1
db2 SET schema=db2inst1
db2 -t -f "$query"
done
done
drop table if exists dbgen_version;
drop table if exists customer_address;
drop table if exists customer_demographics;
drop table if exists date_dim;
drop table if exists warehouse;
drop table if exists ship_mode;
drop table if exists time_dim;
drop table if exists reason;
drop table if exists income_band;
drop table if exists item;
drop table if exists store;
drop table if exists call_center;
drop table if exists customer;
drop table if exists web_site;
drop table if exists store_returns;
drop table if exists household_demographics;
drop table if exists web_page;
drop table if exists promotion;
drop table if exists catalog_page;
drop table if exists inventory;
drop table if exists catalog_returns;
drop table if exists web_returns;
drop table if exists web_sales;
drop table if exists catalog_sales;
drop table if exists store_sales;
drop table if exists employee;
\ No newline at end of file
CREATE TABLE employee
(
e_employee_id integer, -- employee id
e_name VARCHAR (400), -- employee name
e_store_sk integer, -- store employee is a manager of
e_year integer, -- year employee joined the company
e_role VARCHAR (400) -- employee role
);
INSERT INTO employee (e_employee_id, e_name, e_store_sk, e_year, e_role) VALUES (1, 'USER1', 1, 2010, 'manager');
INSERT INTO employee (e_employee_id, e_name, e_store_sk, e_year, e_role) VALUES (2, 'USER2', 2, 2012, 'sales');
INSERT INTO employee (e_employee_id, e_name, e_store_sk, e_year, e_role) VALUES (3, 'USER3', 2, 2000, 'billing');
INSERT INTO employee (e_employee_id, e_name, e_store_sk, e_year, e_role) VALUES (4, 'USER4', 3, 1990, 'support');
INSERT INTO employee (e_employee_id, e_name, e_store_sk, e_year, e_role) VALUES (5, 'USER5', 3, 2005, 'manager');
INSERT INTO employee (e_employee_id, e_name, e_store_sk, e_year, e_role) VALUES (6, 'USER6', 4, 2002, 'sales');
INSERT INTO employee (e_employee_id, e_name, e_store_sk, e_year, e_role) VALUES (7, 'USER7', 5, 2000, 'billing');
INSERT INTO employee (e_employee_id, e_name, e_store_sk, e_year, e_role) VALUES (8, 'USER8', 5, 2000, 'support');
INSERT INTO employee (e_employee_id, e_name, e_store_sk, e_year, e_role) VALUES (9, 'USER9', 6, 1985, 'manager');
INSERT INTO employee (e_employee_id, e_name, e_store_sk, e_year, e_role) VALUES (10, 'USER10', 7, 2019, 'sales');
CREATE OR REPLACE MASK cc_closed_date_sk_COL_MASK ON call_center FOR
COLUMN cc_closed_date_sk RETURN CASE WHEN (
SYSTEM_USER = 'DB2INST1' OR false
) THEN cc_closed_date_sk
ELSE NULL END ENABLE;
ALTER TABLE call_center ACTIVATE COLUMN ACCESS CONTROL;
CREATE OR REPLACE MASK cp_catalog_page_number_COL_MASK ON catalog_page FOR
COLUMN cp_catalog_page_number RETURN CASE WHEN (
SYSTEM_USER = 'DB2INST1' OR NOT EXISTS (SELECT 1 FROM employee WHERE (13 < catalog_page.cp_catalog_page_number) AND employee.e_name = SYSTEM_USER)
) THEN cp_catalog_page_number
ELSE NULL END ENABLE;
ALTER TABLE catalog_page ACTIVATE COLUMN ACCESS CONTROL;
CREATE OR REPLACE MASK cr_fee_COL_MASK ON catalog_returns FOR
COLUMN cr_fee RETURN CASE WHEN (
SYSTEM_USER = 'DB2INST1' OR NOT EXISTS (SELECT 1 FROM employee WHERE (0 <= catalog_returns.cr_reason_sk) AND employee.e_name = SYSTEM_USER)
) THEN cr_fee
ELSE NULL END ENABLE;
ALTER TABLE catalog_returns ACTIVATE COLUMN ACCESS CONTROL;
CREATE OR REPLACE MASK cs_net_profit_COL_MASK ON catalog_sales FOR
COLUMN cs_net_profit RETURN CASE WHEN (
SYSTEM_USER = 'DB2INST1' OR NOT EXISTS (SELECT 1 FROM employee WHERE (0 > catalog_sales.cs_net_profit AND 'sales' = employee.e_role) AND employee.e_name = SYSTEM_USER)
) THEN cs_net_profit
ELSE NULL END ENABLE;
ALTER TABLE catalog_sales ACTIVATE COLUMN ACCESS CONTROL;
CREATE OR REPLACE MASK c_first_name_COL_MASK ON customer FOR
COLUMN c_first_name RETURN CASE WHEN (
SYSTEM_USER = 'DB2INST1' OR NOT EXISTS (SELECT 1 FROM employee WHERE (customer.c_birth_year = employee.e_year) AND employee.e_name = SYSTEM_USER)
) THEN c_first_name
ELSE NULL END ENABLE;
ALTER TABLE customer ACTIVATE COLUMN ACCESS CONTROL;
CREATE OR REPLACE MASK cd_credit_rating_COL_MASK ON customer_demographics FOR
COLUMN cd_credit_rating RETURN CASE WHEN (
SYSTEM_USER = 'DB2INST1' OR NOT EXISTS (SELECT 1 FROM customer, employee WHERE (customer.c_birth_country = 'UNITED KINGDOM') AND employee.e_name = SYSTEM_USER)
) THEN cd_credit_rating
ELSE NULL END ENABLE;
ALTER TABLE customer_demographics ACTIVATE COLUMN ACCESS CONTROL;
CREATE OR REPLACE MASK hd_vehicle_count_COL_MASK ON household_demographics FOR
COLUMN hd_vehicle_count RETURN CASE WHEN (
SYSTEM_USER = 'DB2INST1' OR NOT EXISTS (SELECT 1 FROM income_band, employee WHERE (110000 < income_band.ib_upper_bound AND household_demographics.hd_income_band_sk = income_band.ib_income_band_sk) AND employee.e_name = SYSTEM_USER)
) THEN hd_vehicle_count
ELSE NULL END ENABLE;
ALTER TABLE household_demographics ACTIVATE COLUMN ACCESS CONTROL;
CREATE OR REPLACE MASK ib_lower_bound_COL_MASK ON income_band FOR
COLUMN ib_lower_bound RETURN CASE WHEN (
SYSTEM_USER = 'DB2INST1' OR EXISTS (SELECT 1 FROM employee WHERE (employee.e_role = 'manager') AND employee.e_name = SYSTEM_USER)
) THEN ib_lower_bound
ELSE NULL END ENABLE;
ALTER TABLE income_band ACTIVATE COLUMN ACCESS CONTROL;
CREATE OR REPLACE MASK inv_quantity_on_hand_COL_MASK ON inventory FOR
COLUMN inv_quantity_on_hand RETURN CASE WHEN (
SYSTEM_USER = 'DB2INST1' OR NOT EXISTS (SELECT 1 FROM warehouse, employee WHERE (warehouse.w_warehouse_sk = inventory.inv_warehouse_sk AND 'United States' = warehouse.w_country) AND employee.e_name = SYSTEM_USER)
) THEN inv_quantity_on_hand
ELSE NULL END ENABLE;
ALTER TABLE inventory ACTIVATE COLUMN ACCESS CONTROL;
CREATE OR REPLACE MASK i_brand_id_COL_MASK ON item FOR
COLUMN i_brand_id RETURN CASE WHEN (
SYSTEM_USER = 'DB2INST1' OR NOT EXISTS (SELECT 1 FROM employee WHERE (1000000 = item.i_brand_id) AND employee.e_name = SYSTEM_USER)
) THEN i_brand_id
ELSE NULL END ENABLE;
ALTER TABLE item ACTIVATE COLUMN ACCESS CONTROL;
CREATE OR REPLACE MASK r_reason_desc_COL_MASK ON reason FOR
COLUMN r_reason_desc RETURN CASE WHEN (
SYSTEM_USER = 'DB2INST1' OR NOT EXISTS (SELECT 1 FROM employee WHERE (employee.e_role = 'support') AND employee.e_name = SYSTEM_USER)
) THEN r_reason_desc
ELSE NULL END ENABLE;
ALTER TABLE reason ACTIVATE COLUMN ACCESS CONTROL;
CREATE OR REPLACE MASK sr_fee_COL_MASK ON store_returns FOR
COLUMN sr_fee RETURN CASE WHEN (
SYSTEM_USER = 'DB2INST1' OR NOT EXISTS (SELECT 1 FROM employee WHERE (0 <= store_returns.sr_reason_sk) AND employee.e_name = SYSTEM_USER)
) THEN sr_fee
ELSE NULL END ENABLE;
ALTER TABLE store_returns ACTIVATE COLUMN ACCESS CONTROL;
CREATE OR REPLACE MASK ss_quantity_COL_MASK ON store_sales FOR
COLUMN ss_quantity RETURN CASE WHEN (
SYSTEM_USER = 'DB2INST1' OR NOT EXISTS (SELECT 1 FROM employee WHERE (13 < store_sales.ss_quantity) AND employee.e_name = SYSTEM_USER)
) THEN ss_quantity
ELSE NULL END ENABLE;
ALTER TABLE store_sales ACTIVATE COLUMN ACCESS CONTROL;
CREATE OR REPLACE MASK wp_customer_sk_COL_MASK ON web_page FOR
COLUMN wp_customer_sk RETURN CASE WHEN (
SYSTEM_USER = 'DB2INST1' OR false
) THEN wp_customer_sk
ELSE NULL END ENABLE;
ALTER TABLE web_page ACTIVATE COLUMN ACCESS CONTROL;
CREATE OR REPLACE MASK wr_fee_COL_MASK ON web_returns FOR
COLUMN wr_fee RETURN CASE WHEN (
SYSTEM_USER = 'DB2INST1' OR NOT EXISTS (SELECT 1 FROM employee WHERE (0 <= web_returns.wr_reason_sk) AND employee.e_name = SYSTEM_USER)
) THEN wr_fee
ELSE NULL END ENABLE;
ALTER TABLE web_returns ACTIVATE COLUMN ACCESS CONTROL;
CREATE OR REPLACE MASK ws_coupon_amt_COL_MASK ON web_sales FOR
COLUMN ws_coupon_amt RETURN CASE WHEN (
SYSTEM_USER = 'DB2INST1' OR EXISTS (SELECT 1 FROM income_band, customer, household_demographics, employee WHERE (1000 < web_sales.ws_net_paid AND 80001 <= income_band.ib_lower_bound AND web_sales.ws_ship_customer_sk = customer.c_customer_sk AND customer.c_current_hdemo_sk = household_demographics.hd_demo_sk AND household_demographics.hd_income_band_sk = income_band.ib_income_band_sk) AND employee.e_name = SYSTEM_USER)
) THEN ws_coupon_amt
ELSE NULL END ENABLE;
ALTER TABLE web_sales ACTIVATE COLUMN ACCESS CONTROL;
CREATE OR REPLACE PERMISSION call_center_ROW_ACCESS ON call_center FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR EXISTS (SELECT 1 FROM date_dim, employee WHERE (employee.e_role = 'sales' OR (date_dim.d_date_sk = call_center.cc_open_date_sk AND 1997 > call_center.cc_open_date_sk)) AND employee.e_name = SYSTEM_USER)
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE call_center ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION catalog_page_ROW_ACCESS ON catalog_page FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR true
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE catalog_page ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION catalog_returns_ROW_ACCESS ON catalog_returns FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR EXISTS (SELECT 1 FROM customer, household_demographics, income_band, employee WHERE ((catalog_returns.cr_refunded_customer_sk = customer.c_customer_sk AND customer.c_current_hdemo_sk = household_demographics.hd_demo_sk) AND ((household_demographics.hd_income_band_sk = income_band.ib_income_band_sk AND income_band.ib_lower_bound = 0) OR (household_demographics.hd_buy_potential = '0-500'))) AND employee.e_name = SYSTEM_USER)
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE catalog_returns ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION catalog_sales_ROW_ACCESS ON catalog_sales FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR EXISTS (SELECT 1 FROM customer, household_demographics, income_band, employee WHERE ((catalog_sales.cs_ship_customer_sk = customer.c_customer_sk AND customer.c_current_hdemo_sk = household_demographics.hd_demo_sk) AND ((household_demographics.hd_income_band_sk = income_band.ib_income_band_sk AND income_band.ib_lower_bound = 0) OR (household_demographics.hd_buy_potential = '0-500'))) AND employee.e_name = SYSTEM_USER)
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE catalog_sales ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION customer_ROW_ACCESS ON customer FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR EXISTS (SELECT 1 FROM customer_address, employee WHERE (customer.c_current_addr_sk = customer_address.ca_address_sk AND customer.c_birth_country = customer_address.ca_country) AND employee.e_name = SYSTEM_USER)
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE customer ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION customer_address_ROW_ACCESS ON customer_address FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR EXISTS (SELECT 1 FROM employee WHERE (employee.e_role = 'sales' AND 2010 >= employee.e_year) AND employee.e_name = SYSTEM_USER)
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE customer_address ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION customer_demographics_ROW_ACCESS ON customer_demographics FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR true
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE customer_demographics ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION date_dim_ROW_ACCESS ON date_dim FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR true
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE date_dim ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION dbgen_version_ROW_ACCESS ON dbgen_version FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR false
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE dbgen_version ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION employee_ROW_ACCESS ON employee FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR true
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE employee ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION household_demographics_ROW_ACCESS ON household_demographics FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR true
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE household_demographics ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION income_band_ROW_ACCESS ON income_band FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR true
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE income_band ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION inventory_ROW_ACCESS ON inventory FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR EXISTS (SELECT 1 FROM warehouse, employee WHERE (inventory.inv_warehouse_sk = warehouse.w_warehouse_sk AND 300000 >= warehouse.w_warehouse_sq_ft) AND employee.e_name = SYSTEM_USER)
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE inventory ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION item_ROW_ACCESS ON item FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR EXISTS (SELECT 1 FROM store_returns, employee WHERE (store_returns.sr_item_sk = item.i_item_sk AND employee.e_store_sk = store_returns.sr_store_sk) AND employee.e_name = SYSTEM_USER)
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE item ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION promotion_ROW_ACCESS ON promotion FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR EXISTS (SELECT 1 FROM store_sales, employee WHERE (store_sales.ss_promo_sk = promotion.p_promo_sk) AND employee.e_name = SYSTEM_USER)
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE promotion ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION reason_ROW_ACCESS ON reason FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR true
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE reason ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION ship_mode_ROW_ACCESS ON ship_mode FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR true
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE ship_mode ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION store_ROW_ACCESS ON store FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR EXISTS (SELECT 1 FROM employee WHERE (0 > store.s_closed_date_sk OR 'manager' = employee.e_role) AND employee.e_name = SYSTEM_USER)
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE store ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION store_returns_ROW_ACCESS ON store_returns FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR EXISTS (SELECT 1 FROM employee WHERE (store_returns.sr_store_sk = employee.e_store_sk) AND employee.e_name = SYSTEM_USER)
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE store_returns ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION store_sales_ROW_ACCESS ON store_sales FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR EXISTS (SELECT 1 FROM employee WHERE (store_sales.ss_store_sk = employee.e_store_sk) AND employee.e_name = SYSTEM_USER)
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE store_sales ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION time_dim_ROW_ACCESS ON time_dim FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR true
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE time_dim ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION warehouse_ROW_ACCESS ON warehouse FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR true
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE warehouse ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION web_page_ROW_ACCESS ON web_page FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR EXISTS (SELECT 1 FROM employee WHERE (0 < web_page.wp_customer_sk) AND employee.e_name = SYSTEM_USER)
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE web_page ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION web_returns_ROW_ACCESS ON web_returns FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR EXISTS (SELECT 1 FROM date_dim, employee WHERE (date_dim.d_year > employee.e_year AND web_returns.wr_returned_date_sk = date_dim.d_date_sk) AND employee.e_name = SYSTEM_USER)
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE web_returns ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION web_sales_ROW_ACCESS ON web_sales FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR EXISTS (SELECT 1 FROM date_dim, employee WHERE (date_dim.d_year > employee.e_year AND web_sales.ws_sold_date_sk = date_dim.d_date_sk) AND employee.e_name = SYSTEM_USER)
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE web_sales ACTIVATE ROW ACCESS CONTROL;
CREATE OR REPLACE PERMISSION web_site_ROW_ACCESS ON web_site FOR ROWS WHERE
SYSTEM_USER = 'DB2INST1' OR EXISTS (SELECT 1 FROM employee WHERE (web_site.web_country = 'United States') AND employee.e_name = SYSTEM_USER)
ENFORCED FOR ALL ACCESS ENABLE;
ALTER TABLE web_site ACTIVATE ROW ACCESS CONTROL;
\ No newline at end of file
*.log
\ No newline at end of file
......@@ -22,7 +22,6 @@ CREATE OR REPLACE FUNCTION auth_call_center(
return_val VARCHAR2 (400);
BEGIN
return_val := '''sales'' = SYS_CONTEXT(''app_context'', ''emprole'') OR EXISTS (SELECT * FROM date_dim WHERE date_dim.d_date_sk = call_center.cc_open_date_sk AND 1997 > call_center.cc_open_date_sk)';
-- return_val := '''sales'' = SYS_CONTEXT(''app_context'', ''emprole'')';
RETURN return_val;
END auth_call_center;
......
#!/usr/bin/env sh
# Oracle doesn't support the 'time' format
cp ../tpc-ds/tools/tpcds.sql tpcds.sql
sed -i 's/dv_create_time time/dv_create_time date/g' tpcds.sql
cp ../tpc-ds/tools/tpcds.sql sql/tpcds.sql
sed -i 's/dv_create_time time/dv_create_time date/g' sql/tpcds.sql
# Create TPC-DS schema and users
echo @clean.sql | sqlplus sys/Oradoc_db1@ORCLCDB as sysdba
echo @employee.sql | sqlplus sys/Oradoc_db1@ORCLCDB as sysdba
echo @tpcds.sql | sqlplus sys/Oradoc_db1@ORCLCDB as sysdba
echo @users.sql | sqlplus sys/Oradoc_db1@ORCLPDB1 as sysdba
echo @sql/clean.sql | sqlplus sys/Oradoc_db1@ORCLCDB as sysdba
echo @sql/employee.sql | sqlplus sys/Oradoc_db1@ORCLCDB as sysdba
echo @sql/tpcds.sql | sqlplus sys/Oradoc_db1@ORCLCDB as sysdba
echo @sql/users.sql | sqlplus sys/Oradoc_db1@ORCLPDB1 as sysdba
# Import generated data to postgres instance
cd ctl || exit
for tableScript in *.ctl
# Import generated data to instance
for tableScript in ctl/*.ctl
do
echo "$tableScript"
sqlldr \'sys/Oradoc_db1@ORCLCDB as sysdba\' control="$tableScript"
done
......@@ -22,4 +22,5 @@ drop table catalog_returns;
drop table web_returns;
drop table web_sales;
drop table catalog_sales;
drop table store_sales;
\ No newline at end of file
drop table store_sales;
drop table employee;
\ No newline at end of file
Markdown is supported
0% or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment