vDataFrame.agg / aggregate

In [ ]:
vDataFrame.aggregate(func: list, 
                     columns: list = [],
                     ncols_block: int = 20,
                     processes: int = 1,)

Aggregates the vDataFrame using the input functions.

Parameters

Name Type Optional Description
func
list
List of the different aggregation.
  • aad : average absolute deviation
  • approx_median : approximate median
  • approx_q% : approximative q quantile (ex: approx_50% for the approximate median)
  • approx_unique : approximative cardinality
  • count : number of non-missing elements
  • cvar : conditional value at risk
  • dtype : virtual column type
  • iqr : interquartile range
  • kurtosis : kurtosis
  • jb : Jarque Bera index
  • mad : median absolute deviation
  • max : maximum
  • mean : average
  • median : median
  • min : min
  • mode : most occurent element
  • percent : percent of non-missing elements
  • q% : q quantile (ex: 50% for the median)
  • prod : product
  • range : difference between the max and the min
  • sem : standard error of the mean
  • skewness : skewness
  • sum : sum
  • std : standard deviation
  • topk : kth most occurent element (ex: top1 for the mode)
  • topk_percent : kth most occurent element density
  • unique : cardinality (count distinct)
  • var : variance
  • Other aggregations could work if it is part of the DB version you are using.
columns
list
List of the vcolumns names. If empty, all the vcolumns or only numerical vcolumns will be used depending on the aggregations.
ncols_block
int
Number of columns used per query. Setting this parameter divides what would otherwise be one large query into many smaller queries called "blocks." The size of each block is determined by the ncols_block parameter.
processes
int
Number of child processes to create. Setting this with the ncols_block parameter lets you parallelize a single query into many smaller queries, where each child process creates its own connection to the database and sends one query. This can improve query performance, but consumes more resources. If processes is set to 1, the queries are sent iteratively from a single process.

Returns

tablesample : An object containing the result. For more information, see utilities.tablesample.

Example

