On 06-May-2014 10:26 -0500, Hoteltravelfundotcom wrote:
There is some bad data in our system. There is a lack of validate
checking. In this case, can this SQL reject for processing any such
bad dates? Bad dates are defined as month>12 and days accordingly
SELECT ALL
T01.UAUSRN
, SUBSTR(DIGITS(UAFLWD), 5, 2) CONCAT '/' CONCAT /* MM/ */
SUBSTR(DIGITS(UAFLWD), 7, 2) CONCAT '/' CONCAT /* DD/ */
SUBSTR(DIGITS(UAFLWD), 3, 2) /* YY */
AS FOLLOWUP
, T01.UAENT#
, T01.UASFX#
, T02.ADENTN
, T01.UANOTT
, T01.UANOTL
, T02.ADLNM
, T02.ADFNM
, T01.UAFLWD
FROM ASTDTA.NOTEHDUA T01
INNER JOIN ASTDTA.ADRESsad T02
ON UAENT# = ADENT#
AND UASFX# = ADSFX#
WHERE UAFLWD BETWEEN 20000101 AND 20991231
and ( /* month with full 31 days */
( SUBSTR(DIGITS(UAFLWD), 5, 2) IN
(01, 03, 05, 07, 08, 10, 12)
and SUBSTR(DIGITS(UAFLWD), 7, 2) BETWEEN
01 AND 31
)
or /* month with only 30 days */
( SUBSTR(DIGITS(UAFLWD), 5, 2) IN
(04, 06, 09, 11)
and SUBSTR(DIGITS(UAFLWD), 7, 2) BETWEEN
01 AND 30
)
or /* month with 28 days min. */
( SUBSTR(DIGITS(UAFLWD), 5, 2) = 02
and SUBSTR(DIGITS(UAFLWD), 7, 2) BETWEEN
01 AND 28
)
or /* month with 29 days; leap */
( SUBSTR(DIGITS(UAFLWD), 5, 2) = 02
and SUBSTR(DIGITS(UAFLWD), 7, 2) = 29
and ( MOD(SUBSTR(DIGITS(UAFLWD), 1, 4), 4) = 0
and ( MOD(SUBSTR(DIGITS(UAFLWD), 1, 4), 100) <> 0
or MOD(SUBSTR(DIGITS(UAFLWD), 1, 4), 400) = 0
)
)
)
) /* this compound predicate was not tested, as shown */
AND UAPRGD < 1
AND UANOTT = 'E'
ORDER BY 001 ASC, 008 ASC
The above quoted query, with the additional selection shown inline,
will process\include only rows whereby the value for the field\column
UAFLWD [which is defined as a numeric data type and must contain only
valid numeric data] is a valid date-like representation in decimal
digits having the format commonly described as YYYYMMDD.
If not obvious, all of the additional selection might best be
encapsulated in a User Defined Function (UDF), and a comparison be made
against the result of the UDF; i.e. making the additional selection a
simple [not] equal or IS NOT NULL predicate. For example, the predicate
(vfyYYYYMMDD(CHAR(UAFLWD, 8)) IS NOT NULL) that invokes a UDF named
vfyYYYYMMDD [using an argument casting the numeric to a CHAR(8) which,
while not generally acceptable, likely would be functional in the given
scenario; i.e. contrast with the DIGITS scalar], as described in
http://archive.midrange.com/midrange-l/200911/msg01241.html# [Note: the
hash character as suffix intends to imply the _fixed_ in the upper right
of the page should be clicked to view in /fixed format/ instead of the
default presentation in a variable pitch font; no idea why that is not
directly the effect when the hash character is provided as the suffix].
Another option is to use a calendar table with a lookup\join between
the decimal date-like value to the like [or missing] value in the
calendar data; e.g. using an EXISTS predicate. A recursive Common Table
Expression (CTE) [RCTE] to generate the calendar data, as a derived
table scoped to the query may even be acceptable even for the noted
100-year window [per fewer than 36600 rows of data; i.e. ~365.25*100],
especially if the query is run seldom or there is little desire to
maintain the calendar table in\for the app.
As Rob suggests, the ideal situation is that the data has constraints
defined [CHECK constraints] to prevent any bad date values if the values
as decimal digits must be represented as dates. However a test that
effects a data mapping error [such as the example Rob gave] is not valid
to find check-pending rows because the query will fail. The example in
the above referenced archived message [whence the example compound
predicate as addendum to the query quoted from the OP came] using a CASE
expression can validate the data without a mapping error.
As an Amazon Associate we earn from qualifying purchases.