Graph of top four products each month for last 6 months?

Collapse
X
 
  • Time
  • Show
Clear All
new posts
  • Microblitz
    New Member
    • Jul 2010
    • 40

    Graph of top four products each month for last 6 months?

    Graph of top four products each month for last 6 months?
    (Yeah I know I typ'od the title)

    I need create a chart which displays the four highest selling products for each month in the last 6 months to be displayed in a report.

    Ive managed to get all the products for each month for the last six months but im unsure how to filter so it displays only the top four for each month.

    Ive done some programming but I thiinnk im going about this wrongly.

    This is my code so far

    Code:
    DECLARE @StartDate		SMALLDATETIME -- Variables for the dashboard
    DECLARE @EndDate		SMALLDATETIME
    
    SET @StartDate			= DATEADD(s,0,DATEADD(mm, DATEDIFF(m,0,GETDATE())-6,0)) -- get todays month minus 6
    SET @EndDate			= GETDATE() -- get todays date
    
    ----
    
    DECLARE @WhereDateStart		SMALLDATETIME
    DECLARE @WhereDateEnd		SMALLDATETIME
    
    SET @WhereDateStart = CONVERT(SMALLDATETIME,'01/' + LTRIM(STR(MONTH(@StartDate))) + '/' + LTRIM(STR(YEAR(@StartDate))))
    
    SET @WhereDateEnd = DATEADD(s,-1,DATEADD(mm, DATEDIFF(m,0,@EndDate)+1,0))-1
    -- we want each date/month minus six months for filter
    
    	 SELECT -- Set up columns and graph output.
    
    		LEFT(Products.ProductId,14) AS ChartLabel,
    		Products.ProductId,
    		CONVERT(INT, SUM(ManufacturingOrders.QuantityMade)) AS QuantityMade 
    		,
    		CONVERT(CHAR(10), 
    			LTRIM(STR(YEAR(ManufacturingOrders.ReleaseDate))) + '/' + 
    			LTRIM(STR(MONTH(ManufacturingOrders.ReleaseDate)))) AS ReleaseDate -- trim dates
    	FROM
    		ManufacturingOrders
    		INNER JOIN Products ON ManufacturingOrders.Product = Products.Product -- Get the product type
    		INNER JOIN Classifications ON Products.Classification = Classifications.Classification -- Get the Product number
    	WHERE
    
    		 Products.ProductId IN (
    
    			SELECT  Products.ProductId
     -- sales code
    			FROM       Products INNER JOIN Classifications ON Products.Classification = Classifications.Classification
    
    			WHERE    Classifications.ClassificationId = 'BOOK'
                                                                          ) 	
    
                                      AND	ManufacturingOrders.ReleaseDate BETWEEN @WhereDateStart AND @WhereDateEnd
    		  AND       ManufacturingOrders.SystemType = 'B'
                                      AND       QuantityMade > 0
    
    	GROUP BY
    
    		Products.ProductId
    		,
    		YEAR(ManufacturingOrders.ReleaseDate)
    		,
    		MONTH(ManufacturingOrders.ReleaseDate)
    	ORDER BY
    		ReleaseDate
     		,
     		ProductId
    This produces ChartLabel,Prod uctId,QunatityM ade,ReleaseDate columns.

    but its everything for each month, I just want the top 4 for each month to be sent to the graph.
    Last edited by Microblitz; Aug 13 '10, 02:13 PM. Reason: Typo
  • ck9663
    Recognized Expert Specialist
    • Jun 2007
    • 2878

    #2
    Sorry, too lazy to read your code so I'll post something similar :)

    Try doing something like this:

    Code:
    select * from 
    (
    select
    rank = row_number() over (partition by month order by numberofsolditems desc)
    month, numberofsolditems
    from 
    (your subquery) q) z
    where rank <= 4
    Happy Coding!!!

    ~~ CK

    Comment

    • Microblitz
      New Member
      • Jul 2010
      • 40

      #3
      Care to elaborate?

      Comment

      • NeoPa
        Recognized Expert Moderator MVP
        • Oct 2006
        • 32633

        #4
        What do you need help with?

        Have you tried looking through it to see how you can apply these techniques to your situation?

        Comment

        • Microblitz
          New Member
          • Jul 2010
          • 40

          #5
          Well I got this far last night but it doesnt work.

          It produces a "Msg 8120, Level 16, State 1, Line 14
          Column 'Products.Produ ctId' is invalid in the select list because it is not contained in either an aggregate function or the GROUP BY clause.
          "

          WHich is being caused by the inclusion of the SELECT product.product sId

          But the function being proposed is one which I don't fully understand.

          Specifically these dot functions such as the ".ss" I can only assume is to identify specific variables. I've never seen them before in any of the code I've researched (Remember I'm only about 16 hours into programming this language).

          I have a database which contains information about stock across multiple tables and the point is to locate the top 4 best selling items on a per month basis over the last 6 months then plot them on a barograph. So what I am trying to do is even more complex for me than I am showing here. I can handle the graphics part I just need to figureout how to do what in any normal programming language would be a nested loop.


          Code:
          DECLARE @StartDate		SMALLDATETIME
          DECLARE @EndDate		SMALLDATETIME
          
          SET @StartDate			= DATEADD(s,0,DATEADD(mm, DATEDIFF(m,0,GETDATE())-6,0))
          SET @EndDate			= GETDATE()
          
          
          DECLARE @WhereDateStart		SMALLDATETIME
          DECLARE @WhereDateEnd		SMALLDATETIME
          
          SET @WhereDateStart = CONVERT(SMALLDATETIME,'01/' + LTRIM(STR(MONTH(@StartDate))) + '/' + LTRIM(STR(YEAR(@StartDate))))
          SET @WhereDateEnd = DATEADD(s,-1,DATEADD(mm, DATEDIFF(m,0,@EndDate)+1,0))-1
          
          SELECT * FROM
          		(
          				SELECT 
          					Products.ProductId,
          					CONVERT(INT, SUM(ManufacturingOrders.QuantityMade)) AS Quantity,
          					CONVERT(CHAR(10), 
          								LTRIM(STR(YEAR(ManufacturingOrders.ReleaseDate))) + '/' + 
          								LTRIM(STR(MONTH(ManufacturingOrders.ReleaseDate)))) AS ReleaseDate,
          
          					ROW_NUMBER()OVER (ORDER BY  ReleaseDate,Quantity DESC)AS RowNumber,
          					RANK() OVER (ORDER BY ReleaseDate) AS Rank
          
          				FROM ManufacturingOrders
          
          					INNER JOIN Products ON ManufacturingOrders.Product = Products.Product
          					INNER JOIN Classifications ON Products.Classification = Classifications.Classification
          
          				WHERE 
          
          					Classifications.ClassificationId = 'STOCK 332' 
          					AND	ManufacturingOrders.ReleaseDate BETWEEN @WhereDateStart 
          					AND @WhereDateEnd AND ManufacturingOrders.SystemType = 'C'
          					
          
          		Group By ReleaseDate,Quantity)ss
          
          WHERE ss.RowNumber = ss.Rank or ss.RowNumber = ss.Rank+1

          Comment

          • Microblitz
            New Member
            • Jul 2010
            • 40

            #6
            Conversely if I simplyfy it as much as possible and take CK9663's original code and simply insert what I think are the relevent fields producing this version;

            Code:
            SELECT * FROM  
            ( 
            SELECT 
            Products.ProductId,
            CONVERT(INT, SUM(ManufacturingOrders.QuantityMade)) AS Quantity, -- calculate total sales
            
            RANK = ROW_NUMBER() OVER (PARTITION BY MONTH ORDER BY Quantity DESC) 
            MONTH, Quantity
            
            FROM ManufacturingOrders
            
            INNER JOIN Products ON ManufacturingOrders.Product = Products.Product
            INNER JOIN Classifications ON Products.Classification = Classifications.Classification
            
            (
            Classifications.ClassificationId = 'stock item 443' 
            AND	ManufacturingOrders.ReleaseDate BETWEEN @WhereDateStart 
            AND @WhereDateEnd AND ManufacturingOrders.SystemType = 'C') q) z 
            WHERE RANK <= 4
            It produces;
            "Msg 102, Level 15, State 1, Line 7
            Incorrect syntax near 'MONTH'."


            since the only thing I changed in that line of code was the quantity variable, I'm somwhat puzzled as to why there is a syntax error. All of the commands in that line (Except "Quantity") are reserved words.

            Comment

            • NeoPa
              Recognized Expert Moderator MVP
              • Oct 2006
              • 32633

              #7
              Let's take a bunch of steps backwards. I do not even see how your attempts match the suggestion, but as you say you're new to this.

              A step at a time then, do you understand subqueries (Subqueries in SQL) in SQL?
              There are two levels of subquery in the proposed solution but, although there is a sort of one in one of your examples, it doesn't appear you have what is suggested in the original.

              Comment

              • Microblitz
                New Member
                • Jul 2010
                • 40

                #8
                Well I do now, though my guess work was reasonably accurate. It provides a seconed layer of filtering to the original query.
                I guess the two levels of sub query is the (sub query here) and the final line in the original example.
                "where rank <= 4 "

                Comment

                • NeoPa
                  Recognized Expert Moderator MVP
                  • Oct 2006
                  • 32633

                  #9
                  Originally posted by ck9663
                  ck9663:
                  Code:
                  select * from 
                  (
                  select
                  rank = row_number() over (partition by month order by numberofsolditems desc)
                  month, numberofsolditems
                  from 
                  (your subquery) q) z
                  where rank <= 4
                  Pretty well yes. Let me explain :
                  In line #7 (your subquery) q specifies your query and the result set is renamed (ALIASed) to [q]. This is equivalent to (your subquery) AS q.

                  From there the next level query (named [z] now) would be lines #2 through #7.
                  Code:
                  (
                  SELECT [Rank] = ROW_NUMBER() OVER (PARTITION BY [Month] ORDER BY [NumberOfSoldItems] DESC)
                         [Month]
                       , [NumberOfSoldItems]
                  FROM   (your subquery) AS q) AS z
                  I think possibly an extra comma (,) may be required before [Month].

                  This implies that your query must provide data for [Month] and [NumberOfSoldIte ms].

                  Anyway, if we now call this [QueryZ] then we are left with :
                  Code:
                  SELECT *
                  FROM   (QueryZ) AS [z]
                  WHERE  [Rank] <= 4
                  Does that all start to make a little more sense?

                  Comment

                  • Microblitz
                    New Member
                    • Jul 2010
                    • 40

                    #10
                    Yes that makes a lot more sense as soon as you mentioned the "AS" keyword.

                    The "z" routeine I can leave as is, but the 'q' query needs to specify the particulatr brand of product from a related search.

                    This is the relationship that needs to be parsed
                    Code:
                    FROM ManufacturingOrders 
                      
                    INNER JOIN Products ON ManufacturingOrders.Product = Products.Product 
                    INNER JOIN Classifications ON Products.Classification = Classifications.Classification
                    Which goes inside the query q brackets?
                    and continues with ;
                    Code:
                    Classifications.ClassificationId = 'stock item 443'  
                    AND    ManufacturingOrders.ReleaseDate BETWEEN @WhereDateStart  
                    AND @WhereDateEnd AND ManufacturingOrders.SystemType = 'C'
                    ?

                    I'm not stupid but the syntax of this language is freakish in comparision with those that I have played with in the past. I guess it doesnt help to only have been supplied with one book which is Sams teach yourself Microsoft SQL Server T-SQL.

                    Any suggestions for a quick rummage in amazon.co.uk for a better book than this. It is ... well erm.. brief.. :)

                    Comment

                    • NeoPa
                      Recognized Expert Moderator MVP
                      • Oct 2006
                      • 32633

                      #11
                      Originally posted by MicroBlitz
                      MicroBlitz:
                      Yes that makes a lot more sense as soon as you mentioned the "AS" keyword.
                      I so agree. It's an optional keyword and I always use it myself as I feel clarity is so important, especially when reading someone-else's code.

                      Generally, I find that where subqueries become nested and complicated it is worthwhile to develop each in turn, starting from the innermost and proceeding to the overall. Clearly it's important to have a good understanding of what precisely is required at each level, but once the innermost one is developed and working you can think of it in its own little black box (within parentheses) and know that it does its job. The last SQL of post #9 for instance, is easy to work on if you know you can rely on (QueryZ) to do all that's required of it.

                      Originally posted by MicroBlitz
                      MicroBlitz:
                      I guess it doesnt help to only have been supplied with one book which is Sams teach yourself Microsoft SQL Server T-SQL.

                      Any suggestions for a quick rummage in amazon.co.uk for a better book than this. It is ... well erm.. brief.. :)
                      Not really, but I'm finding out all I need from the Context-Sensitive Help system. I find it is invaluable to me. I'm in a position not far different from yours in fact. I may well have a few years of Jet SQL experience, but T-SQL I'm picking up as I go along (after dipping in to T-SQL 2000 at a very basic level once or twice over the last few years). Not a day goes by at this time without my nose deeply buried in the Help system. It answers almost all of my questions well. If it weren't an electronic resource it would certainly be well thumbed by now, and I've only been even looking at this in the last month or two.

                      Anyway, good luck with your learning. Whichever way you find works best.

                      Comment

                      • Microblitz
                        New Member
                        • Jul 2010
                        • 40

                        #12
                        This is the final version I added to the code. It's not the same method as the suggestion above but I managed to get that way working after I got the report to function properly. If I can find the method detailed here I will post it for comparison - Microblitz
                        Code:
                        DECLARE @Classification bigint
                        DECLARE @StartDate smalldatetime
                        DECLARE @EndDate smalldatetime
                        DECLARE @MonthEndDate smalldatetime
                        DECLARE @TempDate smalldatetime
                        
                        SET @Classification = (SELECT Classification FROM Classifications WHERE Classifications.ClassificationId  = 'STOCKITEM')
                        SET @StartDate = CONVERT(smalldatetime,'01 ' + RIGHT(CONVERT(nvarchar,getdate(),106),8))
                        SET @EndDate = DATEADD(d,-1,@StartDate)
                        SET @StartDate = DATEADD(m,-6,@StartDate)
                        
                        CREATE TABLE #DETAILS
                        (
                        	SalesYear	int,
                        	SalesMonth	int,
                        	ProductId	nvarchar(100),
                        	Quantity	decimal(17,5)
                        )
                        
                        SET @TempDate = @StartDate
                        
                        WHILE @TempDate < @EndDate
                        BEGIN
                        	SET @MonthEndDate = DATEADD(d,-1,DATEADD(m,1,@TempDate))
                        
                        
                        	INSERT INTO #DETAILS
                        	(
                        		SalesYear,
                        		SalesMonth,
                        		ProductId,
                        		Quantity
                        	)
                        	SELECT TOP 4
                        		YEAR(@TempDate),
                        		DATEPART(m,@TempDate),
                        		Products.ProductId,
                        		SUM(SalesInvoiceItems.Quantity) AS QuantityInvoiced
                        	FROM SalesInvoiceItems
                        		INNER JOIN SalesInvoices ON SalesInvoiceItems.SalesInvoice = SalesInvoices.SalesInvoice
                        			AND dbo.wfn_GetSimpleDate(SalesInvoices.EffectiveDate) BETWEEN @TempDate AND @MonthEndDate
                        			AND SalesInvoices.SystemType = 'F'
                        			AND SalesInvoices.SourceType = 'I'
                        		INNER JOIN Products ON SalesInvoiceItems.Product = Products.Product
                        			AND Products.Classification = @Classification
                        	GROUP BY
                        		Products.ProductId
                        	ORDER BY
                        		QuantityInvoiced DESC
                        
                        
                        	SET @TempDate = DATEADD(m,1,@TempDate)
                        END
                        
                        SELECT *
                        FROM #DETAILS
                        
                        DROP TABLE #DETAILS
                        Last edited by Microblitz; Sep 24 '10, 07:34 AM. Reason: To protect the innocent

                        Comment

                        • Microblitz
                          New Member
                          • Jul 2010
                          • 40

                          #13
                          The alternative code using the technique as explained above by ck9663 for comparison.
                          Code:
                          DECLARE @Classification bigint
                          SET @Classification = (SELECT Classification FROM Classifications WHERE Classifications.ClassificationId  = 'STOCKITEM')
                          
                          select * from  
                          ( 
                          	select 
                          		Dtbl.SalesYear
                          		Dtbl.SalesMonth,
                          		Dtbl.ProductId,
                          		row_number() over (partition by SalesYear,SalesMonth order by QuantityInvoiced desc) AS Ranking,
                          		Dtbl.QuantityInvoiced 
                          	from  
                          	(
                          		SELECT
                          			YEAR(SalesInvoices.EffectiveDate) AS SalesYear,
                          			DATEPART(m,SalesInvoices.EffectiveDate) AS SalesMonth,
                          			Products.ProductId,
                          			SUM(SalesInvoiceItems.Quantity) AS QuantityInvoiced
                          		FROM SalesInvoiceItems
                          			INNER JOIN SalesInvoices ON SalesInvoiceItems.SalesInvoice = SalesInvoices.SalesInvoice
                          				AND dbo.wfn_GetSimpleDate(SalesInvoices.EffectiveDate) BETWEEN '01 Mar 2010' AND '31 Aug 2010'
                          				AND SalesInvoices.SystemType = 'F'
                          				AND SalesInvoices.SourceType = 'I'
                          			INNER JOIN Products ON SalesInvoiceItems.Product = Products.Product
                          				AND Products.Classification = @Classification
                          		GROUP BY
                          			YEAR(SalesInvoices.EffectiveDate),
                          			DATEPART(m,SalesInvoices.EffectiveDate),
                          			Products.ProductId
                          	) AS Dtbl
                          ) As DTbl2
                          where Ranking <= 4
                          Last edited by Microblitz; Sep 24 '10, 07:42 AM. Reason: Uphold the law

                          Comment

                          Working...