Querying Teradata and SQL Server - Tutorial 1: The SELECT Statement
- Prerequisites
- The From Cause
- Task
- Query – SQL Server
- Query – Teradata
- Result
- Comment
- The SELECT Clause
- Task
- Query – SQL Server
- Query – Teradata
- Result
- Comments
- Data Types
- Identity column
- Query – SQL Server
- Query – Teradata
- Format
- Date and Time functions
- Task
- Query – SQL Server
- Query – Teradata
- Result
- Character Functions
- Task
- SQL - SQL Server
- SQL – Teradata
- Result
- Comments
- Case Expression
- Task
- SQL – SQL Server
- SQL – Teradata
- Result
- Comments
- COALESCE
- Task
- SQL – SQL Server
- SQL – Teradata
- Result
- ISNULL
- SQL – SQL Server
- Comments
- NULLIF
- Task
- SQL – SQL Server
- SQL – Teradata
- Result
- Comments
- Summary
SELECT is one of the most commonly used statements. In this tutorial, I will cover the following items:
- Two of the principal query clauses—FROM and SELECT
- Data Types
- Built-in functions
- CASE expressions and variations like ISNULL and COALESCE.
* The function names mentioned above are based on SQL Server; Teradata’s equivalent functions may have same or different names.
Prerequisites
Please follow the post below to setup the sample databases in SQL Server and Teradata if you haven’t.
Querying Teradata and SQL Server - Tutorial 0: Preparation
The From Cause
Task
Retrieve all the employees (EmployeeID, Name, Birthday) from Employee table.
Query – SQL Server
USE [TD_MS_SAMPLE_DB] GO SELECT Emp.EmployeeID, Emp.EmployeeName, Emp.Birthday FROM dbo.Employee Emp;
Query – Teradata
DATABASE TD_MS_SAMPLE_DB; SELECT Emp.EmployeeID, Emp.EmployeeName, Emp.Birthday FROM Employee Emp;
Result
Comment
There is no Schema concept in Teradata but Database/User is similar to the schema in SQL Server. Any Teradata USER is also a DATABASE, but not all DATABASEs are USERs.
In Teradata, use ‘DATABASE $DatabaseName;’ statement to set the default database.
The SELECT Clause
Task
Retrieve all the employees (EmployeeID, Name, Birthday Year) from Employee table.
Query – SQL Server
USE [TD_MS_SAMPLE_DB] GO SELECT Emp.EmployeeID, Emp.EmployeeName, YEAR(Emp.Birthday) AS 'Birthday Year' FROM dbo.Employee Emp; -- Or SELECT Emp.EmployeeID, Emp.EmployeeName, YEAR(Emp.Birthday) AS [Birthday Year] FROM dbo.Employee Emp;
Query – Teradata
DATABASE TD_MS_SAMPLE_DB; SELECT Emp.EmployeeID, Emp.EmployeeName, EXTRACT(YEAR FROM Emp.Birthday) AS "Birthday Year" FROM Employee Emp;
Result
Comments
Teradata supports column alias and they have to enclosed with double quotes if there is a space in the name( you can use single quote or [] in SQL Server).
The date and time functions in Teradata are not all the same as SQL Server:
DATE or CURRENT_DATE - Both displays current date.
ADD_MONTHS(date,3) - Add 3 months to the current date.
ADD_MONTHS(date, -2)- Subtract 2 months from the current date.
TIME or CURRENT_TIME - Both displays current time.
EXTRACT( Day FROM Date)- Extracts and displays the day.
EXTRACT(Month FROM Date) - Extracts and display month.
EXTRACT(Year FROM Date) - Extracts and displays year.
CURRENT_TIMESTAMP - Displays combination of both date and time.
EXTRACT( Hour FROM Time) - Extracts and displays hour.
EXTRACT( Minute FROM Time) - Extracts and displays Minute.
EXTRACT( Second FROM Time) - Extracts and displays Second.
In Teradata, the column naming standards are different:
- Uppercase or lowercase letters (A to Z and a to z).
- Digits (0 through 9).
- The special characters $, #, and _.
- Must NOT begin with a digit.
- Must NOT begin with an UNDER SCORE.
- NO keywords can be used as aliases.
- Alias Names can not be duplicated in the same SQL query.
- Usage of the word AS is optional.
- If there is a space used, make sure it is enclosed with only double quotes.
In SQL Server, the identifiers must follow the following rules:
- the first character must be a letter in the range A through Z (lower or uppercase), underscore (_), at sign (@), or number sign (#).
- Subsequent characters can include letters, decimal numbers, at sign, dollar sign ($), number sign, or underscore.
- The identifier cannot be a reserved keyword in T-SQL
- Cannot have embedded spaces, and must not include supplementary characters.
- An identifier doesn’t comply with these rules must be delimited, e.g. [2015] is an legal identifier.
Data Types
Please refer to the following links to understand all the data types in SQL Server and Teradata.
- SQL Server: https://technet.microsoft.com/en-us/library/ms187752(v=sql.110).aspx
- Teradata: http://www.info.teradata.com/HTMLPubs/DB_TTU_14_00/SQL_Reference/B035_1143_111A/title.038.2.html
Both platforms cover the commonly used data types (Exact numerics, Unicode character strings, Approximate numerics, Binary strings, Date and time, Character strings …) while keeping its own extensions/variations.
Identity column
In SQL Server, identity is frequently used. There are multiple choices:
- The identity column property
- Sequence object (ANSI standard)
- UNIQUEIDENTIFIER (NEWID() )
- NEWSEQUENTIALID
In Teradata, you can also define auto-increased columns.
Query – SQL Server
USE [TD_MS_SAMPLE_DB] GO CREATE TABLE TestTable ( ID INT IDENTITY(1,1) NOT NULL );
Query – Teradata
DATABASE TD_MS_SAMPLE_DB; CREATE TABLE TestTable ( ID INT GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1 MINVALUE -2147483647 MAXVALUE 2147483647 NO CYCLE) NOT NULL );
Format
To format data, please refer to the following links:
- SQL Server: https://msdn.microsoft.com/en-us/library/hh213505
- Teradata: http://www.info.teradata.com/htmlpubs/DB_TTU_14_00/index.html#page/SQL_Reference/B035_1143_111A/ch09.051.01.html
Date and Time functions
Task
Retrieve all the employees (EmployeeID, Name, Age) from Employee table.
Query – SQL Server
USE [TD_MS_SAMPLE_DB] GO SELECT Emp.EmployeeID, Emp.EmployeeName, DATEDIFF(YEAR,Emp.Birthday, CURRENT_TIMESTAMP) AS Age FROM dbo.Employee Emp;
Query – Teradata
DATABASE TD_MS_SAMPLE_DB; SELECT Emp.EmployeeID, Emp.EmployeeName, (EXTRACT (YEAR FROM CURRENT_TIMESTAMP) - EXTRACT(YEAR FROM Emp.Birthday)) AS Age FROM Employee Emp;
Result
Character Functions
Task
Retrieve the following information from Employee table:
- EmployeeID
- EmployeeName
- EmployeeNameLength (Length of the name)
- EmployeeNameInitials (The first character of the name)EmployeeJobGradeAndSalary (display as ‘JobGrade - Salary’, e.g. ‘2 - 150000’)
SQL - SQL Server
USE [TD_MS_SAMPLE_DB] GO SELECT Emp.EmployeeID, Emp.EmployeeName, LEN(EmployeeName) AS EmployeeNameLength, SUBSTRING(EmployeeName,1,1) AS EmployeeNameInitials, CAST(Emp.JobGrade AS VARCHAR(1)) + ' - ' + CAST(Emp.Salary AS VARCHAR(13)) AS EmployeeJobGradeAndSalary FROM dbo.Employee Emp;
SQL – Teradata
DATABASE TD_MS_SAMPLE_DB; SELECT Emp.EmployeeID, Emp.EmployeeName, CHARACTER_LENGTH(EmployeeName) AS EmployeeNameLength, SUBSTR(EmployeeName,1,1) AS EmployeeNameInitials, CAST(CAST(Emp.JobGrade AS INTEGER)AS VARCHAR(2)) || ' - ' || CAST(Emp.Salary AS VARCHAR(13)) AS EmployeeJobGradeAndSalary FROM Employee Emp;
Or
SELECT Emp.EmployeeID, Emp.EmployeeName, SUBSTRING(EmployeeName FROM 1 FOR 1) AS EmployeeNameLength, SUBSTR(EmployeeName,1,1) AS EmployeeNameInitials, CAST((Emp.JobGrade (FORMAT '9')) AS VARCHAR(1)) || ' - ' || CAST((Emp.Salary (FORMAT '9(3),999.99')) AS VARCHAR(13)) AS EmployeeJobGradeAndSalary FROM Employee Emp;
Result
Comments
In Teradata, you can also use the following clause for substring:
SUBSTRING (EmployeeName FROM 1 FOR 1)
For string concatenation, the operator is ‘+’in SQL Server while it is ‘||’in Teradata (same as Oracle).
There are also other similar character functions in Teradata, e.g. UPPER, LOWER, TRIM, LTRIM, RTRIM, LPAD, RPAD… You can find more details at http://www.info.teradata.com/HTMLPubs/DB_TTU_14_00/index.html#page/SQL_Reference/B035_1145_111A/String_Ops_Funcs.084.001.html#ww663456.
Case Expression
In both Teradata and SQL Server, there are two forms of CASE expressions:
- The simple CASE expression compares an expression to a set of simple expressions to determine the result.
- The searched CASE expression evaluates a set of Boolean expressions to determine the result.
Task
Retrieve the following information from Employee table:
- EmployeeID,
- EmployeeName,
- Employee Salutation (if employee is Female, return ‘Dear MR + $EmployeeName' else return ‘Dear MS + $EmployeeName')
SQL – SQL Server
USE [TD_MS_SAMPLE_DB] GO SELECT Emp.EmployeeID, Emp.EmployeeName, CASE Emp.Gendar WHEN 'M' THEN 'Dear MR ' +Emp.EmployeeName ELSE 'Dear MS ' +Emp.EmployeeName END AS [Employee Salutation] FROM dbo.Employee Emp;
SQL – Teradata
SELECT Emp.EmployeeID, Emp.EmployeeName, CASE WHEN Emp.Gendar = 'M' THEN 'Dear MR ' || Emp.EmployeeName ELSE 'Dear MS ' ||Emp.EmployeeName END AS "Employee Salutation" FROM Employee Emp;
Result
Comments
The SQL Server sample is the simple version while the Teradata one is following the search format. If you want to evaluate columns with NULL value, you need to use the second format.
COALESCE
COALESCE is the ANSI standard function. Both SQL Server and Teradata support this function. The COALESCE function accepts a list of expressions as input and returns the first that is not NULL, or NULL if all are NULLs.
COALESCE(<exp1>, <exp2>, …, <expn>)
Task
Retrieve the employee id, employee name and manager employee id (display as characters) from Employee table; if there is no manger employee id, return ‘NULL’; the manager id needs to be displayed in the format ‘99,999’.
SQL – SQL Server
USE [TD_MS_SAMPLE_DB] GO SELECT Emp.EmployeeID, Emp.EmployeeName, COALESCE(FORMAT(Emp.EmployeeManagerEmployeeID, '##,###'),'NULL') AS ManagerID FROM dbo.Employee Emp;
SQL – Teradata
SELECT Emp.EmployeeID, Emp.EmployeeName, COALESCE((Emp.EmployeeManagerEmployeeID (FORMAT '99,999')),'NULL') AS ManagerID FROM Employee Emp;
Result
ISNULL
There is no ISNULL equivalent function in Teradata and you need to use COALESCE.
For the previous example, the query can be rewritten using ISNULL in SQL Server.
SQL – SQL Server
USE [TD_MS_SAMPLE_DB] GO SELECT Emp.EmployeeID, Emp.EmployeeName, ISNULL(FORMAT(Emp.EmployeeManagerEmployeeID, '##,###'),'NULL') AS ManagerID FROM dbo.Employee Emp;
Comments
The nullability of the column can be different when using ISNULL compared with COALESCE in SQL Server. Please be careful when you use it as it may impact the execution plan significantly.
NULLIF
Bothe the two platforms supports NULLIF function.
NULLIF(col1, col2)
If col1 is equal to col2, the function returns a NULL; otherwise, it returns the col1 value.
Task
Retrieve the employee id, employee name and manager employee id (display as characters) from Employee table; if there the manger employee id is ‘10,004’, return ‘NULL’; the manager id needs to be displayed in the format ‘99,999’.
SQL – SQL Server
USE [TD_MS_SAMPLE_DB] GO SELECT Emp.EmployeeID, Emp.EmployeeName, NULLIF(FORMAT(Emp.EmployeeManagerEmployeeID, '##,###'),'10,004') AS ManagerID FROM dbo.Employee Emp;
SQL – Teradata
SELECT Emp.EmployeeID, Emp.EmployeeName, NULLIF((Emp.EmployeeManagerEmployeeID (FORMAT '99,999')),'10,004') AS ManagerID FROM Employee Emp;
Result
Comments
There are some other useful variations in Teradata for NULL.
- NULLIFZERO: This will change a zero value to a NULL value.
- NULLIFSPACES: This will change a space value to a NULL value.
- ZEROIFNULL: This will change a NULL value to a zero.
- …
Summary
As both SQL Server and Teradata are following ANSI standards, you can easily convert your T-SQL to Teradata SQL and vice versa. It is recommended to use the ANSI standard functions/expressions so that you can migrate to each other smoothly.
In next tutorial, I will demonstrate the differences of filtering and sorting data.
@Mahe I could not identify any issue with your query directly.
Is your connection using the same credential as you were using in SQL Assistant?