February 6, 2013 at 7:27 am
Hi,
I have an 'items' table that I need to update where and the Date_Effective is the MAX value for matching
Location, ProdCode and Customer column values from the 'Staging1' table. Any columns can be updated other than the Location, ProdCode and Customer columns. (All dates are YMD format)
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[Items_TEST](
[Id] [bigint] IDENTITY(1,1) NOT NULL,
[Location] [nvarchar](5) NOT NULL,
[ProdCode] [nvarchar](5) NOT NULL,
[Item] [nvarchar](6) NULL,
[Customer] [nvarchar](10) NOT NULL,
[Date_Effective] [smalldatetime] NOT NULL,
[Source] [nvarchar](5) NOT NULL,
[User] [nvarchar](50) NULL,
[Date_Exported] [smalldatetime] NULL,
[Time_Exported] [nvarchar](8) NULL,
[Add1] [numeric](7, 2) NOT NULL CONSTRAINT [DF_Items_TEST_Add1] DEFAULT ((0.00)),
[Add2] [numeric](7, 2) NOT NULL CONSTRAINT [DF_Items_TEST_Add2] DEFAULT ((0.00)),
CONSTRAINT [PK_Items_TEST] PRIMARY KEY CLUSTERED
(
[Id] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
truncate table dbo.Items_TEST
;
INSERT INTO dbo.Items_TEST
(
Location, ProdCode, Item, Customer, Date_Effective, Source, [User], Date_Exported, Time_Exported, Add1, Add2
)
VALUES ('9999', '3004', NULL, 'EEVEY', '2012-09-16', 'FV', 'SM', '2012-11-19', '12:01:29', '0.00', '3.00')
;
INSERT INTO dbo.Items_TEST
(
Location, ProdCode, Item, Customer, Date_Effective, Source, [User], Date_Exported, Time_Exported, Add1, Add2
)
VALUES ('9999', '3004', NULL, 'EEVEY', '2012-09-17', 'FV', 'SM', '2012-12-20', '09:14:54', '4.00', '0.00')
;
INSERT INTO dbo.Items_TEST
(
Location, ProdCode, Item, Customer, Date_Effective, Source, [User], Date_Exported, Time_Exported, Add1, Add2
)
VALUES ('9999', '3004', NULL, 'EEVEY', '2012-09-18', 'FV', 'SM', '2013-01-10', '14:36:23', '5.00', '0.00')
;
INSERT INTO dbo.Items_TEST
(
Location, ProdCode, Item, Customer, Date_Effective, Source, [User], Date_Exported, Time_Exported, Add1, Add2
)
VALUES ('5544', '3002', NULL, 'PESS', '2012-09-17', 'FV', 'SM', '2013-01-10', '14:36:23', '1.50', '0.00')
;
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[Staging1](
[Location] [nvarchar](5) NOT NULL,
[ProdCode] [nvarchar](5) NOT NULL,
[Item] [nvarchar](6) NULL,
[Customer] [nvarchar](10) NOT NULL,
[Date_Effective] [smalldatetime] NOT NULL,
[Source] [nvarchar](5) NOT NULL,
[User] [nvarchar](50) NULL,
[Date_Exported] [smalldatetime] NULL,
[Time_Exported] [nvarchar](8) NULL,
[Add1] [numeric](7, 2) NOT NULL CONSTRAINT [DF_Staging1_Add1] DEFAULT ((0.00)),
[Add2] [numeric](7, 2) NOT NULL CONSTRAINT [DF_Staging1_Add2] DEFAULT ((0.00))
) ON [PRIMARY]
TRUNCATE TABLE dbo.Staging1
;
INSERT INTO dbo.Staging1
(
Location, ProdCode, Item, Customer, Date_Effective, Source, [User], Date_Exported, Time_Exported, Add1, Add2
)
VALUES ('5544', '3002', NULL, 'PESSY', '2012-09-21', 'FV', 'SM', '2013-01-19', '14:08:31', '0.50', '0.40')
;
INSERT INTO dbo.Staging1
(
Location, ProdCode, Item, Customer, Date_Effective, Source, [User], Date_Exported, Time_Exported, Add1, Add2
)
VALUES ('9999', '3004', NULL, 'EEVEY', '2012-09-21', 'FV', 'SM', '2013-01-19', '14:08:31', '7.00', '0.00')
;
So, in the above examples, 2 records should be updated:
1.
Add1 becomes '7.00'
where Location = '9999'
AND ProdCode = '3004'
AND Customer = 'EEVE'
AND Date_Effective = '18/09/2012 00:00:00'
(This has the greatest Date_Effective value of the 3 rows)
2.
Add1 becomes '0.50'
AND Add2 becomes '0.40'
where Location = '5544'
AND ProdCode = '3002'
AND Customer = 'PESS'
Any ideas please?
Thanks in advance,
February 6, 2013 at 8:19 am
Here's one way, I think
update it
set Add1 = s.Add1
,Add2 = s.Add2
from dbo.items_test it
join dbo.Staging1 s on it.Location = s.Location
and it.ProdCode = s.ProdCode
and it.Customer = s.Customer
where it.Date_Effective = (
select max(date_effective)
from dbo.Items_TEST t
where t.Location = it.Location
and t.ProdCode = it.ProdCode
and t.Customer = it.Customer
)
The absence of evidence is not evidence of absence.
Martin Rees
You can lead a horse to water, but a pencil must be lead.
Stan Laurel
February 6, 2013 at 8:46 am
Phil - Many thanks!! It looks like it's done the trick 🙂
February 6, 2013 at 8:57 am
Great, no problem!
The absence of evidence is not evidence of absence.
Martin Rees
You can lead a horse to water, but a pencil must be lead.
Stan Laurel
February 6, 2013 at 8:58 am
One more way:-)
2 remarks before the discussion about the way to update your table:
1)Try not to use column names that are also reserved words in SQL Server. The column name user is not a good name and it forces us to use square brackets in the code
2)In you example you had different customer names PESS and PESSY. In the requested solution you treated both customers as the same one. I treated it as a typo.
There are few ways to do what you want. The steps to do it are to identify the columns that should be updated and then update those columns in an update statement that uses from clause with join. I've used CTE that marks those records and give them a value of 1 in a column that is called RowNum. Then I run an update statement on the CTE. The code bellow shows it:
with MyCTE as (
select Location, ProdCode, Item, Customer, Date_Effective, Source, [User], Date_Exported, Time_Exported, Add1, Add2,
row_number() over (partition by Location, ProdCode, Customer order by Date_Effective desc) AS RowNum
from Items_TEST)
update MyCTE
SET MyCTE.Item = Staging1.Item,
MyCTE.Date_Effective = Staging1.Date_Effective,
MyCTE.Source = Staging1.Source,
MyCTE.[User] = Staging1.[User],
MyCTE.Date_Exported = Staging1.Date_Exported,
MyCTE.Time_Exported = Staging1.Time_Exported,
MyCTE.Add1 = Staging1.Add1,
MyCTE.Add2 = Staging1.Add2
from Staging1 inner join MyCTE on Staging1.Customer = MyCTE.Customer
AND Staging1.Location = MyCTE.Location
AND Staging1.ProdCode = MyCTE.ProdCode
AND MyCTE.RowNum = 1
Adi
--------------------------------------------------------------
To know how to ask questions and increase the chances of getting asnwers:
http://www.sqlservercentral.com/articles/Best+Practices/61537/
For better answers on performance questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply