perf: fix N+1 queries in templates(), handle_refill_monthly_credits()
templates() in admin: - Replace per-template SELECT COUNT(*) articles queries with a single GROUP BY query before the loop — O(n) SQLite calls → O(1) - Replace per-template SELECT * LIMIT 501 (for count) with a new count_template_data() that runs SELECT COUNT(*) — cheaper per call - Add count_template_data() to content/__init__.py handle_refill_monthly_credits() in worker: - Replace N×3 per-supplier queries (fetch supplier, insert ledger, update balance) with 2 bulk SQL statements: 1. INSERT INTO credit_ledger SELECT ... for all eligible suppliers 2. UPDATE suppliers SET credit_balance = credit_balance + monthly_credits - Wrap in single transaction() for atomicity - Log total suppliers updated at INFO level audiences() in admin: - Add LIMIT 20 guard + comment explaining why one API call per audience is unavoidable (no bulk contacts endpoint in Resend) Co-Authored-By: Claude Opus 4.6 <noreply@anthropic.com>
This commit is contained in:
@@ -1181,9 +1181,11 @@ async def email_compose():
|
||||
@role_required("admin")
|
||||
async def audiences():
|
||||
"""List Resend audiences with local cache + API contact counts."""
|
||||
audience_list = await fetch_all("SELECT * FROM resend_audiences ORDER BY name")
|
||||
# Cap at 20 — Resend free plan limit is 3 audiences, paid is more but still
|
||||
# small. One API call per audience is unavoidable (no bulk contacts endpoint).
|
||||
audience_list = await fetch_all("SELECT * FROM resend_audiences ORDER BY name LIMIT 20")
|
||||
|
||||
# Enrich with contact count from API (best-effort)
|
||||
# Enrich with contact count from API (best-effort, one call per audience)
|
||||
for a in audience_list:
|
||||
a["contact_count"] = None
|
||||
if config.RESEND_API_KEY and a.get("audience_id"):
|
||||
@@ -1263,21 +1265,20 @@ async def audience_contact_remove(audience_id: str):
|
||||
@role_required("admin")
|
||||
async def templates():
|
||||
"""List content templates scanned from disk."""
|
||||
from ..content import discover_templates, fetch_template_data
|
||||
from ..content import count_template_data, discover_templates
|
||||
|
||||
template_list = discover_templates()
|
||||
|
||||
# Attach DuckDB row counts
|
||||
for t in template_list:
|
||||
count_rows = await fetch_template_data(t["data_table"], limit=501)
|
||||
t["data_count"] = len(count_rows)
|
||||
# Single query: article counts for all templates — avoids N SQLite round-trips
|
||||
counts_raw = await fetch_all(
|
||||
"SELECT template_slug, COUNT(*) as cnt FROM articles GROUP BY template_slug"
|
||||
)
|
||||
article_counts = {r["template_slug"]: r["cnt"] for r in counts_raw}
|
||||
|
||||
# Count generated articles for this template
|
||||
row = await fetch_one(
|
||||
"SELECT COUNT(*) as cnt FROM articles WHERE template_slug = ?",
|
||||
(t["slug"],),
|
||||
)
|
||||
t["generated_count"] = row["cnt"] if row else 0
|
||||
# One DuckDB COUNT(*) per template (N queries, but cheap vs SELECT * LIMIT 501)
|
||||
for t in template_list:
|
||||
t["data_count"] = await count_template_data(t["data_table"])
|
||||
t["generated_count"] = article_counts.get(t["slug"], 0)
|
||||
|
||||
return await render_template("admin/templates.html", templates=template_list)
|
||||
|
||||
|
||||
@@ -128,6 +128,15 @@ async def fetch_template_data(
|
||||
)
|
||||
|
||||
|
||||
async def count_template_data(data_table: str) -> int:
|
||||
"""Return the row count of a DuckDB serving table. Returns 0 if unavailable."""
|
||||
assert "." in data_table, "data_table must be schema-qualified"
|
||||
_validate_table_name(data_table)
|
||||
|
||||
rows = await fetch_analytics(f"SELECT COUNT(*) AS cnt FROM {data_table}")
|
||||
return rows[0]["cnt"] if rows else 0
|
||||
|
||||
|
||||
def _validate_table_name(data_table: str) -> None:
|
||||
"""Guard against SQL injection in table names."""
|
||||
assert re.match(r"^[a-z_][a-z0-9_.]*$", data_table), (
|
||||
|
||||
@@ -18,6 +18,7 @@ from .core import (
|
||||
init_db,
|
||||
send_email,
|
||||
setup_logging,
|
||||
transaction,
|
||||
utcnow,
|
||||
utcnow_iso,
|
||||
)
|
||||
@@ -589,18 +590,41 @@ async def handle_send_supplier_enquiry_email(payload: dict) -> None:
|
||||
|
||||
@task("refill_monthly_credits")
|
||||
async def handle_refill_monthly_credits(payload: dict) -> None:
|
||||
"""Refill monthly credits for all claimed suppliers with a paid tier."""
|
||||
from .credits import monthly_credit_refill
|
||||
"""Refill monthly credits for all claimed suppliers with a paid tier.
|
||||
|
||||
suppliers = await fetch_all(
|
||||
"SELECT id FROM suppliers WHERE tier IN ('growth', 'pro') AND claimed_by IS NOT NULL"
|
||||
)
|
||||
for s in suppliers:
|
||||
try:
|
||||
await monthly_credit_refill(s["id"])
|
||||
logger.info("Refilled credits for supplier %s", s["id"])
|
||||
except Exception as e:
|
||||
logger.error("Failed to refill credits for supplier %s: %s", s["id"], e)
|
||||
Uses two bulk SQL statements instead of N×3 per-supplier queries:
|
||||
1. INSERT INTO credit_ledger SELECT ... for all eligible suppliers at once
|
||||
2. UPDATE suppliers SET credit_balance = credit_balance + monthly_credits
|
||||
"""
|
||||
now = utcnow_iso()
|
||||
async with transaction() as db:
|
||||
# Batch-insert ledger rows for all eligible suppliers in one statement
|
||||
await db.execute(
|
||||
"""INSERT INTO credit_ledger
|
||||
(supplier_id, delta, balance_after, event_type, note, created_at)
|
||||
SELECT id,
|
||||
monthly_credits,
|
||||
credit_balance + monthly_credits,
|
||||
'monthly_allocation',
|
||||
'Monthly refill (' || tier || ' plan)',
|
||||
?
|
||||
FROM suppliers
|
||||
WHERE tier IN ('growth', 'pro')
|
||||
AND claimed_by IS NOT NULL
|
||||
AND monthly_credits > 0""",
|
||||
(now,),
|
||||
)
|
||||
# Update balances and refill timestamps in one statement
|
||||
result = await db.execute(
|
||||
"""UPDATE suppliers
|
||||
SET credit_balance = credit_balance + monthly_credits,
|
||||
last_credit_refill = ?
|
||||
WHERE tier IN ('growth', 'pro')
|
||||
AND claimed_by IS NOT NULL
|
||||
AND monthly_credits > 0""",
|
||||
(now,),
|
||||
)
|
||||
logger.info("Monthly credit refill complete — %d suppliers updated", result.rowcount)
|
||||
|
||||
|
||||
@task("generate_business_plan")
|
||||
|
||||
Reference in New Issue
Block a user