sorarebuddy/db/migrations/00010_avgs.sql

117 lines
5.8 KiB
MySQL
Raw Normal View History

2024-05-23 04:18:54 +00:00
-- +goose Up
CREATE TABLE IF NOT EXISTS player_averages (
player_slug VARCHAR NOT NULL,
fixture_slug VARCHAR NOT NULL,
PRIMARY KEY (player_slug, fixture_slug),
l5 INTEGER,
l5r INTEGER,
l15 INTEGER,
l15r INTEGER,
l40 INTEGER,
l40r INTEGER,
gameweek INTEGER,
ds5 INTEGER,
ds15 INTEGER,
ds40 INTEGER,
aa5 INTEGER,
aa15 INTEGER,
aa40 INTEGER,
minutes15 INTEGER
);
CREATE INDEX player_averages_player_slug_gameweek_index ON player_averages (player_slug ASC, gameweek DESC);
CREATE OR REPLACE PROCEDURE calc_stats (IN starting_gameweek INTEGER) LANGUAGE plpgsql AS $$
DECLARE
fixture RECORD;
player RECORD;
startdate TIMESTAMP WITH TIME ZONE;
l5 INTEGER;
l15 INTEGER;
l40 INTEGER;
l5r INTEGER;
l15r INTEGER;
l40r INTEGER;
ds5 INTEGER;
ds15 INTEGER;
ds40 INTEGER;
aa5 INTEGER;
aa15 INTEGER;
aa40 INTEGER;
minutes15 INTEGER;
BEGIN
FOR fixture IN
(SELECT * FROM fixtures WHERE game_week >= starting_gameweek ORDER BY game_week)
LOOP
RAISE NOTICE 'Processing fixture: %, Game week: %', fixture.slug, fixture.game_week;
SELECT start_date FROM fixtures WHERE game_week = fixture.game_week - 1 INTO startdate;
IF startdate IS NULL THEN
startdate = fixture.start_date - INTERVAL '3 days';
END IF;
RAISE NOTICE 'Start date for calculations: %', startdate;
FOR player IN
(SELECT * FROM players)
LOOP
RAISE NOTICE 'Calculating averages for player: %', player.slug;
WITH subquery AS (SELECT row_number() OVER (ORDER BY g.date DESC) AS rn,
score,
decisive_score,
all_around_score,
minutes
FROM game_player_scores AS gps
JOIN games AS g ON g.id = gps.game_id
WHERE player_slug = player.slug
AND g.date < startdate)
select coalesce(round(avg(score) filter ( where rn <= 5 )), 0),
coalesce(round(avg(score) filter ( where rn <= 15 )), 0),
coalesce(round(avg(score) filter ( where rn <= 40 )), 0),
coalesce(round(avg(score) filter ( where rn <= 5 and minutes > 0 )), 0),
coalesce(round(avg(score) filter ( where rn <= 15 and minutes > 0 )), 0),
coalesce(round(avg(score) filter ( where rn <= 40 and minutes > 0 )), 0),
coalesce(round(avg(decisive_score) filter ( where rn <= 5 and minutes > 0 )), 0),
coalesce(round(avg(decisive_score) filter ( where rn <= 15 and minutes > 0 )), 0),
coalesce(round(avg(decisive_score) filter ( where rn <= 40 and minutes > 0 )), 0),
coalesce(round(avg(all_around_score) filter ( where rn <= 5 and minutes > 0 )), 0),
coalesce(round(avg(all_around_score) filter ( where rn <= 15 and minutes > 0 )), 0),
coalesce(round(avg(all_around_score) filter ( where rn <= 40 and minutes > 0 )), 0),
coalesce(round(avg(minutes) filter ( where rn <= 15 )), 0)
from subquery
into l5r, l15r, l40r, l5, l15, l40, ds5, ds15, ds40, aa5, aa15, aa40, minutes15;
RAISE NOTICE 'Inserting/updating averages for player: %, Fixture: %, Game week: %, l15: %', player.slug, fixture.slug, fixture.game_week, l15;
INSERT INTO player_averages (player_slug, fixture_slug, gameweek, l5, l5r, l15, l15r, l40, l40r, ds5, ds15, ds40, aa5, aa15, aa40, minutes15)
VALUES (player.slug, fixture.slug, fixture.game_week, l5, l5r, l15, l15r, l40, l40r, ds5, ds15, ds40, aa5, aa15, aa40, minutes15)
ON CONFLICT (player_slug, fixture_slug) DO UPDATE SET l5 = EXCLUDED.l5,
l5r = EXCLUDED.l5r,
l15 = EXCLUDED.l15,
l15r = EXCLUDED.l15r,
l40 = EXCLUDED.l40,
l40r = EXCLUDED.l40r,
ds5 = EXCLUDED.ds5,
ds15 = EXCLUDED.ds15,
ds40 = EXCLUDED.ds40,
aa5 = EXCLUDED.aa5,
aa15 = EXCLUDED.aa15,
aa40 = EXCLUDED.aa40,
minutes15 = EXCLUDED.minutes15;
END LOOP;
COMMIT;
END LOOP;
END;
$$;
-- +goose Down
DROP PROCEDURE IF EXISTS calc_stats;
DROP INDEX IF EXISTS player_averages_player_slug_gameweek_index;
DROP TABLE IF EXISTS player_averages;