diff --git a/routes/day.js b/routes/day.js index 7b306da..8e443c0 100644 --- a/routes/day.js +++ b/routes/day.js @@ -48,9 +48,10 @@ dayRouter.post('/', async (req, res) => { start_time, end_time, location, - notes + notes, + day_count ) VALUES ( - nextval('day_id_seq'), $1, $2, $3, $4, $5 + nextval('day_id_seq'), $1, $2, $3, $4, $5, 0 ) RETURNING id; `, [eventDate, startTime, endTime, location, notes], diff --git a/routes/publishedSchedule.js b/routes/publishedSchedule.js index 7f412f8..c6b0935 100644 --- a/routes/publishedSchedule.js +++ b/routes/publishedSchedule.js @@ -80,10 +80,10 @@ publishedScheduleRouter.get('/season', async (req, res) => { LEFT JOIN catalog C ON PS.event_id = C.id LEFT JOIN day D on PS.day_id = D.id WHERE - DATE(PS.start_time) >= $1::date AND DATE(PS.start_time) <= $2::date + D.event_date >= $1::date AND D.event_date <= $2::date AND D.id = PS.day_id ) - SELECT DATE(seasonPS.start_time), + SELECT event_date, json_build_object ( 'id', seasonPS.day_id, 'event_date', seasonPS.event_date, @@ -107,8 +107,8 @@ publishedScheduleRouter.get('/season', async (req, res) => { ) ) AS data FROM seasonPS - GROUP BY DATE(start_time), day_id, event_date, day_start_time, day_end_time, location, day_notes - ORDER BY DATE(start_time) ASC; + GROUP BY event_date, day_id, day_start_time, day_end_time, location, day_notes + ORDER BY event_date ASC; `, [startTime, endTime], ); @@ -129,11 +129,6 @@ publishedScheduleRouter.get('/date', async (req, res) => { SELECT PS.id, PS.day_id, - D.event_date, - D.start_time AS day_start_time, - D.end_time AS day_end_time, - D.location, - D.notes AS day_notes, C.title, C.event_type, C.year, @@ -145,40 +140,41 @@ publishedScheduleRouter.get('/date', async (req, res) => { PS.notes FROM published_schedule PS LEFT JOIN catalog C ON PS.event_id = C.id - LEFT JOIN day D on PS.day_id = D.id - WHERE - DATE(PS.start_time) = $1::date ) - - SELECT json_build_object ( - 'id', seasonPS.day_id, - 'event_date', seasonPS.event_date, - 'start_time', seasonPS.day_start_time, - 'end_time', seasonPS.day_end_time, - 'location', seasonPS.location, - 'notes', seasonPS.day_notes - ) as day, - JSON_AGG( - json_build_object ( - 'id', seasonPS.id, - 'title', seasonPS.title, - 'event_type', seasonPS.event_type, - 'year', seasonPS.year, - 'start_time', seasonPS.start_time, - 'end_time', seasonPS.end_time, - 'confirmed', seasonPS.confirmed, - 'confirmed_on', seasonPS.confirmed_on, - 'cohort', seasonPS.cohort, - 'notes', seasonPS.notes - ) - ) AS data - FROM seasonPS - GROUP BY DATE(start_time), day_id, event_date, day_start_time, day_end_time, location, day_notes - ORDER BY DATE(start_time) ASC; + SELECT + json_build_object( + 'id', D.id, + 'event_date', D.event_date, + 'start_time', D.start_time, + 'end_time', D.end_time, + 'location', D.location, + 'notes', D.notes + ) AS day_data, + JSON_AGG( + json_build_object ( + 'id', seasonPS.id, + 'day_id', seasonPS.day_id, + 'title', seasonPS.title, + 'event_type', seasonPS.event_type, + 'year', seasonPS.year, + 'start_time', seasonPS.start_time, + 'end_time', seasonPS.end_time, + 'confirmed', seasonPS.confirmed, + 'confirmed_on', seasonPS.confirmed_on, + 'cohort', seasonPS.cohort, + 'notes', seasonPS.notes + ) + ) AS data + FROM + seasonPS + JOIN + day D ON seasonPS.day_id = D.id and d.event_date = $1::date + GROUP BY d.event_date, d.id + ORDER BY d.event_date; `, [date], ); - res.status(200).json(keysToCamel(seasonResult)); + res.status(200).json(keysToCamel(seasonResult)[0]); } catch (err) { res.status(400).send(err.message); } @@ -220,8 +216,21 @@ publishedScheduleRouter.get('/:id', async (req, res) => { publishedScheduleRouter.post('/', async (req, res) => { const { eventId, dayId, confirmed, confirmedOn, startTime, endTime, cohort, notes } = req.body; try { - const dayResult = await db.query(`SELECT * FROM day WHERE id = $1;`, [dayId]); + const dayResult = await db.query( + `UPDATE day SET day_count = day_count + 1 WHERE id = $1 RETURNING *;`, + [dayId], + ); const { eventDate } = dayResult ? keysToCamel(dayResult[0]) : null; + await db.query( + ` + UPDATE day + SET + start_time = CASE WHEN $1::timestamp < start_time THEN $1::timestamp ELSE start_time END, + end_time = CASE WHEN $2::timestamp > end_time THEN $2::timestamp ELSE end_time END + WHERE id = $3; + `, + [startTime, endTime, dayId], + ); const returnedData = await db.query( ` INSERT INTO @@ -262,16 +271,25 @@ publishedScheduleRouter.post('/', async (req, res) => { // PUT/:id - Updates an existing row given an id // NOTE: there is a requirement that the selected DAY already exist; this is how // we are able to grab the event day from the day table for use in the cohort +// NOTE: if the day that you're moving the event FROM will have 0 associated events, +// IT WILL BE DELETED publishedScheduleRouter.put('/:id', async (req, res) => { try { const { id } = req.params; const { eventId, dayId, confirmed, confirmedOn, startTime, endTime, cohort, notes } = req.body; - const psDayIdResult = await db.query(`SELECT day_id FROM published_schedule WHERE id = $1`, [ - id, - ]); - const psDayId = psDayIdResult ? keysToCamel(psDayIdResult[0]).dayId : null; - const dayResult = await db.query(`SELECT * FROM day WHERE id = $1;`, [dayId || psDayId]); - const { eventDate } = dayResult ? keysToCamel(dayResult[0]) : null; + // get the current day from the PS table + const psDayIdResult = keysToCamel( + await db.query(`SELECT day_id FROM published_schedule WHERE id = $1;`, id), + )[0]; + // extract the old day id + const psDayId = psDayIdResult.dayId; + // now we need to grab the data from the table (should use dayId unless it is null) + const dayResult = keysToCamel( + await db.query(`SELECT * FROM day WHERE id = $1;`, [dayId || psDayId]), + )[0]; + // grab the eventDate so that you can set the years + const { eventDate } = dayResult; + // update the PS const updatedPublishedSchedule = await db.query( ` UPDATE published_schedule @@ -300,6 +318,45 @@ publishedScheduleRouter.put('/:id', async (req, res) => { id, ], ); + // if day was modified we need to query and reset the min/max + if (dayId) { + if (startTime) { + await db.query( + `UPDATE day SET start_time = (SELECT MIN(start_time) FROM published_schedule WHERE day_id = $1) WHERE id = $1; + UPDATE day SET start_time = (SELECT MIN(start_time) FROM published_schedule WHERE day_id = $2) WHERE id = $2;`, + [psDayId, dayId], + ); + } + if (endTime) { + await db.query( + `UPDATE day SET end_time = (SELECT MAX(end_time) FROM published_schedule WHERE day_id = $1) WHERE id = $1; + UPDATE day SET end_time = (SELECT MAX(end_time) FROM published_schedule WHERE day_id = $2) WHERE id = $2;`, + [psDayId, dayId], + ); + } + const dayCountResult = await db.query( + `UPDATE day SET day_count = day_count + 1 WHERE id = $1; UPDATE day SET day_count = day_count - 1 WHERE id = $2 RETURNING day_count;`, + [dayId, psDayId], + ); + const { dayCount } = keysToCamel(dayCountResult); + // if start time was passed alongside day we need to update the old day and change the new day + if (dayCount === 0) { + await db.query(`DELETE FROM day WHERE id = $1`, [psDayId]); + } + } else { + if (startTime) { + await db.query( + `UPDATE day SET start_time = (SELECT MIN(start_time) FROM published_schedule WHERE day_id = $1) WHERE id = $1;`, + [psDayId], + ); + } + if (endTime) { + await db.query( + `UPDATE day SET end_time = (SELECT MAX(end_time) FROM published_schedule WHERE day_id = $1) WHERE id = $1;`, + [psDayId], + ); + } + } res.status(200).json(keysToCamel(updatedPublishedSchedule)); } catch (err) { res.status(500).send(err.message); @@ -307,9 +364,12 @@ publishedScheduleRouter.put('/:id', async (req, res) => { }); // DELETE/:id - deletes an existing row given an id +// NOTE: if the day that you're deleting the event FROM will have 0 associated events, +// IT WILL BE DELETED publishedScheduleRouter.delete('/:id', async (req, res) => { try { const { id } = req.params; + // delete PS entry const deletedEntry = await db.query( ` DELETE FROM published_schedule @@ -317,6 +377,35 @@ publishedScheduleRouter.delete('/:id', async (req, res) => { `, [id], ); + // grab relevant info from the deleted row + const { dayId, startTime, endTime } = keysToCamel(deletedEntry[0]); + + // update the day table + const updatedDay = await db.query( + `UPDATE day SET day_count = day_count - 1 WHERE id = $1 RETURNING *;`, + [dayId], + ); + const dayResult = keysToCamel(updatedDay[0]); + const { dayCount } = dayResult; + // if the day has 0 events delete day + if (dayCount === 0) { + await db.query(`DELETE FROM day WHERE id = $1`, [dayId]); + } else { + // if the event start time was the earliest change to earliest in PS table for that day + if (startTime.getTime() === dayResult.startTime.getTime()) { + await db.query( + `UPDATE day SET start_time = (SELECT MIN(start_time) FROM published_schedule WHERE day_id = $1) WHERE id = $1`, + [dayId], + ); + } + // if the event end time was the latest change to latest in PS table for that day + if (endTime.getTime() === dayResult.endTime.getTime()) { + await db.query( + `UPDATE day SET end_time = (SELECT MAX(end_time) FROM published_schedule WHERE day_id = $1) WHERE id = $1`, + [dayId], + ); + } + } res.status(200).send(keysToCamel(deletedEntry)); } catch (err) { res.status(500).send(err.message); diff --git a/server/schema/published_schedule.sql b/server/schema/published_schedule.sql index f4030eb..ddeff67 100644 --- a/server/schema/published_schedule.sql +++ b/server/schema/published_schedule.sql @@ -14,3 +14,5 @@ CREATE TABLE IF NOT EXISTS published_schedule ( FOREIGN KEY (day_id) REFERENCES day (id) ); + +CREATE INDEX idx_day_id ON published_schedule (day_id); \ No newline at end of file