
In my previous post “Three Configuration Parameters for PostgreSQL That Are Worth Further Investigation!“, I introduced three PostgreSQL parameters that I feel are the most “neglected” and present the most opportunity for performance tuning in a PostgreSQL instance. I’ve previously discussed “work_mem” in a previous post, so in Part 2 of this series, I would like to demonstrate tuning the “effective_io_concurrency” parameter. While this parameter has been discussed in other blogs, I will attempt to make this discussion relevant to how it might affect a CloudSQL instance.
The parameter “effective_io_concurrency” reflects the number of simultaneous requests that can be handled efficiently by the disk subsystem. One thing to keep in mind is that currently this parameter only effects “bitmap_heap_scans” where the data is not already present in the shared buffer. In general, if using spinning HDD devices, this should be set to reflect the number of drives that participate in the RAID stripe. In cases where SSDs are used, you can set this value much higher, although you must take into account any Quality of Service I/O ops limits which are usually present in a cloud implementation. A full explanation of the parameter can be found here.
To do a simple demonstration of how this parameter can effect queries, I set up a small Google CloudSQL for Postgres instance (2 vCPU X 8GB memory) and loaded up some tables, then executed a query that ensured a “bitmap heap scan” changing “effective_io_concurrency” parameter between each test. In addition, the instance was bounced before each test to ensure that the shared buffers were cleared.
Setup:
CREATE TABLE public.effective_io_concurrency_test ( id int PRIMARY KEY, value numeric, product_id int, effective_date timestamp(3) ); INSERT INTO public.effective_io_concurrency_test VALUES ( generate_series(0,100000000), random()*1000, random()*100, current_timestamp(3)); CREATE INDEX prod_id_idx ON public.effective_io_concurrency_test (product_id); VACUUM ANALYZE public.effective_io_concurrency_test;
Execution:
The resulting query plans did not show any variation in execution path or cost, but the timings did vary across the tests.
EXPLAIN (analyze, verbose, costs, settings, buffers, wal, timing, summary, format text)
SELECT * FROM public.effective_io_concurrency_test
WHERE id BETWEEN 10000 AND 100000;
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Bitmap Heap Scan on public.effective_io_concurrency_test (cost=7035.15..522009.95 rows=547023 width=27) (actual time=293.542..33257.631 rows=588784 loops=1)
Output: id, value, product_id, effective_date
Recheck Cond: (((effective_io_concurrency_test.id >= 10000) AND (effective_io_concurrency_test.id = 100) AND (effective_io_concurrency_test.product_id BitmapOr (cost=7035.15..7035.15 rows=547450 width=0) (actual time=156.951..156.954 rows=0 loops=1)
Buffers: shared hit=6 read=668
I/O Timings: read=24.501
-> Bitmap Index Scan on effective_io_concurrency_test_pkey (cost=0.00..1459.74 rows=94117 width=0) (actual time=14.908..14.908 rows=90001 loops=1)
Index Cond: ((effective_io_concurrency_test.id >= 10000) AND (effective_io_concurrency_test.id Bitmap Index Scan on prod_id_idx (cost=0.00..5301.90 rows=453333 width=0) (actual time=142.040..142.040 rows=499255 loops=1)
Index Cond: ((effective_io_concurrency_test.product_id >= 100) AND (effective_io_concurrency_test.product_id <= 200))
Buffers: shared hit=3 read=421
I/O Timings: read=14.154
Settings: effective_cache_size = '3259448kB', effective_io_concurrency = '8', random_page_cost = '2', work_mem = '512MB'
Query Identifier: -8974663893066369302
Planning:
Buffers: shared hit=103 read=17
I/O Timings: read=26.880
Planning Time: 28.350 ms
Execution Time: 33322.389 ms
Summary:
| effective_io_concurrency | Query Time |
|---|---|
| 1 /* CloudSQL Default */ | 194708.918 ms |
| 2 /* Equal number of CPU */ | 107953.205 ms |
| 4 /* 2x number of CPU */ | 58161.010 ms |
| 8 /* 4x number of CPU */ | 33322.389 ms |
| 10 /* 5x number of CPU */ | 30118.593 ms |
| 20 /* 6x number of CPU */ | 28758.106 ms |
As you can see, there is a diminishing return as we increased the parameter, but why? Upon looking at Google Cloud Console “System Insights” the reason was clear.




**** One thing to note, is that the CPU Utilization spike is a result of the shutdown and restart of the instance between each test. The utilization following the spike represents the utilization found during the test itself.
The Conclusion:
While CPU utilization didn’t hit any limit, the IOPS limits for that CloudSQL shape did. You can add IOPS by changing the shape, but the point of this was to show that the optimal setting always depends on your workload and instance shape. In this case and for this CloudSQL shape, you might actually want to choose a setting of “4” which represents a setting of 2x the number of CPU and one that doesn’t quite max out the guaranteed IOPS. The setting doesn’t get you the fastest query time, but does leave resources left over for other queries to execute at the same time.
As always, be sure to test any changed in your own system and balance accordingly because your “mileage may vary” depending on your individual situation. That being said, in almost no cases is the default setting acceptable unless you are running HDD or on an OS which lacks “posix_fadvise” function (like MacOS or Solaris).
Enjoy!

Pingback: Tuning the PostgreSQL “random_page_cost” Parameter | 🛩️ Shane Borden's Technology Blog
How to change effective_io_concurrency is not available as Cloud SQL flag and it’s not possible to change postgresql system settings because it need superuser privileges (Any features that require SUPERUSER privileges are not unsupported in Cloud SQL)
LikeLike
Getting that flag exposed to the end user is actually on the road map. In the meantime you can set it at the individual session or user level with a “SET SESSION” or “ALTER USER”.
LikeLike
Hello, really appreciate your post!!
I also would like to test this flag, but having difficult time setting this flag to a different value.
Could you give example query/instructions as to how I can change this value at session/user level? Any help would be greatly appreciated. Thanks a lot!
LikeLike
This should work:
ALTER USER name SET parameter { TO | = } { value | DEFAULT }
ALTER USER name RESET parameter
LikeLike
Pingback: Tuning PostgreSQL performance for SSD | Frederik Himpe