It’s long-time public knowledge that X$ fixed tables in Oracle are just “windows” into Oracle’s memory. So whenever you query an X$ table, the FIXED TABLE rowsource function in your SQL execution plan will just read some memory structure, parse its output and show you the results in tabular form. This is correct, but not the whole truth.
Check this example. Let’s query the X$KSUSE table, which is used by V$SESSION:
SQL> SELECT addr, indx, ksuudnam FROM x$ksuse WHERE rownum <= 5;
ADDR INDX KSUUDNAM
-------- ---------- ------------------------------
391513C4 1 SYS
3914E710 2 SYS
3914BA5C 3 SYS
39148DA8 4 SYS
391460F4 5 SYS
Now let’s check in which Oracle memory region this memory address resides (SGA, PGA, UGA etc). I’m using my script fcha for this (Find CHunk Address). You should probably not run this script in busy production systems as it uses the potentially dangerous X$KSMSP fixed table:
SQL> @fcha 391513C4
Find in which heap (UGA, PGA or Shared Pool) the memory address 391513C4 resides...
WARNING!!! This script will query X$KSMSP, which will cause heavy shared pool latch contention
in systems under load and with large shared pool. This may even completely hang
your instance until the query has finished! You probably do not want to run this in production!
Press ENTER to continue, CTRL+C to cancel...
LOC KSMCHPTR KSMCHIDX KSMCHDUR KSMCHCOM KSMCHSIZ KSMCHCLS KSMCHTYP KSMCHPAR
--- -------- ---------- ---------- ---------------- ---------- -------- ---------- --------
SGA 39034000 1 1 permanent memor 3977316 perm 0 00
SQL>
Ok, these X$KSUSE (V$SESSION) records reside in a permanent allocation in SGA and my X$ query apparently just parsed & presented the information from there.
Now, let’s query something else, for example the “Soviet Union” view X$KCCCP:
SQL> SELECT addr, indx, inst_id, cptno FROM x$kcccp WHERE rownum <= 5;
ADDR INDX INST_ID CPTNO
-------- ---------- ---------- ----------
F692347C 0 1 1
F692347C 1 1 2
F692347C 2 1 3
F692347C 3 1 4
F692347C 4 1 5
Ok, let’s see where do these records reside:
SQL> @fcha F692347C
Find in which heap (UGA, PGA or Shared Pool) the memory address F692347C resides...
WARNING!!! This script will query X$KSMSP, which will cause heavy shared pool latch contention
in systems under load and with large shared pool. This may even completely hang
your instance until the query has finished! You probably do not want to run this in production!
Press ENTER to continue, CTRL+C to cancel...
LOC KSMCHPTR KSMCHIDX KSMCHDUR KSMCHCOM KSMCHSIZ KSMCHCLS KSMCHTYP KSMCHPAR
--- -------- ---------- ---------- ---------------- ---------- -------- ---------- --------
UGA F6922EE8 kxsFrame4kPage 4124 freeabl 0 00
SQL>
Wow, why does the X$KCCCP data reside in my session’s UGA? This is where the extra complication (and sophistication) of X$ fixed tables comes into play!
Some X$ tables do not simply read whatever is in some memory location, but they have helper functions associated with them (something like fixed packages that the ASM instance uses internally). So, whenever you query this X$, then first a helper function is called, which will retrieve the source data from whereever it needs to, then copies it to your UGA in the format corresponding to this X$ and then the normal X$ memory location parsing & presentation code kicks in.
If you trace what the X$KCCCP access does – you’d see a bunch of control file parallel read wait events every time you query the X$ table (to retrieve the checkpoint progress records). So this X$ is not doing just a passive read only presentation of some memory structure (array). The helper function will first do some real work, allocates some runtime memory for the session (the kxsFrame4kPage chunk in UGA) and copies the results of its work to this UGA area – so that the X$ array & offset parsing code can read and present it back to the query engine.
In other words, the ADDR column in X$ tables does not necessarily show where the source data it shows ultimately lives, but just where the final array that got parsed for presentation happened to be. Sometimes the parsed data structure _is _the ultimate source where it comes from, sometimes a helper function needs to do a bunch of work (like taking latches and walking linked lists for X$KSMSP or even doing physical disk reads from controlfiles for X$KCCCP access).
And more, let’s run the same query against X$KCCCP twice:
SQL> SELECT addr, indx, inst_id, cptno FROM x$kcccp WHERE rownum <= 5;
ADDR INDX INST_ID CPTNO
-------- ---------- ---------- ----------
F69254B4 0 1 1
F69254B4 1 1 2
F69254B4 2 1 3
F69254B4 3 1 4
F69254B4 4 1 5
And once more:
SQL> SELECT addr, indx, inst_id, cptno FROM x$kcccp WHERE rownum <= 5;
ADDR INDX INST_ID CPTNO
-------- ---------- ---------- ----------
F692B508 0 1 1
F692B508 1 1 2
F692B508 2 1 3
F692B508 3 1 4
F692B508 4 1 5
See how the ADDR column has changed between executions even though we are querying the same data! This is not because the controlfiles or the source data have somehow relocated. It’s just that the temporary cursor execution scratch area, where the final data structure was put for presentation (kxsFrame4kPage chunk in UGA), just happened to be allocated from different locations for the two different executions.
There may be exceptions, but as long as the ADDR resides in SGA, I’d say it’s the actual location of where the data lives – but when it’s in UGA/PGA, it may be just the temporary cursor scratch area and the source data was taken from somewhere else (especially when the ADDR constantly changes or alternates between 2-3 different variants when repeatedly running your X$ query). Note that there are X$ tables which intentionally read data from arrays in your UGA (the actual source data lives in the UGA or PGA itself), but more about that in the future.