Creating New Columns

In addition to selecting columns that are stored in a table, you can create new columns that exist for the duration of the query. These columns can contain text or calculations. PROC SQL writes the columns that you create as if they were columns from the table.

Adding Text to Output

You can add text to the output by including a string expression, or literal expression, in a query. The following query includes two strings as additional columns in the output:
libname sql 'SAS-library';

proc sql outobs=12;
   title 'U.S. Postal Codes';
   select 'Postal code for', Name, 'is', Code
      from sql.postalcodes;
Adding Text to Output
US Postal Codes
To prevent the column headings Name and Code from printing, you can assign a label that starts with a special character to each of the columns. PROC SQL does not output the column name when a label is assigned, and it does not output labels that begin with special characters. For example, you could use the following query to suppress the column headings that PROC SQL displayed in the previous example:
libname sql 'SAS-library';

proc sql outobs=12;
   title 'U.S. Postal Codes';
   select 'Postal code for', Name label='#', 'is', Code label='#'
      from sql.postalcodes;
Suppressing Column Headings in Output
US Postal Codes

Calculating Values

You can perform calculations with values that you retrieve from numeric columns. The following example converts temperatures in the SQL.WORLDTEMPS table from Fahrenheit to Celsius:
libname sql 'SAS-library';

proc sql outobs=12;
   title 'Low Temperatures in Celsius';
   select City, (AvgLow - 32) * 5/9 format=4.1
      from sql.worldtemps;
Note: This example uses the FORMAT attribute to modify the format of the calculated output. For more information, see Specifying Column Attributes.
Calculating Values
Low Temperatures in Celsius

Assigning a Column Alias

By specifying a column alias, you can assign a new name to any column within a PROC SQL query. The new name must follow the rules for SAS names. The name persists only for that query.
When you use an alias to name a column, you can use the alias to reference the column later in the query. PROC SQL uses the alias as the column heading in output. The following example assigns an alias of LowCelsius to the calculated column from the previous example:
libname sql 'SAS-library';

proc sql outobs=12;
   title 'Low Temperatures in Celsius';
   select City, (AvgLow - 32) * 5/9 as LowCelsius format=4.1
      from sql.worldtemps;
Assigning a Column Alias to a Calculated Column
Low Temperatures in Celsius

Referring to a Calculated Column by Alias

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
Range of High and Low Temperatures in Celsius
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.

Assigning Values Conditionally

Using a Simple CASE Expression

CASE expressions enable you to interpret and change some or all of the data values in a column to make the data more useful or meaningful.
You can use conditional logic within a query by using a CASE expression to conditionally assign a value. You can use a CASE expression anywhere that you can use a column name.
The following table, which is used in the next example, describes the world climate zones (rounded to the nearest degree) that exist between Location 1 and Location 2:
World Climate Zones
Climate zone
Location 1
Latitude at Location 1
Location 2
Latitude at Location 2
North Frigid
North Pole
90
Arctic Circle
67
North Temperate
Arctic Circle
67
Tropic of Cancer
23
Torrid
Tropic of Cancer
23
Tropic of Capricorn
-23
South Temperate
Tropic of Capricorn
-23
Antarctic Circle
-67
South Frigid
Antarctic Circle
-67
South Pole
-90
In this example, a CASE expression determines the climate zone for each city based on the value in the Latitude column in the SQL.WORLDCITYCOORDS table. The query also assigns an alias of ClimateZone to the value. You must close the CASE logic with the END keyword.
libname sql 'SAS-library';

proc sql outobs=12;
   title 'Climate Zones of World Cities';
   select City, Country, Latitude,
          case
             when Latitude gt 67 then 'North Frigid'
             when 67 ge Latitude ge 23 then 'North Temperate'
             when 23 gt Latitude gt -23 then 'Torrid'
             when -23 ge Latitude ge -67 then 'South Temperate'
             else 'South Frigid'
          end as ClimateZone
      from sql.worldcitycoords
      order by City;
Using a Simple CASE Expression
Climate Zones of World Cities

Using the CASE-OPERAND Form

You can also construct a CASE expression by using the CASE-OPERAND form, as in the following example. This example selects states and assigns them to a region based on the value of the Continent column:
libname sql 'SAS-library';

proc sql outobs=12;
   title 'Assigning Regions to Continents';
   select Name, Continent,
          case Continent
             when 'North America' then 'Continental U.S.'
             when 'Oceania' then 'Pacific Islands' 
             else 'None'
          end as Region
      from sql.unitedstates;
Note: When you use the CASE-OPERAND form of the CASE expression, the conditions must all be equality tests. That is, they cannot use comparison operators or other types of operators, as are used in Using a Simple CASE Expression.
Using a CASE Expression in the CASE-OPERAND Form
Assigning Regions to Continents

Replacing Missing Values

The COALESCE function enables you to replace missing values in a column with a new value that you specify. For every row that the query processes, the COALESCE function checks each of its arguments until it finds a nonmissing value, and then returns that value. If all of the arguments are missing values, then the COALESCE function returns a missing value. For example, the following query replaces missing values in the LowPoint column in the SQL.CONTINENTS table with the words Not Available:
libname sql 'SAS-library';

proc sql;
   title 'Continental Low Points';
   select Name, coalesce(LowPoint, 'Not Available') as LowPoint
      from sql.continents;  
Using the COALESCE Function to Replace Missing Values
Continental Low Points
The following CASE expression shows another way to perform the same replacement of missing values. However, the COALESCE function requires fewer lines of code to obtain the same results:
libname sql 'SAS-library';

proc sql;
   title 'Continental Low Points';
   select Name, case
                   when LowPoint is missing then 'Not Available'
                   else Lowpoint
                end as LowPoint
      from sql.continents;  

Specifying Column Attributes

You can specify the following column attributes, which determine how SAS data is displayed:
  • FORMAT=
  • INFORMAT=
  • LABEL=
  • LENGTH=
If you do not specify these attributes, then PROC SQL uses attributes that are already saved in the table or, if no attributes are saved, then it uses the default attributes.
The following example assigns a label of State to the Name column and a format of COMMA10. to the Area column:
libname sql 'SAS-library';

proc sql outobs=12;
   title 'Areas of U.S. States in Square Miles';
   select Name label='State', Area format=comma10. 
      from sql.unitedstates;
Note: Using the LABEL= keyword is optional. For example, the following two select clauses are the same:
select Name label='State', Area format=comma10.

select Name 'State', Area format=comma10.
Specifying Column Attributes
Areas of U.S. States in Square Miles