Skip to content

Commit

Permalink
Merge pull request #78 from marcodejongh/fix_duplicate_climbs
Browse files Browse the repository at this point in the history
Only join latest climb_stats result
  • Loading branch information
marcodejongh authored Dec 14, 2024
2 parents 3e2927f + 1f1134c commit 8ed8fd9
Show file tree
Hide file tree
Showing 2 changed files with 21 additions and 18 deletions.
2 changes: 1 addition & 1 deletion app/components/rest-api/api.ts
Original file line number Diff line number Diff line change
Expand Up @@ -36,7 +36,7 @@ export const fetchClimbs = async (

// Build the URL using the new route structure
const response = await fetch(
`${API_BASE_URL}/v1/${routeParameters.board_name}/${routeParameters.layout_id}/${routeParameters.size_id}/${routeParameters.set_ids}/${routeParameters.angle}/search?${urlParams}&bustCache=34`,
`${API_BASE_URL}/v1/${routeParameters.board_name}/${routeParameters.layout_id}/${routeParameters.size_id}/${routeParameters.set_ids}/${routeParameters.angle}/search?${urlParams}&bustCache=36`,
);

const rawResults = await response.json();
Expand Down
37 changes: 20 additions & 17 deletions app/lib/data/queries.ts
Original file line number Diff line number Diff line change
Expand Up @@ -196,23 +196,26 @@ export const searchClimbs = async (

const query = await sql.query({
text: `
WITH filtered_climbs AS (
WITH latest_stats AS (
SELECT DISTINCT ON (climb_uuid) *
FROM ${getTableName(params.board_name, 'climb_stats')}
WHERE angle = $11
ORDER BY climb_uuid, id DESC
),
filtered_climbs AS (
SELECT
climbs.uuid, climbs.setter_username, climbs.name, climbs.description,
climbs.frames, climb_stats.angle, climb_stats.ascensionist_count,
climbs.frames, latest_stats.angle, latest_stats.ascensionist_count,
dg.boulder_name as difficulty,
ROUND(climb_stats.quality_average::numeric, 2) as quality_average,
ROUND(climb_stats.difficulty_average::numeric - climb_stats.display_difficulty::numeric, 2) AS difficulty_error,
climb_stats.benchmark_difficulty
ROUND(latest_stats.quality_average::numeric, 2) as quality_average,
ROUND(latest_stats.difficulty_average::numeric - latest_stats.display_difficulty::numeric, 2) AS difficulty_error,
latest_stats.benchmark_difficulty
FROM ${getTableName(params.board_name, 'climbs')} climbs
LEFT JOIN ${getTableName(
params.board_name,
'climb_stats',
)} climb_stats ON climb_stats.climb_uuid = climbs.uuid
LEFT JOIN latest_stats ON latest_stats.climb_uuid = climbs.uuid
LEFT JOIN ${getTableName(
params.board_name,
'difficulty_grades',
)} dg on dg.difficulty = ROUND(climb_stats.display_difficulty::numeric)
)} dg on dg.difficulty = ROUND(latest_stats.display_difficulty::numeric)
INNER JOIN ${getTableName(params.board_name, 'product_sizes')} product_sizes ON product_sizes.id = $1
WHERE climbs.layout_id = $2
AND climbs.is_listed = true
Expand All @@ -221,29 +224,29 @@ export const searchClimbs = async (
-- Ensures only boulder problems are found and not routes
AND climbs.frames_count = 1
AND product_sizes.id = $3
AND climb_stats.angle = $11
AND climb_stats.ascensionist_count >= $4
AND latest_stats.angle = $11
AND latest_stats.ascensionist_count >= $4
AND climbs.edge_left > product_sizes.edge_left
AND climbs.edge_right < product_sizes.edge_right
AND climbs.edge_bottom > product_sizes.edge_bottom
AND climbs.edge_top < product_sizes.edge_top
${
searchParams.minGrade && searchParams.maxGrade
? 'AND ROUND(climb_stats.display_difficulty::numeric, 0) BETWEEN $5 AND $6'
? 'AND ROUND(latest_stats.display_difficulty::numeric, 0) BETWEEN $5 AND $6'
: ''
}
AND climb_stats.quality_average >= $7
AND ABS(ROUND(climb_stats.display_difficulty::numeric, 0) - climb_stats.difficulty_average::numeric) <= $8
${climbNameClause} -- Conditionally add the name filter
AND latest_stats.quality_average >= $7
AND ABS(ROUND(latest_stats.display_difficulty::numeric, 0) - latest_stats.difficulty_average::numeric) <= $8
${climbNameClause}
)
SELECT *,
(SELECT COUNT(*) FROM filtered_climbs) as total_count
FROM filtered_climbs
ORDER BY ${safeSortBy} ${searchParams.sortOrder === 'asc' ? 'ASC' : 'DESC'}, filtered_climbs.uuid ASC
LIMIT $9 OFFSET $10
`,
values: queryParameters, // Remove any null values that don't match query clauses
values: queryParameters,
});

return {
Expand Down

1 comment on commit 8ed8fd9

@vercel
Copy link

@vercel vercel bot commented on 8ed8fd9 Dec 14, 2024

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.