Home > Articles > Data > SQL

Working with Columns

In this chapter, learn many techniques that will serve you well throughout your career as a SQL programmer. Extend your knowledge of the SELECT statement by working with columns in the database tables; learn how to manipulate data using operators, functions, constants, and the CASE statement; explore how to use the CONVERT and CAST functions to change the data type of a value from one type to another, and to format dates differently; and finally, discover how to use the CASE expression to evaluate the values in selected columns and return a different value based on those contents.
This chapter was selected from Sams Teach Yourself Transact-SQL in 21 Days, Second Edition.

Day 3: Working with Columns

Yesterday, you took your first step in understanding the unique language of database access. Learning how to filter and sort the data returned by a SELECT statement provides you with the skills to get data from your database. Of course, this has only scratched the surface of what you can do with a SELECT statement.

In today's lesson, you will extend your knowledge of the SELECT statement by working with the columns in the database tables. We will cover a lot of information today, so prepare yourself. As you read this, you might ask yourself, "What will this do for me?" The answer to that question might not become clear until later in this book. Much of this lesson will help you throughout your career as a SQL programmer. The topics that will be discussed today are

  • Data types

  • Column manipulation

  • The CONVERT and CAST functions

  • Arithmetic and string operators

  • String functions

  • Date functions

  • Numeric functions

  • System functions

  • The CASE statement

Column Characteristics

When a column is added to a database table, you set several parameters that define the characteristics of that column. These include the name of the column, its data type, its length, and a default value. In this section, you will learn all about data types, what they are and how you should use them. In addition, you will see how empty or null columns are treated by the SQL processor.

Data Types

In a database, every column, variable, expression, and parameter has a related data type associated with it. A data type is an attribute that specifies the type of data (integer, string, date, and so on) that object can contain. All the data that a specific column holds must be of the same data type. A data type also determines how the data for a particular column is accessed, indexed, and physically stored on the server.

Tables 3.1 and 3.2 describe each of the available data types in Microsoft SQL Server 2000 and provide an example of what each might be used for. If the data you are working with is of different lengths, such as names, addresses, and other text, you should use variable-length data types. Fixed-length data types are best used for data, such as phone numbers, Social Security numbers, and ZIP Codes.

Table 3.1  Data Types in SQL Server 2000

Long Name

Syntax

Example

Description

Variable character

varchar(6)

"John"

Variable-length character fields are best for most strings.

Character

char(6)

"John"

Fixed-length character fields are best for most strings.

National variable characters

nvarchar(6)

"John"

Variable-length Unicode data with a maximum length of 4,000 characters.

Datetime

datetime

Jan 1, 200012:15:00.000 pm

Datetime fields are used for precise storage of dates and times. Datetimes can range from Jan 1, 1753 to Dec 31, 9999. Values outside this range must be stored as character.

Small datetime

smalldatetime

Jan 2, 200012:15pm

Small datetimes are half the size of datetimes. They use increments of one minute and represent dates from Jan 1, 1900 to Jun 6, 2079.

Precise decimal

decimal(4,2) or numeric(4,2)

13.22

Decimal/numeric data types store fractional numerics precisely. The first parameter specifies how many digits are allowed in the field. The second parameter specifies how many digits may come after the decimal. In this example, I could represent numbers from –99.99 to 99.99.

Big floating point

float(15)

64023.0134

Floating-point numbers are not guaranteed to be stored precisely. SQL Server rounds up numbers that binary math can't handle. Floats take a parameter specifying the total number of digits.

Little float

real(7)

16.3452

Half the size of a float; the same rules apply.

Integer

int

683423

Integers are four bytes wide and store numbers between plus or minus two billion.

Small integer

smallint

12331

Small integers are half the size of integers, ranging from –32,768 through 32,767.

Tiny integer

tinyint

5

Tiny integers are half again the size of small integers, a single byte, and may not be negative. Values run from 0 to 255. Perfect for an age column.

Bit

bit

1

Bits are the smallest data type available today. They are one bit in size, one-eighth of a byte. Bits may not be null and can have a value of 0 or 1. This is the actual language of all computers.

Binary

binary

0x00223FE2...

Fixed-length binary data with a maximum length of 8,000 bytes.

Money

money

$753.1132

Money types range from +/- 922 trillion. Money types store four digits to the right of the decimal and are stored as fixed-point integers.

Small money

smallmoney

$32.50

Small money can handle about +/ $214,000, with four digits to the right of the decimal. Half the size of Money.

Text

text

"We the people..."

Text fields can be up to 2GB in size. Text fields are treated at Binary Large Objects-(BLOBs) and are subject to a great many limitations They cannot be used in an ORDER BY, indexed, or grouped, and handling the inside an application program takes some extra work. (BLOBs will be discussed on Day 21, "Handling BLOBs in T-SQL.")

Image

image

0x00223FE2...

