Skip to content

Commit 735eaba

Browse files
add section on wide tables (#37)
1 parent e683d73 commit 735eaba

File tree

1 file changed

+110
-0
lines changed

1 file changed

+110
-0
lines changed

features/wide-tables.adoc

Lines changed: 110 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,110 @@
1+
= 4096 table columns
2+
:database-version: 23.2
3+
:database-category: SQL
4+
5+
[[feature_summary]]
6+
7+
The maximum number of columns allowed in a database table or view has been increased to 4096. This feature allows you to build applications that can store attributes in a single table with more than the previous 1000-column limit. Some applications, such as Machine Learning and streaming IoT application workloads, may require the use of de-normalized tables with more than 1000 columns. The majority of existing database applications might not need extra-wide tables.
8+
9+
Before you can create tables with more than 1000 columns you must ensure that the following initialization parameters are set to the required values:
10+
11+
- The value of the `compatible` parameter must be set to `23.0.0` or higher
12+
- Once `compatible` is set accordingly you must change `max_columns` to extended
13+
14+
Please refer to the https://docs.oracle.com/en/database/oracle/oracle-database/23/upgrd/what-is-oracle-database-compatibility.html#GUID-7FCE8614-8163-4393-AE66-2ADD1F73934F[Database Upgrade Guide] for more details about the `compatible` initialization parameter and the implications of changing it.
15+
16+
Typing a `create table` statement featuring 4096 columns would result in a very long statement. The example simplifies the process using Native Dynamic SQL; it assumes that the above mentioned prerequisites are met.
17+
18+
[source,sql]
19+
[subs="verbatim"]
20+
----
21+
DECLARE
22+
l_sql CLOB;
23+
c_num_cols CONSTANT PLS_INTEGER := 4096;
24+
BEGIN
25+
-- construct the `create table` statement and store it as a CLOB
26+
l_sql := 'create table demotable (' || chr(13) || ' c0001 number' || chr(13);
27+
FOR i IN 2..c_num_cols LOOP
28+
l_sql := l_sql || ',c' || lpad(i, 4, 0) || ' number' || chr(13);
29+
END LOOP;
30+
l_sql := l_sql || ')';
31+
32+
-- create the table
33+
EXECUTE IMMEDIATE l_sql;
34+
EXCEPTION
35+
-- notify of errors
36+
WHEN OTHERS THEN
37+
raise_application_error(
38+
-20000,
39+
'an unexpected error occurred '
40+
|| ' ('
41+
|| sqlerrm
42+
|| ')'
43+
);
44+
END;
45+
/
46+
47+
-- validate the number of columns in the table
48+
SELECT
49+
count(*)
50+
FROM
51+
user_tab_columns
52+
WHERE
53+
table_name = 'DEMOTABLE';
54+
----
55+
56+
.Result
57+
[source,sql]
58+
[subs="verbatim"]
59+
----
60+
SQL> DECLARE
61+
2 l_sql CLOB;
62+
3 c_num_cols CONSTANT PLS_INTEGER := 4096;
63+
4 BEGIN
64+
5 -- construct the `create table` statement and store it as a CLOB
65+
6 l_sql := 'create table demotable (' || chr(13) || ' c0001 number' || chr(13);
66+
7 FOR i IN 2..c_num_cols LOOP
67+
8 l_sql := l_sql || ',c' || lpad(i, 4, 0) || ' number' || chr(13);
68+
9 END LOOP;
69+
10 l_sql := l_sql || ')';
70+
11
71+
12 -- create the table
72+
13 EXECUTE IMMEDIATE l_sql;
73+
14 EXCEPTION
74+
15 -- notify of errors
75+
16 WHEN OTHERS THEN
76+
17 raise_application_error(
77+
18 -20000,
78+
19 'an unexpected error occurred '
79+
20 || ' ('
80+
21 || sqlerrm
81+
22 || ')'
82+
23 );
83+
24 END;
84+
25 /
85+
86+
PL/SQL procedure successfully completed.
87+
88+
SQL> -- validate the number of columns in the table
89+
SQL> SELECT
90+
2 count(*)
91+
3 FROM
92+
4 user_tab_columns
93+
5 WHERE
94+
6 table_name = 'DEMOTABLE';
95+
96+
COUNT(*)
97+
----------
98+
4096
99+
----
100+
101+
== Benefits
102+
103+
Whilst most database applications should be fine with the existing limit of 1000 columns per table or view, certain IoT (Internet of Things) or Machine Learning workloads might require wider tables. In such cases you can make use of the wide tables offered by Oracle Database 23c.
104+
105+
== Further information
106+
107+
* Availability: All Offerings
108+
* Database Reference: https://docs.oracle.com/en/database/oracle/oracle-database/23/refrn/MAX_COLUMNS.html#GUID-916B35D1-364E-41C6-A025-E2D32533D08E[`max_columns` initialization parameter]
109+
* Database Reference: https://docs.oracle.com/en/database/oracle/oracle-database/23/refrn/COMPATIBLE.html#GUID-6C57EE11-BD06-4BB8-A0F7-D6CDDD086FA9[`compatible` initialization parameter]
110+
* https://blogs.oracle.com/in-memory/post/23c-free-wider-tables[Blog post] discussing wide tables on `blogs.oracle.com`

0 commit comments

Comments
 (0)