@@ -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