SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 General SQL Server Forums
 New to SQL Server Programming
 referencing a column
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

seeker62
Starting Member

40 Posts

Posted - 02/18/2013 :  11:57:57  Show Profile  Reply with Quote
The following query has many calculations. I would like to use one calculation (GrossAmount) in another calculation in the same query. When i do the query below it says that it cannot find the column GrossAmount.

SELECT *, (ISNULL(InvoiceVolume,0)+ISNULL(PendingVolume,0)+ISNULL(ScheduledVolume,0)-ISNULL(ContractedVolume,0)) as Difference,
(ISNULL(ContractedVolume,0)/2000) as ContractedTons,
(ISNULL(InvoiceVolume,0)/2000) as InvoicedTons,
(ISNULL(InvoiceVolume, 0)*ISNULL(GrossPrice,0)) as GrossAmount,
((([GrossAmount]) + ISNULL(FuelSurchargeAmount,0)) - ISNULL(FreightAmount,0) - ISNULL(MktgFeeAmount,0) - ISNULL(ValueAddedAmount,0)) as NetDue,
((((ISNULL(InvoiceVolume, 0)*ISNULL(GrossPrice,0)) + ISNULL(FuelSurchargeAmount,0)) - ISNULL(FreightAmount,0) - ISNULL(MktgFeeAmount,0) - ISNULL(ValueAddedAmount,0))/(ISNULL(InvoiceVolume,0)/2000)) as NetBack
FROM [EP_DataWarehouse].[dbo].[RptPortfolioCubeData] WITH (NOLOCK)
INNER JOIN [EP_Main].[dbo].[Product] WITH (NOLOCK) ON [EP_DataWarehouse].[dbo].[RptPortfolioCubeData].[ProductType] = [EP_Main].[dbo].[Product].[ProductName]
WHERE [EP_DataWarehouse].[dbo].[RptPortfolioCubeData].[LoadDate] BETWEEN '01/01/2013' AND '01/31/2013'
AND [EP_Main].[dbo].[Product].[ProductID] = 2

James K
Flowing Fount of Yak Knowledge

3334 Posts

Posted - 02/18/2013 :  12:14:32  Show Profile  Reply with Quote
You cannot use the alias you created in the select list (in this case GrossAmount) in another column in the select list. Either you have to repeat all the same computations or, you have to make the whole query into a sub-query like shown below:
-- repeat the calculations
SELECT *, (ISNULL(InvoiceVolume,0)+ISNULL(PendingVolume,0)+ISNULL(ScheduledVolume,0)-ISNULL(ContractedVolume,0)) as Difference, 
(ISNULL(ContractedVolume,0)/2000) as ContractedTons, 
(ISNULL(InvoiceVolume,0)/2000) as InvoicedTons, 
(ISNULL(InvoiceVolume, 0)*ISNULL(GrossPrice,0)) as GrossAmount, 
((((ISNULL(InvoiceVolume, 0)*ISNULL(GrossPrice,0))) + ISNULL(FuelSurchargeAmount,0)) - ISNULL(FreightAmount,0) - ISNULL(MktgFeeAmount,0) - ISNULL(ValueAddedAmount,0)) as NetDue, 
((((ISNULL(InvoiceVolume, 0)*ISNULL(GrossPrice,0)) + ISNULL(FuelSurchargeAmount,0)) - ISNULL(FreightAmount,0) - ISNULL(MktgFeeAmount,0) - ISNULL(ValueAddedAmount,0))/(ISNULL(InvoiceVolume,0)/2000)) as NetBack
FROM [EP_DataWarehouse].[dbo].[RptPortfolioCubeData] WITH (NOLOCK) 
INNER JOIN [EP_Main].[dbo].[Product] WITH (NOLOCK) ON [EP_DataWarehouse].[dbo].[RptPortfolioCubeData].[ProductType] = [EP_Main].[dbo].[Product].[ProductName]
WHERE [EP_DataWarehouse].[dbo].[RptPortfolioCubeData].[LoadDate] BETWEEN '01/01/2013' AND '01/31/2013'
AND [EP_Main].[dbo].[Product].[ProductID] = 2

-- or make it into a subquery
SELECT
	*,
	((([GrossAmount]) + ISNULL(FuelSurchargeAmount,0)) - ISNULL(FreightAmount,0) - ISNULL(MktgFeeAmount,0) - ISNULL(ValueAddedAmount,0)) as NetDue
FROM
(
SELECT *, (ISNULL(InvoiceVolume,0)+ISNULL(PendingVolume,0)+ISNULL(ScheduledVolume,0)-ISNULL(ContractedVolume,0)) as Difference, 
(ISNULL(ContractedVolume,0)/2000) as ContractedTons, 
(ISNULL(InvoiceVolume,0)/2000) as InvoicedTons, 
(ISNULL(InvoiceVolume, 0)*ISNULL(GrossPrice,0)) as GrossAmount, 
((((ISNULL(InvoiceVolume, 0)*ISNULL(GrossPrice,0)) + ISNULL(FuelSurchargeAmount,0)) - ISNULL(FreightAmount,0) - ISNULL(MktgFeeAmount,0) - ISNULL(ValueAddedAmount,0))/(ISNULL(InvoiceVolume,0)/2000)) as NetBack
FROM [EP_DataWarehouse].[dbo].[RptPortfolioCubeData] WITH (NOLOCK) 
INNER JOIN [EP_Main].[dbo].[Product] WITH (NOLOCK) ON [EP_DataWarehouse].[dbo].[RptPortfolioCubeData].[ProductType] = [EP_Main].[dbo].[Product].[ProductName]
WHERE [EP_DataWarehouse].[dbo].[RptPortfolioCubeData].[LoadDate] BETWEEN '01/01/2013' AND '01/31/2013'
AND [EP_Main].[dbo].[Product].[ProductID] = 2
) s

Go to Top of Page

seeker62
Starting Member

40 Posts

Posted - 02/18/2013 :  12:17:52  Show Profile  Reply with Quote
ok thanks.
Go to Top of Page

James K
Flowing Fount of Yak Knowledge

3334 Posts

Posted - 02/18/2013 :  12:18:51  Show Profile  Reply with Quote
You are welcome - glad to help.
Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.41 seconds. Powered By: Snitz Forums 2000