PG中文社区 /
mdi-home
首页 社区新闻 中文文档 加入ACE {{ item.text }} 登录
mdi-home 首页 mdi-chat-processing 社区新闻 mdi-book-open-variant 中文文档 mdi-account-multiple-check 加入ACE mdi-file-multiple-outline 相关资料 mdi-blank {{item.text}} mdi-exit-to-app 退出账号
PostgreSQL与Oracle兼容性之 plpgsql 自治事务补丁

原作者:digoal/德哥  创作时间:2016-11-17 15:56:00+08  
doudou586 发布于2016-11-17 12:58:00           评论: 2   浏览: 7893   顶: 1054  踩: 1017 

PostgreSQL Oracle兼容性之plpgsql 自治事务(autonomous_transaction)补丁

作者: digoal

日期: 2016-11-16


背景

PostgreSQL的plpgsql服务端编程语言与Oracle数据库的pl/sql编程语言非常类似,但是对于自治事务一直没有语法层面的支持。

以往如果要支持自治事务,可以使用exception或者使用dblink来实现。

写法有点复杂,如果你想要语法层面的支持,可以试试社区放出的这个补丁,补丁还没有合并到主分支,不建议生产使用。

用法

以9.6为例,介绍一下这个补丁的用法。

安装补丁

$ wget https://www.postgresql.org/message-id/attachment/45863/autonomous.patch

$ cd postgresql-9.6.1

$ patch -p1 < ../autonomous.patch $ make && make install 

重启数据库

$ pg_ctl restart -m fast

语法讲解

查看这两个回归测试的文件,可以了解它的用法

1. src/pl/plpgsql/src/expected/plpgsql_autonomous.out

CREATE TABLE test1 (a int);
CREATE FUNCTION autonomous_test() RETURNS integer
LANGUAGE plpgsql
AS $$
DECLARE
  PRAGMA AUTONOMOUS_TRANSACTION;
BEGIN
  FOR i IN 0..9 LOOP
    START TRANSACTION;
    EXECUTE 'INSERT INTO test1 VALUES (' || i::text || ')';
    IF i % 2 = 0 THEN
        COMMIT;
    ELSE
        ROLLBACK;
    END IF;
  END LOOP;

  RETURN 42;
END;
$$;
SELECT autonomous_test();
 autonomous_test 
-----------------
              42
(1 row)

SELECT * FROM test1;
 a 
---
 0
 2
 4
 6
 8
(5 rows)

TRUNCATE test1;
CREATE FUNCTION autonomous_test2() RETURNS integer
LANGUAGE plpgsql
AS $$
DECLARE
  PRAGMA AUTONOMOUS_TRANSACTION;
BEGIN
  FOR i IN 0..9 LOOP
    START TRANSACTION;
    INSERT INTO test1 VALUES (i);
    IF i % 2 = 0 THEN
        COMMIT;
    ELSE
        ROLLBACK;
    END IF;
  END LOOP;

  RETURN 42;
END;
$$;
SELECT autonomous_test2();
 autonomous_test2 
------------------
               42
(1 row)

SELECT * FROM test1;
 a
---
 
 
 
 
 
(5 rows)

2. src/pl/plpython/expected/plpython_autonomous.out

CREATE TABLE test1 (a int, b text);
CREATE FUNCTION autonomous_test() RETURNS integer
LANGUAGE plpythonu
AS $$
with plpy.autonomous() as a:
    for i in range(0, 10):
        a.execute("BEGIN")
        a.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
        if i % 2 == 0:
            a.execute("COMMIT")
        else:
            a.execute("ROLLBACK")

return 42
$$;
SELECT autonomous_test();
 autonomous_test 
-----------------
              42
(1 row)

SELECT * FROM test1;
 a | b 
---+---
 0 | 
 2 | 
 4 | 
 6 | 
 8 | 
(5 rows)

CREATE FUNCTION autonomous_test2() RETURNS integer
LANGUAGE plpythonu
AS $$
with plpy.autonomous() as a:
        a.execute("BEGIN")
        a.execute("INSERT INTO test1 (a) VALUES (11)")
        rv = a.execute("SELECT * FROM test1")
        plpy.info(rv)
        a.execute("ROLLBACK")

return 42
$$;
SELECT autonomous_test2();
INFO:  
 autonomous_test2 
------------------
               42
(1 row)

SELECT * FROM test1;
 a | b 
---+---
 0 | 
 2 | 
 4 | 
 6 | 
 8 | 
(5 rows)

CREATE FUNCTION autonomous_test3() RETURNS integer
LANGUAGE plpythonu
AS $$
with plpy.autonomous() as a:
    a.execute("DO $_$ BEGIN RAISE NOTICE 'notice'; END $_$")
    a.execute("DO $_$ BEGIN RAISE EXCEPTION 'error'; END $_$")

