From 0f73f5bc5ed33c0c71a1cc2761247f265bb5f6e2 Mon Sep 17 00:00:00 2001 From: Raphael Michel Date: Tue, 11 May 2021 16:50:53 +0200 Subject: [PATCH] Optimize performance of voucher code generation on PostgreSQL --- src/pretix/control/views/vouchers.py | 44 ++++++++++++++++++++++++++-- 1 file changed, 41 insertions(+), 3 deletions(-) diff --git a/src/pretix/control/views/vouchers.py b/src/pretix/control/views/vouchers.py index 9ee1a81f5a..9605c1b919 100644 --- a/src/pretix/control/views/vouchers.py +++ b/src/pretix/control/views/vouchers.py @@ -55,7 +55,7 @@ from django.views.generic import ( CreateView, DeleteView, ListView, TemplateView, UpdateView, View, ) -from pretix.base.models import CartPosition, LogEntry, OrderPosition, Voucher +from pretix.base.models import CartPosition, LogEntry, OrderPosition, Voucher, Event from pretix.base.models.vouchers import _generate_random_code from pretix.base.services.locking import NoLockManager from pretix.base.services.vouchers import vouchers_send @@ -463,11 +463,49 @@ class VoucherRNG(EventPermissionRequiredMixin, View): return HttpResponseBadRequest() prefix = request.GET.get('prefix') + batch_size = 500 + if 'postgres' in settings.DATABASES['default']['ENGINE']: + batch_size = 5_000 + + """ + We're trying to check if any of the requested codes already exists in the database. Generally, this is a + + SELECT code FROM voucher WHERE code IN (…) + + query. However, it turns out that this query get's rather slow if an organizer has lots of vouchers, even + with a organizer with just over 50_000 vouchers, we've seen that creating 20_000 new voucher codes took + just over 30 seconds. There's another way of doing this query on PostgreSQL, which is joining with a + temporary table + + SELECT code FROM voucher INNER JOIN (VALUES …) vals(v) ON (code = v) + + This is significantly faster, inserting 20_000 vouchers now takes 2-3s instead of 31s on the same dataset. + It's still slow, and removing the JOIN to the event table doesn't significantly speed it up. We might need + an entirely different approach at some point. + """ + while len(codes) < num: new_codes = set() - for i in range(min(num - len(codes), 500)): # Work around SQLite's SQLITE_MAX_VARIABLE_NUMBER + for i in range(min(num - len(codes), batch_size)): # Work around SQLite's SQLITE_MAX_VARIABLE_NUMBER new_codes.add(_generate_random_code(prefix=prefix)) - new_codes -= set([v['code'] for v in Voucher.objects.filter(code__in=new_codes).values('code')]) + + if 'postgres' in settings.DATABASES['default']['ENGINE']: + with connection.cursor() as cursor: + args = list(new_codes) + [request.organizer.pk] + tmptable = "VALUES " + (", ".join(['(%s)'] * len(new_codes))) + cursor.execute( + f'SELECT code ' + f'FROM "{Voucher._meta.db_table}" ' + f'INNER JOIN ({tmptable}) vals(v) ON ("{Voucher._meta.db_table}"."code" = "v")' + f'INNER JOIN "{Event._meta.db_table}" ON ("{Voucher._meta.db_table}"."event_id" = "{Event._meta.db_table}"."id") ' + f'WHERE "{Event._meta.db_table}"."organizer_id" = %s', + args + ) + for row in cursor.fetchall(): + new_codes.remove(row[0]) + else: + new_codes -= set([v['code'] for v in Voucher.objects.filter(code__in=new_codes).values('code')]) + codes |= new_codes return JsonResponse({