PostgreSQL 10 参数模板 - 珍藏级

20 minute read

背景

系统参数模板

《PostgreSQL on Linux 最佳部署手册 - 珍藏级》

PostgreSQL 10参数模板

# -----------------------------
# PostgreSQL configuration file
# -----------------------------
#
# This file consists of lines of the form:
#
#   name = value
#
# (The "=" is optional.)  Whitespace may be used.  Comments are introduced with
# "#" anywhere on a line.  The complete list of parameter names and allowed
# values can be found in the PostgreSQL documentation.
#
# The commented-out settings shown in this file represent the default values.
# Re-commenting a setting is NOT sufficient to revert it to the default value;
# you need to reload the server.
#
# This file is read on server startup and when the server receives a SIGHUP
# signal.  If you edit the file on a running system, you have to SIGHUP the
# server for the changes to take effect, run "pg_ctl reload", or execute
# "SELECT pg_reload_conf()".  Some parameters, which are marked below,
# require a server shutdown and restart to take effect.
#
# Any parameter can also be given as a command-line option to the server, e.g.,
# "postgres -c log_connections=on".  Some parameters can be changed at run time
# with the "SET" SQL command.
#
# Memory units:  kB = kilobytes        Time units:  ms  = milliseconds
#                MB = megabytes                     s   = seconds
#                GB = gigabytes                     min = minutes
#                TB = terabytes                     h   = hours
#                                                   d   = days


#------------------------------------------------------------------------------
# FILE LOCATIONS
#------------------------------------------------------------------------------

# The default values of these variables are driven from the -D command-line
# option or PGDATA environment variable, represented here as ConfigDir.

#data_directory = 'ConfigDir'           # use data in another directory
                                        # (change requires restart)
#hba_file = 'ConfigDir/pg_hba.conf'     # host-based authentication file
                                        # (change requires restart)
#ident_file = 'ConfigDir/pg_ident.conf' # ident configuration file
                                        # (change requires restart)

# If external_pid_file is not explicitly set, no extra PID file is written.
#external_pid_file = ''                 # write an extra PID file
                                        # (change requires restart)


#------------------------------------------------------------------------------
# CONNECTIONS AND AUTHENTICATION
#------------------------------------------------------------------------------

# - Connection Settings -

listen_addresses = '0.0.0.0'            # what IP address(es) to listen on;
                                        # comma-separated list of addresses;
                                        # defaults to 'localhost'; use '*' for all
                                        # (change requires restart)
# 根据业务需求设定监听
port = 1921                             # (change requires restart)  

# 建议不要大于 200 * 四分之一物理内存(GB), 例如四分之一物理内存为16G,则建议不要超过3200.    
# (假设一个连接耗费5MB,实际上syscache很大时,可能更多) 
# [《PostgreSQL relcache在长连接应用中的内存霸占"坑"》](201607/20160709_01.md) 
max_connections = 2000                  # (change requires restart)   
superuser_reserved_connections = 13     # (change requires restart)

# $PGDATA, /tmp中 创建unix socket监听
unix_socket_directories = '/tmp,.'      # comma-separated list of directories   
                                        # (change requires restart)
#unix_socket_group = ''                 # (change requires restart)

# 除了OWNER和超级用户,其他用户无法从/tmp unix socket连接该实例
unix_socket_permissions = 0700          # begin with 0 to use octal notation   
                                        # (change requires restart)
#bonjour = off                          # advertise server via Bonjour
                                        # (change requires restart)
#bonjour_name = ''                      # defaults to the computer name
                                        # (change requires restart)

# - Security and Authentication -

#authentication_timeout = 1min          # 1s-600s
#ssl = off
#ssl_ciphers = 'HIGH:MEDIUM:+3DES:!aNULL' # allowed SSL ciphers
#ssl_prefer_server_ciphers = on
#ssl_ecdh_curve = 'prime256v1'
#ssl_dh_params_file = ''
#ssl_cert_file = 'server.crt'
#ssl_key_file = 'server.key'
#ssl_ca_file = ''
#ssl_crl_file = ''

# md5 or scram-sha-256   # 如果MD5会泄露,建议使用scram-sha-256,但是相互不兼容,请注意。 
# [《PostgreSQL 10.0 preview 安全增强 - SASL认证方法 之 scram-sha-256 安全认证机制》](201703/20170309_01.md)  
password_encryption = md5              
#db_user_namespace = off
#row_security = on

# GSSAPI using Kerberos
#krb_server_keyfile = ''
#krb_caseins_users = off

# - TCP Keepalives -
# see "man 7 tcp" for details

