From 5dc970da3f29cd2ae563339043da6372b97bffc3 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Tue, 16 Sep 2025 21:41:07 -0400 Subject: [PATCH] move rebuild scripts and create ddl scripts --- WARP.md | 127 +++++++++++ rebuild/lastpricedetail.ms.sql | 245 ++++++++++++++++++++ rebuild/lastpricedetail.pg.sql | 1 + rebuild/pricelist_ranged.ms.sql | 199 ++++++++++++++++ rebuild/pricelist_ranged.pg.sql | 101 +++++++++ rebuild/rebuild_target.ms.sql | 22 ++ {tables => rebuild}/rebuild_targets.pg.sql | 0 tables/lastpricedetail.ms.sql | 250 +-------------------- tables/pricelist_ranged.ms.sql | 206 +---------------- tables/pricelist_ranged.pg.sql | 112 +-------- tables/target_prices.ms.sql | 22 -- 11 files changed, 721 insertions(+), 564 deletions(-) create mode 100644 WARP.md create mode 100644 rebuild/lastpricedetail.ms.sql create mode 100644 rebuild/lastpricedetail.pg.sql create mode 100644 rebuild/pricelist_ranged.ms.sql create mode 100644 rebuild/pricelist_ranged.pg.sql create mode 100644 rebuild/rebuild_target.ms.sql rename {tables => rebuild}/rebuild_targets.pg.sql (100%) diff --git a/WARP.md b/WARP.md new file mode 100644 index 0000000..5760acb --- /dev/null +++ b/WARP.md @@ -0,0 +1,127 @@ +# WARP.md + +This file provides guidance to WARP (warp.dev) when working with code in this repository. + +## Architecture Overview + +This is a **pricing engine** that computes product pricing recommendations based on multiple data sources (target prices, historical sales, list prices). The system operates with both **SQL Server** and **PostgreSQL** implementations, providing pricing guidance through structured JSON responses. + +### Core Components + +**Database-First Architecture**: The system is primarily database-driven with stored procedures/functions as the main business logic layer. Each major component has both SQL Server (`.ms.sql`) and PostgreSQL (`.pg.sql`) implementations. + +**Single Price Call Flow**: The main entry point is `single_price_call` which processes one pricing scenario through these stages: +1. **Input enrichment** - Resolves customer/channel/tier from bill-to/ship-to codes +2. **Historical price lookup** - Finds most recent/relevant sales from `lastpricedetail` +3. **Target price lookup** - Gets configured target pricing from `target_prices` +4. **Cost normalization** - Adjusts historical prices across different product data segments +5. **List price lookup** - Retrieves volume-banded list prices from `pricelist_ranged` +6. **Guidance logic** - Computes final recommended price using `guidance_logic` +7. **JSON generation** - Creates structured `ui_json` for frontend consumption + +**Multi-Database Support**: Core logic exists in parallel implementations: +- **SQL Server**: `procs/*.ms.sql`, `tables/*.ms.sql` +- **PostgreSQL**: `procs/*.pg.sql`, `tables/*.pg.sql` + +## Common Development Commands + +### Testing Individual Pricing Scenarios +```sql +-- SQL Server +EXEC pricing.single_price_call + @bill = 'GRIF0001', + @ship = 'GRIF0001', + @part = 'XNS0T1G3G18B096', + @v1ds = 'v1:B..PLT..', + @vol = 9600; + +-- PostgreSQL +SELECT ui_json->'data' +FROM pricequote.single_price_call( + 'GRIF0001', + 'GRIF0001', + 'XNS0T1G3G18B096', + 'v1:B..PLT..', + 9600 +); +``` + +### Running Test Examples +Execute the complete example scenarios: +```powershell +# SQL Server examples +sqlcmd -S server -d database -i example_usage.ms.sql + +# PostgreSQL examples +psql -d database -f example_usage.pg.sql +``` + +### Database Schema Updates +Deploy schema changes in this order: +```powershell +# 1. Tables first +sqlcmd -S server -d database -i tables/target_prices.ms.sql +sqlcmd -S server -d database -i tables/pricelist_ranged.ms.sql +sqlcmd -S server -d database -i tables/lastpricedetail.ms.sql + +# 2. Functions/procedures second +sqlcmd -S server -d database -i procs/guidance_logic.ms.sql +sqlcmd -S server -d database -i procs/single_price_call.ms.sql +``` + +### Data Rebuilds +Refresh core pricing data: +```sql +-- Rebuild price list with UOM conversions +EXEC [script from pricelist_ranged.ms.sql] + +-- Refresh historical price summaries +EXEC [script from lastpricedetail.ms.sql] + +-- Update target price configurations +INSERT INTO pricing.target_prices SELECT * FROM remote.target_prices_view; +``` + +## Key Data Structures + +**Input Parameters**: All pricing calls require: +- `bill` - Bill-to customer code +- `ship` - Ship-to customer code +- `part` - Product part number +- `v1ds` - Product data segment (version 1) +- `vol` - Volume quantity + +**UI JSON Structure**: The output `ui_json` contains: +- `details[]` - Array of pricing panels (History, List, Target Calculation, Guidance) +- `data` - Raw `expl` JSON with all calculation details + +**Product Data Segments**: Products have versioned data segments (v1ds/v0ds) that affect pricing: +- Format: `v1:B..PLT..` (color tier, packaging, etc.) +- Cross-segment price normalization uses target price ratios or cost ratios + +## Database Schemas + +**SQL Server**: Uses `pricing.*` schema +- `pricing.single_price_call` - Main pricing procedure +- `pricing.target_prices` - Configured target pricing rules +- `pricing.lastpricedetail` - Historical price summaries per customer/product group + +**PostgreSQL**: Uses `pricequote.*` schema +- `pricequote.single_price_call()` - Main pricing function +- `pricequote.target_prices` - Target pricing configurations +- `pricequote.lastpricedetail` - Historical price data + +## Key Business Logic + +**Guidance Logic**: Located in `guidance_logic.*sql`, determines final price using precedence: +1. Target price (if available) +2. Last normalized price (prevents price drops) +3. List price (as ceiling) + +**Price Normalization**: When historical prices are from different product segments, they're adjusted using either target price ratios or cost ratios to enable fair comparison. + +**Volume Banding**: List prices and target prices use volume ranges. The `pricelist_ranged` tables normalize all unit-of-measure to "PC" (pieces) for consistent volume comparisons. + +## Archive Directory + +Contains legacy TypeScript implementations and older SQL approaches. The `archive/apply_guidance.ts` shows the previous client-side pricing logic that has been moved to database stored procedures/functions. diff --git a/rebuild/lastpricedetail.ms.sql b/rebuild/lastpricedetail.ms.sql new file mode 100644 index 0000000..885043b --- /dev/null +++ b/rebuild/lastpricedetail.ms.sql @@ -0,0 +1,245 @@ +-------------------------------------------------------------------------------- +-- Reset target tables +-------------------------------------------------------------------------------- +--DROP TABLE IF EXISTS pricing.lastpricedetail; +DELETE FROM pricing.lastpricedetail; +DROP TABLE IF EXISTS #flagged; + +-------------------------------------------------------------------------------- +-- Stage 1: Load cleaned input rows +-- Filters out irrelevant quotes/orders and calculates unit prices +-------------------------------------------------------------------------------- +WITH base AS ( + SELECT + o."Customer" AS customer, + o."Part Group" AS partgroup, + RTRIM(i.V1DS) AS dataseg, + o."Data Source" AS version, + o."Part Code" AS part, + o."Units" AS qty, + CASE + WHEN o."Units" = 0 THEN NULL + ELSE ROUND(o.[Value USD] / NULLIF(o."Units", 0), 5) + END AS price, + o.[Order Date] AS odate, + o.[Order Number] AS ordnum, + o.[Quote Number] AS quoten + FROM + rlarp.osm_stack_pretty o + INNER JOIN CMSInterfaceIn.[CMS.CUSLG].ITEMM i + ON i.item = o.[Part Code] + WHERE + o.[Data Source] IN ('Actual', 'Quotes') + AND o."Customer" IS NOT NULL + AND o."Financial Statement Line" = '41010' + AND o."Order Status" <> 'CANCELLED' + AND o."Units" > 0 + AND o."Part Group" <> '' + -- Optional filter for testing + -- AND o."Customer" = 'ESBENSHADES GREENHOUSE' +), +-------------------------------------------------------------------------------- +-- Stage 2: Rank each row based on recency and volume rules +-- Flags include: +-- - rn_mrs: most recent sale +-- - rn_mrq: most recent quote +-- - rn_lvs: largest sale in last year +-- - rn_lvq: largest quote in last year +-- - rn_dss: most recent sale per dataseg +-- - rn_dsq: most recent quote per dataseg +-------------------------------------------------------------------------------- +ranked AS ( + SELECT + b.* + -- Most recent sale (Actuals only) + ,CASE WHEN b.version = 'Actual' THEN + ROW_NUMBER() OVER ( + PARTITION BY b.customer, b.partgroup + ORDER BY b.odate DESC + ) + END AS rn_mrs + -- Most recent quote (Quotes only) + ,CASE WHEN b.version = 'Quotes' THEN + ROW_NUMBER() OVER ( + PARTITION BY b.customer, b.partgroup + ORDER BY b.odate DESC + ) + END AS rn_mrq + -- Largest volume sale (Actuals only; last 12 months prioritized) + ,CASE WHEN b.version = 'Actual' THEN + ROW_NUMBER() OVER ( + PARTITION BY b.customer, b.partgroup + ORDER BY + CASE WHEN b.version = 'Actual' AND b.odate >= DATEADD(YEAR, -1, GETDATE()) THEN 1 ELSE 0 END DESC, + b.qty DESC + ) + END AS rn_lvs + -- Largest volume quote (Quotes only; last 12 months prioritized) + ,CASE WHEN b.version = 'Quotes' THEN + ROW_NUMBER() OVER ( + PARTITION BY b.customer, b.partgroup + ORDER BY + CASE WHEN b.version = 'Quotes' AND b.odate >= DATEADD(YEAR, -1, GETDATE()) THEN 1 ELSE 0 END DESC, + b.qty DESC + ) + END AS rn_lvq + ,CASE WHEN b.version = 'Actual' THEN + ROW_NUMBER() OVER ( + PARTITION BY b.customer, b.partgroup, b.dataseg, b.version + ORDER BY b.odate DESC + ) + END AS rn_dss + ,CASE WHEN b.version = 'Quotes' THEN + ROW_NUMBER() OVER ( + PARTITION BY b.customer, b.partgroup, b.dataseg, b.version + ORDER BY b.odate DESC + ) + END AS rn_dsq + FROM base b +) +-------------------------------------------------------------------------------- +-- Stage 2.5: Save only rows that meet any of the above criteria +-- and annotate each with global-level flag (mrs, mrq, lvs, lvq) +-------------------------------------------------------------------------------- +SELECT + *, + CASE WHEN rn_mrs = 1 THEN 'mrs' END AS f1, + CASE WHEN rn_mrq = 1 THEN 'mrq' END AS f2, + CASE WHEN rn_lvs = 1 THEN 'lvs' END AS f3, + CASE WHEN rn_lvq = 1 THEN 'lvq' END AS f4, + CASE WHEN rn_dss = 1 AND version = 'Actual' THEN 'dss' END AS f5, + CASE WHEN rn_dsq = 1 AND version = 'Quotes' THEN 'dsq' END AS f6 +INTO #flagged +FROM ranked +WHERE + rn_mrs = 1 + OR rn_mrq = 1 + OR rn_lvs = 1 + OR rn_lvq = 1 + OR (rn_dss = 1 AND version = 'Actual') + OR (rn_dsq = 1 AND version = 'Quotes'); + +CREATE NONCLUSTERED INDEX ix_flagged_lookup +ON #flagged(customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten); + +-------------------------------------------------------------------------------- +-- Stage 3: Build JSON from flagged rows +-------------------------------------------------------------------------------- + +-- Step 3.1: Explode all flags from the #flagged table +WITH exploded_flags AS ( + SELECT + customer, partgroup, part, dataseg, version, qty, price, odate, ordnum, quoten, + flag + FROM #flagged + CROSS APPLY (VALUES (f1), (f2), (f3), (f4), (f5), (f6)) AS f(flag) + WHERE flag IS NOT NULL +) +--SELECT * FROM exploded_flags +-- Step 3.2: Serialize each row into its JSON snippet +-- Carry odate and version for deduplication in seg_pieces +,serialized_flags AS ( + SELECT + customer, + partgroup, + dataseg, + flag, + odate, + version, + CONCAT( + '"', flag, '":', + JSON_QUERY(( + SELECT + version, + dataseg AS datasegment, + part, + qty, + price, + odate, + ordnum, + quoten, + flag + FOR JSON PATH, WITHOUT_ARRAY_WRAPPER + )) + ) AS json_piece + FROM exploded_flags +) +--SELECT * FROM serialized_flags +-- Step 3.3: Collect all global-level flags (mrs, mrq, lvs, lvq) +,flag_json AS ( + SELECT + customer, + partgroup, + STRING_AGG(json_piece, ',') AS json_block + FROM serialized_flags + WHERE flag IN ('mrs', 'mrq', 'lvs', 'lvq') + GROUP BY customer, partgroup +) +--SELECT * FROM flag_json +-- Step 3.4: Nest dss/dsq under each dataseg +-- Only keep the most recent dss/dsq per dataseg/version (prevents duplicate keys) +,seg_pieces AS ( + SELECT + customer, + partgroup, + dataseg, + STRING_AGG(json_piece, ',') AS inner_json + FROM ( + SELECT sf.* + FROM ( + SELECT *, + ROW_NUMBER() OVER ( + PARTITION BY customer, partgroup, dataseg, flag + ORDER BY odate DESC, + CASE WHEN version = 'Actual' THEN 1 ELSE 0 END DESC + ) AS rn + FROM serialized_flags + WHERE flag IN ('dss', 'dsq') + ) sf + WHERE sf.rn = 1 + ) deduped + GROUP BY customer, partgroup, dataseg +) +--SELECT * FROM seg_pieces +-- Step 3.5: Wrap the inner_json under dataseg key +,wrapped_segs AS ( + SELECT + customer, + partgroup, + CONCAT( + '"', dataseg, '": {', inner_json, '}' + ) AS json_piece + FROM seg_pieces +) +-- Step 3.6: Aggregate all dataseg entries into one JSON block per customer/partgroup +,seg_json AS ( + SELECT + customer, + partgroup, + STRING_AGG(json_piece, ',') AS json_block + FROM wrapped_segs + GROUP BY customer, partgroup +) +--SELECT * FROM seg_json +-------------------------------------------------------------------------------- +-- Stage 4: Merge flags and segment blocks into a single JSON object +-- Write final pricing history to pricing.lastpricedetail +-------------------------------------------------------------------------------- +INSERT INTO + pricing.lastpricedetail +SELECT + COALESCE(f.customer, s.customer) AS customer, + COALESCE(f.partgroup, s.partgroup) AS partgroup, + CONCAT( + '{', + COALESCE(f.json_block, ''), + CASE + WHEN f.json_block IS NOT NULL AND s.json_block IS NOT NULL THEN ',' + ELSE '' + END, + COALESCE(s.json_block, ''), + '}' + ) AS part_stats +FROM flag_json f +FULL OUTER JOIN seg_json s + ON f.customer = s.customer AND f.partgroup = s.partgroup; diff --git a/rebuild/lastpricedetail.pg.sql b/rebuild/lastpricedetail.pg.sql new file mode 100644 index 0000000..5ee7df8 --- /dev/null +++ b/rebuild/lastpricedetail.pg.sql @@ -0,0 +1 @@ +REFRESH MATERIALIZED VIEW pricequote.lastpricedetail; diff --git a/rebuild/pricelist_ranged.ms.sql b/rebuild/pricelist_ranged.ms.sql new file mode 100644 index 0000000..d25fc9b --- /dev/null +++ b/rebuild/pricelist_ranged.ms.sql @@ -0,0 +1,199 @@ +DROP TABLE pricing.pricelist_ranged; + +CREATE TABLE pricing.pricelist_ranged ( + jcplcd varchar(5) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, + jcpart varchar(20) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, + jcunit varchar(3) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, + jcvoll numeric(12,5) NOT NULL, + jcpric numeric(12,5) NOT NULL, + vb_from float NULL, + vb_to float NULL, + price float NOT NULL +); + +CREATE NONCLUSTERED INDEX pricelist_ranged_idx ON FAnalysis.PRICING.pricelist_ranged ( jcpart ASC , jcplcd ASC , vb_from ASC , vb_to ASC ) ; + +--XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX +-----------------------------------------------------------traverse unit of measure graph----------------------------------------------------------------------- +--XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX +-------------setup table to hold target conversions--------------------- + + +SELECT DISTINCT + jcpart partn + ,jcunit fu + ,'PC' tu + ,cast(null as numeric) factor +INTO + #anchor +FROM + cmsinterfacein.lgdat.iprcc +WHERE + 1=1; + +--SELECT * FROM #anchor + +-------pre-build punit stacked on itself with the columns flipped so you can go either direction per join--------- +SELECT + * +INTO + #g +FROM + ( + SELECT + IHPART IHPART, + rtrim(IHUNT1) IHUNT1, + rtrim(IHUNT2) IHUNT2, + IHCNV1 IHCNV1, + IHCNV2 IHCNV2 + FROM + CMSInterfaceIN.LGDAT.PUNIT pu + --only deal with parts in the anchor table or the &&global parts + INNER JOIN ( + SELECT DISTINCT partn FROM #anchor + ) items ON + items.partn = pu.ihpart + OR pu.ihpart = '&&GLOBAL' + UNION + SELECT + IHPART IHPART, + rtrim(IHUNT2) IHUNT1, + rtrim(IHUNT1) IHUNT2, + IHCNV2 IHCNV1, + IHCNV1 IHCNV2 + FROM + CMSInterfaceIN.LGDAT.PUNIT pu + --only deal with parts in the anchor table or the &&global parts + INNER JOIN ( + SELECT DISTINCT partn FROM #anchor + ) items ON + items.partn = pu.ihpart + OR pu.ihpart = '&&GLOBAL' + ) x ; + +CREATE INDEX g_idx on #g(ihpart,ihunt1); + +WITH +--------do the expansion on all paths until the target uom is matched---------------------------------------------- +--(complains about types not matching between anchor and recursion, explicitly just casting everything) +uom (partn, partx, lvl, mastf, mastt, xf, xt, factor, xfactor, xnum, xden, id, uom_list) AS +( + SELECT + cast(partn as varchar(20)) --partn + ,cast(partn as varchar(20)) --partx + ,cast(0 as int) --lvl + ,fu --mastf + ,tu --mastt + ,cast(fu as varchar(3)) --xf + ,cast(fu as varchar(3)) --xt + ,CAST(1 AS FLOAT) --factor + ,CAST(1 AS FLOAT) --xfactor + ,CAST(1 AS FLOAT) --xnum + ,CAST(1 AS FLOAT) --xden + ,format(row_number() over (ORDER BY partn),'000000') + ,cast(trim(fu) as varchar(max)) + FROM + #anchor + UNION ALL + SELECT + cast(uom.partn as varchar(20)) --partn + ,cast(ihpart as varchar(20)) --partx + ,CAST(uom.lvl + 1 AS INT) --lvl + ,uom.mastf --mastf + ,uom.mastt --mastt + ,cast(p.ihunt1 as varchar(3)) --xf + ,cast(p.ihunt2 as varchar(3)) --xt + ,CAST(p.ihcnv2/p.ihcnv1 AS FLOAT) --factor + ,CAST(p.ihcnv2/p.ihcnv1 AS FLOAT) * uom.xfactor --xfactor + ,p.ihcnv2 * uom.xnum --xnum + ,p.ihcnv1 * uom.xden --xden + ,uom.id + '.' + format(row_number() over (PARTITION BY uom.id ORDER BY partn),'00') + ,uom.uom_list + '.' + trim(p.ihunt2) + FROM + uom + INNER JOIN #g p ON + p.ihpart IN (uom.partn,'&&GLOBAL') + AND p.ihunt1 = uom.xt + WHERE + 1=1 + --AND p.ihunt2 not in ('BD','BG','BU','BX','CA','CS','PA','PL','SL','C','K','DOZ','PR') + AND p.ihunt1 <> uom.mastt + --prevent recursion: newest joined UOM can't be in the history + AND charindex(p.ihunt2,uom.uom_list) = 0 +) +--SELECT COUNT(*) FROM UOM +--------------uom is going to have multiple rows per requested conversion, need to use row_number to pick the best row------------------------------ +,sorted AS ( +SELECT + partn, mastf from_uom, xt to_uom, xfactor factor, lvl steps, row_number() OVER (PARTITION BY partn, mastf, mastt ORDER BY lvl ASC, factor ASC) rn +FROM + uom +WHERE + xt = mastt +) +SELECT * INTO #uom FROM sorted WHERE rn = 1; +--so far so good + +drop table #anchor; +drop table #g; + +TRUNCATE TABLE pricing.pricelist_ranged; + +WITH +conv AS ( + SELECT + p.jcplcd, + p.jcpart, + p.jcunit, + p.jcvoll, + p.jcpric, + u.factor, + -- Normalize volume and price to PC + p.jcvoll * u.factor AS vol_pc, + p.jcpric / u.factor AS price_pc + FROM + cmsinterfacein.lgdat.iprcc p + INNER JOIN #uom u + ON u.partn = p.jcpart + AND u.from_uom = p.jcunit + AND u.to_uom = 'PC' +), +sorted AS ( + SELECT + c.*, + ROW_NUMBER() OVER (PARTITION BY c.jcplcd, c.jcpart ORDER BY vol_pc ASC) AS rn + FROM conv c +), +ranged AS ( + SELECT + curr.jcplcd, + curr.jcpart, + curr.jcunit, + curr.jcvoll, + curr.jcpric, + curr.vol_pc, + curr.price_pc, + curr.vol_pc AS vb_from, + COALESCE(next.vol_pc, 9999999.0) AS vb_to + FROM + sorted curr + LEFT JOIN sorted next + ON curr.jcplcd = next.jcplcd + AND curr.jcpart = next.jcpart + AND curr.rn + 1 = next.rn +) +INSERT INTO + pricing.pricelist_ranged +SELECT + RTRIM(jcplcd) jcplcd, + RTRIM(jcpart) jcpart, + jcunit, + jcvoll, + jcpric, + vb_from, + vb_to, + price_pc AS price +FROM + ranged; + +--CREATE INDEX pricelist_ranged_idx ON pricing.pricelist_ranged(jcpart, jcplcd, vb_from, vb_to); diff --git a/rebuild/pricelist_ranged.pg.sql b/rebuild/pricelist_ranged.pg.sql new file mode 100644 index 0000000..1035fc5 --- /dev/null +++ b/rebuild/pricelist_ranged.pg.sql @@ -0,0 +1,101 @@ +DROP TABLE IF EXISTS uomc; + +CREATE TEMP TABLE uomc AS ( +WITH +uom AS ( + SELECT + uom.p part + ,uom.f fu + ,uom.t tu + ,uom.nm/uom.dm conv + FROM + ( + SELECT + jsonb_agg(row_to_json(d)::jsonb) jdoc + FROM + ( + select distinct + jcpart partn + , jcunit fu + , 'PC' tu + from + lgdat.iprcc + WHERE + jcpart <> '' + ) d + ) c + JOIN LATERAL rlarp.uom_array(c.jdoc) uom ON TRUE +) +SELECT * FROM uom +) WITH DATA; + +CREATE INDEX uom_idx ON uomc (part, fu, tu); + + +-- Clear the output table +TRUNCATE TABLE pricequote.pricelist_ranged; + +--DROP TABLE pricequote.pricelist_ranged; + +-- Compute normalized volume/price and ranges +--CREATE TABLE pricequote.pricelist_ranged AS ( +WITH +conv AS ( + SELECT + p.jcplcd, + p.jcpart, + p.jcunit, + p.jcvoll, + p.jcpric, + u.conv, + (p.jcvoll * u.conv) AS vol_pc, + (p.jcpric / NULLIF(u.conv, 0)) AS price_pc + FROM + lgdat.iprcc p + INNER JOIN uomc u + ON u.part = p.jcpart + AND u.fu = p.jcunit + AND u.tu = 'PC' +), +--SELECT * FROM conv LIMIT 1000 +sorted AS ( + SELECT + *, + ROW_NUMBER() OVER (PARTITION BY jcplcd, jcpart ORDER BY vol_pc ASC) AS rn + FROM conv +), +ranged AS ( + SELECT + curr.jcplcd, + curr.jcpart, + curr.jcunit, + curr.jcvoll, + curr.jcpric, + curr.vol_pc, + curr.price_pc price, + curr.vol_pc AS vb_from, + COALESCE(next.vol_pc, 9999999.0) AS vb_to + FROM + sorted curr + LEFT JOIN sorted next + ON curr.jcplcd = next.jcplcd + AND curr.jcpart = next.jcpart + AND curr.rn + 1 = next.rn +) +--SELECT * FROM ranged +INSERT INTO pricequote.pricelist_ranged ( + jcplcd, jcpart, jcunit, jcvoll, jcpric, vb_from, vb_to, price +) +SELECT + jcplcd, + jcpart, + jcunit, + jcvoll, + jcpric, + vb_from, + vb_to, + price +FROM ranged; + + +CREATE INDEX pricelist_ranged_idx ON pricequote.pricelist_ranged ( jcpart ASC , jcplcd ASC , vb_from ASC , vb_to ASC ) ; \ No newline at end of file diff --git a/rebuild/rebuild_target.ms.sql b/rebuild/rebuild_target.ms.sql new file mode 100644 index 0000000..7902a5a --- /dev/null +++ b/rebuild/rebuild_target.ms.sql @@ -0,0 +1,22 @@ + +DELETE FROM pricing.target_prices; + +INSERT INTO + pricing.target_prices +SELECT + stlc, + ds, + chan, + tier, + vol, + -- Extract lower bound: text between '[' and ',' + TRY_CAST(SUBSTRING(vol, 2, CHARINDEX(',', vol) - 2) AS INT) AS lower_bound, + -- Extract upper bound: text between ',' and ')' + CASE + WHEN RIGHT(vol, 2) = ',)' THEN NULL + ELSE TRY_CAST(SUBSTRING(vol, CHARINDEX(',', vol) + 1, LEN(vol) - CHARINDEX(',', vol) - 1) AS INT) + END AS upper_bound, + price, + math +FROM + usmidsap02.ubm.pricequote.target_prices_view; diff --git a/tables/rebuild_targets.pg.sql b/rebuild/rebuild_targets.pg.sql similarity index 100% rename from tables/rebuild_targets.pg.sql rename to rebuild/rebuild_targets.pg.sql diff --git a/tables/lastpricedetail.ms.sql b/tables/lastpricedetail.ms.sql index 885043b..e52c201 100644 --- a/tables/lastpricedetail.ms.sql +++ b/tables/lastpricedetail.ms.sql @@ -1,245 +1,7 @@ --------------------------------------------------------------------------------- --- Reset target tables --------------------------------------------------------------------------------- ---DROP TABLE IF EXISTS pricing.lastpricedetail; -DELETE FROM pricing.lastpricedetail; -DROP TABLE IF EXISTS #flagged; +CREATE TABLE lastpricedetail ( + customer varchar(255), + partgroup varchar(10), + part_stats nvarchar(MAX) +); --------------------------------------------------------------------------------- --- Stage 1: Load cleaned input rows --- Filters out irrelevant quotes/orders and calculates unit prices --------------------------------------------------------------------------------- -WITH base AS ( - SELECT - o."Customer" AS customer, - o."Part Group" AS partgroup, - RTRIM(i.V1DS) AS dataseg, - o."Data Source" AS version, - o."Part Code" AS part, - o."Units" AS qty, - CASE - WHEN o."Units" = 0 THEN NULL - ELSE ROUND(o.[Value USD] / NULLIF(o."Units", 0), 5) - END AS price, - o.[Order Date] AS odate, - o.[Order Number] AS ordnum, - o.[Quote Number] AS quoten - FROM - rlarp.osm_stack_pretty o - INNER JOIN CMSInterfaceIn.[CMS.CUSLG].ITEMM i - ON i.item = o.[Part Code] - WHERE - o.[Data Source] IN ('Actual', 'Quotes') - AND o."Customer" IS NOT NULL - AND o."Financial Statement Line" = '41010' - AND o."Order Status" <> 'CANCELLED' - AND o."Units" > 0 - AND o."Part Group" <> '' - -- Optional filter for testing - -- AND o."Customer" = 'ESBENSHADES GREENHOUSE' -), --------------------------------------------------------------------------------- --- Stage 2: Rank each row based on recency and volume rules --- Flags include: --- - rn_mrs: most recent sale --- - rn_mrq: most recent quote --- - rn_lvs: largest sale in last year --- - rn_lvq: largest quote in last year --- - rn_dss: most recent sale per dataseg --- - rn_dsq: most recent quote per dataseg --------------------------------------------------------------------------------- -ranked AS ( - SELECT - b.* - -- Most recent sale (Actuals only) - ,CASE WHEN b.version = 'Actual' THEN - ROW_NUMBER() OVER ( - PARTITION BY b.customer, b.partgroup - ORDER BY b.odate DESC - ) - END AS rn_mrs - -- Most recent quote (Quotes only) - ,CASE WHEN b.version = 'Quotes' THEN - ROW_NUMBER() OVER ( - PARTITION BY b.customer, b.partgroup - ORDER BY b.odate DESC - ) - END AS rn_mrq - -- Largest volume sale (Actuals only; last 12 months prioritized) - ,CASE WHEN b.version = 'Actual' THEN - ROW_NUMBER() OVER ( - PARTITION BY b.customer, b.partgroup - ORDER BY - CASE WHEN b.version = 'Actual' AND b.odate >= DATEADD(YEAR, -1, GETDATE()) THEN 1 ELSE 0 END DESC, - b.qty DESC - ) - END AS rn_lvs - -- Largest volume quote (Quotes only; last 12 months prioritized) - ,CASE WHEN b.version = 'Quotes' THEN - ROW_NUMBER() OVER ( - PARTITION BY b.customer, b.partgroup - ORDER BY - CASE WHEN b.version = 'Quotes' AND b.odate >= DATEADD(YEAR, -1, GETDATE()) THEN 1 ELSE 0 END DESC, - b.qty DESC - ) - END AS rn_lvq - ,CASE WHEN b.version = 'Actual' THEN - ROW_NUMBER() OVER ( - PARTITION BY b.customer, b.partgroup, b.dataseg, b.version - ORDER BY b.odate DESC - ) - END AS rn_dss - ,CASE WHEN b.version = 'Quotes' THEN - ROW_NUMBER() OVER ( - PARTITION BY b.customer, b.partgroup, b.dataseg, b.version - ORDER BY b.odate DESC - ) - END AS rn_dsq - FROM base b -) --------------------------------------------------------------------------------- --- Stage 2.5: Save only rows that meet any of the above criteria --- and annotate each with global-level flag (mrs, mrq, lvs, lvq) --------------------------------------------------------------------------------- -SELECT - *, - CASE WHEN rn_mrs = 1 THEN 'mrs' END AS f1, - CASE WHEN rn_mrq = 1 THEN 'mrq' END AS f2, - CASE WHEN rn_lvs = 1 THEN 'lvs' END AS f3, - CASE WHEN rn_lvq = 1 THEN 'lvq' END AS f4, - CASE WHEN rn_dss = 1 AND version = 'Actual' THEN 'dss' END AS f5, - CASE WHEN rn_dsq = 1 AND version = 'Quotes' THEN 'dsq' END AS f6 -INTO #flagged -FROM ranked -WHERE - rn_mrs = 1 - OR rn_mrq = 1 - OR rn_lvs = 1 - OR rn_lvq = 1 - OR (rn_dss = 1 AND version = 'Actual') - OR (rn_dsq = 1 AND version = 'Quotes'); - -CREATE NONCLUSTERED INDEX ix_flagged_lookup -ON #flagged(customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten); - --------------------------------------------------------------------------------- --- Stage 3: Build JSON from flagged rows --------------------------------------------------------------------------------- - --- Step 3.1: Explode all flags from the #flagged table -WITH exploded_flags AS ( - SELECT - customer, partgroup, part, dataseg, version, qty, price, odate, ordnum, quoten, - flag - FROM #flagged - CROSS APPLY (VALUES (f1), (f2), (f3), (f4), (f5), (f6)) AS f(flag) - WHERE flag IS NOT NULL -) ---SELECT * FROM exploded_flags --- Step 3.2: Serialize each row into its JSON snippet --- Carry odate and version for deduplication in seg_pieces -,serialized_flags AS ( - SELECT - customer, - partgroup, - dataseg, - flag, - odate, - version, - CONCAT( - '"', flag, '":', - JSON_QUERY(( - SELECT - version, - dataseg AS datasegment, - part, - qty, - price, - odate, - ordnum, - quoten, - flag - FOR JSON PATH, WITHOUT_ARRAY_WRAPPER - )) - ) AS json_piece - FROM exploded_flags -) ---SELECT * FROM serialized_flags --- Step 3.3: Collect all global-level flags (mrs, mrq, lvs, lvq) -,flag_json AS ( - SELECT - customer, - partgroup, - STRING_AGG(json_piece, ',') AS json_block - FROM serialized_flags - WHERE flag IN ('mrs', 'mrq', 'lvs', 'lvq') - GROUP BY customer, partgroup -) ---SELECT * FROM flag_json --- Step 3.4: Nest dss/dsq under each dataseg --- Only keep the most recent dss/dsq per dataseg/version (prevents duplicate keys) -,seg_pieces AS ( - SELECT - customer, - partgroup, - dataseg, - STRING_AGG(json_piece, ',') AS inner_json - FROM ( - SELECT sf.* - FROM ( - SELECT *, - ROW_NUMBER() OVER ( - PARTITION BY customer, partgroup, dataseg, flag - ORDER BY odate DESC, - CASE WHEN version = 'Actual' THEN 1 ELSE 0 END DESC - ) AS rn - FROM serialized_flags - WHERE flag IN ('dss', 'dsq') - ) sf - WHERE sf.rn = 1 - ) deduped - GROUP BY customer, partgroup, dataseg -) ---SELECT * FROM seg_pieces --- Step 3.5: Wrap the inner_json under dataseg key -,wrapped_segs AS ( - SELECT - customer, - partgroup, - CONCAT( - '"', dataseg, '": {', inner_json, '}' - ) AS json_piece - FROM seg_pieces -) --- Step 3.6: Aggregate all dataseg entries into one JSON block per customer/partgroup -,seg_json AS ( - SELECT - customer, - partgroup, - STRING_AGG(json_piece, ',') AS json_block - FROM wrapped_segs - GROUP BY customer, partgroup -) ---SELECT * FROM seg_json --------------------------------------------------------------------------------- --- Stage 4: Merge flags and segment blocks into a single JSON object --- Write final pricing history to pricing.lastpricedetail --------------------------------------------------------------------------------- -INSERT INTO - pricing.lastpricedetail -SELECT - COALESCE(f.customer, s.customer) AS customer, - COALESCE(f.partgroup, s.partgroup) AS partgroup, - CONCAT( - '{', - COALESCE(f.json_block, ''), - CASE - WHEN f.json_block IS NOT NULL AND s.json_block IS NOT NULL THEN ',' - ELSE '' - END, - COALESCE(s.json_block, ''), - '}' - ) AS part_stats -FROM flag_json f -FULL OUTER JOIN seg_json s - ON f.customer = s.customer AND f.partgroup = s.partgroup; + CREATE UNIQUE NONCLUSTERED INDEX lastprice_cust_partgroup ON FAnalysis.PRICING.lastpricedetail ( customer ASC , partgroup ASC ); diff --git a/tables/pricelist_ranged.ms.sql b/tables/pricelist_ranged.ms.sql index d25fc9b..fe36c12 100644 --- a/tables/pricelist_ranged.ms.sql +++ b/tables/pricelist_ranged.ms.sql @@ -1,199 +1,11 @@ -DROP TABLE pricing.pricelist_ranged; - CREATE TABLE pricing.pricelist_ranged ( - jcplcd varchar(5) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, - jcpart varchar(20) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, - jcunit varchar(3) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL, - jcvoll numeric(12,5) NOT NULL, - jcpric numeric(12,5) NOT NULL, - vb_from float NULL, - vb_to float NULL, - price float NOT NULL + jcplcd varchar(5) , + jcpart varchar(20) , + jcunit varchar(3) , + jcvoll numeric(12,5) , + jcpric numeric(12,5) , + vb_from float , + vb_to float , + price float ); - -CREATE NONCLUSTERED INDEX pricelist_ranged_idx ON FAnalysis.PRICING.pricelist_ranged ( jcpart ASC , jcplcd ASC , vb_from ASC , vb_to ASC ) ; - ---XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX ------------------------------------------------------------traverse unit of measure graph----------------------------------------------------------------------- ---XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX --------------setup table to hold target conversions--------------------- - - -SELECT DISTINCT - jcpart partn - ,jcunit fu - ,'PC' tu - ,cast(null as numeric) factor -INTO - #anchor -FROM - cmsinterfacein.lgdat.iprcc -WHERE - 1=1; - ---SELECT * FROM #anchor - --------pre-build punit stacked on itself with the columns flipped so you can go either direction per join--------- -SELECT - * -INTO - #g -FROM - ( - SELECT - IHPART IHPART, - rtrim(IHUNT1) IHUNT1, - rtrim(IHUNT2) IHUNT2, - IHCNV1 IHCNV1, - IHCNV2 IHCNV2 - FROM - CMSInterfaceIN.LGDAT.PUNIT pu - --only deal with parts in the anchor table or the &&global parts - INNER JOIN ( - SELECT DISTINCT partn FROM #anchor - ) items ON - items.partn = pu.ihpart - OR pu.ihpart = '&&GLOBAL' - UNION - SELECT - IHPART IHPART, - rtrim(IHUNT2) IHUNT1, - rtrim(IHUNT1) IHUNT2, - IHCNV2 IHCNV1, - IHCNV1 IHCNV2 - FROM - CMSInterfaceIN.LGDAT.PUNIT pu - --only deal with parts in the anchor table or the &&global parts - INNER JOIN ( - SELECT DISTINCT partn FROM #anchor - ) items ON - items.partn = pu.ihpart - OR pu.ihpart = '&&GLOBAL' - ) x ; - -CREATE INDEX g_idx on #g(ihpart,ihunt1); - -WITH ---------do the expansion on all paths until the target uom is matched---------------------------------------------- ---(complains about types not matching between anchor and recursion, explicitly just casting everything) -uom (partn, partx, lvl, mastf, mastt, xf, xt, factor, xfactor, xnum, xden, id, uom_list) AS -( - SELECT - cast(partn as varchar(20)) --partn - ,cast(partn as varchar(20)) --partx - ,cast(0 as int) --lvl - ,fu --mastf - ,tu --mastt - ,cast(fu as varchar(3)) --xf - ,cast(fu as varchar(3)) --xt - ,CAST(1 AS FLOAT) --factor - ,CAST(1 AS FLOAT) --xfactor - ,CAST(1 AS FLOAT) --xnum - ,CAST(1 AS FLOAT) --xden - ,format(row_number() over (ORDER BY partn),'000000') - ,cast(trim(fu) as varchar(max)) - FROM - #anchor - UNION ALL - SELECT - cast(uom.partn as varchar(20)) --partn - ,cast(ihpart as varchar(20)) --partx - ,CAST(uom.lvl + 1 AS INT) --lvl - ,uom.mastf --mastf - ,uom.mastt --mastt - ,cast(p.ihunt1 as varchar(3)) --xf - ,cast(p.ihunt2 as varchar(3)) --xt - ,CAST(p.ihcnv2/p.ihcnv1 AS FLOAT) --factor - ,CAST(p.ihcnv2/p.ihcnv1 AS FLOAT) * uom.xfactor --xfactor - ,p.ihcnv2 * uom.xnum --xnum - ,p.ihcnv1 * uom.xden --xden - ,uom.id + '.' + format(row_number() over (PARTITION BY uom.id ORDER BY partn),'00') - ,uom.uom_list + '.' + trim(p.ihunt2) - FROM - uom - INNER JOIN #g p ON - p.ihpart IN (uom.partn,'&&GLOBAL') - AND p.ihunt1 = uom.xt - WHERE - 1=1 - --AND p.ihunt2 not in ('BD','BG','BU','BX','CA','CS','PA','PL','SL','C','K','DOZ','PR') - AND p.ihunt1 <> uom.mastt - --prevent recursion: newest joined UOM can't be in the history - AND charindex(p.ihunt2,uom.uom_list) = 0 -) ---SELECT COUNT(*) FROM UOM ---------------uom is going to have multiple rows per requested conversion, need to use row_number to pick the best row------------------------------ -,sorted AS ( -SELECT - partn, mastf from_uom, xt to_uom, xfactor factor, lvl steps, row_number() OVER (PARTITION BY partn, mastf, mastt ORDER BY lvl ASC, factor ASC) rn -FROM - uom -WHERE - xt = mastt -) -SELECT * INTO #uom FROM sorted WHERE rn = 1; ---so far so good - -drop table #anchor; -drop table #g; - -TRUNCATE TABLE pricing.pricelist_ranged; - -WITH -conv AS ( - SELECT - p.jcplcd, - p.jcpart, - p.jcunit, - p.jcvoll, - p.jcpric, - u.factor, - -- Normalize volume and price to PC - p.jcvoll * u.factor AS vol_pc, - p.jcpric / u.factor AS price_pc - FROM - cmsinterfacein.lgdat.iprcc p - INNER JOIN #uom u - ON u.partn = p.jcpart - AND u.from_uom = p.jcunit - AND u.to_uom = 'PC' -), -sorted AS ( - SELECT - c.*, - ROW_NUMBER() OVER (PARTITION BY c.jcplcd, c.jcpart ORDER BY vol_pc ASC) AS rn - FROM conv c -), -ranged AS ( - SELECT - curr.jcplcd, - curr.jcpart, - curr.jcunit, - curr.jcvoll, - curr.jcpric, - curr.vol_pc, - curr.price_pc, - curr.vol_pc AS vb_from, - COALESCE(next.vol_pc, 9999999.0) AS vb_to - FROM - sorted curr - LEFT JOIN sorted next - ON curr.jcplcd = next.jcplcd - AND curr.jcpart = next.jcpart - AND curr.rn + 1 = next.rn -) -INSERT INTO - pricing.pricelist_ranged -SELECT - RTRIM(jcplcd) jcplcd, - RTRIM(jcpart) jcpart, - jcunit, - jcvoll, - jcpric, - vb_from, - vb_to, - price_pc AS price -FROM - ranged; - ---CREATE INDEX pricelist_ranged_idx ON pricing.pricelist_ranged(jcpart, jcplcd, vb_from, vb_to); + CREATE NONCLUSTERED INDEX pricelist_ranged_idx ON FAnalysis.PRICING.pricelist_ranged ( jcpart ASC , jcplcd ASC , vb_from ASC , vb_to ASC ); diff --git a/tables/pricelist_ranged.pg.sql b/tables/pricelist_ranged.pg.sql index 1035fc5..0c128e3 100644 --- a/tables/pricelist_ranged.pg.sql +++ b/tables/pricelist_ranged.pg.sql @@ -1,101 +1,11 @@ -DROP TABLE IF EXISTS uomc; - -CREATE TEMP TABLE uomc AS ( -WITH -uom AS ( - SELECT - uom.p part - ,uom.f fu - ,uom.t tu - ,uom.nm/uom.dm conv - FROM - ( - SELECT - jsonb_agg(row_to_json(d)::jsonb) jdoc - FROM - ( - select distinct - jcpart partn - , jcunit fu - , 'PC' tu - from - lgdat.iprcc - WHERE - jcpart <> '' - ) d - ) c - JOIN LATERAL rlarp.uom_array(c.jdoc) uom ON TRUE -) -SELECT * FROM uom -) WITH DATA; - -CREATE INDEX uom_idx ON uomc (part, fu, tu); - - --- Clear the output table -TRUNCATE TABLE pricequote.pricelist_ranged; - ---DROP TABLE pricequote.pricelist_ranged; - --- Compute normalized volume/price and ranges ---CREATE TABLE pricequote.pricelist_ranged AS ( -WITH -conv AS ( - SELECT - p.jcplcd, - p.jcpart, - p.jcunit, - p.jcvoll, - p.jcpric, - u.conv, - (p.jcvoll * u.conv) AS vol_pc, - (p.jcpric / NULLIF(u.conv, 0)) AS price_pc - FROM - lgdat.iprcc p - INNER JOIN uomc u - ON u.part = p.jcpart - AND u.fu = p.jcunit - AND u.tu = 'PC' -), ---SELECT * FROM conv LIMIT 1000 -sorted AS ( - SELECT - *, - ROW_NUMBER() OVER (PARTITION BY jcplcd, jcpart ORDER BY vol_pc ASC) AS rn - FROM conv -), -ranged AS ( - SELECT - curr.jcplcd, - curr.jcpart, - curr.jcunit, - curr.jcvoll, - curr.jcpric, - curr.vol_pc, - curr.price_pc price, - curr.vol_pc AS vb_from, - COALESCE(next.vol_pc, 9999999.0) AS vb_to - FROM - sorted curr - LEFT JOIN sorted next - ON curr.jcplcd = next.jcplcd - AND curr.jcpart = next.jcpart - AND curr.rn + 1 = next.rn -) ---SELECT * FROM ranged -INSERT INTO pricequote.pricelist_ranged ( - jcplcd, jcpart, jcunit, jcvoll, jcpric, vb_from, vb_to, price -) -SELECT - jcplcd, - jcpart, - jcunit, - jcvoll, - jcpric, - vb_from, - vb_to, - price -FROM ranged; - - -CREATE INDEX pricelist_ranged_idx ON pricequote.pricelist_ranged ( jcpart ASC , jcplcd ASC , vb_from ASC , vb_to ASC ) ; \ No newline at end of file +CREATE TABLE pricelist_ranged ( + jcplcd text NULL, + jcpart text NULL, + jcunit text NULL, + jcvoll numeric(12, 5) NULL, + jcpric numeric(12, 5) NULL, + vb_from numeric NULL, + vb_to numeric NULL, + price numeric NULL +); +CREATE INDEX pricelist_ranged_idx ON pricequote.pricelist_ranged USING btree (jcpart, jcplcd, vb_from, vb_to); diff --git a/tables/target_prices.ms.sql b/tables/target_prices.ms.sql index 8c38661..b8fa641 100644 --- a/tables/target_prices.ms.sql +++ b/tables/target_prices.ms.sql @@ -16,26 +16,4 @@ ALTER TABLE pricing.target_prices ADD CONSTRAINT uq_target_prices_unique_combo UNIQUE (stlc, ds, chan, tier, vol, lower_bound); -DELETE FROM pricing.target_prices; - -INSERT INTO - pricing.target_prices -SELECT - stlc, - ds, - chan, - tier, - vol, - -- Extract lower bound: text between '[' and ',' - TRY_CAST(SUBSTRING(vol, 2, CHARINDEX(',', vol) - 2) AS INT) AS lower_bound, - -- Extract upper bound: text between ',' and ')' - CASE - WHEN RIGHT(vol, 2) = ',)' THEN NULL - ELSE TRY_CAST(SUBSTRING(vol, CHARINDEX(',', vol) + 1, LEN(vol) - CHARINDEX(',', vol) - 1) AS INT) - END AS upper_bound, - price, - math -FROM - usmidsap02.ubm.pricequote.target_prices_view; - --SELECT COUNT(*) FROM pricing.target_prices