Image data can be used to store any type of binary data, including images (gif, jpg, and so on), executables, or anything else you can store on your disk drive. Images are also BLOBs, subject to the same limitations.


Table 3.2  New Data Types in SQL Server 2000

Long Name

Use

Example

Description

Big integer

bigint

983422348

A large integer that can hold a number +/- 2 raised to the 63rd power. Twice as large as an integer.

Sql_variant

sql_variant

 

A data type that stores values of other supported data types, except text, ntext, and sql_variant. You can use this to hold data from any other data type without having to know the data type in advance.

Table

table

 

This is a special data type that can be used to store a result set for later processing. It is primarily used for temporary storage of a set of rows.


Data Type Precedence

When two expressions of different data types are combined using one or more operators or functions, the data type precedence rules specify which data type is converted to the other. The data type with the lower precedence is converted to the data type with the higher precedence. If the conversion is not a supported implicit conversion, an error is returned. If both expressions have the same data type, the resulting object has the same data type. The order of precedence for the data types are shown in Table 3.3.

Table 3.3  Data Type Order of Precedence

Precedence Number

Data Type

1

sql_variant

2

datetime

3

smalldatetime

4

float

5

real

6

decimal

7

money

8

smallmoney

9

bigint

10

int

11

smallint

12

tinyint

13

bit

14

ntext

15

image

16

timestamp

17

uniqueidentifier

18

nvarchar

19

nchar

20

varchar

21

char

22

varbinary

23

binary


An example of the precedence can be seen when you add two unlike numbers together as shown here:

Select quantity * price as Sale_Total from "Order Details"

The quantity column is an integer data type, whereas the price column is a money data type. When this calculation is performed, the result would be a money data type.


Note - Don't worry about how to use the multiplication operator, or what the as Sale_Total means. We will cover these issues later in this lesson.


Using Null Data

When a column is empty, it is treated differently than when a column is blank or zero. These might sound the same to you, but to the computer, they are very different. A blank is an actual character that takes a position in the column. Of course, zero is its own explanation. A null means that the column actually contains nothing. To see how a null is displayed, try executing the following SQL statement in the Query Analyzer:

use pubs
select title_id, advance
from titles
order by title_id

Results:

title_id advance
-------- ---------------------
BU1032   5000.0000
BU1111   5000.0000
BU2075   10125.0000
BU7832   5000.0000
MC2222   .0000
MC3021   15000.0000
MC3026   NULL
PC1035   7000.0000
PC8888   8000.0000
PC9999   NULL
...
TC4203   4000.0000
TC7777   8000.0000

(18 row(s) affected)

You should see that null values are displayed using the string NULL. However, most standard comparisons will not recognize the null value. The next example shows you what happens when I add a where clause to the SELECT statement. I am looking for all title IDs where the advance amount is less than $5,000. You might think that 'null' or 'empty' are identical, but they're not. Although you will be covering functions later in this lesson, I want to cover one in this section.

The isnull() function permits a way to include null values in aggregate calculations. The function requires two arguments and its syntax is shown here:

Isnull(<expression>, <value>)

The first argument is the expression on which the calculation will be performed; usually this is a column from the database. The second argument is the value that will replace the null value for display or calculation purposes. If the expression contains a null, the second parameter is returned by this function. If the expression is not null, the value in the expression is returned.

The following SQL query shows the effect of the isnull() function on the titles table in the pubs database.

use pubs
select title_id, price, isnull(price, $45)
from titles
order by price

The output of this query shows which prices were null:

title_id price
-------- --------------------- ---------------------
MC3026   NULL                  45.0000
PC9999   NULL                  45.0000
MC3021   2.9900                 2.9900
BU2075   2.9900                 2.9900
PS2106   7.0000                 7.0000
...
PS3333  19.9900                19.9900
PC8888  20.0000                20.0000
TC3218  20.9500                20.9500
PS1372  21.5900                21.5900
PC1035  22.9500                22.9500

(18 row(s) affected)

As you can see in the output, there are two titles in the table that have null in their price column. When the isnull() function evaluates those columns, it returns $45 for the third column in the result set. For the other columns, it simply returns the value of the column.

You can use the isnull() function inside an aggregate function. If you want to know the average price of a book, you would ask for the avg(price) on the titles table. However, the two books that have null for a price would be excluded from the calculation. Suppose that you know that those books will be priced at $29 each. You could use the isnull() function to include those books in the calculation. The example shows you the query without the isnull() function and then with the isnull() function.

select avg(price)
from titles

Results:

---------------------
14.7662

(1 row(s) affected)

Warning: Null value is eliminated by an aggregate or other SET operation.

As you can see, the server displays a warning message informing you that there were null values found and they were not used.

select avg(isnull(price, $29))
from titles

Results:

---------------------
16.3477

(1 row(s) affected)

In the second version of the query, you can see that the average returned is different because the two books with nulls were included in the calculation. The isnull() function doesn't change the value of the row in the table; it only assumes a value for the purposes of a single query.

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020