From 22a9b7a4055632c03772cac73010d6c4b7ffeb8b Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Miko=C5=82aj=20So=C5=82tan?= Date: Thu, 13 Jun 2024 08:07:15 +0000 Subject: [PATCH 01/16] add used-space-details --- .../oracle/StatsTaskListGenerator.java | 1 + .../native/used-space-details.sql | 21 +++++++++++++++++++ 2 files changed, 22 insertions(+) create mode 100644 dumper/app/src/main/resources/oracle-stats/native/used-space-details.sql diff --git a/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java b/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java index 3ae257960..f73a26a2e 100644 --- a/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java +++ b/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java @@ -42,6 +42,7 @@ ImmutableList> createTasks(ConnectorArguments arguments) throws IOExcept OracleStatsQuery.create("pdbs-info", NATIVE), OracleStatsQuery.create("app-schemas-pdbs", NATIVE), OracleStatsQuery.create("app-schemas-summary", NATIVE), + OracleStatsQuery.create("used-space-details", NATIVE), OracleStatsQuery.create("hist-cmd-types", STATSPACK) // TODO: add entries for other SQLs to this list ); diff --git a/dumper/app/src/main/resources/oracle-stats/native/used-space-details.sql b/dumper/app/src/main/resources/oracle-stats/native/used-space-details.sql new file mode 100644 index 000000000..bd31cf0d9 --- /dev/null +++ b/dumper/app/src/main/resources/oracle-stats/native/used-space-details.sql @@ -0,0 +1,21 @@ +-- Copyright 2022-2024 Google LLC +-- Copyright 2013-2021 CompilerWorks +-- +-- Licensed 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. +SELECT A.con_id "ConId", + A.owner "Owner", + A.segment_type "SegmentType", + SUM(bytes) "Bytes" + FROM cdb_segments A + WHERE A.owner NOT LIKE '%SYS' + GROUP BY A.con_id, A.owner, A.segment_type From f587e02b81272999bfad787e1b88535a842a05c6 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Miko=C5=82aj=20So=C5=82tan?= Date: Thu, 13 Jun 2024 08:07:58 +0000 Subject: [PATCH 02/16] copy unmodified db-objects query from dma --- .../oracle/StatsTaskListGenerator.java | 1 + .../oracle-stats/native/db-objects.sql | 56 +++++++++++++++++++ 2 files changed, 57 insertions(+) create mode 100644 dumper/app/src/main/resources/oracle-stats/native/db-objects.sql diff --git a/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java b/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java index f73a26a2e..1ab21abb6 100644 --- a/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java +++ b/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java @@ -39,6 +39,7 @@ ImmutableList> createTasks(ConnectorArguments arguments) throws IOExcept ImmutableList.of( OracleStatsQuery.create("db-features", NATIVE), OracleStatsQuery.create("db-instances", NATIVE), + OracleStatsQuery.create("db-objects", NATIVE), OracleStatsQuery.create("pdbs-info", NATIVE), OracleStatsQuery.create("app-schemas-pdbs", NATIVE), OracleStatsQuery.create("app-schemas-summary", NATIVE), diff --git a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql new file mode 100644 index 000000000..f00386f02 --- /dev/null +++ b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql @@ -0,0 +1,56 @@ +-- Copyright 2022-2024 Google LLC +-- Copyright 2013-2021 CompilerWorks +-- +-- Licensed 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. +WITH +vdbobji AS ( + SELECT + &v_a_con_id AS con_id, + owner, + object_type, + &v_editionable_col AS editionable, + object_name + FROM &v_tblprefix._objects a + WHERE (owner = 'SYS' AND object_type = 'DIRECTORY') + OR owner NOT IN +@&EXTRACTSDIR/exclude_schemas.sql +), +vdbobjx AS ( + SELECT 'SYNONYM' as object_type, owner, synonym_name , &v_b_con_id AS con_id, table_owner + FROM &v_tblprefix._synonyms b + WHERE owner = 'PUBLIC' and + table_owner in +@&EXTRACTSDIR/exclude_schemas.sql + ), +vdbobj AS ( + SELECT :v_pkey AS pkey, + i.con_id, + i.owner, + i.object_type, + i.editionable, + COUNT(1) count + FROM vdbobji i + LEFT OUTER JOIN vdbobjx x ON i.object_type = x.object_type AND i.owner = x.owner AND i.object_name = x.synonym_name AND i.con_id = x.con_id + WHERE (CASE WHEN i.object_type = 'SYNONYM' and i.owner ='PUBLIC' and ( i.object_name like '/%' OR x.table_owner IS NOT NULL) THEN 0 ELSE 1 END = 1) + AND i.object_name NOT LIKE 'BIN$%' + GROUP BY i.con_id, i.owner, i.editionable , i.object_type +) +SELECT pkey , + con_id , + owner , + object_type , + editionable , + count , + :v_dma_source_id AS DMA_SOURCE_ID, :v_manual_unique_id AS DMA_MANUAL_ID +FROM vdbobj a + From d0a4eec23086db1e4c918351ae9e7379788d6ff6 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Miko=C5=82aj=20So=C5=82tan?= Date: Thu, 13 Jun 2024 08:09:48 +0000 Subject: [PATCH 03/16] replace script file references --- .../src/main/resources/oracle-stats/native/db-objects.sql | 8 ++------ 1 file changed, 2 insertions(+), 6 deletions(-) diff --git a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql index f00386f02..cab651204 100644 --- a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql +++ b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql @@ -22,16 +22,12 @@ vdbobji AS ( object_name FROM &v_tblprefix._objects a WHERE (owner = 'SYS' AND object_type = 'DIRECTORY') - OR owner NOT IN -@&EXTRACTSDIR/exclude_schemas.sql + OR owner NOT LIKE '%SYS' ), vdbobjx AS ( SELECT 'SYNONYM' as object_type, owner, synonym_name , &v_b_con_id AS con_id, table_owner FROM &v_tblprefix._synonyms b - WHERE owner = 'PUBLIC' and - table_owner in -@&EXTRACTSDIR/exclude_schemas.sql - ), + WHERE owner = 'PUBLIC'), vdbobj AS ( SELECT :v_pkey AS pkey, i.con_id, From 86515d73154523e196a82137a0f98a7e4b474787 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Miko=C5=82aj=20So=C5=82tan?= Date: Thu, 13 Jun 2024 08:12:27 +0000 Subject: [PATCH 04/16] remove variables --- .../resources/oracle-stats/native/db-objects.sql | 16 +++++++--------- 1 file changed, 7 insertions(+), 9 deletions(-) diff --git a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql index cab651204..be0f4f412 100644 --- a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql +++ b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql @@ -15,22 +15,21 @@ WITH vdbobji AS ( SELECT - &v_a_con_id AS con_id, + con_id, owner, object_type, - &v_editionable_col AS editionable, + editionable AS editionable, object_name - FROM &v_tblprefix._objects a + FROM cdb_objects a WHERE (owner = 'SYS' AND object_type = 'DIRECTORY') OR owner NOT LIKE '%SYS' ), vdbobjx AS ( - SELECT 'SYNONYM' as object_type, owner, synonym_name , &v_b_con_id AS con_id, table_owner - FROM &v_tblprefix._synonyms b + SELECT 'SYNONYM' as object_type, owner, synonym_name, con_id, table_owner + FROM cdb_synonyms b WHERE owner = 'PUBLIC'), vdbobj AS ( - SELECT :v_pkey AS pkey, - i.con_id, + SELECT i.con_id, i.owner, i.object_type, i.editionable, @@ -46,7 +45,6 @@ SELECT pkey , owner , object_type , editionable , - count , - :v_dma_source_id AS DMA_SOURCE_ID, :v_manual_unique_id AS DMA_MANUAL_ID + count FROM vdbobj a From 3f7c59464651979c95165e2ae0d1d1e10b946a9b Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Miko=C5=82aj=20So=C5=82tan?= Date: Thu, 13 Jun 2024 08:18:34 +0000 Subject: [PATCH 05/16] remove 'WITH' clauses --- .../oracle-stats/native/db-objects.sql | 39 +++++++++---------- 1 file changed, 18 insertions(+), 21 deletions(-) diff --git a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql index be0f4f412..fd7cb2d81 100644 --- a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql +++ b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql @@ -12,8 +12,19 @@ -- 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. -WITH -vdbobji AS ( +SELECT con_id , + owner , + object_type , + editionable , + count +FROM ( + SELECT i.con_id, + i.owner, + i.object_type, + i.editionable, + COUNT(1) count + FROM + ( SELECT con_id, owner, @@ -23,28 +34,14 @@ vdbobji AS ( FROM cdb_objects a WHERE (owner = 'SYS' AND object_type = 'DIRECTORY') OR owner NOT LIKE '%SYS' -), -vdbobjx AS ( +) i + LEFT OUTER JOIN + ( SELECT 'SYNONYM' as object_type, owner, synonym_name, con_id, table_owner FROM cdb_synonyms b - WHERE owner = 'PUBLIC'), -vdbobj AS ( - SELECT i.con_id, - i.owner, - i.object_type, - i.editionable, - COUNT(1) count - FROM vdbobji i - LEFT OUTER JOIN vdbobjx x ON i.object_type = x.object_type AND i.owner = x.owner AND i.object_name = x.synonym_name AND i.con_id = x.con_id + WHERE owner = 'PUBLIC') x + ON i.object_type = x.object_type AND i.owner = x.owner AND i.object_name = x.synonym_name AND i.con_id = x.con_id WHERE (CASE WHEN i.object_type = 'SYNONYM' and i.owner ='PUBLIC' and ( i.object_name like '/%' OR x.table_owner IS NOT NULL) THEN 0 ELSE 1 END = 1) AND i.object_name NOT LIKE 'BIN$%' GROUP BY i.con_id, i.owner, i.editionable , i.object_type ) -SELECT pkey , - con_id , - owner , - object_type , - editionable , - count -FROM vdbobj a - From 539f7276271a1682dfeae5ceaee4fa550a738f0d Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Miko=C5=82aj=20So=C5=82tan?= Date: Thu, 13 Jun 2024 08:27:35 +0000 Subject: [PATCH 06/16] fix indentation and aliases --- .../oracle-stats/native/db-objects.sql | 72 +++++++++++-------- 1 file changed, 41 insertions(+), 31 deletions(-) diff --git a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql index fd7cb2d81..46841e377 100644 --- a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql +++ b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql @@ -12,36 +12,46 @@ -- 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. -SELECT con_id , - owner , - object_type , - editionable , - count +SELECT + con_id , + owner , + object_type , + editionable , + count FROM ( - SELECT i.con_id, - i.owner, - i.object_type, - i.editionable, - COUNT(1) count - FROM - ( - SELECT - con_id, - owner, - object_type, - editionable AS editionable, - object_name - FROM cdb_objects a - WHERE (owner = 'SYS' AND object_type = 'DIRECTORY') - OR owner NOT LIKE '%SYS' -) i - LEFT OUTER JOIN - ( - SELECT 'SYNONYM' as object_type, owner, synonym_name, con_id, table_owner - FROM cdb_synonyms b - WHERE owner = 'PUBLIC') x - ON i.object_type = x.object_type AND i.owner = x.owner AND i.object_name = x.synonym_name AND i.con_id = x.con_id - WHERE (CASE WHEN i.object_type = 'SYNONYM' and i.owner ='PUBLIC' and ( i.object_name like '/%' OR x.table_owner IS NOT NULL) THEN 0 ELSE 1 END = 1) - AND i.object_name NOT LIKE 'BIN$%' - GROUP BY i.con_id, i.owner, i.editionable , i.object_type + SELECT + B.con_id, + B.owner, + B.object_type, + B.editionable, + COUNT(1) count + FROM ( + SELECT + A.con_id, + A.owner, + A.object_type, + A.editionable, + A.object_name + FROM cdb_objects A + WHERE (A.owner = 'SYS' AND A.object_type = 'DIRECTORY') + OR A.owner NOT LIKE '%SYS' + ) B + LEFT OUTER JOIN ( + SELECT + 'SYNONYM' object_type, + C.owner, synonym_name, + C.con_id, + C.table_owner + FROM cdb_synonyms C + WHERE C.owner = 'PUBLIC' + ) D ON B.object_type = D.object_type + AND B.owner = D.owner + AND B.object_name = D.synonym_name + AND B.con_id = D.con_id + WHERE ( + CASE WHEN B.object_type = 'SYNONYM' and B.owner ='PUBLIC' and ( B.object_name like '/%' OR D.table_owner IS NOT NULL + ) THEN 0 ELSE 1 END + = 1) + AND B.object_name NOT LIKE 'BIN$%' + GROUP BY B.con_id, B.owner, B.editionable , B.object_type ) From 854ec4e68061cb03e79e17472df81aea6134756d Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Miko=C5=82aj=20So=C5=82tan?= Date: Thu, 13 Jun 2024 08:32:12 +0000 Subject: [PATCH 07/16] rewrite 'CASE' to a simple condition --- .../main/resources/oracle-stats/native/db-objects.sql | 9 +++++---- 1 file changed, 5 insertions(+), 4 deletions(-) diff --git a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql index 46841e377..005fed279 100644 --- a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql +++ b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql @@ -49,9 +49,10 @@ FROM ( AND B.object_name = D.synonym_name AND B.con_id = D.con_id WHERE ( - CASE WHEN B.object_type = 'SYNONYM' and B.owner ='PUBLIC' and ( B.object_name like '/%' OR D.table_owner IS NOT NULL - ) THEN 0 ELSE 1 END - = 1) - AND B.object_name NOT LIKE 'BIN$%' + B.object_type <> 'SYNONYM' + OR B.owner <> 'PUBLIC' + OR (B.object_name NOT LIKE '/%' AND D.table_owner IS NULL) + ) + AND B.object_name NOT LIKE 'BIN$%' GROUP BY B.con_id, B.owner, B.editionable , B.object_type ) From 43eac981316437ee385a95e9016b1e675c761b91 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Miko=C5=82aj=20So=C5=82tan?= Date: Thu, 13 Jun 2024 08:40:31 +0000 Subject: [PATCH 08/16] substitute D.object_type --- .../app/src/main/resources/oracle-stats/native/db-objects.sql | 3 +-- 1 file changed, 1 insertion(+), 2 deletions(-) diff --git a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql index 005fed279..3bcdf2609 100644 --- a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql +++ b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql @@ -38,13 +38,12 @@ FROM ( ) B LEFT OUTER JOIN ( SELECT - 'SYNONYM' object_type, C.owner, synonym_name, C.con_id, C.table_owner FROM cdb_synonyms C WHERE C.owner = 'PUBLIC' - ) D ON B.object_type = D.object_type + ) D ON B.object_type = 'SYNONYM' AND B.owner = D.owner AND B.object_name = D.synonym_name AND B.con_id = D.con_id From 37b73cc18fe09f1910b2c8e6a76a40204e896c9b Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Miko=C5=82aj=20So=C5=82tan?= Date: Thu, 13 Jun 2024 08:53:04 +0000 Subject: [PATCH 09/16] add a separate sql to get sys-directory ignored by DMA --- .../oracle/StatsTaskListGenerator.java | 1 + .../native/db-objects-sys-directory.sql | 21 +++++++++++++++++++ 2 files changed, 22 insertions(+) create mode 100644 dumper/app/src/main/resources/oracle-stats/native/db-objects-sys-directory.sql diff --git a/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java b/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java index 1ab21abb6..ee0fa57dd 100644 --- a/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java +++ b/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java @@ -39,6 +39,7 @@ ImmutableList> createTasks(ConnectorArguments arguments) throws IOExcept ImmutableList.of( OracleStatsQuery.create("db-features", NATIVE), OracleStatsQuery.create("db-instances", NATIVE), + OracleStatsQuery.create("db-objects-sys-directory", NATIVE), OracleStatsQuery.create("db-objects", NATIVE), OracleStatsQuery.create("pdbs-info", NATIVE), OracleStatsQuery.create("app-schemas-pdbs", NATIVE), diff --git a/dumper/app/src/main/resources/oracle-stats/native/db-objects-sys-directory.sql b/dumper/app/src/main/resources/oracle-stats/native/db-objects-sys-directory.sql new file mode 100644 index 000000000..7b7b382ea --- /dev/null +++ b/dumper/app/src/main/resources/oracle-stats/native/db-objects-sys-directory.sql @@ -0,0 +1,21 @@ +-- Copyright 2022-2024 Google LLC +-- Copyright 2013-2021 CompilerWorks +-- +-- Licensed 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. +SELECT + A.con_id "ConId", + A.editionable "Editionable", + count(1) "Count" +FROM cdb_objects A +WHERE A.owner = 'SYS' AND A.object_type = 'DIRECTORY' +GROUP BY A.con_id, A.editionable From a07c46af7f7838151b49a8a993be4a552b632abb Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Miko=C5=82aj=20So=C5=82tan?= Date: Thu, 13 Jun 2024 11:09:33 +0000 Subject: [PATCH 10/16] remove a redundant subquery --- .../oracle-stats/native/db-objects.sql | 72 +++++++++---------- 1 file changed, 32 insertions(+), 40 deletions(-) diff --git a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql index 3bcdf2609..b0e25d1dc 100644 --- a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql +++ b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql @@ -13,45 +13,37 @@ -- See the License for the specific language governing permissions and -- limitations under the License. SELECT - con_id , - owner , - object_type , - editionable , - count + B.con_id, + B.owner, + B.object_type, + B.editionable, + COUNT(1) count FROM ( SELECT - B.con_id, - B.owner, - B.object_type, - B.editionable, - COUNT(1) count - FROM ( - SELECT - A.con_id, - A.owner, - A.object_type, - A.editionable, - A.object_name - FROM cdb_objects A - WHERE (A.owner = 'SYS' AND A.object_type = 'DIRECTORY') - OR A.owner NOT LIKE '%SYS' - ) B - LEFT OUTER JOIN ( - SELECT - C.owner, synonym_name, - C.con_id, - C.table_owner - FROM cdb_synonyms C - WHERE C.owner = 'PUBLIC' - ) D ON B.object_type = 'SYNONYM' - AND B.owner = D.owner - AND B.object_name = D.synonym_name - AND B.con_id = D.con_id - WHERE ( - B.object_type <> 'SYNONYM' - OR B.owner <> 'PUBLIC' - OR (B.object_name NOT LIKE '/%' AND D.table_owner IS NULL) - ) - AND B.object_name NOT LIKE 'BIN$%' - GROUP BY B.con_id, B.owner, B.editionable , B.object_type -) + A.con_id, + A.owner, + A.object_type, + A.editionable, + A.object_name + FROM cdb_objects A + WHERE (A.owner = 'SYS' AND A.object_type = 'DIRECTORY') + OR A.owner NOT LIKE '%SYS' +) B +LEFT OUTER JOIN ( + SELECT + C.owner, synonym_name, + C.con_id, + C.table_owner + FROM cdb_synonyms C + WHERE C.owner = 'PUBLIC' +) D ON B.object_type = 'SYNONYM' + AND B.owner = D.owner + AND B.object_name = D.synonym_name + AND B.con_id = D.con_id +WHERE ( + B.object_type <> 'SYNONYM' + OR B.owner <> 'PUBLIC' + OR (B.object_name NOT LIKE '/%' AND D.table_owner IS NULL) + ) + AND B.object_name NOT LIKE 'BIN$%' +GROUP BY B.con_id, B.owner, B.editionable , B.object_type From 83f611fa9ede45075deb41ded961a5c1f4960ae5 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Miko=C5=82aj=20So=C5=82tan?= Date: Thu, 13 Jun 2024 12:02:12 +0000 Subject: [PATCH 11/16] move where predicates before the join --- .../oracle-stats/native/db-objects.sql | 20 ++++++++++--------- 1 file changed, 11 insertions(+), 9 deletions(-) diff --git a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql index b0e25d1dc..12642df6f 100644 --- a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql +++ b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql @@ -26,24 +26,26 @@ FROM ( A.editionable, A.object_name FROM cdb_objects A - WHERE (A.owner = 'SYS' AND A.object_type = 'DIRECTORY') - OR A.owner NOT LIKE '%SYS' + WHERE ((A.owner = 'SYS' AND A.object_type = 'DIRECTORY') OR A.owner NOT LIKE '%SYS') + AND ( + A.object_type <> 'SYNONYM' + OR A.owner <> 'PUBLIC' + OR A.object_name NOT LIKE '/%' + ) + AND A.object_name NOT LIKE 'BIN$%' ) B LEFT OUTER JOIN ( SELECT - C.owner, synonym_name, + C.owner, + C.synonym_name, C.con_id, C.table_owner FROM cdb_synonyms C WHERE C.owner = 'PUBLIC' + AND C.table_owner IS NOT NULL ) D ON B.object_type = 'SYNONYM' AND B.owner = D.owner AND B.object_name = D.synonym_name AND B.con_id = D.con_id -WHERE ( - B.object_type <> 'SYNONYM' - OR B.owner <> 'PUBLIC' - OR (B.object_name NOT LIKE '/%' AND D.table_owner IS NULL) - ) - AND B.object_name NOT LIKE 'BIN$%' +WHERE D.table_owner IS NULL GROUP BY B.con_id, B.owner, B.editionable , B.object_type From 2c3eddaac15ede13ce7f4990b3c435b723ad858b Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Miko=C5=82aj=20So=C5=82tan?= Date: Thu, 13 Jun 2024 15:18:08 +0000 Subject: [PATCH 12/16] add db-objects sqls --- .../native/db-objects-no-join.sql | 67 +++++++++++++++++++ ...ects.sql => db-objects-synonym-public.sql} | 44 ++++++------ .../native/db-objects-sys-directory.sql | 21 ------ 3 files changed, 90 insertions(+), 42 deletions(-) create mode 100644 dumper/app/src/main/resources/oracle-stats/native/db-objects-no-join.sql rename dumper/app/src/main/resources/oracle-stats/native/{db-objects.sql => db-objects-synonym-public.sql} (51%) delete mode 100644 dumper/app/src/main/resources/oracle-stats/native/db-objects-sys-directory.sql diff --git a/dumper/app/src/main/resources/oracle-stats/native/db-objects-no-join.sql b/dumper/app/src/main/resources/oracle-stats/native/db-objects-no-join.sql new file mode 100644 index 000000000..f6b32b7e3 --- /dev/null +++ b/dumper/app/src/main/resources/oracle-stats/native/db-objects-no-join.sql @@ -0,0 +1,67 @@ +-- Copyright 2022-2024 Google LLC +-- Copyright 2013-2021 CompilerWorks +-- +-- Licensed 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. + +-- This deals with the simpler case of db-objects. +-- The other case is SYNONYM objects with PUBLIC owner, which require a JOIN +-- with a _synonyms table. +SELECT + A.con_id "ConId", + A.owner "Owner", + A.object_type "ObjectType", + A.editionable "Editionable", + count(1) "Count" +FROM cdb_objects A +WHERE A.owner NOT LIKE '%SYS' + AND A.object_name NOT LIKE 'BIN$%' +GROUP BY + A.con_id, + A.owner, + A.object_type, + A.editionable +UNION ALL ( + SELECT + B.con_id "ConId", + 'SYS' "Owner", + 'DIRECTORY' "ObjectType", + B.editionable "Editionable", + count(1) "Count" + FROM cdb_objects B + WHERE B.owner = 'SYS' + AND B.object_type = 'DIRECTORY' + AND B.object_name NOT LIKE 'BIN$%' + GROUP BY + B.con_id, + B.owner, + B.object_type, + B.editionable +) +UNION ALL ( + SELECT + C.con_id "ConId", + C.owner "Owner", + C.object_type "ObjectType", + C.editionable "Editionable", + count(1) "Count" + FROM cdb_objects C + WHERE C.owner NOT LIKE '%SYS' + AND C.owner <> 'PUBLIC' + AND C.object_type = 'SYNONYM' + AND C.object_name NOT LIKE 'BIN$%' + GROUP BY + C.con_id, + C.owner, + C.editionable, + C.object_type +) diff --git a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql b/dumper/app/src/main/resources/oracle-stats/native/db-objects-synonym-public.sql similarity index 51% rename from dumper/app/src/main/resources/oracle-stats/native/db-objects.sql rename to dumper/app/src/main/resources/oracle-stats/native/db-objects-synonym-public.sql index 12642df6f..7f1226ba1 100644 --- a/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql +++ b/dumper/app/src/main/resources/oracle-stats/native/db-objects-synonym-public.sql @@ -12,40 +12,42 @@ -- 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. + +-- The version of db-objects that gets SYNONYM objects, for which owner is PUBLIC +-- A JOIN is performed to exclude objects which appear in the cdb_synonyms table SELECT - B.con_id, - B.owner, - B.object_type, - B.editionable, - COUNT(1) count + B.con_id "ConId", + B.editionable "Editionable", + -- This looks similar to filtering with WHERE and using count() instead of sum(). + -- + -- It is not similar. DB will see the LIKE inside a WHERE predicate and decide to + -- replace a HASH JOIN with NESTED LOOPS. The JOIN arguments have >10k rows each, + -- so performance-wise the nested loop would be terrible. + sum( + CASE WHEN B.object_name LIKE '/%' THEN 0 + WHEN B.object_name LIKE 'BIN$%' THEN 0 + ELSE 1 END + ) "Count" FROM ( SELECT A.con_id, - A.owner, - A.object_type, A.editionable, - A.object_name + A.object_name, + A.owner FROM cdb_objects A - WHERE ((A.owner = 'SYS' AND A.object_type = 'DIRECTORY') OR A.owner NOT LIKE '%SYS') - AND ( - A.object_type <> 'SYNONYM' - OR A.owner <> 'PUBLIC' - OR A.object_name NOT LIKE '/%' - ) - AND A.object_name NOT LIKE 'BIN$%' + WHERE A.object_type = 'SYNONYM' + AND A.owner = 'PUBLIC' ) B -LEFT OUTER JOIN ( +LEFT JOIN ( SELECT - C.owner, C.synonym_name, C.con_id, C.table_owner FROM cdb_synonyms C WHERE C.owner = 'PUBLIC' AND C.table_owner IS NOT NULL -) D ON B.object_type = 'SYNONYM' - AND B.owner = D.owner - AND B.object_name = D.synonym_name +) D ON B.object_name = D.synonym_name AND B.con_id = D.con_id WHERE D.table_owner IS NULL -GROUP BY B.con_id, B.owner, B.editionable , B.object_type + AND B.owner = 'PUBLIC' +GROUP BY B.con_id, B.editionable diff --git a/dumper/app/src/main/resources/oracle-stats/native/db-objects-sys-directory.sql b/dumper/app/src/main/resources/oracle-stats/native/db-objects-sys-directory.sql deleted file mode 100644 index 7b7b382ea..000000000 --- a/dumper/app/src/main/resources/oracle-stats/native/db-objects-sys-directory.sql +++ /dev/null @@ -1,21 +0,0 @@ --- Copyright 2022-2024 Google LLC --- Copyright 2013-2021 CompilerWorks --- --- Licensed 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. -SELECT - A.con_id "ConId", - A.editionable "Editionable", - count(1) "Count" -FROM cdb_objects A -WHERE A.owner = 'SYS' AND A.object_type = 'DIRECTORY' -GROUP BY A.con_id, A.editionable From 57c2e18144567862aae7b9ce8b5b52bbbdff4d7f Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Miko=C5=82aj=20So=C5=82tan?= Date: Fri, 14 Jun 2024 09:56:35 +0000 Subject: [PATCH 13/16] fix sql names --- .../dumper/connector/oracle/StatsTaskListGenerator.java | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java b/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java index ee0fa57dd..c28f4946a 100644 --- a/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java +++ b/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java @@ -39,8 +39,8 @@ ImmutableList> createTasks(ConnectorArguments arguments) throws IOExcept ImmutableList.of( OracleStatsQuery.create("db-features", NATIVE), OracleStatsQuery.create("db-instances", NATIVE), - OracleStatsQuery.create("db-objects-sys-directory", NATIVE), - OracleStatsQuery.create("db-objects", NATIVE), + OracleStatsQuery.create("db-objects-no-join", NATIVE), + OracleStatsQuery.create("db-objects-synonym-public", NATIVE), OracleStatsQuery.create("pdbs-info", NATIVE), OracleStatsQuery.create("app-schemas-pdbs", NATIVE), OracleStatsQuery.create("app-schemas-summary", NATIVE), From 3a63e7ae13e191f0011cc5172ca402760e43bab0 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Miko=C5=82aj=20So=C5=82tan?= Date: Fri, 14 Jun 2024 10:05:31 +0000 Subject: [PATCH 14/16] move query comments from SQL to Java To avoid spotless failure, file-level SQL comments must be removed. Remove one comment, move the other to Java code. --- .../dumper/connector/oracle/StatsTaskListGenerator.java | 2 ++ .../main/resources/oracle-stats/native/db-objects-no-join.sql | 4 ---- .../oracle-stats/native/db-objects-synonym-public.sql | 3 --- 3 files changed, 2 insertions(+), 7 deletions(-) diff --git a/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java b/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java index c28f4946a..2b7b445f6 100644 --- a/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java +++ b/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java @@ -40,6 +40,8 @@ ImmutableList> createTasks(ConnectorArguments arguments) throws IOExcept OracleStatsQuery.create("db-features", NATIVE), OracleStatsQuery.create("db-instances", NATIVE), OracleStatsQuery.create("db-objects-no-join", NATIVE), + // The version of db-objects that gets SYNONYM objects, for which owner is PUBLIC. + // A JOIN is performed to exclude objects which appear in the cdb_synonyms table. OracleStatsQuery.create("db-objects-synonym-public", NATIVE), OracleStatsQuery.create("pdbs-info", NATIVE), OracleStatsQuery.create("app-schemas-pdbs", NATIVE), diff --git a/dumper/app/src/main/resources/oracle-stats/native/db-objects-no-join.sql b/dumper/app/src/main/resources/oracle-stats/native/db-objects-no-join.sql index f6b32b7e3..16f9be8af 100644 --- a/dumper/app/src/main/resources/oracle-stats/native/db-objects-no-join.sql +++ b/dumper/app/src/main/resources/oracle-stats/native/db-objects-no-join.sql @@ -12,10 +12,6 @@ -- 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. - --- This deals with the simpler case of db-objects. --- The other case is SYNONYM objects with PUBLIC owner, which require a JOIN --- with a _synonyms table. SELECT A.con_id "ConId", A.owner "Owner", diff --git a/dumper/app/src/main/resources/oracle-stats/native/db-objects-synonym-public.sql b/dumper/app/src/main/resources/oracle-stats/native/db-objects-synonym-public.sql index 7f1226ba1..e23f2d498 100644 --- a/dumper/app/src/main/resources/oracle-stats/native/db-objects-synonym-public.sql +++ b/dumper/app/src/main/resources/oracle-stats/native/db-objects-synonym-public.sql @@ -12,9 +12,6 @@ -- 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. - --- The version of db-objects that gets SYNONYM objects, for which owner is PUBLIC --- A JOIN is performed to exclude objects which appear in the cdb_synonyms table SELECT B.con_id "ConId", B.editionable "Editionable", From 9928155b960993b0bf07c1a6a9c07226400c6b1a Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Miko=C5=82aj=20So=C5=82tan?= Date: Fri, 14 Jun 2024 13:09:32 +0000 Subject: [PATCH 15/16] simplify an sql filename --- .../dumper/connector/oracle/StatsTaskListGenerator.java | 2 +- .../native/{db-objects-no-join.sql => db-objects.sql} | 0 2 files changed, 1 insertion(+), 1 deletion(-) rename dumper/app/src/main/resources/oracle-stats/native/{db-objects-no-join.sql => db-objects.sql} (100%) diff --git a/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java b/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java index 2b7b445f6..846a8fa90 100644 --- a/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java +++ b/dumper/app/src/main/java/com/google/edwmigration/dumper/application/dumper/connector/oracle/StatsTaskListGenerator.java @@ -39,7 +39,7 @@ ImmutableList> createTasks(ConnectorArguments arguments) throws IOExcept ImmutableList.of( OracleStatsQuery.create("db-features", NATIVE), OracleStatsQuery.create("db-instances", NATIVE), - OracleStatsQuery.create("db-objects-no-join", NATIVE), + OracleStatsQuery.create("db-objects", NATIVE), // The version of db-objects that gets SYNONYM objects, for which owner is PUBLIC. // A JOIN is performed to exclude objects which appear in the cdb_synonyms table. OracleStatsQuery.create("db-objects-synonym-public", NATIVE), diff --git a/dumper/app/src/main/resources/oracle-stats/native/db-objects-no-join.sql b/dumper/app/src/main/resources/oracle-stats/native/db-objects.sql similarity index 100% rename from dumper/app/src/main/resources/oracle-stats/native/db-objects-no-join.sql rename to dumper/app/src/main/resources/oracle-stats/native/db-objects.sql From f0ca7924306244a12e3786e6bede7e51fd56d933 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Miko=C5=82aj=20So=C5=82tan?= Date: Mon, 17 Jun 2024 12:32:00 +0000 Subject: [PATCH 16/16] add ObjectType and Owner columns in -synonym-public --- .../resources/oracle-stats/native/db-objects-synonym-public.sql | 2 ++ 1 file changed, 2 insertions(+) diff --git a/dumper/app/src/main/resources/oracle-stats/native/db-objects-synonym-public.sql b/dumper/app/src/main/resources/oracle-stats/native/db-objects-synonym-public.sql index e23f2d498..48b7c1250 100644 --- a/dumper/app/src/main/resources/oracle-stats/native/db-objects-synonym-public.sql +++ b/dumper/app/src/main/resources/oracle-stats/native/db-objects-synonym-public.sql @@ -14,6 +14,8 @@ -- limitations under the License. SELECT B.con_id "ConId", + 'PUBLIC' "Owner", + 'SYNONYM' "ObjectType", B.editionable "Editionable", -- This looks similar to filtering with WHERE and using count() instead of sum(). --