2ndQuadrant is now part of EDB

Bringing together some of the world's top PostgreSQL experts.

2ndQuadrant | PostgreSQL
Mission Critical Databases
  • Contact us
  • EN
    • FR
    • IT
    • ES
    • DE
    • PT
  • Support & Services
  • Products
  • Downloads
    • Installers
      • Postgres Installer
      • 2UDA – Unified Data Analytics
    • Whitepapers
      • Business Case for PostgreSQL Support
      • Security Best Practices for PostgreSQL
    • Case Studies
      • Performance Tuning
        • BenchPrep
        • tastyworks
      • Distributed Clusters
        • ClickUp
        • European Space Agency (ESA)
        • Telefónica del Sur
        • Animal Logic
      • Database Administration
        • Agilis Systems
      • Professional Training
        • Met Office
        • London & Partners
      • Database Upgrades
        • Alfred Wegener Institute (AWI)
      • Database Migration
        • International Game Technology (IGT)
        • Healthcare Software Solutions (HSS)
        • Navionics
  • Postgres Learning Center
    • Webinars
      • Upcoming Webinars
      • Webinar Library
    • Whitepapers
      • Business Case for PostgreSQL Support
      • Security Best Practices for PostgreSQL
    • Blog
    • Training
      • Course Catalogue
    • Case Studies
      • Performance Tuning
        • BenchPrep
        • tastyworks
      • Distributed Clusters
        • ClickUp
        • European Space Agency (ESA)
        • Telefónica del Sur
        • Animal Logic
      • Database Administration
        • Agilis Systems
      • Professional Training
        • Met Office
        • London & Partners
      • Database Upgrades
        • Alfred Wegener Institute (AWI)
      • Database Migration
        • International Game Technology (IGT)
        • Healthcare Software Solutions (HSS)
        • Navionics
    • Books
      • PostgreSQL 11 Administration Cookbook
      • PostgreSQL 10 Administration Cookbook
      • PostgreSQL High Availability Cookbook – 2nd Edition
      • PostgreSQL 9 Administration Cookbook – 3rd Edition
      • PostgreSQL Server Programming Cookbook – 2nd Edition
      • PostgreSQL 9 Cookbook – Chinese Edition
    • Videos
    • Events
    • PostgreSQL
      • PostgreSQL – History
      • Who uses PostgreSQL?
      • PostgreSQL FAQ
      • PostgreSQL vs MySQL
      • The Business Case for PostgreSQL
      • Security Information
      • Documentation
  • About Us
    • About 2ndQuadrant
    • 2ndQuadrant’s Passion for PostgreSQL
    • News
    • Careers
    • Team Profile
  • Blog
  • Menu Menu
You are here: Home1 / Blog2 / Francesco's PlanetPostgreSQL3 / PostgreSQL 9.4 for administrators (part two)
2ndQuadrant Press

PostgreSQL 9.4 for administrators (part two)

December 4, 2014/0 Comments/in Francesco's PlanetPostgreSQL /by 2ndQuadrant Press

Written by Francesco Canovai

In the previous instalment, we introduced the logical replication feature which has been added to PostgreSQL 9.4. Let’s go on exploring the multitude of new features that version 9.4 brings to the Operation field, easing the management of PostgreSQL databases for system and database administrators.


pg_prewarm

pg_prewarm is a new extension to solve the problem of slow servers after a restart. Buffers are emptied during a restart, therefore Postgres won’t be able to find in RAM the data it needs, forcing disk reads. With pg_prewarm it is possible to load in memory an important table immediately after a reboot with the simple query:

SELECT pg_prewarm('my_table');

This way, we won’t have to wait for the database to load data in cache through its routine operations.


Tablespace management

Two handy features have been introduced to simplify the usage of tablespaces. The first is the command ALTER TABLESPACE … MOVE, which allows moving tables, indexes and materialised views from one tablespace to another one. The second is the syntax CREATE TABLESPACE … WITH … options, with which it is now possible to set tablespace options while creating tablespaces, saving a second ALTER TABLESPACE. Two parameters are available right now, `seq_page_cost` and `random_page_cost`, which the planner can use to understand which are the faster disks.

CREATE TABLESPACE new_tblspc LOCATION 'my_dir' WITH random_page_cost = 1;
ALTER TABLESPACE old_tblspc MOVE TABLES TO new_tblspc;

WAL archive monitoring

While working on Barman here in 2ndQuadrant, we had to estimate many times the number of WAL segments produced by a server. This is the reason Gabriele Bartolini produced this patch. PostgreSQL 9.4 has a stat table about the archiver activity, showing the number of WAL segments archived since the last reset (and the number of time the archiver failed, in case failures happened).

