Skip to main content

How many columns in a query

Everybody knows that the limit for number of columns in an Oracle table is 1000. It is actually limit of all columns in the table, including internal ones, virtual, unused but not yet dropped and so on.

But what is the limit for a query?

Let's start with a simple table, called many_columns. It has 1000 columns, all NUMBERs, to make things easy. Columns are named COLUMN_0001 to COLUMN_1000.

And I insert 1 row into the table:

insert into many_columns(COLUMN_0001) values (1);
commit;

So what happens with an innocent query?

select m.*, n.* from many_columns m, many_columns n;

Well, nothing special - SQL*Plus is happy to return 2000 columns.

Obviously, there must an upper limit, right? At the very maximum, OCI specifies value for column count as ub2, i.e. max 65535.
However, SQL*Plus complains much sooner: the limit seems to be 8150. I added one more table - many_columns2 with just then columns. The first query to go over the limit, with 8151, fails with:

select
m01.*,
m02.*,
m03.*,
m04.*,
m05.*,
m06.*,
m07.*,
m08.*,
m10.*,
m11.*,
m12.*,
m13.*,
m14.*,
m15.*,
m16.*,
m17.*,
m18.*,
m19.*,
m20.*,
m21.*,
m22.*,
m23.*,
m24.*,
m25.*,
dummy
from
many_columns m01,
many_columns m02,
many_columns m03,
many_columns m04,
many_columns m05,
many_columns m06,
many_columns m07,
many_columns m08,
many_columns2 m10,
many_columns2 m11,
many_columns2 m12,
many_columns2 m13,
many_columns2 m14,
many_columns2 m15,
many_columns2 m16,
many_columns2 m17,
many_columns2 m18,
many_columns2 m19,
many_columns2 m20,
many_columns2 m21,
many_columns2 m22,
many_columns2 m23,
many_columns2 m24,
many_columns2 m25,
dual;

select
*
ERROR at line 1:
ORA-00913: too many values


However, in more complex situations, Oracle will complain much sooner.
select *
from   many_columns
right outer join (select count(*) c, count(*) c2 from dual) on (c=column_0001);
ERROR at line 2:
ORA-01792: maximum number of columns in a table or view is 1000

However, this is version dependent, this was in 12.1.0.2. Same test, same tables on my 11.2.0.4 environment and Oracle does not complain about this.

Comments

Popular posts from this blog

ORA-27048: skgfifi: file header information is invalid

I was asked to analyze a situation, when an attempt to recover a 11g (standby) database resulted in bunch of "ORA-27048: skgfifi: file header information is invalid" errors.

I tried to reproduce the error on my test system, using different versions (EE, SE, 11.1.0.6, 11.1.0.7), but to no avail. Fortunately, I finally got to the failing system:

SQL> recover standby database;
ORA-00279: change 9614132 generated at 11/27/2009 17:59:06 needed for thread 1
ORA-00289: suggestion :
/u01/flash_recovery_area/T1/archivelog/2009_11_27/o1_mf_1_208_%u_.arc
ORA-27048: skgfifi: file header information is invalid
ORA-27048: skgfifi: file header information is invalid
ORA-27048: skgfifi: file header information is invalid
ORA-27048: skgfifi: file header information is invalid
ORA-27048: skgfifi: file header information is invalid
ORA-27048: skgfifi: file header information is invalid
ORA-00280: change 9614132 for thread 1 is in sequence #208


Interestingly, nothing interesting is written to alert.log n…

Reading data from PGA and SGA

Overview For our investigation of execution plan as it is stored in memory, we need in the first place to be able to read the memory.

We have the options of
x$ksmmem, reading SGA using SQL. Personally I don't like it, it's cumbersome and slow.direct SGA read: obviously reading SGA only; it's fast and easy to doread process memory: can read PGA, process stack - and since the processes do map the SGA, too, you can read it as well. Unfortunately ptrace sends signals to the processes and the process is paused when reading it, but so far all my reads were short and fast and the processes did not notice. Some OS configurations can prevent you from using ptrace (e.g. docker by default), google for CAP_SYS_PTRACE.gdb: using your favorite debugger, you can read memory as well. Useful when investigating. Direct SGA read I always considered direct SGA read of some dark magic, but the fundamentals are actually very easy. It still looks like sorcery when actually reading the Oracle in…

Filter and access predicates

More than just column projections When we look around for further pointers in the tree nodes, we find more pieces resembling the column projections we have seen so far. With some experimenting, we will find out that these are access predicates and filters.

First of all, the location of these pointers is not always the same, it seems that the value at 0x34 is some kind of flag, indicating whether filters and/or access predicates are present, and where. Or whether there is just one, or more of them.  It probably also indicates what other info is present, but I have no idea what info that would be or what each value means.
Resembling, but different The data we see as predicates are not columns; after all, a predicate is a condition, not a single column. But the structure is similar to what we have seen with columns, and if we follow pointers further, we eventually build a tree, and some of the leaves are indeed just column projections.
After some contemplation, we realize it's all t…