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


Add a flag field if all rows match?


Add a flag field if all rows match?

Author
Message
SQL_Kills
SQL_Kills
Say Hey Kid
Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)

Group: General Forum Members
Points: 700 Visits: 819
Hi,

I have two tables, salesOrders and ProductList as per below:



SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO

CREATE TABLE [dbo].[salesOrders](
[SalesOrderID] [int] NOT NULL,
[SalesOrderLineID] [int] NOT NULL,
[OrderQty] [smallint] NOT NULL,
[ProductID] [varchar] (5) NOT NULL,
[UnitPrice] [money] NOT NULL,
[LineTotal] [numeric](38, 6) NOT NULL
) ON [PRIMARY]

GO


SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO

SET ANSI_PADDING ON
GO

CREATE TABLE [dbo].[ProductList](
[ProductID] [varchar](5) NOT NULL
) ON [PRIMARY]

GO

SET ANSI_PADDING OFF
GO


insert into salesOrders values ('43659','1','1','A776','2024.994','2024.994')
insert into salesOrders values ('43659','2','3','A777','2024.994','6074.982')
insert into salesOrders values ('43659','3','1','A778','2024.994','2024.994')
insert into salesOrders values ('43659','4','1','A771','2039.994','2039.994')
insert into salesOrders values ('43659','5','1','A772','2039.994','2039.994')
insert into salesOrders values ('43659','6','2','A773','2039.994','4079.988')
insert into salesOrders values ('43659','7','1','A774','2039.994','2039.994')
insert into salesOrders values ('43659','8','3','A714','28.8404','86.5212')
insert into salesOrders values ('43659','9','1','A716','28.8404','28.8404')
insert into salesOrders values ('43659','10','6','A709','5.7','34.2')
insert into salesOrders values ('43659','11','2','A712','5.1865','10.373')
insert into salesOrders values ('43659','12','4','A711','20.1865','80.746')
insert into salesOrders values ('43660','1','1','A762','419.4589','419.4589')
insert into salesOrders values ('43660','2','1','A758','874.794','874.794')
insert into salesOrders values ('43661','1','1','A745','809.76','809.76')
insert into salesOrders values ('43661','2','1','A743','714.7043','714.7043')
insert into salesOrders values ('43661','3','2','A747','714.7043','1429.4086')
insert into salesOrders values ('43661','4','4','A712','5.1865','20.746')
insert into salesOrders values ('43661','5','4','A715','28.8404','115.3616')
insert into salesOrders values ('43661','6','2','A742','722.5949','1445.1898')
insert into salesOrders values ('43661','7','3','A775','2024.994','6074.982')
insert into salesOrders values ('43661','8','2','A778','2024.994','4049.988')
insert into salesOrders values ('43661','9','2','A711','20.1865','40.373')
insert into salesOrders values ('43661','10','2','A741','818.7','1637.4')
insert into salesOrders values ('43661','11','4','A776','2024.994','8099.976')
insert into salesOrders values ('43661','12','2','A773','2039.994','4079.988')
insert into salesOrders values ('43661','13','2','A716','28.8404','57.6808')
insert into salesOrders values ('43661','14','2','A777','2024.994','4049.988')
insert into salesOrders values ('43661','15','5','A708','20.1865','100.9325')
insert into salesOrders values ('43662','1','3','A764','419.4589','1258.3767')
insert into salesOrders values ('43662','2','5','A770','419.4589','2097.2945')
insert into salesOrders values ('43662','3','2','A730','183.9382','367.8764')
insert into salesOrders values ('43662','4','4','A754','874.794','3499.176')
insert into salesOrders values ('43662','5','3','A725','183.9382','551.8146')
insert into salesOrders values ('43662','6','5','A762','419.4589','2097.2945')
insert into salesOrders values ('43662','7','3','A765','419.4589','1258.3767')
insert into salesOrders values ('43662','8','2','A768','419.4589','838.9178')
insert into salesOrders values ('43662','9','1','A753','2146.962','2146.962')
insert into salesOrders values ('43662','10','1','A756','874.794','874.794')
insert into salesOrders values ('43662','11','3','A763','419.4589','1258.3767')
insert into salesOrders values ('43662','12','1','A732','356.898','356.898')
insert into salesOrders values ('43662','13','6','A758','874.794','5248.764')
insert into salesOrders values ('43662','14','1','A729','183.9382','183.9382')
insert into salesOrders values ('43662','15','3','A722','178.5808','535.7424')
insert into salesOrders values ('43662','16','1','A749','2146.962','2146.962')
insert into salesOrders values ('43662','17','3','A760','419.4589','1258.3767')
insert into salesOrders values ('43662','18','1','A726','183.9382','183.9382')
insert into salesOrders values ('43662','19','1','A733','356.898','356.898')
insert into salesOrders values ('43662','20','1','A738','178.5808','178.5808')
insert into salesOrders values ('43662','21','3','A766','419.4589','1258.3767')
insert into salesOrders values ('43662','22','1','A755','874.794','874.794')
insert into salesOrders values ('43663','1','1','A760','419.4589','419.4589')
insert into salesOrders values ('43663','2','1','A755','874.794','874.794')
insert into salesOrders values ('43664','1','1','A772','2039.994','2039.994')
insert into salesOrders values ('43664','2','4','A775','2024.994','8099.976')
insert into salesOrders values ('43664','3','1','A714','28.8404','28.8404')
insert into salesOrders values ('43664','4','1','A716','28.8404','28.8404')
insert into salesOrders values ('43664','5','2','A777','2024.994','4049.988')
insert into salesOrders values ('43664','6','3','A771','2039.994','6119.982')
insert into salesOrders values ('43664','7','1','A773','2039.994','2039.994')
insert into salesOrders values ('43664','8','1','A778','2024.994','2024.994')
insert into salesOrders values ('43665','1','2','A711','20.1865','40.373')
insert into salesOrders values ('43665','2','1','A773','2039.994','2039.994')
insert into salesOrders values ('43665','3','1','A707','20.1865','20.1865')
insert into salesOrders values ('43665','4','2','A715','28.8404','57.6808')
insert into salesOrders values ('43665','5','2','A777','2024.994','4049.988')
insert into salesOrders values ('43665','6','2','A712','5.1865','10.373')
insert into salesOrders values ('43665','7','2','A775','2024.994','4049.988')
insert into salesOrders values ('43665','8','1','A778','2024.994','2024.994')
insert into salesOrders values ('43665','9','6','A709','5.7','34.2')
insert into salesOrders values ('43665','10','1','A776','2024.994','2024.994')
insert into salesOrders values ('43666','1','1','A764','419.4589','419.4589')
insert into salesOrders values ('43666','2','1','A753','2146.962','2146.962')
insert into salesOrders values ('43666','3','1','A732','356.898','356.898')
insert into salesOrders values ('43666','4','1','A756','874.794','874.794')
insert into salesOrders values ('43666','5','2','A768','419.4589','838.9178')
insert into salesOrders values ('43666','6','1','A766','419.4589','419.4589')
insert into salesOrders values ('43667','1','3','A710','5.7','17.1')
insert into salesOrders values ('43667','2','1','A773','2039.994','2039.994')
insert into salesOrders values ('43667','3','1','A778','2024.994','2024.994')
insert into salesOrders values ('43667','4','1','A775','2024.994','2024.994')
insert into salesOrders values ('43668','1','3','A756','874.794','2624.382')
insert into salesOrders values ('43668','2','2','A753','2146.962','4293.924')
insert into salesOrders values ('43668','3','7','A760','419.4589','2936.2123')
insert into salesOrders values ('43668','4','6','A765','419.4589','2516.7534')
insert into salesOrders values ('43668','5','6','A715','28.8404','173.0424')
insert into salesOrders values ('43668','6','6','A730','183.9382','1103.6292')
insert into salesOrders values ('43668','7','2','A707','20.1865','40.373')
insert into salesOrders values ('43668','8','2','A711','20.1865','40.373')
insert into salesOrders values ('43668','9','2','A754','874.794','1749.588')
insert into salesOrders values ('43668','10','4','A712','5.1865','20.746')
insert into salesOrders values ('43668','11','2','A729','183.9382','367.8764')
insert into salesOrders values ('43668','12','3','A755','874.794','2624.382')
insert into salesOrders values ('43668','13','3','A761','419.4589','1258.3767')
insert into salesOrders values ('43668','14','2','A770','419.4589','838.9178')
insert into salesOrders values ('43668','15','3','A726','183.9382','551.8146')
insert into salesOrders values ('43668','16','2','A764','419.4589','838.9178')
insert into salesOrders values ('43668','17','2','A766','419.4589','838.9178')
insert into salesOrders values ('43668','18','2','A725','183.9382','367.8764')
insert into salesOrders values ('43668','19','1','A716','28.8404','28.8404')
insert into salesOrders values ('43668','20','2','A768','419.4589','838.9178')


