|
| 1 | +## 游戏合区、拆区,数据库操作CASE - PostgreSQL Data merge case |
| 2 | + |
| 3 | +### 作者 |
| 4 | +digoal |
| 5 | + |
| 6 | +### 日期 |
| 7 | +2012-02-17 |
| 8 | + |
| 9 | +### 标签 |
| 10 | +PostgreSQL , 游戏数据库 , 合区 , 拆区 |
| 11 | + |
| 12 | +---- |
| 13 | + |
| 14 | +## 背景 |
| 15 | +打个比方,有两个游戏区要合并。 |
| 16 | + |
| 17 | +单个游戏区的用户ID可以有多个角色,角色名不能重复。 |
| 18 | + |
| 19 | +当需要合并游戏区时,可能会涉及到同一个ID的不同区使用的相同的角色。 |
| 20 | + |
| 21 | + |
| 22 | +PostgreSQL没有merge的SQL语法(PostgreSQL 9.5有了) |
| 23 | + |
| 24 | +PostgreSQL 9.5 new feature - Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE |
| 25 | + |
| 26 | +http://blog.163.com/digoal@126/blog/static/163877040201541094137923/ |
| 27 | + |
| 28 | +http://blog.163.com/digoal@126/blog/static/163877040201552343231537/ |
| 29 | + |
| 30 | +, 当然Oracle用MERGE也无法在一条SQL中实现这个需求. |
| 31 | + |
| 32 | +举个例子 : |
| 33 | + |
| 34 | + |
| 35 | +user_info1 表代表1区的用户表。 |
| 36 | + |
| 37 | +``` |
| 38 | +digoal=> create table user_info1 (userid int,nick text,info text,unique (userid,nick)); |
| 39 | +NOTICE: CREATE TABLE / UNIQUE will create implicit index "user_info1_userid_nick_key" for table "user_info1" |
| 40 | +CREATE TABLE |
| 41 | +``` |
| 42 | + |
| 43 | +user_info2 表代表2区的用户表 |
| 44 | + |
| 45 | +``` |
| 46 | +digoal=> create table user_info2 (userid int,nick text,info text,unique (userid,nick)); |
| 47 | +NOTICE: CREATE TABLE / UNIQUE will create implicit index "user_info2_userid_nick_key" for table "user_info2" |
| 48 | +CREATE TABLE |
| 49 | +``` |
| 50 | + |
| 51 | +创建测试数据, 1区和2区在userid=1到100范围内nick相同, 因此合并2个区的用户数据时, 这部分nick需要修改一下. 假如改成nick||'_2' |
| 52 | + |
| 53 | +``` |
| 54 | +digoal=> insert into user_info1 select generate_series(1,100),'digoal'||generate_series(1,100),'user_info1'; |
| 55 | +INSERT 0 100 |
| 56 | +digoal=> insert into user_info2 select generate_series(1,200),'digoal'||generate_series(1,200),'user_info2'; |
| 57 | +INSERT 0 200 |
| 58 | +digoal=> insert into user_info1 select generate_series(201,300),'digoal'||generate_series(201,300),'user_info1'; |
| 59 | +INSERT 0 100 |
| 60 | +``` |
| 61 | + |
| 62 | +创建nick获取函数 : |
| 63 | + |
| 64 | +``` |
| 65 | +CREATE OR REPLACE FUNCTION digoal.get_nick(i_userid int,i_nick text) |
| 66 | + RETURNS text |
| 67 | + LANGUAGE plpgsql |
| 68 | +AS $function$ |
| 69 | +declare |
| 70 | +begin |
| 71 | +perform 1 from user_info1 where userid=i_userid and nick=i_nick; |
| 72 | +if found then |
| 73 | +return i_nick||'_2'; |
| 74 | +end if; |
| 75 | +return i_nick; |
| 76 | +end; |
| 77 | +$function$ |
| 78 | +``` |
| 79 | + |
| 80 | +合并2区的表到1区 |
| 81 | + |
| 82 | +``` |
| 83 | +digoal=> insert into user_info1 select userid,get_nick(userid,nick),info from user_info2; |
| 84 | +INSERT 0 200 |
| 85 | +``` |
| 86 | + |
| 87 | +合并后, 查看重叠部分的数据, 2区的nick已经加上了_2. |
| 88 | + |
| 89 | +``` |
| 90 | +digoal=> select * from user_info1 where userid=1; |
| 91 | + userid | nick | info |
| 92 | +--------+-----------+------------ |
| 93 | + 1 | digoal1 | user_info1 |
| 94 | + 1 | digoal1_2 | user_info2 |
| 95 | +(2 rows) |
| 96 | +``` |
| 97 | + |
| 98 | +非重叠数据正常插入 : |
| 99 | + |
| 100 | +``` |
| 101 | +digoal=> select * from user_info1 where userid=200; |
| 102 | + userid | nick | info |
| 103 | +--------+-----------+------------ |
| 104 | + 200 | digoal200 | user_info2 |
| 105 | +(1 row) |
| 106 | +``` |
| 107 | + |
| 108 | +另一个例子 : |
| 109 | + |
| 110 | +``` |
| 111 | +digoal=> create table t1 (id int,name text unique); |
| 112 | +NOTICE: CREATE TABLE / UNIQUE will create implicit index "t1_name_key" for table "t1" |
| 113 | +CREATE TABLE |
| 114 | +digoal=> create table t2 (id int,name text unique); |
| 115 | +NOTICE: CREATE TABLE / UNIQUE will create implicit index "t2_name_key" for table "t2" |
| 116 | +CREATE TABLE |
| 117 | +digoal=> insert into t1 values(1,'digoal'); |
| 118 | +INSERT 0 1 |
| 119 | +digoal=> insert into t1 values(2,'digoal1'); |
| 120 | +INSERT 0 1 |
| 121 | +digoal=> insert into t1 values(3,'digoal11'); |
| 122 | +INSERT 0 1 |
| 123 | +digoal=> insert into t1 values(4,'digoal111'); |
| 124 | +INSERT 0 1 |
| 125 | +digoal=> insert into t1 values(5,'digoal1111'); |
| 126 | +INSERT 0 1 |
| 127 | +digoal=> insert into t1 values(6,'digoal11111'); |
| 128 | +INSERT 0 1 |
| 129 | +digoal=> insert into t2 values(1,'digoal'); |
| 130 | +``` |
| 131 | + |
| 132 | +把t2的数据合并到t1 : |
| 133 | + |
| 134 | +``` |
| 135 | +create or replace function get_name(i_name text) returns text as $$ |
| 136 | +declare |
| 137 | +v_name text; |
| 138 | +v_suffix text; |
| 139 | +begin |
| 140 | +v_suffix = '1'; |
| 141 | +perform 1 from t1 where name = i_name limit 1; |
| 142 | +if not found then |
| 143 | + return i_name; |
| 144 | +else |
| 145 | + loop |
| 146 | + perform 1 from t1 where name = i_name||v_suffix limit 1; |
| 147 | + if not found then |
| 148 | + exit; |
| 149 | + else |
| 150 | + v_suffix=v_suffix||'1'; |
| 151 | + end if; |
| 152 | + end loop; |
| 153 | +end if; |
| 154 | +return i_name||v_suffix; |
| 155 | +end; |
| 156 | +$$ language plpgsql; |
| 157 | +digoal=> insert into t1 select id,get_name(name) from t2; |
| 158 | +INSERT 0 1 |
| 159 | + |
| 160 | +digoal=> select * from t1; |
| 161 | + id | name |
| 162 | +----+-------------- |
| 163 | + 1 | digoal |
| 164 | + 2 | digoal1 |
| 165 | + 3 | digoal11 |
| 166 | + 4 | digoal111 |
| 167 | + 5 | digoal1111 |
| 168 | + 6 | digoal11111 |
| 169 | + 1 | digoal111111 |
| 170 | +``` |
| 171 | + |
| 172 | + |
0 commit comments