fix(cms): change articles unique constraint to (url_path, language)

url_path UNIQUE prevented multilingual generation — the second language
(e.g. EN after DE) always failed with UNIQUE constraint, leaving tasks in
a retry loop and only the first 1-2 articles visible.

Migration 0020 recreates the articles table with UNIQUE(url_path, language)
and adds a composite index. Adds idx_articles_url_lang for the new lookup
pattern used by article_page and generate_articles upsert.

Also adds search/country/venue_type filters to the admin Scenarios tab
and clarifies what "Published Scenarios" means in the subtitle.

Co-Authored-By: Claude Sonnet 4.6 <noreply@anthropic.com>
This commit is contained in:
Deeman
2026-02-24 09:53:58 +01:00
parent a35036807e
commit 3d99b8c375
3 changed files with 160 additions and 9 deletions

View File

@@ -1395,11 +1395,46 @@ SCENARIO_FORM_FIELDS = [
@bp.route("/scenarios")
@role_required("admin")
async def scenarios():
"""List published scenarios."""
"""List published scenarios with optional filters."""
search = request.args.get("search", "").strip()
country_filter = request.args.get("country", "")
venue_filter = request.args.get("venue_type", "")
wheres = ["1=1"]
params: list = []
if search:
wheres.append("(title LIKE ? OR location LIKE ? OR slug LIKE ?)")
params.extend([f"%{search}%", f"%{search}%", f"%{search}%"])
if country_filter:
wheres.append("country = ?")
params.append(country_filter)
if venue_filter:
wheres.append("venue_type = ?")
params.append(venue_filter)
where = " AND ".join(wheres)
scenario_list = await fetch_all(
"SELECT * FROM published_scenarios ORDER BY created_at DESC"
f"SELECT * FROM published_scenarios WHERE {where} ORDER BY created_at DESC",
tuple(params),
)
countries = await fetch_all(
"SELECT DISTINCT country FROM published_scenarios WHERE country != '' ORDER BY country"
)
venue_types = await fetch_all(
"SELECT DISTINCT venue_type FROM published_scenarios WHERE venue_type != '' ORDER BY venue_type"
)
total = await fetch_one("SELECT COUNT(*) as cnt FROM published_scenarios")
return await render_template(
"admin/scenarios.html",
scenarios=scenario_list,
countries=[r["country"] for r in countries],
venue_types=[r["venue_type"] for r in venue_types],
total=total["cnt"] if total else 0,
current_search=search,
current_country=country_filter,
current_venue_type=venue_filter,
)
return await render_template("admin/scenarios.html", scenarios=scenario_list)
@bp.route("/scenarios/new", methods=["GET", "POST"])

View File

@@ -1,20 +1,55 @@
{% extends "admin/base_admin.html" %}
{% set admin_page = "scenarios" %}
{% block title %}Published Scenarios - Admin - {{ config.APP_NAME }}{% endblock %}
{% block title %}Scenarios - Admin - {{ config.APP_NAME }}{% endblock %}
{% block admin_content %}
<header class="flex justify-between items-center mb-8">
<header class="flex justify-between items-center mb-6">
<div>
<h1 class="text-2xl">Published Scenarios</h1>
<p class="text-slate text-sm">{{ scenarios | length }} scenario{{ 's' if scenarios | length != 1 }}</p>
<h1 class="text-2xl">Scenarios</h1>
<p class="text-slate text-sm">
Pre-computed calculator outputs — embedded as cards in articles and PDFs.
Showing {{ scenarios | length }} of {{ total }}.
</p>
</div>
<div class="flex gap-2">
<a href="{{ url_for('admin.scenario_new') }}" class="btn">New Scenario</a>
<a href="{{ url_for('admin.index') }}" class="btn-outline">Back</a>
</div>
</header>
<form method="get" class="card mb-4 flex flex-wrap gap-3 items-end">
<div class="flex-1 min-w-48">
<label class="block text-sm text-slate mb-1">Search</label>
<input type="text" name="search" value="{{ current_search }}"
placeholder="Title, location, slug…"
class="input w-full">
</div>
<div>
<label class="block text-sm text-slate mb-1">Country</label>
<select name="country" class="input">
<option value="">All countries</option>
{% for c in countries %}
<option value="{{ c }}" {% if c == current_country %}selected{% endif %}>{{ c }}</option>
{% endfor %}
</select>
</div>
<div>
<label class="block text-sm text-slate mb-1">Venue type</label>
<select name="venue_type" class="input">
<option value="">All types</option>
{% for v in venue_types %}
<option value="{{ v }}" {% if v == current_venue_type %}selected{% endif %}>{{ v | capitalize }}</option>
{% endfor %}
</select>
</div>
<div class="flex gap-2">
<button type="submit" class="btn">Filter</button>
{% if current_search or current_country or current_venue_type %}
<a href="{{ url_for('admin.scenarios') }}" class="btn-outline">Clear</a>
{% endif %}
</div>
</form>
<div class="card">
{% if scenarios %}
<table class="table">
@@ -51,7 +86,7 @@
</tbody>
</table>
{% else %}
<p class="text-slate text-sm">No published scenarios yet.</p>
<p class="text-slate text-sm">No scenarios match the current filters.</p>
{% endif %}
</div>
{% endblock %}

View File

@@ -0,0 +1,81 @@
"""Change articles unique constraint from url_path alone to (url_path, language).
Previously url_path was declared UNIQUE, which prevented multiple languages
from sharing the same url_path (e.g. /markets/germany/berlin for both de and en).
"""
def up(conn) -> None:
# ── 1. Drop FTS triggers + virtual table ──────────────────────────────────
conn.execute("DROP TRIGGER IF EXISTS articles_ai")
conn.execute("DROP TRIGGER IF EXISTS articles_ad")
conn.execute("DROP TRIGGER IF EXISTS articles_au")
conn.execute("DROP TABLE IF EXISTS articles_fts")
# ── 2. Recreate articles with UNIQUE(url_path, language) ──────────────────
conn.execute("""
CREATE TABLE articles_new (
id INTEGER PRIMARY KEY AUTOINCREMENT,
url_path TEXT NOT NULL,
slug TEXT UNIQUE NOT NULL,
title TEXT NOT NULL,
meta_description TEXT,
country TEXT,
region TEXT,
og_image_url TEXT,
status TEXT NOT NULL DEFAULT 'draft',
published_at TEXT,
template_slug TEXT,
language TEXT NOT NULL DEFAULT 'en',
date_modified TEXT,
seo_head TEXT,
created_at TEXT NOT NULL DEFAULT (datetime('now')),
updated_at TEXT,
UNIQUE(url_path, language)
)
""")
conn.execute("""
INSERT INTO articles_new
(id, url_path, slug, title, meta_description, country, region,
og_image_url, status, published_at, template_slug, language,
date_modified, seo_head, created_at, updated_at)
SELECT id, url_path, slug, title, meta_description, country, region,
og_image_url, status, published_at, template_slug, language,
date_modified, seo_head, created_at, updated_at
FROM articles
""")
conn.execute("DROP TABLE articles")
conn.execute("ALTER TABLE articles_new RENAME TO articles")
conn.execute("CREATE INDEX IF NOT EXISTS idx_articles_url_path ON articles(url_path)")
conn.execute("CREATE INDEX IF NOT EXISTS idx_articles_url_lang ON articles(url_path, language)")
conn.execute("CREATE INDEX IF NOT EXISTS idx_articles_slug ON articles(slug)")
conn.execute("CREATE INDEX IF NOT EXISTS idx_articles_status ON articles(status, published_at)")
# ── 3. Recreate FTS + triggers ─────────────────────────────────────────────
conn.execute("""
CREATE VIRTUAL TABLE IF NOT EXISTS articles_fts USING fts5(
title, meta_description, country, region,
content='articles', content_rowid='id'
)
""")
conn.execute("""
CREATE TRIGGER IF NOT EXISTS articles_ai AFTER INSERT ON articles BEGIN
INSERT INTO articles_fts(rowid, title, meta_description, country, region)
VALUES (new.id, new.title, new.meta_description, new.country, new.region);
END
""")
conn.execute("""
CREATE TRIGGER IF NOT EXISTS articles_ad AFTER DELETE ON articles BEGIN
INSERT INTO articles_fts(articles_fts, rowid, title, meta_description, country, region)
VALUES ('delete', old.id, old.title, old.meta_description, old.country, old.region);
END
""")
conn.execute("""
CREATE TRIGGER IF NOT EXISTS articles_au AFTER UPDATE ON articles BEGIN
INSERT INTO articles_fts(articles_fts, rowid, title, meta_description, country, region)
VALUES ('delete', old.id, old.title, old.meta_description, old.country, old.region);
INSERT INTO articles_fts(rowid, title, meta_description, country, region)
VALUES (new.id, new.title, new.meta_description, new.country, new.region);
END
""")