When you use a column alias to refer to a calculated
value, you must use the CALCULATED keyword with the alias to inform
PROC SQL that the value is calculated within the query. The following
example uses two calculated values, LowC and HighC, to calculate a
third value, Range:
libname sql 'SAS-library';
proc sql outobs=12;
title 'Range of High and Low Temperatures in Celsius';
select City, (AvgHigh - 32) * 5/9 as HighC format=5.1,
(AvgLow - 32) * 5/9 as LowC format=5.1,
(calculated HighC - calculated LowC)
as Range format=4.1
from sql.worldtemps;
Note: You can use an alias to refer
to a calculated column in a SELECT clause, a WHERE clause, or ORDER
BY clause.
Referring to a Calculated Column by Alias
Note: Because this query sets a
numeric format of 4.1 on the HighC, LowC, and Range columns, the values
in those columns are rounded to the nearest tenth. As a result of
the rounding, some of the values in the HighC and LowC columns do
not reflect the range value output for the Range column. When you
round numeric data values, this type of error sometimes occurs. If
you want to avoid this problem, then you can specify additional decimal
places in the format.