create or replace function trunc(p_timestamp timestamp with time zone, p_formart varchar default 'DD') returns timestamp without time zone as $$ declare v_timestamp timestamp := null; v_formart varchar(10) := upper(p_formart); begin /* * 函數(shù)功能:對日期值進行格式化 * 參數(shù)說明: * P_TIMESTAMP ( 需要格式話的日期值 ) * P_FORMART ( YYYY:年第一天; MM|MONTH|MON|RM:月第一天; NULL|DD:當(dāng)日; D:當(dāng)前周第一天; ....) * 返回格式:YYYY-MM-DD HH24(12):MI:SS (具體值由第二個參數(shù)決定) */ if p_timestamp is not null then if v_formart in ('YYYY', 'YEAR') then -- 當(dāng)前年的第一天(YYYY-01-01 00:00:00) v_timestamp := date_trunc('year', p_timestamp); elsif v_formart in ('MONTH', 'MON', 'MM', 'RM') then -- 當(dāng)前月第一天(YYYY-MM-01 00:00:00) v_timestamp := date_trunc('month', p_timestamp); elsif v_formart in ('DD', 'DAY', 'DY') then -- 當(dāng)天(YYYY-MM-DD 00:00:00) v_timestamp := date_trunc('day', p_timestamp); elsif v_formart = 'D' then -- 當(dāng)前周第一天[周日為第一天](YYYY-MM-DD 00:00:00) v_timestamp := (date_trunc('WEEK', p_timestamp) - interval'1 day'); elsif v_formart in ('W1', 'W2', 'W3', 'W4', 'W5', 'W6', 'W7') then -- 當(dāng)前周第幾天[周日為第一天](YYYY-MM-DD 00:00:00) v_timestamp := date_trunc('WEEK', p_timestamp)::date + substr(v_formart, 2, 1)::integer - 2; elsif v_formart ~ '^D\+?[0-9]*$' then -- 當(dāng)年第幾天(YYYY-MM-DD 00:00:00) if substr(v_formart, 2, length(v_formart)-1)::integer between 1 and 366 then v_timestamp := date_trunc('year', p_timestamp)::date + substr(v_formart, 2, length(v_formart)-1)::integer - 1; if date_trunc('year', v_timestamp)::date > date_trunc('year', p_timestamp)::date then v_timestamp := date_trunc('year', v_timestamp)::date - interval'1 day'; end if; else raise exception 'U-2001 [%] is not recognize. please enter "D[1~366]"', p_formart; end if; elsif v_formart in ('HH', 'HH24') then v_timestamp := date_trunc('hour', p_timestamp); elsif v_formart = 'HH12' then v_timestamp := to_char(p_timestamp, 'yyyy-mm-dd hh22:00:00')::timestamp; elsif v_formart in ('MINUTE', 'MI') then v_timestamp := date_trunc('minute', p_timestamp); elsif v_formart = 'CC' then v_timestamp := to_date((trunc(date_part('years', p_timestamp)::integer/100)*100+1)::varchar, 'yyyy'); elsif v_formart in ('HELP', '?') then raise exception 'U-2001 please enter formart code in ( YYYY|YEAR, MONTH|MON|MM|RM, DD|DAY|DY, D, W[1~7], D[1~366], HH|HH24, HH12, MINUTE|MI, CC )'; else raise exception 'U-2001 [%] is not recognize. you can try [help]', p_formart; end if; else v_timestamp := p_timestamp; end if; return v_timestamp; end; $$ language plpgsql; -- 測試數(shù)據(jù) select trunc(current_date, 'D360'), trunc(current_date, 'D'),trunc(current_date, 'W1');
網(wǎng)站欄目:【小計】PostgreSQL實現(xiàn)Oracle的trunc日期函數(shù)功能
網(wǎng)頁鏈接:http://www.rwnh.cn/article12/gcgegc.html
成都網(wǎng)站建設(shè)公司_創(chuàng)新互聯(lián),為您提供服務(wù)器托管、網(wǎng)站營銷、品牌網(wǎng)站建設(shè)、網(wǎng)站策劃、搜索引擎優(yōu)化、手機網(wǎng)站建設(shè)
聲明:本網(wǎng)站發(fā)布的內(nèi)容(圖片、視頻和文字)以用戶投稿、用戶轉(zhuǎn)載內(nèi)容為主,如果涉及侵權(quán)請盡快告知,我們將會在第一時間刪除。文章觀點不代表本網(wǎng)站立場,如需處理請聯(lián)系客服。電話:028-86922220;郵箱:631063699@qq.com。內(nèi)容未經(jīng)允許不得轉(zhuǎn)載,或轉(zhuǎn)載時需注明來源: 創(chuàng)新互聯(lián)