You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
PostgREST generates a query that doesn't returns the updated row:
WITH pgrst_source AS (
UPDATE"public"."jobs"SET"started_at"="pgrst_body"."started_at"FROM
(SELECT $1AS json_data) pgrst_payload,
LATERAL (SELECT"started_at"FROM json_to_record(pgrst_payload.json_data) AS _("started_at"timestamp with time zone) ) pgrst_body
WHERE"public"."jobs"."id"= $2AND ( "public"."jobs"."started_at" IS NULLOR"public"."jobs"."started_at"< $3)
RETURNING "public"."jobs"."id", "public"."jobs"."started_at"
)
SELECT''AS total_result_set, pg_catalog.count(_postgrest_t) AS page_total,
array[]::text[] AS header, coalesce(json_agg(_postgrest_t)->0, 'null') AS body,
nullif(current_setting('response.headers', true), '') AS response_headers,
nullif(current_setting('response.status', true), '') AS response_status,
''AS response_inserted
FROM (
SELECT"jobs"."started_at"FROM"pgrst_source"AS"jobs"WHERE ( "jobs"."started_at" IS NULLOR"jobs"."started_at"< $4)
);
The problem is the last WHERE clause because at this stage started_at has already been set to now() which can't be less then a moment in the past.
Furthermore, if you try to remove started_at from select:
you'll recieve an error because the following query is invalid:
WITH pgrst_source AS (
UPDATE"public"."jobs"SET"started_at"="pgrst_body"."started_at"FROM (
SELECT $1AS json_data) pgrst_payload,
LATERAL (SELECT"started_at"FROM json_to_record(pgrst_payload.json_data) AS _("started_at"timestamp with time zone) ) pgrst_body
WHERE"public"."jobs"."id"= $2AND ( "public"."jobs"."started_at" IS NULLOR"public"."jobs"."started_at"< $3)
RETURNING "public"."jobs"."id"
)
SELECT''AS total_result_set, pg_catalog.count(_postgrest_t) AS page_total,
array[]::text[] AS header, coalesce(json_agg(_postgrest_t)->0, 'null') AS body,
nullif(current_setting('response.headers', true), '') AS response_headers,
nullif(current_setting('response.status', true), '') AS response_status,
''AS response_inserted
FROM (
SELECT"jobs"."id"FROM"pgrst_source"AS"jobs"WHERE ( "jobs"."started_at" IS NULLOR"jobs"."started_at"< $4)
);
Notice the pgrst_source here, it contains only id but the WHERE clause still references started_at.
Looks like the problem is related to the or operator because when I use is.null:
there is no WHERE clause in the generated by PostgREST query:
WITH pgrst_source AS (
UPDATE"public"."jobs"SET"started_at"="pgrst_body"."started_at"FROM
(SELECT $1AS json_data) pgrst_payload,
LATERAL (SELECT"started_at"FROM json_to_record(pgrst_payload.json_data) AS _("started_at"timestamp with time zone) ) pgrst_body
WHERE"public"."jobs"."id"= $2AND"public"."jobs"."started_at"< $3
RETURNING "public"."jobs"."id", "public"."jobs"."started_at"
)
SELECT''AS total_result_set, pg_catalog.count(_postgrest_t) AS page_total,
array[]::text[] AS header, coalesce(json_agg(_postgrest_t)->0, 'null') AS body,
nullif(current_setting('response.headers', true), '') AS response_headers,
nullif(current_setting('response.status', true), '') AS response_status,
''AS response_inserted
FROM (
SELECT"jobs"."started_at"FROM"pgrst_source"AS"jobs"
);
This is expected behavior and or operator should not add WHERE clause as I understand.
The text was updated successfully, but these errors were encountered:
Environment
Description of issue
I faced a problem when trying to update a timestamp column and return the updated value.
Here is the table structure:
I want to update and return a job if it has not been started yet or if it was started more then one minute ago.
But when I make the following query using supabase:
PostgREST generates a query that doesn't returns the updated row:
The problem is the last WHERE clause because at this stage
started_at
has already been set tonow()
which can't be less then a moment in the past.Furthermore, if you try to remove
started_at
from select:you'll recieve an error because the following query is invalid:
Notice the
pgrst_source
here, it contains onlyid
but the WHERE clause still referencesstarted_at
.Looks like the problem is related to the
or
operator because when I useis.null
:or
lt.
separately:there is no WHERE clause in the generated by PostgREST query:
This is expected behavior and
or
operator should not add WHERE clause as I understand.The text was updated successfully, but these errors were encountered: