Skip to content

Commit 2e65ecc

Browse files
committed
Fixed empty results for ACID tables. Added table type counts total and by db.
1 parent 0849615 commit 2e65ecc

File tree

8 files changed

+322
-217
lines changed

8 files changed

+322
-217
lines changed

pom.xml

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -22,7 +22,7 @@
2222

2323
<groupId>com.cloudera.utils.hive</groupId>
2424
<artifactId>hive-sre</artifactId>
25-
<version>2.4.0.17.0-SNAPSHOT</version>
25+
<version>2.4.0.18.0-SNAPSHOT</version>
2626

2727
<name>hive-sre</name>
2828

src/main/resources/MYSQL/hive_sre_queries.yaml

Lines changed: 68 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -343,3 +343,71 @@ ORDER BY
343343
initial: "%"
344344
sqlType: 12
345345
location: 1
346+
table_catagory_count:
347+
statement: "
348+
WITH WPARAMS AS (
349+
SELECT
350+
SP.TBL_ID,
351+
SP.PARAM_KEY,
352+
SP.PARAM_VALUE
353+
FROM TABLE_PARAMS SP
354+
WHERE LOWER(SP.PARAM_KEY) = 'transactional'
355+
OR LOWER(SP.PARAM_KEY) = 'external'
356+
),
357+
WCAT AS (
358+
SELECT
359+
DB.NAME AS DB_NAME
360+
, TBL.TBL_NAME
361+
, CASE CONCAT(LOWER(TBL_TYPE), LOWER(P.PARAM_KEY), LOWER(P.PARAM_VALUE))
362+
WHEN 'external_tableexternaltrue' THEN 'EXTERNAL'
363+
WHEN 'managed_tabletransactionaltrue' THEN 'ACID'
364+
ELSE 'LEGACY_MANAGED'
365+
END AS TABLE_TYPE
366+
FROM DBS DB
367+
JOIN
368+
TBLS TBL ON
369+
DB.DB_ID = TBL.DB_ID
370+
LEFT OUTER JOIN WPARAMS P
371+
ON TBL.TBL_ID = P.TBL_ID
372+
)
373+
SELECT
374+
TABLE_TYPE
375+
, COUNT(1) AS COUNT
376+
FROM WCAT
377+
GROUP BY TABLE_TYPE
378+
"
379+
table_catagory_count_by_db:
380+
statement: "
381+
WITH WPARAMS AS (
382+
SELECT
383+
SP.TBL_ID,
384+
SP.PARAM_KEY,
385+
SP.PARAM_VALUE
386+
FROM TABLE_PARAMS SP
387+
WHERE LOWER(SP.PARAM_KEY) = 'transactional'
388+
OR LOWER(SP.PARAM_KEY) = 'external'
389+
),
390+
WCAT AS (
391+
SELECT
392+
DB.NAME AS DB_NAME
393+
, TBL.TBL_NAME
394+
, CASE CONCAT(LOWER(TBL_TYPE), LOWER(P.PARAM_KEY), LOWER(P.PARAM_VALUE))
395+
WHEN 'external_tableexternaltrue' THEN 'EXTERNAL'
396+
WHEN 'managed_tabletransactionaltrue' THEN 'ACID'
397+
ELSE 'LEGACY_MANAGED'
398+
END AS TABLE_TYPE
399+
FROM DBS DB
400+
JOIN
401+
TBLS TBL ON
402+
DB.DB_ID = TBL.DB_ID
403+
LEFT OUTER JOIN WPARAMS P
404+
ON TBL.TBL_ID = P.TBL_ID
405+
)
406+
SELECT DISTINCT
407+
DB_NAME,
408+
TABLE_TYPE,
409+
COUNT(1) AS COUNT
410+
FROM WCAT
411+
GROUP BY DB_NAME, TABLE_TYPE
412+
ORDER BY DB_NAME, TABLE_TYPE
413+
"

src/main/resources/MYSQL/hive_u3_queries.yaml

Lines changed: 40 additions & 72 deletions
Original file line numberDiff line numberDiff line change
@@ -347,78 +347,46 @@ WHERE t.tbl_serde_slib IN
347347
"
348348
managed_2_acid:
349349
statement: "
350-
SELECT DISTINCT
351-
db_name,
352-
tbl_name,
353-
tbl_type,
354-
tbl_location
355-
FROM
356-
(SELECT
357-
D.NAME AS DB_NAME,
358-
D.DB_LOCATION_URI AS DB_DEFAULT_LOC,
359-
D.OWNER_NAME AS DB_OWNER,
360-
T.TBL_ID AS TBL_ID,
361-
T.TBL_NAME AS TBL_NAME,
362-
T.OWNER AS TBL_OWNER,
363-
T.TBL_TYPE AS TBL_TYPE,
364-
S.LOCATION AS TBL_LOCATION,
365-
PARAMS.PARAM_KEY AS TBL_PARAM_KEY,
366-
PARAMS.PARAM_VALUE AS TBL_PARAM_VALUE
367-
FROM
368-
DBS D
369-
INNER JOIN
370-
TBLS T
371-
ON
372-
D.DB_ID = T.DB_ID
373-
LEFT OUTER JOIN
374-
SDS S
375-
ON
376-
T.SD_ID = S.SD_ID
377-
LEFT OUTER JOIN
378-
TABLE_PARAMS PARAMS
379-
ON
380-
T.TBL_ID = PARAMS.TBL_ID
381-
WHERE
382-
D.NAME LIKE ?
383-
AND T.TBL_TYPE = 'MANAGED_TABLE') b
384-
WHERE
385-
NOT EXISTS
386-
(SELECT
387-
1
388-
FROM
389-
(SELECT
390-
D.NAME AS DB_NAME,
391-
D.DB_LOCATION_URI AS DB_DEFAULT_LOC,
392-
D.OWNER_NAME AS DB_OWNER,
393-
T.TBL_ID AS TBL_ID,
394-
T.TBL_NAME AS TBL_NAME,
395-
T.OWNER AS TBL_OWNER,
396-
T.TBL_TYPE AS TBL_TYPE,
397-
S.LOCATION AS TBL_LOCATION,
398-
PARAMS.PARAM_KEY AS TBL_PARAM_KEY,
399-
PARAMS.PARAM_VALUE AS TBL_PARAM_VALUE
400-
FROM
401-
DBS D
402-
INNER JOIN
403-
TBLS T
404-
ON
405-
D.DB_ID = T.DB_ID
406-
LEFT OUTER JOIN
407-
SDS S
408-
ON
409-
T.SD_ID = S.SD_ID
410-
LEFT OUTER JOIN
411-
TABLE_PARAMS PARAMS
412-
ON
413-
T.TBL_ID = PARAMS.TBL_ID
414-
WHERE
415-
D.NAME LIKE ?
416-
AND T.TBL_TYPE = 'MANAGED_TABLE') ma
417-
WHERE
418-
ma.TBL_PARAM_KEY = 'transactional'
419-
AND LOWER(ma.TBL_PARAM_VALUE) = 'true'
420-
AND b.db_name = ma.db_name
421-
AND b.tbl_name = ma.tbl_name)
350+
WITH
351+
WPARAMS AS (
352+
SELECT
353+
SP.TBL_ID
354+
, SP.PARAM_KEY
355+
, SP.PARAM_VALUE
356+
FROM TABLE_PARAMS SP
357+
WHERE
358+
LOWER(SP.PARAM_KEY) = 'transactional'
359+
OR LOWER(SP.PARAM_KEY) = 'external'
360+
),
361+
WCAT AS (
362+
SELECT
363+
DB.NAME AS DB_NAME
364+
, TBL.TBL_NAME
365+
, S.LOCATION AS TBL_LOCATION
366+
, CASE CONCAT(LOWER(TBL_TYPE), LOWER(P.PARAM_KEY), LOWER(P.PARAM_VALUE))
367+
WHEN 'external_tableexternaltrue' THEN 'EXTERNAL'
368+
WHEN 'managed_tabletransactionaltrue' THEN 'ACID'
369+
ELSE 'LEGACY_MANAGED'
370+
END AS TBL_TYPE
371+
FROM DBS DB
372+
JOIN
373+
TBLS TBL ON
374+
DB.DB_ID = TBL.DB_ID
375+
INNER JOIN SDS S ON TBL.SD_ID = S.SD_ID
376+
LEFT OUTER JOIN WPARAMS P
377+
ON TBL.TBL_ID = P.TBL_ID
378+
WHERE DB.NAME LIKE ?
379+
)
380+
SELECT DISTINCT
381+
DB_NAME
382+
, TBL_NAME
383+
, TBL_TYPE
384+
, TBL_LOCATION
385+
FROM WCAT
386+
WHERE
387+
TBL_TYPE = 'LEGACY_MANAGED'
388+
ORDER BY
389+
DB_NAME, TBL_TYPE
422390
"
423391
parameters:
424392
dbs:

