Skip to content

Commit 269f6a0

Browse files
authored
add information on generating completely random tables
1 parent 0177e53 commit 269f6a0

File tree

1 file changed

+112
-1
lines changed

1 file changed

+112
-1
lines changed

docs/guides/generating-test-data.md

Lines changed: 112 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -143,4 +143,115 @@ FROM numbers(20000);
143143

144144
:::tip
145145
Read the [Generating Random Data in ClickHouse](https://clickhouse.com/blog/generating-random-test-distribution-data-for-clickhouse) blog for even more examples.
146-
:::
146+
:::
147+
148+
## Generating random tables {#generating-random-tables}
149+
150+
The [`generateRandomStructure`](/sql-reference/functions/other-functions#generaterandomstructure) function is particularly useful when combined with the [`generateRandom`](/sql-reference/table-functions/generate) table engine for testing, benchmarking, or creating mock data with arbitrary schemas.
151+
152+
Let's start by just seeing what a random structure looks like using the `generateRandomStructure` function:
153+
154+
```sql
155+
SELECT generateRandomStructure(5);
156+
```
157+
158+
You might see something like:
159+
160+
```response
161+
c1 UInt32, c2 Array(String), c3 DateTime, c4 Nullable(Float64), c5 Map(String, Int16)
162+
```
163+
164+
You can also use a seed to get the same structure every time:
165+
166+
```sql
167+
SELECT generateRandomStructure(3, 42);
168+
```
169+
170+
```response
171+
c1 String, c2 Array(Nullable(Int32)), c3 Tuple(UInt8, Date)
172+
```
173+
174+
Now let's create an actual table and fill it with random data:
175+
176+
```sql
177+
CREATE TABLE my_test_table
178+
ENGINE = MergeTree
179+
ORDER BY tuple()
180+
AS SELECT *
181+
FROM generateRandom(
182+
'col1 UInt32, col2 String, col3 Float64, col4 DateTime',
183+
1, -- seed for data generation
184+
10 -- number of different random values
185+
)
186+
LIMIT 100; -- 100 rows
187+
188+
-- Step 2: Query your new table
189+
SELECT * FROM my_test_table LIMIT 5;
190+
```
191+
192+
```response
193+
┌───────col1─┬─col2──────┬─────────────────────col3─┬────────────────col4─┐
194+
│ 4107652264 │ &b!M-e;7 │ 1.0013455832230728e-158 │ 2059-08-14 19:03:26 │
195+
│ 652895061 │ Dj7peUH{T │ -1.032074207667996e112 │ 2079-10-06 04:18:16 │
196+
│ 2319105779 │ =D[ │ -2.066555415720528e88 │ 2015-04-26 11:44:13 │
197+
│ 1835960063 │ _@}a │ -1.4998020545039013e110 │ 2063-03-03 20:36:55 │
198+
│ 730412674 │ _}! │ -1.3578492992094465e-275 │ 2098-08-23 18:23:37 │
199+
└────────────┴───────────┴──────────────────────────┴─────────────────────┘
200+
```
201+
202+
Let's combine both functions for a completely random table.
203+
First, see what structure we'll get:
204+
205+
```sql
206+
SELECT generateRandomStructure(7, 123) AS structure FORMAT vertical;
207+
```
208+
209+
```response
210+
┌─structure──────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────┐
211+
│ c1 Decimal64(7), c2 Enum16('c2V0' = -21744, 'c2V1' = 5380), c3 Int8, c4 UUID, c5 UUID, c6 FixedString(190), c7 Map(Enum16('c7V0' = -19581, 'c7V1' = -10024, 'c7V2' = 27615, 'c7V3' = -10177, 'c7V4' = -19644, 'c7V5' = 3554, 'c7V6' = 29073, 'c7V7' = 28800, 'c7V8' = -11512), Float64) │
212+
└────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────┘
213+
```
214+
215+
Now create the table with that structure and use the `DESCRIBE` statement to see what we created:
216+
217+
```sql
218+
CREATE TABLE fully_random_table
219+
ENGINE = MergeTree
220+
ORDER BY tuple()
221+
AS SELECT *
222+
FROM generateRandom(generateRandomStructure(7, 123), 1, 10)
223+
LIMIT 1000;
224+
225+
DESCRIBE TABLE fully_random_table;
226+
```
227+
228+
```response
229+
┌─name─┬─type─────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────┬─default_type─┬─default_expression─┬─comment─┬─codec_expression─┬─ttl_expression─┐
230+
1. │ c1 │ Decimal(18, 7) │ │ │ │ │ │
231+
2. │ c2 │ Enum16('c2V0' = -21744, 'c2V1' = 5380) │ │ │ │ │ │
232+
3. │ c3 │ Int8 │ │ │ │ │ │
233+
4. │ c4 │ UUID │ │ │ │ │ │
234+
5. │ c5 │ UUID │ │ │ │ │ │
235+
6. │ c6 │ FixedString(190) │ │ │ │ │ │
236+
7. │ c7 │ Map(Enum16('c7V4' = -19644, 'c7V0' = -19581, 'c7V8' = -11512, 'c7V3' = -10177, 'c7V1' = -10024, 'c7V5' = 3554, 'c7V2' = 27615, 'c7V7' = 28800, 'c7V6' = 29073), Float64) │ │ │ │ │ │
237+
└──────┴──────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────┴──────────────┴────────────────────┴─────────┴──────────────────┴────────────────┘
238+
```
239+
240+
Inspect the first row for a sample of the generated data:
241+
242+
```sql
243+
SELECT * FROM fully_random_table LIMIT 1 FORMAT vertical;
244+
```
245+
246+
```response
247+
Row 1:
248+
──────
249+
c1: 80416293882.257732 -- 80.42 billion
250+
c2: c2V1
251+
c3: -84
252+
c4: 1a9429b3-fd8b-1d72-502f-c051aeb7018e
253+
c5: 7407421a-031f-eb3b-8571-44ff279ddd36
254+
c6: g̅b�&��rҵ���5C�\�|��H�>���l'V3��R�[��=3�G�LwVMR*s緾/2�J.�
255+
��6# ��(�h>�lە��L^�M�:�R�9 %d�ž�zv��W����Y�S��_no��BP+��u��.0��UZ!x�@7:�nj%3�Λd�S�k>���w��|�&��~
256+
c7: {'c7V8':-1.160941256852442}
257+
```

0 commit comments

Comments
 (0)