Skip to content

Commit

Permalink
Merge pull request #114 from marcodejongh/hold_search_db_migration
Browse files Browse the repository at this point in the history
Add seperate table for the hold mapping
  • Loading branch information
marcodejongh authored Jan 7, 2025
2 parents d6b2d1c + d733ee7 commit 39ed3b1
Show file tree
Hide file tree
Showing 9 changed files with 4,458 additions and 23 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -13,7 +13,8 @@ export async function GET(
const parsedParams = parseBoardRouteParams(params);
const result = await getClimb(parsedParams);

const litUpHoldsMap = convertLitUpHoldsStringToMap(result.frames, parsedParams.board_name);
// TODO: Multiframe support should remove the hardcoded [0]
const litUpHoldsMap = convertLitUpHoldsStringToMap(result.frames, parsedParams.board_name)[0];

if (!result) {
return NextResponse.json({ error: `Failed to find problem ${params.climb_uuid}` }, { status: 404 });
Expand Down
48 changes: 31 additions & 17 deletions app/components/board-renderer/util.ts
Original file line number Diff line number Diff line change
Expand Up @@ -12,22 +12,36 @@ export const getImageUrl = (imageUrl: string, board: BoardName) => {
return `https://api.${board}boardapp${board === 'tension' ? '2' : ''}.com/img/${imageUrl}`;
};

export const convertLitUpHoldsStringToMap = (litUpHolds: string, board: BoardName): LitUpHoldsMap =>
Object.fromEntries(
litUpHolds
.split('p')
.filter((hold) => hold)
.map((holdData) => holdData.split('r').map((str) => Number(str)))
.map(([holdId, stateCode]) => {
if (!HOLD_STATE_MAP[board][stateCode]) {
throw new Error(
`HOLD_STATE_MAP is missing values for ${board} its missing statuscode: ${stateCode}.
You probably need to update that mapping after adding support for more boards`,
);
}
const { name, color, displayColor } = HOLD_STATE_MAP[board][stateCode];
return [holdId, { state: name, color, displayColor: displayColor || color }];
}),
);
export const convertLitUpHoldsStringToMap = (litUpHolds: string, board: BoardName): Record<number, LitUpHoldsMap> => {
// Split the litUpHolds string by frame delimiter (`,`), process each frame
return litUpHolds
.split(',')
.filter((frame) => frame) // Filter out empty frames
.reduce(
(frameMap, frameString, frameIndex) => {
// Convert each frame to a LitUpHoldsMap
const frameHoldsMap = Object.fromEntries(
frameString
.split('p')
.filter((hold) => hold) // Filter out empty hold data
.map((holdData) => holdData.split('r').map((str) => Number(str))) // Extract holdId and stateCode
.map(([holdId, stateCode]) => {
if (!HOLD_STATE_MAP[board][stateCode]) {
throw new Error(
`HOLD_STATE_MAP is missing values for ${board}. Missing status code: ${stateCode}.
You probably need to update that mapping after adding support for more boards`,
);
}
const { name, color, displayColor } = HOLD_STATE_MAP[board][stateCode];
return [holdId, { state: name, color, displayColor: displayColor || color }];
}),
);
frameMap[frameIndex] = frameHoldsMap; // Map each frame's holds
return frameMap;
},
{} as Record<number, LitUpHoldsMap>,
);
};

export const getBoardImageDimensions = (board: BoardName, firstImage: string) =>
BOARD_IMAGE_DIMENSIONS[board][firstImage];
25 changes: 22 additions & 3 deletions app/lib/data-sync/aurora/shared-sync.ts
Original file line number Diff line number Diff line change
Expand Up @@ -17,6 +17,7 @@ import {
SyncPutFields,
} from '../../api-wrappers/sync-api-types';
import { getTable } from '../../db/queries/util/table-select';
import { convertLitUpHoldsStringToMap } from '@/app/components/board-renderer/util';

// Define shared sync tables in correct dependency order
export const SHARED_SYNC_TABLES: string[] = [
Expand Down Expand Up @@ -196,9 +197,12 @@ async function upsertClimbs(
data: Climb[],
) {
await Promise.all(
data.map((item: Climb) => {
data.map(async (item: Climb) => {
const climbsSchema = getTable('climbs', board);
return db
const climbHoldsSchema = getTable('climbHolds', board);

// Insert or update the climb
await db
.insert(climbsSchema)
.values({
uuid: item.uuid,
Expand Down Expand Up @@ -242,10 +246,25 @@ async function upsertClimbs(
angle: item.angle,
},
});

const holdsByFrame = convertLitUpHoldsStringToMap(item.frames, board);

const holdsToInsert = Object.entries(holdsByFrame).flatMap(([frameNumber, holds]) =>
Object.entries(holds).map(([holdId, { state, color }]) => ({
climbUuid: item.uuid,
frameNumber: Number(frameNumber),
holdId: Number(holdId),
holdState: state,
color,
})),
);

await db.insert(climbHoldsSchema).values(holdsToInsert).onConflictDoNothing(); // Avoid duplicate inserts
}),
);
}


async function upsertSharedTableData(
db: PgTransaction<VercelPgQueryResultHKT, Record<string, never>, ExtractTablesWithRelations<Record<string, never>>>,
boardName: BoardName,
Expand Down Expand Up @@ -325,7 +344,7 @@ export async function syncSharedData(

const syncResults = await sharedSync(board, syncParams);

console.log(`Received ${syncResults.PUT.climbs.length} climbs and ${syncResults.PUT.climb_stats.length} climb_stats`);
console.log(`Received ${syncResults.PUT?.climbs?.length} climbs and ${syncResults.PUT?.climb_stats?.length} climb_stats`);

return upsertAllSharedTableData(board, syncResults);
}
Expand Down
5 changes: 3 additions & 2 deletions app/lib/db/queries/search-climbs.ts
Original file line number Diff line number Diff line change
Expand Up @@ -114,7 +114,7 @@ export const searchClimbs = async (
const results = await baseQuery;

// Transform the results into the complete Climb type
const climbs: Climb[] = results.map(({ totalCount, ...result }) => ({
const climbs: Climb[] = results.map((result) => ({
uuid: result.uuid,
setter_username: result.setter_username || '',
name: result.name || '',
Expand All @@ -127,7 +127,8 @@ export const searchClimbs = async (
stars: Math.round((result.quality_average || 0) * 5),
difficulty_error: result.difficulty_error?.toString(),
benchmark_difficulty: result.benchmark_difficulty?.toString() || null,
litUpHoldsMap: convertLitUpHoldsStringToMap(result.frames || '', params.board_name),
// TODO: Multiframe support should remove the hardcoded [0]
litUpHoldsMap: convertLitUpHoldsStringToMap(result.frames || '', params.board_name)[0],
}));

return {
Expand Down
5 changes: 5 additions & 0 deletions app/lib/db/queries/util/table-select.ts
Original file line number Diff line number Diff line change
Expand Up @@ -30,6 +30,8 @@ import {
tensionSharedSyncs,
kilterUserSyncs,
tensionUserSyncs,
kilterClimbHolds,
tensionClimbHolds,
} from '@/lib/db/schema';

export type BoardName = 'kilter' | 'tension';
Expand All @@ -51,6 +53,7 @@ export type TableSet = {
products: typeof kilterProducts | typeof tensionProducts;
userSyncs: typeof kilterUserSyncs | typeof tensionUserSyncs;
sharedSyncs: typeof kilterSharedSyncs | typeof tensionSharedSyncs;
climbHolds: typeof kilterClimbHolds | typeof tensionClimbHolds;
};

// Create a complete mapping of all tables
Expand All @@ -71,6 +74,7 @@ const BOARD_TABLES: Record<BoardName, TableSet> = {
products: kilterProducts,
userSyncs: kilterUserSyncs,
sharedSyncs: kilterSharedSyncs,
climbHolds: kilterClimbHolds,
},
tension: {
climbs: tensionClimbs,
Expand All @@ -88,6 +92,7 @@ const BOARD_TABLES: Record<BoardName, TableSet> = {
products: tensionProducts,
userSyncs: tensionUserSyncs,
sharedSyncs: tensionSharedSyncs,
climbHolds: tensionClimbHolds,
},
} as const;

Expand Down
54 changes: 54 additions & 0 deletions app/lib/db/schema.ts
Original file line number Diff line number Diff line change
Expand Up @@ -642,6 +642,60 @@ export const tensionClimbs = pgTable(
}),
);

export const kilterClimbHolds = pgTable(
'kilter_climb_holds',
{
climbUuid: text('climb_uuid').notNull(),
holdId: integer('hold_id').notNull(),
frameNumber: integer('frame_number').notNull(),
holdState: text('hold_state').notNull(), // STARTING, HAND, FINISH, FOOT
createdAt: timestamp('created_at').defaultNow(),
},
(table) => ({
// Primary key on both columns to ensure no duplicate holds per climb
pk: primaryKey({ columns: [table.climbUuid, table.holdId] }),

// Index for efficient hold searches
holdSearchIdx: index('kilter_climb_holds_search_idx').on(table.holdId, table.holdState),

// Foreign key to climbs table
climbFkey: foreignKey({
columns: [table.climbUuid],
foreignColumns: [kilterClimbs.uuid],
name: 'kilter_climb_holds_climb_uuid_fkey',
})
.onUpdate('cascade')
.onDelete('cascade'),
}),
);

export const tensionClimbHolds = pgTable(
'tension_climb_holds',
{
climbUuid: text('climb_uuid').notNull(),
holdId: integer('hold_id').notNull(),
frameNumber: integer('frame_number').notNull(),
holdState: text('hold_state').notNull(), // STARTING, HAND, FINISH, FOOT
createdAt: timestamp('created_at').defaultNow(),
},
(table) => ({
// Primary key on both columns to ensure no duplicate holds per climb
pk: primaryKey({ columns: [table.climbUuid, table.holdId] }),

// Index for efficient hold searches
holdSearchIdx: index('tension_climb_holds_search_idx').on(table.holdId, table.holdState),

// Foreign key to climbs table
climbFkey: foreignKey({
columns: [table.climbUuid],
foreignColumns: [tensionClimbs.uuid],
name: 'tension_climb_holds_climb_uuid_fkey',
})
.onUpdate('cascade')
.onDelete('cascade'),
}),
);

export const tensionSets = pgTable('tension_sets', {
id: integer().primaryKey().notNull(),
name: text(),
Expand Down
112 changes: 112 additions & 0 deletions drizzle/0011_add_holds_map_table.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,112 @@
CREATE TABLE "kilter_climb_holds" (
"climb_uuid" text NOT NULL,
"frame_number" integer NOT NULL DEFAULT 0,
"hold_id" integer NOT NULL,
"hold_state" text NOT NULL,
"created_at" timestamp DEFAULT now(),
CONSTRAINT "kilter_climb_holds_climb_uuid_frame_number_hold_id_pk" PRIMARY KEY("climb_uuid", "frame_number", "hold_id")
);
--> statement-breakpoint
CREATE TABLE "tension_climb_holds" (
"climb_uuid" text NOT NULL,
"frame_number" integer NOT NULL DEFAULT 0,
"hold_id" integer NOT NULL,
"hold_state" text NOT NULL,
"created_at" timestamp DEFAULT now(),
CONSTRAINT "tension_climb_holds_climb_uuid_frame_number_hold_id_pk" PRIMARY KEY("climb_uuid", "frame_number", "hold_id")
);
--> statement-breakpoint
ALTER TABLE "kilter_climb_holds" ADD CONSTRAINT "kilter_climb_holds_climb_uuid_fkey" FOREIGN KEY ("climb_uuid") REFERENCES "public"."kilter_climbs"("uuid") ON DELETE cascade ON UPDATE cascade;
--> statement-breakpoint
ALTER TABLE "tension_climb_holds" ADD CONSTRAINT "tension_climb_holds_climb_uuid_fkey" FOREIGN KEY ("climb_uuid") REFERENCES "public"."tension_climbs"("uuid") ON DELETE cascade ON UPDATE cascade;
--> statement-breakpoint
CREATE INDEX "kilter_climb_holds_search_idx" ON "kilter_climb_holds" USING btree ("hold_id", "hold_state");
--> statement-breakpoint
CREATE INDEX "tension_climb_holds_search_idx" ON "tension_climb_holds" USING btree ("hold_id", "hold_state");
--> statement-breakpoint
INSERT INTO "kilter_climb_holds" ("climb_uuid", "frame_number", "hold_id", "hold_state")
WITH parsed_holds AS (
SELECT
"uuid" as "climb_uuid",
CASE WHEN "frames_count" = 1 THEN 0
ELSE (array_position(regexp_split_to_array("frames", ','), frame_part) - 1)
END as "frame_number",
SUBSTRING(hold_data, '(\d+)[rx]')::INTEGER as "hold_id",
CASE
WHEN hold_data ~ 'x\d+$' THEN 'OFF'
ELSE
CASE SUBSTRING(hold_data, 'r(\d+)')::INTEGER
WHEN 12 THEN 'STARTING'
WHEN 13 THEN 'HAND'
WHEN 14 THEN 'FINISH'
WHEN 15 THEN 'FOOT'
WHEN 42 THEN 'STARTING'
WHEN 43 THEN 'HAND'
WHEN 44 THEN 'FINISH'
WHEN 45 THEN 'FOOT'
END
END as "hold_state",
-- Add priority (r patterns take precedence over x)
CASE WHEN hold_data ~ 'r\d+$' THEN 0 ELSE 1 END as priority
FROM kilter_climbs,
regexp_split_to_table("frames", ',') WITH ORDINALITY as f(frame_part, frame_ord),
regexp_split_to_table(frame_part, 'p') WITH ORDINALITY as t(hold_data, ord)
WHERE hold_data != ''
AND hold_data != '""'
AND (
hold_data ~ '^\d+r(12|13|14|15|42|43|44|45)$'
OR hold_data ~ '^\d+x\d+$'
)
AND layout_id IN (1, 8)
)
SELECT DISTINCT ON (climb_uuid, frame_number, hold_id)
climb_uuid,
frame_number,
hold_id,
hold_state
FROM parsed_holds
ORDER BY climb_uuid, frame_number, hold_id, priority;


--> statement-breakpoint
INSERT INTO "tension_climb_holds" ("climb_uuid", "frame_number", "hold_id", "hold_state")
WITH parsed_holds AS (
SELECT
"uuid" as "climb_uuid",
CASE
WHEN "frames_count" = 1 THEN 0
ELSE (array_position(regexp_split_to_array("frames", ','), frame_part) - 1)
END as "frame_number",
SUBSTRING(hold_data, '^(\d+)r')::INTEGER as "hold_id",
CASE
WHEN hold_data ~ 'r\d+$' THEN
CASE SUBSTRING(hold_data, 'r(\d+)$')::INTEGER
WHEN 1 THEN 'STARTING'
WHEN 2 THEN 'HAND'
WHEN 3 THEN 'FINISH'
WHEN 4 THEN 'FOOT'
WHEN 5 THEN 'STARTING'
WHEN 6 THEN 'HAND'
WHEN 7 THEN 'FINISH'
WHEN 8 THEN 'FOOT'
ELSE 'UNKNOWN'
END
ELSE 'UNKNOWN'
END as "hold_state",
CASE WHEN hold_data ~ 'r\d+$' THEN 0 ELSE 1 END as priority
FROM tension_climbs,
regexp_split_to_table("frames", ',') WITH ORDINALITY as f(frame_part, frame_ord),
regexp_split_to_table(frame_part, 'p') as t(hold_data)
WHERE hold_data != ''
AND hold_data != '""'
)
SELECT DISTINCT ON (climb_uuid, frame_number, hold_id)
climb_uuid,
frame_number,
hold_id,
hold_state
FROM parsed_holds
WHERE hold_id IS NOT NULL
ORDER BY climb_uuid, frame_number, hold_id, priority;


Loading

1 comment on commit 39ed3b1

@vercel
Copy link

@vercel vercel bot commented on 39ed3b1 Jan 7, 2025

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Please sign in to comment.