In [1]:
from verticapy.datasets import load_titanic
titanic = load_titanic()
display(titanic)
123
pclass
Int
123
survived
Int
Abc
Varchar(164)
Abc
sex
Varchar(20)
123
age
Numeric(6,3)
123
sibsp
Int
123
parch
Int
Abc
ticket
Varchar(36)
123
fare
Numeric(10,5)
Abc
cabin
Varchar(30)
Abc
embarked
Varchar(20)
Abc
boat
Varchar(100)
123
body
Int
Abc
home.dest
Varchar(100)
110female2.012113781151.55C22 C26S[null][null]Montreal, PQ / Chesterville, ON
210male30.012113781151.55C22 C26S[null]135Montreal, PQ / Chesterville, ON
310female25.012113781151.55C22 C26S[null][null]Montreal, PQ / Chesterville, ON
410male39.0001120500.0A36S[null][null]Belfast, NI
510male71.000PC 1760949.5042[null]C[null]22Montevideo, Uruguay
610male47.010PC 17757227.525C62 C64C[null]124New York, NY
710male[null]00PC 1731825.925[null]S[null][null]New York, NY
810male24.001PC 17558247.5208B58 B60C[null][null]Montreal, PQ
910male36.0001305075.2417C6CA[null]Winnipeg, MN
1010male25.0001390526.0[null]C[null]148San Francisco, CA
1110male45.00011378435.5TS[null][null]Trenton, NJ
1210male42.00011048926.55D22S[null][null]London / Winnipeg, MB
1310male41.00011305430.5A21S[null][null]Pomeroy, WA
1410male48.000PC 1759150.4958B10C[null]208Omaha, NE
1510male[null]0011237939.6[null]C[null][null]Philadelphia, PA
1610male45.00011305026.55B38S[null][null]Washington, DC
1710male[null]0011379831.0[null]S[null][null][null]
1810male33.0006955.0B51 B53 B55S[null][null]New York, NY
1910male28.00011305947.1[null]S[null][null]Montevideo, Uruguay
2010male17.00011305947.1[null]S[null][null]Montevideo, Uruguay
2110male49.0001992426.0[null]S[null][null]Ascot, Berkshire / Rochester, NY
2210male36.0101987778.85C46S[null]172Little Onn Hall, Staffs
2310male46.010W.E.P. 573461.175E31S[null][null]Amenia, ND
2410male[null]001120510.0[null]S[null][null]Liverpool, England / Belfast
2510male27.01013508136.7792C89C[null][null]Los Angeles, CA
2610male[null]0011046552.0A14S[null][null]Stoughton, MA
2710male47.000572725.5875E58S[null][null]Victoria, BC
2810male37.011PC 1775683.1583E52C[null][null]Lakewood, NJ
2910male[null]0011379126.55[null]S[null][null]Roachdale, IN
3010male70.011WE/P 573571.0B22S[null]269Milwaukee, WI
3110male39.010PC 1759971.2833C85C[null][null]New York, NY
3210male31.010F.C. 1275052.0B71S[null][null]Montreal, PQ
3310male50.010PC 17761106.425C86C[null]62Deephaven, MN / Cedar Rapids, IA
3410male39.000PC 1758029.7A18C[null]133Philadelphia, PA
3510female36.000PC 1753131.6792A29C[null][null]New York, NY
3610male[null]00PC 17483221.7792C95S[null][null][null]
3710male30.00011305127.75C111C[null][null]New York, NY
3810male19.03219950263.0C23 C25 C27S[null][null]Winnipeg, MB
3910male64.01419950263.0C23 C25 C27S[null][null]Winnipeg, MB
4010male[null]0011377826.55D34S[null][null]Westcliff-on-Sea, Essex
4110male[null]001120580.0B102S[null][null][null]
4210male37.01011380353.1C123S[null][null]Scituate, MA
4310male47.00011132038.5E63S[null]275St Anne's-on-Sea, Lancashire
4410male24.000PC 1759379.2B86C[null][null][null]
4510male71.000PC 1775434.6542A5C[null][null]New York, NY
4610male38.001PC 17582153.4625C91S[null]147Winnipeg, MB
4710male46.000PC 1759379.2B82 B84C[null][null]New York, NY
4810male[null]0011379642.4[null]S[null][null][null]
4910male45.0103697383.475C83S[null][null]New York, NY
5010male40.0001120590.0B94S[null]110[null]
5110male55.0111274993.5B69S[null]307Montreal, PQ
5210male42.00011303842.5B11S[null][null]London / Middlesex
5310male[null]001746351.8625E46S[null][null]Brighton, MA
5410male55.00068050.0C39S[null][null]London / Birmingham
5510male42.01011378952.0[null]S[null]38New York, NY
5610male[null]00PC 1760030.6958[null]C14[null]New York, NY
5710female50.000PC 1759528.7125C49C[null][null]Paris, France New York, NY
5810male46.00069426.0[null]S[null]80Bennington, VT
5910male50.00011304426.0E60S[null][null]London
6010male32.500113503211.5C132C[null]45[null]
6110male58.0001177129.7B37C[null]258Buffalo, NY
6210male41.0101746451.8625D21S[null][null]Southington / Noank, CT
6310male[null]0011302826.55C124S[null][null]Portland, OR
6410male[null]00PC 1761227.7208[null]C[null][null]Chicago, IL
6510male29.00011350130.0D6S[null]126Springfield, MA
6610male30.00011380145.5[null]S[null][null]London / New York, NY
6710male30.00011046926.0C106S[null][null]Brockton, MA
6810male19.01011377353.1D30S[null][null]New York, NY
6910male46.0001305075.2417C6C[null]292Vancouver, BC
7010male54.0001746351.8625E46S[null]175Dorchester, MA
7110male28.010PC 1760482.1708[null]C[null][null]New York, NY
7210male65.0001350926.55E38S[null]249East Bridgewater, MA
7310male44.0201992890.0C78Q[null]230Fond du Lac, WI
7410male55.00011378730.5C30S[null][null]Montreal, PQ
7510male47.00011379642.4[null]S[null][null]Washington, DC
7610male37.001PC 1759629.7C118C[null][null]Brooklyn, NY
7710male58.00235273113.275D48C[null]122Lexington, MA
7810male64.00069326.0[null]S[null]263Isle of Wight, England
7910male65.00111350961.9792B30C[null]234Providence, RI
8010male28.500PC 1756227.7208D43C[null]189?Havana, Cuba
8110male[null]001120520.0[null]S[null][null]Belfast
8210male45.50011304328.5C124S[null]166Surbiton Hill, Surrey
8310male23.0001274993.5B24S[null][null]Montreal, PQ
8410male29.01011377666.6C2S[null][null]Isleworth, England
8510male18.010PC 17758108.9C65C[null][null]Madrid, Spain
8610male47.00011046552.0C110S[null]207Worcester, MA
8710male38.000199720.0[null]S[null][null]Rotterdam, Netherlands
8810male22.000PC 17760135.6333[null]C[null]232[null]
8910male[null]00PC 17757227.525[null]C[null][null][null]
9010male31.000PC 1759050.4958A24S[null][null]Trenton, NJ
9110male[null]0011376750.0A32S[null][null]Seattle, WA
9210male36.0001304940.125A10C[null][null]Winnipeg, MB
9310male55.010PC 1760359.4[null]C[null][null]New York, NY
9410male33.00011379026.55[null]S[null]109London
9510male61.013PC 17608262.375B57 B59 B63 B66C[null][null]Haverford, PA / Cooperstown, NY
9610male50.0101350755.9E44S[null][null]Duluth, MN
9710male56.00011379226.55[null]S[null][null]New York, NY
9810male56.0001776430.6958A7C[null][null]St James, Long Island, NY
9910male24.0101369560.0C31S[null][null]Huntington, WV
10010male[null]0011305626.0A19S[null][null]Streatham, Surrey
Rows: 1-100 | Columns: 14
In [2]:
# Turning on the SQL to see the queries
from verticapy import set_option
set_option("cache", False)
set_option("sql_on", True)
In [8]:
# Sending one query
titanic.aggregate(func = ["min", "approx_10%", "approx_50%", "approx_90%", "max"],
                  columns = ["age", "fare", "pclass", "survived"])

