Subversion Repositories DevTools

Rev

Rev 2197 | Blame | Last modification | View Log | RSS feed

:r ".\queries\SOM_Dashboard_query_init.sql"

SELECT df.defect_month,
       df.project,
       SUM(df.defect_critical) AS defect_severity_critical_count,
       SUM(df.defect_important) AS defect_severity_important_count,
       SUM(df.defect_routine) AS defect_severity_routine_count,
       SUM(df.fixed) AS defect_fixed_count,
       SUM(df.raised) AS defect_raised_count,
       CASE WHEN SUM(df.defect_critical + df.defect_important + df.defect_routine) = 0 THEN 0 ELSE SUM(df.defect_critical) * 100.0 / SUM(df.defect_critical + df.defect_important + df.defect_routine) END AS defect_severity_critical,
       CASE WHEN SUM(df.defect_critical + df.defect_important + df.defect_routine) = 0 THEN 0 ELSE SUM(df.defect_important) * 100.0 / SUM(df.defect_critical + df.defect_important + df.defect_routine) END AS defect_severity_important,
       CASE WHEN SUM(df.defect_critical + df.defect_important + df.defect_routine) = 0 THEN 0 ELSE SUM(df.defect_routine) * 100.0 / SUM(df.defect_critical + df.defect_important + df.defect_routine) END AS defect_severity_routine,
       CASE WHEN SUM(df.raised) = 0 THEN 0 ELSE SUM(df.fixed) * 1.0 /SUM(df.raised) END AS defect_ratio
FROM
  (
  -- get submitted defects
  SELECT  
       si.id as issue_id,
       DATEADD(mm,(YEAR(created)-1900)* 12 + MONTH(created) - 1, 0)AS defect_month, -- truncate to year,month
       CASE WHEN pr.pname IN ('SLS Iteration Plan') THEN 'Stockholm'
            ELSE pr.pname
       END AS project,
       pr.pname as sub_project,
       CASE WHEN (sp.pname IN ('Critical','Blocker')) THEN 1 ELSE 0 END AS defect_critical, 
       CASE WHEN (sp.pname = 'Major') THEN 1 ELSE 0 END AS defect_important, 
       CASE WHEN (sp.pname  IN ('Minor','Trivial')) THEN 1 ELSE 0 END AS defect_routine, 
       0 AS fixed,
       1 AS raised,
       si.created AS defect_datetime, 
       sd.pname as issue_state,si.created as submit_date,si.updated as close_date,si.reporter as login_name, null as severity ,sp.pname as priority,st.pname as issue_type
   FROM
     JIRA.jirauser.jiraissue si,
     JIRA.jirauser.issuestatus sd,
     JIRA.jirauser.project pr,
     JIRA.jirauser.issuetype st,
     JIRA.jirauser.priority sp
   WHERE
          si.issuestatus   = sd.id
      AND si.project = pr.id
      AND si.issuetype = st.id
      AND si.priority = sp.id
      -- filter on date
      AND si.created >= '20090101'
      -- filter on project
      AND pr.pname IN ('SLS Iteration Plan','Cape Town')
      -- filter on defect type
      AND st.pname IN('Bug','Documentation')
      -- filter on submitter
      AND si.reporter IN ('aphoon','amatveev','aserrain','clee','ekilic','fpatel','lguntur',
                          'ggrieve','hbatna','idzukleski','jgodfrey','jkoh','kmuruges','knguyen',
                          'lmiao','mthangav','nkerr','ozaidenv','rthumma','rohearn','sip','kmaesen2',
                          'slibao','stan','tkumar','wloo','ywehalle','sradhakr','bboey','silyas',
                          'wwong','mchua','dmonahan','awehalle')
  UNION 
  -- get closed defects
  SELECT 
       si.id as issue_id,
       DATEADD(mm,(YEAR(si.updated)-1900)* 12 + MONTH(si.updated) - 1, 0)AS defect_month, -- truncate to year,month
       CASE WHEN pr.pname IN ('SLS Iteration Plan') THEN 'Stockholm'
            ELSE pr.pname
       END AS project,
       pr.pname as sub_project,
       0 AS defect_critical, 
       0 AS defect_important, 
       0 AS defect_routine, 
       1 AS fixed,
       0 AS raised,
       si.updated AS defect_datetime,
       sd.pname as issue_state,si.created as submit_date,si.updated as close_date,si.reporter as login_name, null as severity ,sp.pname as priority,st.pname as issue_type
   FROM
     JIRA.jirauser.jiraissue si,
     JIRA.jirauser.issuestatus sd,
     JIRA.jirauser.project pr,
     JIRA.jirauser.issuetype st,
     JIRA.jirauser.priority sp
   WHERE
          si.issuestatus   = sd.id
      AND si.project = pr.id
      AND si.issuetype = st.id
      AND si.priority = sp.id
      AND sd.pname = 'Closed'
      -- filter on date
      AND si.updated >= '20090101'
      -- filter on project
      AND pr.pname IN ('SLS Iteration Plan','Cape Town')
      -- filter on defect type
      AND st.pname IN('Bug','Documentation')
      -- filter on submitter
      AND si.reporter IN ('aphoon','amatveev','aserrain','clee','ekilic','fpatel','lguntur',
                          'ggrieve','hbatna','idzukleski','jgodfrey','jkoh','kmuruges','knguyen',
                          'lmiao','mthangav','nkerr','ozaidenv','rthumma','rohearn','sip','kmaesen2',
                          'slibao','stan','tkumar','wloo','ywehalle','sradhakr','bboey','silyas',
                          'wwong','mchua','dmonahan','awehalle')
   ) df
   where
    df.defect_datetime >= @start_date AND df.defect_datetime < @end_date
GROUP BY df.defect_month,df.project;