Skip to content

Commit

Permalink
Merge pull request #109 from Facts-and-Files/feat/itemsStarted
Browse files Browse the repository at this point in the history
feat: provide itemsStarted in summarize stats endpoint
  • Loading branch information
trenc authored Apr 18, 2024
2 parents c2077fb + 934bff8 commit e168dc7
Show file tree
Hide file tree
Showing 5 changed files with 150 additions and 13 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1,89 @@
<?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 summary_stats_view');

DB::statement('
CREATE VIEW summary_stats_view AS
SELECT
t1.Year,
t1.Month,
t1.ScoreTypeId,
t1.UniqueUsers AS UniqueUsersPerScoreType,
t1.UniqueItems AS UniqueItemsPerScoreType,
t2.UniqueUsers AS OverallUniqueUsers,
t2.UniqueItems AS OverallUniqueItems,
COALESCE(t3.NumberOfFirstRecords, 0) AS OverallItemsStarted,
t1.Amount
FROM
(
SELECT
YEAR(Timestamp) AS Year,
MONTH(Timestamp) AS Month,
ScoreTypeId,
COUNT(DISTINCT UserId) AS UniqueUsers,
COUNT(DISTINCT ItemId) AS UniqueItems,
SUM(Amount) AS Amount
FROM
Score
GROUP BY
YEAR(Timestamp),
MONTH(Timestamp),
ScoreTypeId
) AS t1
JOIN
(
SELECT
YEAR(Timestamp) AS Year,
MONTH(Timestamp) AS Month,
COUNT(DISTINCT UserId) AS UniqueUsers,
COUNT(DISTINCT ItemId) AS UniqueItems
FROM
Score
GROUP BY
YEAR(Timestamp),
MONTH(Timestamp)
) AS t2
ON
t1.Year = t2.Year
AND t1.Month = t2.Month
LEFT JOIN
(
SELECT
YEAR(s.Timestamp) AS Year,
MONTH(s.Timestamp) AS Month,
COUNT(*) AS NumberOfFirstRecords
FROM
Score s
INNER JOIN (
SELECT
ItemId,
MIN(ScoreId) AS FirstScoreId
FROM
Score
GROUP BY
ItemId
) AS firstRecords
ON
s.ItemId = firstRecords.ItemId
AND s.ScoreId = firstRecords.FirstScoreId
GROUP BY
YEAR(s.Timestamp), MONTH(s.Timestamp)
) AS t3
ON
t1.Year = t3.Year
AND t1.Month = t3.Month;
');
}

