Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

[b/341297017] Add used-space-details, db-objects SQLs #432

Merged
merged 16 commits into from
Jun 17, 2024
Merged
Original file line number Diff line number Diff line change
Expand Up @@ -39,9 +39,14 @@ ImmutableList<Task<?>> createTasks(ConnectorArguments arguments) throws IOExcept
ImmutableList.of(
OracleStatsQuery.create("db-features", NATIVE),
OracleStatsQuery.create("db-instances", 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),
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
);
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,52 @@
-- 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
misolt marked this conversation as resolved.
Show resolved Hide resolved
B.con_id "ConId",
'PUBLIC' "Owner",
'SYNONYM' "ObjectType",
B.editionable "Editionable",
misolt marked this conversation as resolved.
Show resolved Hide resolved
-- 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
misolt marked this conversation as resolved.
Show resolved Hide resolved
) "Count"
FROM (
SELECT
A.con_id,
A.editionable,
A.object_name,
A.owner
FROM cdb_objects A
WHERE A.object_type = 'SYNONYM'
AND A.owner = 'PUBLIC'
) B
LEFT JOIN (
SELECT
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_name = D.synonym_name
AND B.con_id = D.con_id
WHERE D.table_owner IS NULL
AND B.owner = 'PUBLIC'
GROUP BY B.con_id, B.editionable
Original file line number Diff line number Diff line change
@@ -0,0 +1,63 @@
-- 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.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'
misolt marked this conversation as resolved.
Show resolved Hide resolved
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
)
Original file line number Diff line number Diff line change
@@ -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