× The internal search function is temporarily non-functional. The current search engine is no longer viable and we are researching alternatives.
As a stop gap measure, we are using Google's custom search engine service.
If you know of an easy to use, open source, search engine ... please contact support@midrange.com.



For all those who want to create an date table with Dates in different
formats.
The following CREATE TABLE statement will generate an Calendar Table with
all Dates between 1900-01-01 and 2099-12-31 in different formats (if a
different date range is needed, starting and ending date in the Common Table
Expression have to be modified).
... Release 7.1 or higher is required!
Holidays are not included, because they are different in all countries and
sometimes even different in different states within the same country.

Create Table YourSchema/Calendar
as (With CTECalendar(RunDate) as
(Values(Timestamp('1900-01-01-00.00.00.000000'))
Union All
Select RunDate + 1 Day
From CTECalendar
where RunDate <
'2099-12-31-00.00.00.000000')
Select Date(RunDate) as
DateDate,
Cast(VarChar_Format(RunDate, 'YYYY') as Dec(4, 0)) as
DateYear4,
Cast(Case When Rundate between '1940-01-01-00.00.00.000000'
and '2039-12-31-24.00.00.000000'
Then VarChar_Format(RunDate, 'YY')
Else NULL End as Dec(3, 0)) as
DateYear2,
Cast(VarChar_Format(RunDate, 'MM') as Dec(2, 0)) as
DateMonth,
Cast(VarChar_Format(RunDate, 'DD') as Dec(2, 0)) as DateDay,
Cast(VarChar_Format(RunDate, 'YYYYMMDD') as Char(8)) as Date8A,
Cast(VarChar_Format(RunDate, 'YYYYMMDD') as Dec(8, 0)) as Date8N,
Cast(VarChar_Format(RunDate, 'MMDDYYYY') as Char(8)) as
DateMDYYA,
Cast(VarChar_Format(RunDate, 'MMDDYYYY') as Dec(8, 0)) as
DateMDYYN,
Cast(VarChar_Format(RunDate, 'DDMMYYYY') as Char(8)) as
DateDMYYA,
Cast(VarChar_Format(RunDAte, 'DDMMYYYY') as Dec(8, 0)) as
DateDMYYN,
Cast(VarChar_Format(RunDate, 'YYYYDDD') as Char(7)) as
DateYYDDDA,
Cast(VarChar_Format(RunDate, 'YYYYDDD') as Dec(7, 0)) as
DateYYDDDN,
Cast(VarChar_Format(Rundate, 'DDD') as Dec(3, 0)) as DayYear,
Cast(VarChar_Format(RunDate, 'ID') as Dec(3, 0)) as
WeekDayISO,
Cast(VarChar_Format(Rundate, 'IYYY') as Dec(4, 0)) as
YearWeekISO,
Cast(VarChar_Format(Rundate, 'IW') as Dec(3, 0)) as WeekISO,
Cast(Case When Rundate between '1940-01-01-00.00.00.000000'
and '2039-12-31-24.00.00.000000'
Then VarChar_Format(RunDate, 'YYMMDD')
Else NULL End as Char(6)) as
DateYMDA,
Cast(Case When Rundate between '1940-01-01-00.00.00.000000'
and '2039-12-31-24.00.00.000000'
Then VarChar_Format(RunDate, 'YYMMDD')
Else NULL End as Dec(6, 0)) as
DateYMDN,
Cast(Case When Rundate between '1940-01-01-00.00.00.000000'
and '2039-12-31-24.00.00.000000'
Then VarChar_Format(RunDate, 'MMDDYY')
Else NULL End as Char(6)) as
DateMDYA,
Cast(Case When Rundate between '1940-01-01-00.00.00.000000'
and '2039-12-31-24.00.00.000000'
Then VarChar_Format(RunDate, 'MMDDYY')
Else NULL End as Dec(6, 0)) as
DateMDYN,
Cast(Case When Rundate between '1940-01-01-00.00.00.000000'
and '2039-12-31-24.00.00.000000'
Then VarChar_Format(RunDate, 'DDMMYY')
Else NULL End as Char(6)) as
DateDMYA,
Cast(Case When Rundate between '1940-01-01-00.00.00.000000'
and '2039-12-31-24.00.00.000000'
Then VarChar_Format(RunDate, 'DDMMYY')
Else NULL End as Dec(6, 0)) as
DateDMYN,
Cast(Case When Rundate between '1940-01-01-00.00.00.000000'
and '2039-12-31-24.00.00.000000'
Then VarChar_Format(RunDate, 'YYDDD')
Else NULL End as Char(5)) as DateYDDDA,
Cast(Case When Rundate between '1940-01-01-00.00.00.000000'
and '2039-12-31-24.00.00.000000'
Then VarChar_Format(RunDate, 'YYDDD')
Else NULL End as Dec(5, 0)) as
DateYDDDN,
Cast(Case When Rundate between '1940-01-01-00.00.00.000000'
and '2039-12-31-24.00.00.000000'
Then VarChar_Format(RunDate, 'YYYYMMDD') - 19000000
Else NULL End as Char(10)) as
DateCYMDA,
Cast(Case When Rundate between '1900-01-01-00.00.00.000000'
and '2099-12-31-24.00.00.000000'
Then VarChar_Format(RunDate, 'YYYYMMDD') - 19000000
Else NULL End as Dec(8, 0)) as
DateCYMDN
From CTECalendar)
With data;;


