悠闲的漫步的个人主页

http://bbs.dragonsoul.top/u.php?uid=117  [收藏] [复制]

悠闲的漫步

世界是美好的,空气是清新的

  • 8

    关注

  • 16

    粉丝

  • 56

    访客

  • 等级:精灵王
  • 身份:论坛版主
  • 总积分:3906
  • 男,1980-04-26

最后登录:2017-01-02

更多资料

日志

Oracle 10g如何对用户姓名,按首字母排序、查询

2010-12-06 10:21
首先介绍Oracle 9i新增加的一个系统自带的排序函数
1、按首字母排序
在oracle9i中新增了按照拼音、部首、笔画排序功能。设置NLS_SORT值    
SCHINESE_RADICAL_M   按照部首(第一顺序)、笔划(第二顺序)排序    
SCHINESE_STROKE_M   按照笔划(第一顺序)、部首(第二顺序)排序    
SCHINESE_PINYIN_M   按照拼音排序

oracle9i中新增了按照拼音、部首、笔画排序功能
用法示例:
  1. 拼音    
    SELECT * FROM TEAM ORDER BY NLSSORT(排序字段,'NLS_SORT = SCHINESE_PINYIN_M')    
    笔划    
    SELECT * FROM TEAM ORDER BY NLSSORT(排序字段,'NLS_SORT = SCHINESE_STROKE_M')    
    部首    
    SELECT * FROM TEAM ORDER BY NLSSORT(排序字段,'NLS_SORT = SCHINESE_RADICAL_M')  


2、按首字母拼音查询
首先我们要创建一个可以查询汉字首字母的函数,函数代码如下:
  1. CREATE OR REPLACE FUNCTION F_TRANS_PINYIN_CAPITAL(P_NAME IN VARCHAR2) RETURN VARCHAR2 AS    
    V_COMPARE VARCHAR2(100);    
    V_RETURN VARCHAR2(4000);    
      
    FUNCTION F_NLSSORT(P_WORD IN VARCHAR2) RETURN VARCHAR2 AS    
    BEGIN    
    RETURN NLSSORT(P_WORD, 'NLS_SORT=SCHINESE_PINYIN_M');    
    END;    
    BEGIN    
    FOR I IN 1..LENGTH(P_NAME) LOOP    
    V_COMPARE := F_NLSSORT(SUBSTR(P_NAME, I, 1));    
    IF V_COMPARE >= F_NLSSORT(' 吖 ') AND V_COMPARE <= F_NLSSORT('驁 ') THEN    
    V_RETURN := V_RETURN || 'a';    
    ELSIF V_COMPARE >= F_NLSSORT('八 ') AND V_COMPARE <= F_NLSSORT('簿 ') THEN    
    V_RETURN := V_RETURN || 'b';    
    ELSIF V_COMPARE >= F_NLSSORT('嚓 ') AND V_COMPARE <= F_NLSSORT('錯 ') THEN    
    V_RETURN := V_RETURN || 'c';    
    ELSIF V_COMPARE >= F_NLSSORT('咑 ') AND V_COMPARE <= F_NLSSORT('鵽 ') THEN    
    V_RETURN := V_RETURN || 'd';    
    ELSIF V_COMPARE >= F_NLSSORT('妸 ') AND V_COMPARE <= F_NLSSORT('樲 ') THEN    
    V_RETURN := V_RETURN || 'e';    
    ELSIF V_COMPARE >= F_NLSSORT('发 ') AND V_COMPARE <= F_NLSSORT('猤 ') THEN    
    V_RETURN := V_RETURN || 'f';    
    ELSIF V_COMPARE >= F_NLSSORT('旮 ') AND V_COMPARE <= F_NLSSORT('腂 ') THEN    
    V_RETURN := V_RETURN || 'g';    
    ELSIF V_COMPARE >= F_NLSSORT('妎 ') AND V_COMPARE <= F_NLSSORT('夻 ') THEN    
    V_RETURN := V_RETURN || 'h';    
    ELSIF V_COMPARE >= F_NLSSORT('丌 ') AND V_COMPARE <= F_NLSSORT('攈 ') THEN    
    V_RETURN := V_RETURN || 'j';    
    ELSIF V_COMPARE >= F_NLSSORT('咔 ') AND V_COMPARE <= F_NLSSORT('穒 ') THEN    
    V_RETURN := V_RETURN || 'k';    
    ELSIF V_COMPARE >= F_NLSSORT('垃 ') AND V_COMPARE <= F_NLSSORT('擽 ') THEN    
    V_RETURN := V_RETURN || 'l';    
    ELSIF V_COMPARE >= F_NLSSORT('嘸 ') AND V_COMPARE <= F_NLSSORT('椧 ') THEN    
    V_RETURN := V_RETURN || 'm';    
    ELSIF V_COMPARE >= F_NLSSORT('拏 ') AND V_COMPARE <= F_NLSSORT('瘧 ') THEN    
    V_RETURN := V_RETURN || 'n';    
    ELSIF V_COMPARE >= F_NLSSORT('筽 ') AND V_COMPARE <= F_NLSSORT('漚 ') THEN    
    V_RETURN := V_RETURN || 'o';    
    ELSIF V_COMPARE >= F_NLSSORT('妑 ') AND V_COMPARE <= F_NLSSORT('曝 ') THEN    
    V_RETURN := V_RETURN || 'p';    
    ELSIF V_COMPARE >= F_NLSSORT('七 ') AND V_COMPARE <= F_NLSSORT('裠 ') THEN    
    V_RETURN := V_RETURN || 'q';    
    ELSIF V_COMPARE >= F_NLSSORT('亽 ') AND V_COMPARE <= F_NLSSORT('鶸 ') THEN    
    V_RETURN := V_RETURN || 'r';    
    ELSIF V_COMPARE >= F_NLSSORT('仨 ') AND V_COMPARE <= F_NLSSORT('蜶 ') THEN    
    V_RETURN := V_RETURN || 's';    
    ELSIF V_COMPARE >= F_NLSSORT('侤 ') AND V_COMPARE <= F_NLSSORT('籜 ') THEN    
    V_RETURN := V_RETURN || 't';    
    ELSIF V_COMPARE >= F_NLSSORT('屲 ') AND V_COMPARE <= F_NLSSORT('鶩 ') THEN    
    V_RETURN := V_RETURN || 'w';    
    ELSIF V_COMPARE >= F_NLSSORT('夕 ') AND V_COMPARE <= F_NLSSORT('鑂 ') THEN    
    V_RETURN := V_RETURN || 'x';    
    ELSIF V_COMPARE >= F_NLSSORT('丫 ') AND V_COMPARE <= F_NLSSORT('韻 ') THEN    
    V_RETURN := V_RETURN || 'y';    
    ELSIF V_COMPARE >= F_NLSSORT('帀 ') AND V_COMPARE <= F_NLSSORT('咗 ') THEN    
    V_RETURN := V_RETURN || 'z';    
    END IF;    
    END LOOP;    
    RETURN V_RETURN;    
    END;  


