Skip to content

Commit 59d4922

Browse files
authored
add txeventq info (#28)
Signed-off-by: Mark Nelson <[email protected]>
1 parent f44c3ee commit 59d4922

File tree

7 files changed

+1701
-141
lines changed

7 files changed

+1701
-141
lines changed

README.md

+102
Original file line numberDiff line numberDiff line change
@@ -19,6 +19,7 @@ Contributions are welcome - please see [contributing](CONTRIBUTING.md).
1919
- [Standalone binary](#standalone-binary)
2020
- [Custom metrics](#custom-metrics)
2121
- [Grafana dashboards](#grafana-dashboards)
22+
- [Monitoring Transactional Event Queues](#monitoring-transactional-event-queues)
2223
- [Developer notes](#developer-notes)
2324

2425

@@ -466,6 +467,107 @@ The dashboard shows some basic information, as shown below:
466467
![](doc/oracledb-dashboard.png)
467468

468469

470+
# Monitoring Transactional Event Queues
471+
472+
[Oracle Transactional Event Queues](https://docs.oracle.com/en/database/oracle/oracle-database/21/adque/index.html) ("TxEventQ") is a fault-tolerant, scalable, real-time messaging backbone offered by converged Oracle Database that allows you to build an enterprise-class event-driven architectures.
473+
474+
Access to the real-time broker, producer, and consumer metrics in a single dashboard and receiving alerts for issues allows teams to understand the state of their system.
475+
476+
The exporter includes a set of metrics for monitoring TxEventQ and a pre-built Grafana dashboard.
477+
478+
> Note: The metrics are written for Oracle Database 21c or later.
479+
480+
## How to create a topic
481+
482+
If you need to create a topic to monitor, you can use these statements to create and start a topic, and create a subscriber:
483+
484+
```sql
485+
declare
486+
subscriber sys.aq$_agent;
487+
begin
488+
-- create the topic
489+
dbms_aqadm.create_transactional_event_queue(
490+
queue_name => 'my_topic',
491+
multiple_consumers => true -- true makes a pub/sub topic
492+
);
493+
494+
-- start the topic
495+
dbms_aqadm.start_queue(
496+
queue_name => 'my_topic'
497+
);
498+
499+
-- create a subscriber
500+
dbms_aqadm.add_subscriber(
501+
queue_name => 'my_teq',
502+
subscriber => sys.aq$_agent(
503+
'my_subscriber', -- the subscriber name
504+
null, -- address, only used for notifications
505+
0 -- protocol
506+
),
507+
rule => 'correlation = ''my_subscriber'''
508+
);
509+
end;
510+
```
511+
512+
You can produce a message with these commands:
513+
514+
```sql
515+
declare
516+
enqueue_options dbms_aq.enqueue_options_t;
517+
message_properties dbms_aq.message_properties_t;
518+
message_handle raw(16);
519+
message SYS.AQ$_JMS_TEXT_MESSAGE;
520+
begin
521+
-- create the message payload
522+
message := SYS.AQ$_JMS_TEXT_MESSAGE.construct;
523+
message.set_text('{"orderid": 12345, "username": "Jessica Smith"}');
524+
525+
-- set the consumer name
526+
message_properties.correlation := 'my_subscriber';
527+
528+
-- enqueue the message
529+
dbms_aq.enqueue(
530+
queue_name => 'my_topic',
531+
enqueue_options => enqueue_options,
532+
message_properties => message_properties,
533+
payload => message,
534+
msgid => message_handle);
535+
536+
-- commit the transaction
537+
commit;
538+
end;
539+
```
540+
541+
## Metrics definitions
542+
543+
The metrics definitions are provided in [this file](./custom-metrics-example/txeventq-metrics.toml). You need to provide this file to the exporter, e.g., by adding it to your container image, or creating a Kubernetes config map containing the file and mounting that config map as a volume in your deployment. You also need to set the `CUSTOM_METRICS` environment variable to the location of this file.
544+
545+
## Additional database permissions
546+
547+
The database user that the exporter uses to connect to the database will also need additional permissions, which can be granted with these statements. This example assumes the exporter connects with the username "exporter":
548+
549+
```sql
550+
grant execute on dbms_aq to exporter;
551+
grant execute on dbms_aqadm to exporter;
552+
grant execute on dbms_aqin to exporter;
553+
grant execute on dbms_aqjms_internal to exporter;
554+
grant execute on dbms_teqk to exporter;
555+
grant execute on DBMS_RESOURCE_MANAGER to exporter;
556+
grant select_catalog_role to exporter;
557+
grant select on sys.aq$_queue_shards to exporter;
558+
grant select on user_queue_partition_assignment_table to exporter;
559+
```
560+
561+
## Grafana dashboard
562+
563+
A Grafana dashboard for Transactional Event Queues is provided [in this file](./docker-compose/grafana/dashboards/txeventq.json). This can be imported into your Grafana environment. Choose the Prometheus datasource that is collecting metrics from the exporter.
564+
565+
> Note: You may not see any activity on the dashboard unless there are clients producing and consuming messages from topics.
566+
567+
The dashboard will look like this:
568+
569+
![](./doc/txeventq-dashboard.png)
570+
469571
# Developer notes
470572

471573
The exporter itself is fairly simple. The initialization is done as follows:

custom-metrics-example/txeventq-metrics.toml

-141
Original file line numberDiff line numberDiff line change
@@ -97,144 +97,3 @@ FROM
9797
) t1
9898
JOIN gv$persistent_queues t2 ON t1.queue_id = t2.queue_id
9999
'''
100-
101-
[[metric]]
102-
context = "sessions"
103-
labels = ["inst_id", "status", "type"]
104-
metricsdesc = { value = "Gauge metric with count of sessions by status and type." }
105-
request = '''
106-
SELECT
107-
inst_id,
108-
status,
109-
type,
110-
COUNT(*) AS value
111-
FROM
112-
gv$session
113-
GROUP BY
114-
status,
115-
type,
116-
inst_id
117-
'''
118-
119-
120-
[[metric]]
121-
context = "asm_diskgroup"
122-
labels = ["inst_id", "name"]
123-
metricsdesc = { total = "Total size of ASM disk group.", free = "Free space available on ASM disk group." }
124-
request = '''
125-
SELECT
126-
inst_id,
127-
name,
128-
total_mb * 1024 * 1024 AS total,
129-
free_mb * 1024 * 1024 AS free
130-
FROM
131-
gv$asm_diskgroup
132-
'''
133-
ignorezeroresult = true
134-
135-
136-
[[metric]]
137-
context = "activity"
138-
labels = ["inst_id", "name"]
139-
metricsdesc = { value = "Generic counter metric from gv$sysstat view in Oracle." }
140-
request = '''
141-
SELECT
142-
inst_id,
143-
name,
144-
value
145-
FROM
146-
gv$sysstat
147-
WHERE
148-
name IN (
149-
'parse count (total)',
150-
'execute count',
151-
'user commits',
152-
'user rollbacks'
153-
)
154-
'''
155-
156-
[[metric]]
157-
context = "process"
158-
labels = ["inst_id"]
159-
metricsdesc = { count = "Gauge metric with count of processes." }
160-
request = '''
161-
SELECT
162-
inst_id,
163-
COUNT(*) AS count
164-
FROM
165-
gv$process
166-
GROUP BY
167-
inst_id
168-
'''
169-
170-
[[metric]]
171-
context = "wait_class"
172-
labels = ["inst_id", "wait_class"]
173-
metricsdesc = { total_waits = "Number of times waits of the class occurred", time_waited = "Amount of time spent in the wait by all sessions in the instance" }
174-
request = '''
175-
SELECT
176-
inst_id,
177-
wait_class,
178-
total_waits,
179-
time_waited
180-
FROM
181-
gv$system_wait_class
182-
'''
183-
184-
[[metric]]
185-
context = "system"
186-
labels = ["inst_id", "stat_name"]
187-
metricsdesc = { value = "os metric from gv$osstat view in Oracle." }
188-
request = '''
189-
SELECT
190-
inst_id,
191-
stat_name,
192-
value
193-
FROM
194-
gv$osstat
195-
WHERE
196-
upper(stat_name) IN (
197-
'NUM_CPUS',
198-
'LOAD',
199-
'IDLE_TIME',
200-
'BUSY_TIME',
201-
'USER_TIME',
202-
'PHYSICAL_MEMORY_BYTES',
203-
'FREE_MEMORY_BYTES'
204-
)
205-
'''
206-
207-
[[metric]]
208-
context = "system_network"
209-
labels = ["inst_id"]
210-
metricsdesc = { received_from_client = "Bytes received from client.", sent_to_client = "Bytes sent to client." }
211-
request = '''
212-
SELECT
213-
t1.inst_id AS inst_id,
214-
t1.received_from_client AS received_from_client,
215-
t2.sent_to_client AS sent_to_client
216-
FROM
217-
(
218-
SELECT
219-
inst_id,
220-
value AS received_from_client
221-
FROM
222-
gv$sysstat
223-
WHERE
224-
lower(name) LIKE '%received via sql*net from client%'
225-
ORDER BY
226-
value DESC
227-
) t1
228-
LEFT JOIN (
229-
SELECT
230-
inst_id,
231-
value AS sent_to_client
232-
FROM
233-
gv$sysstat
234-
WHERE
235-
lower(name) LIKE '%sent via sql*net to client%'
236-
ORDER BY
237-
value DESC
238-
) t2 ON t1.inst_id = t2.inst_id
239-
'''
240-

doc/txeventq-dashboard.png

122 KB
Loading

docker-compose/compose.yaml

+3
Original file line numberDiff line numberDiff line change
@@ -51,6 +51,9 @@ services:
5151
- DB_USERNAME=system
5252
- DB_PASSWORD=Welcome12345
5353
- DB_CONNECT_STRING=free23c:1521/free
54+
- CUSTOM_METRICS=/exporter/txeventq-metrics.toml
55+
volumes:
56+
- ./exporter:/exporter
5457
depends_on:
5558
free23c:
5659
condition: service_healthy
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,99 @@
1+
[[metric]]
2+
context = "ownership"
3+
metricsdesc = { inst_id = "Owner instance of the current queues." }
4+
request = '''
5+
SELECT
6+
inst_id
7+
FROM
8+
gv$persistent_queues
9+
WHERE
10+
ROWNUM < 2
11+
'''
12+
13+
[[metric]]
14+
context = "teq"
15+
metricsdesc = { curr_inst_id = "ID of current instance" }
16+
request = "SELECT instance_number AS curr_inst_id FROM v$instance"
17+
18+
[[metric]]
19+
context = "teq"
20+
labels = ["inst_id"]
21+
metricsdesc = { total_queues = "Total number of queues"}
22+
request = '''
23+
SELECT
24+
inst_id,
25+
COUNT(*) AS total_queues
26+
FROM
27+
(
28+
SELECT DISTINCT
29+
t1.inst_id,
30+
t2.queue_name
31+
FROM
32+
gv$aq_sharded_subscriber_stat t1
33+
JOIN gv$persistent_queues t2 ON t1.queue_id = t2.queue_id
34+
)
35+
GROUP BY
36+
inst_id
37+
'''
38+
39+
[[metric]]
40+
context = "teq"
41+
labels = ["inst_id"]
42+
metricsdesc = { total_subscribers = "Total number of subscribers"}
43+
request = '''
44+
SELECT
45+
inst_id,
46+
COUNT(*) AS total_subscribers
47+
FROM
48+
(
49+
SELECT DISTINCT
50+
inst_id,
51+
subscriber_id
52+
FROM
53+
gv$aq_sharded_subscriber_stat
54+
)
55+
GROUP BY
56+
inst_id
57+
'''
58+
59+
[[metric]]
60+
context = "teq"
61+
labels = ["inst_id", "queue_name", "subscriber_name"]
62+
metricsdesc = { enqueued_msgs = "Total enqueued messages.", dequeued_msgs = "Total dequeued messages.", remained_msgs = "Total remained messages.", time_since_last_dequeue = "Time since last dequeue.", estd_time_to_drain_no_enq = "Estimated time to drain if no enqueue.", message_latency_1 = "Message latency for last 5 mins.", message_latency_2 = "Message latency for last 1 hour.", message_latency_3 = "Message latency for last 5 hours."}
63+
request = '''
64+
SELECT DISTINCT
65+
t1.inst_id,
66+
t1.queue_id,
67+
t2.queue_name,
68+
t1.subscriber_id AS subscriber_name,
69+
t1.enqueued_msgs,
70+
t1.dequeued_msgs,
71+
t1.remained_msgs,
72+
t1.time_since_last_dequeue,
73+
t1.estd_time_to_drain_no_enq,
74+
t1.message_latency_1,
75+
t1.message_latency_2,
76+
t1.message_latency_3
77+
FROM
78+
(
79+
SELECT
80+
inst_id,
81+
queue_id,
82+
subscriber_id,
83+
SUM(enqueued_msgs) AS enqueued_msgs,
84+
SUM(dequeued_msgs) AS dequeued_msgs,
85+
SUM(enqueued_msgs - dequeued_msgs) AS remained_msgs,
86+
MIN(time_since_last_dequeue) AS time_since_last_dequeue,
87+
MAX(estd_time_to_drain_no_enq) AS estd_time_to_drain_no_enq,
88+
AVG(10) AS message_latency_1,
89+
AVG(20) AS message_latency_2,
90+
AVG(30) AS message_latency_3
91+
FROM
92+
gv$aq_sharded_subscriber_stat
93+
GROUP BY
94+
queue_id,
95+
subscriber_id,
96+
inst_id
97+
) t1
98+
JOIN gv$persistent_queues t2 ON t1.queue_id = t2.queue_id
99+
'''

0 commit comments

Comments
 (0)