Skip to content

Add UUID examples from blog post #20

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Draft
wants to merge 3 commits into
base: main
Choose a base branch
from
Draft
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
16 changes: 16 additions & 0 deletions uuid_experiments/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
# UUID Experiments

- UUID v7 extension
<https://pgxn.org/dist/pg_uuidv7/>

- enable pg_prewarm

```sh
# needs libpq, make sure it's using Postgres.app version
make
make install
create extension pg_uuidv7;
```

- Reproduce results here:
<https://www.cybertec-postgresql.com/en/unexpected-downsides-of-uuid-keys-in-postgresql/>
19 changes: 19 additions & 0 deletions uuid_experiments/create_indexes.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
\timing on

create index on records (id); -- records_id_idx
create index on records (uuid_v4); -- records_uuid_v4_idx
create index on records (uuid_v7); -- records_uuid_v7_idx
vacuum analyze records;

SELECT
relname,
pg_size_pretty(pg_relation_size(oid)),
pg_prewarm (oid)
FROM
pg_class
WHERE
relname LIKE 'records%';


EXPLAIN (BUFFERS, ANALYZE, TIMING OFF) SELECT COUNT(id) FROM records;
EXPLAIN (BUFFERS, ANALYZE, TIMING OFF) SELECT COUNT(uuid_v4) FROM records;
31 changes: 31 additions & 0 deletions uuid_experiments/create_tables.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,31 @@
CREATE TABLE records (
id int8 NOT NULL,
uuid_v4 uuid NOT NULL,
uuid_v7 uuid NOT NULL,
filler text
);

-- 10 million inserts
INSERT INTO records
SELECT
id,
gen_random_uuid(),
uuid_generate_v7(),
repeat(' ', 100)
FROM
generate_series(1, 10000000) id;

-- 1 million updates
CREATE TEMP TABLE update_ids AS
SELECT id
FROM generate_series(1, 10000000) id
ORDER BY random()
LIMIT 1000000;

-- Perform the updates on uuid_v4 and uuid_v7 columns (and filler text)
UPDATE records
SET
uuid_v4 = gen_random_uuid(),
uuid_v7 = uuid_generate_v7(),
filler = repeat('x', 100)
WHERE id IN (SELECT id FROM update_ids);
48 changes: 48 additions & 0 deletions uuid_experiments/leaf_pages.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,48 @@
-- number of leaf pages
WITH index_info AS (
SELECT 'records_id_idx'::text AS idxname
UNION ALL
SELECT 'records_uuid_v4_idx'
UNION ALL
SELECT 'records_uuid_v7_idx'
),
page_counts AS (
SELECT
idxname,
pg_relation_size(idxname) / 8192 AS num_pages
FROM index_info
),
all_pages AS (
SELECT
idxname,
generate_series(1, num_pages - 1) AS blkno
FROM page_counts
),
page_stats AS (
SELECT
idxname,
(bt_page_stats(idxname, blkno)).*
FROM all_pages
)
SELECT
idxname,
COUNT(*) FILTER (WHERE type = 'l') AS leaf_pages,
COUNT(*) FILTER (WHERE type = 'd') AS internal_pages
FROM page_stats
GROUP BY idxname
ORDER BY idxname;

-- idxname | leaf_pages | internal_pages
-- ---------------------+------------+----------------
-- records_id_idx | 27323 | 0
-- records_uuid_v4_idx | 38315 | 0
-- records_uuid_v7_idx | 38315 | 0


-- AFTER updates
-- idxname | leaf_pages | internal_pages
-- ---------------------+------------+----------------
-- records_id_idx | 27589 | 0
-- records_uuid_v4_idx | 48093 | 0
-- records_uuid_v7_idx | 42146 | 0
-- (3 rows)
56 changes: 56 additions & 0 deletions uuid_experiments/page_density.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,56 @@
create extension if not exists pageinspect;

-- average leaf density
WITH index_info AS (
SELECT 'records_id_idx'::text AS idxname
UNION ALL
SELECT 'records_uuid_v4_idx'::text
UNION ALL
SELECT 'records_uuid_v7_idx'::text
),
page_counts AS (
SELECT
idxname,
pg_relation_size(idxname) / 8192 AS num_pages -- number of 8KB pages
FROM index_info
),
all_pages AS (
SELECT
idxname,
generate_series(1, num_pages - 1) AS blkno
FROM page_counts
),
page_stats AS (
SELECT
idxname,
(bt_page_stats(idxname, blkno)).*
FROM all_pages
),
leaf_pages AS (
SELECT
idxname,
100 - (free_size::float / 8192 * 100) AS fill_percent
FROM page_stats
WHERE type = 'l'
)
SELECT
idxname,
ROUND(AVG(fill_percent)::numeric, 2) AS avg_leaf_fill_percent
FROM leaf_pages
GROUP BY idxname;

-- After updates
-- idxname | avg_leaf_fill_percent
-- ---------------------+-----------------------
-- records_id_idx | 97.64
-- records_uuid_v4_idx | 79.06
-- records_uuid_v7_idx | 90.09
-- (3 rows)
--
-- v4
-- ⚠️ Implication:
--
-- Write amplification is high
-- Index bloat will grow steadily over time
-- You will eventually need a REINDEX or pg_repack to reclaim wasted space
-- Poorer cache locality and lookup performance may follow