Sqlserver2005迁移至Oracle系列之三:在Oracle中创建sql中的常见函数
2009-03-03 13:11:19 来源:WEB开发网 闂傚倸鍊搁崐鎼佸磹閹间礁纾归柟闂寸绾惧綊鏌熼梻瀵割槮缁炬儳缍婇弻鐔兼⒒鐎靛壊妲紒鐐劤缂嶅﹪寮婚悢鍏尖拻閻庨潧澹婂Σ顔剧磼閻愵剙鍔ょ紓宥咃躬瀵鎮㈤崗灏栨嫽闁诲酣娼ф竟濠偽i鍓х<闁绘劦鍓欓崝銈囩磽瀹ュ拑韬€殿喖顭烽幃銏ゅ礂鐏忔牗瀚介梺璇查叄濞佳勭珶婵犲伣锝夘敊閸撗咃紲闂佽鍨庨崘锝嗗瘱闂備胶顢婂▍鏇㈠箲閸ヮ剙鐏抽柡鍐ㄧ墕缁€鍐┿亜韫囧海顦﹀ù婊堢畺閺屻劌鈹戦崱娆忓毈缂備降鍔庣划顖炲Φ閸曨垰绠抽悗锝庝簽娴犻箖姊洪棃娑欐悙閻庢矮鍗抽悰顕€宕堕澶嬫櫖濠殿噯绲剧€笛囧箲閸ヮ剙钃熼柣鏂挎憸閻熷綊鏌涢…鎴濇灈妞ゎ剙鐗嗛—鍐Χ鎼粹€茬凹缂備緡鍠楅幐鎼佹偩閻戣棄纭€闁绘劕绉靛Λ鍐春閳ь剚銇勯幒鎴濐伀鐎规挷绀侀埞鎴︽偐閹绘帩浼€缂佹儳褰炵划娆撳蓟濞戞矮娌柟瑙勫姇椤ユ繈姊洪柅鐐茶嫰婢т即鏌熼搹顐e磳闁挎繄鍋涢埞鎴犫偓锝庘偓顓涙櫊閺屽秵娼幏灞藉帯闂佹眹鍊曢幊鎰閹惧瓨濯撮柛鎾村絻閸撳崬顪冮妶鍡楃仸闁荤啿鏅涢悾鐑藉Ψ瑜夐崑鎾绘晲鎼粹剝鐏嶉梺缁樻尰濞叉﹢濡甸崟顖氱疀闂傚牊绋愮花鑲╃磽娴h棄鐓愭慨妯稿妿濡叉劙骞樼拠鑼槰闂佸啿鎼崐濠毸囬弶搴撴斀妞ゆ梻銆嬪銉︺亜椤撶偛妲婚柣锝囧厴楠炴帡骞嬮弮鈧悗濠氭⒑鐟欏嫭鍎楅柛妯衡偓鐔插徍濠电姷鏁告慨鐑藉极閸涘﹥鍙忔い鎾卞灩绾惧鏌熼崜褏甯涢柍閿嬪灦閵囧嫰骞掗崱妞惧缂傚倷绀侀ˇ閬嶅极婵犳氨宓侀柛鈩冪⊕閸婄兘鏌涘┑鍡楊伀妞ゆ梹鍔曢埞鎴︽倻閸モ晝校闂佸憡鎸婚悷锔界┍婵犲洦鍤冮柍鍝勫暟閿涙粓姊鸿ぐ鎺戜喊闁告瑥楠搁埢鎾斥堪閸喓鍘搁柣蹇曞仧绾爼宕戦幘璇茬疀濞达絽鎲¢崐顖炴⒑绾懎浜归悶娑栧劦閸┾偓妞ゆ帒鍟惃娲煛娴e湱澧柍瑙勫灴閹瑩寮堕幋鐘辨闂備礁婀辨灙闁硅姤绮庨崚鎺楀籍閸喎浠虹紓浣割儓椤曟娊鏁冮崒娑氬幈闂佸搫娲㈤崝宀勬倶閻樼粯鐓曢柟鑸妼娴滄儳鈹戦敍鍕杭闁稿﹥鐗犲畷婵嬫晝閳ь剟鈥﹂崸妤€鐒垫い鎺嶈兌缁犲墽鈧厜鍋撳┑鐘辩窔閸嬫鈹戦纭烽練婵炲拑绲垮Σ鎰板箳閹冲磭鍠撻幏鐘绘嚑閼稿灚姣愰梻鍌氬€烽懗鑸电仚濠电偛顕崗妯侯嚕椤愩倖瀚氱€瑰壊鍠栧▓銊︾節閻㈤潧校缁炬澘绉瑰鏌ュ箵閹烘繄鍞甸柣鐘烘鐏忋劌顔忛妷褉鍋撶憴鍕碍婵☆偅绻傞~蹇涙惞閸︻厾锛滃┑鈽嗗灠閹碱偊锝炲鍥╃=濞达綁顥撻崝宥夋煙缁嬪灝鏆遍柣锝囧厴楠炲鏁冮埀顒傜不婵犳碍鍋i柛銉戝啰楠囬悗瑙勬尭缁夋挳鈥旈崘顔嘉ч柛鈩兠棄宥囩磽娴e壊鍎愰柛銊ュ缁顓兼径瀣偓閿嬨亜閹哄秶顦︾€殿喖鐏濋埞鎴﹀煡閸℃浠梺鍛婎焼閸曨収娲告俊銈忕到閸燁垶宕愰崹顐e弿婵☆垳鍘ф禍楣冩倵濮樼偓瀚�

