Chinaunix首页 | 论坛 | 博客
  • 博客访问: 418620
  • 博文数量: 66
  • 博客积分: 1416
  • 博客等级: 上尉
  • 技术积分: 922
  • 用 户 组: 普通用户
  • 注册时间: 2006-09-16 10:37
个人简介

高級Oracle DBA,善長Linux系統維運以及Oracle數據庫管理,開發,調優. 具有多年PL/SQL開發經驗.

文章分类

全部博文(66)

文章存档

2015年(9)

2014年(4)

2013年(5)

2010年(1)

2009年(3)

2008年(6)

2007年(30)

2006年(8)

我的朋友

分类: Oracle

2014-03-29 16:13:09

之前有用java封裝一個讀取excel 2000的 oracle package
這個是用來讀取 openoffice ods格式的 package
原理是:
1. 用as_zip解壓得到xml
2. 用oracle xmltype讀取每一行數據, pipelined方式返回.

測試代碼如下

点击(此处)折叠或打开

  1. select b.*
  2. from table( ods_utl_pkg.get_ods_table(
  3.      utl_lob.url2blob('ftp://172.17.2.43/pub/test/work.ods'))) b
效果圖如下
效果圖

oracle package: ods_utl_pkg封裝如下

点击(此处)折叠或打开

  1. create or replace package ods_utl_pkg
  2. as
  3. /* ********************************************************************
  4.    Ver Date Author Description
  5.    --------- ---------- --------------- ------------------------------------
  6.    1.0 2014-3-29 gangjh 1. 用sql select 讀取open office ods數據
  7.    
  8. ********************************************************************/
  9. subtype celltype is varchar2(4000 byte) ; -- limit for oracle 10g
  10.   type xls_row is record (
  11.     sheet int ,
  12.     row_idx int ,
  13.     col_a celltype,
  14.     col_b celltype,
  15.     col_c celltype,
  16.     col_d celltype,
  17.     col_e celltype,
  18.     col_f celltype,
  19.     col_g celltype,
  20.     col_h celltype,
  21.     col_i celltype,
  22.     col_j celltype,
  23.     col_k celltype,
  24.     col_l celltype,
  25.     col_m celltype,
  26.     col_n celltype,
  27.     col_o celltype,
  28.     col_p celltype,
  29.     col_q celltype,
  30.     col_r celltype,
  31.     col_s celltype,
  32.     col_t celltype
  33.   );
  34.   
  35. type xls_table is table of xls_row ;


  36. /**********************************
  37.  @get_xmldoc --抓取ods 壓縮檔中的xml內容
  38. *******************************/
  39. function get_xmldoc (p_zipped_blob in blob, p_file_name in varchar2) return clob ;

  40. /***********************************************
  41. @get_ods_table -- Table函數, 讀取open office ods中的內容, 以xmldom的方式實現
  42.  ex:
  43.   select * from table(
  44.          ods_utl_pkg.get_ods_table(utl_lob.get_blob('MAILTEMP','pcn2.ods')))
  45. *********************************************************/
  46. function get_ods_table(p_data in blob) return xls_table pipelined;

  47. end ods_utl_pkg;

  48.  
  49. /
  50. create or replace package body ods_utl_pkg
  51. as

  52. subtype ods_table is xmltype;
  53. type t_hash_str is table of varchar2(2000) index by varchar2(256);

  54. type t_cell is record (
  55.   col_idx pls_integer,
  56.   value_type varchar2(256), -- @office:value-type
  57.   office_value celltype, -- @office:value | @office:date-value | node()
  58.   spanned pls_integer, -- @table:number-columns-spanned
  59.   repeated pls_integer, -- @table:number-columns-repeated
  60.   raw_data varchar2(32767)
  61. );


  62.   ns_ods constant varchar2(32767) := '
  63. xmlns:office="urn:oasis:names:tc:opendocument:xmlns:office:1.0"
  64. xmlns:text="urn:oasis:names:tc:opendocument:xmlns:text:1.0"
  65. xmlns:table="urn:oasis:names:tc:opendocument:xmlns:table:1.0"
  66. xmlns:number="urn:oasis:names:tc:opendocument:xmlns:datastyle:1.0"
  67. ';

  68.  crlf constant varchar2(1) := chr(10) ;


  69. procedure print(m varchar2) is
  70. begin
  71.   dbms_output.put_line(m);
  72. end;


  73. procedure print_xml(node XMLDOM.DOMNode) is
  74.   m clob ;
  75. begin
  76.   dbms_lob.createtemporary(m, true, dbms_lob.call);
  77.   XMLDOM.writeToClob(node, m);
  78.   dbms_output.put_line(dbms_lob.substr(m,32767, 1));
  79. end;

  80. function get_ns(p_name varchar2) return varchar2 is
  81. begin
  82.    return case p_name
  83.            when 'xmlns:all' then ns_ods
  84.            when 'xmlns:office' then 'xmlns:office="urn:oasis:names:tc:opendocument:xmlns:office:1.0" '
  85.            when 'xmlns:text' then 'xmlns:text="urn:oasis:names:tc:opendocument:xmlns:text:1.0" '
  86.            when 'xmlns:table' then 'xmlns:table="urn:oasis:names:tc:opendocument:xmlns:table:1.0" '
  87.            when 'xmlns:number' then 'xmlns:number="urn:oasis:names:tc:opendocument:xmlns:datastyle:1.0" '
  88.            else ns_ods
  89.       end;
  90.    
  91. end;

  92. -- for openoffice ods
  93. /*
  94.  get_xml 取得ods中的xml文件
  95.  大文件xml可能會使xmltype報ora 24030錯誤
  96. ex:
  97.  select ods_utl_pkg.get_xml(utl_lob.url2blob('ftp://172.17.2.43/pub/test/work.ods'),'content.xml') aa
  98. from dual;
  99. */

  100. function get_xmldoc(p_zipped_blob in blob, p_file_name varchar2) return clob is
  101.   l_clob clob;
  102.   l_blob blob ;
  103.   dest_offset integer := 1;
  104.   src_offset integer := 1;
  105.   lang_context integer := 0;
  106.   warning integer :=0;
  107. begin
  108.   
  109.   l_blob := as_zip.get_file (p_zipped_blob, p_file_name);
  110.   dbms_lob.createtemporary(l_clob, true, dbms_lob.call) ;
  111.   dbms_lob.convertToclob( l_clob
  112.                           , l_blob
  113.                           , dbms_lob.lobmaxsize
  114.                           , dest_offset
  115.                           , src_offset
  116.                           , nls_charset_id( 'AL32UTF8' )
  117.                           , lang_context
  118.                           , warning
  119.                           );
  120.   
  121.   return (l_clob);
  122. end get_xmldoc;


  123. function all_attribute(p_node in XMLDOM.DOMNode) return t_hash_str is
  124.   v_ret t_hash_str ;
  125.   l_attr XMLDOM.domnamednodemap;
  126.   l_node XMLDOM.domnode;
  127. BEGIN
  128.   l_attr := XMLDOM.getAttributes(p_node);
  129.   
  130.   for i in 0.. XMLDOM.getLength(l_attr) -1 loop
  131.      l_node := XMLDOM.item(l_attr, i);
  132.      v_ret(XMLDOM.getNodeName(l_node)) := XMLDOM.getNodeValue(l_node);
  133. -- print( XMLDOM.getNodeName(l_node)||':'||XMLDOM.getNodeValue(l_node));
  134.   end loop;
  135.   return v_ret;
  136. end ;



  137. function get_xmlnode_value(l_node XMLDOM.DOMNode) return varchar2 is
  138.   vret celltype ;
  139.   
  140. /****************************************
  141. get_xmldom_text --遞歸調用,取xmlnode的文字內容
  142. VALUE_ERROR Exception when long varchar2
  143. **************************************/
  144.   procedure get_xmldom_text(p_node XMLDOM.DOMNode, p_dest in out varchar2) is
  145.     p1 XMLDOM.DOMNode;
  146.   begin
  147.     if XMLDOM.getNodeType(p_node) = XMLDOM.ELEMENT_NODE then
  148.       p1 := XMLDOM.getFirstChild(p_node) ;
  149.       while not XMLDOM.isNull(p1) loop
  150.          get_xmldom_text(p1, p_dest) ;
  151.          p1 := XMLDOM.getNextSibling(p1) ;
  152.       end loop;
  153.     elsif XMLDOM.getNodeType(p_node) = XMLDOM.TEXT_NODE then

  154.       p_dest := p_dest || XMLDOM.getNodeValue(p_node) ;
  155.       if XMLDOM.getNodeName(p_node) = '#text' then
  156.         p_dest := p_dest || crlf ;
  157.       end if;
  158.     end if;
  159.       
  160.     exception
  161.       when VALUE_ERROR then --可能超過4000 byte
  162.         null;
  163.   end get_xmldom_text;
  164. begin
  165.   get_xmldom_text(l_node, vret);
  166.   return vret;
  167. end;

  168. /**********************************
  169. @get_ods_table -- 以xmldom的方式實現
  170. **********************************/

  171. function get_ods_table(p_data in blob) return xls_table PIPELINED is
  172.   xpath_table constant varchar2(2000) := '/office:document-content/office:body/office:spreadsheet/table:table';
  173.   
  174.   v_row xls_row ;
  175.   doc XMLDOM.domdocument;
  176.   l_tables XMLDOM.DOMNodeList;
  177.   l_table XMLDOM.DOMNode;
  178.   l_rows XMLDOM.DOMNodeList;
  179.   l_row XMLDOM.DOMNode;
  180.   
  181.   
  182. function xsl_valueOf(n xmldom.DOMNode, pattern varchar2,
  183.                      namespace IN VARCHAR2 default ns_ods) return VARCHAR2 IS
  184. begin
  185.   return xslprocessor.valueOf(n, pattern, namespace);
  186. end;

  187. /********************************
  188. @fill_cell -- 根據col_idx 將數據填入xls_row對應的欄位中
  189. *************************/
  190.  procedure fill_cell(p_row in out xls_row, l_val t_cell) is
  191.  begin
  192.    case l_val.col_idx
  193.       when 1 then p_row.col_a := l_val.office_value ;
  194.       when 2 then p_row.col_b := l_val.office_value ;
  195.       when 3 then p_row.col_c := l_val.office_value ;
  196.       when 4 then p_row.col_d := l_val.office_value ;
  197.       when 5 then p_row.col_e := l_val.office_value ;
  198.       when 6 then p_row.col_f := l_val.office_value ;
  199.       when 7 then p_row.col_g := l_val.office_value ;
  200.       when 8 then p_row.col_h := l_val.office_value ;
  201.       when 9 then p_row.col_i := l_val.office_value ;
  202.       when 10 then p_row.col_j := l_val.office_value ;
  203.       when 11 then p_row.col_k := l_val.office_value ;
  204.       when 12 then p_row.col_l := l_val.office_value ;
  205.       when 13 then p_row.col_m := l_val.office_value ;
  206.       when 14 then p_row.col_n := l_val.office_value ;
  207.       when 15 then p_row.col_o := l_val.office_value ;
  208.       when 16 then p_row.col_p := l_val.office_value ;
  209.       when 17 then p_row.col_q := l_val.office_value ;
  210.       when 18 then p_row.col_r := l_val.office_value ;
  211.       when 19 then p_row.col_s := l_val.office_value ;
  212.       when 20 then p_row.col_t := l_val.office_value ;
  213.       else
  214.         null;
  215.     end case;
  216.  end;


  217. /**********************************************************
  218. @get_ods_row_value -- 根據xpath_table取得xml中的某一行數據
  219. *********************************************************/

  220.   function get_ods_row_value(p_xmlrow XMLDOM.DOMNode) return xls_row is
  221.     c_cell_path constant varchar2(200) :='table:covered-table-cell | table:table-cell';
  222.     v_row xls_row ;

  223.     v_cell t_cell;
  224.     l_cells XMLDOM.DOMNodeList;
  225.     l_cell XMLDOM.DOMNode;
  226.     
  227.   begin
  228.       l_cells := xslprocessor.selectNodes(p_xmlrow, c_cell_path, ns_ods);
  229.       v_cell.col_idx := 1;
  230.       
  231.       for r in 0 .. XMLDOM.getlength( l_cells ) - 1 loop
  232.           l_cell := XMLDOM.item(l_cells, r);
  233.          
  234.           v_cell.value_type := xsl_valueOf(l_cell, '@office:value-type');
  235.           v_cell.repeated := xsl_valueOf(l_cell, '@table:number-columns-repeated');
  236.           v_cell.spanned := xsl_valueOf(l_cell, '@table:number-columns-spanned');
  237.          
  238.           v_cell.office_value :=
  239.           case v_cell.value_type
  240.              when 'string' then get_xmlnode_value(l_cell)
  241.              when 'float' then xsl_valueOf(l_cell, '@office:value')
  242.              when 'date' then xsl_valueOf(l_cell, '@office:date-value')
  243.           end;
  244.             
  245.           fill_cell(v_row, v_cell ) ;
  246.           v_cell.col_idx := v_cell.col_idx + nvl(v_cell.repeated , 1) ;
  247.       end loop;
  248.       return v_row;
  249.   end get_ods_row_value;

  250. begin
  251.     if dbms_lob.substr( p_data, 4, 1 ) <> hextoraw( '504B0304' ) then -- 504B0304: zip file
  252.        raise_application_error(-20013, 'blob is not zip file');
  253.     end if;
  254.   
  255.     doc := XMLDOM.newDOMDocument(get_xmldoc(p_data, 'content.xml'));
  256.     l_tables := xslprocessor.selectNodes( XMLDOM.makeNode( XMLDOM.getDocumentElement(doc) ) , xpath_table, ns_ods);
  257.     
  258.     for r1 in 0 .. XMLDOM.getlength( l_tables ) - 1 loop
  259.         l_table := XMLDOM.item(l_tables, r1);

  260.         l_rows := xslprocessor.selectNodes(l_table, 'table:table-row', ns_ods);
  261.          
  262.         for r2 in 0 .. XMLDOM.getlength( l_rows ) - 1 loop
  263.             l_row := XMLDOM.item(l_rows, r2);

  264.             v_row := get_ods_row_value( l_row ) ;
  265.             v_row.sheet := r1 + 1;
  266.             v_row.row_idx := r2 + 1;
  267.             pipe row( v_row) ;
  268.         end loop;
  269.        
  270.     end loop;

  271.     XMLDOM.freeDocument(doc);
  272.     return ;
  273.       
  274. end get_ods_table;


  275. end ods_utl_pkg;
  276. /



ods_utl_pkg需要as_zip 包來解壓blob數據.

as_zip可由網上取得http://technology.amis.nl/wp-content/uploads/images/as_zip.txt

讀取基本的數據是沒有問題的.
如使用中遇到bug, 可站內告知我,十分感謝.

2015/09/04 更新

                         阿飛
               2014/03/29
阅读(2930) | 评论(0) | 转发(1) |
给主人留下些什么吧!~~