planner: implement "SHOW PLAN FOR <SQL>" for SPM (#60238)

ref pingcap/tidb#60148
This commit is contained in:
Yuanjia Zhang
2025-03-26 12:45:31 +08:00
committed by GitHub
parent 1f0f3560e1
commit 9a024100b7
10 changed files with 284 additions and 4 deletions

View File

@ -4,6 +4,7 @@ go_library(
name = "bindinfo",
srcs = [
"binding.go",
"binding_auto.go",
"binding_cache.go",
"binding_handle.go",
"binding_operator.go",
@ -46,6 +47,7 @@ go_test(
name = "bindinfo_test",
timeout = "moderate",
srcs = [
"binding_auto_test.go",
"binding_cache_test.go",
"binding_operator_test.go",
"main_test.go",
@ -54,7 +56,7 @@ go_test(
embed = [":bindinfo"],
flaky = True,
race = "on",
shard_count = 32,
shard_count = 33,
deps = [
"//pkg/parser",
"//pkg/parser/ast",

View File

@ -0,0 +1,152 @@
// Copyright 2025 PingCAP, Inc.
//
// 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.
package bindinfo
import (
"fmt"
"strings"
"github.com/pingcap/errors"
"github.com/pingcap/tidb/pkg/parser"
"github.com/pingcap/tidb/pkg/sessionctx"
"github.com/pingcap/tidb/pkg/util"
"github.com/pingcap/tidb/pkg/util/chunk"
utilparser "github.com/pingcap/tidb/pkg/util/parser"
"go.uber.org/zap"
)
// BindingPlanInfo contains the binding info and its corresponding plan execution info, which is used by
// "SHOW PLAN FOR <SQL>" to help users understand the historical plans for a specific SQL.
type BindingPlanInfo struct {
*Binding
// Info from StmtStats
Plan string
AvgLatency float64
ExecTimes int64
AvgScanRows float64
AvgReturnedRows float64
LatencyPerReturnRow float64
ScanRowsPerReturnRow float64
// Recommendation
Recommend string
Reason string
}
// BindingAuto represents a series of APIs that help manage bindings automatically.
type BindingAuto interface {
// TODO: RecordHistPlansAsBindings records the history plans as bindings for qualified queries.
// ShowPlansForSQL shows historical plans for a specific SQL.
ShowPlansForSQL(currentDB, sqlOrDigest, charset, collation string) ([]*BindingPlanInfo, error)
}
type bindingAuto struct {
sPool util.DestroyableSessionPool
}
func newBindingAuto(sPool util.DestroyableSessionPool) BindingAuto {
return &bindingAuto{
sPool: sPool,
}
}
// ShowPlansForSQL shows historical plans for a specific SQL.
func (ba *bindingAuto) ShowPlansForSQL(currentDB, sqlOrDigest, charset, collation string) ([]*BindingPlanInfo, error) {
// parse and normalize sqlOrDigest
// if the length is 64 and it has no " ", treat it as a digest.
var whereCond string
sqlOrDigest = strings.TrimSpace(sqlOrDigest)
if len(sqlOrDigest) == 64 && !strings.Contains(sqlOrDigest, " ") {
whereCond = "where sql_digest = %?"
} else {
p := parser.New()
stmtNode, err := p.ParseOneStmt(sqlOrDigest, charset, collation)
if err != nil {
return nil, errors.NewNoStackErrorf("failed to normalize the SQL: %v", err)
}
db := utilparser.GetDefaultDB(stmtNode, currentDB)
sqlOrDigest, _ = NormalizeStmtForBinding(stmtNode, db, false)
whereCond = "where original_sql = %?"
}
bindings, err := readBindingsFromStorage(ba.sPool, whereCond, sqlOrDigest)
if err != nil {
return nil, err
}
// read plan info from information_schema.tidb_statements_stats
bindingPlans := make([]*BindingPlanInfo, 0, len(bindings))
for _, binding := range bindings {
pInfo, err := ba.getPlanExecInfo(binding.PlanDigest)
if err != nil {
bindingLogger().Error("get plan execution info failed", zap.String("plan_digest", binding.PlanDigest), zap.Error(err))
continue
}
autoBinding := &BindingPlanInfo{Binding: binding}
if pInfo != nil && pInfo.ExecCount > 0 { // pInfo could be nil when stmt_stats' data is incomplete.
autoBinding.Plan = pInfo.Plan
autoBinding.ExecTimes = pInfo.ExecCount
autoBinding.AvgLatency = float64(pInfo.TotalTime) / float64(pInfo.ExecCount)
autoBinding.AvgScanRows = float64(pInfo.ProcessedKeys) / float64(pInfo.ExecCount)
autoBinding.AvgReturnedRows = float64(pInfo.ResultRows) / float64(pInfo.ExecCount)
if autoBinding.AvgReturnedRows > 0 {
autoBinding.LatencyPerReturnRow = autoBinding.AvgLatency / autoBinding.AvgReturnedRows
autoBinding.ScanRowsPerReturnRow = autoBinding.AvgScanRows / autoBinding.AvgReturnedRows
}
}
bindingPlans = append(bindingPlans, autoBinding)
}
return bindingPlans, nil
}
// getPlanExecInfo gets the plan execution info from information_schema.tidb_statements_stats table.
func (ba *bindingAuto) getPlanExecInfo(planDigest string) (plan *planExecInfo, err error) {
if planDigest == "" {
return nil, nil
}
stmtQuery := fmt.Sprintf(`select cast(sum(result_rows) as signed), cast(sum(exec_count) as signed),
cast(sum(processed_keys) as signed), cast(sum(total_time) as signed), any_value(plan)
from information_schema.cluster_tidb_statements_stats where plan_digest = '%v'`, planDigest)
var rows []chunk.Row
err = callWithSCtx(ba.sPool, false, func(sctx sessionctx.Context) error {
rows, _, err = execRows(sctx, stmtQuery)
return err
})
if err != nil {
return nil, err
}
if len(rows) == 0 || rows[0].IsNull(0) {
// TODO: read data from workload_schema.hist_stmt_stats in this case if it's enabled.
return nil, nil
}
return &planExecInfo{
ResultRows: rows[0].GetInt64(0),
ExecCount: rows[0].GetInt64(1),
ProcessedKeys: rows[0].GetInt64(2),
TotalTime: rows[0].GetInt64(3),
Plan: rows[0].GetString(4),
}, nil
}
// planExecInfo represents the plan info from information_schema.tidb_statements_stats table.
type planExecInfo struct {
Plan string
ResultRows int64
ExecCount int64
ProcessedKeys int64
TotalTime int64
}

View File

@ -0,0 +1,56 @@
// Copyright 2025 PingCAP, Inc.
//
// 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.
package bindinfo_test
import (
"testing"
"github.com/pingcap/tidb/pkg/testkit"
"github.com/stretchr/testify/require"
)
func TestShowPlanForSQLBasic(t *testing.T) {
store := testkit.CreateMockStore(t)
tk := testkit.NewTestKit(t, store)
tk.MustExec("use test")
tk.MustExec(`create table t (a int, b int, c varchar(10), key(a))`)
require.True(t, len(tk.MustQuery(`show plan for "select a from t where b=1"`).Rows()) == 0)
tk.MustExec(`create global binding using select a from t where b=1`)
require.True(t, len(tk.MustQuery(`show plan for "select a from t where b=1"`).Rows()) == 1)
require.True(t, len(tk.MustQuery(`show plan for "SELECT a FROM t WHERE b=1"`).Rows()) == 1)
require.True(t, len(tk.MustQuery(`show plan for "SELECT a FROM t WHERE b= 1"`).Rows()) == 1)
require.True(t, len(tk.MustQuery(`show plan for " SELECT a FROM test.t WHERE b= 1"`).Rows()) == 1)
require.True(t, len(tk.MustQuery(`show plan for "23109784b802bcef5398dd81d3b1c5b79200c257c101a5b9f90758206f3d09ed"`).Rows()) == 1)
require.True(t, len(tk.MustQuery(`show plan for "select a from t where b in (1, 2, 3)"`).Rows()) == 0)
tk.MustExec(`create global binding using select a from t where b in (1, 2, 3)`)
require.True(t, len(tk.MustQuery(`show plan for "select a from t where b in (1, 2, 3)"`).Rows()) == 1)
require.True(t, len(tk.MustQuery(`show plan for "select a from t where b in (1, 2)"`).Rows()) == 1)
require.True(t, len(tk.MustQuery(`show plan for "select a from t where b in (1)"`).Rows()) == 1)
require.True(t, len(tk.MustQuery(`show plan for "SELECT a from t WHere b in (1)"`).Rows()) == 1)
require.True(t, len(tk.MustQuery(`show plan for "select a from t where c = ''"`).Rows()) == 0)
tk.MustExec(`create global binding using select a from t where c = ''`)
require.True(t, len(tk.MustQuery(`show plan for "select a from t where c = ''"`).Rows()) == 1)
require.True(t, len(tk.MustQuery(`show plan for "select a from t where c = '123'"`).Rows()) == 1)
require.True(t, len(tk.MustQuery(`show plan for "select a from t where c = '\"'"`).Rows()) == 1)
require.True(t, len(tk.MustQuery(`show plan for "select a from t where c = ' '"`).Rows()) == 1)
require.True(t, len(tk.MustQuery(`show plan for 'select a from t where c = ""'`).Rows()) == 1)
require.True(t, len(tk.MustQuery(`show plan for 'select a from t where c = "\'"'`).Rows()) == 1)
tk.MustExecToErr("show plan for 'xxx'", "")
tk.MustExecToErr("show plan for 'SELECT A FROM'", "")
}

View File

@ -51,6 +51,8 @@ type BindingHandle interface {
BindingOperator
BindingAuto
variable.Statistics
}
@ -58,13 +60,15 @@ type BindingHandle interface {
type bindingHandle struct {
BindingCacheUpdater
BindingOperator
BindingAuto
}
// NewBindingHandle creates a new BindingHandle.
func NewBindingHandle(sPool util.DestroyableSessionPool) BindingHandle {
cache := NewBindingCacheUpdater(sPool)
op := newBindingOperator(sPool, cache)
h := &bindingHandle{BindingOperator: op, BindingCacheUpdater: cache}
auto := newBindingAuto(sPool)
h := &bindingHandle{BindingOperator: op, BindingCacheUpdater: cache, BindingAuto: auto}
variable.RegisterStatistics(h)
return h
}

View File

@ -142,13 +142,13 @@ func GenerateBindingSQL(stmtNode ast.StmtNode, planHint string, defaultDB string
return ""
}
func readBindingsFromStorage(sPool util.DestroyableSessionPool, condition string) (bindings []*Binding, err error) {
func readBindingsFromStorage(sPool util.DestroyableSessionPool, condition string, args ...any) (bindings []*Binding, err error) {
selectStmt := fmt.Sprintf(`SELECT original_sql, bind_sql, default_db, status, create_time,
update_time, charset, collation, source, sql_digest, plan_digest FROM mysql.bind_info
%s`, condition)
err = callWithSCtx(sPool, false, func(sctx sessionctx.Context) error {
rows, _, err := execRows(sctx, selectStmt)
rows, _, err := execRows(sctx, selectStmt, args...)
if err != nil {
return err
}

View File

@ -900,6 +900,7 @@ func (b *executorBuilder) buildShow(v *plannercore.PhysicalShow) exec.Executor {
Extended: v.Extended,
Extractor: v.Extractor,
ImportJobID: v.ImportJobID,
SQLOrDigest: v.SQLOrDigest,
}
if e.Tp == ast.ShowMasterStatus || e.Tp == ast.ShowBinlogStatus {
// show master status need start ts.

View File

@ -116,6 +116,7 @@ type ShowExec struct {
Extended bool // Used for `show extended columns from ...`
ImportJobID *int64
SQLOrDigest string // Used for SHOW PLAN FOR <SQL or Digest>
}
type showTableRegionRowItem struct {
@ -259,6 +260,8 @@ func (e *ShowExec) fetchAll(ctx context.Context) error {
return e.fetchShowBind()
case ast.ShowBindingCacheStatus:
return e.fetchShowBindingCacheStatus(ctx)
case ast.ShowPlanForSQL:
return e.fetchPlanForSQL()
case ast.ShowAnalyzeStatus:
return e.fetchShowAnalyzeStatus(ctx)
case ast.ShowRegions:
@ -370,6 +373,37 @@ func (e *ShowExec) fetchShowBind() error {
return nil
}
func (e *ShowExec) fetchPlanForSQL() error {
bindingHandle := domain.GetDomain(e.Ctx()).BindingHandle()
charset, collation := e.Ctx().GetSessionVars().GetCharsetInfo()
currentDB := e.Ctx().GetSessionVars().CurrentDB
plans, err := bindingHandle.ShowPlansForSQL(currentDB, e.SQLOrDigest, charset, collation)
if err != nil {
return err
}
for _, p := range plans {
hintStr, err := p.Binding.Hint.Restore()
if err != nil {
return err
}
e.appendRow([]any{
p.Binding.OriginalSQL,
hintStr,
p.Plan,
p.PlanDigest,
p.AvgLatency,
float64(p.ExecTimes),
p.AvgScanRows,
p.AvgReturnedRows,
p.LatencyPerReturnRow,
p.ScanRowsPerReturnRow,
p.Recommend,
p.Reason})
}
return nil
}
func (e *ShowExec) fetchShowBindingCacheStatus(ctx context.Context) error {
exec := e.Ctx().GetRestrictedSQLExecutor()
ctx = kv.WithInternalSourceType(ctx, kv.InternalTxnBindInfo)

View File

@ -1230,6 +1230,30 @@ func TestUniversalBindingFromHistory(t *testing.T) {
tk.MustQuery(`select @@last_plan_from_binding`).Check(testkit.Rows("1"))
}
func TestStmtSummaryShowPlanForSQL(t *testing.T) {
s := new(clusterTablesSuite)
s.store, s.dom = testkit.CreateMockStoreAndDomain(t)
s.rpcserver, s.listenAddr = s.setUpRPCService(t, "127.0.0.1:0", nil)
s.httpServer, s.mockAddr = s.setUpMockPDHTTPServer()
s.startTime = time.Now()
defer s.httpServer.Close()
defer s.rpcserver.Stop()
tk := s.newTestKitWithRoot(t)
require.NoError(t, tk.Session().Auth(&auth.UserIdentity{Username: "root", Hostname: "%"}, nil, nil, nil))
tk.MustExec(`use test`)
tk.MustExec(`create table t (a int, b int, c int)`)
tk.MustExec(`insert into t values (1, 1, 1), (2, 2, 2), (3, 3, 3)`)
tk.MustQuery(`select * from t where a=1`)
tk.MustExec(`create global binding from history using plan digest '4e3159169cc63c14b139a4e7d72eae1759875c9a9581f94bb2079aae961189cb'`)
result := tk.MustQuery(`show plan for "select * from t where a = 1"`).Rows()[0]
require.Equal(t, result[0], "select * from `test` . `t` where `a` = ?")
require.Equal(t, result[1], "use_index(@`sel_1` `test`.`t` )")
require.Contains(t, result[2], "TableReader")
require.Equal(t, result[5], "1") // exec_count
require.Equal(t, result[7], "1") // avg_returned_rows
}
func TestCreateBindingFromHistory(t *testing.T) {
s := new(clusterTablesSuite)
s.store, s.dom = testkit.CreateMockStoreAndDomain(t)

View File

@ -59,6 +59,7 @@ type ShowContents struct {
Limit *ast.Limit // Used for limit Result Set row number.
ImportJobID *int64 // Used for SHOW LOAD DATA JOB <jobID>
SQLOrDigest string // Used for SHOW PLAN FOR <SQL or Digest>
}
const emptyShowContentsSize = int64(unsafe.Sizeof(ShowContents{}))

View File

@ -3434,6 +3434,7 @@ func (b *PlanBuilder) buildShow(ctx context.Context, show *ast.ShowStmt) (base.P
Extended: show.Extended,
Limit: show.Limit,
ImportJobID: show.ImportJobID,
SQLOrDigest: show.SQLOrDigest,
},
}.Init(b.ctx)
isView := false
@ -5713,6 +5714,11 @@ func buildShowSchema(s *ast.ShowStmt, isView bool, isSequence bool) (schema *exp
case ast.ShowBindingCacheStatus:
names = []string{"bindings_in_cache", "bindings_in_table", "memory_usage", "memory_quota"}
ftypes = []byte{mysql.TypeLonglong, mysql.TypeLonglong, mysql.TypeVarchar, mysql.TypeVarchar}
case ast.ShowPlanForSQL:
names = []string{"statement", "binding_hint", "plan", "plan_digest", "avg_latency", "exec_times", "avg_scan_rows",
"avg_returned_rows", "latency_per_returned_row", "scan_rows_per_returned_row", "recommend", "reason"}
ftypes = []byte{mysql.TypeVarchar, mysql.TypeVarchar, mysql.TypeVarchar, mysql.TypeVarchar, mysql.TypeDouble, mysql.TypeDouble, mysql.TypeDouble,
mysql.TypeDouble, mysql.TypeDouble, mysql.TypeDouble, mysql.TypeVarchar, mysql.TypeVarchar}
case ast.ShowAnalyzeStatus:
names = []string{"Table_schema", "Table_name", "Partition_name", "Job_info", "Processed_rows", "Start_time",
"End_time", "State", "Fail_reason", "Instance", "Process_ID", "Remaining_seconds", "Progress", "Estimated_total_rows"}