Skip to content

Commit 65704d5

Browse files
authored
Merge pull request #311 from seattleflu/barcode-minting
Add `mint_identifiers` function to improve performance
2 parents 97af847 + d153561 commit 65704d5

File tree

11 files changed

+196
-41
lines changed

11 files changed

+196
-41
lines changed

lib/id3c/db/__init__.py

Lines changed: 15 additions & 30 deletions
Original file line numberDiff line numberDiff line change
@@ -4,6 +4,7 @@
44
import logging
55
import secrets
66
import statistics
7+
import json
78
from datetime import datetime
89
from psycopg2 import IntegrityError
910
from psycopg2.errors import ExclusionViolation
@@ -41,7 +42,6 @@ def mint_identifiers(session: DatabaseSession, name: str, n: int) -> Any:
4142
`permission denied` error.
4243
"""
4344
minted: List[Any] = []
44-
failures: Dict[int, int] = {}
4545

4646
# Lookup identifier set by name
4747
identifier_set = session.fetch_row("""
@@ -54,39 +54,24 @@ def mint_identifiers(session: DatabaseSession, name: str, n: int) -> Any:
5454
LOG.error(f"Identifier set «{name}» does not exist")
5555
raise IdentifierSetNotFoundError(name)
5656

57-
started = datetime.now()
57+
minted = session.fetch_all("""
58+
select uuid, barcode, identifier_set_id, generated
59+
from mint_identifiers(%s, %s)
60+
""", (identifier_set.id, n))
5861

59-
while len(minted) < n:
60-
m = len(minted) + 1
62+
LOG.debug(f"finished minting ")
6163

62-
LOG.debug(f"Minting identifier {m}/{n}")
64+
# capture and log notice from postgres function that contains minting performance stats
65+
for notice in session.connection.notices:
66+
if 'id3c_minting_performance::' in notice:
67+
minting_stats = json.loads(notice.split('::')[-1])
6368

64-
try:
65-
with session.savepoint(f"identifier {m}"):
66-
new_identifier = session.fetch_row("""
67-
insert into warehouse.identifier (identifier_set_id, generated)
68-
values (%s, now())
69-
returning uuid, barcode, generated
70-
""",
71-
(identifier_set.id,))
69+
duration = minting_stats['exec_time'] / 1000
70+
per_second = n / duration
71+
per_identifier = duration / n
7272

73-
minted.append(new_identifier)
74-
75-
except ExclusionViolation:
76-
LOG.debug("Barcode excluded. Retrying.")
77-
failures.setdefault(m, 0)
78-
failures[m] += 1
79-
80-
duration = datetime.now() - started
81-
per_second = n / duration.total_seconds()
82-
per_identifier = duration.total_seconds() / n
83-
84-
failure_counts = list(failures.values())
85-
86-
LOG.info(f"Minted {n} identifiers in {n + sum(failure_counts)} tries ({sum(failure_counts)} retries) over {duration} ({per_identifier:.2f} s/identifier = {per_second:.2f} identifiers/s)")
87-
88-
if failure_counts:
89-
LOG.info(f"Failure distribution: max={max(failure_counts)} mode={mode(failure_counts)} median={median(failure_counts)}")
73+
LOG.info(f"Minted {minting_stats['count']} identifiers in {minting_stats['count'] + minting_stats['failures']} tries ({minting_stats['failures']} retries) over {duration:.2f} seconds ({per_identifier:.2f} s/identifier = {per_second:.2f} identifiers/s)")
74+
LOG.info(f"Failure distribution: max={minting_stats['max']} mode={minting_stats['mode']} median={minting_stats['median']}")
9075

9176
return minted
9277

