oracle advance queue 简单测试
本站文章除注明转载外,均为本站原创: 转载自love wife love life —Roger的Oracle/MySQL/PostgreSQL数据恢复博客
本文链接地址: oracle advance queue 简单测试
1 2 3 |
某客户遇到一个高级队列方面的问题,由于自己本身也不熟悉,所以进行了简单的测试, 虽然目前高级队列用的非常少,但是该特性其实已经跟streams集成到一起了,回头会写 几篇关于streams方面的文章。 |
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 |
'###### Create user and grant ######' SQL> create user aq identified by aq; User created. SQL> grant connect, resource, aq_administrator_role to aq; Grant succeeded. SQL> grant execute on dbms_aqadm to aq; Grant succeeded. SQL> grant execute on dbms_aq to aq; Grant succeeded. SQL> alter user aq default tablespace roger; User altered. SQL> connect aq/aq Connected. SQL> create sequence aq_sequence start with 1 increment by 1; Sequence created. '###### Create type and queue table ######' SQL> create type message as object ( 2 city VARCHAR2(30) 3 ); Type created. SQL> BEGIN 2 DBMS_AQADM.create_queue_table (queue_table => 'input_queue_table', 3 sort_list => 'priority', 4 multiple_consumers => TRUE, 5 queue_payload_type => 'message', 6 COMMENT => 'Creating input queue table' 7 ); 8 END; 9 / PL/SQL procedure successfully completed. '###### Create queue ######' SQL> BEGIN 2 DBMS_AQADM.create_queue (queue_name => 'input_queue', 3 queue_table => 'input_queue_table', 4 COMMENT => 'Demo Queue' 5 ); 6 END; 7 / PL/SQL procedure successfully completed. '###### Start queue ######' SQL> BEGIN 2 DBMS_AQADM.start_queue (queue_name => 'input_queue'); 3 END; 4 / PL/SQL procedure successfully completed. SQL> DECLARE 2 subscriber SYS.aq$_agent; 3 BEGIN 4 subscriber := SYS.aq$_agent ('prog1', NULL, NULL); 5 DBMS_AQADM.add_subscriber (queue_name => 'input_queue', 6 subscriber => subscriber 7 ); 8 END; 9 / PL/SQL procedure successfully completed. '###### Create enqueue procedure ######' SQL> CREATE OR REPLACE PROCEDURE demo_enqueue (userinfo MESSAGE) 2 AS 3 enq_msgid RAW (16); 4 eopt DBMS_AQ.enqueue_options_t; 5 mprop DBMS_AQ.message_properties_t; 6 priority NUMBER; 7 BEGIN 8 SELECT aq_sequence.NEXTVAL 9 INTO priority 10 FROM DUAL; 11 12 mprop.priority := priority; 13 DBMS_AQ.enqueue (queue_name => 'input_queue', 14 enqueue_options => eopt, 15 message_properties => mprop, 16 payload => userinfo, 17 msgid => enq_msgid 18 ); 19 COMMIT; 20 END demo_enqueue; 21 / Procedure created. SQL> DECLARE 2 payload1 MESSAGE; 3 payload2 MESSAGE; 4 payload3 MESSAGE; 5 payload4 MESSAGE; 6 BEGIN 7 payload1 := MESSAGE ('BELMONT'); 8 payload2 := MESSAGE ('REDWOOD SHORES'); 9 payload3 := MESSAGE ('SUNNYVALE'); 10 payload4 := MESSAGE ('BURLINGAME'); 11 demo_enqueue (payload1); 12 demo_enqueue (payload2); 13 demo_enqueue (payload3); 14 demo_enqueue (payload4); 15 END; 16 / PL/SQL procedure successfully completed. '###### Create Dequeue procedure ######' SQL> CREATE OR REPLACE PROCEDURE demo_dequeue (appname VARCHAR2) 2 AS 3 deq_msgid RAW (16); 4 dopt DBMS_AQ.dequeue_options_t; 5 mprop DBMS_AQ.message_properties_t; 6 payload MESSAGE; 7 BEGIN 8 dopt.consumer_name := appname; 9 dopt.WAIT := DBMS_AQ.no_wait; 10 dopt.navigation := DBMS_AQ.first_message; 11 DBMS_AQ.dequeue (queue_name => 'input_queue', 12 dequeue_options => dopt, 13 message_properties => mprop, 14 payload => payload, 15 msgid => deq_msgid 16 ); 17 COMMIT; 18 END demo_dequeue; 19 / Procedure created. SQL> BEGIN 2 demo_dequeue('prog1'); 3 END; 4 / PL/SQL procedure successfully completed. SQL> set lines 200 SQL> SELECT queue, TO_CHAR (enq_time, 'dd-mon-yyyy hh:mi:ss') enq_time, 2 msg_priority, msg_state 3 FROM aq$input_queue_table; QUEUE ENQ_TIME MSG_PRIORITY MSG_STATE ------------------------------ ----------------------- ------------ ---------------- INPUT_QUEUE 03-jan-2012 01:38:38 1 PROCESSED INPUT_QUEUE 03-jan-2012 01:38:38 2 READY INPUT_QUEUE 03-jan-2012 01:38:38 3 READY INPUT_QUEUE 03-jan-2012 01:38:38 4 READY SQL> SELECT q_name, TO_CHAR (enq_time, 'dd-mon-yyyy hh:mi:ss') enq_time, step_no, 2 priority 3 FROM input_queue_table; Q_NAME ENQ_TIME STEP_NO PRIORITY ------------------------------ ----------------------- ---------- ---------- INPUT_QUEUE 03-jan-2012 09:38:38 0 2 INPUT_QUEUE 03-jan-2012 09:38:38 0 3 INPUT_QUEUE 03-jan-2012 09:38:38 0 4 SQL> SELECT queue, TO_CHAR (enq_time, 'dd-mon-yyyy hh:mi:ss') enq_time, 2 msg_priority, msg_state 3 FROM aq$input_queue_table; QUEUE ENQ_TIME MSG_PRIORITY MSG_STATE ------------------------------ ----------------------- ------------ ---------------- INPUT_QUEUE 03-jan-2012 01:38:38 2 READY INPUT_QUEUE 03-jan-2012 01:38:38 3 READY INPUT_QUEUE 03-jan-2012 01:38:38 4 READY SQL> SELECT q_name, TO_CHAR (enq_time, 'dd-mon-yyyy hh:mi:ss') enq_time, 2 step_no, priority 3 FROM input_queue_table; Q_NAME ENQ_TIME STEP_NO PRIORITY ------------------------------ ----------------------- ---------- ---------- INPUT_QUEUE 03-jan-2012 09:38:38 0 2 INPUT_QUEUE 03-jan-2012 09:38:38 0 3 INPUT_QUEUE 03-jan-2012 09:38:38 0 4 SQL> DECLARE 2 payload1 MESSAGE; 3 payload2 MESSAGE; 4 payload3 MESSAGE; 5 payload4 MESSAGE; 6 BEGIN 7 payload1 := MESSAGE ('BELMONT'); 8 payload2 := MESSAGE ('REDWOOD SHORES'); 9 payload3 := MESSAGE ('SUNNYVALE'); 10 payload4 := MESSAGE ('BURLINGAME'); 11 demo_enqueue (payload1); 12 demo_enqueue (payload2); 13 demo_enqueue (payload3); 14 demo_enqueue (payload4); 15 END; 16 / PL/SQL procedure successfully completed. SQL> SELECT queue, TO_CHAR (enq_time, 'dd-mon-yyyy hh:mi:ss') enq_time, 2 msg_priority, msg_state 3 FROM aq$input_queue_table; QUEUE ENQ_TIME MSG_PRIORITY MSG_STATE ------------------------------ ----------------------- ------------ ---------------- INPUT_QUEUE 03-jan-2012 01:38:38 2 READY INPUT_QUEUE 03-jan-2012 01:38:38 3 READY INPUT_QUEUE 03-jan-2012 01:38:38 4 READY INPUT_QUEUE 03-jan-2012 01:49:28 5 READY INPUT_QUEUE 03-jan-2012 01:49:28 6 READY INPUT_QUEUE 03-jan-2012 01:49:28 7 READY INPUT_QUEUE 03-jan-2012 01:49:28 8 READY 7 rows selected. SQL> SELECT q_name, TO_CHAR (enq_time, 'dd-mon-yyyy hh:mi:ss') enq_time, step_no, 2 priority 3 FROM input_queue_table; Q_NAME ENQ_TIME STEP_NO PRIORITY ------------------------------ ----------------------- ---------- ---------- INPUT_QUEUE 03-jan-2012 09:49:28 0 7 INPUT_QUEUE 03-jan-2012 09:38:38 0 2 INPUT_QUEUE 03-jan-2012 09:38:38 0 3 INPUT_QUEUE 03-jan-2012 09:38:38 0 4 INPUT_QUEUE 03-jan-2012 09:49:28 0 5 INPUT_QUEUE 03-jan-2012 09:49:28 0 6 INPUT_QUEUE 03-jan-2012 09:49:28 0 8 7 rows selected. SQL> CREATE OR REPLACE PROCEDURE demo_dequeue (appname VARCHAR2) 2 AS 3 deq_msgid RAW (16); 4 dopt DBMS_AQ.dequeue_options_t; 5 mprop DBMS_AQ.message_properties_t; 6 payload MESSAGE; 7 BEGIN 8 dopt.consumer_name := appname; 9 dopt.WAIT := DBMS_AQ.no_wait; 10 dopt.navigation := DBMS_AQ.first_message; 11 DBMS_AQ.dequeue (queue_name => 'input_queue', 12 dequeue_options => dopt, 13 message_properties => mprop, 14 payload => payload, 15 msgid => deq_msgid 16 ); 17 COMMIT; 18 END demo_dequeue; 19 / Procedure created. SQL> SELECT queue, TO_CHAR (enq_time, 'dd-mon-yyyy hh:mi:ss') enq_time, 2 msg_priority, msg_state 3 FROM aq$input_queue_table; QUEUE ENQ_TIME MSG_PRIORITY MSG_STATE ------------------------------ ----------------------- ------------ ---------------- INPUT_QUEUE 03-jan-2012 01:38:38 3 READY INPUT_QUEUE 03-jan-2012 01:38:38 4 READY INPUT_QUEUE 03-jan-2012 01:49:28 5 READY INPUT_QUEUE 03-jan-2012 01:49:28 6 READY INPUT_QUEUE 03-jan-2012 01:49:28 7 READY INPUT_QUEUE 03-jan-2012 01:49:28 8 READY 6 rows selected. SQL> SELECT q_name, TO_CHAR (enq_time, 'dd-mon-yyyy hh:mi:ss') enq_time, step_no, 2 priority 3 FROM input_queue_table; Q_NAME ENQ_TIME STEP_NO PRIORITY ------------------------------ ----------------------- ---------- ---------- INPUT_QUEUE 03-jan-2012 09:49:28 0 7 INPUT_QUEUE 03-jan-2012 09:38:38 0 3 INPUT_QUEUE 03-jan-2012 09:38:38 0 4 INPUT_QUEUE 03-jan-2012 09:49:28 0 5 INPUT_QUEUE 03-jan-2012 09:49:28 0 6 INPUT_QUEUE 03-jan-2012 09:49:28 0 8 6 rows selected. SQL> SELECT queue, TO_CHAR (enq_time, 'dd-mon-yyyy hh:mi:ss') enq_time, 2 msg_priority, msg_state 3 FROM aq$input_queue_table; QUEUE ENQ_TIME MSG_PRIORITY MSG_STATE ------------------------------ ----------------------- ------------ ---------------- INPUT_QUEUE 03-jan-2012 01:38:38 4 READY INPUT_QUEUE 03-jan-2012 01:49:28 5 READY INPUT_QUEUE 03-jan-2012 01:49:28 6 READY INPUT_QUEUE 03-jan-2012 01:49:28 7 READY INPUT_QUEUE 03-jan-2012 01:49:28 8 READY SQL> SELECT q_name, TO_CHAR (enq_time, 'dd-mon-yyyy hh:mi:ss') enq_time, step_no, 2 priority 3 FROM input_queue_table; Q_NAME ENQ_TIME STEP_NO PRIORITY ------------------------------ ----------------------- ---------- ---------- INPUT_QUEUE 03-jan-2012 09:49:28 0 7 INPUT_QUEUE 03-jan-2012 09:38:38 0 4 INPUT_QUEUE 03-jan-2012 09:49:28 0 5 INPUT_QUEUE 03-jan-2012 09:49:28 0 6 INPUT_QUEUE 03-jan-2012 09:49:28 0 8 SQL> DECLARE 2 payload1 MESSAGE; 3 payload2 MESSAGE; 4 payload3 MESSAGE; 5 payload4 MESSAGE; 6 BEGIN 7 payload1 := MESSAGE ('BELMONT'); 8 payload2 := MESSAGE ('REDWOOD SHORES'); 9 payload3 := MESSAGE ('SUNNYVALE'); 10 payload4 := MESSAGE ('BURLINGAME'); 11 demo_enqueue (payload1); 12 demo_enqueue (payload2); 13 demo_enqueue (payload3); 14 demo_enqueue (payload4); 15 END; 16 / PL/SQL procedure successfully completed. SQL> SELECT queue, TO_CHAR (enq_time, 'dd-mon-yyyy hh:mi:ss') enq_time, 2 msg_priority, msg_state 3 FROM aq$input_queue_table; QUEUE ENQ_TIME MSG_PRIORITY MSG_STATE ------------------------------ ----------------------- ------------ ---------------- INPUT_QUEUE 03-jan-2012 01:38:38 4 READY INPUT_QUEUE 03-jan-2012 01:49:28 5 READY INPUT_QUEUE 03-jan-2012 01:49:28 6 READY INPUT_QUEUE 03-jan-2012 01:49:28 7 READY INPUT_QUEUE 03-jan-2012 01:49:28 8 READY INPUT_QUEUE 03-jan-2012 01:57:38 9 READY INPUT_QUEUE 03-jan-2012 01:57:38 10 READY INPUT_QUEUE 03-jan-2012 01:57:38 11 READY INPUT_QUEUE 03-jan-2012 01:57:38 12 READY 9 rows selected. SQL> BEGIN 2 demo_dequeue('prog1'); 3 END; 4 / PL/SQL procedure successfully completed. SQL> SELECT queue, TO_CHAR (enq_time, 'dd-mon-yyyy hh:mi:ss') enq_time, 2 msg_priority, msg_state 3 FROM aq$input_queue_table; QUEUE ENQ_TIME MSG_PRIORITY MSG_STATE ------------------------------ ----------------------- ------------ ---------------- INPUT_QUEUE 03-jan-2012 01:38:38 4 PROCESSED INPUT_QUEUE 03-jan-2012 01:49:28 5 PROCESSED INPUT_QUEUE 03-jan-2012 01:49:28 6 READY INPUT_QUEUE 03-jan-2012 01:49:28 7 READY INPUT_QUEUE 03-jan-2012 01:49:28 8 READY INPUT_QUEUE 03-jan-2012 01:57:38 9 READY INPUT_QUEUE 03-jan-2012 01:57:38 10 READY INPUT_QUEUE 03-jan-2012 01:57:38 11 READY INPUT_QUEUE 03-jan-2012 01:57:38 12 READY 9 rows selected. SQL> SELECT q_name, TO_CHAR (enq_time, 'dd-mon-yyyy hh:mi:ss') enq_time, step_no, 2 priority 3 FROM input_queue_table; Q_NAME ENQ_TIME STEP_NO PRIORITY ------------------------------ ----------------------- ---------- ---------- INPUT_QUEUE 03-jan-2012 09:49:28 0 7 INPUT_QUEUE 03-jan-2012 09:57:38 0 9 INPUT_QUEUE 03-jan-2012 09:57:38 0 11 INPUT_QUEUE 03-jan-2012 09:38:38 0 4 INPUT_QUEUE 03-jan-2012 09:49:28 0 5 INPUT_QUEUE 03-jan-2012 09:49:28 0 6 INPUT_QUEUE 03-jan-2012 09:49:28 0 8 INPUT_QUEUE 03-jan-2012 09:57:38 0 10 INPUT_QUEUE 03-jan-2012 09:57:38 0 12 9 rows selected. SQL> SELECT queue, TO_CHAR (enq_time, 'dd-mon-yyyy hh:mi:ss') enq_time, 2 msg_priority, msg_state 3 FROM aq$input_queue_table; QUEUE ENQ_TIME MSG_PRIORITY MSG_STATE ------------------------------ ----------------------- ------------ ---------------- INPUT_QUEUE 03-jan-2012 01:49:28 6 READY INPUT_QUEUE 03-jan-2012 01:49:28 7 READY INPUT_QUEUE 03-jan-2012 01:49:28 8 READY INPUT_QUEUE 03-jan-2012 01:57:38 9 READY INPUT_QUEUE 03-jan-2012 01:57:38 10 READY INPUT_QUEUE 03-jan-2012 01:57:38 11 READY INPUT_QUEUE 03-jan-2012 01:57:38 12 READY 7 rows selected. SQL> BEGIN 2 demo_dequeue('prog1'); 3 END; 4 / PL/SQL procedure successfully completed. SQL> SELECT queue, TO_CHAR (enq_time, 'dd-mon-yyyy hh:mi:ss') enq_time, 2 msg_priority, msg_state 3 FROM aq$input_queue_table; QUEUE ENQ_TIME MSG_PRIORITY MSG_STATE ------------------------------ ----------------------- ------------ ---------------- INPUT_QUEUE 03-jan-2012 01:49:28 6 PROCESSED INPUT_QUEUE 03-jan-2012 01:49:28 7 READY INPUT_QUEUE 03-jan-2012 01:49:28 8 READY INPUT_QUEUE 03-jan-2012 01:57:38 9 READY INPUT_QUEUE 03-jan-2012 01:57:38 10 READY INPUT_QUEUE 03-jan-2012 01:57:38 11 READY INPUT_QUEUE 03-jan-2012 01:57:38 12 READY 7 rows selected. SQL> / QUEUE ENQ_TIME MSG_PRIORITY MSG_STATE ------------------------------ ----------------------- ------------ ---------------- INPUT_QUEUE 03-jan-2012 01:49:28 6 PROCESSED INPUT_QUEUE 03-jan-2012 01:49:28 7 READY INPUT_QUEUE 03-jan-2012 01:49:28 8 READY INPUT_QUEUE 03-jan-2012 01:57:38 9 READY INPUT_QUEUE 03-jan-2012 01:57:38 10 READY INPUT_QUEUE 03-jan-2012 01:57:38 11 READY INPUT_QUEUE 03-jan-2012 01:57:38 12 READY 7 rows selected. SQL> / QUEUE ENQ_TIME MSG_PRIORITY MSG_STATE ------------------------------ ----------------------- ------------ ---------------- INPUT_QUEUE 03-jan-2012 01:49:28 6 PROCESSED INPUT_QUEUE 03-jan-2012 01:49:28 7 READY INPUT_QUEUE 03-jan-2012 01:49:28 8 READY INPUT_QUEUE 03-jan-2012 01:57:38 9 READY INPUT_QUEUE 03-jan-2012 01:57:38 10 READY INPUT_QUEUE 03-jan-2012 01:57:38 11 READY INPUT_QUEUE 03-jan-2012 01:57:38 12 READY 7 rows selected. SQL> / QUEUE ENQ_TIME MSG_PRIORITY MSG_STATE ------------------------------ ----------------------- ------------ ---------------- INPUT_QUEUE 03-jan-2012 01:49:28 7 READY INPUT_QUEUE 03-jan-2012 01:49:28 8 READY INPUT_QUEUE 03-jan-2012 01:57:38 9 READY INPUT_QUEUE 03-jan-2012 01:57:38 10 READY INPUT_QUEUE 03-jan-2012 01:57:38 11 READY INPUT_QUEUE 03-jan-2012 01:57:38 12 READY 6 rows selected. |
1 2 3 4 |
补充:可以用event 10960 去trace AQ,对于group级别的请参考如下mos文档。 <span style="color: #0000ff;"> Procedure to Dequeue Messages from any Queue not using Message Grouping [ID 243665.1] </span> |
4 Responses to “oracle advance queue 简单测试”
永远支持博主。
roger,申请加入友情链接,我已经加你了
惜分飞 http://www.xifenfei.com
to 惜分飞: 已经add了。
Leave a Reply
You must be logged in to post a comment.