doc-exports/docs/dws/umn/dws_03_2109.html
Lu, Huayi 95132e24fc DWS UMN 830.201_new version
Reviewed-by: Pruthi, Vineet <vineet.pruthi@t-systems.com>
Reviewed-by: Rechenburg, Matthias <matthias.rechenburg@t-systems.com>
Co-authored-by: Lu, Huayi <luhuayi@huawei.com>
Co-committed-by: Lu, Huayi <luhuayi@huawei.com>
2024-05-27 11:54:34 +00:00

92 lines
13 KiB
HTML

<a name="EN-US_TOPIC_0000001527537805"></a><a name="EN-US_TOPIC_0000001527537805"></a>
<h1 class="topictitle1">In Which Scenarios Would a Statement Be "idle in transaction"?</h1>
<div id="body0000001527537805"><p id="EN-US_TOPIC_0000001527537805__p12527173915920">When user SQL information is queried in the <strong id="EN-US_TOPIC_0000001527537805__b0536185862918">PGXC_STAT_ACTIVITY</strong> view, the <strong id="EN-US_TOPIC_0000001527537805__b16629513113311">state </strong>column in the query result sometimes shows <strong id="EN-US_TOPIC_0000001527537805__b103337461331">idle in transaction</strong>. <strong id="EN-US_TOPIC_0000001527537805__b199018173419">idle in transaction</strong> indicates that the backend is in a transaction, but no statement is being executed. This status indicates that a statement has been executed. Therefore, the value of query_id is 0, but the transaction has not been committed or rolled back. Statements in this state have been executed and do not occupy CPU and I/O resources, but they occupy connection resources such as connections and concurrent connections.</p>
<p id="EN-US_TOPIC_0000001527537805__p962915718911">If a statement is in the <strong id="EN-US_TOPIC_0000001527537805__b2213125117359">idle in transaction</strong> state, rectify the fault by referring to the following common scenarios and solutions:</p>
<div class="section" id="EN-US_TOPIC_0000001527537805__section615994321617"><h4 class="sectiontitle">Scenario 1: A Transaction Is Started But Not Committed, and the Statement Is in the "idle in transaction" State</h4><p id="EN-US_TOPIC_0000001527537805__p177214336546"><strong id="EN-US_TOPIC_0000001527537805__b171709196393">BEGIN/START TRANSACTION</strong> is manually executed to start a transaction. After statements are executed, <strong id="EN-US_TOPIC_0000001527537805__b6763102823910">COMMIT/ROLLBACK</strong> is not executed. View the <strong id="EN-US_TOPIC_0000001527537805__b8986135203916">PGXC_STAT_ACTIVITY</strong>:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001527537805__screen20821171301817"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="k">state</span><span class="p">,</span><span class="w"> </span><span class="n">query</span><span class="p">,</span><span class="w"> </span><span class="n">query_id</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">pgxc_stat_activity</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001527537805__p1579934720245">The result shows that the statement is in the <strong id="EN-US_TOPIC_0000001527537805__b9662044012">idle in transaction</strong> state.</p>
<p id="EN-US_TOPIC_0000001527537805__p1469216472258"><span><img id="EN-US_TOPIC_0000001527537805__image11692747172513" src="figure/en-us_image_0000001528679765.png" title="Click to enlarge" class="imgResize"></span></p>
<p id="EN-US_TOPIC_0000001527537805__p6121420173112"><strong id="EN-US_TOPIC_0000001527537805__b11429536404">Solution</strong>: Manually execute <strong id="EN-US_TOPIC_0000001527537805__b8834152010401">COMMIT/ROLLBACK</strong> on the started transaction.</p>
</div>
<div class="section" id="EN-US_TOPIC_0000001527537805__section152625446510"><h4 class="sectiontitle">Scenario 2: After a DDL Statement in a Stored Procedure Is Executed, Other Nodes of the Stored Procedure Is In the "idle in transaction" State</h4><div class="p" id="EN-US_TOPIC_0000001527537805__p101019083915">Create a stored procedure:<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001527537805__screen1499219261718"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal"> 1</span>
<span class="normal"> 2</span>
<span class="normal"> 3</span>
<span class="normal"> 4</span>
<span class="normal"> 5</span>
<span class="normal"> 6</span>
<span class="normal"> 7</span>
<span class="normal"> 8</span>
<span class="normal"> 9</span>
<span class="normal">10</span>
<span class="normal">11</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">CREATE</span><span class="w"> </span><span class="k">OR</span><span class="w"> </span><span class="k">REPLACE</span><span class="w"> </span><span class="k">FUNCTION</span><span class="w"> </span><span class="k">public</span><span class="p">.</span><span class="n">test_sleep</span><span class="p">()</span>
<span class="k">RETURNS</span><span class="w"> </span><span class="n">void</span>
<span class="k">LANGUAGE</span><span class="w"> </span><span class="n">plpgsql</span>
<span class="k">AS</span><span class="w"> </span><span class="err">$$</span>
<span class="k">BEGIN</span>
<span class="w"> </span><span class="k">truncate</span><span class="w"> </span><span class="n">t1</span><span class="p">;</span>
<span class="w"> </span><span class="k">truncate</span><span class="w"> </span><span class="n">t2</span><span class="p">;</span>
<span class="w"> </span><span class="k">EXECUTE</span><span class="w"> </span><span class="k">IMMEDIATE</span><span class="w"> </span><span class="s1">'select pg_sleep(6)'</span><span class="p">;</span>
<span class="w"> </span><span class="k">RETURN</span><span class="p">;</span>
<span class="k">END</span><span class="err">$$</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</div>
<div class="p" id="EN-US_TOPIC_0000001527537805__p18511122143910">View the <strong id="EN-US_TOPIC_0000001527537805__b1346120292505">PGXC_STAT_ACTIVITY</strong> view:<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001527537805__screen880571062819"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="n">coorname</span><span class="p">,</span><span class="n">pid</span><span class="p">,</span><span class="n">query_id</span><span class="p">,</span><span class="k">state</span><span class="p">,</span><span class="n">query</span><span class="p">,</span><span class="n">usename</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">pgxc_stat_activity</span><span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="n">usename</span><span class="o">=</span><span class="s1">'jack'</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</div>
<p id="EN-US_TOPIC_0000001527537805__p1715816193118">The result shows that <strong id="EN-US_TOPIC_0000001527537805__b2097916225567">truncate t2</strong> is in the <strong id="EN-US_TOPIC_0000001527537805__b206019114568">idle in transaction</strong> state and <strong id="EN-US_TOPIC_0000001527537805__b12674111365615">coorname </strong>is <strong id="EN-US_TOPIC_0000001527537805__b6866191514565">coordinator2</strong>. This indicates that the statement has been executed on <strong id="EN-US_TOPIC_0000001527537805__b912224219565">cn2 </strong>and the stored procedure is executing the next statement.</p>
<p id="EN-US_TOPIC_0000001527537805__p74255743211"><span><img id="EN-US_TOPIC_0000001527537805__image10424174328" src="figure/en-us_image_0000001477602096.png" title="Click to enlarge" class="imgResize"></span></p>
<p id="EN-US_TOPIC_0000001527537805__p198901831551"><strong id="EN-US_TOPIC_0000001527537805__b2581852195615">Solution</strong>: This problem is caused by slow execution of the stored procedure. Wait until the execution of the stored procedure is complete. You can also optimize the statements that are executed slowly in the stored procedure.</p>
</div>
<div class="section" id="EN-US_TOPIC_0000001527537805__section2444144510485"><h4 class="sectiontitle">Scenario 3: A Large Number of SAVEPOINT/RELEASE Statements Are in the "idle in transaction" State (Cluster Versions Earlier Than 8.1.0)</h4><p id="EN-US_TOPIC_0000001527537805__p81581616811">View the <strong id="EN-US_TOPIC_0000001527537805__b12276628597">PGXC_STAT_ACTIVITY</strong> view:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001527537805__screen3291151473417"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="n">coorname</span><span class="p">,</span><span class="n">pid</span><span class="p">,</span><span class="n">query_id</span><span class="p">,</span><span class="k">state</span><span class="p">,</span><span class="n">query</span><span class="p">,</span><span class="n">usename</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">pgxc_stat_activity</span><span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="n">usename</span><span class="o">=</span><span class="s1">'jack'</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001527537805__p158921845351">The result shows that the SAVEPOINT/RELEASE statement is in the <strong id="EN-US_TOPIC_0000001527537805__b139242123599">idle in transaction</strong> state.</p>
</div>
<p id="EN-US_TOPIC_0000001527537805__p1273795712345"><span><img id="EN-US_TOPIC_0000001527537805__image67371057153411" src="figure/en-us_image_0000001528522325.png" title="Click to enlarge" class="imgResize"></span></p>
<p id="EN-US_TOPIC_0000001527537805__p0561110134317"><strong id="EN-US_TOPIC_0000001527537805__b125623105432">Solution:</strong></p>
<p id="EN-US_TOPIC_0000001527537805__p942261195510"><strong id="EN-US_TOPIC_0000001527537805__b099442419594">SAVEPOINT </strong>and <strong id="EN-US_TOPIC_0000001527537805__b451472635912">RELEASE </strong>statements are automatically generated by the system when a stored procedure with <strong id="EN-US_TOPIC_0000001527537805__b680017354598">EXCEPTION </strong>is executed. In versions later than 8.1.0, <strong id="EN-US_TOPIC_0000001527537805__b154281845165920">SAVEPOINT </strong>is not delivered to CNs. GaussDB(DWS) stored procedures with <strong id="EN-US_TOPIC_0000001527537805__b314719101016">EXCEPTION </strong>are implemented based on subtransactions, the mapping is as follows:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001527537805__screen139411429144814"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span>
<span class="normal">3</span>
<span class="normal">4</span>
<span class="normal">5</span>
<span class="normal">6</span>
<span class="normal">7</span>
<span class="normal">8</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">begin</span>
<span class="w"> </span><span class="p">(</span><span class="n">Savepoint</span><span class="w"> </span><span class="n">s1</span><span class="p">)</span>
<span class="w"> </span><span class="n">DDL</span><span class="o">/</span><span class="n">DML</span>
<span class="k">exception</span>
<span class="w"> </span><span class="p">(</span><span class="k">Rollback</span><span class="w"> </span><span class="k">to</span><span class="w"> </span><span class="n">s1</span><span class="p">)</span>
<span class="w"> </span><span class="p">(</span><span class="n">Release</span><span class="w"> </span><span class="n">s1</span><span class="p">)</span>
<span class="p">...</span>
<span class="k">end</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001527537805__p15902547764">If there is <strong id="EN-US_TOPIC_0000001527537805__b4307121557">EXCEPTION </strong>in a stored procedure when it is started, a subtransaction will be started. If there is and exception during the execution, the current transaction is rolled back and the exception is handled; if there is no exception, the subtransaction is committed.</p>
<p id="EN-US_TOPIC_0000001527537805__p1234492318559">This problem may occur when there are many such stored procedures and the stored procedures are nested. Similar to scenario 2, you only have to wait after the entire stored procedure is executed. If there are a large number of <strong id="EN-US_TOPIC_0000001527537805__b1625410562103">RELEASE</strong> messages, the stored procedure triggered multiple exceptions. In this case, you must re-examine the logic of the stored procedure.</p>
</div>
<div>
<div class="familylinks">
<div class="parentlink"><strong>Parent topic:</strong> <a href="dws_03_0065.html">Database Usage</a></div>
</div>
</div>
<script language="JavaScript">
<!--
image_size('.imgResize');
var msg_imageMax = "view original image";
var msg_imageClose = "close";
//--></script>