diff --git a/docs/generated/settings/settings.html b/docs/generated/settings/settings.html
index 81c75d1ecda7..b455d8e00a45 100644
--- a/docs/generated/settings/settings.html
+++ b/docs/generated/settings/settings.html
@@ -70,7 +70,7 @@
sql.defaults.default_int_size | integer | 8 | the size, in bytes, of an INT type |
sql.defaults.disallow_full_table_scans.enabled | boolean | false | setting to true rejects queries that have planned a full table scan |
sql.defaults.results_buffer.size | byte size | 16 KiB | default size of the buffer that accumulates results for a statement or a batch of statements before they are sent to the client. This can be overridden on an individual connection with the 'results_buffer_size' parameter. Note that auto-retries generally only happen while no results have been delivered to the client, so reducing this size can increase the number of retriable errors a client receives. On the other hand, increasing the buffer size can increase the delay until the client receives the first result row. Updating the setting only affects new connections. Setting to 0 disables any buffering. |
-sql.defaults.serial_normalization | enumeration | rowid | default handling of SERIAL in table definitions [rowid = 0, virtual_sequence = 1, sql_sequence = 2] |
+sql.defaults.serial_normalization | enumeration | rowid | default handling of SERIAL in table definitions [rowid = 0, virtual_sequence = 1, sql_sequence = 2, sql_sequence_cached = 3] |
sql.distsql.max_running_flows | integer | 500 | maximum number of concurrent flows that can be run on a node |
sql.log.slow_query.experimental_full_table_scans.enabled | boolean | false | when set to true, statements that perform a full table/index scan will be logged to the slow query log even if they do not meet the latency threshold. Must have the slow query log enabled for this setting to have any effect. |
sql.log.slow_query.internal_queries.enabled | boolean | false | when set to true, internal queries which exceed the slow query log threshold are logged to a separate log. Must have the slow query log enabled for this setting to have any effect. |
diff --git a/pkg/sql/exec_util.go b/pkg/sql/exec_util.go
index f047bd7fb4f1..12d282f83b21 100644
--- a/pkg/sql/exec_util.go
+++ b/pkg/sql/exec_util.go
@@ -401,9 +401,10 @@ var SerialNormalizationMode = settings.RegisterEnumSetting(
"default handling of SERIAL in table definitions",
"rowid",
map[int64]string{
- int64(sessiondata.SerialUsesRowID): "rowid",
- int64(sessiondata.SerialUsesVirtualSequences): "virtual_sequence",
- int64(sessiondata.SerialUsesSQLSequences): "sql_sequence",
+ int64(sessiondata.SerialUsesRowID): "rowid",
+ int64(sessiondata.SerialUsesVirtualSequences): "virtual_sequence",
+ int64(sessiondata.SerialUsesSQLSequences): "sql_sequence",
+ int64(sessiondata.SerialUsesCachedSQLSequences): "sql_sequence_cached",
},
).WithPublic()
diff --git a/pkg/sql/logictest/testdata/logic_test/serial b/pkg/sql/logictest/testdata/logic_test/serial
index 2776d40b668b..5d07ecf8a9c0 100644
--- a/pkg/sql/logictest/testdata/logic_test/serial
+++ b/pkg/sql/logictest/testdata/logic_test/serial
@@ -335,3 +335,47 @@ SELECT count(DISTINCT a), count(DISTINCT b), count(DISTINCT c) FROM serials
statement ok
DROP TABLE serials, smallbig, serial
+
+# Verify that the sequence gets incremented to the default cache
+# size of 256 and that serial values increase by 1 each time.
+subtest serial_cached_sequence
+
+statement ok
+SET serial_normalization = sql_sequence_cached
+
+statement ok
+CREATE TABLE serial (
+ cached SERIAL
+);
+
+statement ok
+INSERT INTO serial (cached) VALUES (DEFAULT);
+
+query I
+SELECT cached from serial;
+----
+1
+
+query T
+SELECT pg_get_serial_sequence('serial', 'cached')
+----
+public.serial_cached_seq
+
+query I
+SELECT last_value from public.serial_cached_seq;
+----
+256
+
+statement ok
+INSERT INTO serial (cached) VALUES (DEFAULT);
+
+query I
+SELECT cached from serial ORDER BY cached;
+----
+1
+2
+
+query I
+SELECT last_value from public.serial_cached_seq;
+----
+256
diff --git a/pkg/sql/serial.go b/pkg/sql/serial.go
index 17b2b34dffba..3f446f31209e 100644
--- a/pkg/sql/serial.go
+++ b/pkg/sql/serial.go
@@ -40,6 +40,16 @@ var virtualSequenceOpts = tree.SequenceOptions{
tree.SequenceOption{Name: tree.SeqOptVirtual},
}
+// cachedSequencesCacheSize is the default cache size used when
+// SessionNormalizationMode is SerialUsesCachedSQLSequences.
+var cachedSequencesCacheSize int64 = 256
+
+// cachedSequenceOpts is used when SessionNormalizationMode is
+// SerialUsesCachedSQLSequences.
+var cachedSequenceOpts = tree.SequenceOptions{
+ tree.SequenceOption{Name: tree.SeqOptCache, IntVal: &cachedSequencesCacheSize},
+}
+
// processSerialInColumnDef analyzes a column definition and determines
// whether to use a sequence if the requested type is SERIAL-like.
// If a sequence must be created, it returns an TableName to use
@@ -84,7 +94,7 @@ func (p *planner) processSerialInColumnDef(
// switch this behavior around.
newSpec.Type = types.Int
- case sessiondata.SerialUsesSQLSequences:
+ case sessiondata.SerialUsesSQLSequences, sessiondata.SerialUsesCachedSQLSequences:
// With real sequences we can use the requested type as-is.
default:
@@ -154,6 +164,9 @@ func (p *planner) processSerialInColumnDef(
if serialNormalizationMode == sessiondata.SerialUsesVirtualSequences {
seqType = "virtual "
seqOpts = virtualSequenceOpts
+ } else if serialNormalizationMode == sessiondata.SerialUsesCachedSQLSequences {
+ seqType = "cached "
+ seqOpts = cachedSequenceOpts
}
log.VEventf(ctx, 2, "new column %q of %q will have %s sequence name %q and default %q",
d, tableName, seqType, seqName, defaultExpr)
diff --git a/pkg/sql/sessiondata/session_data.go b/pkg/sql/sessiondata/session_data.go
index 8d0257a00168..815b2c9ad475 100644
--- a/pkg/sql/sessiondata/session_data.go
+++ b/pkg/sql/sessiondata/session_data.go
@@ -373,8 +373,18 @@ const (
// use INT NOT NULL DEFAULT nextval(...).
SerialUsesVirtualSequences
// SerialUsesSQLSequences means create a regular SQL sequence and
- // use INT NOT NULL DEFAULT nextval(...).
+ // use INT NOT NULL DEFAULT nextval(...). Each call to nextval()
+ // is a distributed call to kv. This minimizes the size of gaps
+ // between successive sequence numbers (which occur due to
+ // node failures or errors), but the multiple kv calls
+ // can impact performance negatively.
SerialUsesSQLSequences
+ // SerialUsesCachedSQLSequences is identical to SerialUsesSQLSequences with
+ // the exception that nodes can cache sequence values. This significantly
+ // reduces contention and distributed calls to kv, which results in better
+ // performance. Gaps between sequences may be larger as a result of cached
+ // values being lost to errors and/or node failures.
+ SerialUsesCachedSQLSequences
)
func (m SerialNormalizationMode) String() string {
@@ -385,6 +395,8 @@ func (m SerialNormalizationMode) String() string {
return "virtual_sequence"
case SerialUsesSQLSequences:
return "sql_sequence"
+ case SerialUsesCachedSQLSequences:
+ return "sql_sequence_cached"
default:
return fmt.Sprintf("invalid (%d)", m)
}
@@ -399,6 +411,8 @@ func SerialNormalizationModeFromString(val string) (_ SerialNormalizationMode, o
return SerialUsesVirtualSequences, true
case "SQL_SEQUENCE":
return SerialUsesSQLSequences, true
+ case "SQL_SEQUENCE_CACHED":
+ return SerialUsesCachedSQLSequences, true
default:
return 0, false
}