-
-
Save kjmph/5bd772b2c2df145aa645b837da7eca74 to your computer and use it in GitHub Desktop.
-- Based off IETF draft, https://datatracker.ietf.org/doc/draft-peabody-dispatch-new-uuid-format/ | |
create or replace function uuid_generate_v7() | |
returns uuid | |
as $$ | |
begin | |
-- use random v4 uuid as starting point (which has the same variant we need) | |
-- then overlay timestamp | |
-- then set version 7 by flipping the 2 and 1 bit in the version 4 string | |
return encode( | |
set_bit( | |
set_bit( | |
overlay(uuid_send(gen_random_uuid()) | |
placing substring(int8send(floor(extract(epoch from clock_timestamp()) * 1000)::bigint) from 3) | |
from 1 for 6 | |
), | |
52, 1 | |
), | |
53, 1 | |
), | |
'hex')::uuid; | |
end | |
$$ | |
language plpgsql | |
volatile; | |
-- Generate a custom UUID v8 with microsecond precision | |
create or replace function uuid_generate_v8() | |
returns uuid | |
as $$ | |
declare | |
timestamp timestamptz; | |
microseconds int; | |
begin | |
timestamp = clock_timestamp(); | |
microseconds = (cast(extract(microseconds from timestamp)::int - (floor(extract(milliseconds from timestamp))::int * 1000) as double precision) * 4.096)::int; | |
-- use random v4 uuid as starting point (which has the same variant we need) | |
-- then overlay timestamp | |
-- then set version 8 and add microseconds | |
return encode( | |
set_byte( | |
set_byte( | |
overlay(uuid_send(gen_random_uuid()) | |
placing substring(int8send(floor(extract(epoch from timestamp) * 1000)::bigint) from 3) | |
from 1 for 6 | |
), | |
6, (b'1000' || (microseconds >> 8)::bit(4))::bit(8)::int | |
), | |
7, microseconds::bit(8)::int | |
), | |
'hex')::uuid; | |
end | |
$$ | |
language plpgsql | |
volatile; |
PERFORMANCE: Move from pgcrypto to built-in gen_random_uuid(): | |
Curtis Summers (https://github.com/csummers) | |
PERFORMANCE: Use set_bit to upgrade v4 to v7, not set_byte: | |
PERFORMANCE: Reduce local variable use while still being maintainable | |
Rolf Timmermans (https://github.com/rolftimmermans) |
Copyright 2023 Kyle Hubert <kjmph@users.noreply.github.com> (https://github.com/kjmph) | |
Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the “Software”), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge, publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so, subject to the following conditions: | |
The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software. | |
THE SOFTWARE IS PROVIDED “AS IS”, WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. |
Thanks @dverite! You all are so great, this gist is amazing. Can I ask what everyone is using to benchmark? I'm running \timing
with this query:
$ select true from (select uuid_generate_v7() from generate_series(1, 1000000000)) a limit 1;
However, for this change I don't see a 13-15% improvement. Maybe I'm missing the inlining advantage. Could you, @dverite, please share what your benchmark is?
Hi @kjmph, I'm using select count(uuid_generate_v7()) from generate_series(1,1000000);
in psql with \timing on
On my desktop PC (Ubuntu 22..04, Postgres 15.4, AMD Ryzen 7 5800X3D), executing this query 4 consecutive times, I typically get these durations:
-
SQL version:
Time: 1667.722 ms (00:01.668)
Time: 1666.580 ms (00:01.667)
Time: 1662.223 ms (00:01.662)
Time: 1666.470 ms (00:01.666). -
plpgsql version:
Time: 2109.898 ms (00:02.110)
Time: 2087.937 ms (00:02.088)
Time: 2089.504 ms (00:02.090)
Time: 2090.521 ms (00:02.091)
On my laptop PC (Ubuntu 20.04, Postgres 15.4, Intel core I5-8265U), I get those:
-
SQL version:
Time: 2958,489 ms (00:02,958)
Time: 2969,462 ms (00:02,969)
Time: 2961,334 ms (00:02,961)
Time: 2971,450 ms (00:02,971) -
plpgsql version:
Time: 3587,606 ms (00:03,588)
Time: 3429,490 ms (00:03,429)
Time: 3379,035 ms (00:03,379)
Time: 3402,240 ms (00:03,402)
Great, thanks for sharing @dverite. It took a bit of digging, but it appears the SQL version of the function is more performant for a large number of invocations, and less performant for a small number of invocations. The cross-over on my machine is ~50 invocations. Thus, would you agree that the predominant use case is to insert a new record with an UUIDv7? If so, it seems better to bias towards the single invocation case and keep the current PL/pgSQL version.
Looking at the explain analyze output shows that the reason I wasn't seeing a performance improvement with my benchmark query was most likely because of the subquery scan with the limit. I see that the aggregate (count) performs better at those larger invocation counts.
If you want to try to reproduce, use the bench
function located at this site. Try executing:
$ select * from bench('select uuid_generate_v7_dverite()', 100000); -- the version posted by @dverite
$ select * from bench('select uuid_generate_v7_kjmph()', 100000); -- the version posted in the gist
$ select * from bench('select uuid_generate_v7_dverite() from generate_series(1, 10)', 50000);
$ select * from bench('select uuid_generate_v7_kjmph() from generate_series(1, 10)', 50000);
$ select * from bench('select uuid_generate_v7_dverite() from generate_series(1, 100)', 10000);
$ select * from bench('select uuid_generate_v7_kjmph() from generate_series(1, 100)', 10000);
If you prefer to work up an example query for a typical insert load, we can explore that as well.
Thoughts?
Ahh
No
The given uuidv7 implementations here are not sorted in my tests. Isn't uuidv7 supposed to be sorted?
Simply running following query and checking "generate_series" integer column reveals it.
select uuid_generate_v7(), generate_series from generate_series(1,200) order by uuid_generate_v7 asc
On the other hand the function from this gist works correct.
@ardabeyazoglu If you need that level of granularity you should use UUIDv8, which has microsecond precision. UUIDv7 uses milliseconds only. The functions given here easily generate 200 UUIDs within the same millisecond, which will cause UUIDv7s to be in random order with respect to each other.
@rolftimmermans I see. However, the one provided in gist i sent fulfils that level of granularity. It gives me 500 rows instantly and sorted. But, there is a slight performance drop comparing to this one.
@ardabeyazoglu I guess the function in your link does not implement UUIDv7 correctly (to the extent we can call any implementation of a draft RFC "correct"). There is an implementation of uuid_generate_v8()
given in this gist. I suggest using that; it's fast and has microsecond precision.
Edit: Seems like the draft RFC is changing the level of precision allowed in UUIDv7: https://www.ietf.org/archive/id/draft-ietf-uuidrev-rfc4122bis-14.html#name-uuid-version-7
Hello @ardabeyazoglu, it is a bit of a subtle answer. Earlier drafts of UUIDv7 contained sub-second precision bits in the format, that an implementation MAY use. UUIDv8 was for all custom usage that was implementation controlled. Current versions of the draft made UUIDv7 only for millisecond precision, and all sub-millisecond precision was moved to UUIDv8 for custom formats. The implementation attached to this draft for UUIDv7 conforms to the current drafts, while the UUIDv8 in this gist conforms to old UUIDv7 with microsecond precision.
The gist you linked to was an old UUIDv7 implementation with microsecond precision. If you want to compare apples to apples, please compare uuid_generate_v8
in this gist to the other implementation for performance analysis.
Note, uuid_generate_v7
in this gist is sorted in your example query. It is generating that many UUIDs per millisecond that they look unordered in the test query. As Rolf indicated.
Thanks @rolftimmermans for answering these questions, thought I would provide more color if this helpful.
Thanks for detailed clarification @kjmph, I also saw the difference after reading the codes carefully.
@kjmph, FYI
According to current RFC (was 4122 now it's RFC 9562 - Universally Unique IDentifiers (UUIDs) ):
uuidv7 may contain:
- An OPTIONAL sub-millisecond timestamp fraction (12 bits at maximum) as per Section 6.2 (Method 3).
IMHO, it's ok to fill rand_a
with 12 bit of microseconds in uuid v7
IMHO, it's ok to fill rand_a with 12 bit of microseconds in uuid v7
uuid_generate_uuidv7_with_us()
is wordy, but it's far from the worst function name I've seen. We could have both!
(We could also have both with an optional boolean argument. I suspect that would be a performance hit, but I spend more time in JS than Postgres, so I don't trust my instincts here.)
Hello everyone, thanks for pointing out the uuidv7 changes that specify the optional 12 bits now. However awkward this is, that's what I called uuidv8 in the function above. Back then I thought the uuidv8 name would make sense, since I added custom 12 bits to extend the millisecond precision to microsecond precision and the draft uuidv8 format was specified for custom implementations. Now that the new draft is out, this "custom" extension for a sub-millisecond timestamp fractions is now optional for uuidv7.
So, the above uuid_generate_v8()
function generates a format that looks like this layout:
0 1 2 3
0 1 2 3 4 5 6 7 8 9 0 1 2 3 4 5 6 7 8 9 0 1 2 3 4 5 6 7 8 9 0 1
+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+
| unix_ts_ms |
+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+
| unix_ts_ms | ver | unix_ts_us |
+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+
|var| rand_b |
+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+
| rand_b |
+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+-+
It happens to be that uuid_generate_uuidv7_with_us()
is a perfectly fine name, but I called it uuid_generate_uuidv8()
for historical reasons.
And just to be helpful, a reminder for everyone, I'm using time quantization and mapping the microseconds into 12 bits, so it is still monotonic without any wasted bits. It also happens to mean that the microseconds are approximate, because each discrete interval is ~0.244us (or 244140625 femtoseconds for fun!). Regardless of the details, the point is, I'm aware microseconds are 10bits and I'm properly handling that. :) I got you, open source community. [EDIT: To be clear, this is not my idea, it was specified in the original uuidv7 specification, and I just faithfully reproduced it.]
Glad this has been helpful.
Oh, and thanks for the correct link @vchirikov; I'm updating the header to reference the newer RFC 9562. Also, @jamesarosen, I think it is better to not conditionally generate values as this is highly tuned for performance. Use the uuiv8 function directly. I do the following in my tables, for instance:
row_id uuid primary key default uuid_generate_v8()
With regard to performance, once the function is reduced to a one-liner in the plpgsql language, it should be converted to the SQL language instead of plpgsql. This avoids the overhead of the plpsql interpreter. The contents of SQL functions are typically inlined into the calling query (see https://wiki.postgresql.org/wiki/Inlining_of_SQL_functions).
In a quick test generating 1 million values, with Postgres 15, the following version appears to be 13-15% faster than the plpgsql version:
Code: