Git Product home page Git Product logo

pgmoon's Introduction

pgmoon

test

Note: Have you updated from an older version of OpenResty? You must update to pgmoon 1.12 or above, due to a change in Lua pattern compatibility to avoid incorrect results from queries that return affected rows.

pgmoon is a PostgreSQL client library written in pure Lua (MoonScript).

pgmoon was originally designed for use in OpenResty to take advantage of the cosocket api to provide asynchronous queries but it also works in the regular any Lua environment where LuaSocket or cqueues is available.

It's a perfect candidate for running your queries both inside OpenResty's environment and on the command line (eg. tests) in web frameworks like Lapis.

Install

$ luarocks install pgmoon
Using OpenResty's OPM
$ opm get leafo/pgmoon

Dependencies

pgmoon supports a wide range of environments and libraries, so it may be necessary to install additional dependencies depending on how you intend to communicate with the database:

Tip: If you're using OpenResty then no additional dependencies are needed (generally, a crypto library may be necessary for some authentication methods)

A socket implementation is required to use pgmoon, depending on the environment you can chose one:

  • OpenResty — The built in socket is used, no additional dependencies necessary
  • LuaSocketluarocks install luasocket
  • cqueuesluarocks install cqueues

If you're on PUC Lua 5.1 or 5.2 then you will need a bit libray (not needed for LuaJIT):

$ luarocks install luabitop

If you want to use JSON types you will need lua-cjson

$ luarocks install lua-cjson

SSL connections may require an additional dependency:

  • OpenResty — luarocks install lua-resty-openssl
  • LuaSocket — luarocks install luasec
  • cqueues — luarocks install luaossl

Password authentication may require a crypto library, luaossl.

$ luarocks install luaossl

Note: LuaCrypto can be used as a fallback, but the library is abandoned and not recommended for use

Note: Use within OpenResty will prioritize built in functions if possible

Parsing complex types like Arrays and HStore requires lpeg to be installed.

Example

local pgmoon = require("pgmoon")
local pg = pgmoon.new({
  host = "127.0.0.1",
  port = "5432",
  database = "mydb",
  user = "postgres"
})

assert(pg:connect())