return 42
$$;
SELECT autonomous_test3();
NOTICE:  notice
ERROR:  error
CONTEXT:  PL/pgSQL function inline_code_block line 1 at RAISE
PL/Python function "autonomous_test3"
CREATE FUNCTION autonomous_test4() RETURNS integer
LANGUAGE plpythonu
AS $$
with plpy.autonomous() as a:
    a.execute("SET client_encoding TO SJIS")

return 42
$$;
SELECT autonomous_test4();
ERROR:  cannot set client encoding in autonomous session
CONTEXT:  PL/Python function "autonomous_test4"
TRUNCATE test1;
CREATE FUNCTION autonomous_test5() RETURNS integer
LANGUAGE plpythonu
AS $$
with plpy.autonomous() as a:
    plan = a.prepare("INSERT INTO test1 (a, b) VALUES ($1, $2)", ["int4", "text"])
    a.execute_prepared(plan, [1, "one"])
    a.execute_prepared(plan, [2, "two"])

return 42
$$;
SELECT autonomous_test5();
 autonomous_test5 
------------------
               42
(1 row)

SELECT * FROM test1;
 a |  b  
---+-----
 1 | one
 2 | two
(2 rows)

TRUNCATE test1;
CREATE FUNCTION autonomous_test6() RETURNS integer
LANGUAGE plpythonu
AS $$
with plpy.autonomous() as a:
    plan = a.prepare("INSERT INTO test1 (a) VALUES (i)", {"i": "int4"})
    a.execute_prepared(plan, [1])
    a.execute_prepared(plan, [2])

return 42
$$;
SELECT autonomous_test6();
 autonomous_test6 
------------------
               42
(1 row)

SELECT * FROM test1;
 a | b 
---+---
 1 | 
 2 | 
(2 rows)

TRUNCATE test1;
CREATE FUNCTION autonomous_test7() RETURNS integer
LANGUAGE plpythonu
AS $$
with plpy.autonomous() as a:
        a.execute("BEGIN")
        plan = a.prepare("INSERT INTO test1 (a) VALUES ($1)", ["int4"])
        a.execute_prepared(plan, [11])
        plan = a.prepare("SELECT * FROM test1")
        rv = a.execute_prepared(plan, [])
        plpy.info(rv)
        a.execute("ROLLBACK")

return 42
$$;
SELECT autonomous_test7();
INFO:  
 autonomous_test7 
------------------
               42
(1 row)

SELECT * FROM test1;
 a | b 
---+---
(0 rows)

CREATE FUNCTION autonomous_test8() RETURNS integer
LANGUAGE plpythonu
AS $$
with plpy.autonomous() as a:
        a.execute("BEGIN")

return 42
$$;
SELECT autonomous_test8();
ERROR:  autonomous session ended with transaction block open
CONTEXT:  PL/Python function "autonomous_test8"
DROP TABLE test1;

测试

测试plpgsql的自治事务用法

-- 创建测试表
CREATE TABLE test1 (a int);

创建测试函数
CREATE FUNCTION autonomous_test() RETURNS integer
LANGUAGE plpgsql
AS $$
DECLARE
  -- 定义使用自治事务
  PRAGMA AUTONOMOUS_TRANSACTION;
BEGIN
  FOR i IN 0..9 LOOP
    -- 启动自治事务
    START TRANSACTION;
    -- 目前仅支持动态SQL
    EXECUTE 'INSERT INTO test1 VALUES (' || i::text || ')';
    IF i % 2 = 0 THEN
        -- 整除2的提交
    COMMIT;
    ELSE
        -- 不能整除2的回归
    ROLLBACK;
    END IF;
  END LOOP;

  RETURN 42;
END;
$$;

-- 调用测试函数
SELECT autonomous_test();
 autonomous_test 
-----------------
              42
(1 row)

-- 查看结果
SELECT * FROM test1;
 a 
---
 0
 2
 4
 6
 8
(5 rows)

TRUNCATE test1;


CREATE FUNCTION autonomous_test2() RETURNS integer
LANGUAGE plpgsql
AS $$
DECLARE
  PRAGMA AUTONOMOUS_TRANSACTION;
BEGIN
  FOR i IN 0..9 LOOP
    START TRANSACTION;
    -- 不支持spi prepared statement
    -- 与当前自治事务的设计有关
    INSERT INTO test1 VALUES (i);
    IF i % 2 = 0 THEN
        COMMIT;
    ELSE
        ROLLBACK;
    END IF;
  END LOOP;

  RETURN 42;
END;
$$;

SELECT autonomous_test2();
 autonomous_test2 
------------------
               42
(1 row)

SELECT * FROM test1;
 a
---