public function down(): void
{
DB::statement('DROP VIEW IF EXISTS summary_stats_view');
}
};
Original file line number Diff line number Diff line change
Expand Up @@ -10,34 +10,73 @@ public function up(): void
DB::statement("
CREATE VIEW summary_stats_view AS
SELECT
strftime('%Y', Timestamp) AS Year,
strftime('%m', Timestamp) AS Month,
ScoreTypeId,
COUNT(DISTINCT UserId) AS UniqueUsersPerScoreType,
COUNT(DISTINCT ItemId) AS UniqueItemsPerScoreType,
t1.Year,
t1.Month,
t1.ScoreTypeId,
t1.UniqueUsers AS UniqueUsersPerScoreType,
t1.UniqueItems AS UniqueItemsPerScoreType,
t2.UniqueUsers AS OverallUniqueUsers,
t2.UniqueItems AS OverallUniqueItems,
SUM(Amount) AS Amount
t1.Amount,
COALESCE(t3.NumberOfFirstRecords, 0) AS OverallItemsStarted
FROM
Score
(
SELECT
strftime('%Y', Timestamp) AS Year,
strftime('%m', Timestamp) AS Month,
ScoreTypeId,
COUNT(DISTINCT UserId) AS UniqueUsers,
COUNT(DISTINCT ItemId) AS UniqueItems,
SUM(Amount) AS Amount
FROM
Score
GROUP BY
strftime('%Y', Timestamp),
strftime('%m', Timestamp),
ScoreTypeId
) AS t1
JOIN
(
SELECT
strftime('%Y', Timestamp) AS Year,
strftime('%m', Timestamp) AS Month,
COUNT(DISTINCT UserId) AS UniqueUsers,
COUNT(DISTINCT UserId) AS UniqueItems
COUNT(DISTINCT ItemId) AS UniqueItems
FROM
Score
GROUP BY
strftime('%Y', Timestamp),
strftime('%m', Timestamp)
) AS t2
ON
strftime('%Y', Score.Timestamp) = t2.Year
AND strftime('%m', Score.Timestamp) = t2.Month
GROUP BY
Year, Month, ScoreTypeId;
t1.Year = t2.Year
AND t1.Month = t2.Month
LEFT JOIN
(
SELECT
strftime('%Y', s.Timestamp) AS Year,
strftime('%m', s.Timestamp) AS Month,
COUNT(*) AS NumberOfFirstRecords
FROM
Score s
INNER JOIN (
SELECT
ItemId,
MIN(ScoreId) AS FirstScoreId
FROM
Score
GROUP BY
ItemId
) AS firstRecords
ON
s.ItemId = firstRecords.ItemId
AND s.ScoreId = firstRecords.FirstScoreId
GROUP BY
strftime('%Y', s.Timestamp), strftime('%m', s.Timestamp)
) AS t3
ON
t1.Year = t3.Year
AND t1.Month = t3.Month;
");
}

Expand Down
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.38.0
version: 1.39.0
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
4 changes: 4 additions & 0 deletions src/storage/api-docs/statistics-schema.yaml
Original file line number Diff line number Diff line change
Expand Up @@ -28,6 +28,10 @@ StatisticsGetResponseSchema:
type: integer
description: Amount of unique items which has been enriched/transcribed in this month over all ScoreTypes
example: 8
OverallItemsStarted:
type: integer
description: Amount of unique items which has been started with enriching/transcribing in this month (does not count HTR imports)
example: 8
Amount:
type: integer
description: Amount of the score with a particluar ScoreType
Expand Down
5 changes: 5 additions & 0 deletions src/tests/Feature/SummaryStatsTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -63,6 +63,7 @@ public function testGetAllMonthlyBasedStatistics(): void
'UniqueItemsPerScoreType' => 2,
'OverallUniqueUsers' => 2,
'OverallUniqueItems' => 2,
'OverallItemsStarted' => 2,
'Amount' => 57
],
[
Expand All @@ -73,6 +74,7 @@ public function testGetAllMonthlyBasedStatistics(): void
'UniqueItemsPerScoreType' => 1,
'OverallUniqueUsers' => 1,
'OverallUniqueItems' => 1,
'OverallItemsStarted' => 1,
'Amount' => 10
]
];
Expand Down Expand Up @@ -113,6 +115,7 @@ public function testGetStatisticsByYear(): void
'UniqueItemsPerScoreType' => 2,
'OverallUniqueUsers' => 2,
'OverallUniqueItems' => 2,
'OverallItemsStarted' => 2,
'Amount' => 57
]
];
Expand All @@ -139,6 +142,7 @@ public function testGetStatisticsByYearAndMonth(): void
'UniqueItemsPerScoreType' => 2,
'OverallUniqueUsers' => 2,
'OverallUniqueItems' => 2,
'OverallItemsStarted' => 2,
'Amount' => 57
]
];
Expand All @@ -165,6 +169,7 @@ public function testGetStatisticsByYearMonthAndScoreType(): void
'UniqueItemsPerScoreType' => 2,
'OverallUniqueUsers' => 2,
'OverallUniqueItems' => 2,
'OverallItemsStarted' => 2,
'Amount' => 57
]
];
Expand Down

0 comments on commit e168dc7

Please sign in to comment.