Skip to content
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
8 changes: 4 additions & 4 deletions apps/backend/controllers/flowsheet.controller.ts
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
import { Request, RequestHandler } from 'express';
import { Mutex } from 'async-mutex';
import { NewFSEntry, FSEntry, Show, ShowDJ, library } from '@wxyc/database';
import { FSEntry, Show, ShowDJ, library } from '@wxyc/database';
import * as flowsheet_service from '../services/flowsheet.service.js';
import { fetchAndCacheMetadata } from '../services/metadata/index.js';

Expand Down Expand Up @@ -159,7 +159,7 @@ export const addEntry: RequestHandler = async (req: Request<object, object, FSEn
albumInfo.record_label = body.record_label;
}

const fsEntry: NewFSEntry = {
const fsEntry = {
album_id: body.album_id,
...albumInfo,
track_title: body.track_title,
Expand Down Expand Up @@ -191,7 +191,7 @@ export const addEntry: RequestHandler = async (req: Request<object, object, FSEn
console.error('Bad Request, Missing Flowsheet Parameters: album_title, artist_name, track_title');
res.status(400).send('Bad Request, Missing Flowsheet Parameters: album_title, artist_name, track_title');
} else {
const fsEntry: NewFSEntry = {
const fsEntry = {
...body,
show_id: latestShow.id,
};
Expand Down Expand Up @@ -220,7 +220,7 @@ export const addEntry: RequestHandler = async (req: Request<object, object, FSEn
}
} else {
//we're just throwing the message in there (whatever it may be): dj join event, psa event, talk set event, break-point
const fsEntry: NewFSEntry = {
const fsEntry = {
artist_name: '',
album_title: '',
track_title: '',
Expand Down
28 changes: 25 additions & 3 deletions apps/backend/services/flowsheet.service.ts
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
import { sql, desc, eq, and, lte, gte, inArray } from 'drizzle-orm';
import { sql, desc, eq, and, lte, gte, inArray, max } from 'drizzle-orm';
import {
db,
FSEntry,
Expand Down Expand Up @@ -40,6 +40,12 @@ const updateLastModified = () => {
}
};

/** Get the next play_order value (global max + 1, or 1 if no entries exist) */
export const getNextPlayOrder = async (): Promise<number> => {
const result = await db.select({ maxOrder: max(flowsheet.play_order) }).from(flowsheet);
return (result[0]?.maxOrder ?? 0) + 1;
};

// SQL query fields (flat structure from database)
const FSEntryFieldsRaw = {
id: flowsheet.id,
Expand Down Expand Up @@ -174,7 +180,7 @@ export const getEntriesByShow = async (...show_ids: number[]): Promise<IFSEntry[
return raw.map(transformToIFSEntry);
};

export const addTrack = async (entry: NewFSEntry): Promise<FSEntry> => {
export const addTrack = async (entry: Omit<NewFSEntry, 'play_order'> & { play_order?: number }): Promise<FSEntry> => {
/*
TODO: logic for updating album playcount
*/
Expand Down Expand Up @@ -202,7 +208,15 @@ export const addTrack = async (entry: NewFSEntry): Promise<FSEntry> => {
// }
// }

const response = await db.insert(flowsheet).values(entry).returning();
// Compute play_order if not already set
if (entry.show_id != null && !entry.play_order) {
entry = { ...entry, play_order: await getNextPlayOrder() };
}

const response = await db
.insert(flowsheet)
.values(entry as NewFSEntry)
.returning();
updateLastModified();
return response[0];
};
Expand Down Expand Up @@ -291,8 +305,10 @@ export const startShow = async (dj_id: string, show_name?: string, specialty_id?
})
.returning();

const startPlayOrder = await getNextPlayOrder();
await db.insert(flowsheet).values({
show_id: new_show[0].id,
play_order: startPlayOrder,
entry_type: 'show_start',
message: `Start of Show: DJ ${dj_info.djName || dj_info.name} joined the set at ${new Date().toLocaleString(
'en-US',
Expand Down Expand Up @@ -352,10 +368,12 @@ const createJoinNotification = async (id: string, show_id: number): Promise<FSEn

const message = `${dj_name} joined the set!`;

const joinPlayOrder = await getNextPlayOrder();
const notification = await db
.insert(flowsheet)
.values({
show_id: show_id,
play_order: joinPlayOrder,
entry_type: 'dj_join',
message: message,
})
Expand Down Expand Up @@ -388,8 +406,10 @@ export const endShow = async (currentShow: Show): Promise<Show> => {
const dj_information = (await db.select().from(user).where(eq(user.id, primary_dj_id)).limit(1))[0];
const dj_name = dj_information?.djName || dj_information?.name || 'A DJ';

const endPlayOrder = await getNextPlayOrder();
await db.insert(flowsheet).values({
show_id: currentShow.id,
play_order: endPlayOrder,
entry_type: 'show_end',
message: `End of Show: ${dj_name} left the set at ${new Date().toLocaleString('en-US', {
timeZone: 'America/New_York',
Expand Down Expand Up @@ -431,10 +451,12 @@ const createLeaveNotification = async (dj_id: string, show_id: number): Promise<

const message = `${dj_name} left the set!`;

const leavePlayOrder = await getNextPlayOrder();
const notification = await db
.insert(flowsheet)
.values({
show_id: show_id,
play_order: leavePlayOrder,
entry_type: 'dj_leave',
message: message,
})
Expand Down
4 changes: 2 additions & 2 deletions scripts/ci-env.sh
Original file line number Diff line number Diff line change
Expand Up @@ -51,8 +51,8 @@ fi
# Start database
$COMPOSE_CMD up -d ci-db

# Run database initialization
$COMPOSE_CMD up ci-db-init
# Run database initialization (--abort-on-container-exit propagates failures)
$COMPOSE_CMD up --abort-on-container-exit ci-db-init

# Start auth and backend services
# Environment variables are already exported above, Docker Compose will inherit them
Expand Down
188 changes: 188 additions & 0 deletions shared/database/src/migrations/0026_schema_audit_fixes.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,188 @@
-- Schema audit fixes (Findings 18, 19, 20, 21, 37, 38, 39)
-- This migration must be applied AFTER verifying no NULL rows exist in
-- artist_library_crossreference, and after confirming the shift_covers
-- and flowsheet sequences are not relied upon for auto-generation.

-- F18: shift_covers.schedule_id serial → integer
-- Drop the auto-increment sequence. The column type is already integer in PG;
-- serial just adds a DEFAULT nextval() and owns the sequence.
ALTER TABLE "wxyc_schema"."shift_covers" ALTER COLUMN "schedule_id" DROP DEFAULT;
DO $$ BEGIN
IF EXISTS (SELECT 1 FROM pg_class WHERE relname = 'shift_covers_schedule_id_seq') THEN
DROP SEQUENCE "wxyc_schema"."shift_covers_schedule_id_seq";
END IF;
END $$;
--> statement-breakpoint

-- F19: flowsheet.play_order serial → integer
ALTER TABLE "wxyc_schema"."flowsheet" ALTER COLUMN "play_order" DROP DEFAULT;
DO $$ BEGIN
IF EXISTS (SELECT 1 FROM pg_class WHERE relname = 'flowsheet_play_order_seq') THEN
DROP SEQUENCE "wxyc_schema"."flowsheet_play_order_seq";
END IF;
END $$;
--> statement-breakpoint

-- F20: artist_library_crossreference – add NOT NULL to FK columns
-- IMPORTANT: Run this check first to confirm no NULLs exist:
-- SELECT count(*) FROM wxyc_schema.artist_library_crossreference
-- WHERE artist_id IS NULL OR library_id IS NULL;
ALTER TABLE "wxyc_schema"."artist_library_crossreference" ALTER COLUMN "artist_id" SET NOT NULL;
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."artist_library_crossreference" ALTER COLUMN "library_id" SET NOT NULL;
--> statement-breakpoint

-- F21: show_djs – add unique constraint on (show_id, dj_id)
-- First remove any duplicate rows (keep the first inserted)
DELETE FROM "wxyc_schema"."show_djs" a USING "wxyc_schema"."show_djs" b
WHERE a.ctid < b.ctid
AND a.show_id = b.show_id
AND a.dj_id = b.dj_id;
--> statement-breakpoint
CREATE UNIQUE INDEX "show_djs_show_id_dj_id_unique" ON "wxyc_schema"."show_djs" USING btree ("show_id", "dj_id");
--> statement-breakpoint

-- F37: anonymous_devices – remove redundant unique constraint
-- The explicit uniqueIndex('anonymous_devices_device_id_key') remains.
-- Drop the inline .unique() constraint (named by PG convention).
ALTER TABLE "anonymous_devices" DROP CONSTRAINT IF EXISTS "anonymous_devices_device_id_unique";
--> statement-breakpoint

-- F38: FK cascade rules
-- schedule FKs
ALTER TABLE "wxyc_schema"."schedule" DROP CONSTRAINT IF EXISTS "schedule_specialty_id_specialty_shows_id_fk";
ALTER TABLE "wxyc_schema"."schedule" ADD CONSTRAINT "schedule_specialty_id_specialty_shows_id_fk"
FOREIGN KEY ("specialty_id") REFERENCES "wxyc_schema"."specialty_shows"("id") ON DELETE SET NULL;
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."schedule" DROP CONSTRAINT IF EXISTS "schedule_assigned_dj_id_auth_user_id_fk";
ALTER TABLE "wxyc_schema"."schedule" ADD CONSTRAINT "schedule_assigned_dj_id_auth_user_id_fk"
FOREIGN KEY ("assigned_dj_id") REFERENCES "public"."auth_user"("id") ON DELETE SET NULL;
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."schedule" DROP CONSTRAINT IF EXISTS "schedule_assigned_dj_id2_auth_user_id_fk";
ALTER TABLE "wxyc_schema"."schedule" ADD CONSTRAINT "schedule_assigned_dj_id2_auth_user_id_fk"
FOREIGN KEY ("assigned_dj_id2") REFERENCES "public"."auth_user"("id") ON DELETE SET NULL;
--> statement-breakpoint

-- shift_covers FK
ALTER TABLE "wxyc_schema"."shift_covers" DROP CONSTRAINT IF EXISTS "shift_covers_cover_dj_id_auth_user_id_fk";
ALTER TABLE "wxyc_schema"."shift_covers" ADD CONSTRAINT "shift_covers_cover_dj_id_auth_user_id_fk"
FOREIGN KEY ("cover_dj_id") REFERENCES "public"."auth_user"("id") ON DELETE SET NULL;
--> statement-breakpoint

-- rotation FK
ALTER TABLE "wxyc_schema"."rotation" DROP CONSTRAINT IF EXISTS "rotation_album_id_library_id_fk";
ALTER TABLE "wxyc_schema"."rotation" ADD CONSTRAINT "rotation_album_id_library_id_fk"
FOREIGN KEY ("album_id") REFERENCES "wxyc_schema"."library"("id") ON DELETE CASCADE;
--> statement-breakpoint

-- flowsheet FKs
ALTER TABLE "wxyc_schema"."flowsheet" DROP CONSTRAINT IF EXISTS "flowsheet_show_id_shows_id_fk";
ALTER TABLE "wxyc_schema"."flowsheet" ADD CONSTRAINT "flowsheet_show_id_shows_id_fk"
FOREIGN KEY ("show_id") REFERENCES "wxyc_schema"."shows"("id") ON DELETE SET NULL;
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."flowsheet" DROP CONSTRAINT IF EXISTS "flowsheet_album_id_library_id_fk";
ALTER TABLE "wxyc_schema"."flowsheet" ADD CONSTRAINT "flowsheet_album_id_library_id_fk"
FOREIGN KEY ("album_id") REFERENCES "wxyc_schema"."library"("id") ON DELETE SET NULL;
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."flowsheet" DROP CONSTRAINT IF EXISTS "flowsheet_rotation_id_rotation_id_fk";
ALTER TABLE "wxyc_schema"."flowsheet" ADD CONSTRAINT "flowsheet_rotation_id_rotation_id_fk"
FOREIGN KEY ("rotation_id") REFERENCES "wxyc_schema"."rotation"("id") ON DELETE SET NULL;
--> statement-breakpoint

-- reviews FK
ALTER TABLE "wxyc_schema"."reviews" DROP CONSTRAINT IF EXISTS "reviews_album_id_library_id_fk";
ALTER TABLE "wxyc_schema"."reviews" ADD CONSTRAINT "reviews_album_id_library_id_fk"
FOREIGN KEY ("album_id") REFERENCES "wxyc_schema"."library"("id") ON DELETE CASCADE;
--> statement-breakpoint

-- genre_artist_crossreference FKs
ALTER TABLE "wxyc_schema"."genre_artist_crossreference" DROP CONSTRAINT IF EXISTS "genre_artist_crossreference_artist_id_artists_id_fk";
ALTER TABLE "wxyc_schema"."genre_artist_crossreference" ADD CONSTRAINT "genre_artist_crossreference_artist_id_artists_id_fk"
FOREIGN KEY ("artist_id") REFERENCES "wxyc_schema"."artists"("id") ON DELETE CASCADE;
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."genre_artist_crossreference" DROP CONSTRAINT IF EXISTS "genre_artist_crossreference_genre_id_genres_id_fk";
ALTER TABLE "wxyc_schema"."genre_artist_crossreference" ADD CONSTRAINT "genre_artist_crossreference_genre_id_genres_id_fk"
FOREIGN KEY ("genre_id") REFERENCES "wxyc_schema"."genres"("id") ON DELETE CASCADE;
--> statement-breakpoint

-- artist_library_crossreference FKs
ALTER TABLE "wxyc_schema"."artist_library_crossreference" DROP CONSTRAINT IF EXISTS "artist_library_crossreference_artist_id_artists_id_fk";
ALTER TABLE "wxyc_schema"."artist_library_crossreference" ADD CONSTRAINT "artist_library_crossreference_artist_id_artists_id_fk"
FOREIGN KEY ("artist_id") REFERENCES "wxyc_schema"."artists"("id") ON DELETE CASCADE;
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."artist_library_crossreference" DROP CONSTRAINT IF EXISTS "artist_library_crossreference_library_id_library_id_fk";
ALTER TABLE "wxyc_schema"."artist_library_crossreference" ADD CONSTRAINT "artist_library_crossreference_library_id_library_id_fk"
FOREIGN KEY ("library_id") REFERENCES "wxyc_schema"."library"("id") ON DELETE CASCADE;
--> statement-breakpoint

-- shows FKs
ALTER TABLE "wxyc_schema"."shows" DROP CONSTRAINT IF EXISTS "shows_primary_dj_id_auth_user_id_fk";
ALTER TABLE "wxyc_schema"."shows" ADD CONSTRAINT "shows_primary_dj_id_auth_user_id_fk"
FOREIGN KEY ("primary_dj_id") REFERENCES "public"."auth_user"("id") ON DELETE SET NULL;
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."shows" DROP CONSTRAINT IF EXISTS "shows_specialty_id_specialty_shows_id_fk";
ALTER TABLE "wxyc_schema"."shows" ADD CONSTRAINT "shows_specialty_id_specialty_shows_id_fk"
FOREIGN KEY ("specialty_id") REFERENCES "wxyc_schema"."specialty_shows"("id") ON DELETE SET NULL;
--> statement-breakpoint

-- show_djs FK (show_id → cascade, dj_id already has cascade)
ALTER TABLE "wxyc_schema"."show_djs" DROP CONSTRAINT IF EXISTS "show_djs_show_id_shows_id_fk";
ALTER TABLE "wxyc_schema"."show_djs" ADD CONSTRAINT "show_djs_show_id_shows_id_fk"
FOREIGN KEY ("show_id") REFERENCES "wxyc_schema"."shows"("id") ON DELETE CASCADE;
--> statement-breakpoint

-- F39: Convert all wxyc_schema timestamps to timestamptz
-- PostgreSQL preserves values when converting timestamp → timestamptz
ALTER TABLE "wxyc_schema"."shift_covers" ALTER COLUMN "shift_timestamp" TYPE timestamptz USING "shift_timestamp" AT TIME ZONE 'America/New_York';
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."artists" ALTER COLUMN "last_modified" TYPE timestamptz USING "last_modified" AT TIME ZONE 'America/New_York';
--> statement-breakpoint

-- Drop views that depend on library columns before altering their types
DROP VIEW IF EXISTS "wxyc_schema"."library_artist_view";
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."library" ALTER COLUMN "add_date" TYPE timestamptz USING "add_date" AT TIME ZONE 'America/New_York';
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."library" ALTER COLUMN "last_modified" TYPE timestamptz USING "last_modified" AT TIME ZONE 'America/New_York';
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."flowsheet" ALTER COLUMN "add_time" TYPE timestamptz USING "add_time" AT TIME ZONE 'America/New_York';
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."genres" ALTER COLUMN "last_modified" TYPE timestamptz USING "last_modified" AT TIME ZONE 'America/New_York';
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."reviews" ALTER COLUMN "last_modified" TYPE timestamptz USING "last_modified" AT TIME ZONE 'America/New_York';
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."shows" ALTER COLUMN "start_time" TYPE timestamptz USING "start_time" AT TIME ZONE 'America/New_York';
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."shows" ALTER COLUMN "end_time" TYPE timestamptz USING "end_time" AT TIME ZONE 'America/New_York';
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."specialty_shows" ALTER COLUMN "last_modified" TYPE timestamptz USING "last_modified" AT TIME ZONE 'America/New_York';
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."album_metadata" ALTER COLUMN "last_accessed" TYPE timestamptz USING "last_accessed" AT TIME ZONE 'America/New_York';
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."album_metadata" ALTER COLUMN "created_at" TYPE timestamptz USING "created_at" AT TIME ZONE 'America/New_York';
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."artist_metadata" ALTER COLUMN "last_accessed" TYPE timestamptz USING "last_accessed" AT TIME ZONE 'America/New_York';
--> statement-breakpoint
ALTER TABLE "wxyc_schema"."artist_metadata" ALTER COLUMN "created_at" TYPE timestamptz USING "created_at" AT TIME ZONE 'America/New_York';
--> statement-breakpoint

-- Recreate library_artist_view after altering library column types
CREATE VIEW "wxyc_schema"."library_artist_view" AS
SELECT "wxyc_schema"."library"."id",
"wxyc_schema"."artists"."code_letters",
"wxyc_schema"."artists"."code_artist_number",
"wxyc_schema"."library"."code_number",
"wxyc_schema"."artists"."artist_name",
"wxyc_schema"."library"."album_title",
"wxyc_schema"."format"."format_name",
"wxyc_schema"."genres"."genre_name",
"wxyc_schema"."rotation"."rotation_bin",
"wxyc_schema"."library"."add_date",
"wxyc_schema"."library"."label"
FROM "wxyc_schema"."library"
INNER JOIN "wxyc_schema"."artists" ON "wxyc_schema"."artists"."id" = "wxyc_schema"."library"."artist_id"
INNER JOIN "wxyc_schema"."format" ON "wxyc_schema"."format"."id" = "wxyc_schema"."library"."format_id"
INNER JOIN "wxyc_schema"."genres" ON "wxyc_schema"."genres"."id" = "wxyc_schema"."library"."genre_id"
LEFT JOIN "wxyc_schema"."rotation"
ON "wxyc_schema"."rotation"."album_id" = "wxyc_schema"."library"."id"
AND ("wxyc_schema"."rotation"."kill_date" < CURRENT_DATE OR "wxyc_schema"."rotation"."kill_date" IS NULL);
14 changes: 14 additions & 0 deletions shared/database/src/migrations/meta/_journal.json
Original file line number Diff line number Diff line change
Expand Up @@ -169,6 +169,20 @@
"when": 1771099200000,
"tag": "0029_rename_play_freq_to_rotation_bin",
"breakpoints": true
},
{
"idx": 27,
"version": "7",
"when": 1769067600000,
"tag": "0024_anonymous_devices",
"breakpoints": true
},
{
"idx": 28,
"version": "7",
"when": 1740153600000,
"tag": "0026_schema_audit_fixes",
"breakpoints": true
}
]
}
Loading
Loading