(5 rows)

目前这个PATCH还在fix,请注意跟踪,也许后面的用法就变了。

When running in-process (SPI), we install parser hooks that allow the parser to check back into PL/pgSQL about whether x, y are variables and what they mean. When we run in an autonomous session, we don't have that available. So my idea was to extend the protocol Parse message to allow sending a symbol table instead of parameter types. So instead of saying, there are two parameters and here are their types, I would send a list of symbols and types, and the server would respond to the Parse message with some kind of information about which symbols it found. I think that would work, but I got lost in the weeds and didn't get very far. But you can see some of that in the code. If anyone has other ideas, I'd be very interested.


/images/news/2016/pg_bot_banner.jpg


评论:2   浏览: 7893                   顶: 1054  踩: 1017 

请在登录后发表评论,否则无法保存。

1# __ xcvxcvsdf 回答于 2024-10-12 16:56:14+08
https://zulin.tiancebbs.cn/sh/3083.html https://zulin.tiancebbs.cn/sh/4989.html https://zulin.tiancebbs.cn/sh/3761.html https://www.tiancebbs.cn/ershoufang/468391.html https://zulin.tiancebbs.cn/sh/2703.html https://zulin.tiancebbs.cn/sh/4076.html https://su.tiancebbs.cn/hjzl/457846.html https://hz.tiancebbs.cn/qihuotouzi/55072.html https://www.tiancebbs.cn/wangzhantuiguang/440769.html https://www.tiancebbs.cn/ershouwang/474336.html https://suining.tiancebbs.cn/qths/464745.html https://aihuishou.tiancebbs.cn/sh/2000.html https://fjqz.tiancebbs.cn/qths/472879.html https://zhanjiang.tiancebbs.cn/qths/467056.html https://zulin.tiancebbs.cn/sh/3647.html https://zulin.tiancebbs.cn/sh/1655.html https://chifeng.tiancebbs.cn/qths/452376.html

2# __ xiaowu 回答于 2024-04-22 09:29:34+08
落日文案治愈:https://www.nanss.com/wenan/2289.html 2022朋友圈文案:https://www.nanss.com/wenan/2111.html 关于成功的作文:https://www.nanss.com/xuexi/2215.html 关于感谢的作文:https://www.nanss.com/xuexi/2220.html 冬至作文:https://www.nanss.com/xuexi/2238.html 太空授课观后感:https://www.nanss.com/xuexi/2103.html 为儿子做早餐的心语:https://www.nanss.com/yulu/2008.html 梅花的作文:https://www.nanss.com/xuexi/2219.html 有关秋天的作文:https://www.nanss.com/xuexi/2181.html 愿亲人在天堂安好唯美句子:https://www.nanss.com/yulu/2041.html 如何发朋友圈让客户主动找你:https://www.nanss.com/shenghuo/2318.html 正能量四字成语:https://www.nanss.com/xuexi/1941.html 趁着父母还在尽孝的句子:https://www.nanss.com/yulu/1651.html 关于兄弟反目的说说:https://www.nanss.com/wenan/1895.html 党风廉政建设总结:https://www.nanss.com/gongzuo/2105.html 说唱怼人押韵句子:https://www.nanss.com/yulu/1749.html 有关防溺水的作文:https://www.nanss.com/xuexi/2418.html 我的假期生活作文:https://www.nanss.com/xuexi/2161.html 葬爱家族语录:https://www.nanss.com/shenghuo/1685.html 微信个性签名:https://www.nanss.com/wenan/2084.html 美好的一天从清晨开始说说:https://www.nanss.com/wenan/1853.html 高情商感冒了的朋友圈说说:https://www.nanss.com/wenan/1763.html 亲情的作文:https://www.nanss.com/xuexi/2357.html 关于清明节的作文200字:https://www.nanss.com/xuexi/2021.html 校长讲话:https://www.nanss.com/xuexi/2454.html 小龙虾配饮料的朋友圈文案:https://www.nanss.com/wenan/1657.html 团结作文:https://www.nanss.com/xuexi/2197.html 周末特惠广告语:https://www.nanss.com/shenghuo/1539.html 现代诗摘抄四年级下册:https://www.nanss.com/xuexi/2081.html 父亲忌日思念短语:https://www.nanss.com/yulu/2339.html



发表评论:
加入我们
QQ群1:5276420
QQ群2:3336901
QQ群3:254622631
文档群:150657323
文档翻译平台:按此访问
社区邮件列表:按此订阅
商业支持
扫码关注
加入我们
QQ群1:5276420
QQ群2:3336901
QQ群3:254622631
文档群:150657323
文档翻译平台:按此访问
社区邮件列表:按此订阅
商业支持
扫码关注
© PostgreSQL中文社区 ... (自2010年起)