tcp_keepalives_idle = 60                # TCP_KEEPIDLE, in seconds;
                                        # 0 selects the system default
tcp_keepalives_interval = 10            # TCP_KEEPINTVL, in seconds;
                                        # 0 selects the system default
tcp_keepalives_count = 10               # TCP_KEEPCNT;
                                        # 0 selects the system default


#------------------------------------------------------------------------------
# RESOURCE USAGE (except WAL)
#------------------------------------------------------------------------------

# - Memory -

# 1/4 主机内存 
shared_buffers = 24GB                   # min 128kB  
                                        # (change requires restart)
# 当不使用huge page,并且连接数大于3000时,建议shared buffer不要超过48G


# 建议shared buffer设置超过32GB时 使用大页,页大小 /proc/meminfo Hugepagesize  
huge_pages = try                        # on, off, or try              
                                        # (change requires restart)

#temp_buffers = 8MB                     # min 800kB

# 如果用户需要使用两阶段提交,需要设置为大于0,建议与max_connections一样大
#max_prepared_transactions = 0          # zero disables the feature
                                        # (change requires restart)
# Caution: it is not advisable to set max_prepared_transactions nonzero unless
# you actively intend to use prepared transactions.

# 可以在会话中设置,如果有大量JOIN,聚合操作,并且期望使用hash agg或hash join。 
# 可以设大一些,但是不建议大于    四分之一内存除以最大连接数  . 
# (一条QUERY中可以使用多倍WORK_MEM,与执行计划中的NODE有关)  
# 建议给一个输入,AP模式TP模式OR混合模式。三种模式使用三种不同的计算公式
work_mem = 8MB                          # min 64kB

# min( 2G, (1/4 主机内存)/autovacuum_max_workers )  
maintenance_work_mem = 2GB              # min 1MB    
#replacement_sort_tuples = 150000       # limits use of replacement selection sort
#autovacuum_work_mem = -1               # min 1MB, or -1 to use maintenance_work_mem  
#max_stack_depth = 2MB                  # 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
                                        # (change requires restart) 

# - Disk -

# 如果需要限制临时文件使用量,可以设置。
# 例如防止有异常的递归调用,无限使用临时文件。
#temp_file_limit = -1                   # limits per-process temp file space
                                        # in kB, or -1 for no limit

# - Kernel Resource Usage -

## 如果你的数据库有非常多小文件(比如有几十万以上的表,还有索引等,并且每张表都会被访问到时),
# 建议FD可以设多一些,避免进程需要打开关闭文件。
## 但是不要大于前面章节系统设置的ulimit -n(open files)
# max_files_per_process=655360

#max_files_per_process = 1000           # min 25
                                        # (change requires restart)

# 需要加载什么LIB,预先加载,对于经常访问的库也建议预加载,例如postgis
shared_preload_libraries = 'pg_stat_statements,auto_explain'          # (change requires restart)  

# - Cost-Based Vacuum Delay -

vacuum_cost_delay = 0                   # 0-100 milliseconds
#vacuum_cost_page_hit = 1               # 0-10000 credits
vacuum_cost_page_miss = 5               # 0-10000 credits
vacuum_cost_page_dirty = 10             # 0-10000 credits

# io很好,CPU核数很多的机器,设大一些
vacuum_cost_limit = 10000               # 1-10000 credits  

# - Background Writer -

bgwriter_delay = 10ms                   # 10-10000ms between rounds
bgwriter_lru_maxpages = 500             # 0-1000 max buffers written/round
bgwriter_lru_multiplier = 5.0           # 0-10.0 multiplier on buffers scanned/round

# IO非常强悍的机器,可以考虑设置为0  
#bgwriter_flush_after = 512kB           # measured in pages, 0 disables  

# - Asynchronous Behavior -

effective_io_concurrency = 0            # 1-1000; 0 disables prefetching 

# wal sender, user 动态fork的process, parallel worker等都算作 worker process, 所以你需要设置足够大. 
max_worker_processes = 128              # (change requires restart)    

#  如果需要使用并行查询,设置为大于1 ,不建议超过 主机cores-2
max_parallel_workers_per_gather = 0     # taken from max_parallel_workers    

#  如果需要使用并行查询,设置为大于1 ,不建议超过 主机cores-2
#  必须小于 max_worker_processes 
max_parallel_workers = 8                # maximum number of max_worker_processes that  
                                        # can be used in parallel queries

# 开启后有性能影响,但是如果你的系统中有不可预知的长事务,并且希望数据库不因长事务导致垃圾膨胀,则可以设置。					
#old_snapshot_threshold = -1            # 1min-60d; -1 disables; 0 is immediate  
                                        # (change requires restart)
