GL Balance Detail (pivot)

Description
Categories: Enginatics, Financials
GL balance data on detailed segment level, amounts pivoted into one column per period.
select
z.*,
nvl(z.start_balance,0)+nvl(z.total,0) ytd
from
(
select
x.ledger,
&segment_columns2
nvl(x.period_name,'total') period_name,
max(x.start_balance) over (partition by &segment_columns 1) start_balance,
x.amount
from
(
select
gl.name ledger,
&segment_columns
gl.chart_of_accounts_id,
gps.period_name,
sum(decode(gps.start_period,'Y',nvl(gb.begin_balance_dr,0)-nvl(gb.begin_balance_cr,0))) start_balance,
sum(nvl(gb.period_net_dr,0)-nvl(gb.period_net_cr,0)) amount
from
gl_ledgers gl,
gl_period_statuses gps0,
(select decode(gps.period_num,min(gps.period_num) over (partition by gps.ledger_id, gps.application_id, gps.period_year),'Y') start_period, gps.* from gl_period_statuses gps) gps,
gl_balances gb,
gl_code_combinations gcc
where
1=1 and
gps0.period_name=:period_name and
gb.actual_flag=xxen_util.lookup_code(:balance_type,'XLA_BALANCE_TYPE',602) and
gl.ledger_id=gps0.ledger_id and
gps0.application_id=101 and
gps0.application_id=gps.application_id and
gps0.ledger_id=gps.ledger_id and
gps0.period_year=gps.period_year and
gps0.period_num>=gps.period_num and
gps.ledger_id=gb.ledger_id and
gps.period_name=gb.period_name and
gl.currency_code=gb.currency_code and
gb.code_combination_id=gcc.code_combination_id and
gcc.summary_flag='N'
group by
grouping sets(
(gl.name, &segment_columns gl.chart_of_accounts_id),
(gl.name, &segment_columns gl.chart_of_accounts_id, gps.period_name)
)
) x
) y
pivot (
sum(y.amount)
for period_name in (
&pivot_columns
)
) z
order by
&order_by 1
Parameter Name SQL text Validation
Show All Segments
select
lower(fifs.application_column_name)||',' text
from
fnd_id_flex_segments fifs,
fnd_id_flex_segments_tl fifst
where
:dummy=:dummy and
fifs.application_id=101 and
fifs.id_flex_code='GL#' and
fifs.id_flex_num=(select gl.chart_of_accounts_id from gl_ledgers gl where gl.name=:ledger_name) and
fifs.application_id=fifst.application_id and
fifs.id_flex_code=fifst.id_flex_code and
fifs.id_flex_num=fifst.id_flex_num and
fifs.application_column_name=fifst.application_column_name and
fifst.language=userenv('lang')
order by
fifs.segment_num
LOV
Period
 
LOV
Balance Type
 
