Add tag cloud
This commit is contained in:
parent
15ff7e5b47
commit
44e1b73b1f
7 changed files with 131 additions and 39 deletions
|
@ -18,17 +18,29 @@ const currencyExchange = new Map([
|
|||
])
|
||||
|
||||
const sqls = {
|
||||
album_grid: "SELECT item.*, count(*) AS track_count, iif(sum(duration) > 3600, cast(total(duration)/3600 AS INTEGER) || 'h ' || cast(total(duration)/60%60 AS INTEGER) || 'm', cast(total(duration)/60 AS INTEGER) || 'm') AS total_duration FROM item INNER JOIN track USING (item_id) {WHERE} GROUP BY item_id {ORDER}",
|
||||
album_list: "SELECT item.*, count(*) AS track_count, iif(sum(duration) > 3600, cast(total(duration)/3600 AS INTEGER) || 'h ' || cast(total(duration)/60%60 AS INTEGER) || 'm', cast(total(duration)/60 AS INTEGER) || 'm') AS total_duration FROM item INNER JOIN track USING (item_id) {WHERE} GROUP BY item_id ORDER BY band_url, band_name COLLATE NOCASE, item_title COLLATE NOCASE",
|
||||
artist_grid: "SELECT band_name, count(DISTINCT item_id) AS album_count, group_concat(DISTINCT band_url) AS labels, count(*) AS track_count, iif(sum(duration) > 3600, cast(total(duration)/3600 AS INTEGER) || 'h ' || cast(total(duration)/60%60 AS INTEGER) || 'm', cast(total(duration)/60 AS INTEGER) || 'm') AS total_duration FROM item INNER JOIN track USING (item_id) {WHERE} GROUP BY band_name ORDER BY band_name COLLATE NOCASE",
|
||||
artist_list: "SELECT band_name, count(DISTINCT item_id) AS album_count, band_url, count(*) AS track_count, iif(sum(duration) > 3600, cast(total(duration)/3600 AS INTEGER) || 'h ' || cast(total(duration)/60%60 AS INTEGER) || 'm', cast(total(duration)/60 AS INTEGER) || 'm') AS total_duration FROM item INNER JOIN track USING (item_id) {WHERE} GROUP BY band_name ORDER BY band_name COLLATE NOCASE",
|
||||
label_grid: "SELECT iif(count(DISTINCT band_name) = 1, band_name, band_url) AS display_name, band_url, count(DISTINCT item_id) AS album_count, count(DISTINCT band_name) AS artist_count, count(*) AS track_count, iif(sum(duration) > 3600, cast(total(duration)/3600 AS INTEGER) || 'h ' || cast(total(duration)/60%60 AS INTEGER) || 'm', cast(total(duration)/60 AS INTEGER) || 'm') AS total_duration FROM item INNER JOIN track USING (item_id) {WHERE} GROUP BY band_url ORDER BY display_name COLLATE NOCASE",
|
||||
label_list: "SELECT iif(count(DISTINCT band_name) = 1, band_name, band_url) AS display_name, band_url, count(DISTINCT item_id) AS album_count, count(DISTINCT band_name) AS artist_count, count(*) AS track_count, iif(sum(duration) > 3600, cast(total(duration)/3600 AS INTEGER) || 'h ' || cast(total(duration)/60%60 AS INTEGER) || 'm', cast(total(duration)/60 AS INTEGER) || 'm') AS total_duration FROM item INNER JOIN track USING (item_id) {WHERE} GROUP BY band_url ORDER BY display_name COLLATE NOCASE",
|
||||
track_list: "SELECT * FROM track INNER JOIN item USING (item_id) {WHERE} ORDER BY band_url, item_title COLLATE NOCASE, track_number"
|
||||
album_grid: "SELECT item.*, count(*) AS track_count, iif(sum(duration) > 3600, cast(total(duration)/3600 AS INTEGER) || 'h ' || cast(total(duration)/60%60 AS INTEGER) || 'm', cast(total(duration)/60 AS INTEGER) || 'm') AS total_duration FROM item INNER JOIN track USING (item_id) {JOIN TAG} {WHERE} GROUP BY item_id {ORDER}",
|
||||
album_list: "SELECT item.*, count(*) AS track_count, iif(sum(duration) > 3600, cast(total(duration)/3600 AS INTEGER) || 'h ' || cast(total(duration)/60%60 AS INTEGER) || 'm', cast(total(duration)/60 AS INTEGER) || 'm') AS total_duration FROM item INNER JOIN track USING (item_id) {JOIN TAG} {WHERE} GROUP BY item_id ORDER BY band_url, band_name COLLATE NOCASE, item_title COLLATE NOCASE",
|
||||
artist_grid: "SELECT band_name, count(DISTINCT item_id) AS album_count, group_concat(DISTINCT band_url) AS labels, count(*) AS track_count, iif(sum(duration) > 3600, cast(total(duration)/3600 AS INTEGER) || 'h ' || cast(total(duration)/60%60 AS INTEGER) || 'm', cast(total(duration)/60 AS INTEGER) || 'm') AS total_duration FROM item INNER JOIN track USING (item_id) {JOIN TAG} {WHERE} GROUP BY band_name ORDER BY band_name COLLATE NOCASE",
|
||||
artist_list: "SELECT band_name, count(DISTINCT item_id) AS album_count, band_url, count(*) AS track_count, iif(sum(duration) > 3600, cast(total(duration)/3600 AS INTEGER) || 'h ' || cast(total(duration)/60%60 AS INTEGER) || 'm', cast(total(duration)/60 AS INTEGER) || 'm') AS total_duration FROM item INNER JOIN track USING (item_id) {JOIN TAG} {WHERE} GROUP BY band_name ORDER BY band_name COLLATE NOCASE",
|
||||
label_grid: "SELECT iif(count(DISTINCT band_name) = 1, band_name, band_url) AS display_name, band_url, count(DISTINCT item_id) AS album_count, count(DISTINCT band_name) AS artist_count, count(*) AS track_count, iif(sum(duration) > 3600, cast(total(duration)/3600 AS INTEGER) || 'h ' || cast(total(duration)/60%60 AS INTEGER) || 'm', cast(total(duration)/60 AS INTEGER) || 'm') AS total_duration FROM item INNER JOIN track USING (item_id) {JOIN TAG} {WHERE} GROUP BY band_url ORDER BY display_name COLLATE NOCASE",
|
||||
label_list: "SELECT iif(count(DISTINCT band_name) = 1, band_name, band_url) AS display_name, band_url, count(DISTINCT item_id) AS album_count, count(DISTINCT band_name) AS artist_count, count(*) AS track_count, iif(sum(duration) > 3600, cast(total(duration)/3600 AS INTEGER) || 'h ' || cast(total(duration)/60%60 AS INTEGER) || 'm', cast(total(duration)/60 AS INTEGER) || 'm') AS total_duration FROM item INNER JOIN track USING (item_id) {JOIN TAG} {WHERE} GROUP BY band_url ORDER BY display_name COLLATE NOCASE",
|
||||
tag_grid: "SELECT tag, count(*) AS count FROM (SELECT tag, band_url, band_name, item_id, count(*) AS count FROM item_tag INNER JOIN item USING (item_id) GROUP BY tag, band_url) {WHERE} GROUP BY tag ORDER BY count DESC",
|
||||
track_list: "SELECT * FROM track INNER JOIN item USING (item_id) {JOIN TAG} {WHERE} ORDER BY band_url, item_title COLLATE NOCASE, track_number"
|
||||
}
|
||||
|
||||
function loadPreviews(locals, field, number) {
|
||||
const previews = db.prepare(`SELECT ${field}, item_url, item_art_url FROM (SELECT ${field}, item_url, item_art_url, row_number() OVER (PARTITION BY ${field} ORDER BY purchased DESC) AS row_number FROM item) WHERE row_number <= ?`).all(number)
|
||||
function loadPreviews(locals, field, number, whereClause, filter_field, filter) {
|
||||
const params = [number]
|
||||
let sql = `SELECT ${field}, item_url, item_art_url FROM (SELECT ${field}, item_url, item_art_url, row_number() OVER (PARTITION BY ${field} ORDER BY purchased DESC) AS row_number FROM item {JOIN TAG} {WHERE}) WHERE row_number <= ?`
|
||||
sql = sql.replace("{WHERE}", whereClause)
|
||||
if (whereClause) {
|
||||
params.unshift(filter)
|
||||
}
|
||||
if (filter_field === "tag" && filter) {
|
||||
sql = sql.replace("{JOIN TAG}", "INNER JOIN item_tag USING (item_id)")
|
||||
} else {
|
||||
sql = sql.replace("{JOIN TAG}", "")
|
||||
}
|
||||
const previews = db.prepare(sql).all(params)
|
||||
// TODO: performance?
|
||||
for (const item of locals.items) {
|
||||
item.previews = []
|
||||
|
@ -43,7 +55,7 @@ function loadPreviews(locals, field, number) {
|
|||
const schema = z.object({
|
||||
arrange: z.enum(["album", "artist", "label", "tag", "track"]),
|
||||
shape: z.enum(["grid", "list"]),
|
||||
filter_field: z.enum(["band_name", "band_url", "item_id"]).optional(),
|
||||
filter_field: z.enum(["band_name", "band_url", "item_id", "tag"]).optional(),
|
||||
filter: z.string().optional()
|
||||
})
|
||||
|
||||
|
@ -63,31 +75,54 @@ router.get("/", defineEventHandler({
|
|||
const mode = `${arrange}_${shape}`
|
||||
const params = []
|
||||
let sql = sqls[mode]
|
||||
let whereClause = ""
|
||||
if (filter_field && filter) {
|
||||
sql = sql.replace("{WHERE}", `WHERE ${filter_field} LIKE ?`)
|
||||
let operator = "="
|
||||
if (filter_field === "band_url") {
|
||||
operator = "LIKE"
|
||||
params.push(`%${filter}%`)
|
||||
} else {
|
||||
params.push(filter)
|
||||
}
|
||||
whereClause = `WHERE ${filter_field} ${operator} ?`
|
||||
sql = sql.replace("{ORDER}", "ORDER BY item_title COLLATE NOCASE")
|
||||
params.push(`%${filter}%`)
|
||||
} else {
|
||||
sql = sql.replace("{WHERE}", "")
|
||||
sql = sql.replace("{ORDER}", "ORDER BY purchased DESC")
|
||||
}
|
||||
sql = sql.replace("{WHERE}", whereClause)
|
||||
if (filter_field === "tag" && filter) {
|
||||
sql = sql.replace("{JOIN TAG}", "INNER JOIN item_tag USING (item_id)")
|
||||
} else {
|
||||
sql = sql.replace("{JOIN TAG}", "")
|
||||
}
|
||||
const prepared = db.prepare(sql)
|
||||
if (arrange === "tag") {
|
||||
prepared.raw()
|
||||
}
|
||||
const locals = {
|
||||
items: prepared.all(params),
|
||||
albumCount: db.prepare("SELECT count(*) FROM item WHERE item_type = 'album'").pluck().get(),
|
||||
singleCount: db.prepare("SELECT count(*) FROM item WHERE item_type = 'track'").pluck().get(),
|
||||
trackCount: db.prepare("SELECT count(*) FROM track").pluck().get(),
|
||||
purchaseValue: Math.round(select("item", ["currency", "price"]).all().map(c => {
|
||||
return (currencyExchange.get(c.currency) || 0.5) * c.price / (currencyExchange.get(displayCurrency) || 1) / 10
|
||||
}).reduce((a, c) => a + c, 0)) * 10,
|
||||
displayCurrencySymbol,
|
||||
displayCurrency,
|
||||
query
|
||||
query,
|
||||
count: [
|
||||
["total", db.prepare("SELECT count(*) FROM item").pluck().get()],
|
||||
["runtime", db.prepare("SELECT iif(sum(duration) > 86400, cast(total(duration)/86400 AS INTEGER) || 'd ' || cast(total(duration)/3600%24 AS INTEGER) || 'h', cast(total(duration)/3600 AS INTEGER) || 'h') FROM track").pluck().get()],
|
||||
["albums", db.prepare("SELECT count(*) FROM item WHERE item_type = 'album'").pluck().get()],
|
||||
["singles", db.prepare("SELECT count(*) FROM item WHERE item_type = 'track'").pluck().get()],
|
||||
["free", db.prepare("SELECT count(*) FROM item WHERE price = 0").pluck().get()],
|
||||
["paid", db.prepare("SELECT count(*) FROM item WHERE price > 0").pluck().get()],
|
||||
["tracks", db.prepare("SELECT count(*) FROM track").pluck().get()],
|
||||
["avg tracks", Math.round(db.prepare("SELECT avg(count) FROM (SELECT count(*) AS count FROM track INNER JOIN item USING (item_id) WHERE item_type = 'album' GROUP BY item_id)").pluck().get()*10)/10],
|
||||
["tags", db.prepare("SELECT count(*) FROM item_tag").pluck().get()],
|
||||
["avg tags", Math.round(db.prepare("SELECT avg(count) FROM (SELECT count(*) AS count FROM item_tag GROUP BY item_id)").pluck().get()*10)/10],
|
||||
["lonely tags", db.prepare("SELECT count(*) FROM (SELECT tag FROM item_tag GROUP BY tag HAVING count(*) = 1)").pluck().get()],
|
||||
["value", displayCurrencySymbol + Math.round(select("item", ["currency", "price"]).all().map(c => {
|
||||
return (currencyExchange.get(c.currency) || 0.6) * c.price / (currencyExchange.get(displayCurrency) || 1) / 10
|
||||
}).reduce((a, c) => a + c, 0)) * 10 + " " + displayCurrency]
|
||||
]
|
||||
}
|
||||
if (mode === "artist_grid") {
|
||||
loadPreviews(locals, "band_name", 4)
|
||||
loadPreviews(locals, "band_name", 4, whereClause, filter_field, filter)
|
||||
} else if (mode === "label_grid") {
|
||||
loadPreviews(locals, "band_url", 6)
|
||||
loadPreviews(locals, "band_url", 6, whereClause, filter_field, filter)
|
||||
}
|
||||
return pugSync.render(event, `${arrange}_${shape}.pug`, locals)
|
||||
}
|
||||
|
|
Loading…
Add table
Add a link
Reference in a new issue