Results 1 to 5 of 5
  1. #1
    Join Date
    May 2008
    Posts
    2

    Question Unanswered: Converting MS Access SQL to T-SQL 2005

    I'm tearing my hair out! One of my co-workers has put an Access front-end on a SQL Server 2005 database and created a query to perform statistics. I need the query statement in T-SQL to put it into production. I have taken the statement and tried to modify it below to meet T-SQL syntax requirements. I replaced the Access UCase$ with UPPER, replaced IIF with CASE..END. and am still getting errors. It appears that my SUMmed fields, Department_Essential and EOC_Essential, are not being created correctly in lines 2 & 3, because down in line 5, it indicates the Department_Essential alias does not exist. Can anyone help me with this syntax? Specifically, what is the proper syntax for creating the alias fields, and do I use or not use the square brackets in the calculations? Should I be using 'like' rather than '='? Thanks in advance for your help. Also, can anyone recommend a good source or book for T-SQL commands and syntax conventions?

    SELECT dbo.vwDisplayUserListAllFields.DEPT_DESC,
    SUM(CASE WHEN UPPER(Essential_Code)='D' THEN 1 ELSE 0 END) AS 'Department_Essential',
    SUM(CASE WHEN UPPER(Essential_Code)='E' THEN 1 ELSE 0 END) AS 'EOC_Essential',
    COUNT(dbo.vwDisplayUserListAllFields.UserID) AS 'Total_Employees',
    ([Department_Essential]/[Total_Employees]*100) AS [%Department_Essential],
    ([Department_Essential]/[Total_Employees]*100) AS [%EOC_Essential]
    FROM dbo.vwDisplayUserListAllFields
    GROUP BY dbo.vwDisplayUserListAllFields.DEPT_DESC
    ORDER BY dbo.vwDisplayUserListAllFields.DEPT_DESC

  2. #2
    Join Date
    Nov 2004
    Location
    on the wrong server
    Posts
    8,835
    Provided Answers: 6
    upper is most likely meaningless as it is meaningless in the default SQL Server setup.

    what is the data type of Essential Code? Do you have any sample data for that field?

    SELECT dbo.vwDisplayUserListAllFields.DEPT_DESC,
    SUM(CASE WHEN LEFT(Essential_Code,1)='D' THEN 1 ELSE 0 END) AS 'Department_Essential',
    SUM(CASE WHEN LEFT(Essential_Code,1)='E' THEN 1 ELSE 0 END) AS 'EOC_Essential',
    COUNT(dbo.vwDisplayUserListAllFields.UserID) AS 'Total_Employees',
    ([Department_Essential]/[Total_Employees]*100) AS [%Department_Essential],
    ([Department_Essential]/[Total_Employees]*100) AS [%EOC_Essential]
    FROM dbo.vwDisplayUserListAllFields
    GROUP BY dbo.vwDisplayUserListAllFields.DEPT_DESC
    ORDER BY dbo.vwDisplayUserListAllFields.DEPT_DESC
    “If one brings so much courage to this world the world has to kill them or break them, so of course it kills them. The world breaks every one and afterward many are strong at the broken places. But those that will not break it kills. It kills the very good and the very gentle and the very brave impartially. If you are none of these you can be sure it will kill you too but there will be no special hurry.” Earnest Hemingway, A Farewell To Arms.

  3. #3
    Join Date
    Jan 2007
    Location
    UK
    Posts
    11,434
    Provided Answers: 10
    Code:
    SELECT dept_desc
         , Sum(CASE WHEN essential_code='D' THEN 1 ELSE 0 END) As [dept_essential]
         , Sum(CASE WHEN essential_code='E' THEN 1 ELSE 0 END) As [eoc_essential]
         , Count(userid) As [total_employees]
         , (Sum(CASE WHEN essential_code='D' THEN 1 ELSE 0 END) / Count(UserID) * 100) As [%dept]
         , (Sum(CASE WHEN essential_code='E' THEN 1 ELSE 0 END) / Count(UserID) * 100) As [%eoc]
    FROM   dbo.vwDisplayUserListAllFields
    GROUP
        BY dept_desc
    ORDER
        BY dept_desc
    George
    Home | Blog

  4. #4
    Join Date
    May 2008
    Posts
    2
    That almost did it! However, after proofing, I found that the % calculations are not performed correctly when there are both Dept_essential and EOC_essential values. For instance, if there are 0 Dept_essential for the first dept_desc and 5 EOC_essential, and total_employees of 5, it calculates 0% dept_essential and 100% EOC_essential correctly. If there are 84 employees for a dept_desc, with 42 Dept_essential and 42 EOC_Essential, both %s will show as 0%, rather than 50% & 50%. Current code:

    SELECT dbo.vwDisplayUserListAllFields.DEPT_DESC,
    SUM(CASE WHEN Essential_Code='D' THEN 1 ELSE 0 END) AS [Department_Essential],
    SUM(CASE WHEN Essential_Code='E' THEN 1 ELSE 0 END) AS [EOC_Essential],
    COUNT(UserID) AS [Total_Employees],
    (SUM(CASE WHEN Essential_Code='D' THEN 1 ELSE 0 END) / Count(UserID) * 100) As [%Dept_Essential],
    (SUM(CASE WHEN Essential_Code='E' THEN 1 ELSE 0 END) / Count(UserID) * 100) As [%EOC_Essential]
    FROM dbo.vwDisplayUserListAllFields
    GROUP BY DEPT_DESC
    ORDER BY DEPT_DESC

  5. #5
    Join Date
    Apr 2002
    Location
    Toronto, Canada
    Posts
    20,002
    to calculate a percentage from counts and sums of whole numbers, remember that you must coerce, er, i mean, persuade the result to be converted to decimal

    what i do is always start out a percentage calculation like this:
    Code:
       , 100.0 * ( .... ) AS foo_pct
    rudy.ca | @rudydotca
    Buy my SitePoint book: Simply SQL

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •