Bug fix of query to find days to next free slot

templates/queries-index-mysql.tpl.html,
templates/queries-index-sqlite.tpl.html:
    Rather than driving the search from the eps table itself, this
    version makes a counter that generates slot numbers from the current
    show number to the highest show number in the system. The counter is
    used to interrogate the eps table to find the first empty slot. This
    sems to be a more reliable approach (but time will tell).
This commit is contained in:
Dave Morriss 2023-10-20 13:37:37 +01:00
parent dab80f1772
commit c8135d811d
2 changed files with 25 additions and 23 deletions

View File

@ -1,29 +1,31 @@
<!--% query_next_available_episode = '
WITH next_id AS (
SELECT id, id + 1 AS id_next, date as last_date
FROM eps
WHERE eps.date > NOW()
WITH RECURSIVE
min_id AS (
SELECT max(id) AS start_id FROM eps WHERE date <= NOW()
),
free_slot AS (
max_id AS (
SELECT max(id) AS end_id FROM eps
),
cnt(x) AS (
SELECT start_id from min_id
UNION ALL
SELECT x+1 FROM cnt
WHERE x+1 <= (SELECT end_id FROM max_id)
),
first_empty AS (
SELECT
last_date AS prev_date,
CASE
WHEN DAYOFWEEK(last_date) = 6
THEN 3
ELSE 1
END AS date_offset,
next_id.id_next AS empty_slot
FROM next_id
LEFT JOIN eps ON next_id.id_next = eps.id
WHERE eps.id IS NULL
ORDER BY next_id.id
LIMIT 1
cnt.x AS id
FROM cnt
LEFT JOIN eps e ON cnt.x = e.id
WHERE e.id IS NULL
)
SELECT
empty_slot AS next_id,
ADDDATE(prev_date,date_offset) AS next_date,
DATEDIFF(ADDDATE(prev_date,date_offset),NOW()) AS delta_days
FROM free_slot
fe.id as next_id,
(SELECT DATE(ADDDATE(e2.date,1)) from eps e2 where e2.id = fe.id-1) as next_date,
DATEDIFF((SELECT ADDDATE(e3.date,1) from eps e3 where e3.id = fe.id-1),now()) AS delta_days
FROM first_empty AS fe
LEFT JOIN eps e1 ON fe.id = e1.id
LIMIT 1
'
%-->
<!--% query_latest_episodes = '

View File

@ -20,8 +20,8 @@
WHERE e.id IS NULL
)
SELECT
fe.id as empty_slot,
(SELECT date(eps.date,\'+1 day\') from eps where id = fe.id-1) as slot_date,
fe.id as next_id,
(SELECT date(eps.date,\'+1 day\') from eps where id = fe.id-1) as next_date,
printf(\'%i\',abs(julianday((SELECT date(eps.date,\'+1 day\') from eps where id = fe.id-1)) - julianday(\'now\') + 1)) AS delta_days
FROM first_empty AS fe
LEFT JOIN eps e ON fe.id = e.id