Understanding WAL Files in PostgreSQL – For Oracle DBAs
What is WAL?
WAL (Write-Ahead Logging) ensures data durability and crash recovery. Every change is first written to WAL before being flushed to data files.
1. WAL Location: WAL files are stored in $PGDATA/pg_wal/.
2. Fixed Size: Each WAL segment is pre-allocated with a fixed size (typically 16MB), set at cluster initialization (initdb).
3. Writing & Switching: WAL segments are written sequentially. PostgreSQL switches to the next segment when the current one is full or a manual switch is triggered (e.g., via pg_switch_wal()).
4. WAL and Archive File Size: When archived, the exact same 16MB WAL segment file is copied as raw binary to the archive destination. Therefore, archive files always match the WAL segment size.
5. Archiving: If archive_mode = on, PostgreSQL uses the archive_command to copy completed WAL segments to the archive destination (e.g., /pgArch/...). Only full segments are archived.
6. Recycling: If archiving is disabled, PostgreSQL reuses old WAL segments once they’re no longer needed for recovery or replication.
WAL Files = Redo Log Files
WAL Archives = Archive Log Files
PostgreSQL vs Oracle Comparison
Aspect | Oracle | PostgreSQL |
---|---|---|
Redo Log Files | Called Redo Log Files | Called WAL Files |
Archive Log Files | Called Archive Log Files | Called WAL Archives |
Redo Log File Size | ~200MB (default) | 16MB (default and fixed) |
Redo Log Files Count | Minimum 2 or more redo log groups (Best practice: 3) | No fixed number Controlled by: min_wal_size / wal_segment_size Example: 80MB / 16MB = 5 WAL files |
Archive Log File Size | ~200MB (same as redo log file size) | 16MB (same as WAL file size) |
Log File Storage | Redo log files stored in redo log groups | WAL files stored in pg_wal directory |
Archiving Mechanism | Archive logs created if archiving is enabled | Archived via archive_command if archive_mode = on |
Overwrite Behavior | Redo logs are overwritten when full (if archive not enabled) | WAL segments are recycled/overwritten when full (if archive_mode is off) |
Force Switch Behavior | ALTER SYSTEM SWITCH LOGFILE; | SELECT pg_switch_wal(); |
PostgreSQL WAL Configuration Parameters
Parameter | Meaning | Default |
---|---|---|
wal_segment_size | Size of each WAL file | 16MB |
min_wal_size | Minimum total WAL size retained | 80MB (5 WAL files) Common in production: 8GB |
max_wal_size | Max WAL before triggering a checkpoint | 1GB Common in production: 16GB |
Check Configuration
[postgres@lxicbpgdsgv01 ~]$ psql -c "SHOW wal_segment_size;"
wal_segment_size
------------------
16MB <----- Each redo log file size
(1 row)
[postgres@lxicbpgdsgv01 ~]$
[postgres@lxicbpgdsgv01 ~]$ psql -c "SHOW min_wal_size;"
min_wal_size
--------------
80MB <---- 80MB/16MB = 5 <--- Total 5 redo log files with each 16MB
(1 row)
[postgres@lxicbpgdsgv01 ~]$
[postgres@lxicbpgdsgv01 ~]$ psql -c "SHOW max_wal_size;"
max_wal_size
--------------
1GB <---- 1024MB
(1 row)
[postgres@lxicbpgdsgv01 ~]$
View WAL files (Redo log files)
postgres=# SELECT current_setting('data_directory') || '/pg_wal' AS wal_directory;
wal_directory
-----------------------------
/pgData/pgsql17/data/pg_wal <---- Redo log file directory
(1 row)
postgres=#
[postgres@lxicbpgdsgv01 ~]$ ls -lh /pgData/pgsql17/data/pg_wal | grep -E '^-.* [0-9]+ .* [0-9A-F]{24}$'
-rw-------. 1 postgres postgres 16M Oct 8 01:33 000000010000000000000005
-rw-------. 1 postgres postgres 16M Oct 8 01:28 000000010000000000000006
-rw-------. 1 postgres postgres 16M Oct 8 01:28 000000010000000000000007
[postgres@lxicbpgdsgv01 ~]$
min_wal_size = 80MB means PostgreSQL will try to keep at least 5 WAL segment files on disk (since 80MB ÷ 16MB = 5 files).
However, in our case, only 3 WAL files are currently present. This is likely because the system is under low load in the testing environment, so fewer WAL files are needed at the moment.
---- Lets Generate Load
postgres=# -- Create test table
DROP TABLE IF EXISTS wal_test;
CREATE TABLE wal_test (
id serial PRIMARY KEY,
data text
);
-- Generate WAL traffic
DO $$
DECLARE
i integer;
BEGIN
FOR i IN 1..50 LOOP
-- INSERT: 10,000 rows
INSERT INTO wal_test (data)
SELECT repeat('wal_test_data_', 50)
FROM generate_series(1, 10000);
-- UPDATE: 5,000 rows using CTE with LIMIT
WITH to_update AS (
SELECT id FROM wal_test WHERE id % 2 = 0 LIMIT 5000
)
UPDATE wal_test
SET data = data || '_updated'
WHERE id IN (SELECT id FROM to_update);
-- DELETE: 5,000 rows using CTE with LIMIT
WITH to_delete AS (
SELECT id FROM wal_test WHERE id % 3 = 0 LIMIT 5000
)
DELETE FROM wal_test
WHERE id IN (SELECT id FROM to_delete);
-- Commit to flush WAL
COMMIT;
-- Optional pause to slow down the loop
PERFORM pg_sleep(0.5);
END LOOP;
END$$;
DROP TABLE
CREATE TABLE
DO
postgres=# exit
[postgres@lxicbpgdsgv01 ~]$
[postgres@lxicbpgdsgv01 ~]$
ls -lrth /pgData/pgsql17/data/pg_wal
total 752M
drwx------. 2 postgres postgres 6 Sep 30 21:50 summaries
-rw-------. 1 postgres postgres 16M Oct 8 16:34 000000010000000000000009
-rw-------. 1 postgres postgres 16M Oct 8 16:34 00000001000000000000000A
-rw-------. 1 postgres postgres 16M Oct 8 16:34 00000001000000000000000B
-rw-------. 1 postgres postgres 16M Oct 8 16:34 00000001000000000000000C
-rw-------. 1 postgres postgres 16M Oct 8 16:34 00000001000000000000000D
-rw-------. 1 postgres postgres 16M Oct 8 16:34 00000001000000000000000E
-rw-------. 1 postgres postgres 16M Oct 8 16:34 00000001000000000000000F
-rw-------. 1 postgres postgres 16M Oct 8 16:34 000000010000000000000010
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000011
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000012
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000013
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000014
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000015
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000016
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000017
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000018
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000019
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000001A
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000001B
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000001C
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000001D
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000001E
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000001F
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000020
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000021
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000022
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000023
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000024
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000025
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000026
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000027
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000028
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000029
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000002A
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000002B
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000002C
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000002D
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000002E
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000002F
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000030
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000031
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000032
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000033
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000034
-rw-------. 1 postgres postgres 16M Oct 8 16:36 000000010000000000000035
drwx------. 2 postgres postgres 4.0K Oct 8 16:36 archive_status
-rw-------. 1 postgres postgres 16M Oct 8 16:36 xlogtemp.7289
[postgres@lxicbpgdsgv01 ~]$
-- Now We can see Many WAL Files (Redo log files) generated, count increased from 3 WAL files to 50+ WAL files
View Archived WAL Files (Archive log files)
postgres=# SHOW archive_command;
archive_command
-------------------------------
cp %p /pgArch/pgsql17/arch/%f
(1 row)
postgres=#
[postgres@lxicbpgdsgv01 ~]$
[postgres@lxicbpgdsgv01 ~]$ ls -lrth /pgArch/pgsql17/arch/
total 976M
-rw-------. 1 postgres postgres 16M Oct 7 23:50 000000010000000000000001
-rw-------. 1 postgres postgres 16M Oct 7 23:51 000000010000000000000002
-rw-------. 1 postgres postgres 16M Oct 8 01:28 000000010000000000000003
-rw-------. 1 postgres postgres 16M Oct 8 01:28 000000010000000000000004
-rw-------. 1 postgres postgres 16M Oct 8 04:24 000000010000000000000005
-rw-------. 1 postgres postgres 16M Oct 8 16:08 000000010000000000000006
-rw-------. 1 postgres postgres 16M Oct 8 16:24 000000010000000000000007
-rw-------. 1 postgres postgres 16M Oct 8 16:25 000000010000000000000008
-rw-------. 1 postgres postgres 16M Oct 8 16:34 000000010000000000000009
-rw-------. 1 postgres postgres 16M Oct 8 16:34 00000001000000000000000A
-rw-------. 1 postgres postgres 16M Oct 8 16:34 00000001000000000000000B
-rw-------. 1 postgres postgres 16M Oct 8 16:34 00000001000000000000000C
-rw-------. 1 postgres postgres 16M Oct 8 16:34 00000001000000000000000D
-rw-------. 1 postgres postgres 16M Oct 8 16:34 00000001000000000000000E
-rw-------. 1 postgres postgres 16M Oct 8 16:34 00000001000000000000000F
-rw-------. 1 postgres postgres 16M Oct 8 16:34 000000010000000000000010
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000011
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000012
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000013
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000014
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000015
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000016
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000017
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000018
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000019
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000001A
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000001B
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000001C
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000001D
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000001E
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000001F
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000020
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000021
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000022
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000023
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000024
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000025
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000026
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000027
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000028
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000029
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000002A
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000002B
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000002C
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000002D
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000002E
-rw-------. 1 postgres postgres 16M Oct 8 16:35 00000001000000000000002F
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000030
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000031
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000032
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000033
-rw-------. 1 postgres postgres 16M Oct 8 16:35 000000010000000000000034
-rw-------. 1 postgres postgres 16M Oct 8 16:36 000000010000000000000035
-rw-------. 1 postgres postgres 16M Oct 8 16:36 000000010000000000000036
-rw-------. 1 postgres postgres 16M Oct 8 16:36 000000010000000000000037
-rw-------. 1 postgres postgres 16M Oct 8 16:36 000000010000000000000038
-rw-------. 1 postgres postgres 16M Oct 8 16:36 000000010000000000000039
-rw-------. 1 postgres postgres 16M Oct 8 16:36 00000001000000000000003A
-rw-------. 1 postgres postgres 16M Oct 8 16:36 00000001000000000000003B
-rw-------. 1 postgres postgres 16M Oct 8 16:36 00000001000000000000003C
-rw-------. 1 postgres postgres 16M Oct 8 16:36 00000001000000000000003D
[postgres@lxicbpgdsgv01 ~]$
-- WAL and Archive File Size: When archived, the exact same 16MB WAL segment file is copied as raw binary to the archive destination. Therefore, archive files always match the WAL segment size (redo log size).
Best Practices
- Use a dedicated mount point for
pg_wal
(WAL directory) – eg. /pgWal - Set
min_wal_size
to higher value in production (e.g. 8GB) - Keep WAL archive files on a separate mount point for better I/O and space isolation – eg. /pgArch
- Monitor WAL archive directory regularly to avoid disk full errors
Note:
- WAL file size is fixed at cluster init (default: 16MB). You cannot change it for an existing cluster.
- PostgreSQL WAL Size Be Can Increased only at NEW cluster creation time via initdb (64MB)
/usr/pgsql-17/bin/initdb –wal-segsize=64 -D /pgData/pgsql17/data
Caution: Your use of any information or materials on this website is entirely at your own risk. It is provided for educational purposes only. It has been tested internally, however, we do not guarantee that it will work for you. Ensure that you run it in your test environment before using.
Thank you,
Rajasekhar Amudala
Email: br8dba@gmail.com
Linkedin: https://www.linkedin.com/in/rajasekhar-amudala/