Computing the different aggregations.

  SELECT
    MIN("age"),
    APPROXIMATE_PERCENTILE("age" USING PARAMETERS percentile = 0.1),
    APPROXIMATE_PERCENTILE("age" USING PARAMETERS percentile = 0.5),
    APPROXIMATE_PERCENTILE("age" USING PARAMETERS percentile = 0.9),
    MAX("age"),
    MIN("fare"),
    APPROXIMATE_PERCENTILE("fare" USING PARAMETERS percentile = 0.1),
    APPROXIMATE_PERCENTILE("fare" USING PARAMETERS percentile = 0.5),
    APPROXIMATE_PERCENTILE("fare" USING PARAMETERS percentile = 0.9),
    MAX("fare"),
    MIN("pclass"),
    APPROXIMATE_PERCENTILE("pclass" USING PARAMETERS percentile = 0.1),
    APPROXIMATE_PERCENTILE("pclass" USING PARAMETERS percentile = 0.5),
    APPROXIMATE_PERCENTILE("pclass" USING PARAMETERS percentile = 0.9),
    MAX("pclass"),
    MIN("survived"),
    APPROXIMATE_PERCENTILE("survived" USING PARAMETERS percentile = 0.1),
    APPROXIMATE_PERCENTILE("survived" USING PARAMETERS percentile = 0.5),
    APPROXIMATE_PERCENTILE("survived" USING PARAMETERS percentile = 0.9),
    MAX("survived")  
  FROM
"public"."titanic" LIMIT 1
Out[8]:
min
approx_10%
approx_50%
approx_90%
max
"age"0.3314.528.050.080.0
"fare"0.07.589214.454279.13512.3292
"pclass"1.01.03.03.03.0
"survived"0.00.00.01.01.0
Rows: 1-4 | Columns: 6
In [3]:
# VerticaPy can deal if incompatible aggregations
# It will send multiple queries with compatible aggregations
titanic.aggregate(func = ["unique", "min", "10%", "50%", "approx_90%", "max"],
                  columns = ["age", "fare", "pclass", "survived"])

Computing the different aggregations.

  SELECT
    PERCENTILE_CONT(0.1) WITHIN GROUP (ORDER BY "age") OVER (),
    PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY "age") OVER (),
    PERCENTILE_CONT(0.1) WITHIN GROUP (ORDER BY "fare") OVER (),
    PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY "fare") OVER (),
    PERCENTILE_CONT(0.1) WITHIN GROUP (ORDER BY "pclass") OVER (),
    PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY "pclass") OVER (),
    PERCENTILE_CONT(0.1) WITHIN GROUP (ORDER BY "survived") OVER (),
    PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY "survived") OVER ()  
  FROM
"public"."titanic" LIMIT 1

Computing the different aggregations.

  SELECT
    COUNT(DISTINCT "age"),
    COUNT(DISTINCT "fare"),
    COUNT(DISTINCT "pclass"),
    COUNT(DISTINCT "survived")  
  FROM
"public"."titanic" LIMIT 1

Computing the different aggregations.

  SELECT
    96.0,
    MIN("age"),
    14.5,
    14.5,
    APPROXIMATE_PERCENTILE("age" USING PARAMETERS percentile = 0.9),
    MAX("age"),
    277.0,
    MIN("fare"),
    7.5892,
    7.5892,
    APPROXIMATE_PERCENTILE("fare" USING PARAMETERS percentile = 0.9),
    MAX("fare"),
    3.0,
    MIN("pclass"),
    1.0,
    1.0,
    APPROXIMATE_PERCENTILE("pclass" USING PARAMETERS percentile = 0.9),
    MAX("pclass"),
    2.0,
    MIN("survived"),
    0.0,
    0.0,
    APPROXIMATE_PERCENTILE("survived" USING PARAMETERS percentile = 0.9),
    MAX("survived")  
  FROM
