question

Carol avatar image
Carol asked

Return the latest transactions for all parts

I'd like to query a very large table with millions of records. The query should return the latest transactions for all parts. The final report shows how many quantity on hand for each month.

I give the following example for Part SC198 and SC216. Actually we have thousand of parts.

[Part Number] [Quantity on Hand] [Updated Date]

SC198 30  1/2/2002
SC198 50  1/5/2003
SC198 60  2/3/2007
SC198 70  2/6/2008
SC198 100 3/6/2010
SC198 200 5/2/2010
SC216 10  1/2/2003
SC216 20  2/3/2007
SC216 50  1/1/2010
SC216 80  3/2/2010
SC216 60  4/5/2010

The result for updated date before 3/1/2010 should be

SC198 70 2/6/2008
SC216 50 1/1/2010
..... 
.....

The result for update date before 4/1/2010 should be

SC198 100 3/6/2010
SC216 80  3/2/2010
....
.... 

The final report should looks like this,

[Part Number] Jan Feb March April May ...

SC198 70 70 100 100 200

SC216 50 50 80 60 60 ...

I tried Max and top(1), it didn't return the right result, please help me.

t-sqlcalculations
1 comment
10 |1200 characters needed characters left characters exceeded

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

You've just slyly edited this to turn it into a completely different question. You need to research pivot now.
0 Likes 0 ·
Grant Fritchey avatar image
Grant Fritchey answered

How about

SELECT TOP(1) ColumnWhatever
FROM MyTable
WHERE UpdatedDate < '3/1/2010'
ORDER BY UpdateDate DESC
10 |1200 characters needed characters left characters exceeded

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

Matt Whitfield avatar image
Matt Whitfield answered

This will give you what you want for dates before 2010/05/05 - obviously just change the date as you want. You haven't specified what SQL Server version you're on - this is a 2005+ query as it makes use of the windowed function 'ROW_NUMBER'

DECLARE @EndDate datetime
SET @EndDate = '20100505'

SELECT PartNumber, QtyOnHand, UpdatedDate
  FROM (SELECT PartNumber,  
          QtyOnHand,  
          UpdatedDate,  
          ROW_NUMBER() OVER (PARTITION BY PartNumber ORDER BY UpdatedDate DESC)  
              as __RN
         FROM MyTable
         WHERE UpdatedDate < @EndDate
       ) iDat
 WHERE __RN = 1
10 |1200 characters needed characters left characters exceeded

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

Phil Factor avatar image
Phil Factor answered
    CREATE TABLE #Parts
        (
        [partLog_ID] INT IDENTITY(1,1),
        [Part Number] CHAR(5),
        [Quantity on Hand] INT,
        [Updated Date] DATETIME
        )


    INSERT INTO #parts SELECT 'SC198', 30, '1/2/2002'
    INSERT INTO #parts SELECT 'SC198', 50, '1/5/2003'
    INSERT INTO #parts SELECT 'SC198', 60, '2/3/2007'
    INSERT INTO #parts SELECT 'SC198', 70, '2/6/2008'
    INSERT INTO #parts SELECT 'SC198', 100, '3/6/2010'
    INSERT INTO #parts SELECT 'SC198', 200, '5/2/2010'
    INSERT INTO #parts SELECT 'SC216', 10, '1/2/2003'
    INSERT INTO #parts SELECT 'SC216', 20, '2/3/2007'
    INSERT INTO #parts SELECT 'SC216', 50, '1/1/2010'
    INSERT INTO #parts SELECT 'SC216', 80, '3/2/2010'
    INSERT INTO #parts SELECT 'SC216', 60, '4/5/2010'

    SELECT
      #parts.*
    FROM
      #parts
      INNER JOIN (SELECT
                    [part Number], MAX([Updated Date]) AS [final date]
                  FROM #parts
                  WHERE   [Updated Date] BETWEEN '1 jan 2002' AND '1 jul 2010'
                  GROUP BY
                    [part Number]
                 ) f
        ON f.[part Number]=#parts.[Part Number]
           AND [Updated Date]=[final date]

    /*
    partLog_ID  Part Number Quantity on Hand Updated Date
    ----------- ----------- ---------------- -----------------------
    11          SC216       60               2010-04-05 00:00:00.000
    6           SC198       200              2010-05-02 00:00:00.000
    */*/
10 |1200 characters needed characters left characters exceeded

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

Write an Answer

Hint: Notify or tag a user in this post by typing @username.

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.