Skip to content

Commit d2aed2e

Browse files
committed
add migration to fix and enhance fs_get_user_activity function
1 parent 8016531 commit d2aed2e

File tree

1 file changed

+177
-0
lines changed

1 file changed

+177
-0
lines changed
Lines changed: 177 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,177 @@
1+
exports.up = function (knex) {
2+
return knex.schema.raw(`
3+
DROP FUNCTION IF EXISTS fs_get_user_activity;
4+
5+
CREATE OR REPLACE FUNCTION fs_get_user_activity(
6+
user_id TEXT,
7+
library_ids TEXT[]
8+
)
9+
RETURNS TABLE (
10+
"UserName" TEXT,
11+
"Title" TEXT,
12+
"EpisodeCount" BIGINT,
13+
"FirstActivityDate" TIMESTAMPTZ,
14+
"LastActivityDate" TIMESTAMPTZ,
15+
"TotalPlaybackDuration" BIGINT,
16+
"SeasonName" TEXT,
17+
"MediaType" TEXT,
18+
"NowPlayingItemId" TEXT
19+
) AS $$
20+
BEGIN
21+
RETURN QUERY
22+
WITH DateDifferences AS (
23+
SELECT
24+
jp."UserName" AS "UserNameCol",
25+
CASE
26+
WHEN jp."SeriesName" IS NOT NULL THEN jp."SeriesName"
27+
ELSE jp."NowPlayingItemName"
28+
END AS "TitleCol",
29+
jp."EpisodeId" AS "EpisodeIdCol",
30+
jp."ActivityDateInserted" AS "ActivityDateInsertedCol",
31+
jp."PlaybackDuration" AS "PlaybackDurationCol",
32+
ls."Name" AS "SeasonNameCol",
33+
jl."CollectionType" AS "MediaTypeCol",
34+
jp."NowPlayingItemId" AS "NowPlayingItemIdCol",
35+
LAG(jp."ActivityDateInserted") OVER (PARTITION BY jp."UserName", CASE WHEN jp."SeriesName" IS NOT NULL THEN jp."SeriesName" ELSE jp."NowPlayingItemName" END ORDER BY jp."ActivityDateInserted") AS prev_date
36+
FROM
37+
public.jf_playback_activity AS jp
38+
JOIN
39+
public.jf_library_items AS jli ON jp."NowPlayingItemId" = jli."Id"
40+
JOIN
41+
public.jf_libraries AS jl ON jli."ParentId" = jl."Id"
42+
LEFT JOIN
43+
public.jf_library_seasons AS ls ON jp."SeasonId" = ls."Id"
44+
WHERE
45+
jp."UserId" = user_id
46+
AND jl."Id" = ANY(library_ids)
47+
),
48+
GroupedEntries AS (
49+
SELECT
50+
"UserNameCol",
51+
"TitleCol",
52+
"EpisodeIdCol",
53+
"ActivityDateInsertedCol",
54+
"PlaybackDurationCol",
55+
"SeasonNameCol",
56+
"MediaTypeCol",
57+
"NowPlayingItemIdCol",
58+
prev_date,
59+
CASE
60+
WHEN prev_date IS NULL OR "ActivityDateInsertedCol" > prev_date + INTERVAL '1 month' THEN 1 -- Pick whatever interval you want here, I'm biased as I don't monitor music / never intended this feature to be used for music
61+
ELSE 0
62+
END AS new_group
63+
FROM
64+
DateDifferences
65+
),
66+
FinalGroups AS (
67+
SELECT
68+
"UserNameCol",
69+
"TitleCol",
70+
"EpisodeIdCol",
71+
"ActivityDateInsertedCol",
72+
"PlaybackDurationCol",
73+
"SeasonNameCol",
74+
"MediaTypeCol",
75+
"NowPlayingItemIdCol",
76+
SUM(new_group) OVER (PARTITION BY "UserNameCol", "TitleCol" ORDER BY "ActivityDateInsertedCol") AS grp
77+
FROM
78+
GroupedEntries
79+
)
80+
SELECT
81+
"UserNameCol" AS "UserName",
82+
"TitleCol" AS "Title",
83+
COUNT(DISTINCT "EpisodeIdCol") AS "EpisodeCount",
84+
MIN("ActivityDateInsertedCol") AS "FirstActivityDate",
85+
MAX("ActivityDateInsertedCol") AS "LastActivityDate",
86+
SUM("PlaybackDurationCol")::bigint AS "TotalPlaybackDuration",
87+
"SeasonNameCol" AS "SeasonName",
88+
MAX("MediaTypeCol") AS "MediaType",
89+
"NowPlayingItemIdCol" AS "NowPlayingItemId"
90+
FROM
91+
FinalGroups
92+
GROUP BY
93+
"UserNameCol",
94+
"TitleCol",
95+
"SeasonNameCol",
96+
"NowPlayingItemIdCol",
97+
grp
98+
HAVING
99+
NOT (MAX("MediaTypeCol") = 'Shows' AND "SeasonNameCol" IS NULL)
100+
AND SUM("PlaybackDurationCol") >= 20
101+
ORDER BY
102+
MAX("ActivityDateInsertedCol") DESC;
103+
END;
104+
$$ LANGUAGE plpgsql;
105+
106+
`);
107+
};
108+
109+
exports.down = function (knex) {
110+
return knex.schema.raw(`
111+
112+
DROP FUNCTION IF EXISTS fs_get_user_activity;
113+
create or replace
114+
function fs_get_user_activity(
115+
user_id text,
116+
library_ids text[]
117+
)
118+
returns table (
119+
"UserName" text,
120+
"Title" text,
121+
"EpisodeCount" bigint,
122+
"FirstActivityDate" timestamptz,
123+
"LastActivityDate" timestamptz,
124+
"TotalPlaybackDuration" bigint,
125+
"SeasonName" text,
126+
"MediaType" text,
127+
"NowPlayingItemId" text
128+
) as $$
129+
begin
130+
return QUERY
131+
select
132+
jp."UserName",
133+
case
134+
when jp."SeriesName" is not null then jp."SeriesName"
135+
else jp."NowPlayingItemName"
136+
end as "Title",
137+
COUNT(distinct jp."EpisodeId") as "EpisodeCount",
138+
MIN(jp."ActivityDateInserted") as "FirstActivityDate",
139+
MAX(jp."ActivityDateInserted") as "LastActivityDate",
140+
SUM(jp."PlaybackDuration")::bigint as "TotalPlaybackDuration",
141+
ls."Name" as "SeasonName",
142+
MAX(jl."CollectionType") as "MediaType",
143+
jp."NowPlayingItemId"
144+
from
145+
public.jf_playback_activity as jp
146+
join
147+
public.jf_library_items as jli on
148+
jp."NowPlayingItemId" = jli."Id"
149+
join
150+
public.jf_libraries as jl on
151+
jli."ParentId" = jl."Id"
152+
left join
153+
public.jf_library_seasons as ls on
154+
jp."SeasonId" = ls."Id"
155+
where
156+
jp."UserId" = user_id
157+
and jl."Id" = any(library_ids)
158+
group by
159+
jp."UserName",
160+
case
161+
when jp."SeriesName" is not null then jp."SeriesName"
162+
else jp."NowPlayingItemName"
163+
end,
164+
jp."SeriesName",
165+
jp."SeasonId",
166+
ls."Name",
167+
jp."NowPlayingItemId"
168+
having
169+
not (MAX(jl."Name") = 'Shows'
170+
and ls."Name" is null)
171+
and SUM(jp."PlaybackDuration") >= 30
172+
order by
173+
MAX(jp."ActivityDateInserted") desc;
174+
end;
175+
$$ language plpgsql;
176+
`);
177+
};

0 commit comments

Comments
 (0)