× 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.



When writing an udf for converting numeric dates I'd always add an continue
handler for trapping invalid numeric dates.

CREATE OR REPLACE FUNCTION HSCOMMON10.NUM72DATE (
DATENUM DECIMAL(7, 0) )
RETURNS DATE
LANGUAGE SQL
DETERMINISTIC
READS SQL DATA
CALLED ON NULL INPUT

BEGIN
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION RETURN DATE ( '0001-01-01' ) ;
RETURN CAST (Right (Digits (DateNum + 19000000), 8) concat '000000' AS
DATE ) ;
END ;

For performance issues: using an UDF or scalar function on the left side of
the comparison operator in the where conditions is NOT a good idea, because
the optimizer will not be able to use an index over the field.
Also converting CURRENT_DATE or any other date expression on the right side
of the comparison operator is not an good idea either (may only be allowed
for ad hoc queryies)
Within programs it is far better to fill a numeric variable with the
appropriate value and use this host variable within the SQL statement

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: MIDRANGE-L [mailto:midrange-l-bounces@xxxxxxxxxxxx] Im Auftrag von
CRPence
Gesendet: Wednesday, 29.6 2016 01:06
An: midrange-l@xxxxxxxxxxxx
Betreff: Re: An easy (I think) SQL question

On 28-Jun-2016 15:50 -0500, Bill Howie wrote:

[?] I have a field in a file that is a date (field is in packed
format). The date in the field looks like this: 1160628.

Assumed: DEC(7) representing a /date/ value in form CYYMMDD.

The need is to only grab records from this file that go back 3 months
from the first day of the current month, so in this case I'd only want
records with a date greater than 1160301. This also needs to work if
when subtracting the 3 months I had to go across multiple years. I
know I can do a formula something like this:

(CURRENT_DATE - (DAY(CURRENT_DATE)-1) DAYS - 3 MONTH)

But I'm not sure how to use the packed numeric date field I have to
get there. Any thoughts would be greatly appreciated. Thanks!


Consider the following scripted actions as means to address the issue as
presented, and learn by tests performed, what was created:

Create some effective casting functions, between DATE data type and the
DEC(7) as CYYMMDD:

create function D7cymdToDate
( d7cymd dec(7)
) returns date
language sql
return
date( digits(dec((19000000 + d7cymd), 8)) concat '000000' )
;
create function DateToD7cymd
( inpDate date
) returns dec(7)
language sql
return
replace(char(inpDate, ISO), '-', '') - 19000000
;

Create a function to determine the starting date from the past N months,
according to the expression given:

create function months_past
( inpDate date
, nbrMonths int
) returns date
language sql
return
(inpDate - (DAY(inpDate)-1) DAYS - nbrMonths MONTH)
;

Note: the above UDFs were created with no exception handling nor any
thought as to the default settings [e.g. deterministic]; having only a
RETURN statement, they should be capable of being /inlined/

Create a table with some data for testing; include some data for
selecting into prior year and into prior century, and have a true DATE type
value alongside each CYYMMDD DEC(7) value:

create table d7test
( d7cymd dec(7)
, d7date date
)
;
insert into d7test (d7cymd) values
( 0990930 ), ( 0991001 ), ( 0991031 ), ( 0991101 ), ( 0991130 )
, ( 1150930 ), ( 1151001 ), ( 1151031 ), ( 1151101 ), ( 1151130 )
, ( 1160630 ), ( 1160701 ), ( 1160731 ), ( 1160801 ), ( 1160831 )
;
insert into d7test (d7date) values
( '1999-09-15' ), ( '1999-10-15' ), ( '1999-11-15' )
, ( '2015-09-15' ), ( '2015-10-15' ), ( '2015-11-15' )
, ( '2016-01-15' ), ( '2016-02-15' ), ( '2016-03-15' )
, ( '2016-04-15' ), ( '2016-05-15' ), ( '2016-06-15' )
, ( '2016-07-15' ), ( '2016-08-15' ), ( '2016-09-15' )
, ( '2016-10-15' ), ( '2016-11-15' ), ( '2016-12-15' )
; -- a mid-month date value for all of 2016; test into 2017
update d7test set d7date = D7cymdToDate(d7cymd)
where d7date is null
;
update d7test set d7cymd = DateToD7cymd(d7date)
where d7cymd is null
;

Now perform some tests; to limit the results, each where-clause adds an
extra predicate for d7date being less than the date that is supplied as
input to the months_past UDF on the pertinent predicate:

? verify selection on prior-year; use a date constant vs special
register:

select d7cymd , d7date
from d7test
where d7cymd > DateToD7cymd( months_past( date'2016-01-28', 3 ) )
and d7date<date'2016-01-28'
order by d7date
; -- result: six rows, since 2015-10-15

? verify selection on prior-century year; use a date constant vs the
special register:

select d7cymd , d7date
from d7test
where d7cymd > DateToD7cymd( months_past( date'2000-01-28', 3 ) )
and d7date<date'2000-01-28'
order by d7date
; -- result: five rows, since 1999-10-15

? a less desirable selection prohibits key selection:

select d7cymd , d7date
from d7test
where D7cymdToDate(d7cymd) > months_past( current_date, 3 )
and d7date<current_date
order by d7date
; -- if run in jun-2016, result: four rows, since 2016-03-15

? a more desirable selection to allow keyed selection:

select d7cymd , d7date
from d7test
where d7cymd > DateToD7cymd( months_past( current_date, 3 ) )
and d7date<current_date
order by d7date
; -- if run in jun-2016, result: four rows, since 2016-03-15

--
Regards, Chuck

--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxx To subscribe, unsubscribe,
or change list options,
visit: http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx Before posting, please take a
moment to review the archives at http://archive.midrange.com/midrange-l.

Please contact support@xxxxxxxxxxxx for any subscription related questions.


As an Amazon Associate we earn from qualifying purchases.

This thread ...

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.