SQL can only convert a valid character representation of a date or timestamp, or a numeric value which is the calculated number of days since '0001-01-01' into a real date.
The easiest way to convert numeric dates would be something like this
Here are 3 versions of how to convert numeric dates into a real date.
With x (Y, M, D, NumDate)
as (Values(Dec(2023 , 4, 0), Dec(9, 2, 0), Dec(5, 2, 0), Dec(20230509, 8, 0)),
(Dec(2022 , 4, 0), Dec(12, 2, 0), Dec(31, 2, 0), Dec(20221231, 8, 0)))
Select x.*, Date(Right(Digits(Y*10000000000 + M*100000000 + D * 1000000), 14)) CalcDate,
Date(Digits(y) concat Digits(m) concat Digits(d) concat '000000') CharDate,
Date(Digits(NumDate) concat '000000') DateYMD
from x;
Mit freundlichen Grüßen / Best regards
Birgitta Hauser
Modernization – Education – Consulting on IBM i
IBM Champion since 2020
"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!"
"Train people well enough so they can leave, treat them well enough so they don't want to. " (Richard Branson)
"Learning is experience … everything else is only information!" (Albert Einstein)
-----Original Message-----
From: MIDRANGE-L <midrange-l-bounces@xxxxxxxxxxxxxxxxxx> On Behalf Of Dave
Sent: Tuesday, 5 September 2023 16:43
To: Midrange Systems Technical Discussion <midrange-l@xxxxxxxxxxxxxxxxxx>
Subject: Re: SQL dates and numeric columns
I'm surprised it's still so difficult to get a date from a numeric value Concat gives me this horrendous code :
date(
concat(
concat(
concat(trim(char(Y)), '-'), concat(trim(char(M)), '-')
)
, trim(char(D)))) " MyDate "
I would have liked to have been able to use
Y* 10000 + M* 100 + J
---------- message ---------
From: Dave <>
Date: Fri, 1 Sept 2023 at 10:40
Subject: SQL dates and numeric columns
To: Midrange Systems Technical Discussion <midrange-l@xxxxxxxxxxxxxxxxxx>
Hi,
Trying to do date operations on a physical file where the date is coded in
3 different numeric fields Y, M and D
1 - I created a view, can I do better than this :
date(trim(char(Y))!!'-'!!trim(char(M))!!'-'!!trim(char(D))) "MyDate"
?
2 – This works in an SQL session but the RPG compiler doesn’t seem to like the ‘ !’ character. Any ideas ?
Thanks
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list To post a message email: MIDRANGE-L@xxxxxxxxxxxxxxxxxx To subscribe, unsubscribe, or change list options,
visit:
https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives at
https://archive.midrange.com/midrange-l.
Please contact support@xxxxxxxxxxxxxxxxxxxx for any subscription related questions.
As an Amazon Associate we earn from qualifying purchases.