SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Show Results When more than just my result shows up.


Show Results When more than just my result shows up.

Author
Message
miker 8667
miker 8667
Grasshopper
Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)

Group: General Forum Members
Points: 20 Visits: 35
Hey Guys,

I'm trying to Show All location changes in our system in the last 5 days, now all active items are stored in a table called OITM and when updated the last iteration of the item is stored in a table called AITM however this can be any change to the product, not just a location change. Which means that I can have the same location show up multiple times. The second issue is that the update date is stored on the actual item and the previous update then moves to AITM however if there are 2 changes during this period I would like them all to show up as well.

Here is a SQL FIDDLE of what I have so far, otherwise I will show the tables below:

 

CREATE TABLE AITM
([ItemCode] varchar(9), [FrgnName] varchar(11), [UpdateDate] datetime, [LogInstanc] int)
;

INSERT INTO AITM
([ItemCode], [FrgnName], [UpdateDate], [LogInstanc])
VALUES
('1513360GD', 'STACK-105', '2012-12-30 00:00:00', 1),
('1513360GD', 'STACK-105', '2013-04-12 00:00:00', 2),
('SEW-3035', NULL, '2013-03-21 00:00:00', 1),
('SEW-3035', NULL, '2013-04-13 00:00:00', 2),
('SEW-3035', 'D-34-35-B-M', '2013-04-14 00:00:00', 3),
('SEW-3035', 'b-13-b', '2013-04-15 00:00:00', 4),
('SEW-3035', 'B-13-B', '2013-04-15 00:00:00', 5)
;

CREATE TABLE OITM
([ItemCode] varchar(9), [FrgnName] varchar(6), [UpdateDate] datetime, [LogInstanc] int)
;

INSERT INTO OITM
([ItemCode], [FrgnName], [UpdateDate], [LogInstanc])
VALUES
('1513360GD', 'FW-66', '2013-04-15 00:00:00', 0),
('SEW-3035', 'B-13-B', '2013-04-16 00:00:00', 0)
;



And here is my current code:

SELECT DISTINCT T0.ItemCode, T1.FrgnName as [From Location], T0.FrgnName as [To Location], T0.UpdateDate
FROM OITM T0 Left JOIN
(Select ItemCode, FrgnName, UpdateDate
From AITM A
Where LogInstanc in
(Select Max(LogInstanc)
From AITM B
Where A.ItemCode = B.ItemCode)
Group By ItemCode, FrgnName, UpdateDate) as T1 ON T0.ItemCode = T1.ItemCode
WHERE ISNULL(T0.FrgnName, 0) <> ISNULL(T1.FrgnName, 0)
Group By T0.ItemCode, T1.FrgnName, T0.FrgnName, T0.UpdateDate
Having Max(T0.UpdateDate) > GETDATE()-4
ORDER BY 4, 1



The results now show like this:


ITEMCODE FROM LOCATION TO LOCATION UPDATEDATE
1513360GD STACK-105 FW-66 April, 15 2013 00:00:00+0000



I would like the results to show all changes within that period only if the location changed as such:

ITEMCODE FROM LOCATION TO LOCATION UPDATEDATE
1513360GD STACK-105 FW-66 April, 15 2013 00:00:00+0000
SEW-3035 NULL D-34-35-B-M April, 13 2013 00:00:00+0000
SEW-3035 D-34-35-B-M B-13-B April, 15 2013 00:00:00+0000


John Mitchell-245523
John Mitchell-245523
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14826 Visits: 15980
This works for your sample data.

-- Union both tables together
WITH AllItems (ItemCode, FrgnName, UpdateDate) AS (
SELECT ItemCode, FrgnName, UpdateDate
FROM AITM
UNION ALL
SELECT ItemCode, FrgnName, UpdateDate
FROM OITM
)
-- Number the rows for each itemcode by date order
, AllItemsRanked (ItemCode, FrgnName, UpdateDate, RowNo) AS (
SELECT ItemCode, FrgnName, UpdateDate,
ROW_NUMBER() OVER (PARTITION BY ItemCode ORDER BY UpdateDate)
FROM AllItems
)
-- Self-join to see what's changed
SELECT i1.ItemCode,
i1.FrgnName FromLocation, i2.FrgnName ToLocation,
i2.UpdateDate
FROM AllItemsRanked i1 JOIN AllItemsRanked i2
ON i1.ItemCode = i2.ItemCode
AND COALESCE(i1.FrgnName,'') <> COALESCE(i2.FrgnName,'') -- only want change of location
AND i2.RowNo = i1.RowNo + 1 -- only look at update immediately before


John
miker 8667
miker 8667
Grasshopper
Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)

Group: General Forum Members
Points: 20 Visits: 35
Thanks John I really appreciate your help.

I added the date limits and it seems to work perfectly.

Once again I thank you for your help.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search