ZXDB: Releases browser filters, schema lists, and fixes

- UI: Add /zxdb hub cards for Entries and Releases; implement Releases browser
  with URL‑synced filters (q, year, sort, DL language/machine, file/scheme/source/case, demo)
  and a paginated table (Entry ID, Title, Release #, Year).
- API: Add GET /api/zxdb/releases/search (Zod‑validated, Node runtime) supporting
  title, year, sort, and downloads‑based filters; return paged JSON.
- Repo: Rewrite searchReleases to Drizzle QB; correct ORDER BY on releases.release_year;
  implement EXISTS on downloads using explicit "from downloads as d"; return JSON‑safe rows.
- Schema: Align Drizzle models with ZXDB for releases/downloads; add lookups
  availabletypes, currencies, roletypes, and roles relation.
- API (lookups): Add GET /api/zxdb/{availabletypes,currencies,roletypes} for dropdowns.
- Stability: JSON‑clone SSR payloads before passing to Client Components to avoid
  RowDataPacket serialization errors.

Signed-off-by: Junie@lucy.xalior.com
This commit is contained in:
2025-12-16 23:00:38 +00:00
parent fd4c0f8963
commit f563b41792
16 changed files with 1147 additions and 62 deletions

View File

@@ -1,4 +1,5 @@
import { and, desc, eq, like, sql } from "drizzle-orm";
import { and, desc, eq, like, sql, asc } from "drizzle-orm";
import { alias } from "drizzle-orm/mysql-core";
import { db } from "@/server/db";
import {
entries,
@@ -13,10 +14,12 @@ import {
filetypes,
releases,
downloads,
releasetypes,
schemetypes,
sourcetypes,
casetypes,
availabletypes,
currencies,
roletypes,
} from "@/server/schema/zxdb";
export interface SearchParams {
@@ -289,19 +292,9 @@ export async function getEntryById(id: number): Promise<EntryDetail | null> {
releaseRows = (await db
.select({
releaseSeq: releases.releaseSeq,
releasetypeId: releases.releasetypeId,
releasetypeName: releasetypes.name,
languageId: releases.languageId,
languageName: languages.name,
machinetypeId: releases.machinetypeId,
machinetypeName: machinetypes.name,
year: releases.releaseYear,
comments: releases.comments,
})
.from(releases)
.leftJoin(releasetypes, eq(releasetypes.id as any, releases.releasetypeId as any))
.leftJoin(languages, eq(languages.id as any, releases.languageId as any))
.leftJoin(machinetypes, eq(machinetypes.id as any, releases.machinetypeId as any))
.where(eq(releases.entryId as any, id as any))) as any;
} catch {
releaseRows = [];
@@ -359,11 +352,11 @@ export async function getEntryById(id: number): Promise<EntryDetail | null> {
// that appears in downloads but has no corresponding releases row.
const releasesData = releaseRows.map((r: any) => ({
releaseSeq: Number(r.releaseSeq),
type: { id: (r.releasetypeId as any) ?? null, name: (r.releasetypeName as any) ?? null },
language: { id: (r.languageId as any) ?? null, name: (r.languageName as any) ?? null },
machinetype: { id: (r.machinetypeId as any) ?? null, name: (r.machinetypeName as any) ?? null },
type: { id: null, name: null },
language: { id: null, name: null },
machinetype: { id: null, name: null },
year: (r.year as any) ?? null,
comments: (r.comments as any) ?? null,
comments: null,
downloads: (downloadsBySeq.get(Number(r.releaseSeq)) ?? []).map((d: any) => ({
id: d.id,
link: d.link,
@@ -634,6 +627,9 @@ export async function listMachinetypes() {
return db.select().from(machinetypes).orderBy(machinetypes.name);
}
// Note: ZXDB structure in this project does not include a `releasetypes` table.
// Do not attempt to query it here.
// Search with pagination for lookups
export interface SimpleSearchParams {
q?: string;
@@ -967,3 +963,150 @@ export async function getEntryFacets(params: SearchParams): Promise<EntryFacets>
machinetypes: (mtRows as any[]).map((r: any) => ({ id: Number(r.id), name: r.name ?? "(none)", count: Number(r.count) })).filter((r) => !!r.id),
};
}
// ----- Releases search (browser) -----
export interface ReleaseSearchParams {
q?: string; // match entry title via helper search
page?: number;
pageSize?: number;
year?: number;
sort?: "year_desc" | "year_asc" | "title" | "entry_id_desc";
// Optional download-based filters (matched via EXISTS on downloads)
dLanguageId?: string; // downloads.language_id
dMachinetypeId?: number; // downloads.machinetype_id
filetypeId?: number; // downloads.filetype_id
schemetypeId?: string; // downloads.schemetype_id
sourcetypeId?: string; // downloads.sourcetype_id
casetypeId?: string; // downloads.casetype_id
isDemo?: boolean; // downloads.is_demo
}
export interface ReleaseListItem {
entryId: number;
releaseSeq: number;
entryTitle: string;
year: number | null;
}
export async function searchReleases(params: ReleaseSearchParams): Promise<PagedResult<ReleaseListItem>> {
const q = (params.q ?? "").trim();
const pageSize = Math.max(1, Math.min(params.pageSize ?? 20, 100));
const page = Math.max(1, params.page ?? 1);
const offset = (page - 1) * pageSize;
// Build WHERE conditions in Drizzle QB
const wherePartsQB: any[] = [];
if (q) {
const pattern = `%${q.toLowerCase().replace(/[^a-z0-9]+/g, "")}%`;
wherePartsQB.push(sql`${releases.entryId} in (select ${searchByTitles.entryId} from ${searchByTitles} where ${searchByTitles.entryTitle} like ${pattern})`);
}
if (params.year != null) {
wherePartsQB.push(eq(releases.releaseYear as any, params.year as any));
}
// Optional filters via downloads table: use EXISTS for performance and correctness
// IMPORTANT: when hand-writing SQL with an aliased table, we must render
// "from downloads as d" explicitly; using only the alias identifier ("d")
// would produce "from `d`" which MySQL interprets as a literal table.
const dlConds: any[] = [];
if (params.dLanguageId) dlConds.push(sql`d.language_id = ${params.dLanguageId}`);
if (params.dMachinetypeId != null) dlConds.push(sql`d.machinetype_id = ${params.dMachinetypeId}`);
if (params.filetypeId != null) dlConds.push(sql`d.filetype_id = ${params.filetypeId}`);
if (params.schemetypeId) dlConds.push(sql`d.schemetype_id = ${params.schemetypeId}`);
if (params.sourcetypeId) dlConds.push(sql`d.sourcetype_id = ${params.sourcetypeId}`);
if (params.casetypeId) dlConds.push(sql`d.casetype_id = ${params.casetypeId}`);
if (params.isDemo != null) dlConds.push(sql`d.is_demo = ${params.isDemo ? 1 : 0}`);
if (dlConds.length) {
const baseConds = [
sql`d.entry_id = ${releases.entryId}`,
sql`d.release_seq = ${releases.releaseSeq}`,
...dlConds,
];
wherePartsQB.push(
sql`exists (select 1 from ${downloads} as d where ${sql.join(baseConds as any, sql` and `)})`
);
}
const whereExpr = wherePartsQB.length ? and(...(wherePartsQB as any)) : undefined;
// Count total
const countRows = (await db
.select({ total: sql<number>`count(*)` })
.from(releases)
.where(whereExpr as any)) as unknown as { total: number }[];
const total = Number(countRows?.[0]?.total ?? 0);
// Rows via Drizzle QB to avoid tuple/field leakage
const orderByParts: any[] = [];
switch (params.sort) {
case "year_asc":
orderByParts.push(asc(releases.releaseYear as any), asc(releases.entryId as any), asc(releases.releaseSeq as any));
break;
case "title":
orderByParts.push(asc(entries.title as any), desc(releases.releaseYear as any), asc(releases.releaseSeq as any));
break;
case "entry_id_desc":
orderByParts.push(desc(releases.entryId as any), desc(releases.releaseSeq as any));
break;
case "year_desc":
default:
orderByParts.push(desc(releases.releaseYear as any), desc(releases.entryId as any), desc(releases.releaseSeq as any));
break;
}
const rowsQB = await db
.select({
entryId: releases.entryId,
releaseSeq: releases.releaseSeq,
entryTitle: entries.title,
year: releases.releaseYear,
})
.from(releases)
.leftJoin(entries, eq(entries.id as any, releases.entryId as any))
.where(whereExpr as any)
.orderBy(...(orderByParts as any))
.limit(pageSize)
.offset(offset);
// Ensure plain primitives
const items: ReleaseListItem[] = rowsQB.map((r: any) => ({
entryId: Number(r.entryId),
releaseSeq: Number(r.releaseSeq),
entryTitle: r.entryTitle ?? "",
year: r.year != null ? Number(r.year) : null,
}));
return { items, page, pageSize, total };
}
// ----- Download/lookups simple lists -----
export async function listFiletypes() {
return db.select().from(filetypes).orderBy(filetypes.name);
}
export async function listSchemetypes() {
return db.select().from(schemetypes).orderBy(schemetypes.name);
}
export async function listSourcetypes() {
return db.select().from(sourcetypes).orderBy(sourcetypes.name);
}
export async function listCasetypes() {
return db.select().from(casetypes).orderBy(casetypes.name);
}
// Newly exposed lookups
export async function listAvailabletypes() {
return db.select().from(availabletypes).orderBy(availabletypes.name);
}
export async function listCurrencies() {
// Preserve full fields for UI needs
return db
.select({ id: currencies.id, name: currencies.name, symbol: currencies.symbol, prefix: currencies.prefix })
.from(currencies)
.orderBy(currencies.name);
}
export async function listRoletypes() {
return db.select().from(roletypes).orderBy(roletypes.name);
}