Re: FrontBase SQL: date formatting, „local variable“?
Re: FrontBase SQL: date formatting, „local variable“?
- Subject: Re: FrontBase SQL: date formatting, „local variable“?
- From: Samuel Pelletier <email@hidden>
- Date: Fri, 11 Mar 2016 19:11:56 -0500
Hi OC,
The easiest way to get a date a YYYYMMDD is this:
CAST(EXTRACT(year FROM "dateColumn") * 10000 + EXTRACT(month FROM "dateColumn") * 100 + EXTRACT(day FROM "dateColumn") as CHAR(8))
A more flexible way is to create a function (you can adjust the format):
create function formatDateOC(IN :"date" Timestamp) returns VARCHAR(20)
begin
declare "month" VARCHAR(20);
declare "day" VARCHAR(20);
set :"month" = CAST(EXTRACT(month FROM :"date") as VARCHAR(20));
set :"day" = CAST(EXTRACT(day FROM :"date") as VARCHAR(20));
if (char_length(:"month") = 1) then set :"month" = '0' || :"month"; END IF;
if (char_length(:"day") = 1) then set :"day" = '0' || :"month"; END IF;
return CAST(EXTRACT(year FROM :"date") as VARCHAR(4)) || :"month" || :"day";
end
To test it: values formatDateOC(cast(current_timestamp as timestamp))
Replace the argument by any timestamp value or column name that contains a timestamp.
Samuel
> Le 11 mars 2016 à 17:57, OC <email@hidden> a écrit :
>
> Well...
>
> On 11. 3. 2016, at 22:06, OC <email@hidden> wrote:
>
>> Still, it can be solvable (perhaps even easily)
>>
>> (a) in standard SQL92 which I don't know well enough
>> (b) in some FrontBase-specific extension
>>
>> which is why I am asking.
>
> ... without better knowledge the SQL used to derive the attribute looks like this. Yes, it is _terribly_ ugly, but I can't see how to simplify it whilst keeping the functionality. I would appreaciate if anybody sees and advices how to simplify this brute, especially if there's a way to get rid of the repeated nested SELECTs:
>
> ===
> CASE
> WHEN ( SELECT C_SHORTCUT FROM T_MARKET WHERE T_MARKET.C_UID = C_MARKET_ID ) IS NULL
> THEN
> 'Market(' ||
> CAST(C_MARKET_ID as VARCHAR(18)) ||
> ')'
> ELSE ( SELECT C_SHORTCUT FROM T_MARKET WHERE T_MARKET.C_UID = C_MARKET_ID )
> END ||
> '-' ||
> CASE
> WHEN ( SELECT C_START_DATE FROM T_TIME_CHUNK WHERE T_TIME_CHUNK.C_UID = C_TIME_CHUNK_UID ) IS NULL THEN '0'
> ELSE
> CAST(EXTRACT(year FROM ( SELECT C_START_DATE FROM T_TIME_CHUNK WHERE T_TIME_CHUNK.C_UID = C_TIME_CHUNK_UID )) AS VARCHAR(4)) ||
> CASE
> WHEN EXTRACT(month FROM ( SELECT C_START_DATE FROM T_TIME_CHUNK WHERE T_TIME_CHUNK.C_UID = C_TIME_CHUNK_UID ))<10 THEN '0'
> ELSE ''
> END ||
> CAST(EXTRACT(month FROM ( SELECT C_START_DATE FROM T_TIME_CHUNK WHERE T_TIME_CHUNK.C_UID = C_TIME_CHUNK_UID )) AS VARCHAR(2)) ||
> CASE
> WHEN EXTRACT(day FROM ( SELECT C_START_DATE FROM T_TIME_CHUNK WHERE T_TIME_CHUNK.C_UID = C_TIME_CHUNK_UID ))<10 THEN '0'
> ELSE ''
> END ||
> CAST(EXTRACT(day FROM ( SELECT C_START_DATE FROM T_TIME_CHUNK WHERE T_TIME_CHUNK.C_UID = C_TIME_CHUNK_UID )) AS VARCHAR(2))
> END ||
> '-' ||
> CAST(C_AUCTION_SEQ as VARCHAR(18))
> ===
>
> Thanks and all the best,
> OC
>
>
> _______________________________________________
> Do not post admin requests to the list. They will be ignored.
> Webobjects-dev mailing list (email@hidden)
> Help/Unsubscribe/Update your Subscription:
>
> This email sent to email@hidden
_______________________________________________
Do not post admin requests to the list. They will be ignored.
Webobjects-dev mailing list (email@hidden)
Help/Unsubscribe/Update your Subscription:
This email sent to email@hidden