You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
This section explains advanced features of Transactional Event Queues, including transactional messaging, message propagation between queues and the database, and error handling.
8
8
9
-
10
9
*[Transactional Messaging: Combine Messaging with Database Queries](#transactional-messaging-combine-messaging-with-database-queries)
11
10
*[SQL Example](#sql-example)
12
-
*[Kafka Example](#kafka-example)
13
-
*[Transactional Produce](#transactional-produce)
14
-
*[Producer Methods](#producer-methods)
15
-
*[Transactional Produce Example](#transactional-produce-example)
> Note: The same pattern applies to the `dbms_aq.dequeue` procedure, allowing developers to perform DML operations within dequeue transactions.
76
68
77
-
### Kafka Example
78
-
79
-
The KafkaProducer and KafkaConsumer classes implemented by the [Kafka Java Client for Oracle Transactional Event Queues](https://github.com/oracle/okafka) provide functionality for transactional messaging, allowing developers to run database queries within a produce or consume transaction.
80
-
81
-
#### Transactional Produce
82
-
83
-
To configure a transactional producer, configure the org.oracle.okafka.clients.producer.KafkaProducer class with the `oracle.transactional.producer=true` property.
84
-
85
-
Once the producer instance is created, initialize database transactions with the `producer.initTransactions()` method.
86
-
87
-
```java
88
-
Properties props =newProperties();
89
-
// Use your database service name
90
-
props.put("oracle.service.name", "freepdb1");
91
-
// Choose PLAINTEXT or SSL as appropriate for your database connection
92
-
props.put("security.protocol", "SSL");
93
-
// Your database server
94
-
props.put("bootstrap.servers", "my-db-server");
95
-
// Path to directory containing ojdbc.properties
96
-
// If using Oracle Wallet, this directory must contain the unzipped wallet (such as in sqlnet.ora)
// Initialize the producer for database transactions
109
-
producer.initTransactions();
110
-
```
111
-
112
-
##### Producer Methods
113
-
114
-
- To start a database transaction, use the `producer.beginTransaction()` method.
115
-
- To commit the transaction, use the `producer.commitTransaction()` method.
116
-
- To retrieve the current database connection within the transaction, use the `producer.getDBConnection()` method.
117
-
- To abort the transaction, use the `producer.abortTransaction()` method.
118
-
119
-
##### Transactional Produce Example
120
-
121
-
The following Java method takes in input record and processes it using a transactional producer. On error, the transaction is aborted and neither the DML nor topic produce are committed to the database. Assume the `processRecord` method does some DML operation with the record, like inserting or updating a table.
122
-
123
-
```java
124
-
publicvoid produce(String record) {
125
-
// 1. Begin the current transaction
126
-
producer.beginTransaction();
127
-
128
-
try {
129
-
// 2. Create the producer record and prepare to send it to a topic
To configure a transactional consumer, configure a org.oracle.okafka.clients.consumer.KafkaConsumer class with `auto.commit=false`. Disabling auto-commit will allow great control of database transactions through the `commitSync()` and `commitAsync()` methods.
154
-
155
-
```java
156
-
Properties props =newProperties();
157
-
// Use your database service name
158
-
props.put("oracle.service.name", "freepdb1");
159
-
// Choose PLAINTEXT or SSL as appropriate for your database connection
160
-
props.put("security.protocol", "SSL");
161
-
// Your database server
162
-
props.put("bootstrap.servers", "my-db-server");
163
-
// Path to directory containing ojdbc.properties
164
-
// If using Oracle Wallet, this directory must contain the unzipped wallet (such as in sqlnet.ora)
165
-
props.put("oracle.net.tns_admin", "/my/path/");
166
-
167
-
props.put("group.id" , "MY_CONSUMER_GROUP");
168
-
// Set auto-commit to false for direct transaction management.
- To retrieve the current database connection within the transaction, use the `consumer.getDBConnection()` method.
179
-
- To commit the current transaction synchronously, use the `consumer.commitSync()` method.
180
-
- To commit the current transaction asynchronously, use the `consumer.commitAsync()` method.
181
-
182
-
##### Transactional Consume Example
183
-
184
-
The following Java method demonstrates how to use a KafkaConsumer for transactional messaging. Assume the `processRecord` method does some DML operation with the record, like inserting or updating a table.
185
-
186
-
```java
187
-
publicvoid run() {
188
-
this.consumer.subscribe(List.of("topic1"));
189
-
while (true) {
190
-
try {
191
-
// 1. Poll a batch of records from the subscribed topics
192
-
ConsumerRecords<String, String> records = consumer.poll(
// 2. Get the current transaction's database connection
197
-
Connection conn = consumer.getDBConnection();
198
-
for (ConsumerRecord<String, String> record : records) {
199
-
// 3. Do some DML with the record and connection
200
-
processRecord(record, conn);
201
-
}
202
-
203
-
// 4. Do a blocking commit on the current batch of records. For non-blocking, use commitAsync()
204
-
consumer.commitSync();
205
-
} catch (Exception e) {
206
-
// 5. Since auto-commit is disabled, transactions are not
207
-
// committed when commitSync() is not called.
208
-
System.out.println("Unexpected error processing records. Aborting transaction!");
209
-
}
210
-
}
211
-
}
212
-
```
213
-
214
69
## Message Propagation
215
70
216
71
Messages can be propagated within the same database or across a [database link](https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/CREATE-DATABASE-LINK.html) to different queues or topics. Message propagation is useful for workflows that require message processing d by different consumers or for event-driven actions that need to trigger subsequent processes.
217
72
218
73
#### Queue to Queue Message Propagation
219
74
220
-
Create and start two queues. q1 will be the source queue, and q2 will be the propagated queue.
75
+
Create and start two queues. `source` will be the source queue, and `dest` will be the propagated destination queue.
221
76
222
77
```sql
223
78
begin
224
79
dbms_aqadm.create_transactional_event_queue(
225
-
queue_name =>'q1',
80
+
queue_name =>'source',
226
81
queue_payload_type =>'JSON',
227
82
multiple_consumers => true
228
83
);
229
-
dbms_aqadm.start_queue(
230
-
queue_name =>'q1'
231
-
);
232
84
dbms_aqadm.create_transactional_event_queue(
233
-
queue_name =>'q2',
85
+
queue_name =>'dest',
234
86
queue_payload_type =>'JSON',
235
87
multiple_consumers => true
236
88
);
237
89
dbms_aqadm.start_queue(
238
-
queue_name =>'q2'
90
+
queue_name =>'source'
239
91
);
240
-
end;
241
-
/
242
-
```
243
-
244
-
Add a subscriber to q2 using the [`DBMS_AQADM.ADD_SUBSCRIBER` procedure](https://docs.oracle.com/en/database/oracle/oracle-database/23/arpls/DBMS_AQADM.html#GUID-2B4498B0-7851-4520-89DD-E07FC4C5B2C7):
245
-
246
-
```sql
247
-
begin
248
-
dbms_aqadm.add_subscriber(
249
-
queue_name =>'q2',
250
-
subscriber =>sys.aq$_agent(
251
-
'q2_test_subscriber',
252
-
null,
253
-
null
254
-
)
92
+
dbms_aqadm.start_queue(
93
+
queue_name =>'dest'
255
94
);
256
95
end;
257
96
/
258
97
```
259
98
260
-
Schedule message propagation so messages from q1 are propagated to q2, using the [`DBMS_AQADM.SCHEDULE_PROPAGATION` procedure](https://docs.oracle.com/en/database/oracle/oracle-database/23/arpls/DBMS_AQADM.html#GUID-E97FCD3F-D96B-4B01-A57F-23AC9A110A0D):
261
-
99
+
Schedule message propagation so messages from `source` are propagated to `dest`, using [`DBMS_AQADM.SCHEDULE_PROPAGATION` procedure](https://docs.oracle.com/en/database/oracle/oracle-database/23/arpls/DBMS_AQADM.html#GUID-E97FCD3F-D96B-4B01-A57F-23AC9A110A0D).
262
100
```sql
263
101
begin
264
102
dbms_aqadm.schedule_propagation(
265
-
queue_name =>'q1',
266
-
destination_queue =>'q2',
267
-
latency =>0, -- latency, in seconds, before propagating
268
-
start_time =>sysdate, -- begin propagation immediately
269
-
duration =>null-- propagate until stopped
103
+
queue_name =>'source',
104
+
destination_queue =>'dest'
270
105
);
271
106
end;
272
107
/
273
108
```
274
109
275
-
Let's enqueue a message into q1. We expect this message to be propagated to q2:
110
+
Let's enqueue a message into `source`. We expect this message to be propagated to `dest`:
276
111
277
112
```sql
278
113
declare
@@ -284,7 +119,7 @@ declare
284
119
begin
285
120
select json(body) into message;
286
121
dbms_aq.enqueue(
287
-
queue_name =>'q1',
122
+
queue_name =>'source',
288
123
enqueue_options => enqueue_options,
289
124
message_properties => message_properties,
290
125
payload => message,
@@ -295,37 +130,26 @@ end;
295
130
/
296
131
```
297
132
298
-
#### Removing Subscribers and Stopping Propagation
299
-
300
-
You can remove subscribers and stop propagation using the DBMS_AQADM.STOP_PROPAGATION procedures:
301
-
133
+
If propagation does not occur, check the `JOB_QUEUE_PROCESSES` parameter and ensure its value is high enough. If the value is very low, you may need to update it with a larger value:
302
134
```sql
303
-
begin
304
-
dbms_aqadm.unschedule_propagation(
305
-
queue_name =>'q1',
306
-
destination_queue =>'q2'
307
-
);
308
-
end;
309
-
/
135
+
alter system set job_queue_processes=10;
310
136
```
311
137
312
-
Remove the subscriber:
138
+
#### Stopping Queue Propagation
139
+
140
+
You can stop propagation using the DBMS_AQADM.STOP_PROPAGATION procedures:
313
141
314
142
```sql
315
143
begin
316
-
dbms_aqadm.remove_subscriber(
317
-
queue_name =>'q2',
318
-
subscriber =>sys.aq$_agent(
319
-
'q2_test_subscriber',
320
-
null,
321
-
null
322
-
)
144
+
dbms_aqadm.unschedule_propagation(
145
+
queue_name =>'source',
146
+
destination_queue =>'dest'
323
147
);
324
148
end;
325
149
/
326
150
```
327
151
328
-
Your can view queue subscribers and propagation schedules from the respective `DBA_QUEUE_SCHEDULES` and `DBA_QUEUE_SUBSCRIBERS` system views.
152
+
Your can view queue subscribers and propagation schedules from the respective `DBA_QUEUE_SCHEDULES` and `DBA_QUEUE_SUBSCRIBERS` system views. These views are helpful for debugging propagation issues, including error messages and schedule status.
329
153
330
154
#### Using Database Links
331
155
@@ -334,19 +158,19 @@ To propagate messages between databases, a [database link](https://docs.oracle.c
334
158
```sql
335
159
begin
336
160
dbms_aqadm.schedule_propagation(
337
-
queue_name =>'json_queue_1',
338
-
destination =>'<database link>.<schema name>'-- replace with your database link and schema name,
339
-
destination_queue =>'json_queue_2'
161
+
queue_name =>'source',
162
+
destination =>'<database link>.<schema name>',-- replace with your database link and schema name,
163
+
destination_queue =>'dest'
340
164
);
341
165
end;
342
166
/
343
167
```
344
168
345
169
## Error Handling
346
170
347
-
Error handling is a critical component of message processing, ensuring malformed or otherwise unprocessable messages are handled correctly. Depending on the message payload and exception, an appropriate action should be taken to either replayor store the message for inspection.
171
+
Error handling is a critical component of message processing, ensuring malformed or otherwise unprocessable messages are handled correctly. Depending on the message payload and exception, an appropriate action should be taken to either replay, discard, or otherwise process the failed message. If a message cannot be dequeued due to errors, it may be moved to the [exception queue](./message-operations.md#message-expiry-and-exception-queues), if one exists.
348
172
349
-
If a message cannot be dequeued due to errors, it may be moved to the [exception queue](./message-operations.md#message-expiry-and-exception-queues), if one exists. You can handle such errors by using PL/SQL exception handling mechanisms.
173
+
For errors on procedures like enqueue you may also use the standard SQL exception mechanisms:
0 commit comments