Skip to content

Commit

Permalink
Merge pull request #124 from Facts-and-Files/fix/calculateMilesCorrectly
Browse files Browse the repository at this point in the history
fix: calculate miles the same for user stats and campaign stats
  • Loading branch information
trenc authored Oct 4, 2024
2 parents 868b456 + 162c732 commit 3f63bd7
Show file tree
Hide file tree
Showing 5 changed files with 131 additions and 3 deletions.
2 changes: 1 addition & 1 deletion src/app/Http/Controllers/CampaignStatsController.php
Original file line number Diff line number Diff line change
Expand Up @@ -132,7 +132,7 @@ protected function buildStatistics(Collection $collection): array
'Enrichments' => $collection->pluck('Enrichments')->sum(),
'Descriptions' => $collection->pluck('Descriptions')->sum(),
'HTRTranscriptions' => $collection->pluck('HTRTranscriptions')->sum(),
'Miles' => $collection->pluck('Miles')->sum()
'Miles' => ceil($collection->pluck('Miles')->sum())
];
}
}
3 changes: 2 additions & 1 deletion src/app/Http/Controllers/UserStatsController.php
Original file line number Diff line number Diff line change
Expand Up @@ -19,7 +19,8 @@ public function show(int $id): JsonResponse
}

// cast all as integer
$collection = collect($data[0])->map(function ($value) {
$collection = collect($data[0])->map(function ($value, $key) {
$value = $key === 'Miles' ? ceil($value) : $value;
return is_numeric($value) ? (int) $value : $value;
});

Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,56 @@
<?php

use Illuminate\Database\Migrations\Migration;
use Illuminate\Support\Facades\DB;

return new class extends Migration
{
public function up(): void
{
// delete old view first
DB::statement('DROP VIEW IF EXISTS user_stats_view');

DB::statement('
CREATE VIEW user_stats_view AS
SELECT
s.UserId,
COUNT(DISTINCT s.ItemId) AS Items,
SUM(CASE WHEN s.ScoreTypeId = 1 THEN s.Amount ELSE 0 END) AS Locations,
SUM(CASE WHEN s.ScoreTypeId = 2 THEN s.Amount ELSE 0 END) AS ManualTranscriptions,
SUM(CASE WHEN s.ScoreTypeId = 3 THEN s.Amount ELSE 0 END) AS Enrichments,
SUM(CASE WHEN s.ScoreTypeId = 4 THEN s.Amount ELSE 0 END) AS Descriptions,
SUM(CASE WHEN s.ScoreTypeId = 5 THEN s.Amount ELSE 0 END) AS HTRTranscriptions,
SUM(s.Amount * st.Rate) AS Miles
FROM
Score s
JOIN
ScoreType st ON s.ScoreTypeId = st.ScoreTypeId
GROUP BY
UserId;
');
}

public function down(): void
{
DB::statement('DROP VIEW IF EXISTS user_stats_view');

DB::statement('
CREATE VIEW user_stats_view AS
SELECT
s.UserId,
COUNT(DISTINCT s.ItemId) AS Items,
SUM(CASE WHEN s.ScoreTypeId = 1 THEN s.Amount ELSE 0 END) AS Locations,
SUM(CASE WHEN s.ScoreTypeId = 2 THEN s.Amount ELSE 0 END) AS ManualTranscriptions,
SUM(CASE WHEN s.ScoreTypeId = 3 THEN s.Amount ELSE 0 END) AS Enrichments,
SUM(CASE WHEN s.ScoreTypeId = 4 THEN s.Amount ELSE 0 END) AS Descriptions,
SUM(CASE WHEN s.ScoreTypeId = 5 THEN s.Amount ELSE 0 END) AS HTRTranscriptions,
ROUND(SUM(s.Amount * st.Rate) + 0.5, 0) AS Miles
FROM
Score s
JOIN
ScoreType st ON s.ScoreTypeId = st.ScoreTypeId
GROUP BY
UserId;
');
}
};
Original file line number Diff line number Diff line change
@@ -0,0 +1,71 @@
<?php

use Illuminate\Database\Migrations\Migration;
use Illuminate\Support\Facades\DB;

return new class extends Migration
{
public function up(): void
{
DB::statement('DROP VIEW IF EXISTS campaign_stats_view');

DB::statement('
CREATE VIEW campaign_stats_view AS
SELECT
c.CampaignId,
sc.StoryId,
s.ItemId,
s.UserId,
SUM(CASE WHEN s.ScoreTypeId = 1 THEN s.Amount ELSE 0 END) AS Locations,
SUM(CASE WHEN s.ScoreTypeId = 2 THEN s.Amount ELSE 0 END) AS ManualTranscriptions,
SUM(CASE WHEN s.ScoreTypeId = 3 THEN s.Amount ELSE 0 END) AS Enrichments,
SUM(CASE WHEN s.ScoreTypeId = 4 THEN s.Amount ELSE 0 END) AS Descriptions,
SUM(CASE WHEN s.ScoreTypeId = 5 THEN s.Amount ELSE 0 END) AS HTRTranscriptions,
SUM(s.Amount * st.Rate) AS Miles
FROM
Campaign c
JOIN
StoryCampaign sc ON sc.CampaignId = c.CampaignId
JOIN
Item i ON i.StoryId = sc.StoryId
JOIN
Score s ON s.ItemId = i.ItemId AND s.Timestamp >= c.Start AND s.Timestamp <= c.End
JOIN
ScoreType st ON st.ScoreTypeId = s.ScoreTypeId
GROUP BY
c.CampaignId, sc.StoryId, s.ItemId, s.UserId;
');
}

public function down(): void
{
DB::statement('DROP VIEW IF EXISTS campaign_stats_view');

DB::statement('
CREATE VIEW campaign_stats_view AS
SELECT
c.CampaignId,
sc.StoryId,
s.ItemId,
s.UserId,
SUM(CASE WHEN s.ScoreTypeId = 1 THEN s.Amount ELSE 0 END) AS Locations,
SUM(CASE WHEN s.ScoreTypeId = 2 THEN s.Amount ELSE 0 END) AS ManualTranscriptions,
SUM(CASE WHEN s.ScoreTypeId = 3 THEN s.Amount ELSE 0 END) AS Enrichments,
SUM(CASE WHEN s.ScoreTypeId = 4 THEN s.Amount ELSE 0 END) AS Descriptions,
SUM(CASE WHEN s.ScoreTypeId = 5 THEN s.Amount ELSE 0 END) AS HTRTranscriptions,
ROUND(SUM(s.Amount * st.Rate) + 0.5, 0) AS Miles
FROM
Campaign c
JOIN
StoryCampaign sc ON sc.CampaignId = c.CampaignId
JOIN
Item i ON i.StoryId = sc.StoryId
JOIN
Score s ON s.ItemId = i.ItemId AND s.Timestamp >= c.Start AND s.Timestamp <= c.End
JOIN
ScoreType st ON st.ScoreTypeId = s.ScoreTypeId
GROUP BY
c.CampaignId, sc.StoryId, s.ItemId, s.UserId;
');
}
};
2 changes: 1 addition & 1 deletion src/storage/api-docs/api-docs.yaml
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
openapi: 3.0.3

info:
version: 1.52.1
version: 1.52.2
title: Transcribathon Platform API v2
description: This is the documentation of the Transcribathon API v2 used by [https:transcribathon.eu](https://transcribathon.eu/).<br />
For authorization you can use the the bearer token you are provided with.
Expand Down

0 comments on commit 3f63bd7

Please sign in to comment.