From 781476a3803a3038cbf42cef6525ea542320acf9 Mon Sep 17 00:00:00 2001 From: Marcus Gartner Date: Fri, 24 Jan 2025 12:50:13 -0500 Subject: [PATCH] sql: do not collect histograms for non-indexed JSON columns Informs #139381 Release note (sql change): Since v23.2 table statistics histograms have been collected for non-indexed JSON columns. Histograms are no longer collected for these columns if `sql.stats.non_indexed_json_histograms.enabled` is set to `false`. This reduces memory usage during table statistics collection, for both automatic and manual collection via `ANALYZE` and `CREATE STATISTICS`. --- .../settings/settings-for-tenants.txt | 1 + docs/generated/settings/settings.html | 1 + pkg/sql/create_stats.go | 28 ++++++++++-- pkg/sql/logictest/testdata/logic_test/stats | 45 +++++++++++++++++++ 4 files changed, 72 insertions(+), 3 deletions(-) diff --git a/docs/generated/settings/settings-for-tenants.txt b/docs/generated/settings/settings-for-tenants.txt index d482342e59d3..e42de20761ab 100644 --- a/docs/generated/settings/settings-for-tenants.txt +++ b/docs/generated/settings/settings-for-tenants.txt @@ -309,6 +309,7 @@ sql.stats.histogram_collection.enabled boolean true histogram collection mode ap sql.stats.histogram_samples.count integer 10000 number of rows sampled for histogram construction during table statistics collection application sql.stats.multi_column_collection.enabled boolean true multi-column statistics collection mode application sql.stats.non_default_columns.min_retention_period duration 24h0m0s minimum retention period for table statistics collected on non-default columns application +sql.stats.non_indexed_json_histograms.enabled boolean true set to true to collect table statistics histograms on non-indexed JSON columns application sql.stats.persisted_rows.max integer 1000000 maximum number of rows of statement and transaction statistics that will be persisted in the system tables before compaction begins application sql.stats.post_events.enabled boolean false if set, an event is logged for every CREATE STATISTICS job application sql.stats.response.max integer 20000 the maximum number of statements and transaction stats returned in a CombinedStatements request application diff --git a/docs/generated/settings/settings.html b/docs/generated/settings/settings.html index 204631d7d545..6b846645bb1c 100644 --- a/docs/generated/settings/settings.html +++ b/docs/generated/settings/settings.html @@ -260,6 +260,7 @@
sql.stats.histogram_samples.count
integer10000number of rows sampled for histogram construction during table statistics collectionServerless/Dedicated/Self-Hosted
sql.stats.multi_column_collection.enabled
booleantruemulti-column statistics collection modeServerless/Dedicated/Self-Hosted
sql.stats.non_default_columns.min_retention_period
duration24h0m0sminimum retention period for table statistics collected on non-default columnsServerless/Dedicated/Self-Hosted +
sql.stats.non_indexed_json_histograms.enabled
booleantrueset to true to collect table statistics histograms on non-indexed JSON columnsServerless/Dedicated/Self-Hosted
sql.stats.persisted_rows.max
integer1000000maximum number of rows of statement and transaction statistics that will be persisted in the system tables before compaction beginsServerless/Dedicated/Self-Hosted
sql.stats.post_events.enabled
booleanfalseif set, an event is logged for every CREATE STATISTICS jobServerless/Dedicated/Self-Hosted
sql.stats.response.max
integer20000the maximum number of statements and transaction stats returned in a CombinedStatements requestServerless/Dedicated/Self-Hosted diff --git a/pkg/sql/create_stats.go b/pkg/sql/create_stats.go index 32446c53bb9a..55b4a4196bbd 100644 --- a/pkg/sql/create_stats.go +++ b/pkg/sql/create_stats.go @@ -62,6 +62,18 @@ var statsOnVirtualCols = settings.RegisterBoolSetting( true, settings.WithPublic) +// Collecting histograms on non-indexed JSON columns can require a lot of memory +// when the JSON values are large. This is true even when only two histogram +// buckets are generated because we still sample many JSON values which exist in +// memory for the duration of the stats collection job. By default, we do not +// collect histograms for non-indexed JSON columns. +var nonIndexJSONHistograms = settings.RegisterBoolSetting( + settings.ApplicationLevel, + "sql.stats.non_indexed_json_histograms.enabled", + "set to true to collect table statistics histograms on non-indexed JSON columns", + true, + settings.WithPublic) + const nonIndexColHistogramBuckets = 2 // StubTableStats generates "stub" statistics for a table which are missing @@ -72,6 +84,7 @@ func StubTableStats( ) ([]*stats.TableStatisticProto, error) { colStats, err := createStatsDefaultColumns( context.Background(), desc, false /* virtColEnabled */, false, /* multiColEnabled */ + false, /* nonIndexJSONHistograms */ nonIndexColHistogramBuckets, nil, /* evalCtx */ ) if err != nil { @@ -243,7 +256,9 @@ func (n *createStatsNode) makeJobRecord(ctx context.Context) (*jobs.Record, erro } defaultHistogramBuckets := stats.GetDefaultHistogramBuckets(n.p.ExecCfg().SV(), tableDesc) if colStats, err = createStatsDefaultColumns( - ctx, tableDesc, virtColEnabled, multiColEnabled, defaultHistogramBuckets, n.p.EvalContext(), + ctx, tableDesc, virtColEnabled, multiColEnabled, + nonIndexJSONHistograms.Get(n.p.ExecCfg().SV()), + defaultHistogramBuckets, n.p.EvalContext(), ); err != nil { return nil, err } @@ -355,13 +370,16 @@ const maxNonIndexCols = 100 // predicate expressions are also likely to appear in query filters, so stats // are collected for those columns as well. // +// If nonIndexJsonHistograms is true, 2-bucket histograms are collected for +// non-indexed JSON columns. +// // In addition to the index columns, we collect stats on up to maxNonIndexCols // other columns from the table. We only collect histograms for index columns, // plus any other boolean or enum columns (where the "histogram" is tiny). func createStatsDefaultColumns( ctx context.Context, desc catalog.TableDescriptor, - virtColEnabled, multiColEnabled bool, + virtColEnabled, multiColEnabled, nonIndexJSONHistograms bool, defaultHistogramBuckets uint32, evalCtx *eval.Context, ) ([]jobspb.CreateStatsDetails_ColStat, error) { @@ -618,9 +636,13 @@ func createStatsDefaultColumns( if col.GetType().Family() == types.BoolFamily || col.GetType().Family() == types.EnumFamily { maxHistBuckets = defaultHistogramBuckets } + hasHistogram := !colinfo.ColumnTypeIsOnlyInvertedIndexable(col.GetType()) + if col.GetType().Family() == types.JsonFamily { + hasHistogram = nonIndexJSONHistograms + } colStats = append(colStats, jobspb.CreateStatsDetails_ColStat{ ColumnIDs: colIDs, - HasHistogram: !colinfo.ColumnTypeIsOnlyInvertedIndexable(col.GetType()), + HasHistogram: hasHistogram, HistogramMaxBuckets: maxHistBuckets, }) nonIdxCols++ diff --git a/pkg/sql/logictest/testdata/logic_test/stats b/pkg/sql/logictest/testdata/logic_test/stats index 9d33f3958a7f..b4144b391c9b 100644 --- a/pkg/sql/logictest/testdata/logic_test/stats +++ b/pkg/sql/logictest/testdata/logic_test/stats @@ -50,3 +50,48 @@ CREATE TABLE t122312 (s STRING, g greeting AS (s::greeting) STORED); statement ok ANALYZE t122312; + +# Regression test related to #139381. Do not collect histograms on non-indexed +# JSON columns when sql.stats.non_indexed_json_histograms.enabled is false. +statement ok +CREATE TABLE t139381 ( + k INT PRIMARY KEY, + j JSON, + v STRING AS (j->>'name') VIRTUAL, + INDEX (v) +) + +statement ok +SET CLUSTER SETTING sql.stats.non_indexed_json_histograms.enabled = false + +statement ok +INSERT INTO t139381 +SELECT i, ('{"name": "name_' || i || '", "data": "abcdefghij"}')::JSONB +FROM (VALUES (1), (2)) v(i) + +statement ok +ANALYZE t139381 + +query TT rowsort +SELECT column_names, IF(histogram_id IS NOT NULL, 'histogram_collected', 'no_histogram_collected') +FROM [SHOW STATISTICS FOR TABLE t139381] +---- +{k} histogram_collected +{j} no_histogram_collected +{v} histogram_collected + +# Histograms are collected on non-indexed JSON columns when the cluster setting +# is enabled. +statement ok +SET CLUSTER SETTING sql.stats.non_indexed_json_histograms.enabled = true + +statement ok +ANALYZE t139381 + +query TT rowsort +SELECT column_names, IF(histogram_id IS NOT NULL, 'histogram_collected', 'no_histogram_collected') +FROM [SHOW STATISTICS FOR TABLE t139381] +---- +{k} histogram_collected +{j} histogram_collected +{v} histogram_collected