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

Multitenant and standby: recover from subsetting

In the previous post we learnt how to exclude a PDB (or a datafile) from the standby database recovery. Of course, that might not be the real end goal. We may just want to skip it for now, but have the standby continue to be up-to-date for every other PDB, and eventually include the new PDB as well. Again, standard Oracle pre-12c DBA knowledge is helpful here. These files are just missing datafiles and thus a backup can be used to restore them. The new 12c features add some quirks to this process, but the base is just sound backup and recovery. Backup So let's start with a proper backup: rman target=/ Recovery Manager: Release 12.1.0.2.0 - Production on Mon Nov 16 12:42:38 2015 Copyright (c) 1982, 2014, Oracle and/or its affiliates. All rights reserved. backup database; connected to target database: CDB2 (DBID=600824249) Starting backup at 16-NOV-15 using target database control file instead of recovery catalog allocated channel: ORA_DISK_1 channel ORA_DISK_1: SID=193

Multitenant and standby: subsetting

In the previous post we looked at managing new PDBs added to a standby database, by copying the files to the DR server, as required. However, there is another possible approach, and that is to omit the PDB from the standby configuration altogether. There are two ways of achieving this: 1. Do it the old-school way. A long time before 12c arrived on the scene one could offline a datafile on the standby database to remove it. The same trick is used in TSPITR (tablespace point-in-time recovery), so that you don't need to restore and recover the entire database if you are only after some tablespaces. 2. 12.1.0.2 adds the option to automatically exclude the PDB from standby(s). And 12.2 adds the option to be more specific in case of multiple standbys. For the sake of curiosity I started by setting standby file management to manual again. What I found is that there was very little difference, and the steps to take are exactly the same - it’s just the error message that is slightly