-
Notifications
You must be signed in to change notification settings - Fork 3.9k
/
Copy pathsql_activity_update_job.go
689 lines (631 loc) · 28.1 KB
/
sql_activity_update_job.go
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
// Copyright 2023 The Cockroach Authors.
//
// Use of this software is governed by the Business Source License
// included in the file licenses/BSL.txt.
//
// As of the Change Date specified in that file, in accordance with
// the Business Source License, use of this software will be governed
// by the Apache License, Version 2.0, included in the file
// licenses/APL.txt.
package sql
import (
"context"
"fmt"
"time"
"github.com/cockroachdb/cockroach/pkg/jobs"
"github.com/cockroachdb/cockroach/pkg/jobs/jobspb"
"github.com/cockroachdb/cockroach/pkg/settings"
"github.com/cockroachdb/cockroach/pkg/settings/cluster"
"github.com/cockroachdb/cockroach/pkg/sql/isql"
"github.com/cockroachdb/cockroach/pkg/sql/sem/tree"
"github.com/cockroachdb/cockroach/pkg/sql/sessiondata"
"github.com/cockroachdb/cockroach/pkg/sql/sqlstats/persistedsqlstats"
"github.com/cockroachdb/cockroach/pkg/util/log"
"github.com/cockroachdb/cockroach/pkg/util/metric"
"github.com/cockroachdb/cockroach/pkg/util/timeutil"
"github.com/cockroachdb/errors"
io_prometheus_client "github.com/prometheus/client_model/go"
)
// enabled the stats activity flush job.
var enabled = settings.RegisterBoolSetting(
settings.SystemOnly,
"sql.stats.activity.flush.enabled",
"enable the flush to the system statement and transaction activity tables",
true)
// sqlStatsActivityAggregationInterval is the cluster setting that controls the aggregation
// interval for stats when we flush to disk.
var sqlStatsActivityAggregationInterval = settings.RegisterDurationSetting(
settings.TenantWritable,
"sql.stats.activity.aggregation.interval",
"the interval at which we aggregate SQL activity statistics upon flush, "+
"this value must be greater than or equal to sql.stats.activity.flush.interval",
time.Hour,
settings.NonNegativeDurationWithMaximum(time.Hour*24),
)
// sqlStatsActivityTopCount is the cluster setting that controls the number of
// rows selected to be inserted into the activity tables
var sqlStatsActivityTopCount = settings.RegisterIntSetting(
settings.TenantWritable,
"sql.stats.activity.top.max",
"the limit per column for the top number of statistics to be flushed "+
"to the activity tables",
500,
settings.NonNegativeInt,
)
// sqlStatsActivityMaxPersistedRows specifies maximum number of rows that will be
// retained in system.statement_statistics and system.transaction_statistics.
// Defaults computed 500(top limit)*6(num columns)*24(hrs)*3(days)=216000
// to give a minimum of 3 days of history. It was rounded down to 200k to
// give an even number. The top 500(controlled by sql.stats.activity.top.max)
// are likely the same for several columns, so it should still give 3 days
// of history for the default settings
var sqlStatsActivityMaxPersistedRows = settings.RegisterIntSetting(
settings.TenantWritable,
"sql.stats.activity.persisted_rows.max",
"maximum number of rows of statement and transaction"+
" activity that will be persisted in the system tables",
200000, /* defaultValue*/
settings.NonNegativeInt,
).WithPublic()
const numberOfTopColumns = 6
type sqlActivityUpdateJob struct {
job *jobs.Job
}
// Resume implements the jobs.sqlActivityUpdateJob interface.
// The SQL activity job runs AS a forever-running background job
// and runs the SqlActivityUpdater according to sql.stats.activity.flush.interval.
func (j *sqlActivityUpdateJob) Resume(ctx context.Context, execCtxI interface{}) (jobErr error) {
log.Infof(ctx, "starting sql stats activity flush job")
// The sql activity update job is a forever running background job.
// It's always safe to wind the SQL pod down whenever it's
// running, something we indicate through the job's idle
// status.
j.job.MarkIdle(true)
execCtx := execCtxI.(JobExecContext)
stopper := execCtx.ExecCfg().DistSQLSrv.Stopper
settings := execCtx.ExecCfg().Settings
statsFlush := execCtx.ExecCfg().InternalDB.server.sqlStats
metrics := execCtx.ExecCfg().JobRegistry.MetricsStruct().JobSpecificMetrics[jobspb.TypeAutoUpdateSQLActivity].(ActivityUpdaterMetrics)
flushDoneSignal := make(chan struct{})
defer func() {
statsFlush.SetFlushDoneCallback(nil)
close(flushDoneSignal)
}()
for {
statsFlush.SetFlushDoneCallback(func() {
flushDoneSignal <- struct{}{}
})
select {
case <-flushDoneSignal:
// A flush was done. Set the timer and wait for it to complete.
if enabled.Get(&settings.SV) {
updater := NewSqlActivityUpdater(settings, execCtx.ExecCfg().InternalDB)
if err := updater.TransferStatsToActivity(ctx); err != nil {
log.Warningf(ctx, "error running sql activity updater job: %v", err)
metrics.numErrors.Inc(1)
}
}
case <-ctx.Done():
return nil
case <-stopper.ShouldQuiesce():
return nil
}
}
}
type ActivityUpdaterMetrics struct {
numErrors *metric.Counter
}
func (m ActivityUpdaterMetrics) MetricStruct() {}
func newActivityUpdaterMetrics() metric.Struct {
return ActivityUpdaterMetrics{
numErrors: metric.NewCounter(metric.Metadata{
Name: "jobs.metrics.task_failed",
Help: "Number of metrics sql activity updater tasks that failed",
Measurement: "errors",
Unit: metric.Unit_COUNT,
MetricType: io_prometheus_client.MetricType_COUNTER,
}),
}
}
// OnFailOrCancel implements the jobs.sqlActivityUpdateJob interface.
// No action needs to be taken on our part. There's no state to clean up.
func (r *sqlActivityUpdateJob) OnFailOrCancel(
ctx context.Context, _ interface{}, jobErr error,
) error {
if jobs.HasErrJobCanceled(jobErr) {
err := errors.NewAssertionErrorWithWrappedErrf(jobErr,
"sql activity is not cancelable")
log.Errorf(ctx, "%v", err)
}
return nil
}
func init() {
jobs.RegisterConstructor(jobspb.TypeAutoUpdateSQLActivity,
func(job *jobs.Job, settings *cluster.Settings) jobs.Resumer {
return &sqlActivityUpdateJob{job: job}
},
jobs.DisablesTenantCostControl,
jobs.WithJobMetrics(newActivityUpdaterMetrics()),
)
}
// NewSqlActivityUpdater returns a new instance of SqlActivityUpdater.
func NewSqlActivityUpdater(setting *cluster.Settings, db isql.DB) *SqlActivityUpdater {
return &SqlActivityUpdater{
st: setting,
db: db,
}
}
type SqlActivityUpdater struct {
st *cluster.Settings
db isql.DB
}
func (u *SqlActivityUpdater) TransferStatsToActivity(ctx context.Context) error {
// Get the config and pass it around to avoid any issue of it changing
// in the middle of the execution.
maxRowPersistedRows := sqlStatsActivityMaxPersistedRows.Get(&u.st.SV)
topLimit := sqlStatsActivityTopCount.Get(&u.st.SV)
aggTs := u.ComputeAggregatedTs(ctx, &u.st.SV)
// The counts are using AS OF SYSTEM TIME so the values may be slightly
// off. This is acceptable to increase the performance.
stmtRowCount, txnRowCount, totalStmtClusterExecCount, totalTxnClusterExecCount, err := u.getAostExecutionCount(ctx, aggTs)
if err != nil {
return err
}
// No need to continue since there are no rows to transfer
if stmtRowCount == 0 && txnRowCount == 0 {
log.Infof(ctx, "sql stats activity found no rows at %s", aggTs)
return nil
}
// Create space on the table before adding new rows to avoid
// going OVER the count. If the compaction fails it will not
// add any new rows.
err = u.compactActivityTables(ctx, maxRowPersistedRows-stmtRowCount)
if err != nil {
return err
}
// There are fewer rows than filtered top would return.
// Just transfer all the stats to avoid overhead of getting
// the tops.
if stmtRowCount < (topLimit*numberOfTopColumns) && txnRowCount < (topLimit*numberOfTopColumns) {
return u.transferAllStats(ctx, aggTs, totalStmtClusterExecCount, totalTxnClusterExecCount)
}
// Only transfer the top sql.stats.activity.top.max for each of
// the 6 most popular columns
err = u.transferTopStats(ctx, aggTs, topLimit, totalStmtClusterExecCount, totalTxnClusterExecCount)
return err
}
// transferAllStats is used to transfer all the stats FROM
// system.statement_statistics and system.transaction_statistics
// to system.statement_activity and system.transaction_activity
func (u *SqlActivityUpdater) transferAllStats(
ctx context.Context,
aggTs time.Time,
totalStmtClusterExecCount int64,
totalTxnClusterExecCount int64,
) error {
_, err := u.db.Executor().ExecEx(ctx,
"activity-flush-txn-transfer-all",
nil, /* txn */
sessiondata.NodeUserSessionDataOverride,
`
UPSERT INTO system.public.transaction_activity
(aggregated_ts, fingerprint_id, app_name, agg_interval, metadata,
statistics, query, execution_count, execution_total_seconds,
execution_total_cluster_seconds, contention_time_avg_seconds,
cpu_sql_avg_nanos, service_latency_avg_seconds, service_latency_p99_seconds)
(SELECT aggregated_ts,
fingerprint_id,
app_name,
agg_interval,
metadata,
statistics,
'' AS query,
(statistics->'execution_statistics'->>'cnt')::int,
((statistics->'execution_statistics'->>'cnt')::float)*((statistics->'statistics'->'svcLat'->>'mean')::float),
$1 AS execution_total_cluster_seconds,
COALESCE((statistics->'execution_statistics'->'contentionTime'->>'mean')::float,0),
COALESCE((statistics->'execution_statistics'->'cpu_sql_nanos'->>'mean')::float,0),
(statistics->'statistics'->'svcLat'->>'mean')::float,
COALESCE((statistics->'statistics'->'latencyInfo'->>'p99')::float, 0)
FROM (SELECT
max(aggregated_ts) AS aggregated_ts,
app_name,
fingerprint_id,
agg_interval,
max(metadata) AS metadata,
crdb_internal.merge_transaction_stats(array_agg(statistics)) AS statistics
FROM system.public.transaction_statistics
WHERE aggregated_ts = $2
and app_name not like '$ internal%'
GROUP BY app_name,
fingerprint_id,
agg_interval));
`,
totalTxnClusterExecCount,
aggTs,
)
if err != nil {
return err
}
_, err = u.db.Executor().ExecEx(ctx,
"activity-flush-stmt-transfer-all",
nil, /* txn */
sessiondata.NodeUserSessionDataOverride,
`
UPSERT
INTO system.public.statement_activity (aggregated_ts, fingerprint_id, transaction_fingerprint_id, plan_hash, app_name,
agg_interval, metadata, statistics, plan, index_recommendations, execution_count,
execution_total_seconds, execution_total_cluster_seconds,
contention_time_avg_seconds,
cpu_sql_avg_nanos,
service_latency_avg_seconds, service_latency_p99_seconds)
(SELECT aggregated_ts,
fingerprint_id,
transaction_fingerprint_id,
plan_hash,
app_name,
agg_interval,
metadata,
statistics,
plan,
index_recommendations,
(statistics -> 'execution_statistics' ->> 'cnt')::int,
((statistics -> 'execution_statistics' ->> 'cnt')::float) *
((statistics -> 'statistics' -> 'svcLat' ->> 'mean')::float),
$1 AS execution_total_cluster_seconds,
COALESCE((statistics -> 'execution_statistics' -> 'contentionTime' ->> 'mean')::float, 0),
COALESCE((statistics -> 'execution_statistics' -> 'cpu_sql_nanos' ->> 'mean')::float, 0),
(statistics -> 'statistics' -> 'svcLat' ->> 'mean')::float,
COALESCE((statistics -> 'statistics' -> 'latencyInfo' ->> 'p99')::float, 0)
FROM (SELECT max(aggregated_ts) AS aggregated_ts,
fingerprint_id,
transaction_fingerprint_id,
plan_hash,
app_name,
agg_interval,
max(metadata) AS metadata,
crdb_internal.merge_transaction_stats(array_agg(statistics)) AS statistics,
plan,
index_recommendations
FROM system.public.statement_statistics
WHERE aggregated_ts = $2
and app_name not like '$ internal%'
GROUP BY app_name,
fingerprint_id,
transaction_fingerprint_id,
plan_hash,
agg_interval,
plan,
index_recommendations));
`,
totalStmtClusterExecCount,
aggTs,
)
return err
}
// transferTopStats is used to transfer top N stats FROM
// system.statement_statistics and system.transaction_statistics
// to system.statement_activity and system.transaction_activity
func (u *SqlActivityUpdater) transferTopStats(
ctx context.Context,
aggTs time.Time,
topLimit int64,
totalStmtClusterExecCount int64,
totalTxnClusterExecCount int64,
) (retErr error) {
// Select the top 500 (controlled by sql.stats.activity.top.max) for
// execution_count, total execution time, service_latency,cpu_sql_nanos,
// contention_time, p99_latency and insert into transaction_activity table.
_, err := u.db.Executor().ExecEx(ctx,
"activity-flush-txn-transfer-tops",
nil, /* txn */
sessiondata.NodeUserSessionDataOverride,
`
UPSERT
INTO system.public.transaction_activity
(aggregated_ts, fingerprint_id, app_name, agg_interval, metadata,
statistics, query, execution_count, execution_total_seconds,
execution_total_cluster_seconds, contention_time_avg_seconds,
cpu_sql_avg_nanos, service_latency_avg_seconds, service_latency_p99_seconds)
(SELECT aggregated_ts,
fingerprint_id,
app_name,
agg_interval,
metadata,
statistics,
'' AS query,
(statistics -> 'execution_statistics' ->> 'cnt')::int,
((statistics -> 'execution_statistics' ->> 'cnt')::float) *
((statistics -> 'statistics' -> 'svcLat' ->> 'mean')::float),
$1 AS execution_total_cluster_seconds,
COALESCE((statistics -> 'execution_statistics' -> 'contentionTime' ->> 'mean')::float, 0),
COALESCE((statistics -> 'execution_statistics' -> 'cpu_sql_nanos' ->> 'mean')::float, 0),
(statistics -> 'statistics' -> 'svcLat' ->> 'mean')::float,
COALESCE((statistics -> 'statistics' -> 'latencyInfo' ->> 'p99')::float, 0)
FROM (SELECT max(ts.aggregated_ts) AS aggregated_ts,
ts.app_name,
ts.fingerprint_id,
ts.agg_interval,
max(ts.metadata) AS metadata,
crdb_internal.merge_transaction_stats(array_agg(statistics)) AS statistics
FROM system.public.transaction_statistics ts
inner join (SELECT fingerprint_id, app_name, agg_interval
FROM (SELECT fingerprint_id, app_name, agg_interval,
row_number()
OVER (ORDER BY (statistics -> 'execution_statistics' ->> 'cnt')::int desc) AS ePos,
row_number()
OVER (ORDER BY (statistics -> 'statistics' -> 'svcLat' ->> 'mean')::float desc) AS sPos,
row_number()
OVER (ORDER BY ((statistics -> 'execution_statistics' ->> 'cnt')::float) *
((statistics -> 'statistics' -> 'svcLat' ->> 'mean')::float) desc) AS tPos,
row_number() OVER (ORDER BY COALESCE(
(statistics -> 'execution_statistics' -> 'contentionTime' ->> 'mean')::float,
0) desc) AS cPos,
row_number() OVER (ORDER BY COALESCE(
(statistics -> 'execution_statistics' -> 'cpu_sql_nanos' ->> 'mean')::float,
0) desc) AS uPos,
row_number() OVER (ORDER BY COALESCE(
(statistics -> 'statistics' -> 'latencyInfo' ->> 'p99')::float,
0) desc) AS lPos
FROM (SELECT fingerprint_id, app_name, agg_interval,
crdb_internal.merge_transaction_stats(array_agg(statistics)) AS statistics
FROM system.public.transaction_statistics
WHERE aggregated_ts = $2 and
app_name not like '$ internal%'
GROUP BY app_name,
fingerprint_id,
agg_interval))
WHERE ePos < $3
or sPos < $3
or tPos < $3
or cPos < $3
or uPos < $3
or lPos < $3) agg
on agg.app_name = ts.app_name and agg.fingerprint_id = ts.fingerprint_id and
agg.agg_interval = ts.agg_interval
GROUP BY ts.app_name,
ts.fingerprint_id,
ts.agg_interval));
`,
totalStmtClusterExecCount,
aggTs,
topLimit,
)
if err != nil {
return err
}
// Select the top 500 (controlled by sql.stats.activity.top.max) for
// execution_count, total execution time, service_latency, cpu_sql_nanos,
// contention_time, p99_latency, and any statement that was in the
// top N transactions and insert into statement_activity table.
_, err = u.db.Executor().ExecEx(ctx,
"activity-flush-stmt-transfer-tops",
nil, /* txn */
sessiondata.NodeUserSessionDataOverride,
`
UPSERT
INTO system.public.statement_activity
(aggregated_ts, fingerprint_id, transaction_fingerprint_id, plan_hash, app_name,
agg_interval, metadata, statistics, plan, index_recommendations, execution_count,
execution_total_seconds, execution_total_cluster_seconds,
contention_time_avg_seconds,
cpu_sql_avg_nanos,
service_latency_avg_seconds, service_latency_p99_seconds)
(SELECT aggregated_ts,
fingerprint_id,
transaction_fingerprint_id,
plan_hash,
app_name,
agg_interval,
metadata,
statistics,
plan,
index_recommendations,
(statistics -> 'execution_statistics' ->> 'cnt')::int,
((statistics -> 'execution_statistics' ->> 'cnt')::float) *
((statistics -> 'statistics' -> 'svcLat' ->> 'mean')::float),
$1 AS execution_total_cluster_seconds,
COALESCE((statistics -> 'execution_statistics' -> 'contentionTime' ->> 'mean')::float, 0),
COALESCE((statistics -> 'execution_statistics' -> 'cpu_sql_nanos' ->> 'mean')::float, 0),
(statistics -> 'statistics' -> 'svcLat' ->> 'mean')::float,
COALESCE((statistics -> 'statistics' -> 'latencyInfo' ->> 'p99')::float, 0)
FROM (SELECT max(ss.aggregated_ts) AS aggregated_ts,
ss.fingerprint_id,
ss.transaction_fingerprint_id,
ss.plan_hash,
ss.app_name,
ss.agg_interval,
max(ss.metadata) AS metadata,
crdb_internal.merge_transaction_stats(array_agg(ss.statistics)) AS statistics,
ss.plan,
ss.index_recommendations
FROM system.public.statement_statistics ss
inner join (SELECT fingerprint_id, app_name
FROM (SELECT fingerprint_id, app_name,
row_number()
OVER (ORDER BY (statistics -> 'execution_statistics' ->> 'cnt')::int desc) AS ePos,
row_number()
OVER (ORDER BY (statistics -> 'statistics' -> 'svcLat' ->> 'mean')::float desc) AS sPos,
row_number() OVER (ORDER BY
((statistics -> 'execution_statistics' ->> 'cnt')::float) *
((statistics -> 'statistics' -> 'svcLat' ->> 'mean')::float) desc) AS tPos,
row_number() OVER (ORDER BY COALESCE(
(statistics -> 'execution_statistics' -> 'contentionTime' ->> 'mean')::float,
0) desc) AS cPos,
row_number() OVER (ORDER BY COALESCE(
(statistics -> 'execution_statistics' -> 'cpu_sql_nanos' ->> 'mean')::float,
0) desc) AS uPos,
row_number() OVER (ORDER BY COALESCE(
(statistics -> 'statistics' -> 'latencyInfo' ->> 'p99')::float,
0) desc) AS lPos
FROM (SELECT fingerprint_id,
app_name,
crdb_internal.merge_statement_stats(array_agg(statistics)) AS statistics
FROM system.public.statement_statistics
WHERE aggregated_ts = $2 and
app_name not like '$ internal%'
GROUP BY app_name,
fingerprint_id))
WHERE ePos < $3
or sPos < $3
or tPos < $3
or cPos < $3
or uPos < $3
or lPos < $3) agg on agg.app_name = ss.app_name and agg.fingerprint_id = ss.fingerprint_id
WHERE aggregated_ts = $2
GROUP BY ss.app_name,
ss.fingerprint_id,
ss.transaction_fingerprint_id,
ss.plan_hash,
ss.agg_interval,
ss.plan,
ss.index_recommendations));
`,
totalTxnClusterExecCount,
aggTs,
topLimit,
)
return err
}
// getAosExecutionCount is used to get the row counts of both the
// system.statement_statistics and system.transaction_statistics.
// It also gets the total execution count for the specified aggregated
// timestamp.
func (u *SqlActivityUpdater) getAostExecutionCount(
ctx context.Context, aggTs time.Time,
) (
stmtRowCount int64,
txnRowCount int64,
totalStmtClusterExecCount int64,
totalTxnClusterExecCount int64,
retErr error,
) {
it, err := u.db.Executor().QueryIteratorEx(ctx,
"activity-flush-count",
nil, /* txn */
sessiondata.NodeUserSessionDataOverride,
`
SELECT row_count, ex_sum FROM (SELECT
count_rows():::int AS row_count,
COALESCE(sum(execution_count)::int, 0) AS ex_sum
FROM system.statement_statistics AS OF SYSTEM TIME follower_read_timestamp()
WHERE app_name not like '$ internal%' and aggregated_ts = $1
union all
SELECT
count_rows():::int AS row_count,
COALESCE(sum(execution_count)::int, 0) AS ex_sum
FROM system.transaction_statistics AS OF SYSTEM TIME follower_read_timestamp()
WHERE app_name not like '$ internal%' and aggregated_ts = $1) AS OF SYSTEM TIME follower_read_timestamp()`,
aggTs,
)
if err != nil {
return -1, -1, -1, -1, err
}
defer func() { retErr = errors.CombineErrors(retErr, it.Close()) }()
stmtRowCount, totalStmtClusterExecCount, err = u.getExecutionCountFromRow(ctx, it)
if err != nil {
return -1, -1, -1, -1, err
}
txnRowCount, totalTxnClusterExecCount, err = u.getExecutionCountFromRow(ctx, it)
return stmtRowCount, txnRowCount, totalStmtClusterExecCount, totalTxnClusterExecCount, err
}
func (u *SqlActivityUpdater) getExecutionCountFromRow(
ctx context.Context, iter isql.Rows,
) (rowCount int64, totalExecutionCount int64, err error) {
ok, err := iter.Next(ctx)
if err != nil {
return -1, -1, err
}
if !ok {
return -1, -1, fmt.Errorf("no rows in activity-flush-count")
}
row := iter.Cur()
if row[0] == tree.DNull || row[1] == tree.DNull {
return 0, 0, nil
}
return int64(tree.MustBeDInt(row[0])), int64(tree.MustBeDInt(row[1])), nil
}
// ComputeAggregatedTs returns the aggregation timestamp to assign
// in-memory SQL stats during storage or aggregation.
func (u *SqlActivityUpdater) ComputeAggregatedTs(
ctx context.Context, sv *settings.Values,
) time.Time {
interval := sqlStatsActivityAggregationInterval.Get(sv)
intervalSqlStats := persistedsqlstats.SQLStatsAggregationInterval.Get(sv)
// system.{statement/transaction}_activity stats are based on the values in
// system.{statement/transaction}_statistics, so the interval must be equal
// to or greater than the statistics table.
if interval < intervalSqlStats {
log.Warningf(ctx, "sql.stats.activity.aggregation.interval: %s must be greater than or equal to sql.stats.aggregation.interval: %s", interval, intervalSqlStats)
interval = intervalSqlStats
}
now := timeutil.Now()
aggTs := now.Truncate(interval)
return aggTs
}
// compactActivityTables is used delete rows FROM the activity tables
// to keep the tables under the specified config limit.
func (u *SqlActivityUpdater) compactActivityTables(ctx context.Context, maxRowCount int64) error {
rowCount, err := u.getTableRowCount(ctx, "system.statement_activity")
if err != nil {
return err
}
if rowCount < maxRowCount {
return nil
}
// Delete all the rows FROM the aggregated_ts to avoid
// showing partial data for a time range.
_, err = u.db.Executor().ExecEx(ctx,
"activity-stmt-compaction",
nil, /* txn */
sessiondata.NodeUserSessionDataOverride,
`
DELETE
FROM system.statement_activity
WHERE aggregated_ts IN (SELECT DISTINCT aggregated_ts FROM (SELECT aggregated_ts FROM system.statement_activity ORDER BY aggregated_ts ASC limit $1));`,
rowCount-maxRowCount,
)
if err != nil {
return err
}
// Delete all the rows older than on the oldest statement_activity aggregated_ts.
// This makes sure that the 2 tables are always in sync.
_, err = u.db.Executor().ExecEx(ctx,
"activity-txn-compaction",
nil, /* txn */
sessiondata.NodeUserSessionDataOverride,
`
DELETE
FROM system.transaction_activity
WHERE aggregated_ts not in (SELECT distinct aggregated_ts FROM system.statement_activity);`,
)
return err
}
// getTableRowCount is used to get the row counts of both the
// system.statement_statistics and system.transaction_statistics.
// It also gets the total execution count for the specified aggregated
// timestamp.
func (u *SqlActivityUpdater) getTableRowCount(
ctx context.Context, tableName string,
) (rowCount int64, retErr error) {
query := fmt.Sprintf(`
SELECT
count_rows()::int
FROM %s AS OF SYSTEM TIME follower_read_timestamp()`, tableName)
datums, err := u.db.Executor().QueryRowEx(ctx,
"activity-total-count",
nil, /* txn */
sessiondata.NodeUserSessionDataOverride,
query,
)
if err != nil {
return 0, err
}
if datums == nil {
return 0, nil
}
if datums[0] == tree.DNull {
return 0, nil
}
return int64(tree.MustBeDInt(datums[0])), nil
}