README 10 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300
  1. Erlang PostgreSQL Database Client
  2. Asynchronous fork of https://github.com/wg/epgsql
  3. * Motivation
  4. When you need to execute several queries, it involves a number network
  5. round-trips between the application and the database.
  6. The PostgreSQL frontend/backend protocol supports request pipelining.
  7. This means that you don't need to wait for the previous command to finish
  8. before sending the next command. This version of the driver makes full use
  9. of the protocol feature that allows faster execution.
  10. * Difference highlights
  11. + 3 API sets: pgsql, apgsql and ipgsql:
  12. pgsql maintains backwards compatibility with the original driver API,
  13. apgsql delivers complete results as regular erlang messages,
  14. ipgsql delivers results as messages incrementally (row by row)
  15. + internal queue of client requests, so you don't need to wait for the
  16. response to send the next request
  17. + single process to hold driver state and receive socket data
  18. + execution of several parsed statements as a batch
  19. + binding timestamps in erlang:now() format
  20. see CHANGES for full list.
  21. * Known problems
  22. A timeout supplied at connect time works as a socket connect timeout,
  23. not a query timeout. It passes all tests from original driver except for
  24. the 3 failing timeout tests.
  25. SSL performance can degrade if the driver process has a large inbox
  26. (thousands of messages).
  27. Usage of unnamed prepared statement and portals leads to unpredicted results
  28. in case of concurrent access to same connection.
  29. * Connect
  30. {ok, C} = pgsql:connect(Host, [Username], [Password], Opts).
  31. Host - host to connect to.
  32. Username - username to connect as, defaults to $USER.
  33. Password - optional password to authenticate with.
  34. Opts - property list of extra options. Supported properties:
  35. + {database, String}
  36. + {port, Integer}
  37. + {ssl, Atom} true | false | required
  38. + {ssl_opts, List} see ssl application docs in OTP
  39. + {timeout, Integer} milliseconds, defaults to 5000
  40. + {async, Pid} see Server Notifications section
  41. {ok, C} = pgsql:connect("localhost", "username", [{database, "test_db"}]).
  42. ok = pgsql:close(C).
  43. The timeout parameter will trigger an {error, timeout} result when the
  44. socket fails to connect within Timeout milliseconds.
  45. Asynchronous connect example (applies to ipgsql too):
  46. {ok, C} = apgsql:start_link(),
  47. Ref = apgsql:connect(C, "localhost", "username", [{database, "test_db"}]),
  48. receive
  49. {C, Ref, connected} ->
  50. {ok, C};
  51. {C, Ref, Error = {error, _}} ->
  52. Error;
  53. {'EXIT', C, _Reason} ->
  54. {error, closed}
  55. end.
  56. * Simple Query
  57. {ok, Columns, Rows} = pgsql:squery(C, "select ...").
  58. {ok, Count} = pgsql:squery(C, "update ...").
  59. {ok, Count, Columns, Rows} = pgsql:squery(C, "insert ... returning ...").
  60. {error, Error} = pgsql:squery(C, "invalid SQL").
  61. Columns - list of column records, see pgsql.hrl for definition.
  62. Rows - list of tuples, one for each row.
  63. Count - integer count of rows inserted/updated/etc
  64. The simple query protocol returns all columns as text (Erlang binaries)
  65. and does not support binding parameters.
  66. Several queries separated by semicolon can be executed by squery.
  67. [{ok, _, [{<<"1">>}]}, {ok, _, [{<<"2">>}]}] =
  68. pgsql:squery(C, "select 1; select 2").
  69. apgsql:squery returns result as a single message:
  70. Ref = apgsql:squery(C, Sql),
  71. receive
  72. {C, Ref, Result} -> Result
  73. end.
  74. Result has same format as return value of pgsql:squery.
  75. ipgsql:squery returns results incrementally for each query inside Sql and
  76. for each row:
  77. Ref = ipgsql:squery(C, Sql),
  78. receive
  79. {C, Ref, {columns, Columns}} ->
  80. %% columns description
  81. Columns;
  82. {C, Ref, {data, Row}} ->
  83. %% single data row
  84. Row;
  85. {C, Ref, {error, _E} = Error} ->
  86. Error;
  87. {C, Ref, {complete, {_Type, Count}}} ->
  88. %% execution of one insert/update/delete has finished
  89. {ok, Count}; % affected rows count
  90. {C, Ref, {complete, _Type}} ->
  91. %% execution of one select has finished
  92. ok;
  93. {C, Ref, done} ->
  94. %% execution of all queries from Sql has finished
  95. done;
  96. end.
  97. * Extended Query
  98. {ok, Columns, Rows} = pgsql:equery(C, "select ...", [Parameters]).
  99. {ok, Count} = pgsql:equery(C, "update ...", [Parameters]).
  100. {ok, Count, Columns, Rows} = pgsql:equery(C, "insert ... returning ...", [Parameters]).
  101. {error, Error} = pgsql:equery(C, "invalid SQL", [Parameters]).
  102. Parameters - optional list of values to be bound to $1, $2, $3, etc.
  103. The extended query protocol combines parse, bind, and execute using
  104. the unnamed prepared statement and portal. A "select" statement returns
  105. {ok, Columns, Rows}, "insert/update/delete" returns {ok, Count} or
  106. {ok, Count, Columns, Rows} when a "returning" clause is present. When
  107. an error occurs, all statements result in {error, #error{}}.
  108. PostgreSQL's binary format is used to return integers as Erlang
  109. integers, floats as floats, bytea/text/varchar columns as binaries,
  110. bools as true/false, etc. For details see pgsql_binary.erl and the
  111. Data Representation section below.
  112. Asynchronous api equery requires you to parse statement beforehand
  113. Ref = apgsql:equery(C, Statement, [Parameters]),
  114. receive
  115. {C, Ref, Res} -> Res
  116. end.
  117. Statement - parsed statement (see parse below)
  118. Res has same format as return value of pgsql:equery.
  119. ipgsql:equery(C, Statement, [Parameters]) sends same set of messages as
  120. squery including final {C, Ref, done}.
  121. * Parse/Bind/Execute
  122. {ok, Statement} = pgsql:parse(C, [StatementName], Sql, [ParameterTypes]).
  123. StatementName - optional, reusable, name for the prepared statement.
  124. ParameterTypes - optional list of PostgreSQL types for each parameter.
  125. For valid type names see pgsql_types.erl.
  126. apgsql:parse sends {C, Ref, {ok, Statement} | {error, Reason}}.
  127. ipgsql:parse sends:
  128. {C, Ref, {types, Types}}
  129. {C, Ref, {columns, Columns}}
  130. {C, Ref, no_data} if statement will not return rows
  131. {C, Ref, {error, Reason}}
  132. ok = pgsql:bind(C, Statement, [PortalName], ParameterValues).
  133. PortalName - optional name for the result portal.
  134. both apgsql:bind and ipgsql:bind send {C, Ref, ok | {error, Reason}}
  135. {ok | partial, Rows} = pgsql:execute(C, Statement, [PortalName], [MaxRows]).
  136. {ok, Count} = pgsql:execute(C, Statement, [PortalName]).
  137. {ok, Count, Rows} = pgsql:execute(C, Statement, [PortalName]).
  138. PortalName - optional portal name used in bind/4.
  139. MaxRows - maximum number of rows to return (0 for all rows).
  140. execute returns {partial, Rows} when more rows are available.
  141. apgsql:execute sends {C, Ref, Result} where Result has same format as
  142. return value of pgsql:execute.
  143. ipgsql:execute sends
  144. {C, Ref, {data, Row}}
  145. {C, Ref, {error, Reason}}
  146. {C, Ref, suspended} partial result was sent, more rows are available
  147. {C, Ref, {complete, {_Type, Count}}}
  148. {C, Ref, {complete, _Type}}
  149. ok = pgsql:close(C, Statement).
  150. ok = pgsql:close(C, statement | portal, Name).
  151. ok = pgsql:sync(C).
  152. All pgsql functions return {error, Error} when an error occurs.
  153. apgsql and ipgsql close and sync functions send {C, Ref, ok}.
  154. * Batch execution
  155. Batch execution is bind + execute for several prepared statements.
  156. It uses unnamed portals and MaxRows = 0.
  157. Results = pgsql:execute_batch(C, Batch).
  158. Batch - list of {Statement, ParameterValues}
  159. Results - list of {ok, Count} or {ok, Count, Rows}
  160. Example
  161. {ok, S1} = pgsql:parse(C, "one", "select $1", [int4]),
  162. {ok, S2} = pgsql:parse(C, "two", "select $1 + $2", [int4, int4]),
  163. [{ok, [{1}]}, {ok, [{3}]}] =
  164. pgsql:execute_batch(C, [{S1, [1]}, {S2, [1, 2]}]).
  165. apgsql:execute_batch sends {C, Ref, Results}
  166. ipgsql:execute_batch sends
  167. {C, Ref, {data, Row}}
  168. {C, Ref, {error, Reason}}
  169. {C, Ref, {complete, {_Type, Count}}}
  170. {C, Ref, {complete, _Type}}
  171. {C, Ref, done} - execution of all queries from Batch has finished
  172. * Data Representation
  173. null = null
  174. bool = true | false
  175. char = $A | binary
  176. intX = 1
  177. floatX = 1.0
  178. date = {Year, Month, Day}
  179. time = {Hour, Minute, Second.Microsecond}
  180. timetz = {time, Timezone}
  181. timestamp = {date, time}
  182. timestamptz = {date, time}
  183. interval = {time, Days, Months}
  184. text = <<"a">>
  185. varchar = <<"a">>
  186. bytea = <<1, 2>>
  187. array = [1, 2, 3]
  188. record = {int2, time, text, ...} (decode only)
  189. timestamp and timestamptz parameters can take erlang:now() format {MegaSeconds, Seconds, MicroSeconds}
  190. * Errors
  191. Errors originating from the PostgreSQL backend are returned as {error, #error{}},
  192. see pgsql.hrl for the record definition. epgsql functions may also return
  193. {error, What} where What is one of the following:
  194. {unsupported_auth_method, Method} - required auth method is unsupported
  195. timeout - request timed out
  196. closed - connection was closed
  197. sync_required - error occured and pgsql:sync must be called
  198. * Server Notifications
  199. PostgreSQL may deliver two types of asynchronous message: "notices" in response
  200. to notice and warning messages generated by the server, and "notifications" which
  201. are generated by the LISTEN/NOTIFY mechanism.
  202. Passing the {async, Pid} option to pgsql:connect will result in these async
  203. messages being sent to the specified process, otherwise they will be dropped.
  204. Message formats:
  205. {pgsql, Connection, {notification, Channel, Pid, Payload}}
  206. Connection - connection the notification occurred on
  207. Channel - channel the notification occurred on
  208. Pid - database session pid that sent notification
  209. Payload - optional payload, only available from PostgreSQL >= 9.0
  210. {pgsql, Connection, {notice, Error}}
  211. Connection - connection the notice occurred on
  212. Error - an #error{} record, see pgsql.hrl
  213. * Mailing list
  214. https://groups.google.com/forum/#!forum/epgsql