src/main/resources/ORACLE/hive_sre_queries.yaml

Lines changed: 68 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -353,3 +353,71 @@ WHERE
353353
initial: "%"
354354
sqlType: 12
355355
location: 1
356+
table_catagory_count:
357+
statement: "
358+
WITH WPARAMS AS (
359+
SELECT
360+
SP.TBL_ID,
361+
SP.PARAM_KEY,
362+
SP.PARAM_VALUE
363+
FROM TABLE_PARAMS SP
364+
WHERE LOWER(SP.PARAM_KEY) = 'transactional'
365+
OR LOWER(SP.PARAM_KEY) = 'external'
366+
),
367+
WCAT AS (
368+
SELECT
369+
DB.NAME AS DB_NAME
370+
, TBL.TBL_NAME
371+
, CASE CONCAT(LOWER(TBL_TYPE), LOWER(P.PARAM_KEY), LOWER(P.PARAM_VALUE))
372+
WHEN 'external_tableexternaltrue' THEN 'EXTERNAL'
373+
WHEN 'managed_tabletransactionaltrue' THEN 'ACID'
374+
ELSE 'LEGACY_MANAGED'
375+
END AS TABLE_TYPE
376+
FROM DBS DB
377+
JOIN
378+
TBLS TBL ON
379+
DB.DB_ID = TBL.DB_ID
380+
LEFT OUTER JOIN WPARAMS P
381+
ON TBL.TBL_ID = P.TBL_ID
382+
)
383+
SELECT
384+
TABLE_TYPE
385+
, COUNT(1) AS COUNT
386+
FROM WCAT
387+
GROUP BY TABLE_TYPE
388+
"
389+
table_catagory_count_by_db:
390+
statement: "
391+
WITH WPARAMS AS (
392+
SELECT
393+
SP.TBL_ID,
394+
SP.PARAM_KEY,
395+
SP.PARAM_VALUE
396+
FROM TABLE_PARAMS SP
397+
WHERE LOWER(SP.PARAM_KEY) = 'transactional'
398+
OR LOWER(SP.PARAM_KEY) = 'external'
399+
),
400+
WCAT AS (
401+
SELECT
402+
DB.NAME AS DB_NAME
403+
, TBL.TBL_NAME
404+
, CASE CONCAT(LOWER(TBL_TYPE), LOWER(P.PARAM_KEY), LOWER(P.PARAM_VALUE))
405+
WHEN 'external_tableexternaltrue' THEN 'EXTERNAL'
406+
WHEN 'managed_tabletransactionaltrue' THEN 'ACID'
407+
ELSE 'LEGACY_MANAGED'
408+
END AS TABLE_TYPE
409+
FROM DBS DB
410+
JOIN
411+
TBLS TBL ON
412+
DB.DB_ID = TBL.DB_ID
413+
LEFT OUTER JOIN WPARAMS P
414+
ON TBL.TBL_ID = P.TBL_ID
415+
)
416+
SELECT DISTINCT
417+
DB_NAME,
418+
TABLE_TYPE,
419+
COUNT(1) AS COUNT
420+
FROM WCAT
421+
GROUP BY DB_NAME, TABLE_TYPE
422+
ORDER BY DB_NAME, TABLE_TYPE
423+
"

src/main/resources/ORACLE/hive_u3_queries.yaml

