云数据库 GAUSSDB-DBE_PROFILER:示例
时间:2024-11-02 18:45:48
示例
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 |
--step1 创建表和存储过程 gaussdb=# DROP TABLE IF EXISTS t1; gaussdb=# CREATE TABLE t1 (i int); gaussdb=# CREATE OR REPLACE PROCEDURE p1() AS sql_stmt varchar2(200); result number; BEGIN for i in 1..1000 loop insert into t1 values(1); end loop; sql_stmt := 'select count(*) from t1'; EXECUTE IMMEDIATE sql_stmt into result; END; / gaussdb=# CREATE OR REPLACE PROCEDURE p2() AS BEGIN p1(); END; / gaussdb=# CREATE OR REPLACE PROCEDURE p3() AS BEGIN p2(); END; / --step2 调用plprofiler接口对存储过程进行profiling gaussdb=# SELECT dbe_profiler.pl_start_profiling('123'); gaussdb=# CALL p3(); --step3 查询相关profiling信息 --查询dbe_profiler.pl_profiling_functions表查看此次profiling涉及的存储过程 gaussdb=# SELECT * FROM dbe_profiler.pl_profiling_functions ORDER BY run_id, funcoid; run_id | funcoid | schema | funcname | total_occur | total_time ---------------------+---------+--------+----------+-------------+------------ 140300887521024_123 | 16770 | public | p1() | 1 | 54217 140300887521024_123 | 16771 | public | p2() | 1 | 54941 140300887521024_123 | 16772 | public | p3() | 1 | 55758 (3 rows) --查询dbe_profiler.pl_profiling_details表查看存过内每条语句的执行时间细节 gaussdb=# SELECT * FROM dbe_profiler.pl_profiling_details WHERE funcoid = 16770 ORDER BY run_id, funcoid, line#; run_id | funcoid | line# | source | cmd_type | total_occur | total_time | max_time | min_time ---------------------+---------+-------+---------------------------------------------+------------+-------------+------------+----------+---------- 140300887521024_123 | 16770 | 1 | DECLARE | | 0 | 0 | 0 | 0 140300887521024_123 | 16770 | 2 | sql_stmt varchar2(200); | | 0 | 0 | 0 | 0 140300887521024_123 | 16770 | 3 | result number; | | 0 | 0 | 0 | 0 140300887521024_123 | 16770 | 4 | begin | | 0 | 0 | 0 | 0 140300887521024_123 | 16770 | 5 | for i in 1..1000 loop | FORI | 1 | 52496 | 52496 | 52496 140300887521024_123 | 16770 | 6 | insert into t1 values(1); | EXE CS QL | 1000 | 51970 | 2115 | 47 140300887521024_123 | 16770 | 7 | end loop; | | 0 | 0 | 0 | 0 140300887521024_123 | 16770 | 8 | sql_stmt := 'select count(*) from t1'; | ASSIGN | 1 | 446 | 446 | 446 140300887521024_123 | 16770 | 9 | EXECUTE IMMEDIATE sql_stmt into result; | DYNEXECUTE | 1 | 1271 | 1271 | 1271 140300887521024_123 | 16770 | 10 | end | | 0 | 0 | 0 | 0 (10 rows) --查询dbe_profiler.pl_profiling_callgraph表查看调用栈信息和对应每个存过执行的整体时间(total_time、self_time对应调用栈栈顶存储过程的总时间和自身执行时间) gaussdb=# SELECT * FROM dbe_profiler.pl_profiling_callgraph ORDER BY run_id, stack; run_id | stack | self_time ---------------------+---------------------------------------------------------------------------+----------- 140300887521024_123 | {"public.p3() oid=16772"} | 817 140300887521024_123 | {"public.p3() oid=16772","public.p2() oid=16771"} | 724 140300887521024_123 | {"public.p3() oid=16772","public.p2() oid=16771","public.p1() oid=16770"} | 54217 (3 rows) --查询dbe_profiler.pl_profiling_trackinfo表查看存储过程每个阶段的执行时间 gaussdb=# SELECT step_name, loops_count FROM dbe_profiler.pl_profiling_trackinfo WHERE funcoid=16770; step_name | loops_count --------------+------------- init | 1 package | 1 spictx | 1 compile | 1 exec_context | 1 execute | 1 exec_cursor | 1 cleanup | 1 finsh | 1 (9 rows) --step4 删除系统表数据 gaussdb=# SELECT dbe_profiler.pl_clear_profiling(''); gaussdb=# SELECT step_name, loops_count FROM dbe_profiler.pl_profiling_trackinfo WHERE funcoid=16770; step_name | loops_count -----------+------------- (0 rows) gaussdb=# DROP TABLE t1; --step5 profiling包含自治事务的存储过程。 --建表 gaussdb=# CREATE TABLE t2(a int, b int); --创建包含自治事务的存储过程 gaussdb=# CREATE OR REPLACE PROCEDURE autonomous(a int, b int) AS DECLARE num3 int := a; num4 int := b; PRAGMA AUTONOMOUS_TRANSACTION; BEGIN insert into t2 values(num3, num4); dbe_output.print_line('just use call.'); END; / --创建调用自治事务存储过程的普通存储过程 gaussdb=# CREATE OR REPLACE PROCEDURE autonomous_1(a int, b int) AS DECLARE BEGIN dbe_output.print_line('just no use call.'); insert into t2 values(666, 666); autonomous(a,b); END; / gaussdb=# SELECT dbe_profiler.pl_start_profiling ('100'); gaussdb=# CALL autonomous(11,22); --查询表信息 gaussdb=# SELECT * FROM dbe_profiler.pl_profiling_functions ORDER BY run_id, funcoid; run_id | funcoid | schema | funcname | total_occur | total_time --------+---------+--------+----------+-------------+------------ (0 rows) gaussdb=# SELECT * FROM dbe_profiler.pl_profiling_details ORDER BY run_id, funcoid, line#; run_id | funcoid | line# | source | cmd_type | total_occur | total_time | max_time | min_time --------+---------+-------+--------+----------+-------------+------------+----------+---------- (0 rows) gaussdb=# SELECT * FROM dbe_profiler.pl_profiling_callgraph ORDER BY run_id, stack; run_id | stack | self_time --------+-------+----------- (0 rows) gaussdb=# SELECT * FROM dbe_profiler.pl_profiling_trackinfo ORDER BY run_id, funcoid; run_id | funcoid | step_name | loops_count | max_time | min_time | avg_time | total_time --------+---------+-----------+-------------+----------+----------+----------+------------ (0 rows) gaussdb=# SELECT dbe_profiler.pl_start_profiling ('101'); gaussdb=# CALL autonomous_1(11,22); gaussdb=# SELECT * FROM dbe_profiler.pl_profiling_functions ORDER BY run_id, funcoid; run_id | funcoid | schema | funcname | total_occur | total_time ---------------------+---------+------------+----------------+-------------+------------ 140421237831424_101 | 10422 | dbe_output | print_line() | 1 | 758 140421237831424_101 | 16771 | public | autonomous_1() | 1 | 23855 (2 rows) gaussdb=# SELECT * FROM dbe_profiler.pl_profiling_details ORDER BY run_id, funcoid, line#; run_id | funcoid | line# | source | cmd_type | total_occur | total_time | max_time | min_time ---------------------+---------+-------+---------------------------------------------+----------+-------------+------------+----------+---------- 140421237831424_101 | 10422 | 1 | | | 0 | 0 | 0 | 0 140421237831424_101 | 10422 | 2 | BEGIN | | 0 | 0 | 0 | 0 140421237831424_101 | 10422 | 3 | PKG_UTIL.io_print(format, true); | PERFORM | 1 | 754 | 754 | 754 140421237831424_101 | 10422 | 4 | END; | | 0 | 0 | 0 | 0 140421237831424_101 | 10422 | 5 | | | 0 | 0 | 0 | 0 140421237831424_101 | 16771 | 1 | | | 0 | 0 | 0 | 0 140421237831424_101 | 16771 | 2 | DECLARE | | 0 | 0 | 0 | 0 140421237831424_101 | 16771 | 3 | BEGIN | | 0 | 0 | 0 | 0 140421237831424_101 | 16771 | 4 | dbe_output.print_line('just no use call.'); | PERFORM | 1 | 2435 | 2435 | 2435 140421237831424_101 | 16771 | 5 | insert into t2 values(666, 666); | EXECSQL | 1 | 602 | 602 | 602 140421237831424_101 | 16771 | 6 | autonomous(a,b); | PERFORM | 1 | 20813 | 20813 | 20813 140421237831424_101 | 16771 | 7 | END | | 0 | 0 | 0 | 0 (12 rows) gaussdb=# SELECT * FROM dbe_profiler.pl_profiling_callgraph ORDER BY run_id, stack; run_id | stack | self_time ---------------------+-------------------------------------------------------------------------+----------- 140421237831424_101 | {"public.autonomous_1() oid=16771"} | 23097 140421237831424_101 | {"public.autonomous_1() oid=16771","dbe_output.print_line() oid=10422"} | 758 (2 rows) gaussdb=# SELECT * FROM dbe_profiler.pl_profiling_trackinfo ORDER BY run_id, funcoid; run_id | funcoid | step_name | loops_count | max_time | min_time | avg_time | total_time ---------------------+---------+--------------+-------------+----------+----------+----------+------------ 140421237831424_101 | 10422 | init | 1 | 0 | 0 | 0 | 0 140421237831424_101 | 10422 | package | 1 | 9 | 9 | 9 | 9 140421237831424_101 | 10422 | spictx | 1 | 1 | 1 | 1 | 1 140421237831424_101 | 10422 | compile | 1 | 383 | 383 | 383 | 383 140421237831424_101 | 10422 | exec_context | 1 | 1 | 1 | 1 | 1 140421237831424_101 | 10422 | execute | 1 | 1301 | 1301 | 1301 | 1301 140421237831424_101 | 10422 | exec_cursor | 1 | 3 | 3 | 3 | 3 140421237831424_101 | 10422 | cleanup | 1 | 11 | 11 | 11 | 11 140421237831424_101 | 10422 | finsh | 1 | 0 | 0 | 0 | 0 140421237831424_101 | 16771 | init | 1 | 0 | 0 | 0 | 0 140421237831424_101 | 16771 | package | 1 | 103 | 103 | 103 | 103 140421237831424_101 | 16771 | spictx | 1 | 1 | 1 | 1 | 1 140421237831424_101 | 16771 | compile | 1 | 1869 | 1869 | 1869 | 1869 140421237831424_101 | 16771 | exec_context | 1 | 3 | 3 | 3 | 3 140421237831424_101 | 16771 | execute | 1 | 24011 | 24011 | 24011 | 24011 140421237831424_101 | 16771 | exec_cursor | 1 | 1 | 1 | 1 | 1 140421237831424_101 | 16771 | cleanup | 1 | 16 | 16 | 16 | 16 140421237831424_101 | 16771 | finsh | 1 | 1 | 1 | 1 | 1 (18 rows) gaussdb=# SELECT dbe_profiler.pl_clear_profiling(''); gaussdb=# SELECT * FROM dbe_profiler.pl_profiling_functions; run_id | funcoid | schema | funcname | total_occur | total_time --------+---------+--------+----------+-------------+------------ (0 rows) gaussdb=# DROP TABLE t2; |
support.huaweicloud.com/centralized-devg-v8-gaussdb/gaussdb-42-0841.html
看了此文的人还看了
CDN加速
GaussDB
文字转换成语音
免费的服务器
如何创建网站
域名网站购买
私有云桌面
云主机哪个好
域名怎么备案
手机云电脑
SSL证书申请
云点播服务器
免费OCR是什么
电脑云桌面
域名备案怎么弄
语音转文字
文字图片识别
云桌面是什么
网址安全检测
网站建设搭建
国外CDN加速
SSL免费证书申请
短信批量发送
图片OCR识别
云数据库MySQL
个人域名购买
录音转文字
扫描图片识别文字
OCR图片识别
行驶证识别
虚拟电话号码
电话呼叫中心软件
怎么制作一个网站
Email注册网站
华为VNC
图像文字识别
企业网站制作
个人网站搭建
华为云计算
免费租用云托管
云桌面云服务器
ocr文字识别免费版
HTTPS证书申请
图片文字识别转换
国外域名注册商
使用免费虚拟主机
云电脑主机多少钱
鲲鹏云手机
短信验证码平台
OCR图片文字识别
SSL证书是什么
申请企业邮箱步骤
免费的企业用邮箱
云免流搭建教程
域名价格
推荐文章