mirror of
https://github.com/BreizhHardware/Jellystat.git
synced 2026-01-18 16:27:20 +01:00
updated migrations to account for migrations from unstable branch
This commit is contained in:
@@ -1,23 +0,0 @@
|
||||
exports.up = function(knex) {
|
||||
return knex.schema.createTable('webhooks', table => {
|
||||
table.increments('id').primary();
|
||||
table.string('name').notNullable();
|
||||
table.string('url').notNullable();
|
||||
table.text('headers').defaultTo('{}');
|
||||
table.text('payload').defaultTo('{}');
|
||||
table.string('method').defaultTo('POST');
|
||||
table.string('trigger_type').notNullable();
|
||||
table.string('webhook_type').defaultTo('generic');
|
||||
table.string('schedule').nullable();
|
||||
table.string('event_type').nullable();
|
||||
table.boolean('enabled').defaultTo(true);
|
||||
table.timestamp('last_triggered').nullable();
|
||||
table.boolean('retry_on_failure').defaultTo(false);
|
||||
table.integer('max_retries').defaultTo(3);
|
||||
table.timestamps(true, true);
|
||||
});
|
||||
};
|
||||
|
||||
exports.down = function(knex) {
|
||||
return knex.schema.dropTable('webhooks');
|
||||
};
|
||||
@@ -0,0 +1,121 @@
|
||||
exports.up = async function (knex) {
|
||||
try {
|
||||
await knex.schema.raw(`
|
||||
DROP FUNCTION IF EXISTS public.fs_watch_stats_over_time(integer);
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.fs_watch_stats_over_time(
|
||||
days integer)
|
||||
RETURNS TABLE("Date" date, "Count" bigint, "Duration" bigint, "Library" text, "LibraryID" text)
|
||||
LANGUAGE 'plpgsql'
|
||||
COST 100
|
||||
VOLATILE PARALLEL UNSAFE
|
||||
ROWS 1000
|
||||
|
||||
AS $BODY$
|
||||
BEGIN
|
||||
RETURN QUERY
|
||||
SELECT
|
||||
dates."Date",
|
||||
COALESCE(counts."Count", 0) AS "Count",
|
||||
COALESCE(counts."Duration", 0) AS "Duration",
|
||||
l."Name" as "Library",
|
||||
l."Id" as "LibraryID"
|
||||
FROM
|
||||
(SELECT generate_series(
|
||||
DATE_TRUNC('day', NOW() - CAST(days || ' days' as INTERVAL)),
|
||||
DATE_TRUNC('day', NOW()),
|
||||
'1 day')::DATE AS "Date"
|
||||
) dates
|
||||
CROSS JOIN jf_libraries l
|
||||
|
||||
LEFT JOIN
|
||||
(SELECT
|
||||
DATE_TRUNC('day', a."ActivityDateInserted")::DATE AS "Date",
|
||||
COUNT(*) AS "Count",
|
||||
(SUM(a."PlaybackDuration") / 60)::bigint AS "Duration",
|
||||
l."Name" as "Library"
|
||||
FROM
|
||||
jf_playback_activity a
|
||||
JOIN jf_library_items i ON i."Id" = a."NowPlayingItemId"
|
||||
JOIN jf_libraries l ON i."ParentId" = l."Id"
|
||||
WHERE
|
||||
a."ActivityDateInserted" BETWEEN NOW() - CAST(days || ' days' as INTERVAL) AND NOW()
|
||||
|
||||
GROUP BY
|
||||
l."Name", DATE_TRUNC('day', a."ActivityDateInserted")
|
||||
) counts
|
||||
ON counts."Date" = dates."Date" AND counts."Library" = l."Name"
|
||||
where l.archived=false
|
||||
|
||||
ORDER BY
|
||||
"Date", "Library";
|
||||
END;
|
||||
|
||||
$BODY$;
|
||||
|
||||
ALTER FUNCTION public.fs_watch_stats_over_time(integer)
|
||||
OWNER TO "${process.env.POSTGRES_ROLE}";
|
||||
`);
|
||||
} catch (error) {
|
||||
console.error(error);
|
||||
}
|
||||
};
|
||||
|
||||
exports.down = async function (knex) {
|
||||
try {
|
||||
await knex.schema.raw(`
|
||||
DROP FUNCTION IF EXISTS public.fs_watch_stats_over_time(integer);
|
||||
|
||||
CREATE OR REPLACE FUNCTION fs_watch_stats_over_time(
|
||||
days integer
|
||||
)
|
||||
RETURNS TABLE(
|
||||
"Date" date,
|
||||
"Count" bigint,
|
||||
"Library" text
|
||||
)
|
||||
LANGUAGE 'plpgsql'
|
||||
COST 100
|
||||
VOLATILE PARALLEL UNSAFE
|
||||
ROWS 1000
|
||||
|
||||
AS $BODY$
|
||||
BEGIN
|
||||
RETURN QUERY
|
||||
SELECT
|
||||
dates."Date",
|
||||
COALESCE(counts."Count", 0) AS "Count",
|
||||
l."Name" as "Library"
|
||||
FROM
|
||||
(SELECT generate_series(
|
||||
DATE_TRUNC('day', NOW() - CAST(days || ' days' as INTERVAL)),
|
||||
DATE_TRUNC('day', NOW()),
|
||||
'1 day')::DATE AS "Date"
|
||||
) dates
|
||||
CROSS JOIN jf_libraries l
|
||||
LEFT JOIN
|
||||
(SELECT
|
||||
DATE_TRUNC('day', a."ActivityDateInserted")::DATE AS "Date",
|
||||
COUNT(*) AS "Count",
|
||||
l."Name" as "Library"
|
||||
FROM
|
||||
jf_playback_activity a
|
||||
JOIN jf_library_items i ON i."Id" = a."NowPlayingItemId"
|
||||
JOIN jf_libraries l ON i."ParentId" = l."Id"
|
||||
WHERE
|
||||
a."ActivityDateInserted" BETWEEN NOW() - CAST(days || ' days' as INTERVAL) AND NOW()
|
||||
GROUP BY
|
||||
l."Name", DATE_TRUNC('day', a."ActivityDateInserted")
|
||||
) counts
|
||||
ON counts."Date" = dates."Date" AND counts."Library" = l."Name"
|
||||
ORDER BY
|
||||
"Date", "Library";
|
||||
END;
|
||||
$BODY$;
|
||||
|
||||
ALTER FUNCTION fs_watch_stats_over_time(integer)
|
||||
OWNER TO "${process.env.POSTGRES_ROLE}";`);
|
||||
} catch (error) {
|
||||
console.error(error);
|
||||
}
|
||||
};
|
||||
@@ -0,0 +1,143 @@
|
||||
exports.up = async function (knex) {
|
||||
try {
|
||||
await knex.schema.raw(`
|
||||
DROP FUNCTION IF EXISTS public.fs_watch_stats_popular_days_of_week(integer);
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.fs_watch_stats_popular_days_of_week(
|
||||
days integer)
|
||||
RETURNS TABLE("Day" text, "Count" bigint, "Duration" bigint, "Library" text)
|
||||
LANGUAGE 'plpgsql'
|
||||
COST 100
|
||||
VOLATILE PARALLEL UNSAFE
|
||||
ROWS 1000
|
||||
|
||||
AS $BODY$
|
||||
BEGIN
|
||||
RETURN QUERY
|
||||
WITH library_days AS (
|
||||
SELECT
|
||||
l."Name" AS "Library",
|
||||
d.day_of_week,
|
||||
d.day_name
|
||||
FROM
|
||||
jf_libraries l,
|
||||
(SELECT 0 AS "day_of_week", 'Sunday' AS "day_name" UNION ALL
|
||||
SELECT 1 AS "day_of_week", 'Monday' AS "day_name" UNION ALL
|
||||
SELECT 2 AS "day_of_week", 'Tuesday' AS "day_name" UNION ALL
|
||||
SELECT 3 AS "day_of_week", 'Wednesday' AS "day_name" UNION ALL
|
||||
SELECT 4 AS "day_of_week", 'Thursday' AS "day_name" UNION ALL
|
||||
SELECT 5 AS "day_of_week", 'Friday' AS "day_name" UNION ALL
|
||||
SELECT 6 AS "day_of_week", 'Saturday' AS "day_name"
|
||||
) d
|
||||
where l.archived=false
|
||||
)
|
||||
SELECT
|
||||
library_days.day_name AS "Day",
|
||||
COALESCE(SUM(counts."Count"), 0)::bigint AS "Count",
|
||||
COALESCE(SUM(counts."Duration"), 0)::bigint AS "Duration",
|
||||
library_days."Library" AS "Library"
|
||||
FROM
|
||||
library_days
|
||||
LEFT JOIN
|
||||
(SELECT
|
||||
DATE_TRUNC('day', a."ActivityDateInserted")::DATE AS "Date",
|
||||
COUNT(*) AS "Count",
|
||||
(SUM(a."PlaybackDuration") / 60)::bigint AS "Duration",
|
||||
EXTRACT(DOW FROM a."ActivityDateInserted") AS "DOW",
|
||||
l."Name" AS "Library"
|
||||
FROM
|
||||
jf_playback_activity a
|
||||
JOIN jf_library_items i ON i."Id" = a."NowPlayingItemId"
|
||||
JOIN jf_libraries l ON i."ParentId" = l."Id" and l.archived=false
|
||||
WHERE
|
||||
a."ActivityDateInserted" BETWEEN NOW() - CAST(days || ' days' as INTERVAL) AND NOW()
|
||||
GROUP BY
|
||||
l."Name", EXTRACT(DOW FROM a."ActivityDateInserted"), DATE_TRUNC('day', a."ActivityDateInserted")
|
||||
) counts
|
||||
ON counts."DOW" = library_days.day_of_week AND counts."Library" = library_days."Library"
|
||||
GROUP BY
|
||||
library_days.day_name, library_days.day_of_week, library_days."Library"
|
||||
ORDER BY
|
||||
library_days.day_of_week, library_days."Library";
|
||||
END;
|
||||
|
||||
$BODY$;
|
||||
|
||||
ALTER FUNCTION public.fs_watch_stats_popular_days_of_week(integer)
|
||||
OWNER TO "${process.env.POSTGRES_ROLE}";
|
||||
`);
|
||||
} catch (error) {
|
||||
console.error(error);
|
||||
}
|
||||
};
|
||||
|
||||
exports.down = async function (knex) {
|
||||
try {
|
||||
await knex.schema.raw(`
|
||||
DROP FUNCTION IF EXISTS public.fs_watch_stats_popular_days_of_week(integer);
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.fs_watch_stats_popular_days_of_week(
|
||||
days integer)
|
||||
RETURNS TABLE("Day" text, "Count" bigint, "Library" text)
|
||||
LANGUAGE 'plpgsql'
|
||||
COST 100
|
||||
VOLATILE PARALLEL UNSAFE
|
||||
ROWS 1000
|
||||
|
||||
AS $BODY$
|
||||
BEGIN
|
||||
RETURN QUERY
|
||||
WITH library_days AS (
|
||||
SELECT
|
||||
l."Name" AS "Library",
|
||||
d.day_of_week,
|
||||
d.day_name
|
||||
FROM
|
||||
jf_libraries l,
|
||||
(SELECT 0 AS "day_of_week", 'Sunday' AS "day_name" UNION ALL
|
||||
SELECT 1 AS "day_of_week", 'Monday' AS "day_name" UNION ALL
|
||||
SELECT 2 AS "day_of_week", 'Tuesday' AS "day_name" UNION ALL
|
||||
SELECT 3 AS "day_of_week", 'Wednesday' AS "day_name" UNION ALL
|
||||
SELECT 4 AS "day_of_week", 'Thursday' AS "day_name" UNION ALL
|
||||
SELECT 5 AS "day_of_week", 'Friday' AS "day_name" UNION ALL
|
||||
SELECT 6 AS "day_of_week", 'Saturday' AS "day_name"
|
||||
) d
|
||||
where l.archived=false
|
||||
)
|
||||
SELECT
|
||||
library_days.day_name AS "Day",
|
||||
COALESCE(SUM(counts."Count"), 0)::bigint AS "Count",
|
||||
library_days."Library" AS "Library"
|
||||
FROM
|
||||
library_days
|
||||
LEFT JOIN
|
||||
(SELECT
|
||||
DATE_TRUNC('day', a."ActivityDateInserted")::DATE AS "Date",
|
||||
COUNT(*) AS "Count",
|
||||
EXTRACT(DOW FROM a."ActivityDateInserted") AS "DOW",
|
||||
l."Name" AS "Library"
|
||||
FROM
|
||||
jf_playback_activity a
|
||||
JOIN jf_library_items i ON i."Id" = a."NowPlayingItemId"
|
||||
JOIN jf_libraries l ON i."ParentId" = l."Id" and l.archived=false
|
||||
WHERE
|
||||
a."ActivityDateInserted" BETWEEN NOW() - CAST(days || ' days' as INTERVAL) AND NOW()
|
||||
GROUP BY
|
||||
l."Name", EXTRACT(DOW FROM a."ActivityDateInserted"), DATE_TRUNC('day', a."ActivityDateInserted")
|
||||
) counts
|
||||
ON counts."DOW" = library_days.day_of_week AND counts."Library" = library_days."Library"
|
||||
GROUP BY
|
||||
library_days.day_name, library_days.day_of_week, library_days."Library"
|
||||
ORDER BY
|
||||
library_days.day_of_week, library_days."Library";
|
||||
END;
|
||||
|
||||
$BODY$;
|
||||
|
||||
ALTER FUNCTION public.fs_watch_stats_popular_days_of_week(integer)
|
||||
OWNER TO "${process.env.POSTGRES_ROLE}";
|
||||
`);
|
||||
} catch (error) {
|
||||
console.error(error);
|
||||
}
|
||||
};
|
||||
@@ -0,0 +1,117 @@
|
||||
exports.up = async function (knex) {
|
||||
try {
|
||||
await knex.schema.raw(`
|
||||
DROP FUNCTION IF EXISTS public.fs_watch_stats_popular_hour_of_day(integer);
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.fs_watch_stats_popular_hour_of_day(
|
||||
days integer)
|
||||
RETURNS TABLE("Hour" integer, "Count" integer, "Duration" integer, "Library" text)
|
||||
LANGUAGE 'plpgsql'
|
||||
COST 100
|
||||
VOLATILE PARALLEL UNSAFE
|
||||
ROWS 1000
|
||||
|
||||
AS $BODY$
|
||||
BEGIN
|
||||
RETURN QUERY
|
||||
SELECT
|
||||
h."Hour",
|
||||
COUNT(a."Id")::integer AS "Count",
|
||||
COALESCE(SUM(a."PlaybackDuration") / 60, 0)::integer AS "Duration",
|
||||
l."Name" AS "Library"
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
generate_series(0, 23) AS "Hour"
|
||||
) h
|
||||
CROSS JOIN jf_libraries l
|
||||
LEFT JOIN jf_library_items i ON i."ParentId" = l."Id"
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
"NowPlayingItemId",
|
||||
DATE_PART('hour', "ActivityDateInserted") AS "Hour",
|
||||
"Id",
|
||||
"PlaybackDuration"
|
||||
FROM
|
||||
jf_playback_activity
|
||||
WHERE
|
||||
"ActivityDateInserted" BETWEEN NOW() - CAST(days || ' days' AS INTERVAL) AND NOW()
|
||||
) a ON a."NowPlayingItemId" = i."Id" AND a."Hour"::integer = h."Hour"
|
||||
WHERE
|
||||
l.archived=false
|
||||
and l."Id" IN (SELECT "Id" FROM jf_libraries)
|
||||
GROUP BY
|
||||
h."Hour",
|
||||
l."Name"
|
||||
ORDER BY
|
||||
l."Name",
|
||||
h."Hour";
|
||||
END;
|
||||
|
||||
$BODY$;
|
||||
|
||||
ALTER FUNCTION public.fs_watch_stats_popular_hour_of_day(integer)
|
||||
OWNER TO "${process.env.POSTGRES_ROLE}";
|
||||
`);
|
||||
} catch (error) {
|
||||
console.error(error);
|
||||
}
|
||||
};
|
||||
|
||||
exports.down = async function (knex) {
|
||||
try {
|
||||
await knex.schema.raw(`
|
||||
DROP FUNCTION IF EXISTS public.fs_watch_stats_popular_hour_of_day(integer);
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.fs_watch_stats_popular_hour_of_day(
|
||||
days integer)
|
||||
RETURNS TABLE("Hour" integer, "Count" integer, "Library" text)
|
||||
LANGUAGE 'plpgsql'
|
||||
COST 100
|
||||
VOLATILE PARALLEL UNSAFE
|
||||
ROWS 1000
|
||||
|
||||
AS $BODY$
|
||||
BEGIN
|
||||
RETURN QUERY
|
||||
SELECT
|
||||
h."Hour",
|
||||
COUNT(a."Id")::integer AS "Count",
|
||||
l."Name" AS "Library"
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
generate_series(0, 23) AS "Hour"
|
||||
) h
|
||||
CROSS JOIN jf_libraries l
|
||||
LEFT JOIN jf_library_items i ON i."ParentId" = l."Id"
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
"NowPlayingItemId",
|
||||
DATE_PART('hour', "ActivityDateInserted") AS "Hour",
|
||||
"Id"
|
||||
FROM
|
||||
jf_playback_activity
|
||||
WHERE
|
||||
"ActivityDateInserted" BETWEEN NOW() - CAST(days || ' days' AS INTERVAL) AND NOW()
|
||||
) a ON a."NowPlayingItemId" = i."Id" AND a."Hour"::integer = h."Hour"
|
||||
WHERE
|
||||
l.archived=false
|
||||
and l."Id" IN (SELECT "Id" FROM jf_libraries)
|
||||
GROUP BY
|
||||
h."Hour",
|
||||
l."Name"
|
||||
ORDER BY
|
||||
l."Name",
|
||||
h."Hour";
|
||||
END;
|
||||
|
||||
$BODY$;
|
||||
|
||||
ALTER FUNCTION public.fs_watch_stats_popular_hour_of_day(integer)
|
||||
OWNER TO "${process.env.POSTGRES_ROLE}";
|
||||
`);
|
||||
} catch (error) {
|
||||
console.error(error);
|
||||
}
|
||||
};
|
||||
23
backend/migrations/098_create_webhooks_table.js
Normal file
23
backend/migrations/098_create_webhooks_table.js
Normal file
@@ -0,0 +1,23 @@
|
||||
exports.up = function (knex) {
|
||||
return knex.schema.createTable("webhooks", (table) => {
|
||||
table.increments("id").primary();
|
||||
table.string("name").notNullable();
|
||||
table.string("url").notNullable();
|
||||
table.text("headers").defaultTo("{}");
|
||||
table.text("payload").defaultTo("{}");
|
||||
table.string("method").defaultTo("POST");
|
||||
table.string("trigger_type").notNullable();
|
||||
table.string("webhook_type").defaultTo("generic");
|
||||
table.string("schedule").nullable();
|
||||
table.string("event_type").nullable();
|
||||
table.boolean("enabled").defaultTo(true);
|
||||
table.timestamp("last_triggered").nullable();
|
||||
table.boolean("retry_on_failure").defaultTo(false);
|
||||
table.integer("max_retries").defaultTo(3);
|
||||
table.timestamps(true, true);
|
||||
});
|
||||
};
|
||||
|
||||
exports.down = function (knex) {
|
||||
return knex.schema.dropTable("webhooks");
|
||||
};
|
||||
Reference in New Issue
Block a user