Lines changed: 40 additions & 72 deletions
Original file line numberDiff line numberDiff line change
@@ -347,78 +347,46 @@ WHERE t.tbl_serde_slib IN
347347
"
348348
managed_2_acid:
349349
statement: "
350-
SELECT DISTINCT
351-
db_name,
352-
tbl_name,
353-
tbl_type,
354-
tbl_location
355-
FROM
356-
(SELECT
357-
D.NAME AS DB_NAME,
358-
D.DB_LOCATION_URI AS DB_DEFAULT_LOC,
359-
D.OWNER_NAME AS DB_OWNER,
360-
T.TBL_ID AS TBL_ID,
361-
T.TBL_NAME AS TBL_NAME,
362-
T.OWNER AS TBL_OWNER,
363-
T.TBL_TYPE AS TBL_TYPE,
364-
S.LOCATION AS TBL_LOCATION,
365-
PARAMS.PARAM_KEY AS TBL_PARAM_KEY,
366-
PARAMS.PARAM_VALUE AS TBL_PARAM_VALUE
367-
FROM
368-
DBS D
369-
INNER JOIN
370-
TBLS T
371-
ON
372-
D.DB_ID = T.DB_ID
373-
LEFT OUTER JOIN
374-
SDS S
375-
ON
376-
T.SD_ID = S.SD_ID
377-
LEFT OUTER JOIN
378-
TABLE_PARAMS PARAMS
379-
ON
380-
T.TBL_ID = PARAMS.TBL_ID
381-
WHERE
382-
D.NAME LIKE ?
383-
AND T.TBL_TYPE = 'MANAGED_TABLE') b
384-
WHERE
385-
NOT EXISTS
386-
(SELECT
387-
1
388-
FROM
389-
(SELECT
390-
D.NAME AS DB_NAME,
391-
D.DB_LOCATION_URI AS DB_DEFAULT_LOC,
392-
D.OWNER_NAME AS DB_OWNER,
393-
T.TBL_ID AS TBL_ID,
394-
T.TBL_NAME AS TBL_NAME,
395-
T.OWNER AS TBL_OWNER,
396-
T.TBL_TYPE AS TBL_TYPE,
397-
S.LOCATION AS TBL_LOCATION,
398-
PARAMS.PARAM_KEY AS TBL_PARAM_KEY,
399-
PARAMS.PARAM_VALUE AS TBL_PARAM_VALUE
400-
FROM
401-
DBS D
402-
INNER JOIN
403-
TBLS T
404-
ON
405-
D.DB_ID = T.DB_ID
406-
LEFT OUTER JOIN
407-
SDS S
408-
ON
409-
T.SD_ID = S.SD_ID
410-
LEFT OUTER JOIN
411-
TABLE_PARAMS PARAMS
412-
ON
413-
T.TBL_ID = PARAMS.TBL_ID
414-
WHERE
415-
D.NAME LIKE ?
416-
AND T.TBL_TYPE = 'MANAGED_TABLE') ma
417-
WHERE
418-
ma.TBL_PARAM_KEY = 'transactional'
419-
AND LOWER(to_char(ma.TBL_PARAM_VALUE)) = 'true'
420-
AND b.db_name = ma.db_name
421-
AND b.tbl_name = ma.tbl_name)
350+
WITH
351+
WPARAMS AS (
352+
SELECT
353+
SP.TBL_ID
354+
, SP.PARAM_KEY
355+
, SP.PARAM_VALUE
356+
FROM TABLE_PARAMS SP
357+
WHERE
358+
LOWER(SP.PARAM_KEY) = 'transactional'
359+
OR LOWER(SP.PARAM_KEY) = 'external'
360+
),
361+
WCAT AS (
362+
SELECT
363+
DB.NAME AS DB_NAME
364+
, TBL.TBL_NAME
365+
, S.LOCATION AS TBL_LOCATION
366+
, CASE CONCAT(LOWER(TBL_TYPE), LOWER(P.PARAM_KEY), LOWER(P.PARAM_VALUE))
367+
WHEN 'external_tableexternaltrue' THEN 'EXTERNAL'
368+
WHEN 'managed_tabletransactionaltrue' THEN 'ACID'
369+
ELSE 'LEGACY_MANAGED'
370+
END AS TBL_TYPE
371+
FROM DBS DB
372+
JOIN
373+
TBLS TBL ON
374+
DB.DB_ID = TBL.DB_ID
375+
INNER JOIN SDS S ON TBL.SD_ID = S.SD_ID
376+
LEFT OUTER JOIN WPARAMS P
377+
ON TBL.TBL_ID = P.TBL_ID
378+
WHERE DB.NAME LIKE ?
379+
)
380+
SELECT DISTINCT
381+
DB_NAME
382+
, TBL_NAME
383+
, TBL_TYPE
384+
, TBL_LOCATION
385+
FROM WCAT
386+
WHERE
387+
TBL_TYPE = 'LEGACY_MANAGED'
388+
ORDER BY
389+
DB_NAME, TBL_TYPE
422390
"
423391
parameters:
424392
dbs:

0 commit comments

Comments
 (0)