The query fails, because the calculation is converted into a Integer, so
0002021123 does not match the format YYYYDDD.
... but I'm still not clear why you want to use in any was
Timestamp_Format/TO_DATE to convert a numeric value with a date in the
format CYYDDD into a real date!
Date will do the job much easiser.
The following query converts several numeric dates in the format CYYDDD into
a real date, using the DATE and TIMESTAMP_FORMAT Functions
With x (YourCYYDDD) as (Values(Cast(121123 as Dec(7, 0))),
(Cast(99364 as Dec(7, 0))),
(Cast(107234 as Dec(7, 0))))
Select YourCYYDDD,
Date(Right(Digits(1900000 + YourCYYDDD), 7)) "With Date",
Date(Timestamp_Format(Right(Digits(1900000 + YourCYYDDD), 7),
'YYYYDDD')) "With Timestamp_Format"
from x;
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!"
?Train people well enough so they can leave, treat them well enough so they
don't want to.? (Richard Branson)
-----Original Message-----
From: MIDRANGE-L <midrange-l-bounces@xxxxxxxxxxxxxxxxxx> On Behalf Of
Stephen Landess
Sent: Donnerstag, 11. November 2021 19:38
To: Midrange Systems Technical Discussion <midrange-l@xxxxxxxxxxxxxxxxxx>
Subject: Re: TIMESTAMP_FORMAT
Vern wrote:
I don't know if anyone gave you this idea - first, timestamp_format
will work fine with this - i'm using a constant, but for the Julian
date - timestamp_format('2021025', 'YYYYDDD')
gives you '2021-01-25-00.00.00.000000' for the timestamp value.
At least, it did this correctly on our 7.3 box.
If you need the date only, wrap timestamp_format() with date().
Now your JDE value is CMMDDD, right?
How about adding 1900000 to that and using the digits function?
timestamp_format(digits(CMMDDD + 1900000), 'YYYYDDD')?
As I type that, I think I saw something like this in another post.
Apologies if it has already been suggested.
Vern -
This query:
SELECT
date(to_date(digits(1900000+gldgj),'YYYYDDD')) as date1 FROM f0911 WHERE
gldgj > 0
Fails with:
Message ID . . . . . . : QRY2293 Severity . . . . . . . : 30
Message type . . . . . : Information
Message . . . . : Query cannot be run. See lower level messages.
Cause . . . . . : An error occurred when the query to be run was opened or
while output was being created. Either a cancel reply was received to an
inquiry message about the problem, or the request was ended abruptly
without
use of an inquiry message. In most cases the problem involves data that
is
not correct or data that is not being used correctly.
Perhaps this explains the failure:
DIGITS(1900000+gldgj) produces a computed value which has a 12-byte length.
CHAR(), as suggested by Rob, strips the leading zeros.
Also, if gldgj = zeros, it also fails, thus I added WHERE GLDGJ > 0
Casting the computed value within the DIGITS() function as length 7 works
(see Date3 below):
SELECT
gldgj
, digits(1900000 + gldgj)
, char(1900000 + gldgj)
, date(to_date(char(1900000 + gldgj),'YYYYDDD')) as date1 ,
date(to_date(right(digits(1900000 + gldgj),7),'YYYYDDD')) as date2 ,
date(to_date(digits(cast(1900000 + gldgj as numeric(7,0))),'YYYYDDD')) as
date3
From F0911
WHERE GLDGJ > 0
G/L DIGITS CHAR DATE1 DATE2 DATE3
Date
--------
98,365 000001998365 1998365 1998-12-31 1998-12-31 1998-12-31
98,365 000001998365 1998365 1998-12-31 1998-12-31 1998-12-31
98,365 000001998365 1998365 1998-12-31 1998-12-31 1998-12-31
98,365 000001998365 1998365 1998-12-31 1998-12-31 1998-12-31
98,365 000001998365 1998365 1998-12-31 1998-12-31 1998-12-31
98,365 000001998365 1998365 1998-12-31 1998-12-31 1998-12-31
98,365 000001998365 1998365 1998-12-31 1998-12-31 1998-12-31
98,365 000001998365 1998365 1998-12-31 1998-12-31 1998-12-31
98,365 000001998365 1998365 1998-12-31 1998-12-31 1998-12-31
98,365 000001998365 1998365 1998-12-31 1998-12-31 1998-12-31
******** End of data ********
Regards,
Steve Landess
(512) 289-0387
________________________________
From: MIDRANGE-L <midrange-l-bounces@xxxxxxxxxxxxxxxxxx> on behalf of Vern
Hamberg <vhamberg@xxxxxxxxxxxxxxx>
Sent: Thursday, November 11, 2021 11:54 AM
To: midrange-l@xxxxxxxxxxxxxxxxxx <midrange-l@xxxxxxxxxxxxxxxxxx>
Subject: Re: TIMESTAMP_FORMAT
YYYYMMAA or DDMMYYYY to Julian YYYYDDDD) for that I recommend
invoking
(Call) the program X0028, which has the function of convert from
Gregorian Date to Julian and vice versa, once the date has been
converted you will have the parameters with the date in the
appropriate format (YYYYDDDD) to be used in any embedded SQL or as
you should use it Best Regards
Sergio -
Thanks for your comments.
I have been working with JDE for almost 40 years, so I am very familiar
with all of the JDE callable routines for validating and manipulating data.
In this case, my interest is in SQL scripts or SQL queries against the JDE
files, and I need the simplest way to query JDE and compare jde date fields
OUTSIDE of the JDE software.
Alan's iDate UDF is perfect for that!
Regards,
Steve Landess
512-289-0387
--
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://na01.safelinks.protection.outlook.com/?url=https%3A%2F%2Flists.midra
nge.com%2Fmailman%2Flistinfo%2Fmidrange-l&data=04%7C01%7C%7C87c85e4f070b
41da481608d9a53c53f9%7C84df9e7fe9f640afb435aaaaaaaaaaaa%7C1%7C0%7C6377225007
87557430%7CUnknown%7CTWFpbGZsb3d8eyJWIjoiMC4wLjAwMDAiLCJQIjoiV2luMzIiLCJBTiI
6Ik1haWwiLCJXVCI6Mn0%3D%7C1000&sdata=boqyZPeUTjS85HRJkH7QtEoYzrLNqF%2B3t
MMD4fgVoiE%3D&reserved=0
or email: MIDRANGE-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives at
https://na01.safelinks.protection.outlook.com/?url=https%3A%2F%2Farchive.mid
range.com%2Fmidrange-l&data=04%7C01%7C%7C87c85e4f070b41da481608d9a53c53f
9%7C84df9e7fe9f640afb435aaaaaaaaaaaa%7C1%7C0%7C637722500787557430%7CUnknown%
7CTWFpbGZsb3d8eyJWIjoiMC4wLjAwMDAiLCJQIjoiV2luMzIiLCJBTiI6Ik1haWwiLCJXVCI6Mn
0%3D%7C1000&sdata=bgITi9scSRlTmIyiSPOBlPzaTxks6jth7YqV1kP7dmA%3D&res
erved=0.
Please contact support@xxxxxxxxxxxxxxxxxxxx for any subscription related
questions.
Help support midrange.com by shopping at amazon.com with our affiliate link:
https://na01.safelinks.protection.outlook.com/?url=https%3A%2F%2Famazon.midr
ange.com%2F&data=04%7C01%7C%7C87c85e4f070b41da481608d9a53c53f9%7C84df9e7
fe9f640afb435aaaaaaaaaaaa%7C1%7C0%7C637722500787557430%7CUnknown%7CTWFpbGZsb
3d8eyJWIjoiMC4wLjAwMDAiLCJQIjoiV2luMzIiLCJBTiI6Ik1haWwiLCJXVCI6Mn0%3D%7C1000
&sdata=p1O%2FJanZdoThDX9R%2B2C82jr%2BZRSxFU7%2Fr06DpayL874%3D&reserv
ed=0
--
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.
Help support midrange.com by shopping at amazon.com with our affiliate link:
https://amazon.midrange.com
As an Amazon Associate we earn from qualifying purchases.