insert into ProductList values ('A755')
insert into ProductList values ('A760')
insert into ProductList values ('A776')
insert into ProductList values ('A777')




I have the following query:



select p.*, s.*
From salesOrders s left join ProductList p
on s.ProductID = p.ProductID






I want to add another field called "OrderMatched", where it will show a values of "yes" or "no" if the Product from the table ProductList appears on every SalesOrderLineID for that SalesOrderID.

So for SalesOrderID 43663 this will show as Yes.

Thanks
Igor Micev
Igor Micev
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10450 Visits: 5157
Hi

This code should do your job:

alter table salesOrders
add OrderMatched varchar(3) null

update salesOrders
set OrderMatched = 'yes'
from salesOrders s join ProductList p on s.ProductID = p.ProductID

update salesOrders
set OrderMatched = 'no'
where OrderMatched is null



Igor Micev,
My blog: www.igormicev.com
SQL_Kills
SQL_Kills
Say Hey Kid
Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)

Group: General Forum Members
Points: 700 Visits: 819
Hi,

I don't want to alter any table, I want this done by a sql select statement only? Plus this would not work as only want it to appear as Yes where every product is matched on the order line?

Thanks
dwain.c
dwain.c
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18119 Visits: 6431
If you just want the SalesOrderID that match your criteria:


