vault backup: 2023-11-03 11:00:54
This commit is contained in:
		
							parent
							
								
									0be561a7f2
								
							
						
					
					
						commit
						2fe17ac58c
					
				
							
								
								
									
										77
									
								
								sql/get.sql
									
									
									
									
									
								
							
							
						
						
									
										77
									
								
								sql/get.sql
									
									
									
									
									
								
							| @ -1,46 +1,61 @@ | ||||
| WITH | ||||
| --getj AS ( | ||||
| --    SELECT | ||||
| --        jsonb_build_object('mold',stlc) doc | ||||
| --    FROM | ||||
| --        "CMS.CUSLG".itemm  | ||||
| --    WHERE  | ||||
| --        item = $1 | ||||
| --) | ||||
| agg AS ( | ||||
| getj AS ( | ||||
|     SELECT | ||||
|     ( | ||||
|         SELECT | ||||
|             jsonb_build_object('mold',JSON_AGG(DISTINCT stlc)) doc | ||||
|         FROM | ||||
|             "CMS.CUSLG".itemm  | ||||
|         WHERE  | ||||
|             item ~ 'TUH10000A10B04' | ||||
|     ) || | ||||
|     ( | ||||
|         SELECT | ||||
|             jsonb_build_object('cust',JSONB_AGG(DISTINCT c.dba)) | ||||
|         FROM | ||||
|             rlarp.cust c | ||||
|         WHERE  | ||||
|             c.dba ~ 'DIAMOND R' | ||||
|     ) doc | ||||
| ) | ||||
| ,agg AS ( | ||||
|     SELECT  | ||||
|          gset | ||||
|         ,agglevel | ||||
|         ,(SELECT string_agg(ae.v,'.') FROM jsonb_array_elements_text(p.agglevel) ae(v)) agglvl | ||||
|         ,season | ||||
|         ,(select doc from getj) gdoc | ||||
|     FROM  | ||||
|         rlarp.price_pool_dev  | ||||
|         rlarp.price_pool_dev p | ||||
|     WHERE   | ||||
|         --gset @> '{"mold":"XNS0T1G3"}'::jsonb  | ||||
|         --gut the exact mold and actuals only | ||||
|         gset @> jsonb_build_object( | ||||
|             'mold','TUH10000', | ||||
|             'mold',(SELECT doc->'mold'->>0 FROM getj), | ||||
|             'vers','A' | ||||
|         ) | ||||
|         --pull either the exact customer or no customer | ||||
|         AND ( | ||||
|             gset->>'cust' ~ 'DIAMOND' | ||||
|             gset @> jsonb_build_object( | ||||
|                 'cust',(SELECT doc->'cust'->>0 FROM getj) | ||||
|             ) | ||||
|             OR NOT gset ? 'cust' | ||||
|         ) | ||||
|     ORDER BY  | ||||
|         agglevel ASC | ||||
| ) | ||||
| SELECT | ||||
|     jsonb_build_object('agg',agglevel ) | ||||
|     || jsonb_build_object( | ||||
|         'data', | ||||
|         jsonb_agg(gset || jsonb_build_object('season',season)) | ||||
|     ) data | ||||
| FROM | ||||
|     agg | ||||
| GROUP BY | ||||
|     agglevel | ||||
| LIMIT 10 | ||||
| --SELECT  | ||||
| --     jsonb_pretty(agglevel) agglevel | ||||
| --    ,jsonb_pretty(gset)     gset | ||||
| --    ,jsonb_pretty(season)   season | ||||
| --FROM   | ||||
| --    agg | ||||
| ,final AS ( | ||||
|     SELECT | ||||
|         jsonb_build_object( | ||||
|             agg.agglvl, | ||||
|             jsonb_build_object( | ||||
|                 'data', | ||||
|                 jsonb_agg(gset || jsonb_build_object('season',season)) | ||||
|             )  | ||||
|         ) data | ||||
|         ,gdoc | ||||
|     FROM | ||||
|         agg | ||||
|     GROUP BY | ||||
|         agglvl | ||||
|         ,gdoc | ||||
| ) | ||||
| select * from final | ||||
|  | ||||
							
								
								
									
										42
									
								
								sql/guidance.pg.sql
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										42
									
								
								sql/guidance.pg.sql
									
									
									
									
									
										Normal file
									
								
							| @ -0,0 +1,42 @@ | ||||
| CREATE OR REPLACE FUNCTION rlarp.guidancejsd(_p jsonb, cust text, prod text) | ||||
| RETURNS jsonb | ||||
| LANGUAGE plv8 | ||||
| AS $function$ | ||||
| 
 | ||||
| 
 | ||||
| function findMostRecentPrice(data, cust, prod) { | ||||
|   let mostRecentPrice = null; | ||||
|   let mostRecentYear = null; | ||||
| 
 | ||||
|   // Iterate through each product | ||||
|   data.forEach(product => { | ||||
|     // Check if the product matches the customer channel and version | ||||
|     if (product.chan === cust && (product.v1ds === prod || product.v0ds === prod)) { | ||||
|       // Iterate through the seasons for the product | ||||
|       for (let year in product.season) { | ||||
|         // Convert year to number for comparison | ||||
|         let yearNum = parseInt(year); | ||||
|         // Check if this year is more recent than the current most recent year | ||||
|         if (mostRecentYear === null || yearNum > mostRecentYear) { | ||||
|           mostRecentYear = yearNum; | ||||
|           // Update the most recent price | ||||
|           mostRecentPrice = product.season[year].price_usd; | ||||
|         } | ||||
|       } | ||||
|     } | ||||
|   }); | ||||
| 
 | ||||
|   return mostRecentPrice; | ||||
| } | ||||
| 
 | ||||
| // Example usage: | ||||
| const jsonData = _p; | ||||
| 
 | ||||
| const cust = 'W'; // or 'D', depending on the customer | ||||
| const prod = 'TUH10000'; // the product version you're interested in | ||||
| 
 | ||||
| const price = findMostRecentPrice(jsonData.data, cust, prod); | ||||
| console.log(`The most recent price for the customer is: ${price}`); | ||||
| return price; | ||||
| 
 | ||||
| $function$; | ||||
		Loading…
	
		Reference in New Issue
	
	Block a user