Skip to content

Commit 4ece712

Browse files
committed
sql/stats: fix inject/restore of partial stats not creating merged stats
Previously, JSON statistics would not include the statistic ID. This meant that restoring statement bundles would recreate stats with new IDs, breaking the statisticID/fullStatisticID relationship between full & partial stats and fail to recreate merged stats as a result. This commit adds the statistic ID to JSONStatistic and recreates stats with the same ID if present when injected. Allows for merged stats to be correctly recreated following inject/restore of full and partial stats. Fixes: #94101 See also: #125950 Release note (bug fix): Fixed a bug that prevented merged stats from being created after injecting stats or recreating statement bundles. This would occur when the injected stats/statement bundle contained related full and partial statistics.
1 parent 1d7cc7f commit 4ece712

File tree

6 files changed

+141
-89
lines changed

6 files changed

+141
-89
lines changed

pkg/sql/alter_table.go

Lines changed: 53 additions & 18 deletions
Original file line numberDiff line numberDiff line change
@@ -1587,11 +1587,45 @@ func insertJSONStatistic(
15871587
fullStatisticIDValue = s.FullStatisticID
15881588
}
15891589

1590-
_ /* rows */, err := txn.Exec(
1591-
ctx,
1592-
"insert-stats",
1593-
txn.KV(),
1594-
`INSERT INTO system.table_statistics (
1590+
if s.ID != 0 {
1591+
_ /* rows */, err := txn.Exec(
1592+
ctx,
1593+
"insert-stats",
1594+
txn.KV(),
1595+
`INSERT INTO system.table_statistics (
1596+
"statisticID",
1597+
"tableID",
1598+
"name",
1599+
"columnIDs",
1600+
"createdAt",
1601+
"rowCount",
1602+
"distinctCount",
1603+
"nullCount",
1604+
"avgSize",
1605+
histogram,
1606+
"partialPredicate",
1607+
"fullStatisticID"
1608+
) VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12)`,
1609+
s.ID,
1610+
tableID,
1611+
name,
1612+
columnIDs,
1613+
s.CreatedAt,
1614+
s.RowCount,
1615+
s.DistinctCount,
1616+
s.NullCount,
1617+
s.AvgSize,
1618+
histogram,
1619+
predicateValue,
1620+
fullStatisticIDValue,
1621+
)
1622+
return err
1623+
} else {
1624+
_ /* rows */, err := txn.Exec(
1625+
ctx,
1626+
"insert-stats",
1627+
txn.KV(),
1628+
`INSERT INTO system.table_statistics (
15951629
"tableID",
15961630
"name",
15971631
"columnIDs",
@@ -1604,19 +1638,20 @@ func insertJSONStatistic(
16041638
"partialPredicate",
16051639
"fullStatisticID"
16061640
) VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11)`,
1607-
tableID,
1608-
name,
1609-
columnIDs,
1610-
s.CreatedAt,
1611-
s.RowCount,
1612-
s.DistinctCount,
1613-
s.NullCount,
1614-
s.AvgSize,
1615-
histogram,
1616-
predicateValue,
1617-
fullStatisticIDValue,
1618-
)
1619-
return err
1641+
tableID,
1642+
name,
1643+
columnIDs,
1644+
s.CreatedAt,
1645+
s.RowCount,
1646+
s.DistinctCount,
1647+
s.NullCount,
1648+
s.AvgSize,
1649+
histogram,
1650+
predicateValue,
1651+
fullStatisticIDValue,
1652+
)
1653+
return err
1654+
}
16201655
}
16211656

16221657
// validateConstraintNameIsNotUsed checks that the name of the constraint we're

pkg/sql/logictest/testdata/logic_test/distsql_stats

Lines changed: 42 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -1631,7 +1631,9 @@ statement ok
16311631
CREATE STATISTICS s FROM all_null
16321632

16331633
query T
1634-
SELECT jsonb_pretty(COALESCE(json_agg(stat), '[]'))
1634+
SELECT jsonb_pretty(
1635+
regexp_replace(COALESCE(json_agg(stat), '[]')::STRING, '"id": [0-9]+', '"id": 0', 'g')::JSONB
1636+
)
16351637
FROM (
16361638
SELECT json_array_elements(statistics) - 'created_at' AS stat
16371639
FROM [SHOW STATISTICS USING JSON FOR TABLE all_null]
@@ -1654,6 +1656,7 @@ FROM [SHOW STATISTICS USING JSON FOR TABLE all_null]
16541656
],
16551657
"histo_col_type": "INT8",
16561658
"histo_version": 3,
1659+
"id": 0,
16571660
"name": "s",
16581661
"null_count": 0,
16591662
"row_count": 1
@@ -1666,6 +1669,7 @@ FROM [SHOW STATISTICS USING JSON FOR TABLE all_null]
16661669
"distinct_count": 1,
16671670
"histo_col_type": "INT8",
16681671
"histo_version": 3,
1672+
"id": 0,
16691673
"name": "s",
16701674
"null_count": 1,
16711675
"row_count": 1
@@ -1689,7 +1693,9 @@ statement ok
16891693
CREATE STATISTICS s FROM greeting_stats
16901694

16911695
query T
1692-
SELECT jsonb_pretty(COALESCE(json_agg(stat), '[]'))
1696+
SELECT jsonb_pretty(
1697+
regexp_replace(COALESCE(json_agg(stat), '[]')::STRING, '"id": [0-9]+', '"id": 0', 'g')::JSONB
1698+
)
16931699
FROM (
16941700
SELECT json_array_elements(statistics) - 'created_at' AS stat
16951701
FROM [SHOW STATISTICS USING JSON FOR TABLE greeting_stats]
@@ -1712,6 +1718,7 @@ FROM [SHOW STATISTICS USING JSON FOR TABLE greeting_stats]
17121718
],
17131719
"histo_col_type": "test.public.greeting",
17141720
"histo_version": 3,
1721+
"id": 0,
17151722
"name": "s",
17161723
"null_count": 0,
17171724
"row_count": 1
@@ -1877,7 +1884,9 @@ SHOW HISTOGRAM $hist_id_1
18771884
upper_bound range_rows distinct_range_rows equal_rows
18781885

18791886
query T
1880-
SELECT jsonb_pretty(COALESCE(json_agg(stat), '[]'))
1887+
SELECT jsonb_pretty(
1888+
regexp_replace(COALESCE(json_agg(stat), '[]')::STRING, '"id": [0-9]+', '"id": 0', 'g')::JSONB
1889+
)
18811890
FROM (SELECT json_array_elements(statistics) - 'created_at' AS stat
18821891
FROM [SHOW STATISTICS USING JSON FOR TABLE tabula])
18831892
----
@@ -1890,6 +1899,7 @@ SELECT jsonb_pretty(COALESCE(json_agg(stat), '[]'))
18901899
"distinct_count": 0,
18911900
"histo_col_type": "INT8",
18921901
"histo_version": 3,
1902+
"id": 0,
18931903
"name": "aristotle",
18941904
"null_count": 0,
18951905
"row_count": 0
@@ -1902,6 +1912,7 @@ SELECT jsonb_pretty(COALESCE(json_agg(stat), '[]'))
19021912
"distinct_count": 0,
19031913
"histo_col_type": "INT8",
19041914
"histo_version": 3,
1915+
"id": 0,
19051916
"name": "aristotle",
19061917
"null_count": 0,
19071918
"row_count": 0
@@ -1914,6 +1925,7 @@ SELECT jsonb_pretty(COALESCE(json_agg(stat), '[]'))
19141925
],
19151926
"distinct_count": 0,
19161927
"histo_col_type": "",
1928+
"id": 0,
19171929
"name": "aristotle",
19181930
"null_count": 0,
19191931
"row_count": 0
@@ -1926,6 +1938,7 @@ SELECT jsonb_pretty(COALESCE(json_agg(stat), '[]'))
19261938
"distinct_count": 0,
19271939
"histo_col_type": "INT8",
19281940
"histo_version": 3,
1941+
"id": 0,
19291942
"name": "aristotle",
19301943
"null_count": 0,
19311944
"row_count": 0
@@ -1973,7 +1986,9 @@ SHOW HISTOGRAM $hist_id_1
19731986
upper_bound range_rows distinct_range_rows equal_rows
19741987

19751988
query T
1976-
SELECT jsonb_pretty(COALESCE(json_agg(stat), '[]'))
1989+
SELECT jsonb_pretty(
1990+
regexp_replace(COALESCE(json_agg(stat), '[]')::STRING, '"id": [0-9]+', '"id": 0', 'g')::JSONB
1991+
)
19771992
FROM (SELECT json_array_elements(statistics) - 'created_at' - 'avg_size' AS stat
19781993
FROM [SHOW STATISTICS USING JSON FOR TABLE tabula])
19791994
----
@@ -1993,6 +2008,7 @@ SELECT jsonb_pretty(COALESCE(json_agg(stat), '[]'))
19932008
],
19942009
"histo_col_type": "INT8",
19952010
"histo_version": 3,
2011+
"id": 0,
19962012
"name": "locke",
19972013
"null_count": 0,
19982014
"row_count": 1
@@ -2012,6 +2028,7 @@ SELECT jsonb_pretty(COALESCE(json_agg(stat), '[]'))
20122028
],
20132029
"histo_col_type": "INT8",
20142030
"histo_version": 3,
2031+
"id": 0,
20152032
"name": "locke",
20162033
"null_count": 0,
20172034
"row_count": 1
@@ -2023,6 +2040,7 @@ SELECT jsonb_pretty(COALESCE(json_agg(stat), '[]'))
20232040
],
20242041
"distinct_count": 1,
20252042
"histo_col_type": "",
2043+
"id": 0,
20262044
"name": "locke",
20272045
"null_count": 0,
20282046
"row_count": 1
@@ -2034,6 +2052,7 @@ SELECT jsonb_pretty(COALESCE(json_agg(stat), '[]'))
20342052
"distinct_count": 1,
20352053
"histo_col_type": "INT8",
20362054
"histo_version": 3,
2055+
"id": 0,
20372056
"name": "locke",
20382057
"null_count": 1,
20392058
"row_count": 1
@@ -2081,7 +2100,9 @@ NULL {rowid} 0 0 0 true
20812100
t1_ab {a,b} 0 0 0 false
20822101

20832102
query T
2084-
SELECT jsonb_pretty(COALESCE(json_agg(stat), '[]'))
2103+
SELECT jsonb_pretty(
2104+
regexp_replace(COALESCE(json_agg(stat), '[]')::STRING, '"id": [0-9]+', '"id": 0', 'g')::JSONB
2105+
)
20852106
FROM (
20862107
SELECT json_array_elements(statistics) - 'created_at' AS stat
20872108
FROM [SHOW STATISTICS USING JSON FOR TABLE t1]
@@ -2096,6 +2117,7 @@ FROM [SHOW STATISTICS USING JSON FOR TABLE t1]
20962117
"distinct_count": 0,
20972118
"histo_col_type": "INT8",
20982119
"histo_version": 3,
2120+
"id": 0,
20992121
"null_count": 0,
21002122
"row_count": 0
21012123
},
@@ -2107,6 +2129,7 @@ FROM [SHOW STATISTICS USING JSON FOR TABLE t1]
21072129
"distinct_count": 0,
21082130
"histo_col_type": "INT8",
21092131
"histo_version": 3,
2132+
"id": 0,
21102133
"null_count": 0,
21112134
"row_count": 0
21122135
},
@@ -2118,6 +2141,7 @@ FROM [SHOW STATISTICS USING JSON FOR TABLE t1]
21182141
"distinct_count": 0,
21192142
"histo_col_type": "INT8",
21202143
"histo_version": 3,
2144+
"id": 0,
21212145
"null_count": 0,
21222146
"row_count": 0
21232147
},
@@ -2129,6 +2153,7 @@ FROM [SHOW STATISTICS USING JSON FOR TABLE t1]
21292153
],
21302154
"distinct_count": 0,
21312155
"histo_col_type": "",
2156+
"id": 0,
21322157
"name": "t1_ab",
21332158
"null_count": 0,
21342159
"row_count": 0
@@ -2363,6 +2388,18 @@ statistics_name partial_predicate row_count n
23632388
xy_x_partial (x IS NULL) OR ((x < 0:::INT8) OR (x > 3:::INT8)) 4 0
23642389
xy_x_partial_2 (x IS NULL) OR ((x < 0:::INT8) OR (x > 3:::INT8)) 4 0
23652390

2391+
query T
2392+
SELECT jsonb_pretty(stat->'name')
2393+
FROM (
2394+
SELECT jsonb_array_elements(statistics) AS stat
2395+
FROM [SHOW STATISTICS USING JSON FOR TABLE xy]
2396+
)
2397+
WHERE stat->>'full_statistic_id' = '$statistics_id'
2398+
ORDER BY stat->>'name';
2399+
----
2400+
"xy_x_partial"
2401+
"xy_x_partial_2"
2402+
23662403
# Test null values.
23672404
statement ok
23682405
CREATE TABLE a_null (a INT, INDEX (a));

0 commit comments

Comments
 (0)