|
| 1 | +CREATE OR REPLACE FUNCTION generic.jdate(jdate ANYELEMENT) |
| 2 | +RETURNS DATE AS |
| 3 | +$BODY$ |
| 4 | +DECLARE |
| 5 | +/* |
| 6 | +FUNCTION jdate |
| 7 | + |
| 8 | +AUTHOR: |
| 9 | +------- |
| 10 | +R. Wilmans-Sangwienwong (2020) |
| 11 | + |
| 12 | +PURPOSE: |
| 13 | +-------- |
| 14 | + |
| 15 | +Convert a JDE-date (format CYYDDD) to a regular date |
| 16 | + |
| 17 | +PARAMETERS: |
| 18 | +----------- |
| 19 | +jdate: Date in JD-Edwards format (CYYDDD, C = 0 : 1900, C=1: 2000, C=2: 2100, YY = 2-digit year, DDD = Julian Day (DoY)) |
| 20 | + Datatype: NUMERIC, INTEGER, BIGINT, TEXT, CHARACTER, CHARACTER VARYING |
| 21 | + Default : - |
| 22 | + |
| 23 | +RETURNS: |
| 24 | +-------- |
| 25 | +DATE: The converted JDE-date |
| 26 | + |
| 27 | +REMARKS: |
| 28 | +-------- |
| 29 | +- |
| 30 | + |
| 31 | +Example: |
| 32 | +-- --------------------------------------------------------------- |
| 33 | +SELECT generic.jdate(073308::INTEGER); |
| 34 | +SELECT generic.jdate(073308::BIGINT); |
| 35 | +SELECT generic.jdate(073308::NUMERIC); |
| 36 | +SELECT generic.jdate('073308'::CHARACTER VARYING); |
| 37 | +SELECT generic.jdate('073308'::TEXT); |
| 38 | +SELECT generic.jdate('073308'::CHARACTER(6)); |
| 39 | +-- --------------------------------------------------------------- |
| 40 | +*/ |
| 41 | + |
| 42 | +_jdate CHARACTER VARYING; |
| 43 | + |
| 44 | +BEGIN |
| 45 | + |
| 46 | +CASE |
| 47 | + WHEN PG_TYPEOF(jdate) IN('numeric','integer','bigint') THEN |
| 48 | + IF jdate IS NOT NULL AND jdate != 0 THEN |
| 49 | + _jdate := LPAD(jdate::CHARACTER VARYING,6,'0')::CHARACTER VARYING(6); |
| 50 | + IF RIGHT(_jdate,3)::INT >= 1 AND RIGHT(_jdate,3)::INT <= 366 THEN |
| 51 | + RETURN (SELECT TO_DATE(CONCAT(19+LEFT(_jdate,1)::INT,RIGHT(_jdate,5)),'YYYYDDD')); |
| 52 | + ELSE |
| 53 | + RETURN NULL::DATE; |
| 54 | + END IF; |
| 55 | + |
| 56 | + ELSE |
| 57 | + -- Dit kan geen geldige JDE-date zijn |
| 58 | + RETURN NULL::DATE; |
| 59 | + END IF; |
| 60 | + WHEN PG_TYPEOF(jdate) IN('text','character varying','character') THEN |
| 61 | + IF jdate ~ '^\d{1,6}$' AND jdate::INT >= 1 THEN |
| 62 | + _jdate := LPAD(jdate::CHARACTER VARYING,6,'0')::CHARACTER VARYING(6); |
| 63 | + IF RIGHT(_jdate,3)::INT >= 1 AND RIGHT(_jdate,3)::INT <= 366 THEN |
| 64 | + RETURN (SELECT TO_DATE(CONCAT(19+LEFT(_jdate,1)::INT,RIGHT(_jdate,5)),'YYYYDDD')); |
| 65 | + ELSE |
| 66 | + RETURN NULL::DATE; |
| 67 | + END IF; |
| 68 | + ELSE |
| 69 | + -- Dit kan geen geldige JDE-date zijn |
| 70 | + RETURN NULL::DATE; |
| 71 | + END IF; |
| 72 | + ELSE |
| 73 | + -- Vooralsnog geen datum van maken |
| 74 | + RAISE NOTICE 'Input (value:%) of unknown type: %',jdate,PG_TYPEOF(jdate); |
| 75 | + RETURN NULL::DATE; |
| 76 | +END CASE; |
| 77 | + |
| 78 | +END; |
| 79 | +$BODY$ |
| 80 | +LANGUAGE plpgsql; |
| 81 | +ALTER FUNCTION generic.jdate OWNER TO dwh_owner; |
| 82 | +GRANT EXECUTE ON FUNCTION generic.jdate TO talend; |
0 commit comments