You are viewing a plain text version of this content. The canonical link for it is here.
Posted to issues@hive.apache.org by "ASF GitHub Bot (Jira)" <ji...@apache.org> on 2022/10/30 09:47:00 UTC

[jira] [Work logged] (HIVE-26649) Hive metabase performance issues due to slow queries

     [ https://issues.apache.org/jira/browse/HIVE-26649?focusedWorklogId=821772&page=com.atlassian.jira.plugin.system.issuetabpanels:worklog-tabpanel#worklog-821772 ]

ASF GitHub Bot logged work on HIVE-26649:
-----------------------------------------

                Author: ASF GitHub Bot
            Created on: 30/Oct/22 09:46
            Start Date: 30/Oct/22 09:46
    Worklog Time Spent: 10m 
      Work Description: SelfImpr001 opened a new pull request, #3714:
URL: https://github.com/apache/hive/pull/3714

   ### What changes were proposed in this pull request?
   When the Hive metabase uses Mysql, during the peak period of Hive statement query, the metastore initiates a large number of DirectSQL, which will cause performance problems in the metabase. The fundamental reason is that some DirectSQL performance problems cause a large number of slow queries at the DB level. This PR is mainly for optimization. Slow query problem at the metabase level
   
   ### Why are the changes needed?
   For example for the following Hive query:
   
   `
   select * from imd_fcac_safe.fcac_dw_loan_details where ds='2021-10-10' and sysid='MCFCM'
   `
   
   where ds and sysid are the primary and secondary partitions of the imd_fcac_safe.fcac_dw_loan_details table, respectively
   
   The Hive statement will generate the DirectSQL query as follows:
   
   `
   explain select PARTITIONS.PART_ID from PARTITIONS  inner join TBLS on PARTITIONS.TBL_ID = TBLS.TBL_ID     
   and TBLS.TBL_NAME = 'fcac_dw_loan_details'   inner join DBS on TBLS.DB_ID = DBS.DB_ID      and DBS.NAME = 'imd_fcac_safe' 
   inner join PARTITION_KEY_VALS FILTER0 on FILTER0.PART_ID = PARTITIONS.PART_ID and FILTER0.INTEGER_IDX = 0 
   inner join PARTITION_KEY_VALS FILTER1 on FILTER1.PART_ID = PARTITIONS.PART_ID and FILTER1.INTEGER_IDX = 1 
   where ( ((FILTER0.PART_KEY_VAL = '2021-10-10') and (FILTER1.PART_KEY_VAL = 'MCFCM')) )
   `
   ![image](https://user-images.githubusercontent.com/11420267/198872058-609b8a19-c3ba-4220-a7a8-138150d391fc.png)
   
   Problems with this statement
   There is no TBL_ID field in the PARTITION_KEY_VALS table, which will cause the partition of the same name of the unrelated table to be described when performing an associated query; there is no index column in the PARTITION_KEY_VAL table, so it cannot be accelerated by the index.
   
   
   ### Does this PR introduce _any_ user-facing change?
   No
   
   
   ### How was this patch tested?
   After compiling and packaging, execute the relevant partition filtering statement through the client. After repairing, the corresponding query corresponds to the DirectSQL execution plan as follows:
   
   ![image](https://user-images.githubusercontent.com/11420267/198872182-e4e69d49-75b1-45b8-9089-8ee4e1b8c27e.png)
   
   It can be seen that the amount of query data for partitioned tables has decreased. During the peak period of Hive tasks, the CPU load performance problem at the DB level has decreased.




Issue Time Tracking
-------------------

            Worklog Id:     (was: 821772)
    Remaining Estimate: 95h 50m  (was: 96h)
            Time Spent: 10m

> Hive metabase performance issues due to slow queries
> ----------------------------------------------------
>
>                 Key: HIVE-26649
>                 URL: https://issues.apache.org/jira/browse/HIVE-26649
>             Project: Hive
>          Issue Type: Improvement
>          Components: Metastore
>    Affects Versions: 2.3.3
>         Environment: metastore db :mysql 5.X
> hive:2.3.3
>            Reporter: yihangqiao
>            Assignee: yihangqiao
>            Priority: Major
>              Labels: metastore, patch, performance
>         Attachments: image-2022-10-19-14-42-33-073.png
>
>   Original Estimate: 96h
>          Time Spent: 10m
>  Remaining Estimate: 95h 50m
>
> When the Hive metabase uses Mysql, during the peak period of Hive statement query, the metastore initiates a large amount of DirectSQL, which will cause performance problems in the metabase. The fundamental reason is that some DirectSQL performance problems cause a large number of slow queries at the DB level.
> For example for the following Hive query:
> {code:java}
> select * from imd_fcac_safe.fcac_dw_loan_details where ds='2021-10-10' and sysid='MCFCM' {code}
> where ds and sysid are the primary and secondary partitions of the imd_fcac_safe.fcac_dw_loan_details table, respectively
>  
> The Hive statement will generate the DirectSQL query as follows:
> {code:java}
> explain select PARTITIONS.PART_ID from PARTITIONS  inner join TBLS on PARTITIONS.TBL_ID = TBLS.TBL_ID     and TBLS.TBL_NAME = 'fcac_dw_loan_details'   inner join DBS on TBLS.DB_ID = DBS.DB_ID      and DBS.NAME = 'imd_fcac_safe' inner join PARTITION_KEY_VALS FILTER0 on FILTER0.PART_ID = PARTITIONS.PART_ID and FILTER0.INTEGER_IDX = 0 inner join PARTITION_KEY_VALS FILTER1 on FILTER1.PART_ID = PARTITIONS.PART_ID and FILTER1.INTEGER_IDX = 1 where ( ((FILTER0.PART_KEY_VAL = '2021-10-10') and (FILTER1.PART_KEY_VAL = 'MCFCM')) ) {code}
> !image-2022-10-19-14-42-33-073.png!
>  
> Problems with this statement
> There is no TBL_ID field in the PARTITION_KEY_VALS table, which will cause the partition of the same name of the unrelated table to be described when performing an associated query; there is no index column in the PARTITION_KEY_VAL table, so it cannot be accelerated by the index.



--
This message was sent by Atlassian Jira
(v8.20.10#820010)