mirror of
https://github.com/BreizhHardware/Jellystat.git
synced 2026-01-18 16:27:20 +01:00
optimized materialized view for possible duplication bug with activity having the same activity date
moved refresh views trigger to code as it caused a delay on inserts/updates/deletes
This commit is contained in:
@@ -47,6 +47,12 @@ async function deleteBulk(table_name, data, pkName) {
|
||||
|
||||
await client.query("COMMIT");
|
||||
message = data.length + " Rows removed.";
|
||||
|
||||
if (table_name === "jf_playback_activity") {
|
||||
for (const view of materializedViews) {
|
||||
refreshMaterializedView(view);
|
||||
}
|
||||
}
|
||||
} catch (error) {
|
||||
await client.query("ROLLBACK");
|
||||
message = "Bulk delete error: " + error;
|
||||
@@ -87,6 +93,32 @@ async function updateSingleFieldBulk(table_name, data, field_name, new_value, wh
|
||||
return { Result: result, message: "" + message };
|
||||
}
|
||||
|
||||
const materializedViews = ["js_latest_playback_activity", "js_library_stats_overview"];
|
||||
|
||||
async function refreshMaterializedView(view_name) {
|
||||
const client = await pool.connect();
|
||||
let result = "SUCCESS";
|
||||
let message = "";
|
||||
try {
|
||||
await client.query("BEGIN");
|
||||
|
||||
const refreshQuery = {
|
||||
text: `REFRESH MATERIALIZED VIEW ${view_name}`,
|
||||
};
|
||||
await client.query(refreshQuery);
|
||||
|
||||
await client.query("COMMIT");
|
||||
message = view_name + " refreshed.";
|
||||
} catch (error) {
|
||||
await client.query("ROLLBACK");
|
||||
message = "Refresh materialized view error: " + error;
|
||||
result = "ERROR";
|
||||
} finally {
|
||||
client.release();
|
||||
}
|
||||
return { Result: result, message: "" + message };
|
||||
}
|
||||
|
||||
async function insertBulk(table_name, data, columns) {
|
||||
//dedupe data
|
||||
|
||||
@@ -115,6 +147,12 @@ async function insertBulk(table_name, data, columns) {
|
||||
const query = pgp.helpers.insert(data, cs) + update_query; // Update the column names accordingly
|
||||
await client.query(query);
|
||||
await client.query("COMMIT");
|
||||
|
||||
if (table_name === "jf_playback_activity") {
|
||||
for (const view of materializedViews) {
|
||||
refreshMaterializedView(view);
|
||||
}
|
||||
}
|
||||
} catch (error) {
|
||||
await client.query("ROLLBACK");
|
||||
message = "" + error;
|
||||
@@ -128,9 +166,15 @@ async function insertBulk(table_name, data, columns) {
|
||||
};
|
||||
}
|
||||
|
||||
async function query(text, params) {
|
||||
async function query(text, params, refreshViews = false) {
|
||||
try {
|
||||
const result = await pool.query(text, params);
|
||||
|
||||
if (refreshViews) {
|
||||
for (const view of materializedViews) {
|
||||
refreshMaterializedView(view);
|
||||
}
|
||||
}
|
||||
return result;
|
||||
} catch (error) {
|
||||
if (error?.routine === "auth_failed") {
|
||||
|
||||
@@ -0,0 +1,21 @@
|
||||
exports.up = async function (knex) {
|
||||
try {
|
||||
await knex.schema.raw(`
|
||||
DROP TRIGGER IF EXISTS refresh_js_library_stats_overview_trigger ON public.jf_playback_activity;
|
||||
DROP TRIGGER IF EXISTS refresh_js_latest_playback_activity_trigger ON public.jf_playback_activity;
|
||||
`);
|
||||
} catch (error) {
|
||||
console.error(error);
|
||||
}
|
||||
};
|
||||
|
||||
exports.down = async function (knex) {
|
||||
try {
|
||||
await knex.schema.raw(`
|
||||
DROP TRIGGER IF EXISTS refresh_js_library_stats_overview_trigger ON public.jf_playback_activity;
|
||||
DROP TRIGGER IF EXISTS refresh_js_latest_playback_activity_trigger ON public.jf_playback_activity;
|
||||
`);
|
||||
} catch (error) {
|
||||
console.error(error);
|
||||
}
|
||||
};
|
||||
114
backend/migrations/087_optimize_js_latest_playback_activity.js
Normal file
114
backend/migrations/087_optimize_js_latest_playback_activity.js
Normal file
@@ -0,0 +1,114 @@
|
||||
exports.up = async function (knex) {
|
||||
try {
|
||||
await knex.schema.raw(`
|
||||
DROP MATERIALIZED VIEW IF EXISTS public.js_latest_playback_activity;
|
||||
|
||||
CREATE MATERIALIZED VIEW js_latest_playback_activity AS
|
||||
WITH ranked_activity AS (
|
||||
SELECT
|
||||
"Id",
|
||||
"IsPaused",
|
||||
"UserId",
|
||||
"UserName",
|
||||
"Client",
|
||||
"DeviceName",
|
||||
"DeviceId",
|
||||
"ApplicationVersion",
|
||||
"NowPlayingItemId",
|
||||
"NowPlayingItemName",
|
||||
"SeasonId",
|
||||
"SeriesName",
|
||||
"EpisodeId",
|
||||
"PlaybackDuration",
|
||||
"ActivityDateInserted",
|
||||
"PlayMethod",
|
||||
"MediaStreams",
|
||||
"TranscodingInfo",
|
||||
"PlayState",
|
||||
"OriginalContainer",
|
||||
"RemoteEndPoint",
|
||||
"ServerId",
|
||||
imported,
|
||||
"EpisodeNumber",
|
||||
"SeasonNumber",
|
||||
"ParentId",
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY "NowPlayingItemId", COALESCE("EpisodeId", '1'), "UserId"
|
||||
ORDER BY "ActivityDateInserted" DESC
|
||||
) AS rn
|
||||
FROM jf_playback_activity_with_metadata
|
||||
)
|
||||
SELECT
|
||||
"Id",
|
||||
"IsPaused",
|
||||
"UserId",
|
||||
"UserName",
|
||||
"Client",
|
||||
"DeviceName",
|
||||
"DeviceId",
|
||||
"ApplicationVersion",
|
||||
"NowPlayingItemId",
|
||||
"NowPlayingItemName",
|
||||
"SeasonId",
|
||||
"SeriesName",
|
||||
"EpisodeId",
|
||||
"PlaybackDuration",
|
||||
"ActivityDateInserted",
|
||||
"PlayMethod",
|
||||
"MediaStreams",
|
||||
"TranscodingInfo",
|
||||
"PlayState",
|
||||
"OriginalContainer",
|
||||
"RemoteEndPoint",
|
||||
"ServerId",
|
||||
imported,
|
||||
"EpisodeNumber",
|
||||
"SeasonNumber",
|
||||
"ParentId"
|
||||
FROM ranked_activity
|
||||
WHERE rn = 1
|
||||
ORDER BY "ActivityDateInserted" DESC;
|
||||
|
||||
|
||||
ALTER MATERIALIZED VIEW public.js_latest_playback_activity
|
||||
OWNER TO "${process.env.POSTGRES_ROLE}";
|
||||
`);
|
||||
} catch (error) {
|
||||
console.error(error);
|
||||
}
|
||||
};
|
||||
|
||||
exports.down = async function (knex) {
|
||||
try {
|
||||
await knex.schema.raw(`
|
||||
DROP MATERIALIZED VIEW IF EXISTS public.js_latest_playback_activity;
|
||||
|
||||
CREATE MATERIALIZED VIEW js_latest_playback_activity AS
|
||||
WITH latest_activity AS (
|
||||
SELECT
|
||||
"NowPlayingItemId",
|
||||
"EpisodeId",
|
||||
"UserId",
|
||||
MAX("ActivityDateInserted") AS max_date
|
||||
FROM public.jf_playback_activity
|
||||
GROUP BY "NowPlayingItemId", "EpisodeId", "UserId"
|
||||
order by max_date desc
|
||||
)
|
||||
SELECT
|
||||
a.*
|
||||
FROM public.jf_playback_activity_with_metadata a
|
||||
JOIN latest_activity u
|
||||
ON a."NowPlayingItemId" = u."NowPlayingItemId"
|
||||
AND COALESCE(a."EpisodeId", '1') = COALESCE(u."EpisodeId", '1')
|
||||
AND a."UserId" = u."UserId"
|
||||
AND a."ActivityDateInserted" = u.max_date
|
||||
order by a."ActivityDateInserted" desc;
|
||||
|
||||
|
||||
ALTER MATERIALIZED VIEW public.js_latest_playback_activity
|
||||
OWNER TO "${process.env.POSTGRES_ROLE}";
|
||||
`);
|
||||
} catch (error) {
|
||||
console.error(error);
|
||||
}
|
||||
};
|
||||
@@ -0,0 +1,130 @@
|
||||
exports.up = async function (knex) {
|
||||
try {
|
||||
await knex.schema.raw(`
|
||||
DROP MATERIALIZED VIEW IF EXISTS public.js_library_stats_overview;
|
||||
|
||||
CREATE MATERIALIZED VIEW public.js_library_stats_overview
|
||||
AS
|
||||
SELECT l."Id",
|
||||
l."Name",
|
||||
l."ServerId",
|
||||
l."IsFolder",
|
||||
l."Type",
|
||||
l."CollectionType",
|
||||
l."ImageTagsPrimary",
|
||||
i."Id" AS "ItemId",
|
||||
i."Name" AS "ItemName",
|
||||
i."Type" AS "ItemType",
|
||||
i."PrimaryImageHash",
|
||||
s."IndexNumber" AS "SeasonNumber",
|
||||
e."IndexNumber" AS "EpisodeNumber",
|
||||
e."Name" AS "EpisodeName",
|
||||
( SELECT count(*) AS count
|
||||
FROM jf_playback_activity_with_metadata a
|
||||
WHERE a."ParentId" = l."Id") AS "Plays",
|
||||
( SELECT sum(a."PlaybackDuration") AS sum
|
||||
FROM jf_playback_activity_with_metadata a
|
||||
WHERE a."ParentId" = l."Id") AS total_playback_duration,
|
||||
l.total_play_time::numeric AS total_play_time,
|
||||
l.item_count AS "Library_Count",
|
||||
l.season_count AS "Season_Count",
|
||||
l.episode_count AS "Episode_Count",
|
||||
l.archived,
|
||||
now() - latest_activity."ActivityDateInserted" AS "LastActivity"
|
||||
FROM jf_libraries l
|
||||
LEFT JOIN ( SELECT jso."Id",
|
||||
jso."NowPlayingItemId",
|
||||
jso."SeasonId",
|
||||
jso."EpisodeId",
|
||||
jso."ParentId",
|
||||
jso."ActivityDateInserted"
|
||||
FROM js_latest_playback_activity jso
|
||||
JOIN ( SELECT js_latest_playback_activity."ParentId",
|
||||
max(js_latest_playback_activity."ActivityDateInserted") AS max_date
|
||||
FROM js_latest_playback_activity
|
||||
GROUP BY js_latest_playback_activity."ParentId") latest
|
||||
ON jso."ParentId" = latest."ParentId" AND jso."ActivityDateInserted" = latest.max_date )
|
||||
latest_activity ON l."Id" = latest_activity."ParentId"
|
||||
|
||||
LEFT JOIN jf_library_items i ON i."Id" = latest_activity."NowPlayingItemId"
|
||||
LEFT JOIN jf_library_seasons s ON s."Id" = latest_activity."SeasonId"
|
||||
LEFT JOIN jf_library_episodes e ON e."EpisodeId" = latest_activity."EpisodeId"
|
||||
ORDER BY l."Id", latest_activity."ActivityDateInserted" DESC;
|
||||
|
||||
|
||||
ALTER MATERIALIZED VIEW public.js_library_stats_overview
|
||||
OWNER TO "${process.env.POSTGRES_ROLE}";
|
||||
`);
|
||||
} catch (error) {
|
||||
console.error(error);
|
||||
}
|
||||
};
|
||||
|
||||
exports.down = async function (knex) {
|
||||
try {
|
||||
await knex.schema.raw(`
|
||||
DROP MATERIALIZED VIEW IF EXISTS public.js_library_stats_overview;
|
||||
|
||||
CREATE MATERIALIZED VIEW public.js_library_stats_overview
|
||||
AS
|
||||
SELECT l."Id",
|
||||
l."Name",
|
||||
l."ServerId",
|
||||
l."IsFolder",
|
||||
l."Type",
|
||||
l."CollectionType",
|
||||
l."ImageTagsPrimary",
|
||||
i."Id" AS "ItemId",
|
||||
i."Name" AS "ItemName",
|
||||
i."Type" AS "ItemType",
|
||||
i."PrimaryImageHash",
|
||||
s."IndexNumber" AS "SeasonNumber",
|
||||
e."IndexNumber" AS "EpisodeNumber",
|
||||
e."Name" AS "EpisodeName",
|
||||
( SELECT count(*) AS count
|
||||
FROM jf_playback_activity_with_metadata a
|
||||
WHERE a."ParentId" = l."Id") AS "Plays",
|
||||
( SELECT sum(a."PlaybackDuration") AS sum
|
||||
FROM jf_playback_activity_with_metadata a
|
||||
WHERE a."ParentId" = l."Id") AS total_playback_duration,
|
||||
l.total_play_time::numeric AS total_play_time,
|
||||
l.item_count AS "Library_Count",
|
||||
l.season_count AS "Season_Count",
|
||||
l.episode_count AS "Episode_Count",
|
||||
l.archived,
|
||||
now() - latest_activity."ActivityDateInserted" AS "LastActivity"
|
||||
FROM jf_libraries l
|
||||
LEFT JOIN (
|
||||
|
||||
SELECT
|
||||
jso."Id",
|
||||
jso."NowPlayingItemId",
|
||||
jso."SeasonId",
|
||||
jso."EpisodeId",
|
||||
jso."ParentId",
|
||||
jso."ActivityDateInserted"
|
||||
FROM
|
||||
jf_playback_activity_with_metadata jso
|
||||
INNER JOIN (
|
||||
SELECT
|
||||
"ParentId",
|
||||
MAX("ActivityDateInserted") AS max_date
|
||||
FROM
|
||||
jf_playback_activity_with_metadata
|
||||
GROUP BY
|
||||
"ParentId"
|
||||
) latest ON jso."ParentId" = latest."ParentId" AND jso."ActivityDateInserted" = latest.max_date
|
||||
|
||||
) latest_activity ON l."Id" = latest_activity."ParentId"
|
||||
LEFT JOIN jf_library_items i ON i."Id" = latest_activity."NowPlayingItemId"
|
||||
LEFT JOIN jf_library_seasons s ON s."Id" = latest_activity."SeasonId"
|
||||
LEFT JOIN jf_library_episodes e ON e."EpisodeId" = latest_activity."EpisodeId"
|
||||
ORDER BY l."Id", latest_activity."ActivityDateInserted" DESC;
|
||||
|
||||
|
||||
ALTER MATERIALIZED VIEW public.js_library_stats_overview
|
||||
OWNER TO "${process.env.POSTGRES_ROLE}";`);
|
||||
} catch (error) {
|
||||
console.error(error);
|
||||
}
|
||||
};
|
||||
@@ -93,6 +93,7 @@ async function purgeLibraryItems(id, withActivity, purgeAll = false) {
|
||||
text: `DELETE FROM jf_playback_activity WHERE${
|
||||
episodeIds.length > 0 ? ` "EpisodeId" IN (${pgp.as.csv(episodeIds)}) OR` : ""
|
||||
}${seasonIds.length > 0 ? ` "SeasonId" IN (${pgp.as.csv(seasonIds)}) OR` : ""} "NowPlayingItemId"='${id}'`,
|
||||
refreshViews: true,
|
||||
};
|
||||
await db.query(deleteQuery);
|
||||
}
|
||||
@@ -923,6 +924,7 @@ router.delete("/item/purge", async (req, res) => {
|
||||
}${
|
||||
seasons.length > 0 ? ` "SeasonId" IN (${pgp.as.csv(seasons.map((item) => item.SeasonId))}) OR` : ""
|
||||
} "NowPlayingItemId"='${id}'`,
|
||||
refreshViews: true,
|
||||
};
|
||||
await db.query(deleteQuery);
|
||||
}
|
||||
@@ -1318,7 +1320,7 @@ router.post("/deletePlaybackActivity", async (req, res) => {
|
||||
return;
|
||||
}
|
||||
|
||||
await db.query(`DELETE from jf_playback_activity where "Id" = ANY($1)`, [ids]);
|
||||
await db.query(`DELETE from jf_playback_activity where "Id" = ANY($1)`, [ids], true);
|
||||
res.send(`${ids.length} Records Deleted`);
|
||||
} catch (error) {
|
||||
console.log(error);
|
||||
|
||||
Reference in New Issue
Block a user