-
Notifications
You must be signed in to change notification settings - Fork 1
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge pull request #109 from Facts-and-Files/feat/itemsStarted
feat: provide itemsStarted in summarize stats endpoint
- Loading branch information
Showing
5 changed files
with
150 additions
and
13 deletions.
There are no files selected for viewing
89 changes: 89 additions & 0 deletions
89
...tabase/migrations/2024_04_18_151500_create_anew_summary_stats_view_with_items_started.php
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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'); | ||
} | ||
}; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters