From 67c650048a1e976894f6c54d5cc2504f9bebf5e4 Mon Sep 17 00:00:00 2001 From: mikejeffers Date: Tue, 2 Jul 2019 12:25:36 -0400 Subject: [PATCH 1/5] EP leaderboard queries --- .../game/Procedures/API.LeaderboardRawEP.sql | 30 ++++++++++++++ .../Procedures/API.LeaderboardRawEPByType.sql | 39 +++++++++++++++++++ 2 files changed, 69 insertions(+) create mode 100644 src/Database/game/Procedures/API.LeaderboardRawEP.sql create mode 100644 src/Database/game/Procedures/API.LeaderboardRawEPByType.sql diff --git a/src/Database/game/Procedures/API.LeaderboardRawEP.sql b/src/Database/game/Procedures/API.LeaderboardRawEP.sql new file mode 100644 index 0000000..9f24f4b --- /dev/null +++ b/src/Database/game/Procedures/API.LeaderboardRawEP.sql @@ -0,0 +1,30 @@ +USE [perpetuumsa] +GO + +---------------------------------------------------- +--Query for Top EP earners by some time period +--Last updated: 2019/07/02 +---------------------------------------------------- + + +IF OBJECT_ID('API.LeaderboardRawEP', 'P') IS NOT NULL + DROP PROCEDURE API.LeaderboardRawEP; +GO + +CREATE procedure API.LeaderboardRawEP + @startTime DATETIME, + @endTime DATETIME, + @pageNum INT, + @pageSize INT +as + +SELECT el.characterid, c.nick, SUM(rawpoints) as total +FROM [perpetuumsa].[dbo].[epforactivitylog] el +JOIN characters c on el.characterid = c.characterID +WHERE eventtime > @startTime AND eventtime < @endTime +GROUP BY el.characterid, nick +ORDER BY total DESC +OFFSET @pageSize * (@pageNum - 1) ROWS +FETCH NEXT @pageSize ROWS ONLY; + +GO diff --git a/src/Database/game/Procedures/API.LeaderboardRawEPByType.sql b/src/Database/game/Procedures/API.LeaderboardRawEPByType.sql new file mode 100644 index 0000000..4d9fd0f --- /dev/null +++ b/src/Database/game/Procedures/API.LeaderboardRawEPByType.sql @@ -0,0 +1,39 @@ +USE [perpetuumsa] +GO + +---------------------------------------------------- +--Query for Top EP earners by some time period and Activity Type +--Activity Type Enum: https://github.com/OpenPerpetuum/PerpetuumServer/blob/Development/src/Perpetuum/EpForActivityType.cs +--Undefined = 0 +--Gathering = 1 +--Mission = 2 +--Production = 3 +--Artifact = 4 +--Intrusion = 5 +--Npc = 6 +--Last updated: 2019/07/02 +---------------------------------------------------- + +IF OBJECT_ID('API.LeaderboardEPByType', 'P') IS NOT NULL + DROP PROCEDURE API.LeaderboardEPByType; +GO + +CREATE procedure API.LeaderboardEPByType + @startTime DATETIME, + @endTime DATETIME, + @activityType INT, + @pageNum INT, + @pageSize INT +as + +SELECT el.characterid, c.nick, SUM(rawpoints) as total +FROM [perpetuumsa].[dbo].[epforactivitylog] el +JOIN characters c on el.characterid = c.characterID +WHERE eventtime > @startTime AND eventtime < @endTime +AND @activityType = el.epforactivitytype +GROUP BY el.characterid, nick +ORDER BY total DESC +OFFSET @pageSize * (@pageNum - 1) ROWS +FETCH NEXT @pageSize ROWS ONLY; + +GO From a63d78bdbfe306aa99d0972c0a3471304fc6ec0c Mon Sep 17 00:00:00 2001 From: mikejeffers Date: Tue, 2 Jul 2019 12:40:52 -0400 Subject: [PATCH 2/5] pvp leaderboard, simple kill count - exactly as Most Dangerous Agents --- .../Procedures/API.LeaderboardPVPKill.sql | 34 +++++++++++++++++++ 1 file changed, 34 insertions(+) create mode 100644 src/Database/game/Procedures/API.LeaderboardPVPKill.sql diff --git a/src/Database/game/Procedures/API.LeaderboardPVPKill.sql b/src/Database/game/Procedures/API.LeaderboardPVPKill.sql new file mode 100644 index 0000000..e042cc6 --- /dev/null +++ b/src/Database/game/Procedures/API.LeaderboardPVPKill.sql @@ -0,0 +1,34 @@ +USE [perpetuumsa] +GO + +---------------------------------------------------- +--Most Dangerous Agents - PVP leaderboard - simple killcounts +--Last updated: 2019/07/02 +---------------------------------------------------- + +IF OBJECT_ID('API.LeaderboardPVPKill', 'P') IS NOT NULL + DROP PROCEDURE API.LeaderboardPVPKill; +GO + +CREATE procedure API.LeaderboardPVPKill + @startTime DATETIME, + @endTime DATETIME, + @pageNum INT, + @pageSize INT +as + +DECLARE @accLevel INT; +SET @accLevel = 2; --normal + +SELECT highscore.characterid, c.nick, SUM(playerskilled) as total +FROM [perpetuumsa].[dbo].[characterhighscore] highscore +JOIN characters c on highscore.characterid = c.characterID +WHERE DATE BETWEEN @startTime AND @endTime +AND (SELECT acclevel FROM accounts WHERE accountid=c.accountid)=@accLevel +GROUP BY highscore.characterid, nick +ORDER BY total DESC +OFFSET @pageSize * (@pageNum - 1) ROWS +FETCH NEXT @pageSize ROWS ONLY; + +GO + From 0b60d346da6c5205f891f1ab4255e2160535d4ac Mon Sep 17 00:00:00 2001 From: mikejeffers Date: Tue, 2 Jul 2019 13:35:50 -0400 Subject: [PATCH 3/5] production leaderboard query --- .../game/Procedures/API.LeaderboardIndy.sql | 38 +++++++++++++++++++ 1 file changed, 38 insertions(+) create mode 100644 src/Database/game/Procedures/API.LeaderboardIndy.sql diff --git a/src/Database/game/Procedures/API.LeaderboardIndy.sql b/src/Database/game/Procedures/API.LeaderboardIndy.sql new file mode 100644 index 0000000..9379daa --- /dev/null +++ b/src/Database/game/Procedures/API.LeaderboardIndy.sql @@ -0,0 +1,38 @@ +USE [perpetuumsa] +GO + +---------------------------------------------------- +--Production leaderboard - who produced the most type of item for some time range +--Good general CategoryFlag Names: +--cf_robots, cf_robot_equipment, cf_ammo +--Others work and allow for more specificity, curate as necessary. +--Last updated: 2019/07/02 +---------------------------------------------------- + +IF OBJECT_ID('API.LeaderboardIndy', 'P') IS NOT NULL + DROP PROCEDURE API.LeaderboardIndy; +GO + +CREATE procedure API.LeaderboardIndy + @startTime DATETIME, + @endTime DATETIME, + @cfName varchar(50), + @pageNum INT, + @pageSize INT +as + +DECLARE @cfFlag BIGINT; +SET @cfFlag = (SELECT TOP 1 value FROM [perpetuumsa].[dbo].[categoryFlags] WHERE name = @cfName); + +SELECT prod.characterid, c.nick, SUM(amount) as total +FROM [perpetuumsa].[dbo].[productionlog] prod +JOIN characters c on prod.characterid = c.characterID +WHERE productiontime BETWEEN @startTime AND @endTime +AND definition in (SELECT definition from entitydefaults where (categoryflags & CAST(dbo.GetCFMask(@cfFlag)as BIGINT) = @cfFlag)) +GROUP BY prod.characterid, nick +ORDER BY total DESC +OFFSET @pageSize * (@pageNum - 1) ROWS +FETCH NEXT @pageSize ROWS ONLY; + +GO + From 27bcd435cb7a39dad52058680908243ae659bd58 Mon Sep 17 00:00:00 2001 From: mikejeffers Date: Tue, 2 Jul 2019 16:08:56 -0400 Subject: [PATCH 4/5] Server stats, mining log --- .../game/Procedures/API.ServerStatMining.sql | 31 +++++++++++++++++++ 1 file changed, 31 insertions(+) create mode 100644 src/Database/game/Procedures/API.ServerStatMining.sql diff --git a/src/Database/game/Procedures/API.ServerStatMining.sql b/src/Database/game/Procedures/API.ServerStatMining.sql new file mode 100644 index 0000000..a2b7ae7 --- /dev/null +++ b/src/Database/game/Procedures/API.ServerStatMining.sql @@ -0,0 +1,31 @@ +USE [perpetuumsa] +GO + + +---------------------------------------------------- +--Server Statistics: Mining +--Displays ores gathered as aggregate statistics grouped by ore definition +--Last updated: 2019/07/02 +---------------------------------------------------- + +IF OBJECT_ID('API.ServerStatMining', 'P') IS NOT NULL + DROP PROCEDURE API.ServerStatMining; +GO + +CREATE procedure API.ServerStatMining + @startTime DATETIME, + @endTime DATETIME, + @pageNum INT, + @pageSize INT +as + +SELECT mine.definition, e.definitionname, SUM(amount) AS total +FROM [perpetuumsa].[dbo].[mininglog] mine +JOIN entitydefaults e ON e.definition = mine.definition +WHERE eventtime BETWEEN @startTime AND @endTime +GROUP BY mine.definition, e.definitionname +ORDER BY total DESC +OFFSET @pageSize * (@pageNum - 1) ROWS +FETCH NEXT @pageSize ROWS ONLY; + +GO From 618378a23c8a475ed90204286c77a0f03ee5afdc Mon Sep 17 00:00:00 2001 From: mikejeffers Date: Tue, 2 Jul 2019 16:11:05 -0400 Subject: [PATCH 5/5] remove using db statements --- src/Database/game/Procedures/API.LeaderboardIndy.sql | 3 --- src/Database/game/Procedures/API.LeaderboardPVPKill.sql | 3 --- src/Database/game/Procedures/API.LeaderboardRawEP.sql | 3 --- src/Database/game/Procedures/API.LeaderboardRawEPByType.sql | 3 --- src/Database/game/Procedures/API.ServerStatMining.sql | 4 ---- 5 files changed, 16 deletions(-) diff --git a/src/Database/game/Procedures/API.LeaderboardIndy.sql b/src/Database/game/Procedures/API.LeaderboardIndy.sql index 9379daa..ade04b2 100644 --- a/src/Database/game/Procedures/API.LeaderboardIndy.sql +++ b/src/Database/game/Procedures/API.LeaderboardIndy.sql @@ -1,6 +1,3 @@ -USE [perpetuumsa] -GO - ---------------------------------------------------- --Production leaderboard - who produced the most type of item for some time range --Good general CategoryFlag Names: diff --git a/src/Database/game/Procedures/API.LeaderboardPVPKill.sql b/src/Database/game/Procedures/API.LeaderboardPVPKill.sql index e042cc6..bf2339f 100644 --- a/src/Database/game/Procedures/API.LeaderboardPVPKill.sql +++ b/src/Database/game/Procedures/API.LeaderboardPVPKill.sql @@ -1,6 +1,3 @@ -USE [perpetuumsa] -GO - ---------------------------------------------------- --Most Dangerous Agents - PVP leaderboard - simple killcounts --Last updated: 2019/07/02 diff --git a/src/Database/game/Procedures/API.LeaderboardRawEP.sql b/src/Database/game/Procedures/API.LeaderboardRawEP.sql index 9f24f4b..d78452a 100644 --- a/src/Database/game/Procedures/API.LeaderboardRawEP.sql +++ b/src/Database/game/Procedures/API.LeaderboardRawEP.sql @@ -1,6 +1,3 @@ -USE [perpetuumsa] -GO - ---------------------------------------------------- --Query for Top EP earners by some time period --Last updated: 2019/07/02 diff --git a/src/Database/game/Procedures/API.LeaderboardRawEPByType.sql b/src/Database/game/Procedures/API.LeaderboardRawEPByType.sql index 4d9fd0f..cce6583 100644 --- a/src/Database/game/Procedures/API.LeaderboardRawEPByType.sql +++ b/src/Database/game/Procedures/API.LeaderboardRawEPByType.sql @@ -1,6 +1,3 @@ -USE [perpetuumsa] -GO - ---------------------------------------------------- --Query for Top EP earners by some time period and Activity Type --Activity Type Enum: https://github.com/OpenPerpetuum/PerpetuumServer/blob/Development/src/Perpetuum/EpForActivityType.cs diff --git a/src/Database/game/Procedures/API.ServerStatMining.sql b/src/Database/game/Procedures/API.ServerStatMining.sql index a2b7ae7..d0dad17 100644 --- a/src/Database/game/Procedures/API.ServerStatMining.sql +++ b/src/Database/game/Procedures/API.ServerStatMining.sql @@ -1,7 +1,3 @@ -USE [perpetuumsa] -GO - - ---------------------------------------------------- --Server Statistics: Mining --Displays ores gathered as aggregate statistics grouped by ore definition