<div style="display: flex; flex-wrap: wrap; white-space: pre-wrap; align-items: center; "><img height="20" width="20" style="border-radius:50%; margin-right: 4px;" decoding="async" src="https://avatars.githubusercontent.com/u/147741?s=20&v=4" /><strong>tomhughes</strong> left a comment <a href="https://github.com/openstreetmap/openstreetmap-website/pull/6347#issuecomment-3226054386">(openstreetmap/openstreetmap-website#6347)</a></div>
<p dir="auto">It would have been better if I'd tested that the results were correct though, which they aren't :-(</p>
<p dir="auto">You can get rid of the nested grouping but you do still need the union, like this:</p>
<div class="highlight highlight-source-sql" dir="auto"><pre class="notranslate">WITH changes <span class="pl-k">AS</span> (
    <span class="pl-k">SELECT</span>
      <span class="pl-c1">nodes</span>.<span class="pl-c1">changeset_id</span>,
      CASE WHEN <span class="pl-c1">nodes</span>.<span class="pl-c1">version</span> <span class="pl-k">=</span> <span class="pl-c1">1</span> THEN <span class="pl-c1">1</span> ELSE <span class="pl-c1">0</span> END <span class="pl-k">AS</span> num_created_nodes,
      CASE WHEN <span class="pl-c1">nodes</span>.<span class="pl-c1">version</span> <span class="pl-k">></span> <span class="pl-c1">1</span> <span class="pl-k">AND</span> <span class="pl-c1">nodes</span>.<span class="pl-c1">visible</span> THEN <span class="pl-c1">1</span> ELSE <span class="pl-c1">0</span> END <span class="pl-k">AS</span> num_modified_nodes,
      CASE WHEN <span class="pl-c1">nodes</span>.<span class="pl-c1">version</span> <span class="pl-k">></span> <span class="pl-c1">1</span> <span class="pl-k">AND</span> NOT <span class="pl-c1">nodes</span>.<span class="pl-c1">visible</span> THEN <span class="pl-c1">1</span> ELSE <span class="pl-c1">0</span> END <span class="pl-k">AS</span> num_deleted_nodes,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_created_ways,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_modified_ways,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_deleted_ways,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_created_relations,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_modified_relations,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_deleted_relations
    <span class="pl-k">FROM</span> nodes
    <span class="pl-k">WHERE</span> <span class="pl-c1">nodes</span>.<span class="pl-c1">changeset_id</span> <span class="pl-k">=</span> ANY($<span class="pl-c1">1</span>::<span class="pl-k">bigint</span>[])
  <span class="pl-k">UNION ALL</span>
    <span class="pl-k">SELECT</span>
      <span class="pl-c1">ways</span>.<span class="pl-c1">changeset_id</span>,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_created_nodes,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_modified_nodes,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_deleted_nodes,
      CASE WHEN <span class="pl-c1">ways</span>.<span class="pl-c1">version</span> <span class="pl-k">=</span> <span class="pl-c1">1</span> THEN <span class="pl-c1">1</span> ELSE <span class="pl-c1">0</span> END <span class="pl-k">AS</span> num_created_ways,
      CASE WHEN <span class="pl-c1">ways</span>.<span class="pl-c1">version</span> <span class="pl-k">></span> <span class="pl-c1">1</span> <span class="pl-k">AND</span> <span class="pl-c1">ways</span>.<span class="pl-c1">visible</span> THEN <span class="pl-c1">1</span> ELSE <span class="pl-c1">0</span> END <span class="pl-k">AS</span> num_modified_ways,
      CASE WHEN <span class="pl-c1">ways</span>.<span class="pl-c1">version</span> <span class="pl-k">></span> <span class="pl-c1">1</span> <span class="pl-k">AND</span> NOT <span class="pl-c1">ways</span>.<span class="pl-c1">visible</span> THEN <span class="pl-c1">1</span> ELSE <span class="pl-c1">0</span> END <span class="pl-k">AS</span> num_deleted_ways,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_created_relations,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_modified_relations,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_deleted_relations
    <span class="pl-k">FROM</span> ways
    <span class="pl-k">WHERE</span> <span class="pl-c1">ways</span>.<span class="pl-c1">changeset_id</span> <span class="pl-k">=</span> ANY($<span class="pl-c1">1</span>::<span class="pl-k">bigint</span>[])
  <span class="pl-k">UNION ALL</span>
    <span class="pl-k">SELECT</span>
      <span class="pl-c1">relations</span>.<span class="pl-c1">changeset_id</span>,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_created_nodes,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_modified_nodes,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_deleted_nodes,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_created_ways,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_modified_ways,
      <span class="pl-c1">0</span> <span class="pl-k">AS</span> num_deleted_ways,
      CASE WHEN <span class="pl-c1">relations</span>.<span class="pl-c1">version</span> <span class="pl-k">=</span> <span class="pl-c1">1</span> THEN <span class="pl-c1">1</span> ELSE <span class="pl-c1">0</span> END <span class="pl-k">AS</span> num_created_relations,
      CASE WHEN <span class="pl-c1">relations</span>.<span class="pl-c1">version</span> <span class="pl-k">></span> <span class="pl-c1">1</span> <span class="pl-k">AND</span> <span class="pl-c1">relations</span>.<span class="pl-c1">visible</span> THEN <span class="pl-c1">1</span> ELSE <span class="pl-c1">0</span> END <span class="pl-k">AS</span> num_modified_relations,
      CASE WHEN <span class="pl-c1">relations</span>.<span class="pl-c1">version</span> <span class="pl-k">></span> <span class="pl-c1">1</span> <span class="pl-k">AND</span> NOT <span class="pl-c1">relations</span>.<span class="pl-c1">visible</span> THEN <span class="pl-c1">1</span> ELSE <span class="pl-c1">0</span> END <span class="pl-k">AS</span> num_deleted_relations
    <span class="pl-k">FROM</span> relations
    <span class="pl-k">WHERE</span> <span class="pl-c1">relations</span>.<span class="pl-c1">changeset_id</span> <span class="pl-k">=</span> ANY($<span class="pl-c1">1</span>::<span class="pl-k">bigint</span>[])
),
total <span class="pl-k">AS</span> (
  <span class="pl-k">SELECT</span>
    <span class="pl-c1">changes</span>.<span class="pl-c1">changeset_id</span>,
    <span class="pl-c1">SUM</span>(<span class="pl-c1">changes</span>.<span class="pl-c1">num_created_nodes</span>) <span class="pl-k">AS</span> num_created_nodes,
    <span class="pl-c1">SUM</span>(<span class="pl-c1">changes</span>.<span class="pl-c1">num_modified_nodes</span>) <span class="pl-k">AS</span> num_modified_nodes,
    <span class="pl-c1">SUM</span>(<span class="pl-c1">changes</span>.<span class="pl-c1">num_deleted_nodes</span>) <span class="pl-k">AS</span> num_deleted_nodes,
    <span class="pl-c1">SUM</span>(<span class="pl-c1">changes</span>.<span class="pl-c1">num_created_ways</span>) <span class="pl-k">AS</span> num_created_ways,
    <span class="pl-c1">SUM</span>(<span class="pl-c1">changes</span>.<span class="pl-c1">num_modified_ways</span>) <span class="pl-k">AS</span> num_modified_ways,
    <span class="pl-c1">SUM</span>(<span class="pl-c1">changes</span>.<span class="pl-c1">num_deleted_ways</span>) <span class="pl-k">AS</span> num_deleted_ways,
    <span class="pl-c1">SUM</span>(<span class="pl-c1">changes</span>.<span class="pl-c1">num_created_relations</span>) <span class="pl-k">AS</span> num_created_relations,
    <span class="pl-c1">SUM</span>(<span class="pl-c1">changes</span>.<span class="pl-c1">num_modified_relations</span>) <span class="pl-k">AS</span> num_modified_relations,
    <span class="pl-c1">SUM</span>(<span class="pl-c1">changes</span>.<span class="pl-c1">num_deleted_relations</span>) <span class="pl-k">AS</span> num_deleted_relations
  <span class="pl-k">FROM</span> changes
  <span class="pl-k">GROUP BY</span> <span class="pl-c1">changes</span>.<span class="pl-c1">changeset_id</span>
)
<span class="pl-k">UPDATE</span> changesets
<span class="pl-k">SET</span> num_created_nodes      <span class="pl-k">=</span> <span class="pl-c1">total</span>.<span class="pl-c1">num_created_nodes</span>,
    num_modified_nodes     <span class="pl-k">=</span> <span class="pl-c1">total</span>.<span class="pl-c1">num_modified_nodes</span>,
    num_deleted_nodes      <span class="pl-k">=</span> <span class="pl-c1">total</span>.<span class="pl-c1">num_deleted_nodes</span>,
    num_created_ways       <span class="pl-k">=</span> <span class="pl-c1">total</span>.<span class="pl-c1">num_created_ways</span>,
    num_modified_ways      <span class="pl-k">=</span> <span class="pl-c1">total</span>.<span class="pl-c1">num_modified_ways</span>,
    num_deleted_ways       <span class="pl-k">=</span> <span class="pl-c1">total</span>.<span class="pl-c1">num_deleted_ways</span>,
    num_created_relations  <span class="pl-k">=</span> <span class="pl-c1">total</span>.<span class="pl-c1">num_created_relations</span>,
    num_modified_relations <span class="pl-k">=</span> <span class="pl-c1">total</span>.<span class="pl-c1">num_modified_relations</span>,
    num_deleted_relations  <span class="pl-k">=</span> <span class="pl-c1">total</span>.<span class="pl-c1">num_deleted_relations</span>
<span class="pl-k">FROM</span> total
<span class="pl-k">WHERE</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">id</span> <span class="pl-k">=</span> <span class="pl-c1">total</span>.<span class="pl-c1">changeset_id</span></pre></div>
<p dir="auto">It turns out though that there doesn't seem to be much point as a naive version using subqueries is just as fast:</p>
<div class="highlight highlight-source-sql" dir="auto"><pre class="notranslate"><span class="pl-k">UPDATE</span> changesets
   <span class="pl-k">SET</span> num_created_nodes <span class="pl-k">=</span> (<span class="pl-k">SELECT</span> <span class="pl-c1">COUNT</span>(<span class="pl-k">*</span>) <span class="pl-k">FROM</span> nodes <span class="pl-k">WHERE</span> changeset_id <span class="pl-k">=</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">id</span> <span class="pl-k">AND</span> version <span class="pl-k">=</span> <span class="pl-c1">1</span>),
       num_modified_nodes <span class="pl-k">=</span> (<span class="pl-k">SELECT</span> <span class="pl-c1">COUNT</span>(<span class="pl-k">*</span>) <span class="pl-k">FROM</span> nodes <span class="pl-k">WHERE</span> changeset_id <span class="pl-k">=</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">id</span> <span class="pl-k">AND</span> version <span class="pl-k">></span> <span class="pl-c1">1</span> <span class="pl-k">AND</span> visible),
       num_deleted_nodes <span class="pl-k">=</span> (<span class="pl-k">SELECT</span> <span class="pl-c1">COUNT</span>(<span class="pl-k">*</span>) <span class="pl-k">FROM</span> nodes <span class="pl-k">WHERE</span> changeset_id <span class="pl-k">=</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">id</span> <span class="pl-k">AND</span> version <span class="pl-k">></span> <span class="pl-c1">1</span> <span class="pl-k">AND</span> NOT visible),
       num_created_ways <span class="pl-k">=</span> (<span class="pl-k">SELECT</span> <span class="pl-c1">COUNT</span>(<span class="pl-k">*</span>) <span class="pl-k">FROM</span> ways <span class="pl-k">WHERE</span> changeset_id <span class="pl-k">=</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">id</span> <span class="pl-k">AND</span> version <span class="pl-k">=</span> <span class="pl-c1">1</span>),
       num_modified_ways <span class="pl-k">=</span> (<span class="pl-k">SELECT</span> <span class="pl-c1">COUNT</span>(<span class="pl-k">*</span>) <span class="pl-k">FROM</span> ways <span class="pl-k">WHERE</span> changeset_id <span class="pl-k">=</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">id</span> <span class="pl-k">AND</span> version <span class="pl-k">></span> <span class="pl-c1">1</span> <span class="pl-k">AND</span> visible),
       num_deleted_ways <span class="pl-k">=</span> (<span class="pl-k">SELECT</span> <span class="pl-c1">COUNT</span>(<span class="pl-k">*</span>) <span class="pl-k">FROM</span> ways <span class="pl-k">WHERE</span> changeset_id <span class="pl-k">=</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">id</span> <span class="pl-k">AND</span> version <span class="pl-k">></span> <span class="pl-c1">1</span> <span class="pl-k">AND</span> NOT visible),
       num_created_relations <span class="pl-k">=</span> (<span class="pl-k">SELECT</span> <span class="pl-c1">COUNT</span>(<span class="pl-k">*</span>) <span class="pl-k">FROM</span> relations <span class="pl-k">WHERE</span> changeset_id <span class="pl-k">=</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">id</span> <span class="pl-k">AND</span> version <span class="pl-k">=</span> <span class="pl-c1">1</span>),
       num_modified_relations <span class="pl-k">=</span> (<span class="pl-k">SELECT</span> <span class="pl-c1">COUNT</span>(<span class="pl-k">*</span>) <span class="pl-k">FROM</span> relations <span class="pl-k">WHERE</span> changeset_id <span class="pl-k">=</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">id</span> <span class="pl-k">AND</span> version <span class="pl-k">></span> <span class="pl-c1">1</span> <span class="pl-k">AND</span> visible),
       num_deleted_relations <span class="pl-k">=</span> (<span class="pl-k">SELECT</span> <span class="pl-c1">COUNT</span>(<span class="pl-k">*</span>) <span class="pl-k">FROM</span> relations <span class="pl-k">WHERE</span> changeset_id <span class="pl-k">=</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">id</span> <span class="pl-k">AND</span> version <span class="pl-k">></span> <span class="pl-c1">1</span> <span class="pl-k">AND</span> NOT visible)
<span class="pl-k">WHERE</span> id <span class="pl-k">=</span> ANY($<span class="pl-c1">1</span>::<span class="pl-k">bigint</span>[])</pre></div>
<p dir="auto">Both take about 5s to do the first 10000 changesets when the cache is hot for the indexes.</p>

<p style="font-size:small;-webkit-text-size-adjust:none;color:#666;">—<br />Reply to this email directly, <a href="https://github.com/openstreetmap/openstreetmap-website/pull/6347#issuecomment-3226054386">view it on GitHub</a>, or <a href="https://github.com/notifications/unsubscribe-auth/AAK2OLOJRKJCYMTUSXFMHSD3PTUENAVCNFSM6AAAAACEUBV34SVHI2DSMVQWIX3LMV43OSLTON2WKQ3PNVWWK3TUHMZTEMRWGA2TIMZYGY">unsubscribe</a>.<br />You are receiving this because you are subscribed to this thread.<img src="https://github.com/notifications/beacon/AAK2OLJLBUWRMHZOXZNRF633PTUENA5CNFSM6AAAAACEUBV34SWGG33NNVSW45C7OR4XAZNMJFZXG5LFINXW23LFNZ2KUY3PNVWWK3TUL5UWJTWAJGXPE.gif" height="1" width="1" alt="" /><span style="color: transparent; font-size: 0; display: none; visibility: hidden; overflow: hidden; opacity: 0; width: 0; height: 0; max-width: 0; max-height: 0; mso-hide: all">Message ID: <span><openstreetmap/openstreetmap-website/pull/6347/c3226054386</span><span>@</span><span>github</span><span>.</span><span>com></span></span></p>

<script type="application/ld+json">[
{
"@context": "http://schema.org",
"@type": "EmailMessage",
"potentialAction": {
"@type": "ViewAction",
"target": "https://github.com/openstreetmap/openstreetmap-website/pull/6347#issuecomment-3226054386",
"url": "https://github.com/openstreetmap/openstreetmap-website/pull/6347#issuecomment-3226054386",
"name": "View Pull Request"
},
"description": "View this Pull Request on GitHub",
"publisher": {
"@type": "Organization",
"name": "GitHub",
"url": "https://github.com"
}
}
]</script>