local res = assert(pg:query("select * from users where status = 'active' limit 20")

assert(pg:query("update users set name = $1 where id = $2", "leafo", 99))

If you are using OpenResty you can relinquish the socket to the connection pool after you are done with it so it can be reused in future requests:

pg:keepalive()

Considerations

PostgreSQL allows for results to use the same field name multiple times. Because results are extracted into Lua tables, repeated fields will be overwritten and previous values will be unavailable:

pg:query("select 1 as dog, 'hello' as dog") --> { { dog = "hello" } }

There is currently no way around this limitation. If this is something you need then open an issue.

Reference

Functions in table returned by require("pgmoon"):

new(options={})

Creates a new Postgres object from a configuration object. All fields are optional unless otherwise stated. The newly created object will not automatically connect, you must call conect after creating the object.

Available options:

  • "database": the database name to connect to required
  • "host": the host to connect to (default: "127.0.0.1")
  • "port": the port to connect to (default: "5432")
  • "user": the database username to authenticate (default: "postgres")
  • "password": password for authentication, may be required depending on server configuration
  • "ssl": enable ssl (default: false)
  • "ssl_verify": verify server certificate (default: nil)
  • "ssl_required": abort the connection if the server does not support SSL connections (default: nil)
  • "socket_type": the type of socket to use, one of: "nginx", "luasocket", cqueues (default: "nginx" if in nginx, "luasocket" otherwise)
  • "application_name": set the name of the connection as displayed in pg_stat_activity. (default: "pgmoon")
  • "pool": (OpenResty only) name of pool to use when using OpenResty cosocket (default: "#{host}:#{port}:#{database}")
  • "pool_size": (OpenResty only) Passed directly to OpenResty cosocket connect function, see docs
  • "backlog": (OpenResty only) Passed directly to OpenResty cosocket connect function, see docs
  • "cqueues_openssl_context": Manually created opensssl.ssl.context to use when created cqueues SSL connections
  • "luasec_opts": Manually created options object to use when using LuaSec SSL connections

Methods on the Postgres object returned by new:

postgres:connect()

local success, err = postgres:connect()

Connects to the Postgres server using the credentials specified in the call to new. On success returns true, on failure returns nil and the error message.

postgres:settimeout(time)

postgres:settimeout(5000) -- 5 second timeout

Sets the timeout value (in milliseconds) for all subsequent socket operations (connect, write, receive). This function does not have any return values.

The default timeout depends on the underslying socket implementation but generally corresponds to no timeout.

postgres:disconnect()

local success, err = postgres:disconnect()

Closes the socket. Returns nil if the socket couldn't be closed. On most socket types, connect can be called again to reestaablish a connection with the same postgres object instance.

postgres:keepalive(...)

postgres:keepalive()

Relinquishes socket to OpenResty socket pool via the setkeepalive method. Any arguments passed here are also passed to setkeepalive. After calling this method, the socket is no longer available for queries and should be considered disconnected.

Note: This method only works within OpenResty using the nginx cosocket API

postgres:query(query_string, ...)

-- return values for successful query
local result, err, num_queries = postgres:query("select name from users limit 2")

-- return value for failure (status is nil)
local status, err, partial_result, num_queries = postgres:query("select created_at from tags; select throw_error() from users")

Sends a query (or multiple queries) to the server. On failure the first return value is nil, followed by a string describing the error. Since a single call to postgres:query can contain multiple queries, the results of any queries that succeeded before the error occurred are returned after the error message. (Note: queries are atomic, they either succeed or fail. The partial result will only contain succeed queries, not partially data from the failed query)

Additional return values: notifications and notices

In addition to the return values above, pgmoon will also return two additional values if the query generates them, notifications an notices.

local result, err, num_queries, notifications, notices  = postgres:query("drop table if exists some_table")

In this example, if the table some_table does not exist, then notices will be an array containing a message that the table didn't exist.


The query function has two modes of operation which correspond to the two protocols the Postgres server provides for sending queries to the database server:

  • Simple protocol: you only pass in a single argument, the query string
  • Extended protocol: you pass in a query with parameter placeholders ($1, $2, etc.) and then pass in additional arguments which will be used as values for the placeholders

See Extended and simple query protocol for more information about the differences and trade-offs.

On success, the result returned depends on the kind of query sent:

SELECT queries, INSERT with returning, or anything else that returns a result set will return an array table of results. Each result is a hash table where the key is the name of the column and the value is the result for that row of the result.

local res = pg:query("select id, name from users")

Might return:

{
  {
    id = 123,
    name = "Leafo"
  },
  {
    id = 234,
    name = "Lee"
  }
}

Any queries that affect rows like UPDATE, DELETE, or INSERT return a table result with the affected_rows field set to the number of rows affected.

local res = pg:query("delete from users")

Might return:

{
  affected_rows = 2
}

Any queries with no result set or updated rows will return true.

When using the simple protocol (calling the function with a single string), you can send multiple queries at once by separating them with a ;. The number of queries executed is returned as a second return value after the result object. When more than one query is executed then the result object changes slightly. It becomes a array table holding all the individual results:

local res, num_queries = pg:query([[
  select id, name from users;
  select id, title from posts
]])

Might return:

num_queries = 2

res = {
  {
    {
      id = 123,
      name = "Leafo"
    },
    {
      id = 234,
      name = "Lee"
    }
  },
  {
    {
      id = 546,
      title = "My first post"
    }
  }
}

Similarly for queries that return affected rows or just true, they will be wrapped up in an addition array table when there are multiple of them. You can also mix the different query types as you see fit.

postgres:escape_literal(val)

local sql_fragment = postgres:escape_literal(val)

local res = postgres:query("select created_at from users where id = " .. sql_fragment)

Escapes a Lua value int a valid SQL fragment that can be safely concatenated into a query string. Never concatenate a variable into query without escaping it in some way, or you may open yourself up to SQL injection attacks.

This function is aware of the following Lua value types:

  • type(val) == "number"escape_literal(5.5) --> 5.5
  • type(val) == "string"escape_literal("your's") --> 'your''s'
  • type(val) == "boolean"escape_literal(true) --> TRUE
  • val == pgmoon.NULLescape_literal(pgmoon.NULL) --> NULL

Any other type will throw a hard error, to ensure that you provide a value that is safe for escaping.

postgres:escape_identifier(val)

local sql_fragment = postgres:escape_identifier(some_table_name)`

local res = postgres:query("select * from " .. sql_fragment .. " limit 20)

Escapes a Lua value for use as a Postgres identifier. This includes things like table or column names. This does not include regular values, you should use escape_literal for that. Identifier escaping is required when names collide with built in language keywords.

The argument, val, must be a string.

tostring(postgres)

print(tostring(postgres)) --> "<Postgres socket: 0xffffff>"

Returns string representation of current state of Postgres object.

Extended and simple query protocols

pgmoon will issue your query to the database server using either the simple or extended protocol depending if you provide parameters and parameter placeholders in your query. The simple protocol is used for when your query is just a string, and the extended protocol is used when you provide addition parameters as arguments to the query method.

The protocols have some trade-offs and differences:

Extended protocol

local res, err = postgres:query("select name from users where id = $1 and status = $2", 12, "ready")
  • Advantage: Parameters can be included in query without risk of SQL injection attacks, no need to escape values and interpolate strings
  • Advantage: Supports the pgmoon_serialize method to allow for custom types to be automatically serialized into parameters for the query
  • Disadvantage: Only a single query can be sent a time
  • Disadvantage: Substantially more overhead per query. A no-op query may be 50% to 100% slower. (note that this overhead may be negligible depending on the runtime of the query itself)
  • Disadvantage: Some kinds of query syntax are not compatible with parameters (eg. where id in (...), dynamic expressions), so you may still need to use string interpolation and assume the associated risks

Simple protocol

local res, err = postgres:query("select name from users where id = " .. postgres:escape_literal(12) .." and status = " .. postgres:escape_literal("ready"))
  • Advantage: Higher performance. Low overhead per query means more queries can be sent per second, even when manually escaping and interpolating parameters
  • Advantage: Multiple queries can be sent in a single request (separated by ;)
  • Disadvantage: Any parameters to the query must be manually escaped and interpolated into the query string. This can be error prone and introduce SQL injection attacks if not done correctly

Note: The extended protocol also supports binary encoding of parameter values & results, but since Lua treats binary as strings, it's generally going to be faster to just consume the string values from Postgres rather than using the binary protocol which will require binary to string conversion within Lua.

SSL connections

pgmoon can establish an SSL connection to a Postgres server. It can also refuse to connect to it if the server does not support SSL. Just as pgmoon depends on LuaSocket for usage outside of OpenResty, it depends on luaossl/LuaSec for SSL connections in such contexts.

local pgmoon = require("pgmoon")
local pg = pgmoon.new({
  host = "127.0.0.1",
  ssl = true, -- enable SSL
  ssl_verify = true, -- verify server certificate
  ssl_required = true, -- abort if the server does not support SSL connections
  ssl_version = "tlsv1_2", -- e.g., defaults to highest available, no less than TLS v1.1
  cafile = "...", -- certificate authority (LuaSec only)
  cert = "...", -- client certificate
  key = "...", -- client key
})

assert(pg:connect())

Note: In Postgres 12 and above, the minium SSL version accepted by client connections is 1.2. When using LuaSocket + LuaSec to connect to an SSL server, if you don't specify an ssl_version then tlsv1_2 is used.

In OpenResty, make sure to configure the lua_ssl_trusted_certificate directive if you wish to verify the server certificate.

Authentication types

Postgres has a handful of authentication types. pgmoon currently supports trust, peer and password authentication with scram-sha-256-auth or md5.

Type conversion

Postgres has a very rich set of types built in. pgmoon will do its best to convert any Postgres types into the appropriate Lua type.

All integer, floating point, and numeric types are converted into Lua's number type. The boolean type is converted into a Lua boolean. The JSON type is decoded into a Lua table using Lua CJSON. Lua tables can be encoded to JSON as described below.

Any array types are automatically converted to Lua array tables. If you need to encode an array in Lua to Postgres' array syntax you can use the pgmoon.arrays module. See below.

Any other types are returned as Lua strings.

Handling arrays

Arrays are automatically deserialized into a Lua object when they are returned from a query. Numeric, string, and boolean types are automatically loaded accordingly. Nested arrays are also supported.

Use encode_array to encode a Lua table to array syntax for a query:

local pgmoon = require("pgmoon")
local pg = pgmoon.new(auth)
pg:connect()

local encode_array = require("pgmoon.arrays").encode_array
local my_array = {1,2,3,4,5}
pg:query("insert into some_table (some_arr_col) values(" .. encode_array(my_array) .. ")")

Arrays that are returned from queries have their metatable configured for the PostgresArray type (defined in require("pgmoon.arrays")).

Extended protocol

When using the extended query protocol (query with parameters), an array object created with PostgresArray will automatically be serialized when passed as a parameter.

local PostgresArray = require("pgmoon.arrays").PostgresArray

postgres:query("update user set tags = $1 where id = 44", PostgresArray({1,2,4}))

Keep in mind that calling PostgresArray mutate the argument by setting its metatable. Make a copy first if you don't want the original object to be mutated.

Additionally, array types must contain values of only the same type. No run-time checking is performed on the object you pass. The type OID is determined from the first entry of the array.

Empty Arrays

When trying to encode an empty array an error will be thrown. Postgres requires a type when using an array. When there are values in the array Postgres can infer the type, but with no values in the array no type can be inferred. This is illustrated in the erorr provided by Postgres:

postgres=# select ARRAY[];
ERROR:  cannot determine type of empty array
LINE 1: select ARRAY[];
               ^
HINT:  Explicitly cast to the desired type, for example ARRAY[]::integer[].

You can work around this error by always including a typecast with any value you use, to allow you to pass in an empty array and continue to work with an array of values assuming the types match.

local empty_tags = {}
pg:query("update posts set tags = " .. encode_array(empty_tags) .. "::text[]")

Handling JSON

json and jsonb values are automatically decoded as Lua tables in a query result (using the cjson library if available).

To send JSON in a query you must first convert it into a string literal, then interpolate it into your query. Ensure that you treat it like any other paramter, and call escape_literal on the string to make it suitable to be safely parsed as a value to PostgreSQL.

local pgmoon = require("pgmoon")
local pg = pgmoon.new(auth)
assert(pg:connect())

local my_tbl = { hello = "world" }

local json = require "cjson"

pg:query("update my_table set data = " .. db.escape_literal(json.encode(my_tbl)) .. " where id = 124"

Handling hstore

Because hstore is an extension type, a query is reuired to find out the type id before pgmoon can automatically decode it. Call the setup_hstore method on your connection object after connecting to set it up.

local pgmoon = require("pgmoon")
local pg = pgmoon.new(auth)
pg:connect()
pg:setup_hstore()

Use encode_hstore to encode a Lua table into hstore syntax suitable for interpolating into a query.

Note: The result of encode_hstore is a valid Postgres SQL fragment, it is not necessary to call escape_literal on it. It can safely be inserted directly into the query

local encode_hstore = require("pgmoon.hstore").encode_hstore
local tbl = {foo = "bar"}
pg:query("insert into some_table (hstore_col) values(" .. encode_hstore(tbl) .. ")")

You can manually decode a hstore value from string using the decode_hstore function. This is only required if you didn't call setup_hstore.

local decode_hstore = require("pgmoon.hstore").decode_hstore
local res = pg:query("select * from some_table")
local hstore_tbl = decode_hstore(res[1].hstore_col)

Custom type deserializer

PostgreSQL has a rich set of types. When reading a query's results pgmoon must attempt to interpret the types from postgres and map them to something usable in Lua. By default implementations are included for primitives like numbers, booleans, strings, and JSON.

You can provie you own type deserializer if you want to add custom behavior for certain types of values returned by PostgreSQL.

You must have some knowledge of types and type OIDs. Every type in PostgreSQL is stored in the pg_type catalog table. Each type has an OID (stored as a 32 bit positive integer) to uniquely identify it. The core types provided by Postgres have fixed type OIDs (for example, boolean is always 16), but third-party types may be added without fixed OIDs.

Also note that any composite versions of existing types have their own OID, for example, while a single boolean value has type OID 16, an array of boolean values has type OID 1000. Arrays are homogeneous and must contain the same type for every value.

Adding support for a new type in pgmoon can be done using the set_type_deserializer(oid, type_name, [deserializer]) method:

local pgmoon = require("pgmoon")
local pg = pgmoon.new(config)

-- in this example we create a new deserializer called bignumber and provide
-- the function to deserialize (type OID 20 is an 8 byte integer)
pg:set_type_deserializer(20, "bignumber", function(val)
    return "HUGENUMBER:" .. val
end)

-- in this example we point another OID to the "bignumber" deserializer we
-- provided above (type OID 701 is a 8 byte floating point number)
pg:set_type_deserializer(701, "bignumber")

The arguments are as follows:

  • oid The OID from pg_type that will be handled
  • name The local name of the type. This is a name that points to an existing deserializer or will be used to register a new one if the deserializer argument is
  • deserializer A function that takes the raw string value from Postgres and converts it into something more useful (optional). Any existing deserializer function with the same name will be overwritten

Custom type serializer

When using the query method with params, (aka the extended query protocol), and values passed into parameters must be serialized into a string version of that value and a type OID.

pgmoon provides implementations for Lua's basic types: string, boolean, numbers, and postgres.NULL for the NULL value.

If you want to support custom types, like JSON, then you will need to provide your own serializer.

Serializing vs escaping: pgmoon has two methods for preparing data to be sent in a query. Escaping is used when you want to turn some value into a SQL fragment that can be safely concatenated into a query. This is done with postgres:escape_literal() and is suitable for use with the simple query protocol. Serializing, on the other hand, is used to convert a value into a string representation that can be parsed by Postgres as a value when using the extended query protocol. As an example, an escaped string would be 'hello' (notice the quotes, this is a fragment of valid SQL syntax, whereas a serialized string would be just the string: hello (and typically paired with a type OID, typically 25 for text). Serializing is the oposite of deserializing, which is described above.

Note: Serializing is NOT the same as escaping. You can not take a serialized value and concatenate it directly into your query. You may, however, take a serialized value and escape it as a string, then attempt to cast it to the appropriate type within your query.

To provide your own serializer for an object, you can add a method on the metatable called pgmoon_serialize. This method takes two arguments, the value to be serialized and the current instance of Postgres that is doing the serialization. The method should return two values: the type OID as an integer, and the string representation of that value.

Note: The type OID 0 can be used for "unknown", and Postgres will try to infer the type of the value based on the context. If possible you should always try to provide a specific type OID.

-- this metatable will enable an object to be serialized as json for use as a
-- parameter in postgres:query()
local json_mt = {
  pgmoon_serialize = function(v)
    local cjson = require("cjson")
    return 114, cjson.encode(v) -- 114 is oid from pg_type catalog
  end
}

local data = {
  age = 200,
  color = "blue",
  tags = {"one", "two"}
}

postgres:query("update user set data = $1 where id = 233", setmetatable(data, json_mt))

The pgmoon_serialize method can also return nil and an error message to abort serialization. This will block the query from running at all, and the error will be returned from the postgres:query() method.

Note: Postgres supports a binary representation for values when using the extended query protocol, but at this time pgmoon does not support it.

Converting NULLs

By default NULLs in Postgres are converted to nil, meaning they aren't visible in the resulting tables. If you want to convert NULLs to some visible value set convert_null to true on the Postgres object and the postgres.NULL object will be used to represent NULL.

local pgmoon = require("pgmoon")
local config = {
  database = "my_database",
  convert_null = true
}

local postgres = pgmoon.new(config)
assert(postgres:connect())

local res = postgres:query("select NULL the_null")
assert(postgres.NULL == res[1].the_null)

As shown above, the NULL value is set to postgres.NULL. It's possible to change this value to make pgmoon use something else as NULL. For example if you're using OpenResty you might want to reuse ngx.null.

Also note that you can use postgres.NULL as an extended query parameter or inside escape_literal to generate the value for NULL.

Contact

Author: Leaf Corcoran (leafo) (@moonscript) Email: [email protected] Homepage: http://leafo.net

Changelog

Note: Future changenotes will be published on GitHub releases page: https://github.com/leafo/pgmoon/releases

  • 1.15.0 — 2022-6-3 - Extended query protocol
  • 1.14.0 — 2022-2-17 - OpenResty crypto functions used, better empty array support,
  • 1.13.0 — 2021-10-13 - Add support for scram_sha_256_auth (@murillopaula), 'backlog' and 'pool_size' options while using ngx.socket (@xiaocang), update LuaSec ssl_protocol default options (@jeremymv2), application_name option (@mecampbellsoup)
  • 1.12.0 — 2021-01-06 - Lua pattern compatibility fix, Support for Lua 5.1 through 5.4 (@jprjr). Fix bug where SSL vesrion was not being passed. Default to TLS v1.2 when using LuaSec. Luabitop is no longer automatically installed as a dependency. New test suite.
  • 1.11.0 — 2020-03-26 - Allow for TLS v1.2 when using LuaSec (Miles Elam)
  • 1.10.0 — 2019-04-15 - Support luaossl for crypto functions, added better error when missing crypto library
  • 1.9.0 — 2018-04-02 - nginx pool name includes user, connection reports name as pgmoon
  • 1.8.0 — 2016-11-07 — Add cqueues support, SSL calling fix for Nginx cosocket (@thibaultCha)
  • 1.7.0 — 2016-09-21 — Add to opm, add support for openresty pool, better default pool, support for hstore (@edan)
  • 1.6.0 — 2016-07-21 — Add support for json and jsonb array decoding
  • 1.5.0 — 2016-07-12 — Add SSL support (@thibaultCha), Add UUID array type (@edan), Add support for notifications (@starius)
  • 1.4.0 — 2016-02-18 — Add support for decoding jsonb, add a json serializer (@thibaultCha)
  • 1.3.0 — 2016-02-11 — Fix bug parsing a string that looked like a number failed, add support for using in ngx when in init context (@thibaultCha), add cleartext password auth, fix warning with md5 auth
  • 1.2.0 — 2015-07-10 — Add support for PostgreSQL Arrays
  • 1.1.1 — 2014-08-12 — Fix a bug with md5 auth
  • 1.1.0 — 2014-05-21 — Add support for multiple queries in one call
  • 1.0.0 — 2014-05-19 — Initial release

License (MIT)

Copyright (C) 2021 by Leaf Corcoran

Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge, publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so, subject to the following conditions:

The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software.

THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE.

pgmoon's People

Contributors

agentzh avatar bungle avatar edan avatar fale avatar jprjr avatar leafo avatar lhelsloot avatar mecampbellsoup avatar pygy avatar sanderhahn avatar spacewander avatar starius avatar thibaultcha avatar ttfkam avatar

Stargazers

 avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar

Watchers

 avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar

pgmoon's Issues

error when out of memory

When my server‘s memory is exhausted, pgmoon report below errors:
attempt to get length of local 'err_msg' (a nil value)

2018/08/09 16:15:33 [error] 15433#15433: *9161 recv() failed (104: Connection reset by peer), client: 127.0.0.1, server: localhost, request: "POST /api/test HTTP/1.0", host: "xxx.com"
2018/08/09 16:15:33 [error] 15433#15433: *9161 lua entry thread aborted: runtime error: /usr/local/openresty/site/lualib/pgmoon/init.lua:390: attempt to get length of local 'err_msg' (a nil value)
stack traceback:
coroutine 0:
/usr/local/openresty/site/lualib/pgmoon/init.lua: in function 'parse_error'
/usr/local/openresty/site/lualib/pgmoon/init.lua:243: in function 'auth'
/usr/local/openresty/site/lualib/pgmoon/init.lua:211: in function 'connect'

Default pg_hba.conf settings do not work

The default (at least on Fedora 23) settings for pg_hba.conf do not work with pgmoon.

# TYPE  DATABASE        USER            ADDRESS                 METHOD
# "local" is for Unix domain socket connections only
local   all             all                                     peer
# IPv4 local connections:
host    all             all             127.0.0.1/32            ident
# IPv6 local connections:
host    all             all             ::1/128                 ident

had to be set to:

# TYPE  DATABASE        USER            ADDRESS                 METHOD
# "local" is for Unix domain socket connections only
local   all             all                                     trust
# IPv4 local connections:
host    all             all             127.0.0.1/32            trust
# IPv6 local connections:
host    all             all             ::1/128                 trust

opm get version is 1.7.0

I see version 1.8.0 in main branch, but I use opm get that is version 1.7.0, is it the latest stable version?

Installing with luarocks

Warning: Failed searching manifest: Failed extracting manifest file
Installing https://raw.githubusercontent.com/rocks-moonscript-org/moonrocks-mirror/master/pgmoon-1.2.0-1.src.rock...
Using https://raw.githubusercontent.com/rocks-moonscript-org/moonrocks-mirror/master/pgmoon-1.2.0-1.src.rock... switching to 'build' mode

Error: Failed unpacking rock file: /tmp/luarocks_luarocks-rock-pgmoon-1.2.0-1-9138/pgmoon-1.2.0-1.src.rock

Apologies i'm new to lua, so this may be some other issue. But any help would be great.

Pgmoon should specify a default connection pool name with the Pg database name

Pgmoon should add the Pg database name to the default connection pool name, just like the lua-resty-mysql library:

https://github.com/openresty/lua-resty-mysql/blob/master/lib/resty/mysql.lua#L514

Otherwise, when the app (or multiple apps) running in the same OpenResty, one app would get Pg connections associated with the wrong database (used by another app or other parts of the same app) from the shared connection pool.

pgmoon not support ARM platform

@leafo
Summary :
There is a problem found on ARM platform that is when postgres table contains the type of array, when execute SQL statement query, there is a "Error: bad light userdata pointer" error occur. I try to find the cause of the problem, it seems that the lpeg.so library not work correctly on ARM platform. in the file pgmoom/array.lua , the code as showing below, the problem occurs on the line code "local out = (assert(g:match(str), "failed to parse postgresql array"))", the invocation seems not return.

do
local P, R, S, V, Ct, C, Cs
do
local _obj_0 = require("lpeg")
P, R, S, V, Ct, C, Cs = _obj_0.P, _obj_0.R, _obj_0.S, _obj_0.V, _obj_0.Ct, _obj_0.C, _obj_0.Cs
end
local g = P({
"array",
array = Ct(V("open") * (V("value") * (P(",") * V("value")) ^ 0) ^ -1 * V("close")),
value = V("invalid_char") + V("string") + V("array") + V("literal"),
string = P('"') * Cs((P([[\]]) / [[]] + P([["]]) / [["]] + (P(1) - P('"'))) ^ 0) * P('"'),
literal = C((P(1) - S("},")) ^ 1),
invalid_char = S(" \t\r\n") / function()
return error("got unexpected whitespace")
end,
open = P("{"),
delim = P(","),
close = P("}")
})
decode_array = function(str, convert_fn)
local out = (assert(g:match(str), "failed to parse postgresql array")) --- the problem occurs on this line
setmetatable(out, PostgresArray.__base)
if convert_fn then
return convert_values(out, convert_fn)
else
return out
end
end
end

Also, the discuss of the similar problem about Openresty can see here, it maybe helpful: openresty/lua-nginx-module#1152

Any suggestion, thanks!

Performance test

I came across a blog post: http://mansion.im/2014/speed-comparison-of-postgresql-modules-for-nginx-openresty/ showing performance comparisons.

The fastest solution was ngx_postgres. My 1000 times loop took 1.3 sec.
 The second fastest solution was lua-resty-postgres which took 1.8 sec. 
And then, I tested pgmoon which took 4.4 sec. I guess it was slower because it does type conversion in Lua, although I am not sure that this is the only reason.

Have you done performance analysis?

Listen/Notify support

Hello,

Is it possible to add support for http://www.postgresql.org/docs/9.4/static/sql-listen.html ?
The use case might be:

  1. Lua/moon calls LISTEN in PostgreSQL session and register async callback written in Lua/moon
  2. Lua/Moon callback is asynchronously called as result of NOTIFY inside PostgreSQL
  3. Callback process the data, and send changes to the client via WebSocket

Thank you !

keepalive but still say too many clients already

In production, I insert 100K+items and too many clients already error happens. I want to know:

  1. Is this normal?
  2. Should I do something to the connection if errors happen? Currently, I do nothing.

Below is minimum example here . just clone it , config the database and run mkdir logs tmp && nginx -c nginx.conf -p .

pg.lua

local pg_driver = require "pgmoon"
local encode = require "cjson.safe".encode
local type = type
local tostring = tostring
local setmetatable = setmetatable
local error = error
local table_concat = table.concat
local string_format = string.format

local CONNECT_TABLE = { 
        host     = "127.0.0.1", 
        port     = 5432, 
        database = "test", 
        user     = 'postgres', 
        password = '111111', }
local CONNECT_TIMEOUT = 3000
local IDLE_TIMEOUT = 10000
local POOL_SIZE = 50

local function query(statement)
    local db, res, ok, err
    db = pg_driver.new(CONNECT_TABLE) -- always success
    db:settimeout(CONNECT_TIMEOUT) 
    res, err = db:connect()
    if not res then
        return nil, err
    end
    res, err =  db:query(statement) 
    if res ~= nil then
        ok, err = db:keepalive(IDLE_TIMEOUT, POOL_SIZE)
        if not ok then
            return nil, 'fail to set_keepalive:'..err
        end
    end
    if err then
        ngx.log(ngx.ERR, statement)
    end
    return res, err
end

local function main()
    
    local res, err = query('drop table if exists t1;create table t1(id INT PRIMARY KEY NOT NULL);')
    if err then
        return ngx.say(err)
    end
    local t = {}
    for i=1,10^4 do
        local res, err = query('insert into t1 (id) values1 (1);') -- invalid syntax to make errors
        if err then
            t[err]= (t[err] or 0) + 1
        end
    end
    ngx.say(encode(t))
end

main()

nginx

worker_processes  1;
user root root;

events {worker_connections  1024;}

http {
    lua_code_cache off;
    access_log  logs/access.log;
    error_log  logs/error.log;

    client_body_temp_path tmp/client_body_temp;
    fastcgi_temp_path tmp/fastcgi_temp;
    proxy_temp_path tmp/proxy_temp;
    scgi_temp_path tmp/scgi_temp;
    uwsgi_temp_path tmp/uwsgi_temp;
    

    
    server {
        listen       8888;
        
        location / {
            content_by_lua_file pg.lua;
        }
    }
    
}

the browser output:

{"ERROR: syntax error at or near \"values1\" (21)":9948,"FATAL: sorry, too many clients already":52}

pgmon connect 111: Connection refused

Hi,this is a connect db lua code. connect is refused , but use psql connect is worked.

 local db, err = pgsql:new({database= "mqtt",
                              host = "192.168.25.100",
                              port = "5433",
                              user = "mqtt",
                              password = "mqtt123"})
    if not db then
        ngx.say("failed to instantiate pgsql: ", err)
        return
    end
    -- db:set_timeout(conf.timeout) -- 1 sec

    -- local ok, err, errno, sqlstate = db:connect(conf.pgsql)
assert(db:connect())

at same host , I use psql connect db is worked.

psql  -U mqtt -h 192.168.25.100  -p 5433 -W
Password for user mqtt: 
psql (9.3.1, server 9.4.9)
WARNING: psql major version 9.3, server major version 9.4.
         Some psql features might not work.
Type "help" for help.

mqtt=> 

Parameterized Queries

Am I correct in seeing that pgmoon doesn't support parameterized queries?

e.g. pg:query("SELECT * FROM foo WHERE bar = ?", somevalue)

Attempting to encode an empty array results in "]"

I'm not sure if this is intentional, but encode_array simply returns "]" when the passed in table is empty, which causes an error in Postgresql.

I came across this error when trying to update a Postgresql array column in lapis:

-- ...
import array from require "lapis.db"

class Something extends Model
  some_method: =>
    @the_arr_column = array { } -- "["
    @update "the_arr_column" -- syntax error because "["

Instead, I had to do something like this:

  some_method: =>
    do_something!
    -- ...
    -- cannot do:
    -- @the_arr_column = array new_arr_column
    -- workaround: we know it's empty, but encode_array can't take empty tables.
    @the_arr_column = "{ }" if #new_arr_column == 0
    @update "the_arr_column"

Read from slave, write to master

Would it make sense to implement a feature so that a client can read from a slave node, but write to a different master node?

In a master/slave Postgres setup this would effectively cover the following use-cases:

  • High write/read throughput: splitting the read and write operations on two different nodes would avoid overloading one server, thus improve the overall performance of the system.
  • Multi-DC master/slave replication: when a master node is being replicated to multiple slaves nodes in different datacenters, the clients in those datacenters may want to perform read operations on the local slave node in the same datacenter, thus reducing network latency.

require('pgmoon') in init_by_lua_block

Hi,

I wonder if I do:

pgmoon = require('pgmoon')

in init_by_lua_block,
and then in a location handler, use content_by_lua_file with

local pg = pgmoon.new({...})
-- Do work
pg:keepalive()

Will I get the same pool shared among all workers ?

accessing function value

Hello.
First I would like to apologize for my English :)

I have an issue using this module:
when i'm trying to access stored function returning value:
local res, err = pg:query("select * from test()")
ngx.say(tostring(res))
I'm get the following result
--> table: 0x416ad5f0
how can I fix it?

regards

Support for SSL connections

I am using pgmoon in the context of a Lapis app deployed on Heroku. Postgres databases hosted by Heroku require SSL encryption for remote TCP connections.

Investigating possible fixes, I learned that ngx.socket.tcp does support SSL connections. It was used last year to add support for SSL connections in lua-resty-mysql (see here). Is this a feature that can be added to pgmoon too?

encode_array not support escape_literal

local encode_array = require("pgmoon.arrays").encode_array
local my_array = {“abcd”,“1234”}
pg:query("insert into some_table (text_array_column) values(" .. pg:escape_literal(encode_array(my_array)) .. ")")

Integer conversion problem

I got on my database the following value 1026066510839283908 however pgmoon is returning instead 1.0260665108393e+18 postgres data type for my field is int8

What could be happening?

pgmoon connect to wrong postgresql scheme which is last used when turn keepalive on

my application connects to several PostgreSQL scheme or database according to client's choice. If I used pg:keepalive() in my codes, and client visit different scheme almost at the same time, pgmoon does not switch to right scheme, still connect to last scheme.

below is some of my config(different user use differnt scheme which is decided by postgresql database):
{
"id": 1,
"host": "127.0.0.1",
"port": "5432",
"database": "mydb",
"user": "develop",
"password": "123456"
},
{
"id": 2,
"host": "127.0.0.1",
"port": "5432",
"database": "mydb",
"user": "test",
"password": "123456"
}

below is my code:

`local g_vars = require("global_vars")

local pg_conf = g_vars.get_server_unit(ngx.var.db_id)
if not pg_conf then
ngx.say([[{"return_code": -1, "error_message": "db_id is wrong"}]])
return
end

local pgmoon = require("pgmoon")
local pg = pgmoon.new(pg_conf)

if not pg:connect() then
ngx.say([[{"return_code": -2, "error_message": "fail to connect database"}]])
return
end

local result_obj = pg:query("SELECT get_classes() AS result")
pg:keepalive()

local json = require "cjson.safe"
local result_str = json.encode(result_obj[1].result)
ngx.say(result_str)`

Handle NULL in arrays.

Arrays like {NULL,"NULL"} should be handeled to `{pg.NULL, 'NULL'}.
I use yours lpeg parser with simple patch.

local literal = function(name)
  if name == 'NULL' then return NULL end
  return name
end

local g = P{"array",
....
   literal = C((P(1) - S("},")) ^ 1) / literal,
}

Test case: sql - select ARRAY[NULL,'1','NULL1','NULL',NULL,'2',NULL], result in text mode {NULL,1,NULL1,"NULL",NULL,2,NULL}

I think same cahnges need in Array building.

Jsonb support

To support JSONB (new type added in postgresql 9.4) you need to add to PG_TYPES table this value:
[3802] = "json"

Escape table

Why not try to convert lua's table into JSON object? Especially since pgmoon can deserialize data from JSON field.

Lua 5.3 support

I'm trying to run pgmoon on a Lua 5.3 installation, and I receive the following:

lua: /usr/share/lua/5.3/pgmoon/init.lua:6: module 'bit' not found:
	no field package.preload['bit']
	no file '/usr/share/lua/5.3/bit.lua'
	no file '/usr/share/lua/5.3/bit/init.lua'
	no file '/usr/lib64/lua/5.3/bit.lua'
	no file '/usr/lib64/lua/5.3/bit/init.lua'
	no file './bit.lua'
	no file './bit/init.lua'
	no file '/usr/lib64/lua/5.3/bit.so'
	no file '/usr/lib64/lua/5.3/loadall.so'
	no file './bit.so'
stack traceback:
	[C]: in function 'require'
	/usr/share/lua/5.3/pgmoon/init.lua:6: in main chunk
	[C]: in function 'require'
	pgmoon.lua:1: in main chunk
	[C]: in ?

I think the code should be tweaked to accept the external bit library (for Lua 5.1 and Lua 5.2) and the internal one for Lua 5.3

how to use bigint

I use lapis with pgmoon, and I have a table like this

create table visits (id bigint primary key, ua varchar(255));

store one record

visit = Visits\create { id: '811205756297019392', ua: ngx.var.http_user_agent }

fetch the record

v = Visits\find '811205756297019392'
print v.id -- 8.1120575629702e+17

I try same code with mysql, it's fine.

So, pgmoon is pure lua(jit), has not int64 support?

thanks.

when i select data from pg10, some column does't display

My table has three column

CREATE TABLE public.test_nextid
(
  id  serial,
  name character varying(255),
  desc character varying(255)
)

And i insert one recorder

inert into test_nextid (name) values("testname_1")

And i select all data from the table

        local sql = "select * from test_nextid"
        res,err = assert_error(db.query(sql))
        --res,err = db.select("* from test_nextid")

But there is no desc in result....
I want to see the "desc " column in the result,what should i do? thank u

pgmoon doesn't work in init_by_lua(_block)

pgmoon is able to connect fine, but sending a query results in:

init_by_lua error: /usr/local/share/lua/5.1/pgmoon/init.lua:240: attempt to call method 'send_message' (a nil value)

host cannot use hostname

cannot connect database when use hostname, such as:

local pg = pgmoon.new({
host = "server1",
port = "5432",
database = "mydb",
user = "postgres"
})

returning column problem in update or insert sql

When I run INSERT or UPDATE sql with returning some columns, the result only contains affected_rows, I cannot find returned columns in my sql.
such as:
update t1 set name='b' where id=1 returning id,name;

Error in using ssl on openresty environment

Hi, @leafo! Thanks for ur work!

Here is a little error, i've found in openresty/ssl environment:

lua entry thread aborted: runtime error: /usr/share/lua/5.1/pgmoon/init.lua:200: ngx.socket connect: expecting 1 ~ 5 arguments (including the object), but seen 6
stack traceback:
coroutine 0:
	[C]: in function 'send_ssl_message'
	/usr/share/lua/5.1/pgmoon/init.lua:200: in function 'connect'

As i can see, there is no check for environment in which script is runing, so you always pass a luasec_opt to self.sock:sslhandshake. But, thats not correct for ngx.socket .
Error is on pgmoon/init.lua#L579:

...
if t == MSG_TYPE.status then
        return self.sock:sslhandshake(false, nil, self.ssl_verify, nil, self.luasec_opts)
elseif ...

postgresql say too many clients already.

Hello,here my postgresql conf.

grep -v '^#' /etc/postgresql/9.5/main/postgresql.conf  | grep -v '^$' | grep -v '#'
archive_mode = on
effective_cache_size = 20GB
syslog_facility = 'LOCAL0'
syslog_ident = 'postgres'
log_checkpoints = on
log_disconnections = on
log_timezone = 'PRC'
stats_temp_directory = '/var/run/postgresql/9.5-main.pg_stat_tmp'
datestyle = 'iso, ymd'
timezone = 'PRC'
default_text_search_config = 'pg_catalog.english'
root@25-108:/home/www/test_openresty# grep -v '^#' /etc/postgresql/9.5/main/postgresql.conf  | grep -v '^$' 
data_directory = '/data/pgdata'		# use data in another directory
					# (change requires restart)
hba_file = '/etc/postgresql/9.5/main/pg_hba.conf'	# host-based authentication file
					# (change requires restart)
ident_file = '/etc/postgresql/9.5/main/pg_ident.conf'	# ident configuration file
					# (change requires restart)
external_pid_file = '/var/run/postgresql/9.5-main.pid'			# write an extra PID file
					# (change requires restart)
listen_addresses = '*'		# what IP address(es) to listen on;
					# comma-separated list of addresses;
					# defaults to 'localhost'; use '*' for all
					# (change requires restart)
port = 5432				# (change requires restart)
max_connections = 4000                  # (change requires restart)
unix_socket_directories = '/var/run/postgresql'	# comma-separated list of directories
					# (change requires restart)
					# (change requires restart)
					# (change requires restart)
					# (change requires restart)
ssl = true				# (change requires restart)
					# (change requires restart)
ssl_cert_file = '/etc/ssl/certs/ssl-cert-snakeoil.pem'		# (change requires restart)
ssl_key_file = '/etc/ssl/private/ssl-cert-snakeoil.key'		# (change requires restart)
					# 0 selects the system default
					# 0 selects the system default
					# 0 selects the system default
shared_buffers = 16GB # min 128kB
					# (change requires restart)
					# (change requires restart)
temp_buffers = 32MB			# min 800kB
					# (change requires restart)
work_mem = 8192MB				# min 64kB
maintenance_work_mem = 8192MB		# min 1MB
max_stack_depth = 4096			# min 100kB
dynamic_shared_memory_type = posix	# the default is the first option
					# supported by the operating system:
					#   posix
					#   sysv
					#   windows
					#   mmap
					# use none to disable dynamic shared memory
					# in kB, or -1 for no limit
					# (change requires restart)
vacuum_cost_delay = 10ms			# 0-100 milliseconds
vacuum_cost_limit = 10000		# 1-10000 credits
bgwriter_delay = 10ms			# 10-10000ms between rounds
wal_level =  hot_standby  # minimal, archive, hot_standby, or logical
					# (change requires restart)
synchronous_commit = on		# synchronization level;
					# off, local, remote_write, or on
					# supported by the operating system:
					#   open_datasync
					#   fdatasync (default on Linux)
					#   fsync
					#   fsync_writethrough
					#   open_sync
					# (change requires restart)
wal_buffers = 16MB			# min 32kB, -1 sets based on shared_buffers
					# (change requires restart)
wal_writer_delay = 20ms		# 1-10000 milliseconds
checkpoint_timeout = 5min		# range 30s-1h
archive_mode = on
				# (change requires restart)
				# placeholders: %p = path of file to archive
				#               %f = file name only
				# e.g. 'test ! -f /mnt/server/archivedir/%f && cp %p /mnt/server/archivedir/%f'
				# number of seconds; 0 disables
max_wal_senders = 32		# max number of walsender processes
				# (change requires restart)
				# (change requires restart)
				# (change requires restart)
				# comma-separated list of application_name
				# from standby(s); '*' = all
hot_standby = on # "on" allows queries during recovery
					# (change requires restart)
					# when reading WAL from archive;
					# -1 allows indefinite delay
					# when reading streaming WAL;
					# -1 allows indefinite delay
					# 0 disables
					# query conflicts
					# communication from master
					# in milliseconds; 0 disables
					# retrieve WAL after a failed attempt
effective_cache_size = 20GB
					# JOIN clauses
log_destination = 'csvlog'		# Valid values are combinations of
					# stderr, csvlog, syslog, and eventlog,
					# depending on platform.  csvlog
					# requires logging_collector to be on.
logging_collector = on		# Enable capturing of stderr and csvlog
					# into log files. Required to be on for
					# csvlogs.
					# (change requires restart)
					# can be absolute or relative to PGDATA
					# can include strftime() escapes
					# begin with 0 to use octal notation
log_truncate_on_rotation = on # If on, an existing log file with the
					# same name as the new log file will be
					# truncated rather than appended to.
					# But such truncation only occurs on
					# time-driven rotation, not on restarts
					# or size-driven rotation.  Default is
					# off, meaning append to existing files
					# in all cases.
log_rotation_age = 1d			# Automatic rotation of logfiles will
					# happen after that time.  0 disables.
log_rotation_size = 10MB		# Automatic rotation of logfiles will
					# happen after that much log output.
					# 0 disables.
syslog_facility = 'LOCAL0'
syslog_ident = 'postgres'
client_min_messages = notice # values in order of decreasing detail:
					#   debug5
					#   debug4
					#   debug3
					#   debug2
					#   debug1
					#   log
					#   notice
					#   warning
					#   error
log_min_messages = notice # values in order of decreasing detail:
					#   debug5
					#   debug4
					#   debug3
					#   debug2
					#   debug1
					#   info
					#   notice
					#   warning
					#   error
					#   log
					#   fatal
					#   panic
					#   debug5
					#   debug4
					#   debug3
					#   debug2
					#   debug1
					#   info
					#   notice
					#   warning
					#   error
					#   log
					#   fatal
					#   panic (effectively off)
log_min_duration_statement = 1000ms	# -1 is disabled, 0 logs all statements
					# and their durations, > 0 logs only
					# statements running at least this number
					# of milliseconds
log_checkpoints = on
log_disconnections = on
log_error_verbosity = verbose # terse, default, or verbose messages
log_line_prefix = '%t [%p-%l] %q%u@%d '			# special values:
					#   %a = application name
					#   %u = user name
					#   %d = database name
					#   %r = remote host and port
					#   %h = remote host
					#   %p = process ID
					#   %t = timestamp without milliseconds
					#   %m = timestamp with milliseconds
					#   %i = command tag
					#   %e = SQL state
					#   %c = session ID
					#   %l = session line number
					#   %s = session start timestamp
					#   %v = virtual transaction ID
					#   %x = transaction ID (0 if none)
					#   %q = stop here in non-session
					#        processes
					#   %% = '%'
					# e.g. '<%u%%%d> '
log_lock_waits = on # log lock waits >= deadlock_timeout
					# than the specified size in kilobytes;
					# -1 disables, 0 logs all temp files
log_timezone = 'PRC'
					# (change requires restart)
stats_temp_directory = '/var/run/postgresql/9.5-main.pg_stat_tmp'
autovacuum = on			# Enable autovacuum subprocess?  'on'
					# requires track_counts to also be on.
log_autovacuum_min_duration = 0 	# -1 disables, 0 logs all actions and
					# their durations, > 0 logs only
					# actions running at least this number
					# of milliseconds.
					# (change requires restart)
					# vacuum
					# analyze
					# (change requires restart)
					# before forced vacuum
					# (change requires restart)
					# autovacuum, in milliseconds;
					# -1 means use vacuum_cost_delay
					# autovacuum, -1 means use
					# vacuum_cost_limit
					# only default tablespace
datestyle = 'iso, ymd'
timezone = 'PRC'
					# abbreviations.  Currently, there are
					#   Default
					#   Australia (historical usage)
					#   India
					# You can create your own file in
					# share/timezonesets/.
					# encoding
lc_messages = 'en_US.UTF-8'			# locale for system error message
					# strings
lc_monetary = 'zh_CN.UTF-8'			# locale for monetary formatting
lc_numeric = 'zh_CN.UTF-8'			# locale for number formatting
lc_time = 'zh_CN.UTF-8'				# locale for time formatting
default_text_search_config = 'pg_catalog.english'
					# (change requires restart)
					# (change requires restart)
					# directory 'conf.d'
root@25-108:/home/www/test_openresty# ^C
root@25-108:/home/www/test_openresty# grep -v '^#' /etc/postgresql/9.5/main/postgresql.conf  | grep -v '^$'  
data_directory = '/data/pgdata'		# use data in another directory
					# (change requires restart)
hba_file = '/etc/postgresql/9.5/main/pg_hba.conf'	# host-based authentication file
					# (change requires restart)
ident_file = '/etc/postgresql/9.5/main/pg_ident.conf'	# ident configuration file
					# (change requires restart)
external_pid_file = '/var/run/postgresql/9.5-main.pid'			# write an extra PID file
					# (change requires restart)
listen_addresses = '*'		# what IP address(es) to listen on;
					# comma-separated list of addresses;
					# defaults to 'localhost'; use '*' for all
					# (change requires restart)
port = 5432				# (change requires restart)
max_connections = 4000                  # (change requires restart)
unix_socket_directories = '/var/run/postgresql'	# comma-separated list of directories
					# (change requires restart)
					# (change requires restart)
					# (change requires restart)
					# (change requires restart)
ssl = true				# (change requires restart)
					# (change requires restart)
ssl_cert_file = '/etc/ssl/certs/ssl-cert-snakeoil.pem'		# (change requires restart)
ssl_key_file = '/etc/ssl/private/ssl-cert-snakeoil.key'		# (change requires restart)
					# 0 selects the system default
					# 0 selects the system default
					# 0 selects the system default
shared_buffers = 16GB # min 128kB
					# (change requires restart)
					# (change requires restart)
temp_buffers = 32MB			# min 800kB
					# (change requires restart)
work_mem = 8192MB				# min 64kB
maintenance_work_mem = 8192MB		# min 1MB
max_stack_depth = 4096			# min 100kB
dynamic_shared_memory_type = posix	# the default is the first option
					# supported by the operating system:
					#   posix
					#   sysv
					#   windows
					#   mmap
					# use none to disable dynamic shared memory
					# in kB, or -1 for no limit
					# (change requires restart)
vacuum_cost_delay = 10ms			# 0-100 milliseconds
vacuum_cost_limit = 10000		# 1-10000 credits
bgwriter_delay = 10ms			# 10-10000ms between rounds
wal_level =  hot_standby  # minimal, archive, hot_standby, or logical
					# (change requires restart)
synchronous_commit = on		# synchronization level;
					# off, local, remote_write, or on
					# supported by the operating system:
					#   open_datasync
					#   fdatasync (default on Linux)
					#   fsync
					#   fsync_writethrough
					#   open_sync
					# (change requires restart)
wal_buffers = 16MB			# min 32kB, -1 sets based on shared_buffers
					# (change requires restart)
wal_writer_delay = 20ms		# 1-10000 milliseconds
checkpoint_timeout = 5min		# range 30s-1h
archive_mode = on
				# (change requires restart)
				# placeholders: %p = path of file to archive
				#               %f = file name only
				# e.g. 'test ! -f /mnt/server/archivedir/%f && cp %p /mnt/server/archivedir/%f'
				# number of seconds; 0 disables
max_wal_senders = 32		# max number of walsender processes
				# (change requires restart)
				# (change requires restart)
				# (change requires restart)
				# comma-separated list of application_name
				# from standby(s); '*' = all
hot_standby = on # "on" allows queries during recovery
					# (change requires restart)
					# when reading WAL from archive;
					# -1 allows indefinite delay
					# when reading streaming WAL;
					# -1 allows indefinite delay
					# 0 disables
					# query conflicts
					# communication from master
					# in milliseconds; 0 disables
					# retrieve WAL after a failed attempt
effective_cache_size = 20GB
					# JOIN clauses
log_destination = 'csvlog'		# Valid values are combinations of
					# stderr, csvlog, syslog, and eventlog,
					# depending on platform.  csvlog
					# requires logging_collector to be on.
logging_collector = on		# Enable capturing of stderr and csvlog

016-12-20 11:14:09 CST [24633-1] [unknown]@[unknown] LOG: incomplete startup packet
2016-12-20 11:14:09 CST [25669-1] mqtt@test_mqtt FATAL: sorry, too many clients already
2016-12-20 11:14:09 CST [25667-1] mqtt@test_mqtt FATAL: remaining connection slots are reserved for non-replication superuser connections
2016-12-20 11:14:09 CST [25668-1] mqtt@test_mqtt FATAL: remaining connection slots are reserved for non-replication superuser connections
2016-12-20 11:14:09 CST [25670-1] mqtt@test_mqtt FATAL: remaining connection slots are reserved for non-replication superuser connections

invalid password packet size(?)

Any time i use pg:connect() on Openresty this pops up on postgres log:

2014-09-16 17:07:34 UTC LOG:  invalid password packet size

Not sure how it affects though since the queries still work.

edit: i have the default md5 authentication in use

Calling connect() after keepalive()

This used to work in 1.6 but no longer in 1.7 or 1.8, with error
.../pgmoon/init.lua:194: attempt to index field 'sock' (a nil value)

File app/db.lua

local pg = require('pgmoon')
return pg.new({...})

File app/handler.lua

local db = require('app.db')
function ware1(db)
	db:connect()
	-- do work
	db:keepalive()
end

function ware2(db)
	db:connect()
	-- do work
	db:keepalive()
end

function handler(db)
	ware1(db)
	-- do some work
	ware2(db)
	-- do more work
end

I found that the self.sock handle is set to nil after keepalive().
Can we call connect() after keepalive() if they are within the same request?

Thanks!

Add SSL protocol to options

In some situations i need to specify SSL protocol (e.g. tlsv1_2).
Now this parameter is hardcoded to tlsv1.

Recommend Projects

  • React photo React

    A declarative, efficient, and flexible JavaScript library for building user interfaces.

  • Vue.js photo Vue.js

    🖖 Vue.js is a progressive, incrementally-adoptable JavaScript framework for building UI on the web.

  • Typescript photo Typescript

    TypeScript is a superset of JavaScript that compiles to clean JavaScript output.

  • TensorFlow photo TensorFlow

    An Open Source Machine Learning Framework for Everyone

  • Django photo Django

    The Web framework for perfectionists with deadlines.

  • D3 photo D3

    Bring data to life with SVG, Canvas and HTML. 📊📈🎉

Recommend Topics

  • javascript

    JavaScript (JS) is a lightweight interpreted programming language with first-class functions.

  • web

    Some thing interesting about web. New door for the world.

  • server

    A server is a program made to process requests and deliver data to clients.

  • Machine learning

    Machine learning is a way of modeling and interpreting data that allows a piece of software to respond intelligently.

  • Game

    Some thing interesting about game, make everyone happy.

Recommend Org

  • Facebook photo Facebook

    We are working to build community through open source technology. NB: members must have two-factor auth.

  • Microsoft photo Microsoft

    Open source projects and samples from Microsoft.

  • Google photo Google

    Google ❤️ Open Source for everyone.

  • D3 photo D3

    Data-Driven Documents codes.