madlib-dev mailing list archives

Site index · List index
Message view « Date » · « Thread »
Top « Date » · « Thread »
From iyerr3 <...@git.apache.org>
Subject [GitHub] incubator-madlib pull request #54: Pivoting: Phase 2
Date Sat, 23 Jul 2016 00:23:48 GMT
Github user iyerr3 commented on a diff in the pull request:

    https://github.com/apache/incubator-madlib/pull/54#discussion_r71962292
  
    --- Diff: src/ports/postgres/modules/utilities/pivot.py_in ---
    @@ -58,66 +61,255 @@ def pivot(schema_madlib, source_table, out_table,
                                     pivoted table
             @param aggregate_func   The aggregate function to be applied to the
                                     values
    +        @param fill_value       If specified, determines how to fill NULL
    +                                values resulting from pivot operation
    +        @param keep_null        The flag for determining how to handle NULL
    +                                values in pivot columns
         """
    -
         """
         Assume we have the following table
             pivset( id INTEGER, piv FLOAT8, val FLOAT8 )
    -    where the piv column has 3 distinct values (10.0, 20.0 and 30.0).
    +    where the piv column has 3 distinct values (10, 20 and 30).
         If the pivot function call is :
             SELECT madlib.pivot('pivset', 'pivout', 'id', 'piv', 'val');
         We want to construct the following sql code to pivot the table.
             CREATE TABLE pivout AS (SELECT id,
    -        sum(CASE WHEN "piv" = '10.0' THEN val ELSE NULL END ) as "piv_10.0",
    -        sum(CASE WHEN "piv" = '20.0' THEN val ELSE NULL END ) as "piv_20.0",
    -        sum(CASE WHEN "piv" = '30.0' THEN val ELSE NULL END ) as "piv_30.0"
    +        avg(CASE WHEN "piv" = '10' THEN val ELSE NULL END ) as "val_avg_piv_10",
    +        avg(CASE WHEN "piv" = '20' THEN val ELSE NULL END ) as "val_avg_piv_20",
    +        avg(CASE WHEN "piv" = '30' THEN val ELSE NULL END ) as "val_avg_piv_30"
             FROM pivset GROUP BY id ORDER BY id)
     
         """
    +
         indices = split_quoted_delimited_str(index)
    -    pcol = split_quoted_delimited_str(pivot_cols)
    -    pval = split_quoted_delimited_str(pivot_values)
    -    validate_pivot_coding(source_table, out_table, indices, pcol, pval)
    -    new_col_names =[]
    -    sql_list = ["CREATE TABLE " + out_table + " AS (SELECT " + index]
    +    pcols = split_quoted_delimited_str(pivot_cols)
    +    pvals = split_quoted_delimited_str(pivot_values)
    +    validate_pivot_coding(source_table, out_table, indices, pcols, pvals)
     
    -    pcol_no_quotes = strip_end_quotes(pcol[0].strip())
    -    pval_no_quotes = strip_end_quotes(pval[0].strip())
    +    # Strip end quotes from pivot columns
    +    pcols = [strip_end_quotes(pcol.strip()) for pcol in pcols]
    +    pvals = [strip_end_quotes(pval.strip()) for pval in pvals]
    +
    +    # Parse the aggregate_func as a dictionary
    +    try:
    +        param_types = dict.fromkeys(pvals, list)
    +        param_types['__madlib_def_pval__'] = list
    +        agg_dict = extract_keyvalue_params(aggregate_func,param_types)
    +    except KeyError, e:
    +        with MinWarning("warning"):
    +            plpy.warning("Pivot: Not all columns from '{aggregate_func}'"
    +            " present in '{pivot_values}'".format(**locals()))
    +            raise
    +
    +    # If the dictionary is empty, parse it as a list
    +    agg_set = split_quoted_delimited_str(aggregate_func) if len(agg_dict) < 1 \
    +         else []
    +    # If the list is empty set 'avg' as default
    +    agg_dict['__madlib_def_agg__'] = ['avg'] if len(agg_set) < 1 else agg_set
     
         # Find the distinct values of pivot_cols
    -    distinct_values = plpy.execute(
    -        "SELECT array_agg(DISTINCT {pcol} ORDER BY {pcol}) AS value "
    -        "FROM {source_table}".
    -        format(pcol=pcol[0], source_table=source_table))
    -
    -    distinct_values = [strip_end_quotes(item)
    -                        for item in distinct_values[0]['value']]
    -    # The aggregate collects pivot_values values for a given pivot_cols value
    -    case_str = ("{agg}("
    -                "CASE WHEN \"{{pcol}}\" = '{{value}}' THEN {pval} ELSE NULL END"
    -                ")".
    -                format(agg=aggregate_func,
    -                       pval=pval_no_quotes))
    -    sql_list.append(
    -        ", " +
    -        # Assign the name of the new column
    -        ', '.join("{case_str} as \"{{pcol}}_{{value}}\"".
    -                  format(case_str=case_str).
    -                  format(pcol=pcol_no_quotes, value=str(value))
    -                  for value in distinct_values if value is not None))
    +    # Note that the distinct values are appended in order of users list
    +    # This ordering is important when we access pivot_comb entries
    +    distinct_str = ["SELECT "]
    +    distinct_str.append(
    +        ', '.join("array_agg(DISTINCT {pcol}) AS {pcol}_values".
    +            format(pcol=pcol) for pcol in pcols))
    +    distinct_str.append(" FROM " + source_table)
    +    distinct_values = plpy.execute(''.join(distinct_str))
    +
    +    # Collect the distinc values for every pivot column
    +    pcol_distinct_values = {}
    +    pcol_max_length = 0
    +    for pcol in pcols:
    +        # Read the distinct values for this pcol
    +        pcol_tmp = [item for item in distinct_values[0][pcol+"_values"]]
    +        # Remove null values if keep null is not true
    +        if not keep_null:
    +            pcol_tmp = [x for x in pcol_tmp if x is not None]
    +        pcol_distinct_values[pcol]=pcol_tmp
    +        # Max length of the string that pcol values can create +
    +        # length of pcol + 1 (for _ character)
    +        pcol_max_length+=max([len(str(item)) for item in pcol_tmp])+len(pcol)+1
    +
    +    # For non postgres systems add null to the pcol_distinct_values if necessary
    +    # This is required because DISTINCT keyword is implemented differently
    +    is_pg = m4_ifdef(<!__POSTGRESQL__!>, True, False)
    +    if keep_null and not is_pg:
    +        null_str_begin = ["SELECT "]
    +        null_str_begin.append(
    +            ', '.join("array_agg({pcol}_isn) as {pcol}_isnull".
    +                format(pcol=pcol) for pcol in pcols))
    +        null_str_end = [" FROM (SELECT DISTINCT "]
    +        null_str_end.append(
    +            ', '.join(" (CASE WHEN {pcol} IS NULL THEN 1 END) "
    +                " AS {pcol}_isn".
    +                format(pcol=pcol) for pcol in pcols))
    +        null_str_end.append(" FROM " + source_table +") x")
    +        null_str = ''.join(null_str_begin) + ''.join(null_str_end)
    +        null_values = plpy.execute(null_str)
    +        for pcol in pcols:
    +            pcol_tmp = [item for item in null_values[0][pcol+"_isnull"]]
    +            if 1 in pcol_tmp:
    +                pcol_distinct_values[pcol].append(None)
    +
    +    # Create the combination of every possible pivot column
    +    # Assume piv and piv2 are pivot columns. piv=(1,2) and piv2=(3,4,5)
    +    # pivot_comb = ((1,3),(1,4),(1,5),(2,3),(2,4),(2,5))
    +    pivot_comb = list(itertools.product(*([pcol_distinct_values[pcol]
    --- End diff --
    
    I suggest keeping the product output as an iterator (i.e. don't make it a list) since
you're only looping through it once. Further keep a count of number of pivot_comb seen while
iterating and return a warning when you've reached the threshold. Finally, make the threshold
a constant and initialize it at top with explanation on why it's set to that particular value
(1000).  


---
If your project is set up for it, you can reply to this email and have your
reply appear on GitHub as well. If your project does not have this feature
enabled and wishes so, or if the feature is enabled but not working, please
contact infrastructure at infrastructure@apache.org or file a JIRA ticket
with INFRA.
---

Mime
View raw message