After reading this article, you'll never worry about date formats again.
My recent articles on exporting data have generated a number of questions on formatting dates with SQL. So let's explore SQL dates by looking at how to create date fields in physical files, insert dates into physical files, and export the dates in different formats.
For a practical example of using dates in SQL, let's create a simple physical file/table that will keep a record of the temperature by postal code. The physical file will be named mc_temp and the comparable table will be named mc_temp2. It will have a primary composite key consisting of the postal code, date, and time, which will store a description of the weather and the temperature for the specified time. And to examine the timestamp field, we will also record the date and time of the data entry.
Create a Physical File Using DDS
If we were to use DDS to create a physical file named mc_temp, the code could look like this:
A R TFMT
A TPOSTAL 12A COLHDG('POSTAL_CODE')
A TDATE L DATFMT(*ISO)
A COLHDG('TEMP_DATE')
A TTIME T TIMFMT(*HMS)
A COLHDG('TEMP_TIME')
A TDATTIM Z COLHDG('ENTRY_DATE_TIME')
A TDESC 10A COLHDG('DESCRIPTION')
A TTEMP 5S 2 COLHDG('DEGREES_F')
A K TPOSTAL
A K TDATE
A K TTIME
Create a Table Using SQL
If we were to create a similar table using SQL, our SQL statement could look like this:
create table mc_temp2
(POSTAL_CODE for column TPOSTAL char(12),
TEMP_DATE for column TDATE date,
TEMP_TIME for column TTIME time,
ENTRY_DATE_TIME for column TDATTIM timestamp,
DESCRIPTION for column TDESC char(10),
DEGREES_F for column TTEMP numeric(5, 2),
primary key (TPOSTAL, TDATE, TTIME))
You may note that in the DDS, we were able to specify the DATFMT, but we cannot use the DATFMT in the SQL command when creating a table. The date, time, and timestamp data is all stored in the physical file the same way; we would just format the data when we're using it.
Compare the Date and Time Fields in the Physical File/Tables
When we compare the results of the two different methods of creating the physical file/table, we will see the following:
Figure 1: These are the date and time fields for the DDS physical file. (Click images to enlarge.)
Figure 2: These are the date and time fields for the SQL Create Table.
You can see that the data types, field length, and column headings are the same.
Compare the Zoned Fields in the Physical File/Table
I know it doesn't have anything to do with the date and time, but while we're at it, we may as well take a look at how to create a zoned field using SQL.
Figure 3: Here is the zoned field for the DDS physical file.
Figure 4: And here is the zoned field for the SQL numeric field.
Both methods provide the same data type, field length, and column heading.
Inserting Date, Time, and Timestamp Using SQL
Now that we have created our tables, we can start to insert some data. To insert an entry for ZIP code 19104 in the USA on June 16, 2010, at 10:30 a.m., we will manually set the entry timestamp and set the description to be Sunny at 69.12 degrees Fahrenheit.
insert into mc_temp values('USA 19104', '06/16/2010', '10:30:00',
'2010-06-16-10.31.43','Sunny', 69.12)
1 rows inserted in MC_TEMP in MYLIB.
To avoid redundancy, I'll just be using the mc_temp table because the behavior will be the same for both cases.
Use Different Date Formats During the Insert
As you can see in the next example of an insert, SQL is not picky about the format of the date and time that is used to set the values.
insert into mc_temp values('USA 19104', '2010-06-21', '13.14.15',
'2010-06-21-13.30.00', 'Sunny', 76.00)
1 rows inserted in MC_TEMP in MYLIB.
The previous insertion used the mm/dd/yyyy format, whereas this insertion is using the yyyy-mm-dd date format. The time format is also different. The previous statement used the colon (:) separator and this statement is using a period (.).
Use the Current Time and Date Values
It may always be sunny in Philadelphia, but that's not the case everywhere. Let's make our SQL statements more interesting by adding some data for another city, and while we're at it, we'll do it by using some special register values that are available to SQL: current date, current time, and current timestamp.
insert into mc_temp values('USA 90210', current date, current time,
current timestamp,'Rain Storm', 51.50)
1 rows inserted in MC_TEMP in MYLIB.
View the Results with Select
Now if we were to view the results of our data insertions, we could execute a simple Select statement to view the default formatting for the dates:
select * from mc_temp
Figure 5: This is the result of the Select statement.
You can see that even though the date was specified in the DDS to be in the ISO format, it still displays in the MM/DD/YY format. You can also see the column headings are displayed in the results, instead of the field names. We would get the same results using the file that was created with SQL.
Format Selected Dates and Times
So, we've seen the results of the default date and time formats. Now, let's look at some common formatting for one of my favorite dates: June 21(my daughter's birthday).
Common Date Formats |
||
Description |
Format |
Results |
International Standards Organization (*ISO) |
yyyy-mm-dd |
2010-06-21 |
USA Standard (*USA) |
mm/dd/yyyy |
06/21/2010 |
European Standard (*EUR) |
dd.mm.yyyy |
21.06.2010 |
Now let's look at some common time formats for one of my favorite times: 5:00 p.m.
Common Time Formats |
||
Description |
Format |
Results |
International Standards Organization (*ISO) |
hh.mm.ss |
17.00.00 |
USA Standard (*USA) |
hh:mm AM or PM |
5:00 PM |
Hours, Minutes, Seconds (*HMS) |
hh:mm:ss |
17:00:00 |
Format Dates in the Select Statement
OK, we have all the tools, so let's start formatting some dates! The simplest way that I have found to format dates would be to use the CHAR function. With the CHAR function, you simply specify the format and you're all set.
USA Standard
Let's start by running a Select statement to format our dates and times in USA style:
select tpostal, char(tdate, usa), char(ttime, usa), ttemp from mc_temp
Figure 6: Now the dates are formatted in USA format
.
And look there, the headings were changed to "CHAR conversion." We can fix that by using "as" followed by the heading name to display.
European Standard
What would it look like in Europe? Simple enough—just change the format in the char function, and while we're at it, we will set the heading names.
select tpostal, char(tdate, eur) as TEMP_DATE, char(ttime, eur) as TEMP_TIME, ttemp from mc_temp
Figure 7: Voila! We have the European standard.
And if we use ISO, we will get the expected results, but what about HMS? That doesn't work. And what if we want to create a custom date format outside of the standard? Now is a good time to talk about how to split out the different parts of the date.
Use SQL Built-In Functions to Split a Date Apart
DB2 has a set of built-in functions (BIFs) that we can use in SQL statements. Among these are a few date/time functions that we could use to split the dates apart: YEAR, MONTH, DAY, HOUR, MINUTE, and SECOND. Instead of pushing the date into a data structure and overlaying fixed formatted fields on top of the data to split the data apart, we can just use the functions to do the work.
In order to merge each piece of the date together, we will also cast the values to characters and concatenate them all together using double pipes (||). So, here is the SQL statement to generate the same results in yyyy/mm/dd and HMS format.
select tpostal,
cast(YEAR(tdate)||'/'||MONTH(tdate)||'/'||
DAY(tdate) as char(10)),
cast(HOUR(ttime)||':'||MINUTE(ttime)||':'||
SECOND(ttime) as char(8)),
ttemp from mc_temp
Figure 8: And this is the result.
We could get fancy with formatting and zero fill single digits to take up two spaces with a leading zero, but we'll save that project for another day.
Format Time Stamps
You may have noticed that I didn't include the timestamp values in the results of my queries. That's because there is one additional step required to use the char function on them to extract the date and time. There are two additional built in functions, DATE and TIME, that allow you to extract those values from the timestamp; then you could use the char function to perform the formatting.
select char(date(tdattim),iso), char(time(tdattim),iso) from mc_temp
Figure 9: And now we get a list of the timestamps in the ISO format.
Change the Defaults
In my default example above, the results were determined by the defaults that were set in my particular interactive SQL environment. You can change these when you execute the STRSQL command by prompting it.
And if you are using embedded SQL, you could set the defaults when you execute the CRTSQLxxx command. Then there are always your SQL_ATTR_DATE_FMT and SQL_ATTR_DATE_SEP environment variables as well. And if you were to use ODBC or JDBC, you could also set the defaults there too.
I deal with so many different formats that could be mixed within a single file that I don't usually change the defaults. I usually put them in the SQL statements so I know that the data will be the way that I want it when I execute them.
Put It All Together
Now if you refer to my previous articles, you will be able to export dates in any format to your IFS or any networked drive in ASCII format:
"Using DB2 with Sed, Tail, Pipes, and Redirection from Within Qshell"
"Create ASCII Text Files Using DB2 in Qshell"
Additional Information
- A useful presentation: "What's New in DB2 for i" by Mike Cain
- An IBM link showing the Create Table syntax and available data types: click here
- Another useful IBM link: DB2 Basics: Fun with Dates and Times
LATEST COMMENTS
MC Press Online