Lines changed: 59 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,59 @@
1+
-- Deploy seattleflu/schema:functions/mint_identifiers to pg
2+
3+
begin;
4+
5+
create or replace function public.mint_identifiers(set_id integer, number_to_mint integer)
6+
returns setof warehouse.identifier
7+
language plpgsql as $$
8+
9+
declare
10+
counter integer := 0;
11+
r record;
12+
failure_count integer := 0;
13+
failure_count_arr integer[];
14+
error_detail text;
15+
16+
start_ts timestamptz;
17+
exec_time numeric;
18+
19+
stats jsonb;
20+
begin
21+
start_ts := clock_timestamp();
22+
23+
while counter < number_to_mint loop
24+
begin
25+
insert into warehouse.identifier (identifier_set_id) values (set_id)
26+
returning uuid, barcode, identifier_set_id, generated into r;
27+
28+
raise notice 'Successfully minted identifier: %; barcode: %', r.uuid, r.barcode;
29+
counter := counter + 1;
30+
failure_count_arr[counter] = failure_count;
31+
failure_count := 0;
32+
return next r;
33+
34+
exception
35+
when others then
36+
GET STACKED DIAGNOSTICS error_detail = PG_EXCEPTION_DETAIL;
37+
raise notice '%; %', SQLERRM, error_detail;
38+
failure_count := failure_count + 1;
39+
end;
40+
41+
end loop;
42+
43+
exec_time := 1000 * (extract(epoch FROM clock_timestamp() - start_ts));
44+
45+
stats := jsonb_build_object('count',counter, 'exec_time', exec_time) ||
46+
(select jsonb_agg(t) -> 0 from (select sum(x) as failures, max(x), mode() within group (order by x), percentile_disc(0.5) within group (order by x) as median from unnest(failure_count_arr) as x) t) as stats;
47+
48+
raise notice 'id3c_minting_performance::%', stats;
49+
end;
50+
51+
52+
$$
53+
volatile
54+
parallel unsafe;
55+
56+
comment on function public.mint_identifiers(integer, integer) is
57+
'Generates and inserts the specified number of valid identifiers for a given identifier set.';
58+
59+
commit;

schema/deploy/roles/identifier-minter/grants.sql

Lines changed: 8 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -21,4 +21,12 @@ grant select, insert
2121
on warehouse.identifier
2222
to "identifier-minter";
2323

24+
revoke execute
25+
on function public.mint_identifiers(integer, integer)
26+
from public;
27+
28+
grant execute
29+
on function public.mint_identifiers(integer, integer)
30+
to "identifier-minter";
31+
2432
commit;
Lines changed: 24 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,24 @@
1+
-- Deploy seattleflu/schema:roles/identifier-minter/grants to pg
2+
-- requires: warehouse/identifier
3+
-- requires: roles/identifier-minter/create
4+
5+
begin;
6+
7+
-- This change is designed to be sqitch rework-able to make it easier to update
8+
-- the grants for this role.
9+
10+
grant connect on database :"DBNAME" to "identifier-minter";
11+
12+
grant usage
13+
on schema warehouse
14+
to "identifier-minter";
15+
16+
grant select
17+
on warehouse.identifier_set
18+
to "identifier-minter";
19+
20+
grant select, insert
21+
on warehouse.identifier
22+
to "identifier-minter";
23+
24+
commit;
Lines changed: 7 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,7 @@
1+
-- Revert seattleflu/schema:functions/mint_identifiers from pg
2+
3+
begin;
4+
5+
drop function if exists public.mint_identifiers(integer, integer);
6+
7+
commit;
Lines changed: 20 additions & 11 deletions
Original file line numberDiff line numberDiff line change
@@ -1,19 +1,28 @@
1-
-- Revert seattleflu/schema:roles/identifier-minter/grants from pg
1+
-- Deploy seattleflu/schema:roles/identifier-minter/grants to pg
2+
-- requires: warehouse/identifier
3+
-- requires: roles/identifier-minter/create
24

35
begin;
46

5-
revoke select, insert
6-
on warehouse.identifier
7-
from "identifier-minter";
7+
-- This change is designed to be sqitch rework-able to make it easier to update
8+
-- the grants for this role.
89

9-
revoke select
10-
on warehouse.identifier_set
11-
from "identifier-minter";
10+
grant connect on database :"DBNAME" to "identifier-minter";
1211

13-
revoke usage
14-
on schema warehouse
15-
from "identifier-minter";
12+
grant usage
13+
on schema warehouse
14+
to "identifier-minter";
1615

17-
revoke connect on database :"DBNAME" from "identifier-minter";
16+
grant select
17+
on warehouse.identifier_set
18+
to "identifier-minter";
19+
20+
grant select, insert
21+
on warehouse.identifier
22+
to "identifier-minter";
23+
24+
revoke execute
25+
on function public.mint_identifiers(integer, integer)
26+
from "identifier-minter";
1827

1928
commit;
Lines changed: 19 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,19 @@
1+
-- Revert seattleflu/schema:roles/identifier-minter/grants from pg
2+
3+
begin;
4+
5+
revoke select, insert
6+
on warehouse.identifier
7+
from "identifier-minter";
8+
9+
revoke select
10+
on warehouse.identifier_set
11+
from "identifier-minter";
12+
13+
revoke usage
14+
on schema warehouse
15+
from "identifier-minter";
16+
17+
revoke connect on database :"DBNAME" from "identifier-minter";
18+
19+
commit;