#backend_flush_after = 0                # measured in pages, 0 disables


#------------------------------------------------------------------------------
# WRITE AHEAD LOG
#------------------------------------------------------------------------------

# - Settings -

# 需要物理备库设置为replica,需要逻辑订阅或逻辑备库则设置为logical
wal_level = replica                     # minimal, replica, or logical  
                                        # (change requires restart)
#fsync = on                             # flush data to disk for crash safety
                                        # (turning this off can cause
                                        # unrecoverable data corruption)

# 如果双节点,设置为ON,如果是多副本,同步模式,建议设置为remote_write。 
# 如果磁盘性能很差,并且是OLTP业务。可以考虑设置为off降低COMMIT的RT,提高吞吐(设置为OFF时,可能丢失部分XLOG RECORD)
synchronous_commit = on                 # synchronization level;    
                                        # off, local, remote_write, remote_apply, or on

# 建议使用pg_test_fsync测试后,决定用哪个最快。通常LINUX下open_datasync比较快。
#wal_sync_method = fsync                # the default is the first option 
                                        # supported by the operating system:
                                        #   open_datasync
                                        #   fdatasync (default on Linux)
                                        #   fsync
                                        #   fsync_writethrough
                                        #   open_sync

# 如果文件系统支持COW例如ZFS,则建议设置为OFF。 如果文件系统可以保证datafile block size的原子写,在对齐后也可以设置为OFF。
#full_page_writes = on                  # recover from partial page writes  
#wal_compression = off                  # enable compression of full-page writes
#wal_log_hints = off                    # also do full page writes of non-critical updates
                                        # (change requires restart)


# 建议 min( 512MB, shared_buffers/32 ) 
wal_buffers = -1                        # min 32kB, -1 sets based on shared_buffers    
                                        # (change requires restart)

# 如果设置了synchronous_commit = off,可以设置wal_writer_delay
wal_writer_delay = 10ms                # 1-10000 milliseconds
wal_writer_flush_after = 1MB           # measured in pages, 0 disables


# 如果synchronous_commit=on, 并且已知业务系统为高并发,对数据库有写操作的小事务,则可以设置commit_delay来实现分组提交,合并WAL FSYNCIO 。
#commit_delay = 0                       # range 0-100000, in microseconds   

# 同时处于提交状态的事务数超过commit_siblings时,使用分组提交
#commit_siblings = 5                    # range 1-1000  

# - Checkpoints -

#  不建议频繁做检查点,否则XLOG会产生很多的FULL PAGE WRITE(when full_page_writes=on)。
checkpoint_timeout = 30min              # range 30s-1d   

# 建议等于SHARED BUFFER,或2倍。
# 同时需要考虑崩溃恢复时间, 越大,检查点可能拉越长导致崩溃恢复耗时越长。但是越小,开启FPW时,WAL日志写入量又越大。 建议采用COW文件系统,关闭FPW。
max_wal_size = 256GB     

# 建议是SHARED BUFFER的2分之一
min_wal_size = 64GB       

# 硬盘好的情况下,可以让检查点快速结束,恢复时也可以快速达到一致状态。否则建议0.5~0.9
checkpoint_completion_target = 0.1      # checkpoint target duration, 0.0 - 1.0  

# IO很好的机器,不需要考虑平滑调度, 否则建议128~256kB
#checkpoint_flush_after = 256kB         # measured in pages, 0 disables    
#checkpoint_warning = 30s               # 0 disables 

# - Archiving -

# 建议默认打开,因为修改它需要重启实例
archive_mode = on             # enables archiving; off, on, or always
                                # (change requires restart)

#  后期再修改,如  'test ! -f /disk1/digoal/arch/%f && cp %p /disk1/digoal/arch/%f'
archive_command = '/bin/date'           # command to use to archive a logfile segment  
                                # 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'
#archive_timeout = 0            # force a logfile segment switch after this
                                # number of seconds; 0 disables


#------------------------------------------------------------------------------
# REPLICATION
#------------------------------------------------------------------------------

# - Sending Server(s) -

# Set these on the master and on any standby that will send replication data.

# 同时需要几个流复制连接,根据实际需求设定
max_wal_senders = 8             # max number of walsender processes  
                                # (change requires restart)

# 根据实际情况设置保留WAL的数量,主要是防止过早的清除WAL,导致备库因为主库的WAL清除而中断。根据实际情况设定。
wal_keep_segments = 0           # in logfile segments, 16MB each; 0 disables 
#wal_sender_timeout = 60s       # in milliseconds; 0 disables