prompt
prompt Creating function CHARINDEX
prompt ===========================
prompt
CREATE OR REPLACE FUNCTION charindex
(
search VARCHAR2,
src VARCHAR2,
pos INT := 0
) RETURN INT AS
tp_pos INT;
tp_src VARCHAR2(2000);
v_pos INT;
BEGIN
v_pos := 0;
tp_pos := pos;
tp_src := src;
IF pos <= 0 THEN
RETURN(instr(src, search, 1, 1));
ELSE
tp_src := substr(src, pos);
v_pos := nvl(instr(tp_src, search, 1, 1), 0);
IF v_pos = 0 THEN
RETURN(0);
ELSE
RETURN(v_pos + tp_pos - 1);
END IF;
END IF;
END charindex;
/
prompt
prompt Creating function DATEADD
prompt =========================
prompt
CREATE OR REPLACE FUNCTION dateadd
(
format VARCHAR2 := 'd',
n INT := 0,
dateval DATE := SYSDATE
) RETURN DATE AS
fmt VARCHAR2(10);
BEGIN
fmt := upper(format);
IF fmt IN ('D', 'DD', 'DAY') THEN
RETURN(dateval + n);
ELSIF fmt IN ('M', 'MM', 'MONTH') THEN
RETURN(add_months(dateval, n));
ELSIF fmt IN ('Y', 'YY', 'YYY', 'YYYY', 'YEAR') THEN
RETURN(add_months(dateval, n * 12.0));
ELSIF fmt IN ('H', 'HH', 'HOUR') THEN
RETURN(dateval + n / 24.0);
ELSIF fmt IN ('N', 'MI', 'MINUTE') THEN
RETURN(dateval + n / 24.0 / 60.0);
ELSIF fmt IN ('S', 'SS', 'SECOND') THEN
RETURN(dateval + n / 24.0 / 60.0 / 60.0);
ELSE
RETURN(NULL);
END IF;
END;
/
prompt
prompt Creating function DATEDIFF
prompt ==========================
prompt
CREATE OR REPLACE FUNCTION datediff
(
format VARCHAR2 := 'd',
datebegin DATE := SYSDATE,
dateend DATE := SYSDATE
) RETURN INT AS
fmt VARCHAR2(10);
BEGIN
fmt := upper(format);
IF fmt IN ('D', 'DD', 'DAY')
THEN
RETURN(datebegin - dateend);
ELSIF fmt IN ('M', 'MM', 'MONTH')
THEN
RETURN((datebegin - dateend) / 30);
ELSIF fmt IN ('Y', 'YY', 'YYY', 'YYYY', 'YEAR')
THEN
RETURN((datebegin - dateend) / 365);
ELSIF fmt IN ('H', 'HH', 'HOUR')
THEN
RETURN((datebegin - dateend) * 24);
ELSIF fmt IN ('N', 'MI', 'MINUTE')
THEN
RETURN((datebegin - dateend) * 24.0 * 60.0);
ELSIF fmt IN ('S', 'SS', 'SECOND')
THEN
RETURN((datebegin - dateend) * 24.0 * 60.0 * 60.0);
ELSE
RETURN(NULL);
END IF;
END;
/
prompt
prompt Creating function DATEPART
prompt ==========================
prompt
CREATE OR REPLACE FUNCTION datepart
(
format VARCHAR2 := 'd',
dateval DATE := SYSDATE
) RETURN VARCHAR2 AS
fmt VARCHAR2(10);
BEGIN
fmt := upper(format);
IF fmt IN ('D', 'DD', 'DAY')
THEN
RETURN(to_char(dateval, 'DD'));
ELSIF fmt IN ('M', 'MM', 'MONTH')
THEN
RETURN(to_char(dateval, 'MM'));
ELSIF fmt IN ('Y', 'YY', 'YYY', 'YYYY', 'YEAR')
THEN
RETURN(to_char(dateval, 'YYYY'));
ELSIF fmt IN ('H', 'HH', 'HOUR')
THEN
RETURN(to_char(dateval, 'HH'));
ELSIF fmt IN ('N', 'MI', 'MINUTE')
THEN
RETURN(to_char(dateval, 'MI'));
ELSIF fmt IN ('S', 'SS', 'SECOND')
THEN
RETURN(to_char(dateval, 'SS'));
ELSE
RETURN(NULL);
END IF;
END;
/
prompt
prompt Creating function DAY
prompt =====================
prompt
create or replace function day(v_date date := sysdate) return int as
begin
return(
to_number(TO_CHAR(v_date, 'dd'))
);
end;
/
prompt
prompt Creating function LEFT
prompt ======================
prompt
CREATE OR REPLACE FUNCTION left(src VARCHAR2,n INT) RETURN VARCHAR2 AS
BEGIN
RETURN(SUBSTR(src, 0, n));
END left;
/
prompt
prompt Creating function MONTH
prompt =======================
prompt
create or replace function month(v_date date := sysdate) return int as
begin
return(
to_number(TO_CHAR(v_date, 'mm'))
);
end;
/
prompt
prompt Creating function REPLICATE
prompt ===========================
prompt
CREATE OR REPLACE FUNCTION replicate
(
v_str VARCHAR2,
n INT
)
RETURN VARCHAR2 AS
v_dest VARCHAR(2000);
BEGIN
IF n <= 0 THEN
RETURN('');
ELSE
FOR i IN 1 .. n LOOP
v_dest := v_dest || v_str;
END LOOP;
END IF;
RETURN(v_dest);
END;
/
prompt
prompt Creating function RIGHT
prompt =======================
prompt
CREATE OR REPLACE FUNCTION right(src VARCHAR2,n INT) RETURN VARCHAR2 AS
BEGIN
RETURN(SUBSTR(src, -n));
END right;
/
prompt
prompt Creating function STR
prompt =====================
prompt
CREATE OR REPLACE FUNCTION str
(
numberval NUMBER,
len INT := 10,
decima INT := 0
) RETURN VARCHAR2 AS
v_decima INT;
v_numberval VARCHAR(300);
v_pos INT;
BEGIN
v_decima := abs(decima);
v_numberval := to_char(numberval);
v_pos := instr(v_numberval, '.');
IF v_decima > 16
THEN
v_decima := 16;
END IF;
IF v_pos = 0
THEN
v_pos := length(v_numberval);
IF abs(len) < v_pos
THEN
RETURN(lpad('*', len, '*'));
ELSE
RETURN(substr(v_numberval, 0, v_pos));
END IF;
ELSE
IF abs(len) < v_pos - 1
THEN
RETURN(lpad('*', len, '*'));
ELSE
IF least(v_decima, abs(len) - v_pos) > 0
THEN
v_numberval := to_char(round(numberval, least(v_decima, abs(len) - v_pos)));
RETURN(v_numberval);
ELSE
RETURN(rtrim(substr(v_numberval, 0, least((v_pos + v_decima), abs(len))), '.'));
END IF;
END IF;
END IF;
END str;
/
prompt
prompt Creating function STUFF
prompt =======================
prompt
CREATE OR REPLACE FUNCTION stuff
(
v_str VARCHAR2,
v_start INT,
v_len INT,
v_repacestr VARCHAR2
) RETURN VARCHAR2 AS
tp_str VARCHAR2(4000);
BEGIN
tp_str := v_str;
IF v_start <= 0
OR v_len < 0 THEN
RETURN('');
ELSIF v_start > length(v_str) THEN
RETURN('');
ELSE
tp_str := substr(v_str, 0, greatest(1, v_start) - 1) || v_repacestr || substr(v_str, greatest(1, v_start) + v_len);
RETURN(tp_str);
END IF;
END;
/
prompt
prompt Creating function SUBSTRING
prompt ===========================
prompt
CREATE OR REPLACE FUNCTION substring
(
str VARCHAR2,
pos INT := 0,
len INT := 0
) RETURN VARCHAR2 AS
BEGIN
IF len <= 0 THEN
RETURN('');
ELSIF (pos + len) <= 0 THEN
RETURN('');
ELSE
RETURN(substr(str, greatest(pos, 0), least(len, len + pos)));
END IF;
END substring;
/
prompt
prompt Creating function YEAR
prompt ======================
prompt
create or replace function year(v_date date := sysdate) return int as
begin
return(
to_number(TO_CHAR(v_date, 'yyyy'))
);
end;
/
- ››oracle 恢复误删除的表和误更新的表
- ››Oracle分页查询排序数据重复问题
- ››Oracle创建dblink报错:ORA-01017、ORA-02063解决
- ››Oracle 提高SQL执行效率的方法
- ››Oracle 动态查询,EXECUTE IMMEDIATE select into...
- ››Oracle 11g必须开启的服务及服务详细介绍
- ››oracle性能34条优化技巧
- ››oracle数据库生成随机数的函数
- ››Oracle 数据库表空间容量调整脚本
- ››oracle单库彻底删除干净的方法
- ››sqlserver 每30分自动生成一次
- ››Oracle创建表空间、创建用户以及授权、查看权限
更多精彩
赞助商链接