Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Update using Max() value on multi join query


Update using Max() value on multi join query

Author
Message
DerbyNeal
DerbyNeal
SSC-Enthusiastic
SSC-Enthusiastic (156 reputation)SSC-Enthusiastic (156 reputation)SSC-Enthusiastic (156 reputation)SSC-Enthusiastic (156 reputation)SSC-Enthusiastic (156 reputation)SSC-Enthusiastic (156 reputation)SSC-Enthusiastic (156 reputation)SSC-Enthusiastic (156 reputation)

Group: General Forum Members
Points: 156 Visits: 909
Hi,

I have a problem where I need to update a table (Results). The one thing I can't get my head around is the part concerning the ct.DateStart >= ao.Date_Effective line in the join. There could be multiple ao.Date_Effective records in this instance, and i need to join on the row with the maximum date value. How do i apply this?

The tables/values are...

--DATEFORMAT YMD

--RESULTS
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[Results](
[FV_Flag] [nvarchar](1) NULL,
[EX16] [numeric](7, 2) NULL,
[CustBookId] [nvarchar](5) NULL,
[FormatNumber] [nvarchar](5) NULL,
[ContractId] [nvarchar](10) NULL,
[Source] [nvarchar](5) NULL
) ON [PRIMARY]
;

INSERT INTO Results
(FV_Flag, EX16, CustBookId, FormatNumber, ContractId, Source)
VALUES('x', '0.00', 'c134', '5170', '2345', 'p');

INSERT INTO Results
(FV_Flag, EX16, CustBookId, FormatNumber, ContractId, Source)
VALUES('x', '0.00', 'c135', '5170', '', 'p');

INSERT INTO Results
(FV_Flag, EX16, CustBookId, FormatNumber, ContractId, Source)
VALUES('x', '0.00', 'c136', '4234', '3344', 'p');


--AddOns
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[Addons](
[Customer] [nvarchar](10) NULL,
[FmNo] [nvarchar](10) NULL,
[Date_Effective] [smalldatetime] NULL,
[EX16] [numeric](7, 2) NULL,
[Mill] [nvarchar](4) NULL
) ON [PRIMARY]
;

INSERT INTO AddOns
(Customer, FmNo, Date_Effective, EX16, Mill)
VALUES('c134', '5170', '2012/09/02', '1', '9999');

INSERT INTO AddOns
(Customer, FmNo, Date_Effective, EX16, Mill)
VALUES('c134', '5170', '2012/09/07', '2', '9999');

INSERT INTO AddOns
(Customer, FmNo, Date_Effective, EX16, Mill)
VALUES('c134', '5170', '2012/09/10', '4', '9999');

INSERT INTO AddOns
(Customer, FmNo, Date_Effective, EX16, Mill)
VALUES('c135', '5170', '2012/09/02', '2', '9999');

INSERT INTO AddOns
(Customer, FmNo, Date_Effective, EX16, Mill)
VALUES('c136', '4234', '2012/09/12', '5', '9999');


--ContractTable
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[ContractTable](
[ContractId] [nvarchar](50) NULL,
[DateStart] [smalldatetime] NULL
) ON [PRIMARY]
;

INSERT INTO ContractTable
(ContractId, DateStart)
VALUES('2345', '2012/09/09');

INSERT INTO ContractTable
(ContractId, DateStart)
VALUES('3344', '2012/09/11');



The join is...

UPDATE tr

SET FV_Flag = 'N', 
EX16 = ao.EX16
FROM @tblResults tr
LEFT JOIN Market_Prices.dbo.BV_AddOns ao WITH ( NOLOCK) ON
ao.Customer = tr.CustBookId
AND ao.FmNo = tr.SIG_FormatNumber
LEFT JOIN SIG_CONTRACTTABLE ct WITH ( NOLOCK) ON
ct.CONTRACTID = tr.SIG_ContractId
AND ct.DateStart >= ao.Date_Effective --Max Date_Effective
WHERE ao.Mill = '9999'
AND tr.Source = 'P'
AND tr.SIG_ContractId != ''
AND tr.CustBookId IS NOT NULL



The only row that should be affected is where the CustBookId = 'c134'.
c135 is NOT updated as there is no ContractId
c136 is NOT updated as DateStart is less than the Date_Effective in the query join

Any ideas please?

Thanks in advance,
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)

Group: General Forum Members
Points: 9027 Visits: 19036
UPDATE tr SET 
FV_Flag = 'N',
EX16 = ao.EX16
FROM Results tr
CROSS APPLY (
SELECT TOP 1
ao.EX16,
ao.Date_Effective
FROM AddOns ao
WHERE ao.Customer = tr.CustBookId
AND ao.FmNo = tr.SIG_FormatNumber
AND ao.Mill = '9999'
ORDER BY Date_Effective DESC
) ao
LEFT JOIN ContractTable ct
ON ct.CONTRACTID = tr.SIG_ContractId
AND ct.DateStart >= ao.Date_Effective --Max Date_Effective
WHERE tr.Source = 'P'
AND tr.SIG_ContractId != ''
AND tr.CustBookId IS NOT NULL



ContractTable is not required in this query.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
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