Use stored procedure to speed up per-exceptiongroup instability calculation
This commit is contained in:
Родитель
c8da7ca063
Коммит
7be03183a1
|
@ -40,7 +40,8 @@ namespace UsageDataAnalysisWebClient.Controllers
|
|||
var crashes = chart.Series.Add("Occurrences");
|
||||
crashes.ChartType = System.Web.UI.DataVisualization.Charting.SeriesChartType.Line;
|
||||
|
||||
foreach (var pair in StabilityController.GetCrashStatisticsForExceptionGroup(new udcEntities(), id)) {
|
||||
ExceptionGroupRepository exceptionGroupRepository = new ExceptionGroupRepository();
|
||||
foreach (var pair in exceptionGroupRepository.GetCrashStatisticsForExceptionGroup(id)) {
|
||||
crashes.Points.AddXY(pair.Item1, pair.Item2);
|
||||
}
|
||||
|
||||
|
|
|
@ -13,36 +13,6 @@ namespace UsageDataAnalysisWebClient.Controllers
|
|||
{
|
||||
public class StabilityController : Controller
|
||||
{
|
||||
public static List<Tuple<string, double>> GetCrashStatisticsForExceptionGroup(udcEntities db, int exceptionGroupId)
|
||||
{
|
||||
var q =
|
||||
from s in db.Sessions
|
||||
where s.ClientSessionId != 0 // ignore welcome sessions
|
||||
where !s.IsDebug // ignore debug builds
|
||||
join tag in db.TaggedCommits on s.CommitId equals tag.CommitId
|
||||
where tag.IsRelease // only use released versions, not branch
|
||||
group new {
|
||||
IsCrashed = s.Exceptions.Any(ex => ex.ExceptionGroupId == exceptionGroupId),
|
||||
//IsKilled = s.EndTime == null,
|
||||
s.StartTime
|
||||
} by new { s.UserId, Date = EntityFunctions.TruncateTime(s.StartTime), tag.Name };
|
||||
|
||||
var resultList = (
|
||||
from g in q.AsEnumerable()
|
||||
group g by new { g.Key.Name } into g
|
||||
let userDaysWithCrash = g.Count(g2 => g2.Any(s => s.IsCrashed))
|
||||
let userDays = g.Count()
|
||||
select Tuple.Create(
|
||||
g.Key.Name, // TagName
|
||||
100.0 * userDaysWithCrash / userDays
|
||||
)
|
||||
).OrderBy(g => g.Item1, new VersionNameComparer()).ToList();
|
||||
// remove '0' entries at the ends
|
||||
while (resultList.Count > 0 && resultList[0].Item2 == 0) resultList.RemoveAt(0);
|
||||
while (resultList.Count > 0 && resultList.Last().Item2 == 0) resultList.RemoveAt(resultList.Count - 1);
|
||||
return resultList;
|
||||
}
|
||||
|
||||
//
|
||||
// GET: /Stability/
|
||||
|
||||
|
|
|
@ -5,6 +5,9 @@ using UsageDataAnalysisWebClient.Models;
|
|||
using Exception = UsageDataAnalysisWebClient.Models.Exception;
|
||||
using System.Diagnostics;
|
||||
using UsageDataAnalysisWebClient.Controllers;
|
||||
using System.Data.SqlClient;
|
||||
using System.Configuration;
|
||||
using System.Data;
|
||||
|
||||
namespace UsageDataAnalysisWebClient.Repositories {
|
||||
public class ExceptionGroupRepository : IExceptionGroupRepository {
|
||||
|
@ -191,7 +194,7 @@ namespace UsageDataAnalysisWebClient.Repositories {
|
|||
}
|
||||
|
||||
// get statistics about this exception
|
||||
editModel.CrashProbabilities = StabilityController.GetCrashStatisticsForExceptionGroup(_db, id);
|
||||
editModel.CrashProbabilities = GetCrashStatisticsForExceptionGroup(id);
|
||||
|
||||
// get details about the exception instances
|
||||
editModel.Exceptions = EvaluateQuery((
|
||||
|
@ -245,7 +248,29 @@ namespace UsageDataAnalysisWebClient.Repositories {
|
|||
return taggedCommit.CommitId;
|
||||
}
|
||||
return null;
|
||||
}
|
||||
}
|
||||
|
||||
public List<Tuple<string, double>> GetCrashStatisticsForExceptionGroup(int exceptionGroupId)
|
||||
{
|
||||
var result = new List<Tuple<string,double>>();
|
||||
using (var c = new SqlConnection(ConfigurationManager.ConnectionStrings["udcADO"].ConnectionString)) {
|
||||
c.Open();
|
||||
using (var command = c.CreateCommand()) {
|
||||
command.CommandText = "[InstabilityForException]";
|
||||
command.CommandType = CommandType.StoredProcedure;
|
||||
command.Parameters.Add("@exceptionGroup", SqlDbType.Int).Value = exceptionGroupId;
|
||||
using (var reader = command.ExecuteReader()) {
|
||||
while (reader.Read()) {
|
||||
string versionName = reader.GetString(0);
|
||||
int totalUserDays = reader.GetInt32(1);
|
||||
int crashedUserDays = reader.GetInt32(2);
|
||||
result.Add(Tuple.Create(versionName, 100.0 * crashedUserDays / totalUserDays));
|
||||
}
|
||||
}
|
||||
}
|
||||
}
|
||||
return result.OrderBy(g => g.Item1, new VersionNameComparer()).ToList();
|
||||
}
|
||||
}
|
||||
|
||||
static partial class ExtensionMethods
|
||||
|
|
|
@ -106,7 +106,8 @@
|
|||
<%
|
||||
} else if (Model.CrashProbabilities.Count == 1) {
|
||||
%>
|
||||
<p>This exception occurred in only one release (<%: Model.CrashProbabilities[0].Item1%>)</p>
|
||||
<p>This exception occurred in only one release (<%: Model.CrashProbabilities[0].Item1%>).
|
||||
The instability in that release caused by this exception is <%: Model.CrashProbabilities[0].Item2.ToString("f2")%>%.</p>
|
||||
<%
|
||||
} else {
|
||||
%><p>This exception did not occur in any tagged release versions.</p><%
|
||||
|
|
|
@ -1,114 +1,19 @@
|
|||
USE [UsageDataAnalysis]
|
||||
GO
|
||||
/****** Object: StoredProcedure [dbo].[InstabilityForException] Script Date: 02/19/2012 16:18:44 ******/
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
|
||||
ALTER TABLE dbo.ExceptionGroups DROP COLUMN UserFixedInRevision;
|
||||
ALTER TABLE dbo.ExceptionGroups ADD UserFixedInCommit int NULL;
|
||||
|
||||
/* New columns for Session: */
|
||||
ALTER TABLE dbo.Sessions ADD CommitId [int] NULL
|
||||
GO
|
||||
|
||||
ALTER TABLE dbo.[Sessions] ADD IsDebug BIT NOT NULL DEFAULT(0);
|
||||
GO
|
||||
UPDATE dbo.[Sessions] SET Sessions.IsDebug=1
|
||||
WHERE EXISTS (SELECT * FROM EnvironmentData
|
||||
JOIN EnvironmentDataNames ON EnvironmentData.EnvironmentDataNameId = EnvironmentDataNames.EnvironmentDataNameId
|
||||
WHERE EnvironmentDataNames.EnvironmentDataName = 'debug'
|
||||
AND EnvironmentData.SessionId = Sessions.SessionId
|
||||
);
|
||||
GO
|
||||
ALTER TABLE dbo.[Sessions] ALTER COLUMN IsDebug BIT NOT NULL;
|
||||
GO
|
||||
|
||||
ALTER TABLE dbo.[Sessions] ADD FirstException datetime NULL;
|
||||
GO
|
||||
UPDATE dbo.[Sessions] SET Sessions.FirstException=
|
||||
(SELECT MIN(ThrownAt)
|
||||
FROM Exceptions
|
||||
WHERE Exceptions.SessionId = Sessions.SessionId
|
||||
);
|
||||
GO
|
||||
|
||||
ALTER TABLE dbo.[Sessions] ADD LastFeatureUse datetime NULL;
|
||||
GO
|
||||
UPDATE dbo.[Sessions] SET Sessions.LastFeatureUse=
|
||||
(SELECT MAX(UseTime)
|
||||
FROM FeatureUse
|
||||
WHERE FeatureUse.SessionId = Sessions.SessionId
|
||||
);
|
||||
GO
|
||||
|
||||
/****** Object: Table [dbo].[Commits] Script Date: 01/07/2011 23:16:54 ******/
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
CREATE TABLE [dbo].[Commits](
|
||||
[Id] [int] IDENTITY(1,1) NOT NULL,
|
||||
[Hash] [nvarchar](50) NOT NULL,
|
||||
[CommitDate] [datetime] NOT NULL,
|
||||
CONSTRAINT [PK_Versions] PRIMARY KEY CLUSTERED
|
||||
(
|
||||
[Id] ASC
|
||||
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
|
||||
) ON [PRIMARY]
|
||||
GO
|
||||
CREATE UNIQUE NONCLUSTERED INDEX [IX_Versions] ON [dbo].[Commits]
|
||||
(
|
||||
[Hash] ASC
|
||||
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
|
||||
GO
|
||||
/****** Object: Table [dbo].[CommitRelations] Script Date: 01/07/2011 23:16:54 ******/
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
CREATE TABLE [dbo].[CommitRelations](
|
||||
[ParentCommit] [int] NOT NULL,
|
||||
[ChildCommit] [int] NOT NULL,
|
||||
PRIMARY KEY CLUSTERED
|
||||
(
|
||||
[ParentCommit] ASC,
|
||||
[ChildCommit] ASC
|
||||
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
|
||||
) ON [PRIMARY]
|
||||
GO
|
||||
|
||||
/****** Object: Table [dbo].[TaggedCommits] Script Date: 01/07/2011 23:16:54 ******/
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
CREATE TABLE [dbo].[TaggedCommits](
|
||||
[TagId] [int] IDENTITY(1,1) NOT NULL,
|
||||
[CommitId] [int] NOT NULL,
|
||||
[Name] [nvarchar](50) NOT NULL,
|
||||
[IsRelease] [bit] NOT NULL,
|
||||
CONSTRAINT [PK_TaggedVersions] PRIMARY KEY CLUSTERED
|
||||
(
|
||||
[TagId] ASC
|
||||
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
|
||||
) ON [PRIMARY]
|
||||
GO
|
||||
|
||||
|
||||
DROP PROCEDURE [dbo].[DailyUsers];
|
||||
GO
|
||||
|
||||
/****** Object: StoredProcedure [dbo].[UserCount] Script Date: 01/07/2011 23:16:57 ******/
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
CREATE PROCEDURE [dbo].[UserCount]
|
||||
-- Add the parameters for the stored procedure here
|
||||
@startDate datetime2,
|
||||
@endDate datetime2,
|
||||
@mode int
|
||||
-- =============================================
|
||||
-- Author: Daniel Grunwald
|
||||
-- Create date: 19.02.2012
|
||||
-- Description: Calculates the instability for a single exception group
|
||||
-- =============================================
|
||||
CREATE PROCEDURE [dbo].[InstabilityForException]
|
||||
@exceptionGroup int
|
||||
AS
|
||||
BEGIN
|
||||
-- SET NOCOUNT ON added to prevent extra result sets from
|
||||
|
@ -116,44 +21,35 @@ BEGIN
|
|||
SET NOCOUNT ON;
|
||||
|
||||
-- Insert statements for procedure here
|
||||
IF @mode = 0
|
||||
SELECT DATEADD(day, DATEDIFF(day,0,StartTime), 0) AS Day, TaggedCommits.Name, COUNT(DISTINCT UserId)
|
||||
AS UserCount
|
||||
FROM dbo.Sessions
|
||||
LEFT JOIN dbo.TaggedCommits ON TaggedCommits.CommitId = Sessions.CommitId
|
||||
WHERE (TaggedCommits.IsRelease IS NULL OR TaggedCommits.IsRelease = 1)
|
||||
AND StartTime BETWEEN @startDate AND @endDate
|
||||
GROUP BY DATEADD(day, DATEDIFF(day,0,StartTime), 0), TaggedCommits.Name
|
||||
ORDER BY Day, TaggedCommits.Name;
|
||||
ELSE IF @mode = 1
|
||||
SELECT DATEADD(week, DATEDIFF(week,0,StartTime), 0) AS Week, TaggedCommits.Name, COUNT(DISTINCT UserId)
|
||||
AS UserCount
|
||||
FROM dbo.Sessions
|
||||
LEFT JOIN dbo.TaggedCommits ON TaggedCommits.CommitId = Sessions.CommitId
|
||||
WHERE (TaggedCommits.IsRelease IS NULL OR TaggedCommits.IsRelease = 1)
|
||||
AND StartTime BETWEEN @startDate AND @endDate
|
||||
GROUP BY DATEADD(week, DATEDIFF(week,0,StartTime), 0), TaggedCommits.Name
|
||||
ORDER BY Week, TaggedCommits.Name;
|
||||
ELSE
|
||||
SELECT DATEADD(month, DATEDIFF(month,0,StartTime), 0) AS Month, TaggedCommits.Name, COUNT(DISTINCT UserId)
|
||||
AS UserCount
|
||||
FROM dbo.Sessions
|
||||
LEFT JOIN dbo.TaggedCommits ON TaggedCommits.CommitId = Sessions.CommitId
|
||||
WHERE (TaggedCommits.IsRelease IS NULL OR TaggedCommits.IsRelease = 1)
|
||||
AND StartTime BETWEEN @startDate AND @endDate
|
||||
GROUP BY DATEADD(month, DATEDIFF(month,0,StartTime), 0), TaggedCommits.Name
|
||||
ORDER BY Month, TaggedCommits.Name;
|
||||
SELECT TotalQuery.VersionName, TotalUserDays, UserDaysWithCrash
|
||||
FROM (
|
||||
SELECT VersionName, COUNT(*) as TotalUserDays
|
||||
FROM (
|
||||
SELECT UserId,
|
||||
DATEADD(day, DATEDIFF(day,0,StartTime), 0) as [Date],
|
||||
TaggedCommits.Name as [VersionName]
|
||||
FROM [Sessions]
|
||||
JOIN [TaggedCommits] ON [Sessions].CommitID = [TaggedCommits].CommitId
|
||||
Where ClientSessionId != 0 AND [Sessions].IsDebug = 0 AND [TaggedCommits].IsRelease = 1
|
||||
GROUP BY UserId, DATEADD(day, DATEDIFF(day,0,StartTime), 0), TaggedCommits.Name
|
||||
) AS X
|
||||
GROUP BY VersionName
|
||||
) AS TotalQuery,
|
||||
(
|
||||
SELECT VersionName, COUNT(*) As UserDaysWithCrash
|
||||
FROM (
|
||||
SELECT UserId,
|
||||
DATEADD(day, DATEDIFF(day,0,StartTime), 0) as [Date],
|
||||
TaggedCommits.Name as [VersionName]
|
||||
FROM [Sessions]
|
||||
JOIN [Exceptions] ON [Exceptions].SessionId = [Sessions].SessionId
|
||||
JOIN [TaggedCommits] ON [Sessions].CommitID = [TaggedCommits].CommitId
|
||||
Where ClientSessionId != 0 AND [Sessions].IsDebug = 0 AND [TaggedCommits].IsRelease = 1 AND ExceptionGroupId = @exceptionGroup
|
||||
GROUP BY UserId, DATEADD(day, DATEDIFF(day,0,StartTime), 0), TaggedCommits.Name
|
||||
) AS X
|
||||
GROUP BY VersionName
|
||||
) As CrashQuery
|
||||
WHERE TotalQuery.VersionName = CrashQuery.VersionName;
|
||||
END
|
||||
GO
|
||||
|
||||
/* Fix indices */
|
||||
|
||||
DROP INDEX [IX_EnvironmentData] ON [dbo].[EnvironmentData];
|
||||
GO
|
||||
CREATE NONCLUSTERED INDEX [IX_EnvironmentData] ON [dbo].[EnvironmentData]
|
||||
(
|
||||
[SessionId] ASC,
|
||||
[EnvironmentDataNameId] ASC,
|
||||
[EnvironmentDataValueId] ASC
|
||||
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
|
||||
GO
|
||||
|
|
|
@ -362,6 +362,64 @@ BEGIN
|
|||
ORDER BY Value, Week;
|
||||
END
|
||||
GO
|
||||
USE [UsageDataAnalysis]
|
||||
GO
|
||||
|
||||
/****** Object: StoredProcedure [dbo].[InstabilityForException] Script Date: 02/19/2012 16:18:44 ******/
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
|
||||
-- =============================================
|
||||
-- Author: Daniel Grunwald
|
||||
-- Create date: 19.02.2012
|
||||
-- Description: Calculates the instability for a single exception group
|
||||
-- =============================================
|
||||
CREATE PROCEDURE [dbo].[InstabilityForException]
|
||||
@exceptionGroup int
|
||||
AS
|
||||
BEGIN
|
||||
-- SET NOCOUNT ON added to prevent extra result sets from
|
||||
-- interfering with SELECT statements.
|
||||
SET NOCOUNT ON;
|
||||
|
||||
-- Insert statements for procedure here
|
||||
SELECT TotalQuery.VersionName, TotalUserDays, UserDaysWithCrash
|
||||
FROM (
|
||||
SELECT VersionName, COUNT(*) as TotalUserDays
|
||||
FROM (
|
||||
SELECT UserId,
|
||||
DATEADD(day, DATEDIFF(day,0,StartTime), 0) as [Date],
|
||||
TaggedCommits.Name as [VersionName]
|
||||
FROM [Sessions]
|
||||
JOIN [TaggedCommits] ON [Sessions].CommitID = [TaggedCommits].CommitId
|
||||
Where ClientSessionId != 0 AND [Sessions].IsDebug = 0 AND [TaggedCommits].IsRelease = 1
|
||||
GROUP BY UserId, DATEADD(day, DATEDIFF(day,0,StartTime), 0), TaggedCommits.Name
|
||||
) AS X
|
||||
GROUP BY VersionName
|
||||
) AS TotalQuery,
|
||||
(
|
||||
SELECT VersionName, COUNT(*) As UserDaysWithCrash
|
||||
FROM (
|
||||
SELECT UserId,
|
||||
DATEADD(day, DATEDIFF(day,0,StartTime), 0) as [Date],
|
||||
TaggedCommits.Name as [VersionName]
|
||||
FROM [Sessions]
|
||||
JOIN [Exceptions] ON [Exceptions].SessionId = [Sessions].SessionId
|
||||
JOIN [TaggedCommits] ON [Sessions].CommitID = [TaggedCommits].CommitId
|
||||
Where ClientSessionId != 0 AND [Sessions].IsDebug = 0 AND [TaggedCommits].IsRelease = 1 AND ExceptionGroupId = @exceptionGroup
|
||||
GROUP BY UserId, DATEADD(day, DATEDIFF(day,0,StartTime), 0), TaggedCommits.Name
|
||||
) AS X
|
||||
GROUP BY VersionName
|
||||
) As CrashQuery
|
||||
WHERE TotalQuery.VersionName = CrashQuery.VersionName;
|
||||
END
|
||||
|
||||
GO
|
||||
|
||||
|
||||
/****** Object: Default [DF__Sessions__IsDebu__1273C1CD] Script Date: 01/09/2011 14:13:58 ******/
|
||||
ALTER TABLE [dbo].[Sessions] ADD DEFAULT ((0)) FOR [IsDebug]
|
||||
GO
|
||||
|
|
Загрузка…
Ссылка в новой задаче