<p></p>
<p dir="auto">That's a possibility I guess though it means managing the function outside the normal database migration logic.</p>
<p dir="auto">I've actually already written an plpgsql implementation with the configuration hard coded:</p>
<div class="highlight highlight-source-sql" dir="auto"><pre class="notranslate"><span class="pl-k">CREATE OR REPLACE</span> <span class="pl-k">FUNCTION</span> <span class="pl-en">check_rate_limit</span>(user_id int8, new_changes int4)
RETURNS <span class="pl-k">boolean</span>
<span class="pl-k">AS</span> $$
DECLARE
min_changes_per_hour int4;
initial_changes_per_hour int4;
max_changes_per_hour int4;
importer_changes_per_hour int4;
moderator_changes_per_hour int4;
roles <span class="pl-k">text</span>[];
last_block <span class="pl-k">timestamp without time zone</span>;
first_change <span class="pl-k">timestamp without time zone</span>;
active_reports int4;
time_since_first_change <span class="pl-k">double precision</span>;
max_changes <span class="pl-k">double precision</span>;
recent_changes int4;
<span class="pl-k">BEGIN</span>
min_changes_per_hour :<span class="pl-k">=</span> <span class="pl-c1">100</span>;
initial_changes_per_hour :<span class="pl-k">=</span> <span class="pl-c1">1000</span>;
max_changes_per_hour :<span class="pl-k">=</span> <span class="pl-c1">100000</span>;
importer_changes_per_hour :<span class="pl-k">=</span> <span class="pl-c1">1000000</span>;
moderator_changes_per_hour :<span class="pl-k">=</span> <span class="pl-c1">1000000</span>;
<span class="pl-k">SELECT</span> ARRAY_AGG(<span class="pl-c1">user_roles</span>.<span class="pl-c1">role</span>) INTO STRICT roles <span class="pl-k">FROM</span> user_roles <span class="pl-k">WHERE</span> <span class="pl-c1">user_roles</span>.<span class="pl-c1">user_id</span> <span class="pl-k">=</span> <span class="pl-c1">check_rate_limit</span>.<span class="pl-c1">user_id</span>;
IF <span class="pl-s"><span class="pl-pds">'</span>moderator<span class="pl-pds">'</span></span> <span class="pl-k">=</span> ANY(roles) THEN
max_changes :<span class="pl-k">=</span> moderator_changes_per_hour;
ELSIF <span class="pl-s"><span class="pl-pds">'</span>importer<span class="pl-pds">'</span></span> <span class="pl-k">=</span> ANY(roles) THEN
max_changes :<span class="pl-k">=</span> importer_changes_per_hour;
ELSE
<span class="pl-k">SELECT</span> <span class="pl-c1">user_blocks</span>.<span class="pl-c1">created_at</span> INTO STRICT last_block <span class="pl-k">FROM</span> user_blocks <span class="pl-k">WHERE</span> <span class="pl-c1">user_blocks</span>.<span class="pl-c1">user_id</span> <span class="pl-k">=</span> <span class="pl-c1">check_rate_limit</span>.<span class="pl-c1">user_id</span> <span class="pl-k">ORDER BY</span> <span class="pl-c1">user_blocks</span>.<span class="pl-c1">created_at</span> <span class="pl-k">DESC</span> <span class="pl-k">LIMIT</span> <span class="pl-c1">1</span>;
IF FOUND THEN
<span class="pl-k">SELECT</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">created_at</span> INTO STRICT first_change <span class="pl-k">FROM</span> changesets <span class="pl-k">WHERE</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">user_id</span> <span class="pl-k">=</span> <span class="pl-c1">check_rate_limit</span>.<span class="pl-c1">user_id</span> <span class="pl-k">AND</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">created_at</span> <span class="pl-k">></span> last_block <span class="pl-k">ORDER BY</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">created_at</span> <span class="pl-k">LIMIT</span> <span class="pl-c1">1</span>;
ELSE
<span class="pl-k">SELECT</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">created_at</span> INTO STRICT first_change <span class="pl-k">FROM</span> changesets <span class="pl-k">WHERE</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">user_id</span> <span class="pl-k">=</span> <span class="pl-c1">check_rate_limit</span>.<span class="pl-c1">user_id</span> <span class="pl-k">ORDER BY</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">created_at</span> <span class="pl-k">LIMIT</span> <span class="pl-c1">1</span>;
END IF;
<span class="pl-k">SELECT</span> COALESCE(<span class="pl-c1">SUM</span>(<span class="pl-c1">issues</span>.<span class="pl-c1">reports_count</span>), <span class="pl-c1">0</span>) INTO STRICT active_reports <span class="pl-k">FROM</span> issues <span class="pl-k">WHERE</span> <span class="pl-c1">issues</span>.<span class="pl-c1">reported_user_id</span> <span class="pl-k">=</span> <span class="pl-c1">check_rate_limit</span>.<span class="pl-c1">user_id</span> <span class="pl-k">AND</span> <span class="pl-c1">issues</span>.<span class="pl-c1">status</span> <span class="pl-k">=</span> <span class="pl-s"><span class="pl-pds">'</span>open<span class="pl-pds">'</span></span>;
time_since_first_change :<span class="pl-k">=</span> EXTRACT(EPOCH <span class="pl-k">FROM</span> NOW() <span class="pl-k">-</span> first_change);
max_changes :<span class="pl-k">=</span> max_changes_per_hour <span class="pl-k">*</span> POWER(time_since_first_change, <span class="pl-c1">2</span>) <span class="pl-k">/</span> POWER(<span class="pl-c1">7</span> <span class="pl-k">*</span> <span class="pl-c1">24</span> <span class="pl-k">*</span> <span class="pl-c1">60</span> <span class="pl-k">*</span> <span class="pl-c1">60</span>, <span class="pl-c1">2</span>);
max_changes :<span class="pl-k">=</span> GREATEST(initial_changes_per_hour, LEAST(max_changes_per_hour, FLOOR(max_changes)));
max_changes :<span class="pl-k">=</span> max_changes <span class="pl-k">/</span> POWER(<span class="pl-c1">2</span>, active_reports);
max_changes :<span class="pl-k">=</span> GREATEST(min_changes_per_hour, LEAST(max_changes_per_hour, max_changes));
END IF;
<span class="pl-k">SELECT</span> COALESCE(<span class="pl-c1">SUM</span>(<span class="pl-c1">changesets</span>.<span class="pl-c1">num_changes</span>), <span class="pl-c1">0</span>) INTO STRICT recent_changes <span class="pl-k">FROM</span> changesets <span class="pl-k">WHERE</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">user_id</span> <span class="pl-k">=</span> <span class="pl-c1">check_rate_limit</span>.<span class="pl-c1">user_id</span> <span class="pl-k">AND</span> <span class="pl-c1">changesets</span>.<span class="pl-c1">created_at</span> <span class="pl-k">>=</span> now() <span class="pl-k">-</span> <span class="pl-s"><span class="pl-pds">'</span>1 hour<span class="pl-pds">'</span></span>::interval;
RETURN recent_changes <span class="pl-k">+</span> new_changes <span class="pl-k"><</span> max_changes;
END;
$$ LANGUAGE plpgsql;</pre></div>
<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/4319#issuecomment-1787994686">view it on GitHub</a>, or <a href="https://github.com/notifications/unsubscribe-auth/AAK2OLME3A7Z2AU6X3NOSVDYCFOQ5AVCNFSM6AAAAAA6VBWHDWVHI2DSMVQWIX3LMV43OSLTON2WKQ3PNVWWK3TUHMYTOOBXHE4TINRYGY">unsubscribe</a>.<br />You are receiving this because you are subscribed to this thread.<img src="https://github.com/notifications/beacon/AAK2OLIS3D6SPFD6HESDYOTYCFOQ5A5CNFSM6AAAAAA6VBWHDWWGG33NNVSW45C7OR4XAZNMJFZXG5LFINXW23LFNZ2KUY3PNVWWK3TUL5UWJTTKSKRD4.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/4319/c1787994686</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/4319#issuecomment-1787994686",
"url": "https://github.com/openstreetmap/openstreetmap-website/pull/4319#issuecomment-1787994686",
"name": "View Pull Request"
},
"description": "View this Pull Request on GitHub",
"publisher": {
"@type": "Organization",
"name": "GitHub",
"url": "https://github.com"
}
}
]</script>