├── .github └── workflows │ ├── ci.yml │ └── release.yml ├── .gitignore ├── LICENSE ├── META.json ├── Makefile ├── README.md ├── sequential_uuids--1.0--1.0.1.sql ├── sequential_uuids--1.0.1--1.0.2.sql ├── sequential_uuids--1.0.1.sql ├── sequential_uuids--1.0.2--1.0.3.sql ├── sequential_uuids.c ├── sequential_uuids.control └── test ├── expected └── uuids.out └── sql └── uuids.sql /.github/workflows/ci.yml: -------------------------------------------------------------------------------- 1 | name: make installcheck 2 | on: [push, pull_request] 3 | jobs: 4 | test: 5 | strategy: 6 | matrix: 7 | pg: [17, 16, 15, 14, 13, 12, 11, 10] 8 | name: PostgreSQL ${{ matrix.pg }} 9 | runs-on: ubuntu-latest 10 | container: pgxn/pgxn-tools 11 | steps: 12 | 13 | - name: Start PostgreSQL ${{ matrix.pg }} 14 | run: pg-start ${{ matrix.pg }} 15 | 16 | - name: Check out the repo 17 | uses: actions/checkout@v2 18 | 19 | - name: Test on PostgreSQL ${{ matrix.pg }} 20 | run: pg-build-test 21 | -------------------------------------------------------------------------------- /.github/workflows/release.yml: -------------------------------------------------------------------------------- 1 | name: Release 2 | on: 3 | push: 4 | tags: [v*] 5 | jobs: 6 | release: 7 | name: Release on GitHub and PGXN 8 | runs-on: ubuntu-latest 9 | container: pgxn/pgxn-tools 10 | env: 11 | GITHUB_TOKEN: ${{ secrets.GITHUB_TOKEN }} 12 | PGXN_USERNAME: ${{ secrets.PGXN_USERNAME }} 13 | PGXN_PASSWORD: ${{ secrets.PGXN_PASSWORD }} 14 | steps: 15 | - name: Check out the repo 16 | uses: actions/checkout@v4 17 | - name: Install required packages 18 | run: | 19 | sudo apt-get update 20 | sudo apt-get install -y libpq-dev 21 | sudo apt-get install -y postgresql-server-dev-all 22 | sudo apt-get install -y postgresql-common 23 | - name: Bundle the Release 24 | id: bundle 25 | run: pgxn-bundle 26 | - name: Release on PGXN 27 | run: pgxn-release 28 | - name: Generate Release Changes 29 | run: make latest-changes.md 30 | - name: Create GitHub Release 31 | id: release 32 | uses: actions/create-release@v1 33 | with: 34 | tag_name: ${{ github.ref }} 35 | release_name: Release ${{ github.ref }} 36 | body_path: latest-changes.md 37 | - name: Upload Release Asset 38 | uses: actions/upload-release-asset@v1 39 | with: 40 | upload_url: ${{ steps.release.outputs.upload_url }} 41 | asset_path: ./${{ steps.bundle.outputs.bundle }} 42 | asset_name: ${{ steps.bundle.outputs.bundle }} 43 | asset_content_type: application/zip 44 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | *.o 2 | *.so 3 | results/ 4 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2018 Tomas Vondra 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "sequential_uuids", 3 | "abstract": "UUID generators with sequential patterns, which helps to reduce random I/O patterns associated with regular entirely-random UUID.", 4 | "description": "Regular random UUIDs are distributed uniformly over the whole range of possible values. This results in poor locality when inserting data into indexes - all index leaf pages are equally likely to be hit, forcing the whole index into memory. With small indexes that's fine, but once the index size exceeds shared buffers (or RAM), the cache hit ratio quickly deteriorates. The main goal of the two generators implemented by this extension, is generating UUIDS in a more sequential pattern, but without reducing the randomness too much (which could increase the probability of collision and predictability of the generated UUIDs). This idea is not new, and is described as", 5 | "version": "1.0.3", 6 | "maintainer": "Tomas Vondra ", 7 | "license": "bsd", 8 | "prereqs": { 9 | "runtime": { 10 | "requires": { 11 | "PostgreSQL": "10.0.0" 12 | } 13 | } 14 | }, 15 | "provides": { 16 | "sequential_uuids": { 17 | "file": "sequential_uuids--1.0.2--1.0.3.sql", 18 | "docfile" : "README.md", 19 | "version": "1.0.3" 20 | } 21 | }, 22 | "resources": { 23 | "repository": { 24 | "url": "https://github.com/tvondra/sequential-uuids.git", 25 | "web": "http://github.com/tvondra/sequential-uuids", 26 | "type": "git" 27 | } 28 | }, 29 | "tags" : ["UUID", "generator"], 30 | "meta-spec": { 31 | "version": "1.0.0", 32 | "url": "http://pgxn.org/meta/spec.txt" 33 | }, 34 | "release_status" : "stable" 35 | } 36 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | # sequeantial_uuids/Makefile 2 | # 3 | # Copyright (c) 2018-2022 Tomas Vondra 4 | # 5 | 6 | MODULE_big = sequential_uuids 7 | 8 | OBJS = sequential_uuids.o 9 | 10 | EXTENSION = sequential_uuids 11 | DATA = sequential_uuids--1.0.1.sql sequential_uuids--1.0.1--1.0.2.sql sequential_uuids--1.0.2--1.0.3.sql 12 | 13 | TESTS = $(wildcard test/sql/*.sql) 14 | REGRESS = $(patsubst test/sql/%.sql,%,$(TESTS)) 15 | REGRESS_OPTS = --inputdir=test 16 | 17 | PG_CONFIG = pg_config 18 | PGXS := $(shell $(PG_CONFIG) --pgxs) 19 | include $(PGXS) 20 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | Sequential UUID generators 2 | ========================== 3 | 4 | [![make installcheck](https://github.com/tvondra/sequential-uuids/actions/workflows/ci.yml/badge.svg)](https://github.com/tvondra/sequential-uuids/actions/workflows/ci.yml) 5 | [![PGXN version](https://badge.fury.io/pg/sequential_uuids.svg)](https://badge.fury.io/pg/sequential_uuids) 6 | 7 | This PostgreSQL extension implements two UUID generators with sequential 8 | patterns, which helps to reduce random I/O patterns associated with 9 | regular entirely-random UUID. 10 | 11 | Regular random UUIDs are distributed uniformly over the whole range of 12 | possible values. This results in poor locality when inserting data into 13 | indexes - all index leaf pages are equally likely to be hit, forcing 14 | the whole index into memory. With small indexes that's fine, but once 15 | the index size exceeds shared buffers (or RAM), the cache hit ratio 16 | quickly deteriorates. 17 | 18 | Compare this to sequences and timestamps, which have a more sequential 19 | pattern and the new data almost always end up in the right-most part of 20 | the index (new sequence value is larger than all preceding values, same 21 | for timestamp). This results in a nicer and cache-friendlier behavior, 22 | but the values are predictable and may easily collide cross machines. 23 | 24 | The main goal of the two generators implemented by this extension, is 25 | generating UUIDS in a more sequential pattern, but without reducing the 26 | randomness too much (which could increase the probability of collision 27 | and predictability of the generated UUIDs). This idea is not new, and 28 | it's pretty much what the UUID wikipedia article [1] calls COMB 29 | (combined-time GUID) and is more more thoroughly explained in [2]. 30 | 31 | The benefits (performance, reduced amount of WAL, ...) are demonstrated 32 | in a blog post on 2ndQuadrant site [3]. 33 | 34 | 35 | Generators 36 | ---------- 37 | 38 | The extension provides two functions generating sequential UUIDs using 39 | either a sequence or timestamp. 40 | 41 | * `uuid_sequence_nextval(sequence regclass, block_size int default 65536, block_count int default 65536)` 42 | 43 | * `uuid_time_nextval(interval_length int default 60, interval_count int default 65536) RETURNS uuid` 44 | 45 | The default values for parameters are selected to work well for a range 46 | of workloads. See the next section explaining the design for additional 47 | information about the meaning of those parameters. 48 | 49 | 50 | Design 51 | ------ 52 | 53 | The easiest way to make UUIDs more sequential is to use some sequential 54 | value as a prefix. For example, we might take a sequence or a timestamp 55 | and add random data until we have 16B in total. The resulting values 56 | would be almost perfectly sequential, but there are two issues with it: 57 | 58 | * reduction of randomness - E.g. with a sequence producing bigint values 59 | this would reduce the randomness from 16B to 8B. Timestamps do reduce 60 | the randomness in a similar way, depending on the accuracy. This 61 | increases both the collision probability and predictability (e.g. it 62 | allows determining which UUIDs were generated close to each other, and 63 | perhaps the exact timestamp). 64 | 65 | * bloat - If the values only grow, this may result in bloat in indexes 66 | after deleting historical data. This is a well-known issue e.g. with 67 | indexes on timestamps in log tables. 68 | 69 | To address both of these issues, the implemented generators are designed 70 | to wrap-around regularly, either after generating a certain number of 71 | UUIDs or some amount of time. In both cases, the UUIDs are generates in 72 | blocks and have the form of 73 | 74 | (block ID; random data) 75 | 76 | The size of the block ID depends on the number of blocks and is fixed 77 | (depends on generator parameters). For example with the default 64k 78 | blocks we need 2 bytes to store it. The block ID increments regularly, 79 | and eventually wraps around. 80 | 81 | For sequence-based generators the block size is determined by the number 82 | of UUIDs generated. For example we may use blocks of 256 values, in 83 | which case the two-byte block ID may be computed like this: 84 | 85 | (nextval('s') / 256) % 65536 86 | 87 | So the generator wraps-around every ~16M UUIDs (because 256 * 65536). 88 | 89 | For timestamp-based generators, the block size is defined as interval 90 | length, with the default value 60 seconds. As the default number of 91 | blocks is 64k (same as for sequence-based generators), the block may be 92 | computed like this 93 | 94 | (timestamp / 60) % 65536 95 | 96 | Which means the generator wraps around every ~45 days. 97 | 98 | 99 | Supported Releases 100 | ------------------ 101 | 102 | Currently, this extension works only on releases since PostgreSQL 10. It 103 | can be made working on older releases with some minor code tweaks if 104 | someone wants to spend a bit of time on that. 105 | 106 | 107 | [1] https://en.wikipedia.org/wiki/Universally_unique_identifier 108 | 109 | [2] http://www.informit.com/articles/article.aspx?p=25862 110 | 111 | [3] https://www.2ndquadrant.com/en/blog/sequential-uuid-generators/ 112 | -------------------------------------------------------------------------------- /sequential_uuids--1.0--1.0.1.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/tvondra/sequential-uuids/13c9c172cc0f28852878ae5dad2a479057a219cd/sequential_uuids--1.0--1.0.1.sql -------------------------------------------------------------------------------- /sequential_uuids--1.0.1--1.0.2.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/tvondra/sequential-uuids/13c9c172cc0f28852878ae5dad2a479057a219cd/sequential_uuids--1.0.1--1.0.2.sql -------------------------------------------------------------------------------- /sequential_uuids--1.0.1.sql: -------------------------------------------------------------------------------- 1 | /* sequential_uuids.sql */ 2 | 3 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 4 | \echo Use "CREATE EXTENSION sequential_uuids" to load this file. \quit 5 | 6 | CREATE FUNCTION uuid_sequence_nextval(regclass, block_size int default 65536, block_count int default 65536) RETURNS uuid 7 | AS 'MODULE_PATHNAME', 'uuid_sequence_nextval' 8 | LANGUAGE C STRICT PARALLEL SAFE; 9 | 10 | CREATE FUNCTION uuid_time_nextval(interval_length int default 60, interval_count int default 65536) RETURNS uuid 11 | AS 'MODULE_PATHNAME', 'uuid_time_nextval' 12 | LANGUAGE C STRICT PARALLEL SAFE; 13 | -------------------------------------------------------------------------------- /sequential_uuids--1.0.2--1.0.3.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/tvondra/sequential-uuids/13c9c172cc0f28852878ae5dad2a479057a219cd/sequential_uuids--1.0.2--1.0.3.sql -------------------------------------------------------------------------------- /sequential_uuids.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * sequential_uuids.c 4 | * generators of sequential UUID values based on sequence/timestamp 5 | * 6 | * 7 | * Currently, this only works on PostgreSQL 10. Adding support for older 8 | * releases is possible, but it would require solving a couple issues: 9 | * 10 | * 1) pg_uuid_t hidden in uuid.c (can be solved by local struct definition) 11 | * 12 | * 2) pg_strong_random not available (can fallback to random, probably) 13 | * 14 | * 3) functions defined as PARALLEL SAFE, which fails on pre-9.6 releases 15 | * 16 | *------------------------------------------------------------------------- 17 | */ 18 | #include 19 | #include 20 | #include 21 | #include 22 | 23 | #include "postgres.h" 24 | 25 | #include "catalog/namespace.h" 26 | #include "commands/sequence.h" 27 | #include "utils/uuid.h" 28 | 29 | PG_MODULE_MAGIC; 30 | 31 | PG_FUNCTION_INFO_V1(uuid_sequence_nextval); 32 | PG_FUNCTION_INFO_V1(uuid_time_nextval); 33 | 34 | static Datum 35 | sequential_uuid(int64 val, int32 block_size, int32 block_count) 36 | { 37 | pg_uuid_t *uuid = palloc(sizeof(pg_uuid_t)); 38 | unsigned char *p; 39 | int prefix_bits; 40 | int prefix_count; 41 | int i; 42 | uint64 tmp; 43 | unsigned char *mask = (unsigned char *) &tmp; 44 | uint64 wrap_size; 45 | 46 | /* generate random bytes (use strong generator) */ 47 | if(!pg_strong_random(uuid->data, UUID_LEN)) 48 | ereport(ERROR, 49 | (errcode(ERRCODE_INTERNAL_ERROR), 50 | errmsg("could not generate random values"))); 51 | 52 | /* count the number of bits to keep from the value */ 53 | prefix_bits = 1; 54 | prefix_count = 2; 55 | while (block_count > prefix_count) 56 | { 57 | prefix_bits++; 58 | prefix_count *= 2; 59 | } 60 | 61 | /* make sure the prefix is a multiple of whole bytes */ 62 | prefix_bits = ((prefix_bits + 7) / 8) * 8; 63 | 64 | /* calculate the number of blocks for the rounded prefix bits */ 65 | prefix_count = 1; 66 | for (i = 0; i < prefix_bits; i++) 67 | prefix_count *= 2; 68 | 69 | /* 70 | * Recalculate the block size, using the prefix_count instead of the 71 | * original block_count. 72 | */ 73 | wrap_size = (int64) block_size * block_count; 74 | block_size = Max(1, wrap_size / prefix_count); 75 | 76 | /* determine in which block the value belongs */ 77 | val = (val / block_size); 78 | 79 | /* cap the number of blocks to the desired number of blocks */ 80 | val = val & (0xFFFFFFFFFFFFFFFF >> (64 - prefix_bits)); 81 | val = (val << (64 - prefix_bits)); 82 | 83 | /* 84 | * Calculate the mask (to zero the random bits when copying the 85 | * prefix bytes). 86 | */ 87 | tmp = (0xFFFFFFFFFFFFFFFF >> prefix_bits); 88 | 89 | /* easier to deal with big endian byte order */ 90 | val = htobe64(val); 91 | tmp = htobe64(tmp); 92 | 93 | /* 94 | * Copy the prefix in. We already have random data, so use the mask 95 | * to zero the bits first. 96 | */ 97 | p = (unsigned char *) &val; 98 | for (i = 0; i < 8; i++) 99 | uuid->data[i] = (uuid->data[i] & mask[i]) | p[i]; 100 | 101 | /* 102 | * Set the UUID version flags according to "version 4" (pseudorandom) 103 | * UUID, see http://tools.ietf.org/html/rfc4122#section-4.4 104 | * 105 | * This does reduce the randomness a bit, because it determines the 106 | * value of certain bits, but that should be negligible (certainly 107 | * compared to the reduction due to prefix). 108 | * 109 | * UUID v4 is probably the safest choice here. There is v1 which is 110 | * time-based, but it includes MAC address (which we don't use) and 111 | * works with very special timestamp (starting at 1582 etc.). So we 112 | * just use v4 and claim this is pseudorandom. 113 | */ 114 | uuid->data[6] = (uuid->data[6] & 0x0f) | 0x40; /* time_hi_and_version */ 115 | uuid->data[8] = (uuid->data[8] & 0x3f) | 0x80; /* clock_seq_hi_and_reserved */ 116 | 117 | PG_RETURN_UUID_P(uuid); 118 | } 119 | 120 | /* 121 | * uuid_sequence_nextval 122 | * generate sequential UUID using a sequence 123 | * 124 | * The sequence-based sequential UUID generator define the group size 125 | * and group count based on number of UUIDs generated. 126 | * 127 | * The block_size (65546 by default) determines the number of UUIDs with 128 | * the same prefix, and block_count (65536 by default) determines the 129 | * number of blocks before wrapping around to 0. This means that with 130 | * the default values, the generator wraps around every ~4B UUIDs. 131 | * 132 | * You may increase (or rather decrease) the parameters if needed, e.g, 133 | * by lowering the block size to 256, in wich case the cycle interval 134 | * is only 16M values. 135 | */ 136 | Datum 137 | uuid_sequence_nextval(PG_FUNCTION_ARGS) 138 | { 139 | Oid relid = PG_GETARG_OID(0); 140 | int32 block_size = PG_GETARG_INT32(1); 141 | int32 block_count = PG_GETARG_INT32(2); 142 | 143 | /* some basic sanity checks */ 144 | if (block_size < 1) 145 | ereport(ERROR, 146 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 147 | errmsg("block size must be a positive integer"))); 148 | 149 | if (block_count < 1) 150 | ereport(ERROR, 151 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 152 | errmsg("number of blocks must be a positive integer"))); 153 | 154 | /* 155 | * Read the next value from the sequence and get rid of the least 156 | * significant bytes. Subtract one, because sequences start at 1. 157 | */ 158 | return sequential_uuid( 159 | /* Create sequential uuid using next value of sequence */ 160 | nextval_internal(relid, true) - 1, 161 | block_size, 162 | block_count); 163 | } 164 | 165 | /* 166 | * uuid_time_nextval 167 | * generate sequential UUID using current time 168 | * 169 | * The timestamp-based sequential UUID generator define the group size 170 | * and group count based on data extracted from current timestamp. 171 | * 172 | * The interval_length (60 seconds by default) is defined as number of 173 | * seconds where UUIDs share the same prefix). The prefix length is 174 | * determined by the number of intervals (65536 by default, i.e. 2B). 175 | * With these parameters the generator wraps around every ~45 days. 176 | */ 177 | Datum 178 | uuid_time_nextval(PG_FUNCTION_ARGS) 179 | { 180 | struct timeval tv; 181 | int32 interval_length = PG_GETARG_INT32(0); 182 | int32 interval_count = PG_GETARG_INT32(1); 183 | 184 | /* some basic sanity checks */ 185 | if (interval_length < 1) 186 | ereport(ERROR, 187 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 188 | errmsg("length of interval must be a positive integer"))); 189 | 190 | if (interval_count < 1) 191 | ereport(ERROR, 192 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 193 | errmsg("number of intervals must be a positive integer"))); 194 | 195 | if (gettimeofday(&tv, NULL) != 0) 196 | elog(ERROR, "gettimeofday call failed"); 197 | 198 | /* Create sequential uuid using current time in seconds */ 199 | return sequential_uuid( 200 | tv.tv_sec, 201 | interval_length, 202 | interval_count); 203 | } 204 | -------------------------------------------------------------------------------- /sequential_uuids.control: -------------------------------------------------------------------------------- 1 | # sequential UUID generators 2 | comment = 'generator of sequential UUIDs' 3 | default_version = '1.0.3' 4 | module_pathname = '$libdir/sequential_uuids' 5 | relocatable = true 6 | -------------------------------------------------------------------------------- /test/expected/uuids.out: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION sequential_uuids; 2 | -- uuid_sequence_nextval 3 | CREATE SEQUENCE s; 4 | -- invalid block size 5 | SELECT uuid_sequence_nextval('s'::regclass, 0, 1); 6 | ERROR: block size must be a positive integer 7 | SELECT uuid_sequence_nextval('s'::regclass, -1, 1); 8 | ERROR: block size must be a positive integer 9 | -- invalid block count 10 | SELECT uuid_sequence_nextval('s'::regclass, 1, 0); 11 | ERROR: number of blocks must be a positive integer 12 | SELECT uuid_sequence_nextval('s'::regclass, 1, -1); 13 | ERROR: number of blocks must be a positive integer 14 | CREATE TABLE uuid_tmp AS SELECT uuid_sequence_nextval('s'::regclass, 256, 65536)::text AS val FROM generate_series(1,10000) s(i); 15 | -- there should be 10k distinct UUID values (collisions unlikely) 16 | SELECT COUNT(DISTINCT val) FROM uuid_tmp; 17 | count 18 | ------- 19 | 10000 20 | (1 row) 21 | 22 | -- there should be 40 blocks (each up to 256 values) 23 | SELECT COUNT(DISTINCT substring(val, 1, 4)) FROM uuid_tmp; 24 | count 25 | ------- 26 | 40 27 | (1 row) 28 | 29 | -- there should be two blocks that are not exactly 256 values - the first one 30 | -- (because sequences start at 1) and the last one (not fully generated yet) 31 | WITH x AS (SELECT substring(val, 1, 4) AS block, count(*) AS cnt FROM uuid_tmp GROUP BY 1) 32 | SELECT * FROM x WHERE cnt != 256; 33 | block | cnt 34 | -------+----- 35 | 0027 | 16 36 | (1 row) 37 | 38 | DROP SEQUENCE s; 39 | DROP TABLE uuid_tmp; 40 | -- try with a larger block 41 | CREATE SEQUENCE s; 42 | CREATE TABLE uuid_tmp AS SELECT uuid_sequence_nextval('s'::regclass, 65536, 256)::text AS val FROM generate_series(1,200000) s(i); 43 | -- there should be 200k distinct UUID values (collisions unlikely) 44 | SELECT COUNT(DISTINCT val) FROM uuid_tmp; 45 | count 46 | -------- 47 | 200000 48 | (1 row) 49 | 50 | -- there should be 4 blocks (each up to 65536 values) 51 | SELECT COUNT(DISTINCT substring(val, 1, 2)) FROM uuid_tmp; 52 | count 53 | ------- 54 | 4 55 | (1 row) 56 | 57 | -- there should be two blocks that are not exactly 256 values - the first one 58 | -- (because sequences start at 1) and the last one (not fully generated yet) 59 | SELECT substring(val, 1, 2) AS block, count(*) AS cnt FROM uuid_tmp GROUP BY 1; 60 | block | cnt 61 | -------+------- 62 | 00 | 65536 63 | 01 | 65536 64 | 02 | 65536 65 | 03 | 3392 66 | (4 rows) 67 | 68 | DROP SEQUENCE s; 69 | DROP TABLE uuid_tmp; 70 | -- try with tiny block, to make sure we generate prefix correctly 71 | CREATE SEQUENCE s; 72 | CREATE TABLE uuid_tmp AS SELECT uuid_sequence_nextval('s'::regclass, 100, 100)::text AS val FROM generate_series(1,1000) s(i); 73 | -- there should be 200k distinct UUID values (collisions unlikely) 74 | SELECT COUNT(DISTINCT val) FROM uuid_tmp; 75 | count 76 | ------- 77 | 1000 78 | (1 row) 79 | 80 | -- there should be 4 blocks (each up to 65536 values) 81 | SELECT COUNT(DISTINCT substring(val, 1, 2)) FROM uuid_tmp; 82 | count 83 | ------- 84 | 26 85 | (1 row) 86 | 87 | -- there should be two blocks that are not exactly 256 values - the first one 88 | -- (because sequences start at 1) and the last one (not fully generated yet) 89 | SELECT substring(val, 1, 2) AS block, count(*) AS cnt FROM uuid_tmp GROUP BY 1 ORDER BY 1; 90 | block | cnt 91 | -------+----- 92 | 00 | 39 93 | 01 | 39 94 | 02 | 39 95 | 03 | 39 96 | 04 | 39 97 | 05 | 39 98 | 06 | 39 99 | 07 | 39 100 | 08 | 39 101 | 09 | 39 102 | 0a | 39 103 | 0b | 39 104 | 0c | 39 105 | 0d | 39 106 | 0e | 39 107 | 0f | 39 108 | 10 | 39 109 | 11 | 39 110 | 12 | 39 111 | 13 | 39 112 | 14 | 39 113 | 15 | 39 114 | 16 | 39 115 | 17 | 39 116 | 18 | 39 117 | 19 | 25 118 | (26 rows) 119 | 120 | DROP SEQUENCE s; 121 | DROP TABLE uuid_tmp; 122 | -- try wrapping the block count 123 | CREATE SEQUENCE s; 124 | CREATE TABLE uuid_tmp AS SELECT uuid_sequence_nextval('s'::regclass, 256, 256)::text AS val FROM generate_series(1,67000) s(i); 125 | -- there should be 256 blocks 126 | WITH x AS (SELECT substring(val, 1, 2) AS block, count(*) AS cnt FROM uuid_tmp GROUP BY 1 ORDER BY 1) 127 | SELECT * FROM x WHERE cnt != 256; 128 | block | cnt 129 | -------+----- 130 | 00 | 512 131 | 01 | 512 132 | 02 | 512 133 | 03 | 512 134 | 04 | 512 135 | 05 | 440 136 | (6 rows) 137 | 138 | DROP SEQUENCE s; 139 | DROP TABLE uuid_tmp; 140 | -- uuid_time_nextval 141 | CREATE TABLE uuid_tmp (val text); 142 | INSERT INTO uuid_tmp SELECT uuid_time_nextval(1, 256); 143 | SELECT pg_sleep(2); 144 | pg_sleep 145 | ---------- 146 | 147 | (1 row) 148 | 149 | INSERT INTO uuid_tmp SELECT uuid_time_nextval(1, 256); 150 | SELECT COUNT(DISTINCT substring(val, 1, 2)) FROM uuid_tmp; 151 | count 152 | ------- 153 | 2 154 | (1 row) 155 | 156 | DROP TABLE uuid_tmp; 157 | -------------------------------------------------------------------------------- /test/sql/uuids.sql: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION sequential_uuids; 2 | 3 | -- uuid_sequence_nextval 4 | 5 | CREATE SEQUENCE s; 6 | 7 | -- invalid block size 8 | SELECT uuid_sequence_nextval('s'::regclass, 0, 1); 9 | SELECT uuid_sequence_nextval('s'::regclass, -1, 1); 10 | 11 | -- invalid block count 12 | SELECT uuid_sequence_nextval('s'::regclass, 1, 0); 13 | SELECT uuid_sequence_nextval('s'::regclass, 1, -1); 14 | 15 | CREATE TABLE uuid_tmp AS SELECT uuid_sequence_nextval('s'::regclass, 256, 65536)::text AS val FROM generate_series(1,10000) s(i); 16 | 17 | -- there should be 10k distinct UUID values (collisions unlikely) 18 | SELECT COUNT(DISTINCT val) FROM uuid_tmp; 19 | 20 | -- there should be 40 blocks (each up to 256 values) 21 | SELECT COUNT(DISTINCT substring(val, 1, 4)) FROM uuid_tmp; 22 | 23 | -- there should be two blocks that are not exactly 256 values - the first one 24 | -- (because sequences start at 1) and the last one (not fully generated yet) 25 | WITH x AS (SELECT substring(val, 1, 4) AS block, count(*) AS cnt FROM uuid_tmp GROUP BY 1) 26 | SELECT * FROM x WHERE cnt != 256; 27 | 28 | DROP SEQUENCE s; 29 | DROP TABLE uuid_tmp; 30 | 31 | -- try with a larger block 32 | CREATE SEQUENCE s; 33 | 34 | CREATE TABLE uuid_tmp AS SELECT uuid_sequence_nextval('s'::regclass, 65536, 256)::text AS val FROM generate_series(1,200000) s(i); 35 | 36 | -- there should be 200k distinct UUID values (collisions unlikely) 37 | SELECT COUNT(DISTINCT val) FROM uuid_tmp; 38 | 39 | -- there should be 4 blocks (each up to 65536 values) 40 | SELECT COUNT(DISTINCT substring(val, 1, 2)) FROM uuid_tmp; 41 | 42 | -- there should be two blocks that are not exactly 256 values - the first one 43 | -- (because sequences start at 1) and the last one (not fully generated yet) 44 | SELECT substring(val, 1, 2) AS block, count(*) AS cnt FROM uuid_tmp GROUP BY 1; 45 | 46 | DROP SEQUENCE s; 47 | DROP TABLE uuid_tmp; 48 | 49 | -- try with tiny block, to make sure we generate prefix correctly 50 | CREATE SEQUENCE s; 51 | 52 | CREATE TABLE uuid_tmp AS SELECT uuid_sequence_nextval('s'::regclass, 100, 100)::text AS val FROM generate_series(1,1000) s(i); 53 | 54 | -- there should be 200k distinct UUID values (collisions unlikely) 55 | SELECT COUNT(DISTINCT val) FROM uuid_tmp; 56 | 57 | -- there should be 4 blocks (each up to 65536 values) 58 | SELECT COUNT(DISTINCT substring(val, 1, 2)) FROM uuid_tmp; 59 | 60 | -- there should be two blocks that are not exactly 256 values - the first one 61 | -- (because sequences start at 1) and the last one (not fully generated yet) 62 | SELECT substring(val, 1, 2) AS block, count(*) AS cnt FROM uuid_tmp GROUP BY 1 ORDER BY 1; 63 | 64 | DROP SEQUENCE s; 65 | DROP TABLE uuid_tmp; 66 | 67 | 68 | -- try wrapping the block count 69 | CREATE SEQUENCE s; 70 | CREATE TABLE uuid_tmp AS SELECT uuid_sequence_nextval('s'::regclass, 256, 256)::text AS val FROM generate_series(1,67000) s(i); 71 | 72 | -- there should be 256 blocks 73 | WITH x AS (SELECT substring(val, 1, 2) AS block, count(*) AS cnt FROM uuid_tmp GROUP BY 1 ORDER BY 1) 74 | SELECT * FROM x WHERE cnt != 256; 75 | 76 | DROP SEQUENCE s; 77 | DROP TABLE uuid_tmp; 78 | 79 | -- uuid_time_nextval 80 | 81 | CREATE TABLE uuid_tmp (val text); 82 | 83 | INSERT INTO uuid_tmp SELECT uuid_time_nextval(1, 256); 84 | SELECT pg_sleep(2); 85 | INSERT INTO uuid_tmp SELECT uuid_time_nextval(1, 256); 86 | 87 | SELECT COUNT(DISTINCT substring(val, 1, 2)) FROM uuid_tmp; 88 | 89 | DROP TABLE uuid_tmp; 90 | --------------------------------------------------------------------------------