SELECT SalesOrderID
FROM SalesOrders a
LEFT JOIN ProductList b ON a.ProductID = b.ProductID
GROUP BY SalesOrderID
HAVING COUNT(CASE WHEN b.ProductID IS NULL THEN 1 END) = 0;




If you want every line in that sales order to appear, you can put the above code into a CTE and then INNER JOIN it back the the SalesOrder table (ON SalesOrderID).


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
SQL_Kills
SQL_Kills
Say Hey Kid
Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)

Group: General Forum Members
Points: 700 Visits: 819
Hi,

How do you do the CTE? As I would like a flag field?

Thanks
dwain.c
dwain.c
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18119 Visits: 6431
Here's one way that lists all Sales Order records.


WITH CTE AS (
SELECT SalesOrderID
FROM #SalesOrders a
LEFT JOIN #ProductList b ON a.ProductID = b.ProductID
GROUP BY SalesOrderID
HAVING COUNT(CASE WHEN b.ProductID IS NULL THEN 1 END) = 0)
SELECT *
,Flag=ISNULL((SELECT 'YES' FROM CTE b WHERE a.SalesOrderID = b.SalesOrderID), 'NO')
FROM #SalesOrders a;





My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
Igor Micev
Igor Micev
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10450 Visits: 5157
SQL_Kills (9/8/2013)
Hi,

I don't want to alter any table, I want this done by a sql select statement only? Plus this would not work as only want it to appear as Yes where every product is matched on the order line?

Thanks


Ok, then the following query will probably help you:

select p.*, s.*, 
case
when s.ProductID = p.ProductID then 'Yes'
else 'No'
end as OrderMatch
From salesOrders s left join ProductList p
on s.ProductID = p.ProductID



Regards
IgorMi

Igor Micev,
My blog: www.igormicev.com
SQL_Kills
SQL_Kills
Say Hey Kid
Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)

Group: General Forum Members
Points: 700 Visits: 819
Thanks dwain.c !

Exactly what I need, nice work!
SQL_Kills
SQL_Kills
Say Hey Kid
Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)Say Hey Kid (700 reputation)

Group: General Forum Members
Points: 700 Visits: 819
Hi IgorMi this will not work, thanks though!
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