March 31, 2019 at 4:32 pm
Hello community,
I have build this query and what i want is :
1. When fo.dprocesso not null then return all documents with this value
2.If fo.dprocesso is null then return all documents with the supplier name like ( fo.nome ).
<SQL>
Declare @Process as varchar(10)
Declare @Suppliername Varchar(60)
Set @Processo = ''
Set @Suppliername = 'weber'
SELECT cast(0 as bit) as marca, fo.*
FROM fo inner join fo2 on fo2.fo2stamp = fo.fostamp
where
foano = 2019 and fo2.u_tstamp = ''
AND (
(CASE WHEN fo.dprocesso IS NOT NULL THEN '%' + @Process + '%' ELSE '0' END ) = '1'
AND
(CASE WHEN fo.nome IS NOT NULL AND fo.dprocesso IS NULL THEN '%' + @Suppliername + '%' ELSE '0' END ) = '1'
)
</SQL>
something is missing because no value was return when @process not null, or, when @process is null and @Suppliername is not nul
Could someone help me.
Best regards,
Luis
April 1, 2019 at 8:35 am
Sometimes it helps to separate out the decision logic from the action logic, and a convenient way to do this is to put the decision logic into a CROSS APPLY block like this:
Declare @Processo as varchar(10)
Declare @Suppliername Varchar(60)
Set @Processo = ''
Set @Suppliername = 'weber'
SELECT cast(0 as bit) as marca, fo.*
FROM fo
INNER JOIN fo2
ON fo2.fo2stamp = fo.fostamp
CROSS APPLY (
SELECT MyFilter = CASE
WHEN fo.dprocesso IS NOT NULL THEN 1
WHEN fo.dprocesso IS NULL AND fo.nome IS NOT NULL THEN 2
WHEN fo.dprocesso IS NULL AND fo.nome IS NULL THEN 3
ELSE NULL END
) x
WHERE foano = 2019
AND fo2.u_tstamp = ''
AND (
(MyFilter = 1 AND fo.dprocesso LIKE '%' + @Processo + '%')
OR
(MyFilter = 2 AND fo.nome LIKE '%' + @Suppliername + '%')
OR
(MyFilter = 3)
)
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
April 1, 2019 at 11:18 am
Hello Chris,
Great idea and example 🙂
it´s the first example with Cross Apply and separate decision logic that i saw, i will go to test it.
Many thanks for your reply.
Best regards,
Luis
Viewing 3 posts - 1 through 2 (of 2 total)
You must be logged in to reply to this topic. Login to reply