Mit freundlichen Grüßen / Best regards

Birgitta Hauser

"Shoot for the moon, even if you miss, you'll land among the stars." (Les
Brown)
"If you think education is expensive, try ignorance." (Derek Bok)
"What is worse than training your staff and losing them? Not training them
and keeping them!"

-----Ursprüngliche Nachricht-----
Von: RPG400-L [mailto:rpg400-l-bounces@xxxxxxxxxxxx] Im Auftrag von Hiebert,
Chris
Gesendet: Monday, 04.1 2016 21:42
An: RPG programming on the IBM i (AS/400 and iSeries)
Betreff: RE: AW: Embedded SQL formatting dates

Here is the midrange code link:

code.midrange.com/c0a1c9c4cb.html

Please note that I just typed this up to make it more generic than what my
company actually used to load the table. So I apologize if there are any
syntax errors.

Also, the value I chose to start the D_DATE_SK index column with is very
specific.
Most DATE_DIM tables I found started with a value of 1.
I chose to start with a value of 693596. This was because the integer 693596
can be passed to the SQL DATE() function on the iSeries to generate the date
'1900-01-01'.

This little change allows any of the index values to be passed directly into
the DATE function to return the actual date, without needing to actually
retrieve the original row from the database. I'm referring specifically to
the First/Last of Month/Week columns, which all reference back to a
D_DATE_SK key value.

Also, the SQL for the indexes was not included. Currently, we have created
multiple indexes:

D_DATE_SK
D_DATE
D_YEAR,D_MOY,D_DOW,D_DATE
D_DATEYYMD,D_DATE
D_QOYN,D_DATE
D_MOYNA,D_DATE
D_MNYR,D_DATE
D_DATE_SK,D_DATE
D_QOYN,D_DATE

Chris Hiebert
Senior Programmer/Analyst
Disclaimer: Any views or opinions presented are solely those of the author
and do not necessarily represent those of the company.
--
This is the RPG programming on the IBM i (AS/400 and iSeries) (RPG400-L)
mailing list To post a message email: RPG400-L@xxxxxxxxxxxx To subscribe,
unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives at
http://archive.midrange.com/rpg400-l.



As an Amazon Associate we earn from qualifying purchases.

This thread ...

Follow-Ups:
Replies:

Follow On AppleNews
Return to Archive home page | Return to MIDRANGE.COM home page

This mailing list archive is Copyright 1997-2024 by midrange.com and David Gibbs as a compilation work. Use of the archive is restricted to research of a business or technical nature. Any other uses are prohibited. Full details are available on our policy page. If you have questions about this, please contact [javascript protected email address].

Operating expenses for this site are earned using the Amazon Associate program and Google Adsense.