Sometimes you want to automatically populate a database table with a number rows. Maybe you need a big table with lots of entries for a performance experiment or some dummy data for development. Unfortunately, there’s no standard SQL statement to achieve this task. There are different possibilities for the various database management systems. For the Oracle database (10g or later) I will show you the simplest one I have encountered so far. It actually “abuses” an unrelated functionality: the CONNECT BY clause for hierarchical queries in combination with the DUAL table.
Here’s how it can be used:
SELECT ROWNUM id FROM dual CONNECT BY LEVEL <= 1000;
This select creates a result set with the numbers from 1 to 1000. You can combine it with INSERT to populate the following table with rows:
CREATE TABLE example ( id NUMBER(5,0), name VARCHAR2(200) ); INSERT INTO example (id, name) SELECT ROWNUM, 'Name '||ROWNUM FROM dual CONNECT BY LEVEL <= 10;
The resulting table is:
ID NAME 1 Name 1 2 Name 2 3 Name 3 ... 10 Name 10
Of course, you can use the incrementing ROWNUM in more creative ways. The following example populates a table for time series data with a million values forming a sinus curve with equidistant timestamps (in this case 15 minute intervals) starting with a specified time:
CREATE TABLE example ( id NUMBER(5,0), time TIMESTAMP, value NUMBER ); INSERT INTO example (id, time, value) SELECT ROWNUM, TIMESTAMP'2020-05-01 12:00:00' + (ROWNUM-1)*(INTERVAL '15' MINUTE), SIN(ROWNUM/10) FROM dual CONNECT BY LEVEL <= 1000000;
ID TIME VALUE 1 2020-05-01 12:00 0.099833 2 2020-05-01 12:15 0.198669 3 2020-05-01 12:30 0.295520 ...
As mentioned at the beginning, there are other row generator techniques to achieve this. But this one is the simplest so far, at least for Oracle.