chore: commit pending ZXDB explorer changes prior to index perf work
Context - Housekeeping commit to capture all current ZXDB Explorer work before index-page performance optimizations. Includes - Server-rendered entry detail page with ISR and parallelized DB queries. - Node runtime for ZXDB API routes and params validation updates for Next 15. - ZXDB repository extensions (facets, label queries, category queries). - Cross-linking and Link-based prefetch across ZXDB UI. - Cache headers on low-churn list APIs. Notes - Follow-up commit will focus specifically on speeding up index pages via SSR initial data and ISR. Signed-off-by: Junie@lucy.xalior.com
This commit is contained in:
@@ -38,6 +38,18 @@ export interface PagedResult<T> {
|
||||
total: number;
|
||||
}
|
||||
|
||||
export interface FacetItem<T extends number | string> {
|
||||
id: T;
|
||||
name: string;
|
||||
count: number;
|
||||
}
|
||||
|
||||
export interface EntryFacets {
|
||||
genres: FacetItem<number>[];
|
||||
languages: FacetItem<string>[];
|
||||
machinetypes: FacetItem<number>[];
|
||||
}
|
||||
|
||||
export async function searchEntries(params: SearchParams): Promise<PagedResult<SearchResultItem>> {
|
||||
const q = (params.q ?? "").trim();
|
||||
const pageSize = Math.max(1, Math.min(params.pageSize ?? 20, 100));
|
||||
@@ -124,44 +136,42 @@ export interface EntryDetail {
|
||||
}
|
||||
|
||||
export async function getEntryById(id: number): Promise<EntryDetail | null> {
|
||||
// Basic entry with lookups
|
||||
const rows = await db
|
||||
.select({
|
||||
id: entries.id,
|
||||
title: entries.title,
|
||||
isXrated: entries.isXrated,
|
||||
machinetypeId: entries.machinetypeId,
|
||||
machinetypeName: machinetypes.name,
|
||||
languageId: entries.languageId,
|
||||
languageName: languages.name,
|
||||
genreId: entries.genretypeId,
|
||||
genreName: genretypes.name,
|
||||
})
|
||||
.from(entries)
|
||||
.leftJoin(machinetypes, eq(machinetypes.id, entries.machinetypeId as any))
|
||||
.leftJoin(languages, eq(languages.id, entries.languageId as any))
|
||||
.leftJoin(genretypes, eq(genretypes.id, entries.genretypeId as any))
|
||||
.where(eq(entries.id, id));
|
||||
// Run base row + contributors in parallel to reduce latency
|
||||
const [rows, authorRows, publisherRows] = await Promise.all([
|
||||
db
|
||||
.select({
|
||||
id: entries.id,
|
||||
title: entries.title,
|
||||
isXrated: entries.isXrated,
|
||||
machinetypeId: entries.machinetypeId,
|
||||
machinetypeName: machinetypes.name,
|
||||
languageId: entries.languageId,
|
||||
languageName: languages.name,
|
||||
genreId: entries.genretypeId,
|
||||
genreName: genretypes.name,
|
||||
})
|
||||
.from(entries)
|
||||
.leftJoin(machinetypes, eq(machinetypes.id, entries.machinetypeId as any))
|
||||
.leftJoin(languages, eq(languages.id, entries.languageId as any))
|
||||
.leftJoin(genretypes, eq(genretypes.id, entries.genretypeId as any))
|
||||
.where(eq(entries.id, id)),
|
||||
db
|
||||
.select({ id: labels.id, name: labels.name, labeltypeId: labels.labeltypeId })
|
||||
.from(authors)
|
||||
.innerJoin(labels, eq(labels.id, authors.labelId))
|
||||
.where(eq(authors.entryId, id))
|
||||
.groupBy(labels.id),
|
||||
db
|
||||
.select({ id: labels.id, name: labels.name, labeltypeId: labels.labeltypeId })
|
||||
.from(publishers)
|
||||
.innerJoin(labels, eq(labels.id, publishers.labelId))
|
||||
.where(eq(publishers.entryId, id))
|
||||
.groupBy(labels.id),
|
||||
]);
|
||||
|
||||
const base = rows[0];
|
||||
if (!base) return null;
|
||||
|
||||
// Authors
|
||||
const authorRows = await db
|
||||
.select({ id: labels.id, name: labels.name, labeltypeId: labels.labeltypeId })
|
||||
.from(authors)
|
||||
.innerJoin(labels, eq(labels.id, authors.labelId))
|
||||
.where(eq(authors.entryId, id))
|
||||
.groupBy(labels.id);
|
||||
|
||||
// Publishers
|
||||
const publisherRows = await db
|
||||
.select({ id: labels.id, name: labels.name, labeltypeId: labels.labeltypeId })
|
||||
.from(publishers)
|
||||
.innerJoin(labels, eq(labels.id, publishers.labelId))
|
||||
.where(eq(publishers.entryId, id))
|
||||
.groupBy(labels.id);
|
||||
|
||||
return {
|
||||
id: base.id,
|
||||
title: base.title,
|
||||
@@ -339,3 +349,57 @@ export async function entriesByMachinetype(mtId: number, page: number, pageSize:
|
||||
.offset(offset);
|
||||
return { items: items as any, page, pageSize, total: Number(total ?? 0) };
|
||||
}
|
||||
|
||||
// ----- Facets for search -----
|
||||
|
||||
export async function getEntryFacets(params: SearchParams): Promise<EntryFacets> {
|
||||
const q = (params.q ?? "").trim();
|
||||
const pattern = q ? `%${q.toLowerCase().replace(/[^a-z0-9]+/g, "")}%` : null;
|
||||
|
||||
// Build base WHERE SQL snippet considering q + filters
|
||||
const whereParts: any[] = [];
|
||||
if (pattern) {
|
||||
whereParts.push(sql`id in (select entry_id from ${searchByTitles} where ${searchByTitles.entryTitle} like ${pattern})`);
|
||||
}
|
||||
if (params.genreId) whereParts.push(sql`${entries.genretypeId} = ${params.genreId}`);
|
||||
if (params.languageId) whereParts.push(sql`${entries.languageId} = ${params.languageId}`);
|
||||
if (params.machinetypeId) whereParts.push(sql`${entries.machinetypeId} = ${params.machinetypeId}`);
|
||||
|
||||
const whereSql = whereParts.length ? sql.join([sql`where `, sql.join(whereParts as any, sql` and `)], sql``) : sql``;
|
||||
|
||||
// Genres facet
|
||||
const genresRows = await db.execute(sql`
|
||||
select e.genretype_id as id, gt.text as name, count(*) as count
|
||||
from ${entries} as e
|
||||
left join ${genretypes} as gt on gt.id = e.genretype_id
|
||||
${whereSql}
|
||||
group by e.genretype_id, gt.text
|
||||
order by count desc, name asc
|
||||
`) as any;
|
||||
|
||||
// Languages facet
|
||||
const langRows = await db.execute(sql`
|
||||
select e.language_id as id, l.text as name, count(*) as count
|
||||
from ${entries} as e
|
||||
left join ${languages} as l on l.id = e.language_id
|
||||
${whereSql}
|
||||
group by e.language_id, l.text
|
||||
order by count desc, name asc
|
||||
`) as any;
|
||||
|
||||
// Machinetypes facet
|
||||
const mtRows = await db.execute(sql`
|
||||
select e.machinetype_id as id, m.text as name, count(*) as count
|
||||
from ${entries} as e
|
||||
left join ${machinetypes} as m on m.id = e.machinetype_id
|
||||
${whereSql}
|
||||
group by e.machinetype_id, m.text
|
||||
order by count desc, name asc
|
||||
`) as any;
|
||||
|
||||
return {
|
||||
genres: (genresRows as any[]).map((r: any) => ({ id: Number(r.id), name: r.name ?? "(none)", count: Number(r.count) })).filter((r) => !!r.id),
|
||||
languages: (langRows as any[]).map((r: any) => ({ id: String(r.id), name: r.name ?? "(none)", count: Number(r.count) })).filter((r) => !!r.id),
|
||||
machinetypes: (mtRows as any[]).map((r: any) => ({ id: Number(r.id), name: r.name ?? "(none)", count: Number(r.count) })).filter((r) => !!r.id),
|
||||
};
|
||||
}
|
||||
|
||||
Reference in New Issue
Block a user