Thread: Will PQsetSingleRowMode get me results faster?
I've been using LibPQ to get data from PostgreSQL instances with great success.
I'm using PQsendQuery and PQgetResult, but noticed there's also PQsetSingleRowMode.
The documentation is clearly stating it only benefits a limited set of scenario's, but I'm saddened that it can't help to get the first resulte of a (longer running) query faster.
There's a different database solution I won't name here that has a thing they call 'firehose mode' that in fact does this: their equivalent of PQntuples actually returns -1 in this mode, and you're expected to use their equivalent of PQgetResult to get record per record ** as it is rolling in from the server while the query is still running **.
From what I notice using LibPQ, it appears a query needs to complete before resulting data is being transferred to the client. Please correct me if I'm wrong.
Please point me in the correct direction if I'm missing something and I need to look elsewhere. (I just now notice there's a PQsetChunkedRowsMode now —nice! — but I suspect the above still holds.)
Should I attempt to use LIMIT and OFFSET to limit the running time of queries to get results faster? This will still interrupt the query and add overhead of starting and stopping each query, even using PQexecPrepared, I guess...
Greetings
Stijn
On Mon, Jan 6, 2025 at 12:21 PM Stijn Sanders <stijnsanders@gmail.com> wrote: > I've been using LibPQ to get data from PostgreSQL instances with great success. > I'm using PQsendQuery and PQgetResult, but noticed there's also PQsetSingleRowMode. > The documentation is clearly stating it only benefits a limited set of scenario's, but I'm saddened that it can't helpto get the first resulte of a (longer running) query faster. I haven't used single-row-mode myself, but I can tell you that using a cursor instead of a statement allows you to reduce your time-to-first-row. But at the expense of overall performance, i.e. in my (limited) testing, getting the whole result-set in one go is faster than getting the same rows via a cursor, even in varying chunk sizes. Another alternative is to use COPY, which gets your the rows as they come, but then you're on your own to "decode" the row and its select-clause. FWIW. --DD
Stijn Sanders wrote: > From what I notice using LibPQ, it appears a query needs to complete > before resulting data is being transferred to the client. Please > correct me if I'm wrong. No, the query does not need to complete. If you run something like "select * from bigtable" in single-row or chunked mode, you should see that the first results are typically available immediately to the application, while the query is far from finished. But it depends on the query plan. A lot of queries cannot produce any result until the final stage of their execution. For these, you can't expect any difference in how fast the first results are available client-side. Best regards, -- Daniel Vérité https://postgresql.verite.pro/ Twitter: @DanielVerite
"Daniel Verite" <daniel@manitou-mail.org> writes: > Stijn Sanders wrote: >> From what I notice using LibPQ, it appears a query needs to complete >> before resulting data is being transferred to the client. Please >> correct me if I'm wrong. > No, the query does not need to complete. If you run something like > "select * from bigtable" in single-row or chunked mode, you should > see that the first results are typically available immediately to the > application, while the query is far from finished. > But it depends on the query plan. A lot of queries cannot produce any > result until the final stage of their execution. For these, you can't > expect any difference in how fast the first results are available > client-side. Right. But there's yet another moving part here: when creating a plan for a cursor query, the planner will give some preference (not infinite preference, but some) to plans that are expected to produce their first result row sooner. For example it might pick an indexscan plan on a suitably-ordered index over a seqscan-and-sort plan, even if the indexscan is estimated to take more time to run to completion. So in principle, you might get best results by defining your query with DECLARE CURSOR and then using PQsetSingleRowMode on the FETCH. But it'd really depend on the particular query whether this gives any benefit. regards, tom lane
On Mon, Jan 6, 2025 at 9:06 PM Tom Lane <tgl@sss.pgh.pa.us> wrote: > So in principle, you might get best results by defining your query > with DECLARE CURSOR and then using PQsetSingleRowMode on the FETCH. > But it'd really depend on the particular query whether this gives > any benefit. That's a really nice suggestion, and it took me some time to set up a suitable test environment to see if it would work, but using separate PQsendquery/PQexec calls for: start transaction read only declare cr1 no scroll cursor for select (and the rest of my query) fetch next in cr1 it seems like the fetch instruction still takes about as much time as the full 'normal' select would, I tried a few different queries, but I'm still suspecting PostgreSQL's internals is waiting for the data to all 'be ready' before it can send any data over, even if these PQgetResult's for each fetch will have a PQntuples of 1. (I even tried with "fetch 8", and PQntuples neatly serves 8 at a time, but still after about the same time PQsendquery(,'select... would take) Or could there still be something that I'm doing that prevents 'firehosing'?
On Fri, 2025-04-04 at 13:41 +0200, Stijn Sanders wrote: > On Mon, Jan 6, 2025 at 9:06 PM Tom Lane <tgl@sss.pgh.pa.us> wrote: > > So in principle, you might get best results by defining your query > > with DECLARE CURSOR and then using PQsetSingleRowMode on the FETCH. > > But it'd really depend on the particular query whether this gives > > any benefit. > > That's a really nice suggestion, and it took me some time to set up a > suitable test environment to see if it would work, but using separate > PQsendquery/PQexec calls for: > > start transaction read only > declare cr1 no scroll cursor for select (and the rest of my query) > fetch next in cr1 > > it seems like the fetch instruction still takes about as much time as > the full 'normal' select would, I tried a few different queries, but > I'm still suspecting PostgreSQL's internals is waiting for the data to > all 'be ready' before it can send any data over, even if these > PQgetResult's for each fetch will have a PQntuples of 1. > (I even tried with "fetch 8", and PQntuples neatly serves 8 at a time, > but still after about the same time PQsendquery(,'select... would > take) > Or could there still be something that I'm doing that prevents 'firehosing'? That looks like you are doing everything right, but there just isn't a "fast start" execution plan, and calculating the first row already is taking a lot of time. Perhaps you can tell PostgreSQL to optimize for a fast start plan more aggressively by lowering "cursor_tuple_fraction" inside the transaction: SET LOCAL cursor_tuple_fraction = 0.001; Yours, Laurenz Albe