"public"."titanic" LIMIT 1
Out[3]:
unique
min
10%
50%
approx_90%
max
"age"96.00.3314.514.550.080.0
"fare"277.00.07.58927.589279.13512.3292
"pclass"3.01.01.01.03.03.0
"survived"2.00.00.00.01.01.0
Rows: 1-4 | Columns: 7
In [11]:
# Sending multiple queries iteratively (2 elements at the time)
titanic.aggregate(func = ["min", "approx_10%", "approx_50%", "approx_90%", "max"],
                  columns = ["age", "fare", "pclass", "survived"],
                  ncols_block = 2)

Computing the different aggregations.

  SELECT
    MIN("age"),
    APPROXIMATE_PERCENTILE("age" USING PARAMETERS percentile = 0.1),
    APPROXIMATE_PERCENTILE("age" USING PARAMETERS percentile = 0.5),
    APPROXIMATE_PERCENTILE("age" USING PARAMETERS percentile = 0.9),
    MAX("age"),
    MIN("fare"),
    APPROXIMATE_PERCENTILE("fare" USING PARAMETERS percentile = 0.1),
    APPROXIMATE_PERCENTILE("fare" USING PARAMETERS percentile = 0.5),
    APPROXIMATE_PERCENTILE("fare" USING PARAMETERS percentile = 0.9),
    MAX("fare")  
  FROM
"public"."titanic" LIMIT 1

Computing the different aggregations.

  SELECT
    MIN("pclass"),
    APPROXIMATE_PERCENTILE("pclass" USING PARAMETERS percentile = 0.1),
    APPROXIMATE_PERCENTILE("pclass" USING PARAMETERS percentile = 0.5),
    APPROXIMATE_PERCENTILE("pclass" USING PARAMETERS percentile = 0.9),
    MAX("pclass"),
    MIN("survived"),
    APPROXIMATE_PERCENTILE("survived" USING PARAMETERS percentile = 0.1),
    APPROXIMATE_PERCENTILE("survived" USING PARAMETERS percentile = 0.5),
    APPROXIMATE_PERCENTILE("survived" USING PARAMETERS percentile = 0.9),
    MAX("survived")  
  FROM
"public"."titanic" LIMIT 1

Out[11]:
min
approx_10%
approx_50%
approx_90%
max
"age"0.3314.528.050.080.0
"fare"0.07.589214.454279.13512.3292
"pclass"1.01.03.03.03.0
"survived"0.00.00.01.01.0
Rows: 1-4 | Columns: 6
In [4]:
# Sending multiple queries in parallel (2 elements at the time)
titanic.aggregate(func = ["min", "approx_10%", "approx_50%", "approx_90%", "max"],
                  columns = ["age", "fare", "pclass", "survived"],
                  ncols_block = 2,
                  process = 2)

Computing the different aggregations.

  SELECT
    MIN("age"),
    APPROXIMATE_PERCENTILE("age" USING PARAMETERS percentile = 0.1),
    APPROXIMATE_PERCENTILE("age" USING PARAMETERS percentile = 0.5),
    APPROXIMATE_PERCENTILE("age" USING PARAMETERS percentile = 0.9),
    MAX("age"),
    MIN("fare"),
    APPROXIMATE_PERCENTILE("fare" USING PARAMETERS percentile = 0.1),
    APPROXIMATE_PERCENTILE("fare" USING PARAMETERS percentile = 0.5),
    APPROXIMATE_PERCENTILE("fare" USING PARAMETERS percentile = 0.9),
    MAX("fare")  
  FROM
"public"."titanic" LIMIT 1

Computing the different aggregations.

  SELECT
    MIN("pclass"),
    APPROXIMATE_PERCENTILE("pclass" USING PARAMETERS percentile = 0.1),
    APPROXIMATE_PERCENTILE("pclass" USING PARAMETERS percentile = 0.5),
    APPROXIMATE_PERCENTILE("pclass" USING PARAMETERS percentile = 0.9),
    MAX("pclass"),
    MIN("survived"),
    APPROXIMATE_PERCENTILE("survived" USING PARAMETERS percentile = 0.1),
    APPROXIMATE_PERCENTILE("survived" USING PARAMETERS percentile = 0.5),
    APPROXIMATE_PERCENTILE("survived" USING PARAMETERS percentile = 0.9),
    MAX("survived")  
  FROM
"public"."titanic" LIMIT 1

Out[4]:
min
approx_10%
approx_50%
approx_90%
max
"age"0.3314.528.050.080.0
"fare"0.07.589214.454279.13512.3292
"pclass"1.01.03.03.03.0
"survived"0.00.00.01.01.0
Rows: 1-4 | Columns: 6

See Also

vDataFrame.analytic Adds a new vcolumn to the vDataFrame by using an advanced analytical function on a specific vcolumn.
vDataFrame.score Computes the score using the input columns and the input method.