# 根据实际情况设置需要创建多少replication slot
# 建议大于等于max_wal_senders
#max_replication_slots = 10     # max number of replication slots   
                                # (change requires restart)
#track_commit_timestamp = off   # collect timestamp of transaction commit
                                # (change requires restart)

# - Master Server -

# These settings are ignored on a standby server.

# 如果有2个或2个以上的备库,可以考虑使用同步多副本模式。 根据实际情况设置
[《PostgreSQL 一主多从(多副本,强同步)简明手册 - 配置、压测、监控、切换、防脑裂、修复、0丢失 - 珍藏级》](201803/20180326_01.md)  
#synchronous_standby_names = '' # standby servers that provide sync rep   
                                # method to choose sync standbys, number of sync standbys,
                                # and comma-separated list of application_name
                                # from standby(s); '*' = all
#vacuum_defer_cleanup_age = 0   # number of xacts by which cleanup is delayed

# - Standby Servers -

# These settings are ignored on a master server.

#hot_standby = on                       # "off" disallows queries during recovery
                                        # (change requires restart)
max_standby_archive_delay = 300s        # max delay before canceling queries
                                        # when reading WAL from archive;
                                        # -1 allows indefinite delay
max_standby_streaming_delay = 300s      # max delay before canceling queries
                                        # when reading streaming WAL;
                                        # -1 allows indefinite delay
wal_receiver_status_interval = 1s       # send replies at least this often
                                        # 0 disables


# 建议关闭,以免备库长事务导致 主库无法回收垃圾而膨胀。
hot_standby_feedback = off             # send info from standby to prevent   
                                        # query conflicts
#wal_receiver_timeout = 60s             # time that receiver waits for
                                        # communication from master
                                        # in milliseconds; 0 disables
wal_retrieve_retry_interval = 5s       # time to wait before retrying to
                                        # retrieve WAL after a failed attempt

# - Subscribers -

# [《PostgreSQL 10.0 preview 逻辑订阅 - 原理与最佳实践》](201702/20170227_01.md)  
# These settings are ignored on a publisher. 
# 必须小于  max_worker_processes
#max_logical_replication_workers = 4    # taken from max_worker_processes
                                        # (change requires restart)
#max_sync_workers_per_subscription = 2  # taken from max_logical_replication_workers


#------------------------------------------------------------------------------
# QUERY TUNING
#------------------------------------------------------------------------------

# - Planner Method Configuration -

#enable_bitmapscan = on
#enable_hashagg = on
#enable_hashjoin = on
#enable_indexscan = on
#enable_indexonlyscan = on
#enable_material = on
#enable_mergejoin = on
#enable_nestloop = on
#enable_seqscan = on
#enable_sort = on
#enable_tidscan = on

# - Planner Cost Constants -

#seq_page_cost = 1.0                    # measured on an arbitrary scale


# 离散IO很好的机器(例如ssd, nvme ssd),不需要考虑离散和顺序扫描的成本差异 
random_page_cost = 1.1                  # same scale as above     
#cpu_tuple_cost = 0.01                  # same scale as above
#cpu_index_tuple_cost = 0.005           # same scale as above
#cpu_operator_cost = 0.0025             # same scale as above
#parallel_tuple_cost = 0.1              # same scale as above
#parallel_setup_cost = 1000.0   # same scale as above
#min_parallel_table_scan_size = 8MB
#min_parallel_index_scan_size = 512kB

# 扣掉会话连接RSS,shared buffer, autovacuum worker, 剩下的都是OS可用的CACHE。
effective_cache_size = 400GB    

# - Genetic Query Optimizer -

#geqo = on
#geqo_threshold = 12
#geqo_effort = 5                        # range 1-10
#geqo_pool_size = 0                     # selects default based on effort
#geqo_generations = 0                   # selects default based on effort
#geqo_selection_bias = 2.0              # range 1.5-2.0
#geqo_seed = 0.0                        # range 0.0-1.0

# - Other Planner Options -

#default_statistics_target = 100        # range 1-10000
#constraint_exclusion = partition       # on, off, or partition
#cursor_tuple_fraction = 0.1            # range 0.0-1.0
#from_collapse_limit = 8
#join_collapse_limit = 8                # 1 disables collapsing of explicit
                                        # JOIN clauses
#force_parallel_mode = off


#------------------------------------------------------------------------------
# ERROR REPORTING AND LOGGING
#------------------------------------------------------------------------------

# - Where to Log -

log_destination = 'csvlog'              # Valid values are combinations of
                                        # stderr, csvlog, syslog, and eventlog,
                                        # depending on platform.  csvlog
                                        # requires logging_collector to be on.

