Files
Jellystat/SQL Scripts/2. CREATE FUNCTIONS/CREATE FUNCTION fs_most_viewed_libraries.sql
Thegan Govender 582a39918e full change to statistics
1) Created components for statistic reporting.
2) Database changes and PROC/Function creations. Still need to make MOST VIEWED LIBRARIES/CLIENTS/ MOST ACTIVE USERS dynamically load with date range (Function Creation on DB side)
2023-03-19 22:01:40 +02:00

49 lines
1.3 KiB
PL/PgSQL

-- FUNCTION: public.fs_most_viewed_libraries(integer)
-- DROP FUNCTION IF EXISTS public.fs_most_viewed_libraries(integer);
CREATE OR REPLACE FUNCTION public.fs_most_viewed_libraries(
days integer)
RETURNS TABLE("Plays" numeric, "Id" text, "Name" text, "ServerId" text, "IsFolder" boolean, "Type" text, "CollectionType" text, "ImageTagsPrimary" text)
LANGUAGE 'plpgsql'
COST 100
VOLATILE PARALLEL UNSAFE
ROWS 1000
AS $BODY$
BEGIN
RETURN QUERY
SELECT
sum(t."Plays"),
l."Id",
l."Name",
l."ServerId",
l."IsFolder",
l."Type",
l."CollectionType",
l."ImageTagsPrimary"
FROM (
SELECT count(*) AS "Plays",
sum(jf_playback_activity."PlaybackDuration") AS "TotalPlaybackDuration",
jf_playback_activity."NowPlayingItemId"
FROM jf_playback_activity
WHERE
jf_playback_activity."ActivityDateInserted" BETWEEN CURRENT_DATE - MAKE_INTERVAL(days => days) and NOW()
GROUP BY jf_playback_activity."NowPlayingItemId"
ORDER BY "Plays" DESC
) t
JOIN jf_library_items i
ON i."Id" = t."NowPlayingItemId"
JOIN jf_libraries l
ON l."Id" = i."ParentId"
GROUP BY
l."Id"
ORDER BY
(sum( t."Plays")) DESC;
END;
$BODY$;
ALTER FUNCTION public.fs_most_viewed_libraries(integer)
OWNER TO postgres;