SELECT * FROM pg_stat_archiver;
-[ RECORD 1 ]------+------------------------------
 archived_count     | 4
 last_archived_wal  | 00000001000000000000000B
 last_archived_time | 2014-10-07 08:58:02.258657+00
 failed_count       | 0
 last_failed_wal    |
 last_failed_time   |
 stats_reset        | 2014-10-07 08:51:29.852523+00

Time delayed standbys

While a standby server is very useful if the master server crashes, its utility is zero in the instance of a human error. A mistakenly run `DROP TABLE` would be replicated immediately on the standby, making a *point in time recovery* a necessity. The possibility of having a replication server which applies the changes with a certain delay gives the admin some time to stop the replication, thus avoiding the propagation of the error and saving the standby server.

To configure a standby server with a delay of at least one hour, it is sufficient to set in the `recovery.conf`

min_recovery_apply_delay = 1h

Modify configuration on the fly

`ALTER SYSTEM` is another new command introduced in version 9.4 to ease working with Postgres. It is now possible to change the `postgresql.conf` file from within a SQL connection. With the sole exception of the `PGDATA` and the parameters that need to be set during compile time, all the other parameters can be changed as in the following example:

ALTER SYSTEM SET wal_level = hot_standby;

The new values will be written in the `postgresql.auto.conf` file. A reload or a restart will still be necessary if the altered parameter requires it.


WAL performance

Write-ahead logging performance has improved. Lock contention has been reduced for insert operations into the WAL, and the WAL record size has been reduced for UPDATEs. Thus the same UPDATE operation would now generate less I/O.


Conclusions

For us Linux sysadmins and DBAs, PostgreSQL 9.4 improves further the management of databases in business continuity. It also lays the groundwork for new horizons in system architectures, with the multi-master replication in sight. Finally, thanks to the logical replication, we will surely see the trigger-based replication tools (Londiste, Slony, Bucardo) add support for event decodification from logical replication slots, making replication management lighter. Keep following our blog for the new article from Giuseppe on the new PostgreSQL features for developers. See you soon!

Tags: 9.4, alter system, pg prewarm, pg stat archiver, postgres, PostgreSQL, tablespace, time delayed standby, wal
Share this entry
  • Share on Facebook
  • Share on Twitter
  • Share on WhatsApp
  • Share on LinkedIn
0 replies

Leave a Reply

Want to join the discussion?
Feel free to contribute!

Leave a Reply Cancel reply

Your email address will not be published. Required fields are marked *

Search

Get in touch with us!

Recent Posts

  • Random Data December 3, 2020
  • Webinar: COMMIT Without Fear – The Beauty of CAMO [Follow Up] November 13, 2020
  • Full-text search since PostgreSQL 8.3 November 5, 2020
  • Random numbers November 3, 2020
  • Webinar: Best Practices for Bulk Data Loading in PostgreSQL [Follow Up] November 2, 2020

Featured External Blogs

Tomas Vondra's Blog

Our Bloggers

  • Simon Riggs
  • Alvaro Herrera
  • Andrew Dunstan
  • Craig Ringer
  • Francesco Canovai
  • Gabriele Bartolini
  • Giulio Calacoci
  • Ian Barwick
  • Marco Nenciarini
  • Mark Wong
  • Pavan Deolasee
  • Petr Jelinek
  • Shaun Thomas
  • Tomas Vondra
  • Umair Shahid

PostgreSQL Cloud

2QLovesPG 2UDA 9.6 backup Barman BDR Business Continuity community conference database DBA development devops disaster recovery greenplum Hot Standby JSON JSONB logical replication monitoring OmniDB open source Orange performance PG12 pgbarman pglogical PG Phriday postgres Postgres-BDR postgres-xl PostgreSQL PostgreSQL 9.6 PostgreSQL10 PostgreSQL11 PostgreSQL 11 PostgreSQL 11 New Features postgresql repmgr Recovery replication security sql wal webinar webinars

Support & Services

24/7 Production Support

Developer Support

Remote DBA for PostgreSQL

PostgreSQL Database Monitoring

PostgreSQL Health Check

PostgreSQL Performance Tuning

Database Security Audit

Upgrade PostgreSQL

PostgreSQL Migration Assessment

Migrate from Oracle to PostgreSQL

Products

HA Postgres Clusters

Postgres-BDR®

2ndQPostgres

pglogical

repmgr

Barman

Postgres Cloud Manager

SQL Firewall

Postgres-XL

OmniDB

Postgres Installer

2UDA

Postgres Learning Center

Introducing Postgres

Blog

Webinars

Books

Videos

Training

Case Studies

Events

About Us

About 2ndQuadrant

What does 2ndQuadrant Mean?

News

Careers 

Team Profile

© 2ndQuadrant Ltd. All rights reserved. | Privacy Policy
  • Twitter
  • LinkedIn
  • Facebook
  • Youtube
  • Mail
Progress on online upgrade BDR for PostgreSQL: Present and future
Scroll to top
×