# This is used when logging to stderr:
logging_collector = on          # Enable capturing of stderr and csvlog
                                        # into log files. Required to be on for
                                        # csvlogs.
                                        # (change requires restart)

# These are only used if logging_collector is on:
#log_directory = 'log'                  # directory where log files are written,
                                        # can be absolute or relative to PGDATA
#log_filename = 'postgresql-%Y-%m-%d_%H%M%S.log'        # log file name pattern,
                                        # can include strftime() escapes
#log_file_mode = 0600                   # creation mode for log files,
                                        # 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.

# These are relevant when logging to syslog:
#syslog_facility = 'LOCAL0'
#syslog_ident = 'postgres'
#syslog_sequence_numbers = on
#syslog_split_messages = on

# This is only relevant when logging to eventlog (win32):
# (change requires restart)
#event_source = 'PostgreSQL'

# - When to Log -

#client_min_messages = notice           # values in order of decreasing detail:
                                        #   debug5
                                        #   debug4
                                        #   debug3
                                        #   debug2
                                        #   debug1
                                        #   log
                                        #   notice
                                        #   warning
                                        #   error

#log_min_messages = warning             # values in order of decreasing detail:
                                        #   debug5
                                        #   debug4
                                        #   debug3
                                        #   debug2
                                        #   debug1
                                        #   info
                                        #   notice
                                        #   warning
                                        #   error
                                        #   log
                                        #   fatal
                                        #   panic

#log_min_error_statement = error        # values in order of decreasing detail:
                                        #   debug5
                                        #   debug4
                                        #   debug3
                                        #   debug2
                                        #   debug1
                                        #   info
                                        #   notice
                                        #   warning
                                        #   error
                                        #   log
                                        #   fatal
                                        #   panic (effectively off)

# 根据实际情况设定,例如业务上认为5秒以上是慢SQL,那么就设置为5秒。
log_min_duration_statement = 5s        # -1 is disabled, 0 logs all statements   
                                        # and their durations, > 0 logs only
                                        # statements running at least this number
                                        # of milliseconds


# - What to Log -

#debug_print_parse = off
#debug_print_rewritten = off
#debug_print_plan = off
#debug_pretty_print = on
log_checkpoints = on

# 如果业务是短连接,建议设置为OFF,否则建议设置为ON
log_connections = off   

# 如果业务是短连接,建议设置为OFF,否则建议设置为ON
log_disconnections = off   
#log_duration = off
log_error_verbosity = verbose  # terse, default, or verbose messages
#log_hostname = off
#log_line_prefix = '%m [%p] '           # 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
                                        #   %n = timestamp with milliseconds (as a Unix epoch)
                                        #   %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
# 如果需要审计SQL,则可以设置为all
log_statement = 'ddl'                 # none, ddl, mod, all
#log_replication_commands = off
log_temp_files = 1GB                    # log temporary files equal or larger
                                        # than the specified size in kilobytes;
                                        # -1 disables, 0 logs all temp files
log_timezone = 'PRC'


# - Process Title -

#cluster_name = ''                      # added to process titles if nonempty
                                        # (change requires restart)
#update_process_title = on


#------------------------------------------------------------------------------
# RUNTIME STATISTICS
#------------------------------------------------------------------------------

# - Query/Index Statistics Collector -

#track_activities = on
#track_counts = on

# 跟踪IO耗时会带来一定的性能影响,默认是关闭的
# 如果需要统计IO的时间开销,设置为ON
track_io_timing = off    
#track_functions = none                 # none, pl, all
#track_activity_query_size = 1024       # (change requires restart)
#stats_temp_directory = 'pg_stat_tmp'   


# - Statistics Monitoring -

#log_parser_stats = off
#log_planner_stats = off
#log_executor_stats = off
#log_statement_stats = off


#------------------------------------------------------------------------------
# AUTOVACUUM PARAMETERS
#------------------------------------------------------------------------------

#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.

# CPU核多,并且IO好的情况下,可多点,但是注意最多可能消耗这么多内存: 
# autovacuum_max_workers * autovacuum mem(autovacuum_work_mem),
# 会消耗较多内存,所以内存也要有基础。     
# 当DELETE\UPDATE非常频繁时,建议设置多一点,防止膨胀严重    
autovacuum_max_workers = 6              # max number of autovacuum subprocesses   
                                        # (change requires restart)