LOV
Ledger
gl.name=:ledger_name
LOV
Show All Segments
select
--:dummy
case when x.level_=1 then
'x.'||lower(fifs.application_column_name)||' "'||fifst.form_left_prompt||'",' else
'xxen_util.segment_description(x.'||lower(fifs.application_column_name)||', '''||fifs.application_column_name||''', x.chart_of_accounts_id)'||' "'||fifst.form_left_prompt||' desc",'
end text
from
(select level level_ from dual connect by level<3) x,
fnd_id_flex_segments fifs,
fnd_id_flex_segments_tl fifst
where
fifs.application_id=101 and
fifs.id_flex_code='GL#' and
fifs.id_flex_num=(select gl.chart_of_accounts_id from gl_ledgers gl where gl.name=:ledger_name) and
fifs.application_id=fifst.application_id and
fifs.id_flex_code=fifst.id_flex_code and
fifs.id_flex_num=fifst.id_flex_num and
fifs.application_column_name=fifst.application_column_name and
fifst.language=userenv('lang')
order by
fifs.segment_num,
x.level_
Show All Segments
select
--:dummy
'"'||fifst.form_left_prompt||'",' text
from
fnd_id_flex_segments fifs,
fnd_id_flex_segments_tl fifst
where
fifs.application_id=101 and
fifs.id_flex_code='GL#' and
fifs.id_flex_num=(select gl.chart_of_accounts_id from gl_ledgers gl where gl.name=:ledger_name) and
fifs.application_id=fifst.application_id and
fifs.id_flex_code=fifst.id_flex_code and
fifs.id_flex_num=fifst.id_flex_num and
fifs.application_column_name=fifst.application_column_name and
fifst.language=userenv('lang')
order by
fifs.segment_num
Show Cost Center
select
--:dummy
case when x.level_=1 then
'x.'||lower(fsav.application_column_name)||' "'||fifst.form_left_prompt||'",' else
'xxen_util.segment_description(x.'||lower(fsav.application_column_name)||', '''||fsav.application_column_name||''', x.chart_of_accounts_id)'||' "'||fifst.form_left_prompt||' desc",'
end text
from
(select level level_ from dual connect by level<3) x,
fnd_segment_attribute_values fsav,
fnd_id_flex_segments_tl fifst
where
fsav.application_id=101 and
fsav.id_flex_code='GL#' and
fsav.segment_attribute_type='FA_COST_CTR' and
fsav.attribute_value='Y' and
fsav.id_flex_num in (select gl.chart_of_accounts_id from gl_ledgers gl where gl.name=:ledger_name) and
fsav.application_id=fifst.application_id and
fsav.id_flex_code=fifst.id_flex_code and
fsav.id_flex_num=fifst.id_flex_num and
fsav.application_column_name=fifst.application_column_name and
fifst.language=userenv('lang')
Show Cost Center
select
--:dummy
'"'||fifst.form_left_prompt||'",' text
from
fnd_segment_attribute_values fsav,
fnd_id_flex_segments_tl fifst
where
fsav.application_id=101 and
fsav.id_flex_code='GL#' and
fsav.segment_attribute_type='FA_COST_CTR' and
fsav.attribute_value='Y' and
fsav.id_flex_num in (select gl.chart_of_accounts_id from gl_ledgers gl where gl.name=:ledger_name) and
fsav.application_id=fifst.application_id and
fsav.id_flex_code=fifst.id_flex_code and
fsav.id_flex_num=fifst.id_flex_num and
fsav.application_column_name=fifst.application_column_name and
fifst.language=userenv('lang')
Show Account
select
--:dummy
case when x.level_=1 then
'x.'||lower(fsav.application_column_name)||' "'||fifst.form_left_prompt||'",' else
'xxen_util.segment_description(x.'||lower(fsav.application_column_name)||', '''||fsav.application_column_name||''', x.chart_of_accounts_id)'||' "'||fifst.form_left_prompt||' desc",'
end text
from
(select level level_ from dual connect by level<3) x,
fnd_segment_attribute_values fsav,
fnd_id_flex_segments_tl fifst
where
fsav.application_id=101 and
fsav.id_flex_code='GL#' and
fsav.segment_attribute_type='GL_ACCOUNT' and
fsav.attribute_value='Y' and
fsav.id_flex_num in (select gl.chart_of_accounts_id from gl_ledgers gl where gl.name=:ledger_name) and
fsav.application_id=fifst.application_id and
fsav.id_flex_code=fifst.id_flex_code and
fsav.id_flex_num=fifst.id_flex_num and
fsav.application_column_name=fifst.application_column_name and
fifst.language=userenv('lang')
Show Account
select
--:dummy
'"'||fifst.form_left_prompt||'",' text
from
fnd_segment_attribute_values fsav,
fnd_id_flex_segments_tl fifst
where
fsav.application_id=101 and
fsav.id_flex_code='GL#' and
fsav.segment_attribute_type='GL_ACCOUNT' and
fsav.attribute_value='Y' and
fsav.id_flex_num in (select gl.chart_of_accounts_id from gl_ledgers gl where gl.name=:ledger_name) and
fsav.application_id=fifst.application_id and
fsav.id_flex_code=fifst.id_flex_code and
fsav.id_flex_num=fifst.id_flex_num and
fsav.application_column_name=fifst.application_column_name and
fifst.language=userenv('lang')
Show Company
select
--:dummy
case when x.level_=1 then
'x.'||lower(fsav.application_column_name)||' "'||fifst.form_left_prompt||'",' else
'xxen_util.segment_description(x.'||lower(fsav.application_column_name)||', '''||fsav.application_column_name||''', x.chart_of_accounts_id)'||' "'||fifst.form_left_prompt||' desc",'
end text
from
(select level level_ from dual connect by level<3) x,
fnd_segment_attribute_values fsav,
fnd_id_flex_segments_tl fifst
where
fsav.application_id=101 and
fsav.id_flex_code='GL#' and
fsav.segment_attribute_type='GL_BALANCING' and
fsav.attribute_value='Y' and
fsav.id_flex_num in (select gl.chart_of_accounts_id from gl_ledgers gl where gl.name=:ledger_name) and
fsav.application_id=fifst.application_id and
fsav.id_flex_code=fifst.id_flex_code and
fsav.id_flex_num=fifst.id_flex_num and
fsav.application_column_name=fifst.application_column_name and
fifst.language=userenv('lang')
Show Company
select
--:dummy
'"'||fifst.form_left_prompt||'",' text
from
fnd_segment_attribute_values fsav,
fnd_id_flex_segments_tl fifst
where
fsav.application_id=101 and
fsav.id_flex_code='GL#' and
fsav.segment_attribute_type='GL_BALANCING' and
fsav.attribute_value='Y' and
fsav.id_flex_num in (select gl.chart_of_accounts_id from gl_ledgers gl where gl.name=:ledger_name) and
fsav.application_id=fifst.application_id and
fsav.id_flex_code=fifst.id_flex_code and
fsav.id_flex_num=fifst.id_flex_num and
fsav.application_column_name=fifst.application_column_name and
fifst.language=userenv('lang')
Period
select
x.*
from
(
select
''''||gps.period_name||''' '||decode(gps.adjustment_period_flag,'Y','adj_')||to_char(gps.start_date+8,'mon_YYYY','nls_date_language=american')||',' pivot_text
from
gl_ledgers gl,
gl_period_statuses gps0,
gl_period_statuses gps
where
gl.name=:ledger_name and
gps0.period_name=:period_name and
gl.ledger_id=gps0.ledger_id and
gps0.application_id=101 and
gps0.application_id=gps.application_id and
gps0.ledger_id=gps.ledger_id and
gps0.period_year=gps.period_year and
gps0.period_num>=gps.period_num
order by
gps.effective_period_num
) x
union all
select '''total'' total' from dual
Show Cost Center
select
lower(fsav.application_column_name)||',' text
from
fnd_segment_attribute_values fsav
where
:dummy=:dummy and
fsav.application_id=101 and
fsav.id_flex_code='GL#' and
fsav.segment_attribute_type='FA_COST_CTR' and
fsav.attribute_value='Y' and
fsav.id_flex_num in (select gl.chart_of_accounts_id from gl_ledgers gl where gl.name=:ledger_name)
LOV
Show Account
select
lower(fsav.application_column_name)||',' text
from
fnd_segment_attribute_values fsav
where
:dummy=:dummy and
fsav.application_id=101 and
fsav.id_flex_code='GL#' and
fsav.segment_attribute_type='GL_ACCOUNT' and
fsav.attribute_value='Y' and
fsav.id_flex_num in (select gl.chart_of_accounts_id from gl_ledgers gl where gl.name=:ledger_name)
LOV
Show Company
select
lower(fsav.application_column_name)||',' text
from
fnd_segment_attribute_values fsav
where
:dummy=:dummy and
fsav.application_id=101 and
fsav.id_flex_code='GL#' and
fsav.segment_attribute_type='GL_BALANCING' and
fsav.attribute_value='Y' and
fsav.id_flex_num in (select gl.chart_of_accounts_id from gl_ledgers gl where gl.name=:ledger_name)
LOV