随后,我们可以先取出姓名,然后截取第一个汉字,最后取汉字的首字母,即可用来作为查询条件
  1. select e.fullname,e.expert_id from expert e where f_trans_pinyin_capital(substr(e.fullname,1,1)) = 'z'


最后展示一个将两个结合起来运用的例子:
  1. select e.expert_id,e.eperson_id,e.fullname,  
    sum(b2i.browse_num) browsecount,  
    count(o.object_id),wmsys.wm_concat(distinct d.name)  
    from expert e  
    left join expert2disciplinetype e2d on e2d.expert_id = e.expert_id  
    left join disciplinetype d on d.discipline_type_id = e2d.discipline_type_id  
    and d.upid = '0'  
    left join community2expert c2e on c2e.expert_id = e.expert_id  
    left join item i on i.item_type_id = 'AcademicRes' and i.withdrawn = 'N'  
    join metadatavalue m on m.item_id = i.item_id and m.metadata_field_id = '64'  
    join objectpublishinfo o on o.object_id = i.item_id  
    and o.object_type = 'item' and o.viewobjecttype = 'eperson'  
    and o.viewobjectid = e.eperson_id and o.state = '1'  
    and o.publishstate_id = '3'  
    left join browse2item b2i on b2i.item_id = o.object_id  
    where e.state = '1' and f_trans_pinyin_capital(substr(e.fullname,1,1)) = 'z'  
    group by e.expert_id,e.eperson_id,e.fullname  
    order by nlssort(e.fullname,'NLS_SORT=SCHINESE_PINYIN_M')  
分类:默认分类|回复:0|浏览:1459|全站可见|转载
 

Powered by phpwind v8.7.1 Certificate Copyright Time now is:05-19 10:09
©2003-2011 龍魂公会 版权所有 Gzip enabled 闽ICP备08004643号-3 Total 0.130228(s)