schema/sqitch.plan

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -237,3 +237,9 @@ warehouse/identifier/indexes/identifier_set_id_btree 2021-07-06T22:33:41Z Dave R
237237
roles/sample-editor/create 2021-08-13T15:01:31Z Dave Reinhart <[email protected]> # Add sample editor role
238238
roles/sample-editor/grants 2021-08-13T15:03:19Z Dave Reinhart <[email protected]> # Grant permissions to sample-editor role
239239
@2021-08-13 2021-08-13T15:15:55Z Dave Reinhart <[email protected]> # Schema as of 13 Aug 2021
240+
241+
functions/mint_identifiers 2022-07-15T22:13:52Z Dave Reinhart <[email protected]> # Adding mint_identifiers function to batch mint identifiers for a given set.
242+
@2022-07-25 2022-07-25T21:27:47Z Dave Reinhart <[email protected]> # Schemas as of 25 July 2022
243+
244+
roles/identifier-minter/grants [roles/identifier-minter/grants@2022-07-25] 2022-07-28T19:05:20Z Dave Reinhart <[email protected]> # Add execute permissions on mint_identifiers function to identiifer-minter
245+
@2022-07-28 2022-07-28T19:20:25Z Dave Reinhart <[email protected]> # Schema as of 28 July 2022
Lines changed: 22 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,22 @@
1+
-- Verify seattleflu/schema:functions/mint_identifiers on pg
2+
3+
begin;
4+
5+
do $$
6+
declare
7+
test record;
8+
begin
9+
create temp table if not exists tests
10+
as select uuid, barcode, identifier_set_id, generated
11+
from public.mint_identifiers(6, 3);
12+
13+
assert (select count(*) from tests) = 3;
14+
15+
for test in table tests loop
16+
assert test.identifier_set_id = 6;
17+
end loop;
18+
19+
end
20+
$$;
21+
22+
rollback;

schema/verify/roles/identifier-minter/grants.sql

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -6,9 +6,11 @@ select 1/pg_catalog.has_database_privilege('identifier-minter', :'DBNAME', 'conn
66
select 1/pg_catalog.has_schema_privilege('identifier-minter', 'warehouse', 'usage')::int;
77
select 1/pg_catalog.has_table_privilege('identifier-minter', 'warehouse.identifier', 'select,insert')::int;
88
select 1/pg_catalog.has_table_privilege('identifier-minter', 'warehouse.identifier_set', 'select')::int;
9+
select 1/pg_catalog.has_function_privilege('identifier-minter', 'public.mint_identifiers(integer,integer)', 'execute')::int;
910

1011
select 1/(not pg_catalog.has_schema_privilege('identifier-minter', 'receiving', 'usage'))::int;
1112
select 1/(not pg_catalog.has_table_privilege('identifier-minter', 'warehouse.identifier', 'update,delete'))::int;
1213
select 1/(not pg_catalog.has_table_privilege('identifier-minter', 'warehouse.identifier_set', 'insert,update,delete'))::int;
14+
select 1/(not pg_catalog.has_function_privilege('public', 'public.mint_identifiers(integer,integer)', 'execute'))::int;
1315

1416
rollback;
Lines changed: 14 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,14 @@
1+
-- Verify seattleflu/schema:roles/identifier-minter/grants on pg
2+
3+
begin;
4+
5+
select 1/pg_catalog.has_database_privilege('identifier-minter', :'DBNAME', 'connect')::int;
6+
select 1/pg_catalog.has_schema_privilege('identifier-minter', 'warehouse', 'usage')::int;
7+
select 1/pg_catalog.has_table_privilege('identifier-minter', 'warehouse.identifier', 'select,insert')::int;
8+
select 1/pg_catalog.has_table_privilege('identifier-minter', 'warehouse.identifier_set', 'select')::int;
9+
10+
select 1/(not pg_catalog.has_schema_privilege('identifier-minter', 'receiving', 'usage'))::int;
11+
select 1/(not pg_catalog.has_table_privilege('identifier-minter', 'warehouse.identifier', 'update,delete'))::int;
12+
select 1/(not pg_catalog.has_table_privilege('identifier-minter', 'warehouse.identifier_set', 'insert,update,delete'))::int;
13+
14+
rollback;

0 commit comments

Comments
 (0)