Skip to content

Commit a560ffd

Browse files
authored
[b/368572924] Fix: missing data of public synonym objects (#558)
1 parent e6a7792 commit a560ffd

File tree

2 files changed

+37
-71
lines changed

2 files changed

+37
-71
lines changed

dumper/app/src/main/resources/oracle-stats/cdb/native/db-objects-synonym-public.sql

Lines changed: 20 additions & 38 deletions
Original file line numberDiff line numberDiff line change
@@ -13,44 +13,26 @@
1313
-- See the License for the specific language governing permissions and
1414
-- limitations under the License.
1515
SELECT
16-
B.con_id "ConId",
16+
A.con_id "ConId",
1717
'PUBLIC' "Owner",
1818
'SYNONYM' "ObjectType",
19-
B.editionable "Editionable",
20-
B.object_name "ObjectName",
21-
-- This looks similar to filtering with WHERE and using count() instead of sum().
22-
--
23-
-- It is not similar. DB will see the LIKE inside a WHERE predicate and decide to
24-
-- replace a HASH JOIN with NESTED LOOPS. The JOIN arguments have >10k rows each,
25-
-- so performance-wise the nested loop would be terrible.
26-
sum(
27-
CASE WHEN B.object_name LIKE '/%' THEN 0
28-
WHEN B.object_name LIKE 'BIN$%' THEN 0
29-
ELSE 1 END
30-
) "Count"
31-
FROM (
32-
SELECT
33-
A.con_id,
34-
A.editionable,
35-
A.object_name,
36-
A.owner
37-
FROM cdb_objects A
38-
WHERE A.object_type = 'SYNONYM'
39-
AND A.owner = 'PUBLIC'
40-
) B
41-
LEFT JOIN (
42-
SELECT
43-
C.synonym_name,
44-
C.con_id,
45-
C.table_owner
46-
FROM cdb_synonyms C
47-
WHERE C.owner = 'PUBLIC'
48-
AND C.table_owner IS NOT NULL
49-
) D ON B.object_name = D.synonym_name
50-
AND B.con_id = D.con_id
51-
WHERE D.table_owner IS NULL
52-
AND B.owner = 'PUBLIC'
19+
A.editionable "Editionable",
20+
A.object_name "ObjectName",
21+
-- "Count" is kept for backwards compatibility
22+
1 "Count",
23+
C.table_owner "TableOwner"
24+
FROM cdb_objects A
25+
LEFT OUTER JOIN cdb_synonyms C
26+
ON A.owner = C.owner
27+
AND C.table_owner IS NOT NULL
28+
AND A.object_name = C.synonym_name
29+
AND A.con_id = C.con_id
30+
WHERE A.object_type = 'SYNONYM'
31+
AND A.object_name NOT LIKE '/%'
32+
AND A.object_name NOT LIKE 'BIN$%'
33+
AND A.owner = 'PUBLIC'
5334
GROUP BY
54-
B.con_id,
55-
B.editionable,
56-
B.object_name
35+
A.con_id,
36+
A.editionable,
37+
A.object_name,
38+
C.table_owner

dumper/app/src/main/resources/oracle-stats/dba/native/db-objects-synonym-public.sql

Lines changed: 17 additions & 33 deletions
Original file line numberDiff line numberDiff line change
@@ -16,37 +16,21 @@ SELECT
1616
NULL "ConId",
1717
'PUBLIC' "Owner",
1818
'SYNONYM' "ObjectType",
19-
B.editionable "Editionable",
20-
B.object_name "ObjectName",
21-
-- This looks similar to filtering with WHERE and using count() instead of sum().
22-
--
23-
-- It is not similar. DB will see the LIKE inside a WHERE predicate and decide to
24-
-- replace a HASH JOIN with NESTED LOOPS. The JOIN arguments have >10k rows each,
25-
-- so performance-wise the nested loop would be terrible.
26-
sum(
27-
CASE WHEN B.object_name LIKE '/%' THEN 0
28-
WHEN B.object_name LIKE 'BIN$%' THEN 0
29-
ELSE 1 END
30-
) "Count"
31-
FROM (
32-
SELECT
33-
A.editionable,
34-
A.object_name,
35-
A.owner
36-
FROM dba_objects A
37-
WHERE A.object_type = 'SYNONYM'
38-
AND A.owner = 'PUBLIC'
39-
) B
40-
LEFT JOIN (
41-
SELECT
42-
C.synonym_name,
43-
C.table_owner
44-
FROM dba_synonyms C
45-
WHERE C.owner = 'PUBLIC'
46-
AND C.table_owner IS NOT NULL
47-
) D ON B.object_name = D.synonym_name
48-
WHERE D.table_owner IS NULL
49-
AND B.owner = 'PUBLIC'
19+
A.editionable "Editionable",
20+
A.object_name "ObjectName",
21+
-- "Count" is kept for backwards compatibility
22+
1 "Count",
23+
C.table_owner "TableOwner"
24+
FROM dba_objects A
25+
LEFT OUTER JOIN dba_synonyms C
26+
ON A.owner = C.owner
27+
AND C.table_owner IS NOT NULL
28+
AND A.object_name = C.synonym_name
29+
WHERE A.object_type = 'SYNONYM'
30+
AND A.object_name NOT LIKE '/%'
31+
AND A.object_name NOT LIKE 'BIN$%'
32+
AND A.owner = 'PUBLIC'
5033
GROUP BY
51-
B.editionable,
52-
B.object_name
34+
A.editionable,
35+
A.object_name,
36+
C.table_owner

0 commit comments

Comments
 (0)