Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 General SQL Server Forums
 New to SQL Server Programming
 referencing a column

Author  Topic 

seeker62
Starting Member

40 Posts

Posted - 2013-02-18 : 11:57:57
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
Master Smack Fu Yak Hacker

3873 Posts

Posted - 2013-02-18 : 12:14:32
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 - 2013-02-18 : 12:17:52
ok thanks.
Go to Top of Page

James K
Master Smack Fu Yak Hacker

3873 Posts

Posted - 2013-02-18 : 12:18:51
You are welcome - glad to help.
Go to Top of Page
   

- Advertisement -