March 2, 2004 at 2:17 pm
March 2, 2004 at 3:05 pm
Create Table #Tmp(Product VarChar(50),Quantity Decimal(10,4))
Go
Insert #Tmp
Select 'Widget',5
Insert #Tmp
Select 'Widget',6
Insert #Tmp
Select 'Widget',4
GO
Select * from #Tmp
Go
Select Product,Counter,Quantity
From #Tmp as t
Cross Join (Select 1 Union Select 2 Union Select 3 Union Select 4 Union Select 5) as c(Counter)
Where t.quantity=5
Go
Drop Table #Tmp
Go
March 2, 2004 at 3:39 pm
With a minor variation:
Create Table #Tmp(Product VarChar(50),Quantity Decimal(10,4))
Go
Insert #Tmp
Select 'Widget',5
Insert #Tmp
Select 'Widget',6
Insert #Tmp
Select 'Widget',4
GO
Select * from #Tmp
Go
Select Product,number,Quantity
From #Tmp as t
Cross Join (SELECT number from master..spt_values where type ='P' ) N
Where N.number Between 1 and t.Quantity
order by Product,Quantity, number
Go
Drop Table #Tmp
Go
* Noel
March 2, 2004 at 3:50 pm
March 2, 2004 at 4:00 pm
carmines,
none of the methods shown require temporary tables they were created using temptables just to avoid the creation of a "true" table in our enviroment.
If you replace the #T1 on my case for your Base table you are going to get the results you wanted:
CREATE VIEW vwMyView AS
Select Top 100 Percent Product,number,Quantity
From YOURTABLE as t
Cross Join (SELECT number from master..spt_values where type ='P' ) N
Where N.number Between 1 and t.Quantity
order by Product,Quantity, number
Select * from vwMyView where Product ='x' and quantity =y
* Noel
March 2, 2004 at 9:19 pm
>I would like to do this in a view if possible becuase it is going to be used as the data source to a report designer.
How would you pass a parameter to a VIEW to get only "WIDGETS" to return? Would a FUNCTION be acceptable?
--Jeff Moden
Change is inevitable... Change for the better is not.
March 3, 2004 at 1:31 pm
March 3, 2004 at 2:13 pm
As noeld uses spt_values in Master, I do also for the same kind of usages. This table seems to perform even faster than any "user table" made with the same values and indexing. It works great when CROSS JOINing to get iterations. I use it for values, not only between 0 and 255, but even performs great when CROSS JOINed with itself for values 0 - 65535. Its a quick and easy way to get a result set of integers without gaps. While it is a table in Master, and MS has the right to change it, I'm going to use it. If/when it does not work for this type of usage any longer, I'll mass search & replace to use a home made user table. Until then, I want to reap the performance and convenience benifits of using this table and the data it furnishes to me.
Just my $.02
Once you understand the BITs, all the pieces come together
March 3, 2004 at 5:28 pm
All well and good...
But the "poster" said that he wanted to do this as a VIEW! I asked the question a while back, "How would he parametrize a VIEW" to accept the part name? Especially without using dynamic SQL? Enquiring minds what to know!
--Jeff Moden
Change is inevitable... Change for the better is not.
March 4, 2004 at 11:14 am
Hi Jeff,
It is not a case of parameterising the view - I would simply use a where clause when selecting from the view.
Select * from vwMyView where Product ='widget'
Regards
John
March 5, 2004 at 6:51 am
Thanks carimines...
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 12 posts - 1 through 11 (of 11 total)
You must be logged in to reply to this topic. Login to reply