# 建议不要太高频率,否则会因为vacuum产生较多的XLOG。或者在某些垃圾回收不掉的情况下(例如长事务、feed back on,等),导致一直触发vacuum,CPU和IO都会升高
[《PostgreSQL垃圾回收代码分析 - why postgresql cann't reclaim tuple is HEAPTUPLE_RECENTLY_DEAD》](201505/20150503_01.md)  
[《PostgreSQL物理"备库"的哪些操作或配置,可能影响"主库"的性能、垃圾回收、IO波动》](201704/20170410_03.md)  
#autovacuum_naptime = 1min              # time between autovacuum runs      
#autovacuum_vacuum_threshold = 50       # min number of row updates before
                                        # vacuum
#autovacuum_analyze_threshold = 50      # min number of row updates before
                                        # analyze
#autovacuum_vacuum_scale_factor = 0.2   # fraction of table size before vacuum
#autovacuum_analyze_scale_factor = 0.1  # fraction of table size before analyze

# 除了设置较大的FREEZE值。
# 还是需要注意FREEZE风暴  [《PostgreSQL Freeze 风暴预测续 - 珍藏级SQL》](201804/20180411_01.md)  
# 表级定制freeze
autovacuum_freeze_max_age = 1500000000  # maximum XID age before forced vacuum   
                                        # (change requires restart)
autovacuum_multixact_freeze_max_age = 1600000000        # maximum multixact age
                                        # before forced vacuum
                                        # (change requires restart)
autovacuum_vacuum_cost_delay = 10ms      # default vacuum cost delay for
                                        # autovacuum, in milliseconds;
                                        # -1 means use vacuum_cost_delay
autovacuum_vacuum_cost_limit = -1      # default vacuum cost limit for
                                        # autovacuum, -1 means use
                                        # vacuum_cost_limit


#------------------------------------------------------------------------------
# CLIENT CONNECTION DEFAULTS
#------------------------------------------------------------------------------

# - Statement Behavior -

#search_path = '"$user", public'        # schema names
#default_tablespace = ''                # a tablespace name, '' uses the default
#temp_tablespaces = ''                  # a list of tablespace names, '' uses
                                        # only default tablespace
#check_function_bodies = on
#default_transaction_isolation = 'read committed'
#default_transaction_read_only = off
#default_transaction_deferrable = off
#session_replication_role = 'origin'

# 可以用来防止风暴,但是不建议全局设置
statement_timeout = 0                  # in milliseconds, 0 is disabled   

# 执行DDL时,建议加上超时
#lock_timeout = 0                       # in milliseconds, 0 is disabled   

# 空闲中事务自动清理,根据业务实际情况设置
idle_in_transaction_session_timeout = 15min        # in milliseconds, 0 is disabled   
#vacuum_freeze_min_age = 50000000
vacuum_freeze_table_age = 1450000000
#vacuum_multixact_freeze_min_age = 5000000
vacuum_multixact_freeze_table_age = 1450000000
#bytea_output = 'hex'                   # hex, escape
#xmlbinary = 'base64'
#xmloption = 'content'

# 限制GIN扫描的返回结果集大小,在想限制超多匹配的返回时可以设置
#gin_fuzzy_search_limit = 0     

# GIN索引pending list的大小
#gin_pending_list_limit = 4MB   

# - Locale and Formatting -

datestyle = 'iso, ymd'
#intervalstyle = 'postgres'
timezone = 'PRC'
#timezone_abbreviations = 'Default'     # Select the set of available time zone
                                        # abbreviations.  Currently, there are
                                        #   Default
                                        #   Australia (historical usage)
                                        #   India
                                        # You can create your own file in
                                        # share/timezonesets/.
#extra_float_digits = 0                 # min -15, max 3
#client_encoding = sql_ascii            # actually, defaults to database
                                        # encoding

# These settings are initialized by initdb, but they can be changed.
lc_messages = 'C'                       # locale for system error message
                                        # strings
lc_monetary = 'C'                       # locale for monetary formatting
lc_numeric = 'C'                        # locale for number formatting
lc_time = 'C'                           # locale for time formatting

# default configuration for text search
default_text_search_config = 'pg_catalog.english'

# - Other Defaults -

#dynamic_library_path = '$libdir'
#local_preload_libraries = ''
#session_preload_libraries = ''


#------------------------------------------------------------------------------
# LOCK MANAGEMENT
#------------------------------------------------------------------------------

#deadlock_timeout = 1s
#max_locks_per_transaction = 64         # min 10
                                        # (change requires restart)
#max_pred_locks_per_transaction = 64    # min 10
                                        # (change requires restart)
#max_pred_locks_per_relation = -2       # negative values mean
                                        # (max_pred_locks_per_transaction
                                        #  / -max_pred_locks_per_relation) - 1
#max_pred_locks_per_page = 2            # min 0


#------------------------------------------------------------------------------
# VERSION/PLATFORM COMPATIBILITY
#------------------------------------------------------------------------------

# - Previous PostgreSQL Versions -

#array_nulls = on
#backslash_quote = safe_encoding        # on, off, or safe_encoding
#default_with_oids = off

# [《PostgreSQL 转义、UNICODE、与SQL注入》](201704/20170402_01.md)  
#escape_string_warning = on   
#lo_compat_privileges = off
#operator_precedence_warning = off
#quote_all_identifiers = off
#standard_conforming_strings = on
#synchronize_seqscans = on

# - Other Platforms and Clients -

#transform_null_equals = off


#------------------------------------------------------------------------------
# ERROR HANDLING
#------------------------------------------------------------------------------

#exit_on_error = off                    # terminate session on any error?
#restart_after_crash = on               # reinitialize after backend crash?


#------------------------------------------------------------------------------
# CONFIG FILE INCLUDES
#------------------------------------------------------------------------------

# These options allow settings to be loaded from files other than the
# default postgresql.conf.

#include_dir = 'conf.d'                 # include files ending in '.conf' from
                                        # directory 'conf.d'
#include_if_exists = 'exists.conf'      # include file only if it exists
#include = 'special.conf'               # include file


#------------------------------------------------------------------------------
# CUSTOMIZED OPTIONS
#------------------------------------------------------------------------------

# Add settings for extensions here

可以给开发者开放的建议配置

# 允许用户取值: -1 或 大于102400
#temp_file_limit = -1                   # limits per-process temp file space
                                        # in kB, or -1 for no limit

# 允许用户取值: >=0 , <= 规格CPU个数-2
max_parallel_workers_per_gather = 0     # taken from max_parallel_workers    

# 允许用户取值: >=0 , <= 规格CPU个数-2,必须小于 max_worker_processes
max_parallel_workers = 8                # maximum number of max_worker_processes that  
                                        # can be used in parallel queries


# 允许用户取值: -1 或 1min ~ 1d 		
#old_snapshot_threshold = -1            # 1min-60d; -1 disables; 0 is immediate  
                                        # (change requires restart)

# 允许用户取值: replica 或 replica
wal_level = replica                     # minimal, replica, or replica  
                                        # (change requires restart)

# 如果双节点、单节点版本,允许用户取值: off or on 
# 如果是多副本,允许用户取值: remote_write, remote_apply or on 
synchronous_commit = on                 # synchronization level;    
                                        # off, local, remote_write, remote_apply, or on



# 允许用户取值: 0 ~ 100
#commit_delay = 0                       # range 0-100000, in microseconds   

# 允许用户取值: 1 ~ 50
#commit_siblings = 5                    # range 1-1000  


# 允许用户取值: 5min ~ 120min
checkpoint_timeout = 30min              # range 30s-1d  

# 允许用户取值: 0.1 ~ 0.9
checkpoint_completion_target = 0.1      # checkpoint target duration, 0.0 - 1.0  



# 允许用户取值: 128 ~ 8192  约 128GB 
wal_keep_segments = 0           # in logfile segments, 16MB each; 0 disables 


# 允许用户取值: 0 或 5s ~ 60s
#wal_sender_timeout = 60s       # in milliseconds; 0 disables

# 允许用户取值: 0 ~ 1000000
#vacuum_defer_cleanup_age = 0   # number of xacts by which cleanup is delayed

# 只读节点开放时,允许用户设置只读节点参数
# 允许用户取值: 0 ~ 2h
max_standby_archive_delay = 300s        # max delay before canceling queries
                                        # when reading WAL from archive;
                                        # -1 allows indefinite delay
max_standby_streaming_delay = 300s      # max delay before canceling queries
                                        # when reading streaming WAL;
                                        # -1 allows indefinite delay


# 允许用户取值: 0 ~ 16,必须小于 max_worker_processes
#max_logical_replication_workers = 4    # taken from max_worker_processes
                                        # (change requires restart)

# 允许用户取值: 0 ~ 16,必须小于等于 max_logical_replication_workers
#max_sync_workers_per_subscription = 2  # taken from max_logical_replication_workers



# 允许用户取值: 100ms ~ 60s  
log_min_duration_statement = 5s        # -1 is disabled, 0 logs all statements   
                                        # and their durations, > 0 logs only
                                        # statements running at least this number
                                        # of milliseconds

# 允许用户取值: -1 , 10MB ~ 10GB
#log_temp_files = -1                    # log temporary files equal or larger
                                        # than the specified size in kilobytes;
                                        # -1 disables, 0 logs all temp files


# 允许用户取值: 15s ~ 5min
#autovacuum_naptime = 1min              # time between autovacuum runs      

# 允许用户取值: 1.5亿 ~ 15亿
autovacuum_freeze_max_age = 1500000000  # maximum XID age before forced vacuum   
                                        # (change requires restart)

# 允许用户取值: 1.5亿 ~ 15亿
autovacuum_multixact_freeze_max_age = 1600000000        # maximum multixact age
                                        # before forced vacuum
                                        # (change requires restart)

# 允许用户取值: 0 ~ 100ms
autovacuum_vacuum_cost_delay = 10ms      # default vacuum cost delay for
                                        # autovacuum, in milliseconds;
                                        # -1 means use vacuum_cost_delay

# 允许用户取值: -1 ~ 10000
autovacuum_vacuum_cost_limit = -1       # default vacuum cost limit for
                                        # autovacuum, -1 means use
                                        # vacuum_cost_limit


# 允许用户取值: 0 或 1s ~ 3600s
statement_timeout = 0                  # in milliseconds, 0 is disabled   

# 允许用户取值: 0 或 1s ~ 60s
#lock_timeout = 0                       # in milliseconds, 0 is disabled   

# 允许用户取值: 0 或 5s ~ 300s
idle_in_transaction_session_timeout = 15min        # in milliseconds, 0 is disabled   

# 允许用户取值: 1.5亿 ~ 15亿
vacuum_freeze_table_age = 1450000000
vacuum_multixact_freeze_table_age = 1450000000

# 允许用户取值: hex, escape
#bytea_output = 'hex'                   # hex, escape

# 允许用户取值: 0 ~ 100万
#gin_fuzzy_search_limit = 0     




# 允许用户设置,设置为数据库允许的值
datestyle = 'iso, ymd'
#intervalstyle = 'postgres'
timezone = 'PRC'
#timezone_abbreviations = 'Default'     # Select the set of available time zone
                                        # abbreviations.  Currently, there are
                                        #   Default
                                        #   Australia (historical usage)
                                        #   India
                                        # You can create your own file in
                                        # share/timezonesets/.
#extra_float_digits = 0                 # min -15, max 3
#client_encoding = sql_ascii            # actually, defaults to database
                                        # encoding

# These settings are initialized by initdb, but they can be changed.
lc_messages = 'C'                       # locale for system error message
                                        # strings
lc_monetary = 'C'                       # locale for monetary formatting
lc_numeric = 'C'                        # locale for number formatting
lc_time = 'C'                           # locale for time formatting

#backslash_quote = safe_encoding        # on, off, or safe_encoding

#escape_string_warning = on   

#standard_conforming_strings = on

#transform_null_equals = off

内存使用评估

# 1/4 主机内存 
shared_buffers = 24GB 

#temp_buffers = 8MB


# 可以在会话中设置,如果有大量JOIN,聚合操作,并且期望使用hash agg或hash join。 
# 可以设大一些,但是不建议大于    四分之一内存除以最大连接数  . 
# (一条QUERY中可以使用多倍WORK_MEM,与执行计划中的NODE有关)  
work_mem = 8MB 

# min( 2G, (1/4 主机内存)/autovacuum_max_workers )  
maintenance_work_mem = 2GB   

#autovacuum_work_mem = -1    

# 建议 min( 512MB, shared_buffers/32 ) 
wal_buffers = -1 


autovacuum_max_workers = 6 


max_connections = 2000  



总memory使用评估:   

shared buffer   shared_buffers  : 24GB
vacuum          autovacuum_work_mem * autovacuum_max_workers  或  maintenance_work_mem * autovacuum_max_workers  : 2G*6=12G    
create index    maintenance_work_mem * 同时创建索引的并发  : 2G * 8 = 16G        (假设同时创建索引的进程为6个)      
group by, sort, hash agg, hash join    并发使用这些操作的SQL * work_mem      :   (max_connections/10)*8MB = 1.6GB  (假设十分之一的连接,每条SQL只用一份work_mem, 实际上复杂SQL可能用多份)     
wal buffer      wal_buffers  :         16MB    
connection      :   max_connections * 10MB    = 20GB      (假设每个连接使用10MB,实际上可能更多,relcache, syscache,与访问的对象有关)

page table      :   页表,与shared_buffers,并发连接,以及连接TOUCH的SHARED BUFFER数,是否使用HUGE PAGE有关
[《PostgreSQL Huge Page 使用建议 - 大内存主机、实例注意》](201803/20180325_02.md)  

Flag Counter

digoal’s 大量PostgreSQL文章入口