|
| 1 | +## PostgreSQL GUC_REPORT+libpq 实现客户端决策链路 - multi host + 客户端 target_session_attrs + 发起连接时即刻获取PG数据库当前状态 - libpq 协议级 驱动级 failover balance |
| 2 | + |
| 3 | +### 作者 |
| 4 | +digoal |
| 5 | + |
| 6 | +### 日期 |
| 7 | +2021-03-04 |
| 8 | + |
| 9 | +### 标签 |
| 10 | +PostgreSQL , libpq , target_session_attrs , guc_report , multi host配置 , 期望被连接的数据库状态 , failover , balance |
| 11 | + |
| 12 | +---- |
| 13 | + |
| 14 | +## 背景 |
| 15 | +PostgreSQL libpq支持多数据库host配置(多数据源, 例如abcd四个数据库实例), 当客户端发起连接请求, 数据库a告诉你当前的状态, 客户端根据对数据库状态的预期选择是否要使用这个数据库a或者连接其他数据库实例bcd. |
| 16 | + |
| 17 | +使用这种方法可以实现数据库驱动(协议)级别的failover, loadbalance |
| 18 | + |
| 19 | +### 1、客户端是怎么配置多数据源的? |
| 20 | + |
| 21 | +https://www.postgresql.org/docs/devel/libpq-connect.html#LIBPQ-CONNSTRING |
| 22 | + |
| 23 | +It is possible to specify multiple host components, each with an optional port component, in a single URI. A URI of the form postgresql://host1:port1,host2:port2,host3:port3/ is equivalent to a connection string of the form host=host1,host2,host3 port=port1,port2,port3. As further described below, each host will be tried in turn until a connection is successfully established. |
| 24 | + |
| 25 | +34.1.1.3. Specifying Multiple Hosts |
| 26 | +It is possible to specify multiple hosts to connect to, so that they are tried in the given order. In the Keyword/Value format, the host, hostaddr, and port options accept comma-separated lists of values. The same number of elements must be given in each option that is specified, such that e.g., the first hostaddr corresponds to the first host name, the second hostaddr corresponds to the second host name, and so forth. As an exception, if only one port is specified, it applies to all the hosts. |
| 27 | + |
| 28 | +In the connection URI format, you can list multiple host:port pairs separated by commas in the host component of the URI. |
| 29 | + |
| 30 | +In either format, a single host name can translate to multiple network addresses. A common example of this is a host that has both an IPv4 and an IPv6 address. |
| 31 | + |
| 32 | +When multiple hosts are specified, or when a single host name is translated to multiple addresses, all the hosts and addresses will be tried in order, until one succeeds. If none of the hosts can be reached, the connection fails. If a connection is established successfully, but authentication fails, the remaining hosts in the list are not tried. |
| 33 | + |
| 34 | +If a password file is used, you can have different passwords for different hosts. All the other connection options are the same for every host in the list; it is not possible to e.g., specify different usernames for different hosts. |
| 35 | + |
| 36 | +### 2、数据库实例是怎么告诉客户它的状态的? |
| 37 | + |
| 38 | +设置为GUC_REPORT的参数, 在连接时就可以被获取, 可以报告哪些状态呢? |
| 39 | + |
| 40 | +### 3、客户的是根据什么配置决策是否要使用当前请求的数据库实例的? |
| 41 | + |
| 42 | +target_session_attrs |
| 43 | +This option determines whether the session must have certain properties to be acceptable. It's typically used in combination with multiple host names to select the first acceptable alternative among several hosts. There are six modes: |
| 44 | + |
| 45 | +any (default) |
| 46 | +any successful connection is acceptable |
| 47 | + |
| 48 | +read-write |
| 49 | +session must accept read-write transactions by default (that is, the server must not be in hot standby mode and the default_transaction_read_only parameter must be off) |
| 50 | + |
| 51 | +read-only |
| 52 | +session must not accept read-write transactions by default (the converse) |
| 53 | + |
| 54 | +primary |
| 55 | +server must not be in hot standby mode |
| 56 | + |
| 57 | +standby |
| 58 | +server must be in hot standby mode |
| 59 | + |
| 60 | +prefer-standby |
| 61 | +first try to find a standby server, but if none of the listed hosts is a standby server, try again in all mode |
| 62 | + |
| 63 | +PostgreSQL 14 扩展libpq target_session_attrs 参数, 可以选择6种数据库实例的被期望状态. |
| 64 | + |
| 65 | +https://git.postgresql.org/gitweb/?p=postgresql.git;a=commit;h=ee28cacf619f4d9c23af5a80e1171a5adae97381 |
| 66 | + |
| 67 | +``` |
| 68 | +Extend the abilities of libpq's target_session_attrs parameter. |
| 69 | + |
| 70 | +In addition to the existing options of "any" and "read-write", we |
| 71 | +now support "read-only", "primary", "standby", and "prefer-standby". |
| 72 | +"read-write" retains its previous meaning of "transactions are |
| 73 | +read-write by default", and "read-only" inverts that. The other |
| 74 | +three modes test specifically for hot-standby status, which is not |
| 75 | +quite the same thing. (Setting default_transaction_read_only on |
| 76 | +a primary server renders it read-only to this logic, but not a |
| 77 | +standby.) |
| 78 | + |
| 79 | +Furthermore, if talking to a v14 or later server, no extra network |
| 80 | +round trip is needed to detect the session's status; the GUC_REPORT |
| 81 | +variables delivered by the server are enough. When talking to an |
| 82 | +older server, a SHOW or SELECT query is issued to detect session |
| 83 | +read-only-ness or server hot-standby state, as needed. |
| 84 | + |
| 85 | +Haribabu Kommi, Greg Nancarrow, Vignesh C, Tom Lane; reviewed at |
| 86 | +various times by Laurenz Albe, Takayuki Tsunakawa, Peter Smith. |
| 87 | + |
| 88 | +Discussion: https://postgr.es/m/CAF3+xM+8-ztOkaV9gHiJ3wfgENTq97QcjXQt+rbFQ6F7oNzt9A@mail.gmail.com |
| 89 | +``` |
| 90 | + |
| 91 | +PostgreSQL 14 新增guc_report参数 in_hot_standby、default_transaction_read_only, 可以在连接时报告给客户端. |
| 92 | + |
| 93 | + |
| 94 | +https://git.postgresql.org/gitweb/?p=postgresql.git;a=commit;h=d16f8c8e416d288bd4734ed5f14076b62ec8d153 |
| 95 | + |
| 96 | +``` |
| 97 | +Mark default_transaction_read_only as GUC_REPORT. |
| 98 | + |
| 99 | +This allows clients to find out the setting at connection time without |
| 100 | +having to expend a query round trip to do so; |
| 101 | +which is helpful when trying to identify read/write servers. |
| 102 | +(One must also look at in_hot_standby, but that's already GUC_REPORT, cf bf8a662c9.) |
| 103 | +Modifying libpq to make use of this will come soon, |
| 104 | +but I felt it cleaner to push the server change separately. |
| 105 | + |
| 106 | +Haribabu Kommi, Greg Nancarrow, Vignesh C; reviewed at various times |
| 107 | +by Laurenz Albe, Takayuki Tsunakawa, Peter Smith. |
| 108 | + |
| 109 | +Discussion: https://postgr.es/m/CAF3+xM+8-ztOkaV9gHiJ3wfgENTq97QcjXQt+rbFQ6F7oNzt9A@mail.gmail.com |
| 110 | +``` |
| 111 | + |
| 112 | +目前PG支持的所有guc_report类型参数: |
| 113 | + |
| 114 | + |
| 115 | +src/backend/utils/misc/guc.c |
| 116 | + |
| 117 | +``` |
| 118 | +1125 { |
| 119 | +1126 /* Not for general use --- used by SET SESSION AUTHORIZATION */ |
| 120 | +1127 {"is_superuser", PGC_INTERNAL, UNGROUPED, |
| 121 | +1128 gettext_noop("Shows whether the current user is a superuser."), |
| 122 | +1129 NULL, |
| 123 | +1130 GUC_REPORT | GUC_NO_SHOW_ALL | GUC_NO_RESET_ALL | GUC_NOT_IN_SAMPLE | GUC_DISALLOW_IN_FILE |
| 124 | +1131 }, |
| 125 | +1132 &session_auth_is_superuser, |
| 126 | +1133 false, |
| 127 | +1134 NULL, NULL, NULL |
| 128 | +1135 }, |
| 129 | + |
| 130 | +1619 { |
| 131 | +1620 {"default_transaction_read_only", PGC_USERSET, CLIENT_CONN_STATEMENT, |
| 132 | +1621 gettext_noop("Sets the default read-only status of new transactions."), |
| 133 | +1622 NULL, |
| 134 | +1623 GUC_REPORT |
| 135 | +1624 }, |
| 136 | +1625 &DefaultXactReadOnly, |
| 137 | +1626 false, |
| 138 | +1627 NULL, NULL, NULL |
| 139 | +1628 }, |
| 140 | + |
| 141 | +1777 { |
| 142 | +1778 {"integer_datetimes", PGC_INTERNAL, PRESET_OPTIONS, |
| 143 | +1779 gettext_noop("Datetimes are integer based."), |
| 144 | +1780 NULL, |
| 145 | +1781 GUC_REPORT | GUC_NOT_IN_SAMPLE | GUC_DISALLOW_IN_FILE |
| 146 | +1782 }, |
| 147 | +1783 &integer_datetimes, |
| 148 | +1784 true, |
| 149 | +1785 NULL, NULL, NULL |
| 150 | +1786 }, |
| 151 | + |
| 152 | +1808 { |
| 153 | +1809 {"standard_conforming_strings", PGC_USERSET, COMPAT_OPTIONS_PREVIOUS, |
| 154 | +1810 gettext_noop("Causes '...' strings to treat backslashes literally."), |
| 155 | +1811 NULL, |
| 156 | +1812 GUC_REPORT |
| 157 | +1813 }, |
| 158 | +1814 &standard_conforming_strings, |
| 159 | +1815 true, |
| 160 | +1816 NULL, NULL, NULL |
| 161 | +1817 }, |
| 162 | + |
| 163 | +1859 { |
| 164 | +1860 {"in_hot_standby", PGC_INTERNAL, PRESET_OPTIONS, |
| 165 | +1861 gettext_noop("Shows whether hot standby is currently active."), |
| 166 | +1862 NULL, |
| 167 | +1863 GUC_REPORT | GUC_NOT_IN_SAMPLE | GUC_DISALLOW_IN_FILE |
| 168 | +1864 }, |
| 169 | +1865 &in_hot_standby, |
| 170 | +1866 false, |
| 171 | +1867 NULL, NULL, show_in_hot_standby |
| 172 | +1868 }, |
| 173 | + |
| 174 | +3865 { |
| 175 | +3866 {"client_encoding", PGC_USERSET, CLIENT_CONN_LOCALE, |
| 176 | +3867 gettext_noop("Sets the client's character set encoding."), |
| 177 | +3868 NULL, |
| 178 | +3869 GUC_IS_NAME | GUC_REPORT |
| 179 | +3870 }, |
| 180 | +3871 &client_encoding_string, |
| 181 | +3872 "SQL_ASCII", |
| 182 | +3873 check_client_encoding, assign_client_encoding, NULL |
| 183 | +3874 }, |
| 184 | + |
| 185 | +3896 { |
| 186 | +3897 {"DateStyle", PGC_USERSET, CLIENT_CONN_LOCALE, |
| 187 | +3898 gettext_noop("Sets the display format for date and time values."), |
| 188 | +3899 gettext_noop("Also controls interpretation of ambiguous " |
| 189 | +3900 "date inputs."), |
| 190 | +3901 GUC_LIST_INPUT | GUC_REPORT |
| 191 | +3902 }, |
| 192 | +3903 &datestyle_string, |
| 193 | +3904 "ISO, MDY", |
| 194 | +3905 check_datestyle, assign_datestyle, NULL |
| 195 | +3906 }, |
| 196 | + |
| 197 | +4084 { |
| 198 | +4085 /* Can't be set in postgresql.conf */ |
| 199 | +4086 {"server_encoding", PGC_INTERNAL, CLIENT_CONN_LOCALE, |
| 200 | +4087 gettext_noop("Sets the server (database) character set encoding."), |
| 201 | +4088 NULL, |
| 202 | +4089 GUC_IS_NAME | GUC_REPORT | GUC_NOT_IN_SAMPLE | GUC_DISALLOW_IN_FILE |
| 203 | +4090 }, |
| 204 | +4091 &server_encoding_string, |
| 205 | +4092 "SQL_ASCII", |
| 206 | +4093 NULL, NULL, NULL |
| 207 | +4094 }, |
| 208 | + |
| 209 | +4096 { |
| 210 | +4097 /* Can't be set in postgresql.conf */ |
| 211 | +4098 {"server_version", PGC_INTERNAL, PRESET_OPTIONS, |
| 212 | +4099 gettext_noop("Shows the server version."), |
| 213 | +4100 NULL, |
| 214 | +4101 GUC_REPORT | GUC_NOT_IN_SAMPLE | GUC_DISALLOW_IN_FILE |
| 215 | +4102 }, |
| 216 | +4103 &server_version_string, |
| 217 | +4104 PG_VERSION, |
| 218 | +4105 NULL, NULL, NULL |
| 219 | +4106 }, |
| 220 | + |
| 221 | +4120 { |
| 222 | +4121 /* Not for general use --- used by SET SESSION AUTHORIZATION */ |
| 223 | +4122 {"session_authorization", PGC_USERSET, UNGROUPED, |
| 224 | +4123 gettext_noop("Sets the session user name."), |
| 225 | +4124 NULL, |
| 226 | +4125 GUC_IS_NAME | GUC_REPORT | GUC_NO_SHOW_ALL | GUC_NO_RESET_ALL | GUC_NOT_IN_SAMPLE | GUC_DISALLOW_IN_FILE | GUC_NOT_WHILE_SEC_REST |
| 227 | +4126 }, |
| 228 | +4127 &session_authorization_string, |
| 229 | +4128 NULL, |
| 230 | +4129 check_session_authorization, assign_session_authorization, NULL |
| 231 | +4130 }, |
| 232 | + |
| 233 | +4188 { |
| 234 | +4189 {"TimeZone", PGC_USERSET, CLIENT_CONN_LOCALE, |
| 235 | +4190 gettext_noop("Sets the time zone for displaying and interpreting time stamps."), |
| 236 | +4191 NULL, |
| 237 | +4192 GUC_REPORT |
| 238 | +4193 }, |
| 239 | +4194 &timezone_string, |
| 240 | +4195 "GMT", |
| 241 | +4196 check_timezone, assign_timezone, show_timezone |
| 242 | +4197 }, |
| 243 | + |
| 244 | +4453 { |
| 245 | +4454 {"application_name", PGC_USERSET, LOGGING_WHAT, |
| 246 | +4455 gettext_noop("Sets the application name to be reported in statistics and logs."), |
| 247 | +4456 NULL, |
| 248 | +4457 GUC_IS_NAME | GUC_REPORT | GUC_NOT_IN_SAMPLE |
| 249 | +4458 }, |
| 250 | +4459 &application_name, |
| 251 | +4460 "", |
| 252 | +4461 check_application_name, assign_application_name, NULL |
| 253 | +4462 }, |
| 254 | + |
| 255 | +4581 { |
| 256 | +4582 {"IntervalStyle", PGC_USERSET, CLIENT_CONN_LOCALE, |
| 257 | +4583 gettext_noop("Sets the display format for interval values."), |
| 258 | +4584 NULL, |
| 259 | +4585 GUC_REPORT |
| 260 | +4586 }, |
| 261 | +4587 &IntervalStyle, |
| 262 | +4588 INTSTYLE_POSTGRES, intervalstyle_options, |
| 263 | +4589 NULL, NULL, NULL |
| 264 | +4590 }, |
| 265 | +``` |
| 266 | + |
| 267 | + |
| 268 | + |
| 269 | + |
| 270 | +#### [PostgreSQL 许愿链接](https://github.com/digoal/blog/issues/76 "269ac3d1c492e938c0191101c7238216") |
| 271 | +您的愿望将传达给PG kernel hacker、数据库厂商等, 帮助提高数据库产品质量和功能, 说不定下一个PG版本就有您提出的功能点. 针对非常好的提议,奖励限量版PG文化衫、纪念品、贴纸、PG热门书籍等,奖品丰富,快来许愿。[开不开森](https://github.com/digoal/blog/issues/76 "269ac3d1c492e938c0191101c7238216"). |
| 272 | + |
| 273 | + |
| 274 | +#### [9.9元购买3个月阿里云RDS PostgreSQL实例](https://www.aliyun.com/database/postgresqlactivity "57258f76c37864c6e6d23383d05714ea") |
| 275 | + |
| 276 | + |
| 277 | +#### [PostgreSQL 解决方案集合](https://yq.aliyun.com/topic/118 "40cff096e9ed7122c512b35d8561d9c8") |
| 278 | + |
| 279 | + |
| 280 | +#### [德哥 / digoal's github - 公益是一辈子的事.](https://github.com/digoal/blog/blob/master/README.md "22709685feb7cab07d30f30387f0a9ae") |
| 281 | + |
| 282 | + |
| 283 | + |
| 284 | + |
0 commit comments