全部博文(136)
分类: Oracle
2008-06-05 17:10:23
DECLARE
directions CLOB; amount BINARY_INTEGER; offset INTEGER; first_direction VARCHAR2(100); more_directions VARCHAR2(500); BEGIN --Delete any existing rows for 'Munising Falls' so that this --example can be executed multiple times DELETE FROM waterfalls WHERE falls_name='Munising Falls'; --Insert a new row
using EMPTY_CLOB( ) to create a LOB locator
INSERT INTO waterfalls (falls_name,falls_directions) VALUES ('Munising Falls',EMPTY_CLOB( )); --Retrieve the LOB locator created by
the previous INSERT statement
SELECT falls_directions INTO directions FROM waterfalls WHERE falls_name='Munising Falls'; --Open the LOB; not
strictly necessary, but best to open/close LOBs.
DBMS_LOB.OPEN(directions, DBMS_LOB.LOB_READWRITE); --Use DBMS_LOB.WRITE to
begin
first_direction := 'Follow I-75 across the Mackinac Bridge.'; amount := LENGTH(first_direction); --number of characters to write offset := 1; --begin writing to the first character of the CLOB DBMS_LOB.WRITE(directions, amount, offset, first_direction); --Add some more directions using
DBMS_LOB.WRITEAPPEND
more_directions := ' Take US-2 west from St. Ignace to Blaney Park.' || ' Turn north on M-77 and drive to Seney.' || ' From Seney, take M-28 west to Munising.'; DBMS_LOB.WRITEAPPEND(directions, LENGTH(more_directions), more_directions); --Add yet more directions
more_directions := ' In front of the paper mill, turn right on H-58.' || ' Follow H-58 to Washington Street. Veer left onto' || ' Washington Street. You''ll find the Munising' || ' Falls visitor center across from the hospital at' || ' the point where Washington Street becomes' || ' Sand Point Road.'; DBMS_LOB.WRITEAPPEND(directions, LENGTH(more_directions), more_directions); --Close the LOB, and we are
done. DBMS_LOB.CLOSE(directions); END; |
SQL> set long 10000
SQL> select FALLS_DIRECTIONS from waterfalls;
FALLS_DIRECTIONS
-------------------------------------------------------------------------------- Follow I-75 across the Mackinac Bridge. Take US-2 west from St. Ignace to Blaney Park. Turn north on M-77 and drive to Seney. From Seney, take M-28 west to Muni sing. In front of the paper mill, turn right on H-58. Follow H-58 to Washington Street. Veer left onto Washington Street. You'll find the Munising Falls visitor center across from the hospital at the point where Washington Street becomes Sa nd Point Road. SQL> commit; 提交完成。 |
DECLARE
directions CLOB; directions_1 VARCHAR2(300); directions_2 VARCHAR2(300); chars_read_1 BINARY_INTEGER; chars_read_2 BINARY_INTEGER; offset INTEGER; BEGIN --Retrieve the LOB locator inserted previously SELECT falls_directions INTO directions FROM waterfalls WHERE falls_name='Munising Falls'; --Begin reading with the first
character
offset := 1; --Attempt to read 229 characters of
directions, chars_read_1 will
--be updated with the actual number of characters read chars_read_1 := 229; DBMS_LOB.READ(directions, chars_read_1, offset, directions_1); --If we read 229 characters, update the
offset and try to
--read 255 more. IF chars_read_1 = 229 THEN offset := offset + chars_read_1; chars_read_2 := 255; DBMS_LOB.READ(directions, chars_read_2, offset, directions_2); ELSE chars_read_2 := 0; directions_2 := ''; END IF; --Display the total number of
characters read
DBMS_OUTPUT.PUT_LINE('Characters read = ' || TO_CHAR(chars_read_1+chars_read_2)); --Display the directions DBMS_OUTPUT.PUT_LINE(directions_1); DBMS_OUTPUT.PUT_LINE(directions_2); END; |
Characters read = 414 Follow I-75 across the Mackinac Bridge. Take US-2 west from St. Ignace to Blaney Park. Turn north on M-77 and drive to Seney. From Seney, take M-28 west to Munising. In front of the paper mill, turn right on H-58. Follow H-58 to Washington Street. Veer left onto Washington Street. You'll find the Munising Falls visitor center across from the hospital at the point where Washington Street becomes Sand Point Road. |
DBMS_LOB.READ(waterfall, 60, 1, piece); * ERROR 位于第 15 行: ORA-06550: 第 15 行, 第 29 列: PLS-00363: 表达式 '60' 不能用作赋值目标 ORA-06550: 第 15 行, 第 4 列: PL/SQL: Statement ignored |
你也可以使用系统函数 DBMS_LOB.GET_LENGTH( lob_locator ) 来获取 LOB
数据的长度。 |